Find CHECK constraints that refer only to mandatory columns but the Boolean expression has IS NULL condition.
Notes
The query considers CHECK constraints that are associated with a column directly as well as through a domain. The query considers check constraints that involve multiple columns.
Type
Problem detection (Each row in the result could represent a flaw in the design)
WITH table_checks AS (SELECT ccu.table_schema, ccu.table_name, ccu.column_name, cc.check_clause, cc.constraint_name
FROM INFORMATION_SCHEMA.constraint_column_usage AS ccu INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc
USING (constraint_schema, constraint_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, cdu.column_name, cc.check_clause, cc.constraint_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 table_schema, table_name, check_clause, constraint_name
FROM table_checks INNER JOIN information_schema.columns USING (table_schema, table_name, column_name)
WHERE check_clause~*'IS[[:space:]]*NULL'
GROUP BY table_schema, table_name, check_clause, constraint_name
HAVING Count(*) FILTER (WHERE is_nullable='NO')=Count(*)
ORDER BY table_schema, table_name, constraint_name;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
WITH table_checks AS (SELECT ccu.table_schema, ccu.table_name, ccu.column_name, cc.check_clause, cc.constraint_name
FROM INFORMATION_SCHEMA.constraint_column_usage AS ccu INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc
USING (constraint_schema, constraint_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 TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', table_schema, table_name, constraint_name) AS statements
FROM table_checks INNER JOIN information_schema.columns USING (table_schema, table_name, column_name)
WHERE check_clause~*'IS[[:space:]]*NULL'
GROUP BY table_schema, table_name, check_clause, constraint_name
HAVING Count(*) FILTER (WHERE is_nullable='NO')=Count(*)
ORDER BY table_schema, table_name, constraint_name;
Drop the constraint of the base table
Collections
This query belongs to the following collections:
Name
Description
Find problems automatically
Queries, 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:
Name
Description
CHECK constraints
Queries of this category provide information about CHECK constraints.
Missing data
Queries of this category provide information about missing data (NULLs) in a database.
Validity and completeness
Queries 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).