The list of all the queries

Duplicate CHECK constraints that are connected directly to a table

Query goal: The same table should not have multiple CHECK constraints with exactly the same Boolean expression. 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 about the query: The query only considers CHECK constraints that are directly associated with a table, i.e., not constraints that are associated with a 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.
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: Drop the redundant constraints.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

SELECT ccu.table_schema, ccu.table_name, cc.check_clause,
string_agg(DISTINCT cc.constraint_name, ';<br>') AS constraints, 
Count(DISTINCT cc.constraint_name) AS number_of_constraints
FROM INFORMATION_SCHEMA.constraint_column_usage AS ccu INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc
USING (constraint_schema, constraint_name)
WHERE cc.check_clause NOT LIKE '%IS NOT NULL' AND 
ccu.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)
GROUP BY ccu.table_schema, ccu.table_name, cc.check_clause
HAVING Count(DISTINCT cc.constraint_name)>1
ORDER BY ccu.table_schema, ccu.table_name, Count(DISTINCT cc.constraint_name) DESC;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
WITH duplicate_checks AS (SELECT ccu.table_schema, ccu.table_name, cc.check_clause,
array_agg(DISTINCT cc.constraint_name) AS constraints_array
FROM INFORMATION_SCHEMA.constraint_column_usage AS ccu INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc
USING (constraint_schema, constraint_name)
WHERE cc.check_clause NOT LIKE '%IS NOT NULL' AND 
ccu.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)
GROUP BY ccu.table_schema, ccu.table_name, cc.check_clause
HAVING Count(DISTINCT cc.constraint_name)>1)
SELECT format ('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', table_schema, table_name, unnest(constraints_array)) AS statements
FROM duplicate_checks
ORDER BY table_schema, table_name;
Drop the constraint. One of the constraints must stay in place.

Collections where the query belongs to

Collection nameCollection description
Find problems about integrity constraintsA 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 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.
Duplication of implementation elementsQueries of this catergory provide information about the duplication of the database objects.

Reference materials for further reading

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)

The list of all the queries