The list of all the queries

Cannot accommodate all the fractional seconds in case of table columns

Query goal: The precision of a timestamp type of a column must be able to accommodate all the fractional seconds of the default value of the column. Find table columns with the type timestamp without time zone(m) or timestamp with time zone(m) that have a default value LOCALTIMESTAMP(n) or CURRENT_TIMESTAMP(n) WHERE n>m.
Notes about the query: The query finds default values that are associated directly with a base table column as well as default values that are specified through a domain. The query does not find default values of domains that are not associated with any table.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: High (Few or no false-positive results)
Query license: MIT License
Fixing suggestion: Increase the precision of values that the column could accommodate or decrease the precision of the default value.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

WITH temp_col AS (SELECT c.table_schema, t.table_type, c.table_name, c.column_name, c.data_type, coalesce(column_default, domain_default) AS def, c.datetime_precision
FROM INFORMATION_SCHEMA.columns AS c LEFT JOIN INFORMATION_SCHEMA.domains AS d
ON c.domain_schema=d.domain_schema AND c.domain_name=d.domain_name
INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name)
WHERE c.data_type IN ('timestamp without time zone', 'timestamp with time zone') 
AND 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)),
precisions AS (SELECT table_schema, table_type, table_name, column_name, data_type, datetime_precision, def, (CASE WHEN regexp_replace(def, '[^0-9]', E'', 'g')='' THEN '6' ELSE regexp_replace(def, '[^0-9]', E'', 'g') END)::INT AS def_precision
FROM temp_col
WHERE def ILIKE 'LOCALTIMESTAMP%' OR def LIKE 'CURRENT_TIMESTAMP%')
SELECT table_schema, table_type, table_name, column_name, data_type, datetime_precision, def, def_precision
FROM Precisions
WHERE def_precision>datetime_precision
ORDER BY table_type, 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
Data typesQueries of this category provide information about the data types and their usage.
Default valueQueries of this catergory provide information about the use of default values.
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