Find foreign key constraints that refer to a base table that has at least one subtable in the inheritance hierarchy. Rows of the subtable do not belong to the supertable in terms of checking the referential integrity. Let us assume that there is a table T with a subtable Tsub. Let us also assume that table B has a foreign key that refers to the table T. If a row is inserted into Tsub, then this row cannot be referenced from B.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Do not use table inheritance to associate T and Tsub.
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,
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, foreign_table_oid, 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, 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, foreign_table_oid, target_schema, target_table,on_update, on_delete)
select conname, foreign_schema, foreign_table, foreign_col, target_schema, target_table, target_col, on_update, on_delete, pc.nspname as foreign_table_subtable_schema, c.relname as foreign_table_subtable_name
from fk_with_names inner join pg_inherits pi on pi.inhparent=fk_with_names.foreign_table_oid
inner join pg_class c on pi.inhrelid=c.oid
inner join pg_namespace pc on c.relnamespace=pc.oid
order by foreign_schema, foreign_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
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.
Table inheritance
Queries of this category provide information about the inheritance between base tables.