From cb6f51867800ca68535e5f38b3e8644367149cd4 Mon Sep 17 00:00:00 2001 From: Bobbie Soedirgo Date: Wed, 7 Jun 2023 21:45:51 +0800 Subject: [PATCH 1/4] fix: replace CTEs with joins --- src/lib/PostgresMetaTables.ts | 8 ----- src/lib/sql/tables.sql | 58 ++++++++++++++++++++++++++++++++++- test/lib/tables.ts | 4 +-- 3 files changed, 59 insertions(+), 11 deletions(-) diff --git a/src/lib/PostgresMetaTables.ts b/src/lib/PostgresMetaTables.ts index 2350c664..1f8a1bc7 100644 --- a/src/lib/PostgresMetaTables.ts +++ b/src/lib/PostgresMetaTables.ts @@ -250,15 +250,7 @@ COMMIT;` const generateEnrichedTablesSql = ({ includeColumns }: { includeColumns: boolean }) => ` with tables as (${tablesSql}) ${includeColumns ? `, columns as (${columnsSql})` : ''} - , primary_keys as (${primaryKeysSql}) - , relationships as (${relationshipsOldSql}) select * ${includeColumns ? `, ${coalesceRowsToArray('columns', 'columns.table_id = tables.id')}` : ''} - , ${coalesceRowsToArray('primary_keys', 'primary_keys.table_id = tables.id')} - , ${coalesceRowsToArray( - 'relationships', - `(relationships.source_schema = tables.schema AND relationships.source_table_name = tables.name) - OR (relationships.target_table_schema = tables.schema AND relationships.target_table_name = tables.name)` - )} from tables` diff --git a/src/lib/sql/tables.sql b/src/lib/sql/tables.sql index 5ac269fb..6a335352 100644 --- a/src/lib/sql/tables.sql +++ b/src/lib/sql/tables.sql @@ -16,10 +16,64 @@ SELECT ) AS size, pg_stat_get_live_tuples(c.oid) AS live_rows_estimate, pg_stat_get_dead_tuples(c.oid) AS dead_rows_estimate, - obj_description(c.oid) AS comment + obj_description(c.oid) AS comment, + coalesce( + jsonb_agg(primary_keys) filter (where primary_keys is not null), + '[]' + ) as primary_keys, + coalesce( + jsonb_agg(relationships) filter (where relationships is not null), + '[]' + ) as relationships FROM pg_namespace nc JOIN pg_class c ON nc.oid = c.relnamespace + left join ( + select + n.nspname as schema, + c.relname as table_name, + a.attname as name, + c.oid :: int8 as table_id + from + pg_index i, + pg_class c, + pg_attribute a, + pg_namespace n + where + i.indrelid = c.oid + and c.relnamespace = n.oid + and a.attrelid = c.oid + and a.attnum = any (i.indkey) + and i.indisprimary + ) as primary_keys + on primary_keys.table_id = c.oid + left join ( + select + c.oid :: int8 as id, + c.conname as constraint_name, + nsa.nspname as source_schema, + csa.relname as source_table_name, + sa.attname as source_column_name, + nta.nspname as target_table_schema, + cta.relname as target_table_name, + ta.attname as target_column_name + from + pg_constraint c + join ( + pg_attribute sa + join pg_class csa on sa.attrelid = csa.oid + join pg_namespace nsa on csa.relnamespace = nsa.oid + ) on sa.attrelid = c.conrelid and sa.attnum = any (c.conkey) + join ( + pg_attribute ta + join pg_class cta on ta.attrelid = cta.oid + join pg_namespace nta on cta.relnamespace = nta.oid + ) on ta.attrelid = c.confrelid and ta.attnum = any (c.confkey) + where + c.contype = 'f' + ) as relationships + on (relationships.source_schema = nc.nspname and relationships.source_table_name = c.relname) + or (relationships.target_table_schema = nc.nspname and relationships.target_table_name = c.relname) WHERE c.relkind IN ('r', 'p') AND NOT pg_is_other_temp_schema(nc.oid) @@ -31,3 +85,5 @@ WHERE ) OR has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES') ) +group by + c.oid, nc.nspname diff --git a/test/lib/tables.ts b/test/lib/tables.ts index ae3dfe97..9122b166 100644 --- a/test/lib/tables.ts +++ b/test/lib/tables.ts @@ -465,12 +465,12 @@ test('primary keys', async () => { "name": "t", "primary_keys": [ { - "name": "c", + "name": "cc", "schema": "public", "table_name": "t", }, { - "name": "cc", + "name": "c", "schema": "public", "table_name": "t", }, From 139911a56d49f91776d9c8f3c6103d97c12a7009 Mon Sep 17 00:00:00 2001 From: Bobbie Soedirgo Date: Wed, 7 Jun 2023 22:01:04 +0800 Subject: [PATCH 2/4] chore: remove unused vars & files --- src/lib/PostgresMetaTables.ts | 2 +- src/lib/sql/index.ts | 2 -- src/lib/sql/primary_keys.sql | 16 ---------------- src/lib/sql/relationships_old.sql | 25 ------------------------- 4 files changed, 1 insertion(+), 44 deletions(-) delete mode 100644 src/lib/sql/primary_keys.sql delete mode 100644 src/lib/sql/relationships_old.sql diff --git a/src/lib/PostgresMetaTables.ts b/src/lib/PostgresMetaTables.ts index 1f8a1bc7..5b97c253 100644 --- a/src/lib/PostgresMetaTables.ts +++ b/src/lib/PostgresMetaTables.ts @@ -1,7 +1,7 @@ import { ident, literal } from 'pg-format' import { DEFAULT_SYSTEM_SCHEMAS } from './constants.js' import { coalesceRowsToArray, filterByList } from './helpers.js' -import { columnsSql, primaryKeysSql, relationshipsOldSql, tablesSql } from './sql/index.js' +import { columnsSql, tablesSql } from './sql/index.js' import { PostgresMetaResult, PostgresTable, diff --git a/src/lib/sql/index.ts b/src/lib/sql/index.ts index 1ad0c380..a58f1a28 100644 --- a/src/lib/sql/index.ts +++ b/src/lib/sql/index.ts @@ -13,13 +13,11 @@ export const materializedViewsSql = await readFile( 'utf-8' ) export const policiesSql = await readFile(join(__dirname, 'policies.sql'), 'utf-8') -export const primaryKeysSql = await readFile(join(__dirname, 'primary_keys.sql'), 'utf-8') export const publicationsSql = await readFile(join(__dirname, 'publications.sql'), 'utf-8') export const tableRelationshipsSql = await readFile( join(__dirname, 'table_relationships.sql'), 'utf-8' ) -export const relationshipsOldSql = await readFile(join(__dirname, 'relationships_old.sql'), 'utf-8') export const rolesSql = await readFile(join(__dirname, 'roles.sql'), 'utf-8') export const schemasSql = await readFile(join(__dirname, 'schemas.sql'), 'utf-8') export const tablesSql = await readFile(join(__dirname, 'tables.sql'), 'utf-8') diff --git a/src/lib/sql/primary_keys.sql b/src/lib/sql/primary_keys.sql deleted file mode 100644 index b49d0603..00000000 --- a/src/lib/sql/primary_keys.sql +++ /dev/null @@ -1,16 +0,0 @@ -SELECT - n.nspname AS schema, - c.relname AS table_name, - a.attname AS name, - c.oid :: int8 AS table_id -FROM - pg_index i, - pg_class c, - pg_attribute a, - pg_namespace n -WHERE - i.indrelid = c.oid - AND c.relnamespace = n.oid - AND a.attrelid = c.oid - AND a.attnum = ANY (i.indkey) - AND i.indisprimary diff --git a/src/lib/sql/relationships_old.sql b/src/lib/sql/relationships_old.sql deleted file mode 100644 index 953a33e3..00000000 --- a/src/lib/sql/relationships_old.sql +++ /dev/null @@ -1,25 +0,0 @@ -SELECT - c.oid :: int8 AS id, - c.conname AS constraint_name, - nsa.nspname AS source_schema, - csa.relname AS source_table_name, - sa.attname AS source_column_name, - nta.nspname AS target_table_schema, - cta.relname AS target_table_name, - ta.attname AS target_column_name -FROM - pg_constraint c - JOIN ( - pg_attribute sa - JOIN pg_class csa ON sa.attrelid = csa.oid - JOIN pg_namespace nsa ON csa.relnamespace = nsa.oid - ) ON sa.attrelid = c.conrelid - AND sa.attnum = ANY (c.conkey) - JOIN ( - pg_attribute ta - JOIN pg_class cta ON ta.attrelid = cta.oid - JOIN pg_namespace nta ON cta.relnamespace = nta.oid - ) ON ta.attrelid = c.confrelid - AND ta.attnum = ANY (c.confkey) -WHERE - c.contype = 'f' From 2f8a204eb39018a3f122351328705b3b2101133d Mon Sep 17 00:00:00 2001 From: Bobbie Soedirgo Date: Wed, 7 Jun 2023 22:52:33 +0800 Subject: [PATCH 3/4] chore: complete group by columns --- src/lib/sql/tables.sql | 7 ++++++- 1 file changed, 6 insertions(+), 1 deletion(-) diff --git a/src/lib/sql/tables.sql b/src/lib/sql/tables.sql index 6a335352..273fab05 100644 --- a/src/lib/sql/tables.sql +++ b/src/lib/sql/tables.sql @@ -86,4 +86,9 @@ WHERE OR has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES') ) group by - c.oid, nc.nspname + c.oid, + c.relname, + c.relrowsecurity, + c.relforcerowsecurity, + c.relreplident, + nc.nspname From 2fcab08f00fc7dd7c4044518de2a6551f2009ceb Mon Sep 17 00:00:00 2001 From: Bobbie Soedirgo Date: Thu, 8 Jun 2023 01:09:09 +0800 Subject: [PATCH 4/4] fix: pre-aggregate primary_keys Can't aggregate over 2 source tables in the same query, otherwise it'll produce incorrect results: https://stackoverflow.com/a/27626358/12396224 --- src/lib/sql/tables.sql | 48 +++++++++++++++++++++++------------------- test/lib/tables.ts | 4 ++-- 2 files changed, 28 insertions(+), 24 deletions(-) diff --git a/src/lib/sql/tables.sql b/src/lib/sql/tables.sql index 273fab05..d0bb9df3 100644 --- a/src/lib/sql/tables.sql +++ b/src/lib/sql/tables.sql @@ -17,10 +17,7 @@ SELECT pg_stat_get_live_tuples(c.oid) AS live_rows_estimate, pg_stat_get_dead_tuples(c.oid) AS dead_rows_estimate, obj_description(c.oid) AS comment, - coalesce( - jsonb_agg(primary_keys) filter (where primary_keys is not null), - '[]' - ) as primary_keys, + coalesce(pk.primary_keys, '[]') as primary_keys, coalesce( jsonb_agg(relationships) filter (where relationships is not null), '[]' @@ -30,23 +27,29 @@ FROM JOIN pg_class c ON nc.oid = c.relnamespace left join ( select - n.nspname as schema, - c.relname as table_name, - a.attname as name, - c.oid :: int8 as table_id - from - pg_index i, - pg_class c, - pg_attribute a, - pg_namespace n - where - i.indrelid = c.oid - and c.relnamespace = n.oid - and a.attrelid = c.oid - and a.attnum = any (i.indkey) - and i.indisprimary - ) as primary_keys - on primary_keys.table_id = c.oid + table_id, + jsonb_agg(_pk.*) as primary_keys + from ( + select + n.nspname as schema, + c.relname as table_name, + a.attname as name, + c.oid :: int8 as table_id + from + pg_index i, + pg_class c, + pg_attribute a, + pg_namespace n + where + i.indrelid = c.oid + and c.relnamespace = n.oid + and a.attrelid = c.oid + and a.attnum = any (i.indkey) + and i.indisprimary + ) as _pk + group by table_id + ) as pk + on pk.table_id = c.oid left join ( select c.oid :: int8 as id, @@ -91,4 +94,5 @@ group by c.relrowsecurity, c.relforcerowsecurity, c.relreplident, - nc.nspname + nc.nspname, + pk.primary_keys diff --git a/test/lib/tables.ts b/test/lib/tables.ts index 9122b166..ae3dfe97 100644 --- a/test/lib/tables.ts +++ b/test/lib/tables.ts @@ -465,12 +465,12 @@ test('primary keys', async () => { "name": "t", "primary_keys": [ { - "name": "cc", + "name": "c", "schema": "public", "table_name": "t", }, { - "name": "c", + "name": "cc", "schema": "public", "table_name": "t", },