The list of all the queries

Perhaps the type of a base table column/domain should be VARCHAR (based on column names)

Query goal: Find base table columns that have CHAR type, where character maximum length is bigger than 1 and the name of the column does not refer to the possibility that the column holds some kind of codes or flags or hash values.
Notes about the query: The query takes into account both column names in Estonian and English.
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 column type to VARCHAR.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

SELECT table_schema, table_name, column_name,  character_maximum_length
FROM INFORMATION_SCHEMA.columns
WHERE data_type='character' 
AND character_maximum_length>1 
AND column_name !~*'(kood|code|flag|key|type|tyyp|state|status|seisund|olek|curr|currency|country|lang|keel|riik|parool|passw|hash|(?<!(tel|telef|telefoni|phone)[_]{0,1})number)'
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)
ORDER BY table_schema, table_name, ordinal_position;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
SELECT format('ALTER TABLE  %1$I.%2$I ALTER COLUMN %3$I SET DATA TYPE VARCHAR(%4$s);', table_schema, table_name, column_name,  character_maximum_length) AS statements
FROM INFORMATION_SCHEMA.columns
WHERE data_type='character' 
AND character_maximum_length>1 
AND column_name !~*'(kood|code|flag|key|type|tyyp|state|status|seisund|olek|curr|currency|country|lang|keel|riik|parool|passw|hash|(?<!(tel|telef|telefoni|phone)[_]{0,1})number)'
AND domain_name IS NULL
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)
ORDER BY table_schema, table_name, ordinal_position;
Change the column type in case the column has not been defined by using a domain.

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
Data typesQueries of this category provide information about the data types and their usage.
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