The list of all the queries

Perhaps CHECK should be associated with a domain

Query goal: Find cases where multiple columns with the same domain have exactly the same CHECK constraint that is directly associated with the table.
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
Fixing suggestion: Associate the check with the domain instead of the table or create a separate domain based on the columns that have the same constraint.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH table_checks_on_domain_columns 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,
n.nspname AS domain_schema,
t.typname AS domain_name, 
replace(substring(pg_get_constraintdef(o.oid),7), a.attname, 'VALUE') AS column_check
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
INNER JOIN pg_type AS t ON a.atttypid=t.oid AND t.typtype='d'
INNER JOIN pg_namespace AS n ON t.typnamespace=n.oid
WHERE cardinality(o.conkey)=1 AND o.contype = 'c' AND c.relkind = 'r'),
possibly_problematic_checks AS (SELECT domain_schema, domain_name, column_check, Count(DISTINCT table_schema || '.' || table_name || '.' || column_name) AS nr_of_cols,
string_agg(DISTINCT table_schema || '.' || table_name || '.' || column_name,',<br>' ORDER BY table_schema || '.' || table_name || '.' || column_name) AS columns 
FROM table_checks_on_domain_columns
GROUP BY domain_schema, domain_name, column_check
HAVING Count(DISTINCT table_schema || '.' || table_name || '.' || column_name)>1),
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 domain_schema, domain_name, domain_checks, column_check, nr_of_cols, columns
FROM possibly_problematic_checks LEFT JOIN column_domain_usage USING (domain_schema, domain_name)
ORDER BY domain_schema, domain_name;

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.
DomainsQueries of this category provide information about reusable specifications of column properties.

The list of all the queries