Goal This query detects inconsistencies in the application of ON UPDATE CASCADE for foreign keys referencing the same candidate key. It identifies sets of foreign key constraints where a proper, non-empty subset is configured with ON UPDATE CASCADE. Such a mixed configuration is a functional flaw, as any attempt to update the parent key will be blocked by the non-cascading constraints, rendering the CASCADE action ineffective and preventing the intended data modification. The principle of atomicity requires that for any given key, either all referencing foreign keys have ON UPDATE CASCADE, or none do.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion Find out as to whether the referenced candidate keys is a natural key. In this case ON UPDATE CASCADE is needed. If it is the case, then drop the foreign keys without ON UPDATE CASCADE and recreate these with the compensating action.
Data Source system catalog only
SQL Query
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,
o.confupdtype
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'),
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, confupdtype
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, target_schema, target_table, array_agg(a_target.attname order by ordin) as target_col, confupdtype
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
group by conname, foreign_schema, foreign_table, target_schema, target_table, confupdtype)
select conname, foreign_schema, foreign_table, foreign_col, target_schema, target_table, target_col,  
case when confupdtype='a' then 'ON UPDATE NO ACTION' when confupdtype='r' then 'ON UPDATE RESTRICT' when confupdtype='n' then 'ON UPDATE SET NULL'  when confupdtype='d' then 'ON UPDATE SET DEFAULT' end as compensatory_action
from fk_with_names fk
where confupdtype<>'c' and exists (select 1 from fk_with_names as fwn where fk.foreign_schema=fwn.foreign_schema and fk.foreign_table=fwn.foreign_table and fk.foreign_col=fwn.foreign_col and fwn.confupdtype='c')
order by target_schema, target_table, conname;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
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,
o.confupdtype
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'),
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, confupdtype
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, target_schema, target_table, array_agg(a_target.attname order by ordin) as target_col, confupdtype
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
group by conname, foreign_schema, foreign_table, target_schema, target_table, confupdtype)
SELECT format('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', target_schema, target_table, conname) AS statements
from fk_with_names fk
where confupdtype<>'c' and exists (select 1 from fk_with_names as fwn where fk.foreign_schema=fwn.foreign_schema and fk.foreign_table=fwn.foreign_table and fk.foreign_col=fwn.foreign_col and fwn.confupdtype='c')
order by target_schema, target_table, conname;
Drop the foreign key.
Collections

This query belongs to the following collections:

NameDescription
Find problems about integrity constraintsA selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview
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

This query is classified under the following categories:

NameDescription
Comfortability of data managementQueries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient.
Compensating actionsQueries of this category provide information about compensating actions of foreign key constraints.
InconsistenciesQueries of this catergory provide information about inconsistencies of solving the same problem in different places.
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.
Validity and completenessQueries of this category provide information about whether database design represents the world (domain) correctly (validity) and whether database design captures all the information about the world (domain) that is correct and relevant (completeness).