|
| 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