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
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 condeferrable=false),
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
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, a_foreign.attname as foreign_col, foreign_col_num, target_schema, target_table, a_target.attname as target_col, target_col_num
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
where (fk.target_schema, fk.target_table, a_target.attname) IN (SELECT c.table_schema, c.table_name, c.column_name
FROM information_schema.columns AS c
WHERE c.is_nullable='NO')),
table_paryicipates_in_relationship AS (SELECT foreign_schema AS table_schema, foreign_table AS table_name
FROM fk_with_names
UNION SELECT target_schema AS table_schema, target_table AS table_name
FROM fk_with_names)
SELECT 'Perhaps the relationships form a cycle' AS warning
WHERE (SELECT Count(DISTINCT target_schema || '.' || target_table) AS cnt
FROM fk_with_names)=(SELECT Count(*) AS cnt
FROM table_paryicipates_in_relationship)
AND (SELECT Count(*) AS cnt
FROM table_paryicipates_in_relationship)>0;