The list of all the queries

CHECK constraints that perhaps incorrectly consider 'infinity' and '-infinity' special values

Query goal: Such special values belong to the types DATE, TIMESTAMP, NUMERIC, REAL, and DOUBLE PRECISION. No value can be bigger than infinity or smaller than -infinity. If the check constraint cheks that a value must be bigger than -infinity or smaller than infinity, then it does not restrict (almost) anything.
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: Change the Boolean expression of the CHECK constraint if needed.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

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)),
inf_domains AS (
SELECT table_schema, table_name, column_name, data_type, check_clause
FROM domains
WHERE data_type IN ('date','timestamp with time zone','timestamp without time zone','numeric','real','double precision')),
inf_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 type_name,
pg_get_constraintdef(o.oid) 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 ('date', 'timestamp', 'timestamptz', 'numeric', 'float4', 'float8')
UNION SELECT table_schema, table_name, column_name, data_type, check_clause
FROM inf_domains)
SELECT DISTINCT table_schema, table_name, column_name, type_name, check_clause
FROM inf_simple_chk
WHERE check_clause~*'(<=|<|>|>=)[[:space:]]''(-){0,1}infinity'
OR check_clause~*'(-){0,1}infinity''::([[:space:]]|[[:alpha:]])+(<=|<|>|>=)'
ORDER BY table_schema, table_name, column_name;

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.

Reference materials for further reading

Reference
https://www.postgresql.org/docs/15/datatype-datetime.html#DATATYPE-DATETIME-SPECIAL-VALUES

The list of all the queries