The list of all the queries

Incorrect use of non-deterministic functions in CHECK constraints

Query goal: Do not create a constraint in case of which data that satisfied a constraint c at the registration time suddenly does not satisfy it any more as the time goes by. Find all the check constraints that use non-deterministic functions (now, current_timestamp, localtimestamp, current_date, current_time) in a way that makes this situation possible. Fort instance, localtimestamp(0)>end_date is an example of such constraint.
Notes about the query: 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. According to the SQL standard: Certain s are identified as “retrospectively deterministic”. A retrospectively deterministic has the property that if it is True at one point time, then it is True for all later points in time if re-evaluated for the identical SQL-data by an arbitrary user with the identical set of privileges. No integrity constraint shall be defined using a that is not retrospectively deterministic.
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: Drop the constraints. Implement the checks by using triggers, user-defined routines, or in the application.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

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~* '[[:space:]]+(>|>=|=)([[:space:]]|[(])+(current_|localtimestamp|now)'
OR check_clause~* '[[:space:]]+(>|>=|=)([[:space:]]|[(])+extract[(].*(current_|localtimestamp|now)'
OR check_clause~* '(current_date|current_timestamp([(][[:digit:]][)]){0,1}|localtimestamp([(][[:digit:]][)]){0,1}|now[(][)])([[:space:]]|[)])+(<|<=|=)[[:space:]]+'
OR check_clause~* 'extract[(].*(current_date|current_timestamp([(][[:digit:]][)]){0,1}|localtimestamp([(][[:digit:]][)]){0,1}|now[(][)])([[:space:]]|[)])+(<|<=|=)[[:space:]]+'
ORDER BY table_schema, table_name, column_name;

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

SQL queryDescription
WITH checks AS (SELECT ccu.table_schema, ccu.table_name, t.table_type, 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)
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 DISTINCT 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~* '[[:space:]]+(>|>=|=)([[:space:]]|[(])+(current_|localtimestamp|now)'
OR check_clause~* '[[:space:]]+(>|>=|=)([[:space:]]|[(])+extract[(].*(current_|localtimestamp|now)'
OR check_clause~* '(current_date|current_timestamp([(][[:digit:]][)]){0,1}|localtimestamp([(][[:digit:]][)]){0,1}|now[(][)])([[:space:]]|[)])+(<|<=|=)[[:space:]]+'
OR check_clause~* 'extract[(].*(current_date|current_timestamp([(][[:digit:]][)]){0,1}|localtimestamp([(][[:digit:]][)]){0,1}|now[(][)])([[:space:]]|[)])+(<|<=|=)[[:space:]]+'
ORDER BY statements;
Drop the constraint that is associated directly with the table.
WITH checks AS (SELECT cdu.domain_schema, cdu.domain_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_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 format('ALTER DOMAIN %1$I.%2$I DROP CONSTRAINT %3$I;', domain_schema, domain_name, constraint_name) AS statements
FROM checks
WHERE check_clause~* '[[:space:]]+(>|>=|=)([[:space:]]|[(])+(current_|localtimestamp|now)'
OR check_clause~* '[[:space:]]+(>|>=|=)([[:space:]]|[(])+extract[(].*(current_|localtimestamp|now)'
OR check_clause~* '(current_date|current_timestamp([(][[:digit:]][)]){0,1}|localtimestamp([(][[:digit:]][)]){0,1}|now[(][)])([[:space:]]|[)])+(<|<=|=)[[:space:]]+'
OR check_clause~* 'extract[(].*(current_date|current_timestamp([(][[:digit:]][)]){0,1}|localtimestamp([(][[:digit:]][)]){0,1}|now[(][)])([[:space:]]|[)])+(<|<=|=)[[:space:]]+'
ORDER BY domain_schema, domain_name, constraint_name;
Drop the constraint that is associated with the domain.

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.
System-defined functionsQueries of this category provide information about the use of system-defined functions.
Temporal dataQueries of this category provide information about temporal (time-related) data that is kept in the database.
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