The list of all the queries

ON DELETE CASCADE is not needed (based on classifier tables)

Query goal: Find foreign key constraints with ON DELETE CASCADE compensating action that refer to classifier (reference data) tables.
Notes about the query: The query searches classifier tables by searching base tables that satisfy all the following conditions: the table has at most four columns, the table has a column that name contains the word "code", and the table does not have any foreign key columns.
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: Use instead ON DELETE NO ACTION.
Data source: INFORMATION_SCHEMA+system catalog
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,
'CASCADE' 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'
and o.confdeltype='c'),
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),
classifiers AS (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables AS t
WHERE table_type='BASE TABLE'
AND table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND (SELECT Count(*) FROM INFORMATION_SCHEMA.columns AS c
WHERE t.table_schema=c.table_schema 
AND t.table_name=c.table_name)<=4
AND EXISTS (SELECT *
FROM INFORMATION_SCHEMA.columns AS c
WHERE t.table_schema=c.table_schema 
AND t.table_name=c.table_name
AND c.column_name~*'(code|kood)')
AND (table_schema, table_name) NOT IN (SELECT target_schema, target_table
FROM fk_with_names))
select conname, foreign_schema, foreign_table, foreign_col, target_schema, target_table, target_col, on_update, on_delete
from fk_with_names
WHERE (foreign_schema, foreign_table) IN (SELECT table_schema, table_name
FROM classifiers)
order by target_schema, target_table, conname;

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
Comfortability of data managementQueries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient.
Compensating actionsQueries of this category provide information about compensating actions of foreign key constraints.
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.

The list of all the queries