Goal Find columns with a timestamp or a time type where the precision (the permitted maximum number of fractional sections) is bigger than the precision in the default value of the column.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion Change the column definition so that the precision of the column corresponds to the precision of the default value. By default the precision is 6.
Data Source INFORMATION_SCHEMA only
SQL Query
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~*'time' 
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~*'(local|current)')
SELECT table_schema, table_type, table_name, column_name, data_type, datetime_precision, def, def_precision
FROM Precisions
WHERE datetime_precision>def_precision
ORDER BY table_type, table_schema, table_name, column_name;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
WITH temp_col AS (SELECT c.table_schema, c.table_name, c.column_name, c.data_type, c.column_default AS def, c.datetime_precision
FROM INFORMATION_SCHEMA.columns AS c INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name)
WHERE c.data_type~*'time' 
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)
AND t.table_type='BASE TABLE'
AND c.domain_name IS NULL),
precisions AS (SELECT table_schema, 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~*'(local|current)')
SELECT format('ALTER TABLE %1$I.%2$I ALTER COLUMN %3$I SET DATA TYPE %4$s(%5$s);', table_schema, table_name , column_name, 
CASE WHEN data_type='timestamp without time zone' THEN 'timestamp' 
WHEN data_type='timestamp with time zone' THEN 'timestamptz' 
WHEN data_type='time without time zone' THEN 'time' 
WHEN data_type='time with time zone' THEN 'timetz' END, 
def_precision) AS statements
FROM Precisions
WHERE datetime_precision>def_precision
ORDER BY table_schema, table_name, column_name;
Change the data type of base table column that is not defined based on a domain.
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
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).