Goal Find columns of base tables and foreign tables where one uses a check constraint to prevent values that consist of only spaces. Make sure that this is the correct constraint and there is no need to prevent values that consist of only whitespace characters.
Notes The query takes into account constraints that are associated directly with the column as well as constraints that are associated with the column through a domain. The query does not find CHECK constraints of domains that are not associated with any table.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion If there is instead a rule that prevents strings that consist of only whitespace characters in the column, then instead use the following constraint: (column_name|VALUE)!~'^[[:space:]]*$'.
Data Source INFORMATION_SCHEMA only
SQL Query
WITH checks AS (SELECT ccu.table_schema, ccu.table_name, t.table_type, ccu.column_name, cc.check_clause, cc.constraint_name, 'TABLE CHECK' AS check_type
FROM INFORMATION_SCHEMA.constraint_column_usage AS ccu INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name)
INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_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)
UNION SELECT cdu.table_schema, cdu.table_name, t.table_type, cdu.column_name, cc.check_clause, cc.constraint_name, 'DOMAIN CHECK' AS check_type
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_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, table_type, column_name, check_clause, constraint_name, check_type
FROM checks
WHERE check_clause ~* '(btrim[(].+[)][[:space:]]*<>[[:space:]]*''''|length[(]btrim[(].+[)][)][[:space:]]*>[[:space:]]*0)'
ORDER BY table_schema, table_name, column_name;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
WITH checks AS (SELECT ccu.table_schema, ccu.table_name, t.table_type, cc.constraint_name, cc.check_clause
FROM INFORMATION_SCHEMA.constraint_column_usage AS ccu INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name)
INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_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))
SELECT format('ALTER %4$s TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', table_schema, table_name, constraint_name, CASE WHEN table_type='FOREIGN' THEN table_type END) AS statements
FROM checks
WHERE check_clause ~* '(btrim[(].+[)][[:space:]]*<>[[:space:]]*''''|length[(]btrim[(].+[)][)][[:space:]]*>[[:space:]]*0)'
ORDER BY table_schema, table_name, constraint_name;
Drop the constraint that is directly associated with the table.
WITH chk_constraint_names AS (select 
o.conname AS constraint_name,
(select nspname from pg_namespace where oid=t.typnamespace) as domain_schema,
t.typname as domain_name, 
pg_get_constraintdef(o.oid) AS check_clause
from pg_constraint o inner join pg_type t on t.oid = o.contypid
where o.contype = 'c' 
and t.typtype='d')
SELECT format('ALTER DOMAIN %1$I.%2$I DROP CONSTRAINT %3$I;', domain_schema, domain_name, constraint_name) AS statements
FROM chk_constraint_names
WHERE check_clause ~* '(btrim[(].+[)][[:space:]]*<>[[:space:]]*''''|length[(]btrim[(].+[)][)][[:space:]]*>[[:space:]]*0)'
ORDER BY domain_schema, domain_name;
Drop the constraint that is associated with the domain.
WITH chk_constraint_names AS (select 
o.conname AS constraint_name,
(select nspname from pg_namespace where oid=c.relnamespace) as table_schema,
c.relname as table_name, 
CASE WHEN c.relkind='r' THEN 'BASE TABLE'
ELSE 'FOREIGN' END AS table_type,
(select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as column_name,
pg_get_constraintdef(o.oid) AS check_clause,
case when o.convalidated='f' then ' NOT VALID' else '' end as is_validated
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype = 'c' and c.relkind = 'r' and cardinality(o.conkey)=1)
SELECT format('ALTER %6$s TABLE %1$I.%2$I ADD CONSTRAINT %3$I CHECK (%4$I!~''^[[:space:]]*$'')%5$s;', table_schema, table_name, constraint_name, column_name,is_validated,
CASE WHEN table_type='FOREIGN' THEN table_type END) AS statements
FROM chk_constraint_names
WHERE check_clause ~* '(btrim[(].+[)][[:space:]]*<>[[:space:]]*''''|length[(]btrim[(].+[)][)][[:space:]]*>[[:space:]]*0)'
ORDER BY table_schema, table_name;
Add the constraint that is directly associated to the table.
WITH chk_constraint_names AS (select 
o.conname AS constraint_name,
(select nspname from pg_namespace where oid=t.typnamespace) as domain_schema,
t.typname as domain_name, 
pg_get_constraintdef(o.oid) AS check_clause,
case when o.convalidated='f' then ' NOT VALID' else '' end as is_validated
from pg_constraint o inner join pg_type t on t.oid = o.contypid
where o.contype = 'c' 
and t.typtype='d')
SELECT format('ALTER DOMAIN %1$I.%2$I ADD CONSTRAINT %3$I CHECK (VALUE!~''^[[:space:]]*$'')%4$s;', domain_schema, domain_name, constraint_name, is_validated) AS statements
FROM chk_constraint_names
WHERE check_clause ~* '(btrim[(].+[)][[:space:]]*<>[[:space:]]*''''|length[(]btrim[(].+[)][)][[:space:]]*>[[:space:]]*0)'
ORDER BY domain_schema, domain_name;
Add the constraint that is associated with the domain.
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.
Validity and completenessQueries of this category provide information about whether database design represents the world (domain) correctly (validity) and whether database design captures all the information about the world (domain) that is correct and relevant (completeness).