The list of all the queries

All non-identifying relationships

Query goal: Find all non-identifying relationships where the foreign key (a set of columns) is not a subset of any uniqueness constraint (primary key, unique, or exclude constraint).
Query type: General (Overview of some aspect of the database.)
Query license: MIT License
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,
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 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, target_schema, target_table,on_update, on_delete, target_col),

uq as (select
(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.conname
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype in ('p','u','x')),
uq_unnest as (select target_schema, target_table, conname, target_table_oid, target_col, target_col_num, ordin
from uq, unnest(uq.target_col) with ordinality as f(target_col_num, ordin)),
uq_with_names as (select target_schema, target_table, conname, array_agg(CASE WHEN a_target.attname IS NOT NULL THEN a_target.attname ELSE 'something' END order by ordin) as target_col
from uq_unnest uq left join pg_attribute a_target on uq.target_col_num = a_target.attnum and uq.target_table_oid = a_target.attrelid and a_target.attisdropped = false
left join pg_type AS t_target ON a_target.atttypid=t_target.oid
WHERE a_target.attnotnull = true 
OR t_target.typnotnull=true
OR (a_target.attnotnull IS NULL AND t_target.typnotnull IS NULL)
group by target_schema, target_table, conname)

SELECT fk.conname, fk.foreign_schema, fk.foreign_table, fk.foreign_col, fk.target_schema, fk.target_table, fk.target_col, fk.on_update, fk.on_delete
FROM fk_with_names as fk
WHERE NOT EXISTS (SELECT *
FROM uq_with_names as uq
WHERE fk.target_schema=uq.target_schema
AND fk.target_table=uq.target_table
AND fk.target_col <@ uq.target_col)
ORDER BY fk.target_schema, fk.target_table, fk.conname;

Collections where the query belongs to

Collection nameCollection description
Find problems by overviewQueries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems 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.

Reference materials for further reading

Reference
https://stackoverflow.com/questions/762937/whats-the-difference-between-identifying-and-non-identifying-relationships

The list of all the queries