Find the names of table CHECK constraints that have the same Boolean expression but a different naming style in different places (tables). The naming of constraints should be consistent. "If you do something a certain way, do all similar things in the same way." (Robert C. Martin, Clean Code)x
Notes
The query constructs patterns of constraint names by replacing the table name with the word TABLE and column name with the word COLUMN. The query only considers CHECK constraints that are associated with a base table and that restrict values in exactly one column. The query only considers constraints that have the same syntax. The same rule could be enforced by different CHECK constraint Boolean expressions. The names of such constraints should follow the same pattern but the query does not check that. In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Rename constraints to follow the same naming pattern. Pay attention that in PostgreSQL maximum identifier length is 63 bytes, i.e., in some places one has, for instance, to shorten the name.
Data Source
system catalog only
SQL Query
WITH chk_constraint_names AS (select
n.nspname as table_schema,
c.relname as table_name,
(select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as column_name,
o.conname AS constraint_name,
substring(pg_get_constraintdef(o.oid),7) AS consrc
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_namespace n on o.connamespace=n.oid
where o.contype = 'c' and cardinality(o.conkey)=1),
chk_constraint_names_generalized AS (
SELECT table_schema, table_name, column_name,
replace(consrc, column_name,'VALUE') AS consrc,
constraint_name AS constraint_name_original,
CASE WHEN lower(table_name) ILIKE '%' || lower(column_name) || '%' THEN
replace(replace(lower(constraint_name), lower(table_name), 'T A B L E'), lower(column_name),'C O L U M N')
ELSE
replace(replace(lower(constraint_name), lower(column_name), 'C O L U M N'), lower(table_name),'T A B L E') END AS constraint_name
FROM chk_constraint_names)
SELECT consrc, Count(DISTINCT constraint_name) AS cnt_different,
Count(constraint_name) AS cnt_total,
string_agg(DISTINCT constraint_name, '; ' ORDER BY constraint_name DESC) as name_different,
string_agg('' || table_schema || '.' || table_name || ' ' || constraint_name || ' (' || constraint_name_original || ')', '; ' ORDER BY constraint_name DESC) as name_all
FROM chk_constraint_names_generalized
GROUP BY consrc
HAVING Count(DISTINCT constraint_name)>1
ORDER BY Count(DISTINCT constraint_name) DESC;
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
CHECK constraints
Queries of this category provide information about CHECK constraints.
Inconsistencies
Queries of this catergory provide information about inconsistencies of solving the same problem in different places.
Naming
Queries of this category provide information about the style of naming.
Further reading and related materials:
Reference
The corresponding code smell in case of cleaning code is "G11: Inconsistency". (Robert C. Martin, Clean Code)