Goal Find base table columns that have type NUMERIC and the scale is 0, i.e., one can record in the column only integer values. Arithmetic operations are slower in case of the numeric type compared to an integer type. Thus, in order to record integer values, one should use columns with the type SMALLINT, INTEGER, or BIGINT instead of NUMERIC(p,0).
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability High (Few or no false-positive results)
License MIT License
Fixing Suggestion Change the data type to SMALLINT, INTEGER, or BIGINT. If the column has been defined based on a domain, then change the underlying type of domain. In case changing the type of a domain one has to drop and recreate the domain and associate the recreated domain again with all the columns with which it was previously associated.
Data Source INFORMATION_SCHEMA only
SQL Query
SELECT table_schema, table_name, column_name, data_type, numeric_precision, numeric_scale, CASE WHEN numeric_precision<5 THEN 'SMALLINT' WHEN numeric_precision BETWEEN 5 AND 9 THEN 'INTEGER' ELSE 'BIGINT' END AS suggested_type
FROM INFORMATION_SCHEMA.columns
WHERE data_type IN ('decimal', 'numeric') 
AND (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') 
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 (numeric_scale=0)
ORDER BY table_schema, table_name, ordinal_position;

SQL statements that help generate fixes for the identified problem.

SQL Query to Generate FixDescription
SELECT format('ALTER TABLE %1$I.%2$I ALTER COLUMN %3$I SET DATA TYPE %4$s;', table_schema, table_name, column_name, CASE WHEN numeric_precision<5 THEN 'SMALLINT' WHEN numeric_precision BETWEEN 5 AND 9 THEN 'INTEGER' ELSE 'BIGINT' END) AS statements
FROM INFORMATION_SCHEMA.columns
WHERE data_type IN ('decimal', 'numeric') 
AND (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') 
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 (numeric_scale=0)
AND domain_name IS NULL
ORDER BY table_schema, table_name, ordinal_position;
Change type of the column if the column 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.
PerformanceQueries of this category provide information about indexes in a database.