The list of all the queries

Constraints that are not redefined in a subtable

Query goal: Find primary key, unique, foreign key, and exclude constraints that have been defined in a supertable (parent table) but not in its subtable. Unfortunately, PostgreSQL table inheritance is implemented in a manner that some constraints (CHECK, NOT NULL) are inherited from the supertable but others are not. "All check constraints and not-null constraints on a parent table are automatically inherited by its children, unless explicitly specified otherwise with NO INHERIT clauses. Other types of constraints (unique, primary key, and foreign key constraints) are not inherited." (PostgreSQL documentation)
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: Define constraints in subtables.
Data source: system catalog only
SQL query: Click on query to copy it

with constr as (select
o.conname as constraint_name,
(select nspname from pg_namespace where oid=c.relnamespace) as supertable_schema,
c.relname as supertable,
c.oid as supertable_oid,
o.conkey AS constraint_col,
CASE WHEN o.contype='p' THEN 'PRIMARY KEY'
WHEN o.contype='u' THEN 'UNIQUE'
WHEN o.contype='f' THEN 'FOREIGN KEY'
WHEN o.contype='x' THEN 'EXCLUDE' END AS constraint_type
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype in ('f','p','u', 'x')),
constr_unnest as (select constraint_name, constraint_type, supertable_schema, supertable, supertable_oid, constraint_col, constraint_col_num, ordin
from constr, unnest(constr.constraint_col) with ordinality as f(constraint_col_num, ordin)),
constr_with_names as (select constraint_name, constraint_type, supertable_schema, supertable, supertable_oid, array_agg(a_target.attname order by ordin) as constraint_col 
from constr_unnest constr inner join pg_attribute a_target on constr.constraint_col_num = a_target.attnum and constr.supertable_oid = a_target.attrelid and a_target.attisdropped = false
group by constraint_name, constraint_type, supertable_schema, supertable, supertable_oid),
supertable_constraints as (select constraint_name, constraint_type, supertable_schema, supertable, constraint_col, pc.nspname as subtable_schema, c.relname as subtable_name
from constr_with_names inner join pg_inherits pi on pi.inhparent=constr_with_names.supertable_oid
inner join pg_class c on pi.inhrelid=c.oid
inner join pg_namespace pc on c.relnamespace=pc.oid)
SELECT constraint_name, constraint_type, supertable_schema, supertable, constraint_col, subtable_schema, subtable_name
FROM supertable_constraints as sc
WHERE NOT EXISTS (SELECT 1
FROM constr_with_names AS cn
WHERE sc.subtable_schema=cn.supertable_schema 
AND sc.subtable_name=cn.supertable
AND sc.constraint_type=cn.constraint_type
AND sc.constraint_col=cn.constraint_col)
order by supertable_schema, supertable, constraint_name, subtable_schema, subtable_name, constraint_col;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
with constr as (select
o.conname as constraint_name,
(select nspname from pg_namespace where oid=c.relnamespace) as supertable_schema,
c.relname as supertable,
c.oid as supertable_oid,
o.conkey AS constraint_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype ='p'),
constr_unnest as (select constraint_name, supertable_schema, supertable, supertable_oid, constraint_col, constraint_col_num, ordin
from constr, unnest(constr.constraint_col) with ordinality as f(constraint_col_num, ordin)),
constr_with_names as (select constraint_name, supertable_schema, supertable, supertable_oid, array_agg(a_target.attname order by ordin) as constraint_col 
from constr_unnest constr inner join pg_attribute a_target on constr.constraint_col_num = a_target.attnum and constr.supertable_oid = a_target.attrelid and a_target.attisdropped = false
group by constraint_name, supertable_schema, supertable, supertable_oid),
supertable_constraints as (select constraint_name, supertable_schema, supertable, constraint_col, pc.nspname as subtable_schema, c.relname as subtable_name
from constr_with_names inner join pg_inherits pi on pi.inhparent=constr_with_names.supertable_oid
inner join pg_class c on pi.inhrelid=c.oid
inner join pg_namespace pc on c.relnamespace=pc.oid)
SELECT format('ALTER TABLE %1$I.%2$I ADD CONSTRAINT pk_%2$s PRIMARY KEY(%3$s);', subtable_schema, subtable_name, array_to_string(constraint_col,',')) AS statements
FROM supertable_constraints as sc
WHERE NOT EXISTS (SELECT 1
FROM constr_with_names AS cn
WHERE sc.subtable_schema=cn.supertable_schema 
AND sc.subtable_name=cn.supertable
AND sc.constraint_col=cn.constraint_col)
ORDER BY statements;
Define the primary key constraint.
with constr as (select
o.conname as constraint_name,
(select nspname from pg_namespace where oid=c.relnamespace) as supertable_schema,
c.relname as supertable,
c.oid as supertable_oid,
o.conkey AS constraint_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype='u'),
constr_unnest as (select constraint_name, supertable_schema, supertable, supertable_oid, constraint_col, constraint_col_num, ordin
from constr, unnest(constr.constraint_col) with ordinality as f(constraint_col_num, ordin)),
constr_with_names as (select constraint_name, supertable_schema, supertable, supertable_oid, array_agg(a_target.attname order by ordin) as constraint_col 
from constr_unnest constr inner join pg_attribute a_target on constr.constraint_col_num = a_target.attnum and constr.supertable_oid = a_target.attrelid and a_target.attisdropped = false
group by constraint_name, supertable_schema, supertable, supertable_oid),
supertable_constraints as (select constraint_name, supertable_schema, supertable, constraint_col, pc.nspname as subtable_schema, c.relname as subtable_name
from constr_with_names inner join pg_inherits pi on pi.inhparent=constr_with_names.supertable_oid
inner join pg_class c on pi.inhrelid=c.oid
inner join pg_namespace pc on c.relnamespace=pc.oid)
SELECT format('ALTER TABLE %1$I.%2$I ADD CONSTRAINT ak_%2$s UNIQUE(%3$s);', subtable_schema, subtable_name, array_to_string(constraint_col,',')) AS statements
FROM supertable_constraints as sc
WHERE NOT EXISTS (SELECT 1
FROM constr_with_names AS cn
WHERE sc.subtable_schema=cn.supertable_schema 
AND sc.subtable_name=cn.supertable
AND sc.constraint_col=cn.constraint_col)
ORDER BY statements;
Define the unique constraint.
with constr as (select
o.conname as constraint_name,
(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 supertable_schema,
c.relname as supertable,
c.oid as supertable_oid,
o.conkey AS constraint_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'),

constr_unnest as (select constraint_name, foreign_schema, foreign_table,  foreign_table_oid, foreign_col, foreign_col_num, supertable_schema, supertable, supertable_oid, constraint_col, constraint_col_num, ordin, on_update, on_delete
from constr, unnest(constr.foreign_col, constr.constraint_col) with ordinality as f(foreign_col_num, constraint_col_num, ordin)),

constr_with_names as (select constraint_name, foreign_schema, foreign_table, foreign_table_oid, array_agg(a_foreign.attname order by ordin) as foreign_col, supertable_schema, supertable, supertable_oid, array_agg(a_target.attname order by ordin) as constraint_col, on_update, on_delete 
from constr_unnest constr inner join pg_attribute a_foreign on constr.foreign_col_num = a_foreign.attnum and constr.foreign_table_oid = a_foreign.attrelid and a_foreign.attisdropped = false
inner join pg_attribute a_target on constr.constraint_col_num = a_target.attnum and constr.supertable_oid = a_target.attrelid and a_target.attisdropped = false
group by constraint_name, foreign_schema, foreign_table, foreign_table_oid,  supertable_schema, supertable, supertable_oid, on_update, on_delete),

supertable_constraints as (select constraint_name, foreign_schema, foreign_table, foreign_col, supertable_schema, supertable, constraint_col, on_update, on_delete, pc.nspname as subtable_schema, c.relname as subtable_name
from constr_with_names inner join pg_inherits pi on pi.inhparent=constr_with_names.supertable_oid
inner join pg_class c on pi.inhrelid=c.oid
inner join pg_namespace pc on c.relnamespace=pc.oid)

SELECT format('ALTER TABLE %1$I.%2$I ADD CONSTRAINT fk_%2$s_%5$s FOREIGN KEY(%3$s) REFERENCES %4$I.%5$I(%6$s) ON UPDATE %7$s ON DELETE %8$s;', subtable_schema, subtable_name, array_to_string(constraint_col,','), foreign_schema, foreign_table, array_to_string(foreign_col,','), on_update, on_delete) AS statements
FROM supertable_constraints as sc
WHERE NOT EXISTS (SELECT 1
FROM constr_with_names AS cn
WHERE sc.subtable_schema=cn.supertable_schema 
AND sc.subtable_name=cn.supertable
AND sc.constraint_col=cn.constraint_col)
ORDER BY statements;
Define 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
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.
Table inheritanceQueries of this category provide information about the inheritance between base tables.
UniquenessQueries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.
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).

Reference materials for further reading

Reference
https://www.postgresql.org/docs/current/tutorial-inheritance.html

The list of all the queries