The list of all the queries

Optional composite foreign keys that do not have MATCH FULL specified

Query goal: Find optional composite foreign keys that do not have MATCH FULL specified. Without MATCH FULL the system will permit partial foreign key values
Notes about the query: The query considers only foreign key constraints that involve more than one column.
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: Drop the forein key constraint and recreate it with the MATCH FULL specification.
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
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.confmatchtype<>'f' and 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 
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)
select conname, foreign_schema, foreign_col, target_schema, target_col
from fk_grouped 
where not (target_not_null @> array['t']::boolean[])
order by target_schema, target_col;

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

SQL queryDescription
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
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.confmatchtype<>'f' and 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, fk.target_table, 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 
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, fk.target_table)
SELECT format('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I;',  target_schema, target_table, conname) AS statements
from fk_grouped 
where not (target_not_null @> array['t']::boolean[])
order by target_schema, target_col;
Drop the constraint.

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