This query identifies foreign key constraints with a superfluous ON UPDATE CASCADE action. It operates on the heuristic that foreign keys referencing surrogate keys should not permit cascading updates, as their values are immutable by definition. The query uses a naming convention to identify probable surrogate keys, specifically flagging foreign key columns with the prefix or suffix "id". The presence of ON UPDATE CASCADE on such keys is not only unnecessary but also misrepresents the nature of the relationship to a schema observer.
Type
Problem detection (Each row in the result could represent a flaw in the design)
The recommended corrective actions depend on the type of key referenced:
For natural keys: The referenced column and the corresponding foreign key column should be renamed to include the "code" prefix or suffix. This ensures the naming convention clearly indicates that the key is a user-defined value.
For surrogate keys: The ON UPDATE CASCADE compensating action should be removed from the foreign key constraint. This aligns the schema with the principle that surrogate key values are immutable.
Data Source
system catalog only
SQL Query
select constraint_name, foreign_schema, foreign_table, af.attname as foreign_column_name, target_schema, target_table, at.attname as target_column_name, update_compensating_action
from (select
(select nspname from pg_namespace where oid=m.relnamespace) as foreign_schema,
m.relname as foreign_table,
m.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,
o.confupdtype,
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,
o.conname as constraint_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_class m on m.oid = o.confrelid
where o.contype = 'f' and o.conrelid in (select oid from pg_class c where c.relkind = 'r')) f
inner join pg_attribute af on f.foreign_col = af.attnum and f.foreign_table_oid = af.attrelid and af.attisdropped = false
inner join pg_attribute at on f.target_col = at.attnum and f.target_table_oid = at.attrelid and at.attisdropped = false
AND (af.attname~*'_id$' OR af.attname~*'^(id)_')
AND confupdtype='c'
ORDER BY target_schema, target_table, target_column_name, foreign_schema, foreign_table, foreign_column_name;
Collections
This query belongs to the following collections:
Name
Description
Find problems automatically
Queries, 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
This query is classified under the following categories:
Name
Description
Compensating actions
Queries of this category provide information about compensating actions of foreign key constraints.
Naming
Queries of this category provide information about the style of naming.
Relationships between tables
Queries 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.
Result quality depends on names
Queries of this category use names (for instance, column names) to try to guess the meaning of a database object. Thus, the goodness of names determines the number of false positive and false negative results.