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,
unnest(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,
unnest(o.conkey) AS target_col,
CASE WHEN o.confmatchtype='f' THEN 'FULL'
WHEN o.confmatchtype='p' THEN 'PARTIAL'
WHEN o.confmatchtype='s' THEN 'SIMPLE' END AS match_type
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 cardinality(o.confkey)>1),
fk_grouped as (
select fk.conname, fk.foreign_schema, array_agg(fk.foreign_table || '.' || a_foreign.attname order by a_foreign.attnum) as foreign_col, fk.target_schema, array_agg(fk.target_table || '.' || a_target.attname order by a_target.attnum) as target_col,
array_agg(a_target.attnotnull order by a_target.attnum) as target_not_null, match_type
from fk inner join pg_attribute a_foreign on fk.foreign_col = 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 = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false
group by fk.conname, fk.foreign_schema, fk.target_schema, match_type)
select conname, foreign_schema, foreign_col, target_schema, target_col, target_not_null, match_type
from fk_grouped
where target_not_null @> array['f']::boolean[] and target_not_null @> array['t']::boolean[]
order by conname, target_schema, target_col, match_type;