The list of all the queries

The expression of a check constraint that is associated with a domain needs type conversion

Query goal: Find check constraints of domains where the Boolean expression invokes an operation that does not match with the data type of the domain.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Medium (Medium number of false-positive results)
Query license: MIT License
Fixing suggestion: 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: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

WITH checks AS (SELECT dc.domain_schema, dc.domain_name, d.data_type, cc.constraint_name, cc.check_clause
FROM INFORMATION_SCHEMA.domain_constraints AS dc
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 cc.check_clause NOT LIKE '%IS NOT NULL'  AND 
dc.domain_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 domain_schema, domain_name, data_type, constraint_name, check_clause 
FROM checks
WHERE (data_type !~* '^(character|text)' AND check_clause ~*'::(bpchar|character|text).*(=|>|<|~).*::(bpchar|character|text)' AND check_clause !~*'(to_date|to_timestamp)[(][^)]*::(bpchar|character|text)')
OR
(data_type ~* '^(character|text)' AND check_clause !~*'::(bpchar|character|text)' AND check_clause ~*'::')
ORDER BY domain_schema, domain_name;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
WITH checks AS (SELECT dc.domain_schema, dc.domain_name, d.data_type, cc.constraint_name, cc.check_clause
FROM INFORMATION_SCHEMA.domain_constraints AS dc
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 cc.check_clause NOT LIKE '%IS NOT NULL'  AND 
dc.domain_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;', domain_schema, domain_name, constraint_name) AS statements
FROM checks
WHERE (data_type !~* '^(character|text)' AND check_clause ~*'::(bpchar|character|text).*(=|>|<|~).*::(bpchar|character|text)' AND check_clause !~*'(to_date|to_timestamp)[(][^)]*::(bpchar|character|text)')
OR
(data_type ~* '^(character|text)' AND check_clause !~*'::(bpchar|character|text)' AND check_clause ~*'::')
ORDER BY domain_schema, domain_name;
Drop the constraint.

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.
Data typesQueries of this category provide information about the data types and their usage.
DomainsQueries of this category provide information about reusable specifications of column properties.
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).

The list of all the queries