Query goal: | Find foreign key constraints that use a SET NULL compensating action but a foreign key column is mandatory, i.e., does not permit NULLs. Compensatory actions cannot make changes that violate integrity constraints in a database. SET NULL cannot put NULL to a mandatory column (delete a foreign key value). |
Notes about the query: | The query consider only simple foreign keys, i.e., foreign keys that involve only one column. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | High (Few or no false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Change the compensatory action (better) or make the foreign key columns optional (worse, due to potential problems that NULLs cause in formulating queries). In order to change the compensatory action one has to drop and recreate the foreign key constraint. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH f AS (select (select nspname from pg_namespace where oid=f.relnamespace) as foreign_ns, f.relname as foreign_table, (select a.attname from pg_attribute a where a.attrelid = f.oid and a.attnum = o.confkey[1] and a.attisdropped = false) as foreign_colname, (select nspname from pg_namespace where oid=c.relnamespace) as target_ns, c.relname as target_table, (select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as target_colname, o.confupdtype, o.confdeltype 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 cardinality(o.conkey)=1) SELECT foreign_ns, foreign_table, foreign_colname, target_ns, target_table, target_colname, CASE WHEN confupdtype='c' THEN 'CASCADE' WHEN confupdtype='r' THEN 'RESTRICT' WHEN confupdtype='n' THEN 'SET NULL' WHEN confupdtype='d' THEN 'SET DEFAULT' ELSE 'NO ACTION' END AS on_update_behavior, CASE WHEN confdeltype='c' THEN 'CASCADE' WHEN confdeltype='r' THEN 'RESTRICT' WHEN confdeltype='n' THEN 'SET NULL' WHEN confdeltype='d' THEN 'SET DEFAULT' ELSE 'NO ACTION' END AS on_delete_behavior FROM f WHERE (confupdtype='n' OR confdeltype='n') AND EXISTS (SELECT 1 FROM information_schema.columns AS c WHERE f.target_ns=c.table_schema AND f.target_table=c.table_name AND f.target_colname=c.column_name AND c.is_nullable='NO') ORDER BY target_ns, target_table, target_colname, confupdtype, confdeltype; |
SQL query | Description |
---|---|
WITH f AS (select o.conname, (select nspname from pg_namespace where oid=c.relnamespace) as target_ns, c.relname as target_table, (select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as target_colname, o.confupdtype, o.confdeltype 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 cardinality(o.conkey)=1) SELECT format('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', target_ns, target_table, conname) AS statements FROM f WHERE (confupdtype='n' OR confdeltype='n') AND EXISTS (SELECT 1 FROM information_schema.columns AS c WHERE f.target_ns=c.table_schema AND f.target_table=c.table_name AND f.target_colname=c.column_name AND c.is_nullable='NO') ORDER BY target_ns, target_table, target_colname; | Drop the foreign key constraint. |
Collection name | Collection 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 . |
Category name | Category description |
---|---|
Compensating actions | Queries of this category provide information about compensating actions of foreign key constraints. |
Missing data | Queries of this category provide information about missing data (NULLs) in a database. |
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. |