The list of all the queries

Simple check constraints with multiple tasks

Query goal: Find simple check constraints, i.e., check constraints that cover one column that seem to have multiple tasks. The corresponding code smell in case of cleaning code is "G30: Functions Should Do One Thing". (Robert C. Martin, Clean Code)
Notes about the query: The query finds CHECK constraints that are associated with a base table directly as well as CHECK constraints that are associated with domains that are used to define at least one column. The query does not find CHECK constraints of domains that are not associated with any table.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Low (Many false-positive results)
Query license: MIT License
Fixing suggestion: Create multiple CHECK constraints instead of one.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

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, check_type, constraint_name
FROM checks
WHERE check_clause~*'[[:space:]]AND[[:space:]]'
AND check_clause!~*'[[:space:]]OR[[:space:]]'
AND check_clause~*'[[:space:]](=|<>|~|!~|~\*|!~\*|~~|~~\*|!~~|!~~*)[[:space:]]'
ORDER BY table_schema, table_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.
Comfortability of database evolutionQueries of this category provide information about the means that influence database evolution.

Reference materials for further reading

Reference
https://en.wikipedia.org/wiki/Single_responsibility_principle

The list of all the queries