Goal Find cases where some CHECKS are associated with a domain and some with the base table columns that have the domain. Avoid duplication of code. Write as little code as possible. If possible, move things "before the brackets" so to say. In this case it means declaring CHECKS at the level of the domain and not at the level of base table columns.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Low (Many false-positive results)
License MIT License
Fixing Suggestion Drop the constraints that are associated directly with the base table and associate the constraints with the domain.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH simple_checks AS (SELECT 
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS table_schema,
c.relname as table_name, 
a.attname AS column_name,
o.conname,
substring(pg_get_constraintdef(o.oid),7) AS check_clause
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
INNER JOIN pg_attribute a ON a.attrelid = c.oid AND a.attnum = o.conkey[1] AND a.attisdropped = FALSE
WHERE cardinality(o.conkey)=1 AND o.contype = 'c' AND c.relkind = 'r'),
simple_checks_agg AS (SELECT table_schema, table_name, column_name, string_agg(check_clause,';' ORDER BY conname) AS column_checks
FROM simple_checks
GROUP BY table_schema, table_name, column_name),

column_domain_usage AS (SELECT cdu.domain_schema, cdu.domain_name, cdu.table_schema, cdu.table_name, cdu.column_name, string_agg(cc.check_clause,';' ORDER BY cc.constraint_name) AS domain_checks
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.check_constraints AS cc
USING (constraint_catalog, constraint_schema, constraint_name)
WHERE t.table_type='BASE TABLE' 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 catalog_name IS NOT NULL AND schema_name IS NOT NULL)
GROUP BY cdu.domain_schema, cdu.domain_name, cdu.table_schema, cdu.table_name, cdu.column_name)

SELECT cdu.domain_schema, domain_name, domain_checks, sc.table_schema, sc.table_name, sc.column_name, sc.column_checks
FROM simple_checks_agg sc INNER JOIN column_domain_usage cdu USING (table_schema, table_name, column_name)
ORDER BY cdu.domain_schema, domain_name, sc.table_schema, sc.table_name, sc.column_name;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
WITH simple_checks AS (SELECT 
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS table_schema,
c.relname as table_name, 
a.attname AS column_name,
o.conname,
substring(pg_get_constraintdef(o.oid),7) AS check_clause
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
INNER JOIN pg_attribute a ON a.attrelid = c.oid AND a.attnum = o.conkey[1] AND a.attisdropped = FALSE
WHERE cardinality(o.conkey)=1 AND o.contype = 'c' AND c.relkind = 'r'),

column_domain_usage AS (SELECT cdu.table_schema, cdu.table_name, cdu.column_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.check_constraints AS cc
USING (constraint_catalog, constraint_schema, constraint_name)
WHERE t.table_type='BASE TABLE' 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 catalog_name IS NOT NULL AND schema_name IS NOT NULL))

SELECT format('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', table_schema, table_name,  conname) AS statements

FROM simple_checks AS sc
WHERE EXISTS (SELECT 1
FROM column_domain_usage AS cdu WHERE sc.table_schema=cdu.table_schema
AND sc.table_name=cdu.table_name
AND sc.column_name=cdu.column_name)
ORDER BY table_schema, table_name,  conname;
Drop the constraint that is associated directly with the table.
Categories

This query is classified under the following categories:

NameDescription
CHECK constraintsQueries of this category provide information about CHECK constraints.
Comfortability of database evolutionQueries of this category provide information about the means that influence database evolution.
DomainsQueries of this category provide information about reusable specifications of column properties.
Duplication of implementation elementsQueries of this catergory provide information about the duplication of the database objects.