From 6e9737f96a5a6630023eb2d2cb0c4f20d057d45c Mon Sep 17 00:00:00 2001 From: BLoHny <113517233+BLoHny@users.noreply.github.com> Date: Thu, 5 Sep 2024 11:18:33 +0900 Subject: [PATCH 1/3] add check duplicated foreign key --- sql/check_duplicated_foreign_keys.sql | 55 +++++++++++++++++++++++++++ 1 file changed, 55 insertions(+) create mode 100644 sql/check_duplicated_foreign_keys.sql diff --git a/sql/check_duplicated_foreign_keys.sql b/sql/check_duplicated_foreign_keys.sql new file mode 100644 index 0000000..dca8653 --- /dev/null +++ b/sql/check_duplicated_foreign_keys.sql @@ -0,0 +1,55 @@ +/* + * Copyright (c) 2019-2024. Ivan Vakhrushev and others. + * https://github.com/mfvanek/pg-index-health-sql + * + * Licensed under the Apache License 2.0 + */ + +with +-- combine fk constraints with the attributes involved in them +fk_with_attributes as ( + select + c.conname as fk_name, + c.conrelid, + c.confrelid, + fk_conkey.conkey_order as att_order, + fk_conkey.conkey_number, + fk_confkey.confkey_number, + rel_att.attname as rel_att_name, + rel_att.atttypid as rel_att_type_id, + rel_att.atttypmod as rel_att_type_mod, + rel_att.attnotnull as rel_att_notnull, + frel_att.attname as frel_att_name, + frel_att.atttypid as frel_att_type_id, + frel_att.atttypmod as rel_att_type_mod, + frel_att.attnotnull as rel_att_notnull + from pg_catalog.pg_constraint as c + cross join lateral unnest(c.conkey) with ordinality as fk_conkey(conkey_number, conkey_order) + left join lateral unnest(c.confkey) with ordinality as fk_confkey(confkey_number, confkey_order) + on fk_conkey.conkey_order = fk_confkey.confkey_order + left join pg_catalog.pg_attribute as rel_att + on rel_att.attrelid = c.conrelid and rel_att.attnum = fk_conkey.conkey_number + left join pg_catalog.pg_attribute as frel_att + on frel_att.attrelid = c.confrelid and frel_att.attnum = fk_confkey.confkey_number + where c.contype in ('f') + ), + -- + fk_with_attributes_grouped as ( + select + fk_name, + conrelid, + confrelid, + array_agg (rel_att_name order by att_order) as rel_att_names, + array_agg (frel_att_name order by att_order) as frel_att_names + from fk_with_attributes + group by 1, 2, 3 + ) +select + r_from.relname, -- referencing relation + c1.fk_name, -- name of the fk constraint + c2.fk_name -- name of the fk constraint (potential duplicate) +from fk_with_attributes_grouped as c1 + inner join fk_with_attributes_grouped as c2 on c1.fk_name < c2.fk_name + and c1.conrelid = c2.conrelid and c1.confrelid = c2.confrelid + and c1.rel_att_names = c2.rel_att_names + inner join pg_catalog.pg_class as r_from on r_from.oid = c1.conrelid; From 1bbb2ff08bdaa04feb2e0fa795895ae6faee9cad Mon Sep 17 00:00:00 2001 From: BLoHny <113517233+BLoHny@users.noreply.github.com> Date: Sat, 7 Sep 2024 13:14:18 +0900 Subject: [PATCH 2/3] ignore lint check and add 'as' state --- sql/check_duplicated_foreign_keys.sql | 34 ++++++++++++++++----------- 1 file changed, 20 insertions(+), 14 deletions(-) diff --git a/sql/check_duplicated_foreign_keys.sql b/sql/check_duplicated_foreign_keys.sql index dca8653..ae276f0 100644 --- a/sql/check_duplicated_foreign_keys.sql +++ b/sql/check_duplicated_foreign_keys.sql @@ -5,9 +5,10 @@ * Licensed under the Apache License 2.0 */ +-- noqa: disable=PRS with --- combine fk constraints with the attributes involved in them -fk_with_attributes as ( + -- combine fk constraints with the attributes involved in them + fk_with_attributes as ( select c.conname as fk_name, c.conrelid, @@ -21,16 +22,18 @@ fk_with_attributes as ( rel_att.attnotnull as rel_att_notnull, frel_att.attname as frel_att_name, frel_att.atttypid as frel_att_type_id, - frel_att.atttypmod as rel_att_type_mod, - frel_att.attnotnull as rel_att_notnull + frel_att.atttypmod as frel_att_type_mod, + frel_att.attnotnull as frel_att_notnull from pg_catalog.pg_constraint as c cross join lateral unnest(c.conkey) with ordinality as fk_conkey(conkey_number, conkey_order) left join lateral unnest(c.confkey) with ordinality as fk_confkey(confkey_number, confkey_order) on fk_conkey.conkey_order = fk_confkey.confkey_order left join pg_catalog.pg_attribute as rel_att - on rel_att.attrelid = c.conrelid and rel_att.attnum = fk_conkey.conkey_number + on rel_att.attrelid = c.conrelid + and rel_att.attnum = fk_conkey.conkey_number left join pg_catalog.pg_attribute as frel_att - on frel_att.attrelid = c.confrelid and frel_att.attnum = fk_confkey.confkey_number + on frel_att.attrelid = c.confrelid + and frel_att.attnum = fk_confkey.confkey_number where c.contype in ('f') ), -- @@ -39,17 +42,20 @@ fk_with_attributes as ( fk_name, conrelid, confrelid, - array_agg (rel_att_name order by att_order) as rel_att_names, - array_agg (frel_att_name order by att_order) as frel_att_names + array_agg(rel_att_name order by att_order) as rel_att_names, + array_agg(frel_att_name order by att_order) as frel_att_names from fk_with_attributes group by 1, 2, 3 ) select - r_from.relname, -- referencing relation - c1.fk_name, -- name of the fk constraint - c2.fk_name -- name of the fk constraint (potential duplicate) + r_from.relname as table_name, -- referencing relation (renamed to table_name) + c1.fk_name as constraint_name, -- name of the fk constraint (renamed to constraint_name) + c2.fk_name as duplicate_constraint_name -- potential duplicate constraint name (renamed to duplicate_constraint_name) from fk_with_attributes_grouped as c1 - inner join fk_with_attributes_grouped as c2 on c1.fk_name < c2.fk_name - and c1.conrelid = c2.conrelid and c1.confrelid = c2.confrelid + inner join fk_with_attributes_grouped as c2 + on c1.fk_name < c2.fk_name + and c1.conrelid = c2.conrelid + and c1.confrelid = c2.confrelid and c1.rel_att_names = c2.rel_att_names - inner join pg_catalog.pg_class as r_from on r_from.oid = c1.conrelid; + inner join pg_catalog.pg_class as r_from + on r_from.oid = c1.conrelid; From 988cf7aa98cff42b601a88693f2265e208f05251 Mon Sep 17 00:00:00 2001 From: BLoHny <113517233+BLoHny@users.noreply.github.com> Date: Thu, 19 Sep 2024 10:01:44 +0900 Subject: [PATCH 3/3] fix lint error --- sql/check_duplicated_foreign_keys.sql | 109 ++++++++++++++------------ 1 file changed, 60 insertions(+), 49 deletions(-) diff --git a/sql/check_duplicated_foreign_keys.sql b/sql/check_duplicated_foreign_keys.sql index ae276f0..0af1b6f 100644 --- a/sql/check_duplicated_foreign_keys.sql +++ b/sql/check_duplicated_foreign_keys.sql @@ -5,57 +5,68 @@ * Licensed under the Apache License 2.0 */ --- noqa: disable=PRS + -- noqa: disable=PRS with - -- combine fk constraints with the attributes involved in them - fk_with_attributes as ( - select - c.conname as fk_name, - c.conrelid, - c.confrelid, - fk_conkey.conkey_order as att_order, - fk_conkey.conkey_number, - fk_confkey.confkey_number, - rel_att.attname as rel_att_name, - rel_att.atttypid as rel_att_type_id, - rel_att.atttypmod as rel_att_type_mod, - rel_att.attnotnull as rel_att_notnull, - frel_att.attname as frel_att_name, - frel_att.atttypid as frel_att_type_id, - frel_att.atttypmod as frel_att_type_mod, - frel_att.attnotnull as frel_att_notnull - from pg_catalog.pg_constraint as c - cross join lateral unnest(c.conkey) with ordinality as fk_conkey(conkey_number, conkey_order) - left join lateral unnest(c.confkey) with ordinality as fk_confkey(confkey_number, confkey_order) - on fk_conkey.conkey_order = fk_confkey.confkey_order - left join pg_catalog.pg_attribute as rel_att - on rel_att.attrelid = c.conrelid - and rel_att.attnum = fk_conkey.conkey_number - left join pg_catalog.pg_attribute as frel_att - on frel_att.attrelid = c.confrelid - and frel_att.attnum = fk_confkey.confkey_number - where c.contype in ('f') - ), - -- - fk_with_attributes_grouped as ( - select - fk_name, - conrelid, - confrelid, - array_agg(rel_att_name order by att_order) as rel_att_names, - array_agg(frel_att_name order by att_order) as frel_att_names - from fk_with_attributes - group by 1, 2, 3 - ) +fk_with_attributes as ( + select + c.conname as fk_name, + c.conrelid, + c.confrelid, + fk_conkey.conkey_order as att_order, + fk_conkey.conkey_number, + fk_confkey.confkey_number, + rel_att.attname as rel_att_name, + rel_att.atttypid as rel_att_type_id_1, + rel_att.atttypmod as rel_att_type_mod_1, + rel_att.attnotnull as rel_att_notnull_1, + frel_att.attname as frel_att_name, + frel_att.atttypid as frel_att_type_id_2, + frel_att.atttypmod as frel_att_type_mod_2, + frel_att.attnotnull as frel_att_notnull_2 + from pg_catalog.pg_constraint as c + cross join + lateral unnest(c.conkey) + with ordinality as fk_conkey(conkey_number, conkey_order) + left join + lateral unnest(c.confkey) + with ordinality as fk_confkey(confkey_number, confkey_order) + on fk_conkey.conkey_order = fk_confkey.confkey_order + left join pg_catalog.pg_attribute as rel_att + on + rel_att.attrelid = c.conrelid + and rel_att.attnum = fk_conkey.conkey_number + left join pg_catalog.pg_attribute as frel_att + on + frel_att.attrelid = c.confrelid + and frel_att.attnum = fk_confkey.confkey_number + where c.contype = 'f' +), + +-- +fk_with_attributes_grouped as ( + select + fk_name, + conrelid, + confrelid, + array_agg(rel_att_name order by att_order) as rel_att_names, + array_agg(frel_att_name order by att_order) as frel_att_names + from fk_with_attributes + group by fk_name, conrelid, confrelid +) + select - r_from.relname as table_name, -- referencing relation (renamed to table_name) - c1.fk_name as constraint_name, -- name of the fk constraint (renamed to constraint_name) - c2.fk_name as duplicate_constraint_name -- potential duplicate constraint name (renamed to duplicate_constraint_name) -from fk_with_attributes_grouped as c1 - inner join fk_with_attributes_grouped as c2 - on c1.fk_name < c2.fk_name + r_from.relname as table_name, + c1.fk_name as constraint_name, + c2.fk_name as duplicate_constraint_name +from pg_catalog.pg_class as r_from +inner join pg_catalog.pg_namespace as nsp + on r_from.relnamespace = nsp.oid +inner join fk_with_attributes_grouped as c1 + on r_from.oid = c1.conrelid +inner join fk_with_attributes_grouped as c2 + on + c1.fk_name < c2.fk_name and c1.conrelid = c2.conrelid and c1.confrelid = c2.confrelid and c1.rel_att_names = c2.rel_att_names - inner join pg_catalog.pg_class as r_from - on r_from.oid = c1.conrelid; +where nsp.nspname = :schema_name_param::text;