Perhaps the Boolean expression is incorrect. For instance, in case of price domain CHECK(VALUE::text<>''). In this case drop the constraint and think through what you have to check, whether the check is implemented already with the selection of data type, and if not then what would be a correct Boolean expression. It could also be that the data type of the domain is incorrect and has to be changed.
Data Source
system catalog only
SQL Query
WITH domain_checks AS (SELECT
ns.nspname AS domain_schema,
t.typname AS domain_name,
basetype.typname AS data_type,
c.conname AS constraint_name,
pg_get_constraintdef(c.oid) AS check_clause
FROM pg_constraint c
INNER JOIN pg_type t ON c.contypid = t.oid
INNER JOIN pg_namespace ns ON t.typnamespace = ns.oid
INNER JOIN pg_type basetype ON t.typbasetype = basetype.oid
WHERE
c.contype = 'c'
AND c.contypid <> 0
AND pg_get_constraintdef(c.oid) <> 'CHECK ((VALUE IS NOT NULL))')
SELECT domain_schema, domain_name, data_type, constraint_name, check_clause
FROM domain_checks
WHERE (data_type !~* '(char|text)'
AND check_clause ~*'::(bpchar|char|text).*(=|>|<|~).*::(bpchar|char|text)'
AND check_clause !~*'(to_date|to_timestamp)[(][^)]*::(bpchar|character|text)'
AND check_clause !~*'AT[[:space:]]+TIME[[:space:]]+ZONE[[:space:]]+\''Europe/Tallinn\''::text')
OR
(data_type ~* '(char|text)'
AND check_clause !~*'::(bpchar|char|text)'
AND check_clause ~*'::')
ORDER BY domain_schema, domain_name;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
WITH domain_checks AS (SELECT
ns.nspname AS domain_schema,
t.typname AS domain_name,
basetype.typname AS data_type,
c.conname AS constraint_name,
pg_get_constraintdef(c.oid) AS check_clause
FROM pg_constraint c
INNER JOIN pg_type t ON c.contypid = t.oid
INNER JOIN pg_namespace ns ON t.typnamespace = ns.oid
INNER JOIN pg_type basetype ON t.typbasetype = basetype.oid
WHERE
c.contype = 'c'
AND c.contypid <> 0
AND pg_get_constraintdef(c.oid) <> 'CHECK ((VALUE IS NOT NULL))')
SELECT format('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', domain_schema, domain_name, constraint_name) AS statements
FROM domain_checks
WHERE (data_type !~* '(char|text)'
AND check_clause ~*'::(bpchar|char|text).*(=|>|<|~).*::(bpchar|char|text)'
AND check_clause !~*'(to_date|to_timestamp)[(][^)]*::(bpchar|character|text)'
AND check_clause !~*'AT[[:space:]]+TIME[[:space:]]+ZONE[[:space:]]+\''Europe/Tallinn\''::text')
OR
(data_type ~* '(char|text)'
AND check_clause !~*'::(bpchar|char|text)'
AND check_clause ~*'::')
ORDER BY domain_schema, domain_name;
Drop the constraint.
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.
Data types
Queries of this category provide information about the data types and their usage.
Domains
Queries of this category provide information about reusable specifications of column properties.
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).