|
7 | 7 | #} |
8 | 8 |
|
9 | 9 | {%- call statement('relations', fetch_result=True) -%} |
10 | | - with relation as ( |
11 | | - select |
12 | | - pg_rewrite.ev_class as class, |
13 | | - pg_rewrite.oid as id |
14 | | - from pg_rewrite |
15 | | - ), |
16 | | - class as ( |
17 | | - select |
18 | | - oid as id, |
19 | | - relname as name, |
20 | | - relnamespace as schema, |
21 | | - relkind as kind |
22 | | - from pg_class |
23 | | - ), |
24 | | - dependency as ( |
25 | | - select distinct |
26 | | - pg_depend.objid as id, |
27 | | - pg_depend.refobjid as ref |
28 | | - from pg_depend |
29 | | - ), |
30 | | - schema as ( |
31 | | - select |
32 | | - pg_namespace.oid as id, |
33 | | - pg_namespace.nspname as name |
34 | | - from pg_namespace |
35 | | - where nspname != 'information_schema' and nspname not like 'pg\_%' |
36 | | - ), |
37 | | - referenced as ( |
38 | | - select |
39 | | - relation.id AS id, |
40 | | - referenced_class.name , |
41 | | - referenced_class.schema , |
42 | | - referenced_class.kind |
43 | | - from relation |
44 | | - join class as referenced_class on relation.class=referenced_class.id |
45 | | - where referenced_class.kind in ('r', 'v', 'm') |
46 | | - ), |
47 | | - relationships as ( |
48 | | - select |
49 | | - referenced.name as referenced_name, |
50 | | - referenced.schema as referenced_schema_id, |
51 | | - dependent_class.name as dependent_name, |
52 | | - dependent_class.schema as dependent_schema_id, |
53 | | - referenced.kind as kind |
54 | | - from referenced |
55 | | - join dependency on referenced.id=dependency.id |
56 | | - join class as dependent_class on dependency.ref=dependent_class.id |
57 | | - where |
58 | | - (referenced.name != dependent_class.name or |
59 | | - referenced.schema != dependent_class.schema) |
60 | | - ) |
| 10 | + select distinct |
| 11 | + dependent_namespace.nspname as dependent_schema, |
| 12 | + dependent_class.relname as dependent_name, |
| 13 | + referenced_namespace.nspname as referenced_schema, |
| 14 | + referenced_class.relname as referenced_name |
61 | 15 |
|
62 | | - select |
63 | | - referenced_schema.name as referenced_schema, |
64 | | - relationships.referenced_name as referenced_name, |
65 | | - dependent_schema.name as dependent_schema, |
66 | | - relationships.dependent_name as dependent_name |
67 | | - from relationships |
68 | | - join schema as dependent_schema on relationships.dependent_schema_id=dependent_schema.id |
69 | | - join schema as referenced_schema on relationships.referenced_schema_id=referenced_schema.id |
70 | | - group by referenced_schema, referenced_name, dependent_schema, dependent_name |
71 | | - order by referenced_schema, referenced_name, dependent_schema, dependent_name; |
| 16 | + -- Query for views: views are entries in pg_class with an entry in pg_rewrite, but we avoid |
| 17 | + -- a seq scan on pg_rewrite by leveraging the fact there is an "internal" row in pg_depend for |
| 18 | + -- the view... |
| 19 | + from pg_class as dependent_class |
| 20 | + join pg_namespace as dependent_namespace on dependent_namespace.oid = dependent_class.relnamespace |
| 21 | + join pg_depend as dependent_depend on dependent_depend.refobjid = dependent_class.oid |
| 22 | + and dependent_depend.classid = 'pg_rewrite'::regclass |
| 23 | + and dependent_depend.refclassid = 'pg_class'::regclass |
| 24 | + and dependent_depend.deptype = 'i' |
| 25 | + |
| 26 | + -- ... and via pg_depend (that has a row per column, hence the need for "distinct" above, and |
| 27 | + -- making sure to exclude internal row to avoid a view appearing to depend on itself)... |
| 28 | + join pg_depend as referenced_depend on referenced_depend.objid = dependent_depend.objid |
| 29 | + and referenced_depend.classid = 'pg_rewrite'::regclass |
| 30 | + and referenced_depend.refclassid = 'pg_class'::regclass |
| 31 | + and referenced_depend.refobjid != dependent_depend.refobjid |
| 32 | + |
| 33 | + -- ... we can find the tables they query from in pg_class, but excluding system tables. Note we |
| 34 | + -- don't need need to exclude _dependent_ system tables, because they only query from other |
| 35 | + -- system tables, and so are automatically excluded by excluding _referenced_ system tables |
| 36 | + join pg_class as referenced_class on referenced_class.oid = referenced_depend.refobjid |
| 37 | + join pg_namespace as referenced_namespace on referenced_namespace.oid = referenced_class.relnamespace |
| 38 | + and referenced_namespace.nspname != 'information_schema' |
| 39 | + and referenced_namespace.nspname not like 'pg\_%' |
| 40 | + |
| 41 | + order by |
| 42 | + dependent_schema, dependent_name, referenced_schema, referenced_name; |
72 | 43 |
|
73 | 44 | {%- endcall -%} |
74 | 45 |
|
|
0 commit comments