Skip to content

Commit

Permalink
Add check "The type of the foreign key must match the type of column …
Browse files Browse the repository at this point in the history
…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
  • Loading branch information
mfvanek authored Oct 25, 2024
1 parent f42bf86 commit 3b0f227
Show file tree
Hide file tree
Showing 5 changed files with 67 additions and 3 deletions.
1 change: 1 addition & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -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

Expand Down
2 changes: 1 addition & 1 deletion sql/duplicated_foreign_keys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
)
Expand Down
63 changes: 63 additions & 0 deletions sql/foreign_keys_with_unmatched_column_type.sql
Original file line number Diff line number Diff line change
@@ -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;
2 changes: 1 addition & 1 deletion sql/foreign_keys_without_index.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
2 changes: 1 addition & 1 deletion sql/intersected_foreign_keys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
)
Expand Down

0 comments on commit 3b0f227

Please sign in to comment.