The list of all the queries

The same CHECK has a different name in different places (2)

Query goal: 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)
Notes about the query: The query constructs patterns of constraint names by replacing the table name with the word TABLE . The query only considers CHECK constraints that are associated with a base table. 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.
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
Data source: system catalog only
SQL query: Click on query to copy it

with ck as (select 
o.conname,
(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,
substring(pg_get_constraintdef(o.oid),7) as consrc
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype = 'c'),
ck_names as (select replace(lower(ck.conname), lower(ck.target_table),'T A B L E') as conname_pattern, ck.target_schema, ck.target_table, string_agg(a_target.attname, ', ' ORDER BY a_target.attname) as target_col, ck.consrc
from ck inner join pg_attribute a_target on ck.target_col = a_target.attnum and ck.target_table_oid = a_target.attrelid and a_target.attisdropped = false
group by conname, ck.target_schema, ck.target_table, ck.consrc)
SELECT consrc, string_agg(target_schema || '.' || target_table || '.(' || target_col || ').' || conname_pattern, ',<br>' ORDER BY target_schema, target_table) AS constraints
FROM ck_names
GROUP BY consrc
HAVING Count(DISTINCT conname_pattern)>1
ORDER BY consrc;

Collections where the query belongs to

Collection nameCollection description
Find problems automaticallyQueries, 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 where the query belongs to

Category nameCategory description
CHECK constraintsQueries of this category provide information about CHECK constraints.
InconsistenciesQueries of this catergory provide information about inconsistencies of solving the same problem in different places.
NamingQueries of this category provide information about the style of naming.

Reference materials for further reading

Reference
The corresponding code smell in case of cleaning code is "G11: Inconsistency". (Robert C. Martin, Clean Code)

The list of all the queries