Skip to content

Commit 711c857

Browse files
committed
chore: simplify relationships.sql
1 parent ca7a140 commit 711c857

File tree

1 file changed

+23
-42
lines changed

1 file changed

+23
-42
lines changed

src/lib/sql/relationships.sql

Lines changed: 23 additions & 42 deletions
Original file line numberDiff line numberDiff line change
@@ -1,44 +1,25 @@
11
-- Adapted from
22
-- https://github.com/PostgREST/postgrest/blob/f9f0f79fa914ac00c11fbf7f4c558e14821e67e2/src/PostgREST/SchemaCache.hs#L722
3-
WITH
4-
pks_uniques_cols AS (
5-
SELECT
6-
connamespace,
7-
conrelid,
8-
jsonb_agg(column_info.cols) as cols
9-
FROM pg_constraint
10-
JOIN lateral (
11-
SELECT array_agg(cols.attname order by cols.attnum) as cols
12-
FROM ( select unnest(conkey) as col) _
13-
JOIN pg_attribute cols on cols.attrelid = conrelid and cols.attnum = col
14-
) column_info ON TRUE
15-
WHERE
16-
contype IN ('p', 'u') and
17-
connamespace::regnamespace::text <> 'pg_catalog'
18-
GROUP BY connamespace, conrelid
19-
)
20-
SELECT
21-
traint.oid AS id,
22-
traint.conname AS foreign_key_name,
23-
ns1.nspname AS schema,
24-
tab.relname AS relation,
25-
column_info.cols AS columns,
26-
ns2.nspname AS referenced_schema,
27-
other.relname AS referenced_relation,
28-
column_info.refs AS referenced_columns
29-
FROM pg_constraint traint
30-
JOIN LATERAL (
31-
SELECT
32-
array_agg(row(cols.attname, refs.attname) order by ord) AS cols_and_fcols,
33-
jsonb_agg(cols.attname order by ord) AS cols,
34-
jsonb_agg(refs.attname order by ord) AS refs
35-
FROM unnest(traint.conkey, traint.confkey) WITH ORDINALITY AS _(col, ref, ord)
36-
JOIN pg_attribute cols ON cols.attrelid = traint.conrelid AND cols.attnum = col
37-
JOIN pg_attribute refs ON refs.attrelid = traint.confrelid AND refs.attnum = ref
38-
) AS column_info ON TRUE
39-
JOIN pg_namespace ns1 ON ns1.oid = traint.connamespace
40-
JOIN pg_class tab ON tab.oid = traint.conrelid
41-
JOIN pg_class other ON other.oid = traint.confrelid
42-
JOIN pg_namespace ns2 ON ns2.oid = other.relnamespace
43-
LEFT JOIN pks_uniques_cols pks_uqs ON pks_uqs.connamespace = traint.connamespace AND pks_uqs.conrelid = traint.conrelid
44-
WHERE traint.contype = 'f'
3+
SELECT
4+
traint.oid AS id,
5+
traint.conname AS foreign_key_name,
6+
ns1.nspname AS schema,
7+
tab.relname AS relation,
8+
column_info.cols AS columns,
9+
ns2.nspname AS referenced_schema,
10+
other.relname AS referenced_relation,
11+
column_info.refs AS referenced_columns
12+
FROM pg_constraint traint
13+
JOIN LATERAL (
14+
SELECT
15+
jsonb_agg(cols.attname order by ord) AS cols,
16+
jsonb_agg(refs.attname order by ord) AS refs
17+
FROM unnest(traint.conkey, traint.confkey) WITH ORDINALITY AS _(col, ref, ord)
18+
JOIN pg_attribute cols ON cols.attrelid = traint.conrelid AND cols.attnum = col
19+
JOIN pg_attribute refs ON refs.attrelid = traint.confrelid AND refs.attnum = ref
20+
) AS column_info ON TRUE
21+
JOIN pg_namespace ns1 ON ns1.oid = traint.connamespace
22+
JOIN pg_class tab ON tab.oid = traint.conrelid
23+
JOIN pg_class other ON other.oid = traint.confrelid
24+
JOIN pg_namespace ns2 ON ns2.oid = other.relnamespace
25+
WHERE traint.contype = 'f'

0 commit comments

Comments
 (0)