From 3b0f227f8f9f4abb29ae48fca52a4421fe2e4bd6 Mon Sep 17 00:00:00 2001 From: Ivan Vakhrushev Date: Fri, 25 Oct 2024 10:12:46 +0400 Subject: [PATCH] Add check "The type of the foreign key must match the type of column in the target table" (#57) * Add check "The type of the foreign key must match the type of column in the target table" * Update description and readme --- README.md | 1 + sql/duplicated_foreign_keys.sql | 2 +- ...oreign_keys_with_unmatched_column_type.sql | 63 +++++++++++++++++++ sql/foreign_keys_without_index.sql | 2 +- sql/intersected_foreign_keys.sql | 2 +- 5 files changed, 67 insertions(+), 3 deletions(-) create mode 100644 sql/foreign_keys_with_unmatched_column_type.sql diff --git a/README.md b/README.md index 684abf5..a9ab7ae 100644 --- a/README.md +++ b/README.md @@ -47,6 +47,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg 22. Intersected (partially identical) foreign keys ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/intersected_foreign_keys.sql)). 23. Objects with possible name overflow ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/possible_object_name_overflow.sql)). 24. Tables not linked to other tables ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/tables_not_linked_to_others.sql)). +25. Foreign keys [with unmatched column type](https://habr.com/ru/articles/803841/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/foreign_keys_with_unmatched_column_type.sql)). ## Local development diff --git a/sql/duplicated_foreign_keys.sql b/sql/duplicated_foreign_keys.sql index cac329b..890cc16 100644 --- a/sql/duplicated_foreign_keys.sql +++ b/sql/duplicated_foreign_keys.sql @@ -32,7 +32,7 @@ with constraint_name, table_oid, foreign_table_oid, - array_agg(attname::text || ', ' || attnotnull::text order by attposition) as columns + array_agg(attname::text || ',' || attnotnull::text order by attposition) as columns from fk_with_attributes group by constraint_name, table_oid, foreign_table_oid ) diff --git a/sql/foreign_keys_with_unmatched_column_type.sql b/sql/foreign_keys_with_unmatched_column_type.sql new file mode 100644 index 0000000..880fdac --- /dev/null +++ b/sql/foreign_keys_with_unmatched_column_type.sql @@ -0,0 +1,63 @@ +/* + * Copyright (c) 2019-2024. Ivan Vakhrushev and others. + * https://github.com/mfvanek/pg-index-health-sql + * + * Licensed under the Apache License 2.0 + */ + +-- Finds foreign keys where the type of the constrained column does not match the type in the referenced table. +-- +-- The column types in the referring and target relation must match. +-- For example, a column with the integer type should refer to a column with the integer type. +-- This eliminates unnecessary conversions at the DBMS level and in the application code, +-- and reduces the number of errors that may appear due to type inconsistencies in the future. +-- +-- See https://www.postgresql.org/docs/current/catalog-pg-constraint.html +-- Based on query from https://habr.com/ru/articles/803841/ +with + fk_with_attributes as ( + select + c.conname as constraint_name, + c.conrelid as table_oid, + c.confrelid as foreign_table_oid, + u.attposition, + col.attname, + col.attnotnull, + col.atttypid, + col.atttypmod, + foreign_u.attposition as foreign_attposition, + foreign_col.attname as foreign_attname, + foreign_col.attnotnull as foreign_attnotnull, + foreign_col.atttypid as foreign_atttypid, + foreign_col.atttypmod as foreign_atttypmod + from + pg_catalog.pg_constraint c + inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace + inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true + inner join lateral unnest(c.confkey) with ordinality foreign_u(attnum, attposition) on foreign_u.attposition = u.attposition + inner join pg_catalog.pg_attribute col on col.attrelid = c.conrelid and col.attnum = u.attnum + inner join pg_catalog.pg_attribute foreign_col on foreign_col.attrelid = c.confrelid and foreign_col.attnum = foreign_u.attnum + where + c.contype = 'f' and + nsp.nspname = :schema_name_param::text + ), + + fk_with_attributes_grouped as ( + select + constraint_name, + table_oid, + foreign_table_oid, + array_agg(attname::text || ',' || attnotnull::text order by attposition) as columns + from fk_with_attributes + where + (atttypid != foreign_atttypid) or (atttypmod != foreign_atttypmod) + group by constraint_name, table_oid, foreign_table_oid + ) + +select + table_oid::regclass::text as table_name, + constraint_name, + columns +from + fk_with_attributes_grouped +order by table_name, constraint_name; diff --git a/sql/foreign_keys_without_index.sql b/sql/foreign_keys_without_index.sql index a95ae32..c5cf659 100644 --- a/sql/foreign_keys_without_index.sql +++ b/sql/foreign_keys_without_index.sql @@ -10,7 +10,7 @@ select c.conrelid::regclass::text as table_name, c.conname as constraint_name, - array_agg(col.attname::text || ', ' || col.attnotnull::text order by u.attposition) as columns + array_agg(col.attname::text || ',' || col.attnotnull::text order by u.attposition) as columns from pg_catalog.pg_constraint c inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true diff --git a/sql/intersected_foreign_keys.sql b/sql/intersected_foreign_keys.sql index 93017a7..1c7183f 100644 --- a/sql/intersected_foreign_keys.sql +++ b/sql/intersected_foreign_keys.sql @@ -32,7 +32,7 @@ with constraint_name, table_oid, foreign_table_oid, - array_agg(attname::text || ', ' || attnotnull::text order by attposition) as columns + array_agg(attname::text || ',' || attnotnull::text order by attposition) as columns from fk_with_attributes group by constraint_name, table_oid, foreign_table_oid )