Find columns that have a check that prevents the empty string in the column but there is already another check on the column that enforces the constraint.
Notes
The query gives false positive results if permitted symbols include whitespace characters. Thus, "Mrs Smith" is permitted but a string that consist of only spaces is not permitted.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Remove redundant constraints that are covered by other constraints.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
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)),
aggregate_checks AS (SELECT table_schema, table_name, column_name, string_agg (check_clause, '; ') AS constraints
FROM checks
GROUP BY table_schema, table_name, column_name)
SELECT table_schema, table_name, column_name, constraints
FROM aggregate_checks
WHERE ((constraints~'<>[[:space:]]+'''''
OR constraints~'[[:space:]]!~[*]{0,1}[[:space:]]''[\^][[]{2}[:]space[:][]]{2}[*+][$]'''
OR constraints~'[[:space:]]!~[*]{0,1}[[:space:]]''[\^][[]\\s[]][*+][$]''')
AND constraints~'[[:space:]]~[*]{0,1}[[:space:]]+[^~]*([+]|[{][123456789])')
ORDER BY table_schema, table_name, column_name;
Categories
This query is classified under the following categories:
Name
Description
CHECK constraints
Queries of this category provide information about CHECK constraints.
Duplication of implementation elements
Queries of this catergory provide information about the duplication of the database objects.