The list of all the queries

ON UPDATE CASCADE is probably missing (based on data types)

Query goal: Find foreign key constraints where the foreign key column does not have an integer type or uuid type and the foreign key constraint does not have ON UPDATE CASCADE compensating action. In this case the foreign key probably refferes to a natural key (i.e., a key that values have meaning outside the computer system) and ON UPDATE CASCADE would be suitable because the key values could be changed over time.
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 foreign key constraint and recreate with ON UPDATE CASCADE compensating 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 confupdtype='a' then 'ON UPDATE NO ACTION' 
when confupdtype='r' then 'ON UPDATE RESTRICT' 
when confupdtype='c' then 'ON UPDATE CASCADE' 
when confupdtype='n' then 'ON UPDATE SET NULL' 
when confupdtype='d' then 'ON UPDATE SET DEFAULT' end as update_compensating_action
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.confupdtype<>'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, update_compensating_action
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, target_schema, target_table, a_target.attname as target_col, update_compensating_action
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),
data_types AS (SELECT table_schema, table_name, column_name, 
CASE WHEN data_type='numeric' THEN data_type || '(' || numeric_precision || ',' || numeric_scale || ')'
WHEN character_maximum_length IS NOT NULL THEN data_type || '(' ||  character_maximum_length || ')'
WHEN datetime_precision IS NOT NULL AND data_type<>'date' THEN data_type || '(' ||  datetime_precision || ')'
ELSE data_type END AS data_type
FROM INFORMATION_SCHEMA.columns
WHERE (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables 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))

SELECT fk.*, dtf.data_type AS foreign_data_type, dtt.data_type AS target_data_type
FROM fk_with_names AS fk INNER JOIN data_types AS dtf ON fk.foreign_schema=dtf.table_schema AND fk.foreign_table=dtf.table_name AND fk.foreign_col=dtf.column_name
INNER JOIN data_types AS dtt ON fk.target_schema=dtt.table_schema AND fk.target_table=dtt.table_name AND fk.target_col=dtt.column_name
WHERE dtt.data_type!~*'(smallint|integer|bigint|uuid)'
ORDER BY target_schema, target_table, target_col, foreign_schema, foreign_table, foreign_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=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 o.confupdtype<>'u'),
fk_unnest as (select conname, target_schema, target_table, target_table_oid, target_col, target_col_num, ordin
from fk, unnest(fk. target_col) with ordinality as f(target_col_num, ordin)),
fk_with_names as (select conname, target_schema, target_table, a_target.attname as target_col
from fk_unnest fk 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),
data_types AS (SELECT table_schema, table_name, column_name, 
CASE WHEN data_type='numeric' THEN data_type || '(' || numeric_precision || ',' || numeric_scale || ')'
WHEN character_maximum_length IS NOT NULL THEN data_type || '(' ||  character_maximum_length || ')'
WHEN datetime_precision IS NOT NULL AND data_type<>'date' THEN data_type || '(' ||  datetime_precision || ')'
ELSE data_type END AS data_type
FROM INFORMATION_SCHEMA.columns
WHERE (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables 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))
SELECT DISTINCT format('ALTER TABLE %1$I.%2$I DROP CONSTRAIN %3$I;', target_schema, target_table,conname) AS statements
from fk_with_names AS fk inner join data_types AS dtt ON fk.target_schema=dtt.table_schema AND fk.target_table=dtt.table_name AND fk.target_col=dtt.column_name
WHERE dtt.data_type!~*'(smallint|integer|bigint)'
order by statements;
Drop the foreign key constraint.

Collections where the query belongs to

Collection nameCollection description
Find problems about integrity constraintsA selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview
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.
Data typesQueries of this category provide information about the data types and their usage.
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