The list of all the queries

Perhaps the type of a base table column/domain should be numeric (based on default values)

Query goal: Specify for each column/domain a right data type that takes into account expected values in the column/domain. Find base table columns and domains that have a textual type but the default value that represents a number (for instance, '100', '2', or '0.22'). Exclude columns about formats.
Notes about the query: The query considers both column names in English and Estonian. 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: Medium (Medium number of false-positive results)
Query license: MIT License
Fixing suggestion: Change the data type of the column/domain. If the default value represents an integer value (for instance, 100), then change the type to SMALLINT, INTEGER, or BIGINT. If the default value represents a fixed-point value (for instance, '0.22'), then change the type to DECIMAL/NUMERIC.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

WITH columns AS (SELECT A.table_schema AS schema, A.table_name, A.column_name AS object, A.data_type, a.column_default AS default_value, 'COLUMN' AS object_type
FROM information_schema.columns A INNER JOIN information_schema.schemata S ON A.table_schema=S.schema_name
WHERE A.data_type IN ('character varying','text','character') 
AND A.column_default~*'^''([-]{0,1}[1-9][[:digit:]]*|[-]{0,1}[[:digit:]]+[.][[:digit:]]+)''::'
AND A.column_name!~*'(format|formaat)'
AND (A.table_schema = 'public'
OR S.schema_owner<>'postgres')
AND (table_schema, table_name) IN (SELECT table_schema, table_name
FROM information_schema.tables
WHERE table_type='BASE TABLE')),
domains AS (SELECT D.domain_schema AS schema, NULL AS table_name, D.domain_name AS object, D.data_type, D.domain_default AS default_value, 'DOMAIN' AS object_type
FROM information_schema.domains D INNER JOIN information_schema.schemata S ON D.domain_schema=S.schema_name
WHERE D.data_type IN ('character varying','text','character')
AND D.domain_name!~*'(format|formaat)' 
AND D.domain_default~*'^''([-]{0,1}[1-9][[:digit:]]*|[-]{0,1}[[:digit:]]+[.][[:digit:]]+)''::'
AND (D.domain_schema = 'public'
OR S.schema_owner<>'postgres'))
SELECT schema, table_name, object, object_type, data_type, default_value
FROM columns
UNION SELECT schema, table_name, object, object_type, data_type, default_value
FROM domains
ORDER BY schema, object_type, object;

Collections where the query belongs to

Collection nameCollection description
Find problems about base tablesA selection of queries that return information about the data types, field sizes, default values as well as general structure of base tables. Contains all the types of queries - problem detection, software measure, and general overview
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
Comfortability of database evolutionQueries of this category provide information about the means that influence database evolution.
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.
DomainsQueries of this category provide information about reusable specifications of column properties.
Result quality depends on namesQueries of this category use names (for instance, column names) to try to guess the meaning of a database object. Thus, the goodness of names determines the number of false positive and false negative results.
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