Find as to whether in case of foreign key constraints both the compensating actions RESTRICT and NO ACTION are used within the same database. If the same thing has to do in different places, then try to do it in the same way.
Type
Problem detection (Each row in the result could represent a flaw in the design)
If your intent is not to allow deferrable foreign key constraints in one place and prohibit in another places, then use consistently either NO ACTION or RESTRICT setting. Drop the foreign key constraints in question and recreate with an appropriate compensating action setting.
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,
o.confdeltype
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.confupdtype in ('a','r')) or (o.confdeltype in ('a','r')))),
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, confdeltype
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, confdeltype
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,confdeltype)
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' end as update_compensatory_action,
case when confdeltype='a' then 'ON DELETE NO ACTION' when confdeltype='r' then 'ON DELETE RESTRICT' end as delete_compensatory_action
from fk_with_names fk
where exists (select 1 from fk_with_names fk where confupdtype='a' or confdeltype='a') and exists (select 1 from fk_with_names fk where confupdtype='r' or confdeltype='r')
order by target_schema, target_table, conname;
Collections
This query belongs to the following collections:
Name
Description
Find problems automatically
Queries, 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:
Name
Description
Inconsistencies
Queries of this catergory provide information about inconsistencies of solving the same problem in different places.
Relationships between tables
Queries 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.
Further reading and related materials:
Reference
The corresponding code smell in case of cleaning code is "G11: Inconsistency". (Robert C. Martin, Clean Code)