|
| 1 | +/* |
| 2 | + * Copyright (c) 2019-2024. Ivan Vakhrushev and others. |
| 3 | + * https://github.com/mfvanek/pg-index-health-sql |
| 4 | + * |
| 5 | + * Licensed under the Apache License 2.0 |
| 6 | + */ |
| 7 | + |
| 8 | +with |
| 9 | +-- combine fk constraints with the attributes involved in them |
| 10 | +fk_with_attributes as ( |
| 11 | + select |
| 12 | + c.conname as fk_name, |
| 13 | + c.conrelid, |
| 14 | + c.confrelid, |
| 15 | + fk_conkey.conkey_order as att_order, |
| 16 | + fk_conkey.conkey_number, |
| 17 | + fk_confkey.confkey_number, |
| 18 | + rel_att.attname as rel_att_name, |
| 19 | + rel_att.atttypid as rel_att_type_id, |
| 20 | + rel_att.atttypmod as rel_att_type_mod, |
| 21 | + rel_att.attnotnull as rel_att_notnull, |
| 22 | + frel_att.attname as frel_att_name, |
| 23 | + frel_att.atttypid as frel_att_type_id, |
| 24 | + frel_att.atttypmod as rel_att_type_mod, |
| 25 | + frel_att.attnotnull as rel_att_notnull |
| 26 | + from pg_catalog.pg_constraint as c |
| 27 | + cross join lateral unnest(c.conkey) with ordinality as fk_conkey(conkey_number, conkey_order) |
| 28 | + left join lateral unnest(c.confkey) with ordinality as fk_confkey(confkey_number, confkey_order) |
| 29 | + on fk_conkey.conkey_order = fk_confkey.confkey_order |
| 30 | + left join pg_catalog.pg_attribute as rel_att |
| 31 | + on rel_att.attrelid = c.conrelid and rel_att.attnum = fk_conkey.conkey_number |
| 32 | + left join pg_catalog.pg_attribute as frel_att |
| 33 | + on frel_att.attrelid = c.confrelid and frel_att.attnum = fk_confkey.confkey_number |
| 34 | + where c.contype in ('f') |
| 35 | + ), |
| 36 | + -- |
| 37 | + fk_with_attributes_grouped as ( |
| 38 | + select |
| 39 | + fk_name, |
| 40 | + conrelid, |
| 41 | + confrelid, |
| 42 | + array_agg (rel_att_name order by att_order) as rel_att_names, |
| 43 | + array_agg (frel_att_name order by att_order) as frel_att_names |
| 44 | + from fk_with_attributes |
| 45 | + group by 1, 2, 3 |
| 46 | + ) |
| 47 | +select |
| 48 | + r_from.relname, -- referencing relation |
| 49 | + c1.fk_name, -- name of the fk constraint |
| 50 | + c2.fk_name -- name of the fk constraint (potential duplicate) |
| 51 | +from fk_with_attributes_grouped as c1 |
| 52 | + inner join fk_with_attributes_grouped as c2 on c1.fk_name < c2.fk_name |
| 53 | + and c1.conrelid = c2.conrelid and c1.confrelid = c2.confrelid |
| 54 | + and c1.rel_att_names = c2.rel_att_names |
| 55 | + inner join pg_catalog.pg_class as r_from on r_from.oid = c1.conrelid; |
0 commit comments