Query goal: | Find foreign key constraints that do not feature ON UPDATE CASCADE compensating action although people have a reason to change the key value in the primary table by assuming that the names of foreign key columns correctly point towards the use of natural keys in the table. |
Notes about the query: | The query considers both column names in English and Estonian. |
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 it with ON UPDATE CASCADE compensating action. Another possibility is that the names of key columns do not follow a naming convention and have to be changed. |
Data source: | system catalog only |
SQL query: | Click on query to copy it
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~*'(kood|code)$' OR af.attname~*'^(kood|code)_') AND confupdtype<>'c' ORDER BY target_schema, target_table, target_column_name, foreign_schema, foreign_table, foreign_column_name; |
SQL query | Description |
---|---|
SELECT DISTINCT format('ALTER TABLE %1$I.%2$I DROP CONSTRAIN %3$I;', target_schema, target_table, constraint_name) AS statements 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, 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~*'(kood|code)$' OR af.attname~*'^(kood|code)_') AND confupdtype<>'c' ORDER BY statements; | 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. |
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. |
Validity and completeness | Queries of this category provide information about whether database design represents the world (domain) correctly (validity) and whether database design captures all the information about the world (domain) that is correct and relevant (completeness). |
Reference |
---|
http://whileicompile.com/2012/03/my-take-on-identifier-semantics-id-vs-no-vs-code-vs-key/ |