Query goal: | Find the foreign key constraints that do not have ON UPDATE CASCADE and that referenced key is a simple key that has an integer type, is not covered by another foreign key, and does not have an associated sequence generator, i.e., the foreign key references a simple natural key. |
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: | Find out as to whether the referenced candidate keys is a natural key. In this case ON UPDATE CASCADE is needed. If it is the case, then drop the foreign keys without ON UPDATE CASCADE and recreate these with the compensating action. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
with keys as (select (select nspname from pg_namespace where oid=c.relnamespace) as key_schema, c.relname as key_table, c.oid as key_table_oid, o.conkey AS key_col from pg_constraint o inner join pg_class c on c.oid = o.conrelid where o.contype in ('u', 'p') and cardinality(o.conkey)=1), keys_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin from keys, unnest(keys.key_col) with ordinality as k(key_col_num, ordin)), keys_with_names AS (select key_schema, key_table, a_key.attname as key_col from keys_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false ), 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 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'), 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 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, foreign_col_num, target_schema, target_table, a_target.attname as target_col, target_col_num,on_update 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), fk_with_names_grouped as (select conname, foreign_schema, foreign_table, array_agg(foreign_col order by foreign_col_num) as foreign_col, target_schema, target_table, array_agg(target_col order by target_col_num) as target_col, on_update from fk_with_names group by conname, foreign_schema, foreign_table, target_schema, target_table,on_update, target_col), key_not_fk AS (select key_schema, key_table, key_col from keys_with_names except select target_schema, target_table, target_col from fk_with_names), non_surrogate_int_keys AS (SELECT c.table_schema, c.table_name , c.column_name FROM information_schema.columns c LEFT JOIN information_schema.domains d USING (domain_schema, domain_name) INNER JOIN information_schema.schemata s ON c.table_schema=s.schema_name WHERE (coalesce (c.column_default, d.domain_default) NOT LIKE '%nextval%' OR coalesce (c.column_default, d.domain_default) IS NULL) AND c.is_identity='NO' AND (c.data_type~*'(smallint|integer|bigint)') AND (c.table_schema = 'public' OR s.schema_owner<>'postgres') AND EXISTS (SELECT * FROM key_not_fk AS k WHERE k.key_schema=c.table_schema AND k.key_table=c.table_name AND k.key_col=c.column_name)) SELECT conname AS constraint_name, foreign_schema, foreign_table, foreign_col AS foreign_column_name, target_schema, target_table, target_col AS target_column_name, on_update AS update_compensating_action FROM fk_with_names_grouped AS f WHERE on_update<>'CASCADE' AND EXISTS (SELECT * FROM non_surrogate_int_keys AS k WHERE f.foreign_schema=k.table_schema AND f.foreign_table=k.table_name AND k.column_name = ANY (f.foreign_col)) ORDER BY target_schema, target_table, target_col, foreign_schema, foreign_table, foreign_col; |
SQL query | Description |
---|---|
with keys as (select (select nspname from pg_namespace where oid=c.relnamespace) as key_schema, c.relname as key_table, c.oid as key_table_oid, o.conkey AS key_col from pg_constraint o inner join pg_class c on c.oid = o.conrelid where o.contype in ('u', 'p') and cardinality(o.conkey)=1), keys_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin from keys, unnest(keys.key_col) with ordinality as k(key_col_num, ordin)), keys_with_names AS (select key_schema, key_table, a_key.attname as key_col from keys_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false ), 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, CASE WHEN o.confdeltype='a' THEN 'NO ACTION' WHEN o.confdeltype='r' THEN 'RESTRICT' WHEN o.confdeltype='c' THEN 'CASCADE' WHEN o.confdeltype='n' THEN 'SET NULL' WHEN o.confdeltype='d' THEN 'SET DEFAULT' END 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'), 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, a_foreign.attname as foreign_col, foreign_col_num, target_schema, target_table, a_target.attname as target_col, target_col_num,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), fk_with_names_grouped as (select conname, foreign_schema, foreign_table, array_agg(foreign_col order by foreign_col_num) as foreign_col, target_schema, target_table, array_agg(target_col order by target_col_num) as target_col, on_update, on_delete from fk_with_names group by conname, foreign_schema, foreign_table, target_schema, target_table,on_update, on_delete, target_col), key_not_fk AS (select key_schema, key_table, key_col from keys_with_names except select target_schema, target_table, target_col from fk_with_names), non_surrogate_int_keys AS (SELECT c.table_schema, c.table_name , c.column_name FROM information_schema.columns c LEFT JOIN information_schema.domains d USING (domain_schema, domain_name) INNER JOIN information_schema.schemata s ON c.table_schema=s.schema_name WHERE (coalesce (c.column_default, d.domain_default) NOT LIKE '%nextval%' OR coalesce (c.column_default, d.domain_default) IS NULL) AND c.is_identity='NO' AND (c.data_type~*'(smallint|integer|bigint)') AND (c.table_schema = 'public' OR s.schema_owner<>'postgres') AND EXISTS (SELECT * FROM key_not_fk AS k WHERE k.key_schema=c.table_schema AND k.key_table=c.table_name AND k.key_col=c.column_name)) SELECT format('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', target_schema, target_table, conname) AS statements FROM fk_with_names_grouped AS f WHERE on_update<>'CASCADE' AND EXISTS (SELECT * FROM non_surrogate_int_keys AS k WHERE f.foreign_schema=k.table_schema AND f.foreign_table=k.table_name AND k.column_name = ANY (f.foreign_col)) ORDER BY target_schema, target_table, conname; | Drop the foreign key constraint. |
Collection name | Collection description |
---|---|
Find problems about integrity constraints | A 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 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 . |
Category name | Category description |
---|---|
Comfortability of data management | Queries 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 actions | Queries of this category provide information about compensating actions of foreign key constraints. |
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. |
Sequence generators | Queries of this category provide information about sequence generators and their usage. |