Goal Find duplication of simple CHECK constraints on the same base table or foreign table column. Duplication of the same constraint means that if one starts to manage the code, then changes have to be made in multiple places. The problem is essentially similar with the data redundancy problem that database normalization tries to reduce. Do remember that the same task can be solved in SQL usually in multiple different ways. Thus, the exact copies are not the only possible duplication.
Notes The query tries to make the representation of domain check constraints the same as the representation of table check constraints in order to be able to detect situations where a constraint is associated with a domain and the same constraint is associated also with the column that has been defined based on the domain. 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)
Reliability High (Few or no false-positive results)
License MIT License
Fixing Suggestion Drop the duplicates.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH checks AS (
select 
n.nspname as table_schema,
c.relname as table_name,
CASE WHEN c.relkind='r' THEN 'BASE TABLE' ELSE 'FOREIGN' END AS table_type,
a.attname as column_name,
regexp_replace(pg_get_constraintdef(o.oid),'CHECK ', '','g') AS check_clause,
'TABLE CHECK' AS check_type, 
o.conname AS constraint_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_namespace n on o.connamespace=n.oid
INNER JOIN pg_attribute a ON a.attrelid = c.oid AND a.attnum = o.conkey[1] AND a.attisdropped = FALSE
where o.contype = 'c' 
AND cardinality(o.conkey)=1
AND c.relkind IN ('r', 'f')
UNION ALL SELECT cdu.table_schema, cdu.table_name, t.table_type, cdu.column_name, regexp_replace(cc.check_clause, 'VALUE', '(' || cdu.column_name ||')::' || lower(d.data_type)) AS check_clause, 'DOMAIN CHECK' AS check_type, 
d.domain_schema||'.'||d.domain_name || '.' || cc.constraint_name AS name
FROM INFORMATION_SCHEMA.column_domain_usage AS cdu INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name) 
INNER JOIN INFORMATION_SCHEMA.domain_constraints AS dc USING (domain_schema, domain_name) 
INNER JOIN INFORMATION_SCHEMA.domains AS d USING (domain_schema, domain_name)
INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name)
WHERE t.table_type IN ('BASE TABLE', 'FOREIGN') AND cc.check_clause NOT LIKE '%IS NOT NULL'  AND 
cdu.table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL))
SELECT table_schema, table_name, column_name, check_clause, Count(*) AS number_of_occurrences, string_agg(check_type || ': ' || constraint_name, ';
' ORDER BY constraint_name) AS constraints FROM checks GROUP BY table_schema, table_name, column_name, check_clause HAVING Count(*)>1 ORDER BY Count(*) DESC, table_schema, table_name;
Collections

This query belongs to the following collections:

NameDescription
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

This query is classified under the following categories:

NameDescription
CHECK constraintsQueries of this category provide information about CHECK constraints.
Duplication of implementation elementsQueries of this catergory provide information about the duplication of the database objects.

Further reading and related materials:

Reference
https://refactoring.guru/smells/alternative-classes-with-different-interfaces
https://refactoring.guru/smells/duplicate-code
The corresponding code smell in case of cleaning code is "G5: Duplication". (Robert C. Martin, Clean Code)