The list of all the queries

Composite foreign keys with an incorrect order of columns (ver 2)

Query goal: Find composite foreign keys where the order of columns does not correspond to the order of columns in the referenced candidate key. Find composite foreign keys in case of which the foreign key and candidate key are not the same in terms of data types of the columns. For instance, the query returns information about a foreign key that columns have the types (SMALLINT, INTEGER) that refers to the candidate key that columns have the types (INTEGER, SMALLINT). In SQL keys are ordered sets of columns. Thus, in case of composite foreign key declarations one has to pay attention that the order of columns in the FOREIGN KEY clause matches the order of columns in the REFERENCES clause.
Notes about the query: The query depends on data types of columns. If the key columns have the same type, then it may cause false negative result. For instance, FOREIGN KEY (person_id INTEGER, car_id INTEGER) REFERENCES (car_id INTEGER, person_id integer) will not be detected.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Medium (Medium number of false-positive results)
Query license: MIT License
Fixing suggestion: Drop the foreign key constraint and recreate with the correct column order.
Data source: system catalog only
SQL query: Click on query to copy it

with fk as (select 
o.conname,
(select nspname from pg_namespace where oid=f.relnamespace) as foreign_schema,
f.relname as foreign_table,
f.oid as foreign_table_oid,
o.confkey AS foreign_col,
(select nspname from pg_namespace where oid=c.relnamespace) as target_schema,
c.relname as target_table, 
c.oid as target_table_oid,
o.conkey AS target_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_class f on f.oid = o.confrelid 
where o.contype = 'f' and cardinality(o.conkey)>1),
fk_unnest as (select conname, foreign_schema, foreign_table,  foreign_table_oid, foreign_col, foreign_col_num, target_schema, target_table, target_table_oid, target_col, target_col_num, ordin
from fk, unnest(fk.foreign_col, fk. target_col) with ordinality as f(foreign_col_num, target_col_num, ordin)),

fk_with_names as (select conname, foreign_schema, foreign_table, 
array_agg(a_foreign.attname order by ordin) as foreign_col_name, 
array_agg(case when a_foreign.atttypmod=-1 then t_foreign.typname else t_foreign.typname || '(' || a_foreign.atttypmod || ')' end order by ordin) as foreign_col_types, 
array_agg(a_target.attname order by ordin) as target_col_name,
target_schema, target_table, array_agg(case when a_target.atttypmod=-1 then t_target.typname else t_target.typname || '(' || a_target.atttypmod || ')' end  order by ordin) as target_col_types
from fk_unnest fk inner join pg_attribute a_foreign on fk.foreign_col_num = a_foreign.attnum and fk.foreign_table_oid = a_foreign.attrelid and a_foreign.attisdropped = false
inner join pg_attribute a_target on fk.target_col_num = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false
inner join pg_type AS t_foreign on a_foreign.atttypid=t_foreign.oid
inner join pg_type AS t_target on a_target.atttypid=t_target.oid
group by conname, foreign_schema, foreign_table, target_schema, target_table)
select conname, foreign_schema, foreign_table,  foreign_col_name, foreign_col_types, target_schema, target_table, target_col_name, target_col_types
from fk_with_names
where foreign_col_types<>target_col_types
order by target_schema, target_table, conname;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
with fk as (select 
o.conname,
(select nspname from pg_namespace where oid=f.relnamespace) as foreign_schema,
f.relname as foreign_table,
f.oid as foreign_table_oid,
o.confkey AS foreign_col,
(select nspname from pg_namespace where oid=c.relnamespace) as target_schema,
c.relname as target_table, 
c.oid as target_table_oid,
o.conkey AS target_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_class f on f.oid = o.confrelid 
where o.contype = 'f' and cardinality(o.conkey)>1),
fk_unnest as (select conname, foreign_schema, foreign_table,  foreign_table_oid, foreign_col, foreign_col_num, target_schema, target_table, target_table_oid, target_col, target_col_num, ordin
from fk, unnest(fk.foreign_col, fk. target_col) with ordinality as f(foreign_col_num, target_col_num, ordin)),

fk_with_names as (select conname, foreign_schema, foreign_table, 
array_agg(case when a_foreign.atttypmod=-1 then t_foreign.typname else t_foreign.typname || '(' || a_foreign.atttypmod || ')' end order by ordin) as foreign_col_types, 
target_schema, target_table, array_agg(case when a_target.atttypmod=-1 then t_target.typname else t_target.typname || '(' || a_target.atttypmod || ')' end  order by ordin) as target_col_types
from fk_unnest fk inner join pg_attribute a_foreign on fk.foreign_col_num = a_foreign.attnum and fk.foreign_table_oid = a_foreign.attrelid and a_foreign.attisdropped = false
inner join pg_attribute a_target on fk.target_col_num = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false
inner join pg_type AS t_foreign on a_foreign.atttypid=t_foreign.oid
inner join pg_type AS t_target on a_target.atttypid=t_target.oid
group by conname, foreign_schema, foreign_table, target_schema, target_table)
SELECT format('ALTER TABLE %1$I.%2$I DROP CONSTRAIN %3$I;', target_schema, target_table, conname) AS statements
from fk_with_names
where foreign_col_types<>target_col_types
order by target_schema, target_table, conname;
Drop the foreign key constraint.

Collections where the query belongs to

Collection nameCollection description
Find problems automaticallyQueries, that results point to problems in the database. Each query in the collection produces an initial assessment. However, a human reviewer has the final say as to whether there is a problem or not .

Categories where the query belongs to

Category nameCategory description
Data typesQueries of this category provide information about the data types and their usage.
Relationships between tablesQueries of this category provide information about how database tables are connected to each other and whether such connections have been explicitly defined and whether it has been done correctly.

The list of all the queries