The list of all the queries

ON DELETE CASCADE is probably missing (based on the multiplicity of the relationship)

Query goal: Find foreign key constraints that completely overlap with a candidate key constraint (primary key or unique constraint) but the foreign key constraint does not have the ON DELETE CASCADE compensating action. In this case there is a foreign key that implements a relationship type between a strong entity type and a weak entity type (1-1 relationship type). Therefore, in this case ON DELETE CASCADE is an appropriate compensating action.
Notes about the query: In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser.
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 ON DELETE CASCADE compensating action.
Data source: system catalog only
SQL query: Click on query to copy it

with keys as (select 
o.conname,
(select nspname from pg_namespace where oid=c.relnamespace) as key_schema,
c.relname as key_table, 
c.oid as key_table_oid,
o.conkey AS key_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype in ('u', 'p')),
keys_unnest as (select conname, key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
from keys, unnest(keys.key_col) with ordinality as k(key_col_num, ordin)),
keys_with_names AS (select key_schema, key_table, array_agg(a_key.attname order by ordin) as key_col
from keys_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false
group by conname, key_schema, key_table
),
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,
CASE WHEN o.confupdtype='a' THEN 'NO ACTION'
WHEN o.confupdtype='r' THEN 'RESTRICT'
WHEN o.confupdtype='c' THEN 'CASCADE'
WHEN o.confupdtype='n' THEN 'SET NULL'
WHEN o.confupdtype='d' THEN 'SET DEFAULT' END AS on_update,
CASE WHEN o.confdeltype='a' THEN 'NO ACTION'
WHEN o.confdeltype='r' THEN 'RESTRICT'
WHEN o.confdeltype='c' THEN 'CASCADE'
WHEN o.confdeltype='n' THEN 'SET NULL'
WHEN o.confdeltype='d' THEN 'SET DEFAULT' END AS on_delete
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, on_update, on_delete
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 foreign_col_num) as foreign_col, target_schema, target_table, array_agg(a_target.attname order by  target_col_num) as target_col,on_update, on_delete
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,on_update, on_delete, target_col)

SELECT f.* 
FROM fk_with_names AS f, keys_with_names AS k
WHERE f.target_schema=k.key_schema
AND f.target_table=k.key_table
AND f.target_col = k.key_col
AND f.on_delete<>'CASCADE'
ORDER BY target_table, target_schema, target_col, foreign_schema, foreign_table, foreign_col;

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=c.relnamespace) AS target_schema,
c.relname AS target_table, 
c.oid AS target_table_oid,
o.conkey
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 o.confdeltype<>'c'),
ck AS (SELECT 
o.conname,
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS target_schema,
c.relname AS target_table, 
o.conkey
FROM pg_constraint o INNER JOIN pg_class c on c.oid = o.conrelid
WHERE o.contype in ('p','u')),
one_to_one AS (SELECT fk.conname, fk.target_schema, fk.target_table, unnest(fk.conkey) AS target_column, fk.target_table_oid
FROM fk,ck
WHERE fk.target_schema=ck.target_schema AND fk.target_table=ck.target_table AND fk.conkey <@ ck.conkey AND fk.conkey @> ck.conkey)
SELECT format('ALTER TABLE %1$I.%2$I DROP CONSTRAIN %3$I;', target_schema, target_table, conname) AS statements
FROM one_to_one o INNER JOIN pg_attribute a on o.target_column = a.attnum and o.target_table_oid = a.attrelid
GROUP BY conname, target_schema, target_table
ORDER BY target_schema, target_table, conname;
Drop the foreign key constraint.

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.
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