Skip to content

Commit 80809c7

Browse files
committed
feat(typegen): view relationships
Generate types for relationships from views to tables, tables to views, and views to views.
1 parent 844164a commit 80809c7

File tree

7 files changed

+443
-49
lines changed

7 files changed

+443
-49
lines changed

src/lib/PostgresMetaMaterializedViews.ts

Lines changed: 0 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -72,7 +72,6 @@ export default class PostgresMetaMaterializedViews {
7272
const sql = `${generateEnrichedMaterializedViewsSql({
7373
includeColumns: true,
7474
})} where materialized_views.id = ${literal(id)};`
75-
console.log(sql)
7675
const { data, error } = await this.query(sql)
7776
if (error) {
7877
return { data, error }

src/lib/PostgresMetaRelationships.ts

Lines changed: 138 additions & 14 deletions
Original file line numberDiff line numberDiff line change
@@ -1,27 +1,151 @@
1-
import { tableRelationshipsSql } from './sql/index.js'
1+
import { literal } from 'pg-format'
2+
import { DEFAULT_SYSTEM_SCHEMAS } from './constants.js'
3+
import { tableRelationshipsSql, viewsKeyDependenciesSql } from './sql/index.js'
24
import { PostgresMetaResult, PostgresRelationship } from './types.js'
35

6+
/*
7+
* Only used for generating types at the moment. Will need some cleanups before
8+
* using it for other things, e.g. /relationships endpoint.
9+
*/
410
export default class PostgresMetaRelationships {
511
query: (sql: string) => Promise<PostgresMetaResult<any>>
612

713
constructor(query: (sql: string) => Promise<PostgresMetaResult<any>>) {
814
this.query = query
915
}
1016

11-
async list({
12-
limit,
13-
offset,
14-
}: {
15-
limit?: number
16-
offset?: number
17-
} = {}): Promise<PostgresMetaResult<PostgresRelationship[]>> {
18-
let sql = tableRelationshipsSql
19-
if (limit) {
20-
sql = `${sql} LIMIT ${limit}`
17+
async list(): Promise<PostgresMetaResult<PostgresRelationship[]>> {
18+
let allTableM2oAndO2oRelationships: PostgresRelationship[]
19+
{
20+
let sql = tableRelationshipsSql
21+
const { data, error } = (await this.query(sql)) as PostgresMetaResult<PostgresRelationship[]>
22+
if (error) {
23+
return { data: null, error }
24+
}
25+
allTableM2oAndO2oRelationships = data
2126
}
22-
if (offset) {
23-
sql = `${sql} OFFSET ${offset}`
27+
28+
/*
29+
* Adapted from:
30+
* https://github.com/PostgREST/postgrest/blob/f9f0f79fa914ac00c11fbf7f4c558e14821e67e2/src/PostgREST/SchemaCache.hs#L392
31+
*/
32+
let allViewM2oAndO2oRelationships: PostgresRelationship[]
33+
{
34+
type ColDep = {
35+
table_column: string
36+
view_columns: string[]
37+
}
38+
type KeyDep = {
39+
table_schema: string
40+
table_name: string
41+
view_schema: string
42+
view_name: string
43+
constraint_name: string
44+
constraint_type: 'f' | 'f_ref' | 'p' | 'p_ref'
45+
column_dependencies: ColDep[]
46+
}
47+
48+
const { data: viewsKeyDependencies, error } = (await this.query(
49+
allViewsKeyDependenciesSql
50+
)) as PostgresMetaResult<KeyDep[]>
51+
if (error) {
52+
return { data: null, error }
53+
}
54+
55+
const viewRelationships = allTableM2oAndO2oRelationships.flatMap((r) => {
56+
const expandKeyDepCols = (
57+
colDeps: ColDep[]
58+
): { tableColumns: string[]; viewColumns: string[] }[] => {
59+
const tableColumns = colDeps.map(({ table_column }) => table_column)
60+
// https://gist.github.com/ssippe/1f92625532eef28be6974f898efb23ef?permalink_comment_id=3474581#gistcomment-3474581
61+
const cartesianProduct = <T>(allEntries: T[][]): T[][] => {
62+
return allEntries.reduce<T[][]>(
63+
(results, entries) =>
64+
results
65+
.map((result) => entries.map((entry) => [...result, entry]))
66+
.reduce((subResults, result) => [...subResults, ...result], []),
67+
[[]]
68+
)
69+
}
70+
const viewColumnsPermutations = cartesianProduct(colDeps.map((cd) => cd.view_columns))
71+
return viewColumnsPermutations.map((viewColumns) => ({ tableColumns, viewColumns }))
72+
}
73+
74+
const viewToTableKeyDeps = viewsKeyDependencies.filter(
75+
(vkd) =>
76+
vkd.table_schema === r.schema &&
77+
vkd.table_name === r.relation &&
78+
vkd.constraint_name === r.foreign_key_name &&
79+
vkd.constraint_type === 'f'
80+
)
81+
const tableToViewKeyDeps = viewsKeyDependencies.filter(
82+
(vkd) =>
83+
vkd.table_schema === r.referenced_schema &&
84+
vkd.table_name === r.referenced_relation &&
85+
vkd.constraint_name === r.foreign_key_name &&
86+
vkd.constraint_type === 'f_ref'
87+
)
88+
89+
const viewToTableRelationships = viewToTableKeyDeps.flatMap((vtkd) =>
90+
expandKeyDepCols(vtkd.column_dependencies).map(({ viewColumns }) => ({
91+
foreign_key_name: r.foreign_key_name,
92+
schema: vtkd.view_schema,
93+
relation: vtkd.view_name,
94+
columns: viewColumns,
95+
referenced_schema: r.referenced_schema,
96+
referenced_relation: r.referenced_relation,
97+
referenced_columns: r.referenced_columns,
98+
}))
99+
)
100+
101+
const tableToViewRelationships = tableToViewKeyDeps.flatMap((tvkd) =>
102+
expandKeyDepCols(tvkd.column_dependencies).map(({ viewColumns }) => ({
103+
foreign_key_name: r.foreign_key_name,
104+
schema: r.schema,
105+
relation: r.relation,
106+
columns: r.columns,
107+
referenced_schema: tvkd.view_schema,
108+
referenced_relation: tvkd.view_name,
109+
referenced_columns: viewColumns,
110+
}))
111+
)
112+
113+
const viewToViewRelationships = viewToTableKeyDeps.flatMap((vtkd) =>
114+
expandKeyDepCols(vtkd.column_dependencies).flatMap(({ viewColumns }) =>
115+
tableToViewKeyDeps.flatMap((tvkd) =>
116+
expandKeyDepCols(tvkd.column_dependencies).map(
117+
({ viewColumns: referencedViewColumns }) => ({
118+
foreign_key_name: r.foreign_key_name,
119+
schema: vtkd.view_schema,
120+
relation: vtkd.view_name,
121+
columns: viewColumns,
122+
referenced_schema: tvkd.view_schema,
123+
referenced_relation: tvkd.view_name,
124+
referenced_columns: referencedViewColumns,
125+
})
126+
)
127+
)
128+
)
129+
)
130+
131+
return [
132+
...viewToTableRelationships,
133+
...tableToViewRelationships,
134+
...viewToViewRelationships,
135+
]
136+
})
137+
138+
allViewM2oAndO2oRelationships = viewRelationships
139+
}
140+
141+
return {
142+
data: allTableM2oAndO2oRelationships.concat(allViewM2oAndO2oRelationships),
143+
error: null,
24144
}
25-
return await this.query(sql)
26145
}
27146
}
147+
148+
const allViewsKeyDependenciesSql = viewsKeyDependenciesSql.replaceAll(
149+
'__EXCLUDED_SCHEMAS',
150+
literal(DEFAULT_SYSTEM_SCHEMAS)
151+
)

src/lib/sql/index.ts

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -26,4 +26,8 @@ export const tablesSql = await readFile(join(__dirname, 'tables.sql'), 'utf-8')
2626
export const triggersSql = await readFile(join(__dirname, 'triggers.sql'), 'utf-8')
2727
export const typesSql = await readFile(join(__dirname, 'types.sql'), 'utf-8')
2828
export const versionSql = await readFile(join(__dirname, 'version.sql'), 'utf-8')
29+
export const viewsKeyDependenciesSql = await readFile(
30+
join(__dirname, 'views_key_dependencies.sql'),
31+
'utf-8'
32+
)
2933
export const viewsSql = await readFile(join(__dirname, 'views.sql'), 'utf-8')
Lines changed: 191 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,191 @@
1+
-- Adapted from
2+
-- https://github.com/PostgREST/postgrest/blob/f9f0f79fa914ac00c11fbf7f4c558e14821e67e2/src/PostgREST/SchemaCache.hs#L820
3+
with recursive
4+
pks_fks as (
5+
-- pk + fk referencing col
6+
select
7+
contype::text as contype,
8+
conname,
9+
array_length(conkey, 1) as ncol,
10+
conrelid as resorigtbl,
11+
col as resorigcol,
12+
ord
13+
from pg_constraint
14+
left join lateral unnest(conkey) with ordinality as _(col, ord) on true
15+
where contype IN ('p', 'f')
16+
union
17+
-- fk referenced col
18+
select
19+
concat(contype, '_ref') as contype,
20+
conname,
21+
array_length(confkey, 1) as ncol,
22+
confrelid,
23+
col,
24+
ord
25+
from pg_constraint
26+
left join lateral unnest(confkey) with ordinality as _(col, ord) on true
27+
where contype='f'
28+
),
29+
views as (
30+
select
31+
c.oid as view_id,
32+
n.nspname as view_schema,
33+
c.relname as view_name,
34+
r.ev_action as view_definition
35+
from pg_class c
36+
join pg_namespace n on n.oid = c.relnamespace
37+
join pg_rewrite r on r.ev_class = c.oid
38+
where c.relkind in ('v', 'm') and n.nspname not in (__EXCLUDED_SCHEMAS)
39+
),
40+
transform_json as (
41+
select
42+
view_id, view_schema, view_name,
43+
-- the following formatting is without indentation on purpose
44+
-- to allow simple diffs, with less whitespace noise
45+
replace(
46+
replace(
47+
replace(
48+
replace(
49+
replace(
50+
replace(
51+
replace(
52+
regexp_replace(
53+
replace(
54+
replace(
55+
replace(
56+
replace(
57+
replace(
58+
replace(
59+
replace(
60+
replace(
61+
replace(
62+
replace(
63+
replace(
64+
view_definition::text,
65+
-- This conversion to json is heavily optimized for performance.
66+
-- The general idea is to use as few regexp_replace() calls as possible.
67+
-- Simple replace() is a lot faster, so we jump through some hoops
68+
-- to be able to use regexp_replace() only once.
69+
-- This has been tested against a huge schema with 250+ different views.
70+
-- The unit tests do NOT reflect all possible inputs. Be careful when changing this!
71+
-- -----------------------------------------------
72+
-- pattern | replacement | flags
73+
-- -----------------------------------------------
74+
-- `<>` in pg_node_tree is the same as `null` in JSON, but due to very poor performance of json_typeof
75+
-- we need to make this an empty array here to prevent json_array_elements from throwing an error
76+
-- when the targetList is null.
77+
-- We'll need to put it first, to make the node protection below work for node lists that start with
78+
-- null: `(<> ...`, too. This is the case for coldefexprs, when the first column does not have a default value.
79+
'<>' , '()'
80+
-- `,` is not part of the pg_node_tree format, but used in the regex.
81+
-- This removes all `,` that might be part of column names.
82+
), ',' , ''
83+
-- The same applies for `{` and `}`, although those are used a lot in pg_node_tree.
84+
-- We remove the escaped ones, which might be part of column names again.
85+
), E'\\{' , ''
86+
), E'\\}' , ''
87+
-- The fields we need are formatted as json manually to protect them from the regex.
88+
), ' :targetList ' , ',"targetList":'
89+
), ' :resno ' , ',"resno":'
90+
), ' :resorigtbl ' , ',"resorigtbl":'
91+
), ' :resorigcol ' , ',"resorigcol":'
92+
-- Make the regex also match the node type, e.g. `{QUERY ...`, to remove it in one pass.
93+
), '{' , '{ :'
94+
-- Protect node lists, which start with `({` or `((` from the greedy regex.
95+
-- The extra `{` is removed again later.
96+
), '((' , '{(('
97+
), '({' , '{({'
98+
-- This regex removes all unused fields to avoid the need to format all of them correctly.
99+
-- This leads to a smaller json result as well.
100+
-- Removal stops at `,` for used fields (see above) and `}` for the end of the current node.
101+
-- Nesting can't be parsed correctly with a regex, so we stop at `{` as well and
102+
-- add an empty key for the followig node.
103+
), ' :[^}{,]+' , ',"":' , 'g'
104+
-- For performance, the regex also added those empty keys when hitting a `,` or `}`.
105+
-- Those are removed next.
106+
), ',"":}' , '}'
107+
), ',"":,' , ','
108+
-- This reverses the "node list protection" from above.
109+
), '{(' , '('
110+
-- Every key above has been added with a `,` so far. The first key in an object doesn't need it.
111+
), '{,' , '{'
112+
-- pg_node_tree has `()` around lists, but JSON uses `[]`
113+
), '(' , '['
114+
), ')' , ']'
115+
-- pg_node_tree has ` ` between list items, but JSON uses `,`
116+
), ' ' , ','
117+
)::json as view_definition
118+
from views
119+
),
120+
target_entries as(
121+
select
122+
view_id, view_schema, view_name,
123+
json_array_elements(view_definition->0->'targetList') as entry
124+
from transform_json
125+
),
126+
results as(
127+
select
128+
view_id, view_schema, view_name,
129+
(entry->>'resno')::int as view_column,
130+
(entry->>'resorigtbl')::oid as resorigtbl,
131+
(entry->>'resorigcol')::int as resorigcol
132+
from target_entries
133+
),
134+
-- CYCLE detection according to PG docs: https://www.postgresql.org/docs/current/queries-with.html#QUERIES-WITH-CYCLE
135+
-- Can be replaced with CYCLE clause once PG v13 is EOL.
136+
recursion(view_id, view_schema, view_name, view_column, resorigtbl, resorigcol, is_cycle, path) as(
137+
select
138+
r.*,
139+
false,
140+
ARRAY[resorigtbl]
141+
from results r
142+
where view_schema not in (__EXCLUDED_SCHEMAS)
143+
union all
144+
select
145+
view.view_id,
146+
view.view_schema,
147+
view.view_name,
148+
view.view_column,
149+
tab.resorigtbl,
150+
tab.resorigcol,
151+
tab.resorigtbl = ANY(path),
152+
path || tab.resorigtbl
153+
from recursion view
154+
join results tab on view.resorigtbl=tab.view_id and view.resorigcol=tab.view_column
155+
where not is_cycle
156+
),
157+
repeated_references as(
158+
select
159+
view_id,
160+
view_schema,
161+
view_name,
162+
resorigtbl,
163+
resorigcol,
164+
array_agg(attname) as view_columns
165+
from recursion
166+
join pg_attribute vcol on vcol.attrelid = view_id and vcol.attnum = view_column
167+
group by
168+
view_id,
169+
view_schema,
170+
view_name,
171+
resorigtbl,
172+
resorigcol
173+
)
174+
select
175+
sch.nspname as table_schema,
176+
tbl.relname as table_name,
177+
rep.view_schema,
178+
rep.view_name,
179+
pks_fks.conname as constraint_name,
180+
pks_fks.contype as constraint_type,
181+
jsonb_agg(
182+
jsonb_build_object('table_column', col.attname, 'view_columns', view_columns) order by pks_fks.ord
183+
) as column_dependencies
184+
from repeated_references rep
185+
join pks_fks using (resorigtbl, resorigcol)
186+
join pg_class tbl on tbl.oid = rep.resorigtbl
187+
join pg_attribute col on col.attrelid = tbl.oid and col.attnum = rep.resorigcol
188+
join pg_namespace sch on sch.oid = tbl.relnamespace
189+
group by sch.nspname, tbl.relname, rep.view_schema, rep.view_name, pks_fks.conname, pks_fks.contype, pks_fks.ncol
190+
-- make sure we only return key for which all columns are referenced in the view - no partial PKs or FKs
191+
having ncol = array_length(array_agg(row(col.attname, view_columns) order by pks_fks.ord), 1)

0 commit comments

Comments
 (0)