Goal This query identifies potentially flawed CHECK constraints on columns of type timestamp or a timestamp range (e.g., tstzrange, daterange). It targets range checks where the upper bound of the value or the range is defined using an inclusive operator (<=). This is a common source of bugs, as a condition like column <= '2025-12-31' or UPPER(column) <= '2025-12-31' is interpreted as being up to 00:00:00 on that day, inadvertently excluding the entire last day of the intended period. The more robust pattern is to use an exclusive upper bound, such as column < '2026-01-01'.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Low (Many false-positive results)
License MIT License
Fixing Suggestion For instance, if one has to check that values in the column reg_time are between years 2010 and 2100, then one should have

CHECK (reg_time>='2010-01-01' AND reg_time<'2101-01-01')

instead of checks like


  • CHECK (reg_time>='2010-01-01' AND reg_time<='2100-12-31')
  • CHECK (reg_time>='2010-01-01' AND reg_time<='2100-12-31 23:59:59')
  • CHECK (reg_time BETWEEN '2010-01-01' AND '2100-12-31 23:59:59')


These checks would omit some moments from the permitted range.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH domains AS (
SELECT cdu.table_schema, cdu.table_name, cdu.column_name, (SELECT data_type FROM INFORMATION_SCHEMA.domains AS d
WHERE d.domain_schema=dc.domain_schema AND d.domain_name=dc.domain_name) AS data_type, cc.check_clause
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)),

temp_domains AS (SELECT table_schema, table_name, column_name, data_type, check_clause
FROM domains
WHERE data_type IN ('timestamp with time zone','timestamp without time zone','tsrange','tstzrange')),

temp_simple_chk AS (SELECT 
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS table_schema,
c.relname as table_name, 
a.attname AS column_name,
t.typname AS data_type,
regexp_replace(pg_get_constraintdef(o.oid),'^CHECK ','','i') AS check_clause
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
INNER JOIN pg_attribute a ON a.attrelid = c.oid AND a.attnum = o.conkey[1] AND a.attisdropped = FALSE
INNER JOIN pg_type t ON a.atttypid=t.oid
WHERE cardinality(o.conkey)=1 AND o.contype = 'c' AND t.typname IN ('timestamp', 'timestamptz','tsrange','tstzrange')
UNION SELECT table_schema, table_name, column_name, data_type, check_clause
FROM temp_domains)

SELECT table_schema, table_name, column_name, data_type, check_clause
FROM temp_simple_chk
WHERE  check_clause~*'([[:space:]]between[[:space:]].+[[:space:]]and|[[:space:]]>=[[:space:]].+[[:space:]]and[[:space:]].+<=)'
ORDER BY table_schema, table_name, column_name;

Collections

This query belongs to the following collections:

NameDescription
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

This query is classified under the following categories:

NameDescription
CHECK constraintsQueries of this category provide information about CHECK constraints.
Temporal dataQueries of this category provide information about temporal (time-related) data that is kept in the database.