The list of all the queries

Composite foreign keys with a mix of mandatory and optional columns

Query goal: Find composite foreign keys with a mix of mandatory and optional columns. In case of a composite foreign keys all the columns should either optional or mandatory in order to avoid problems with NULLs.
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: If possible, then declare to all the foreign key columns NOT NULL constraint. If there indeed must be a mix of mandatory and optional columns in the foreign key, then make sure that the match type is FULL in this case in order to avoid problems with NULLs.
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,
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;

Collections where the query belongs to

Collection nameCollection description
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
Missing dataQueries of this category provide information about missing data (NULLs) in a database.
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://dba.stackexchange.com/questions/58894/differences-between-match-full-match-simple-and-match-partial

The list of all the queries