The list of all the queries

ON UPDATE CASCADE is perhaps missing (based on the compensating actions of other foreign key constraints)

Query goal: Find inconsistencies of using ON UPDATE CASCADE in case of foreign key constraints. An example of inconsistency is that there are two foreign key constraints in different tables that refer to the same table and its candidate key. One of the constraints has ON UPDATE CASCADE compensating action one does not. ON UPDATE CASCADE usage should be consistent, otherwise it does not allow us to change key values in the primary table. More generally, there is a set of foreign key constraints F that refer to a candidate key of table T. It cannot be the case that a proper non-empty subset of these foreign keys have ON UPDATE CASCADE compensatory action. Either all the constraints in F should have it or none of it should have it (depending on circumstances).
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: 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: 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,
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 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,
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 where the query belongs to

Collection nameCollection description
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 where the query belongs to

Category nameCategory description
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).

The list of all the queries