The list of all the queries

Perhaps an unsuitable use of CHAR(n) type in base tables

Query goal: Find non-foreign key base table columns with the type CHAR(n) where n>1 that are not meant for storing codes or hash values. CHAR(n) is suitable for storing values that have a fixed length (for instance, country code according to the ISO standard). In case of variable length strings the end of the stored string is padded with spaces. Thus, for instance, do not use CHAR(n) in case of columns for storing names, comments, descriptions, e-mail addresses etc. Hash values have a fixed length that depends on the used hash function.
Notes about the query: The query considers both column names in English and Estonian.
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(n).
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH fk_cols AS (select target_schema as table_schema, target_table as table_name, a.attname as column_name
from (select 
(select nspname from pg_namespace where oid=c.relnamespace) as target_schema,
c.relname as target_table, 
c.oid as target_table_oid,
unnest(o.conkey) AS target_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype = 'f' ) t
inner join pg_attribute a on t.target_col = a.attnum and t.target_table_oid = a.attrelid and a.attisdropped = false)
SELECT table_schema, table_name, column_name, data_type, character_maximum_length
FROM INFORMATION_SCHEMA.columns AS c
WHERE (data_type='character') 
AND character_maximum_length>1 
AND (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') 
AND column_name !~*'(kood|code|flag|key|type|tyyp|state|seisund|olek|curr|currency|country|keel|riik|parool|passw|hash|(?<!(tel|telef|telefoni|phone)[_]{0,1})number)' 
AND column_name !~*'_id$' 
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 NOT EXISTS (SELECT 1 FROM fk_cols
WHERE fk_cols.table_schema=c.table_schema AND fk_cols.table_name=c.table_name AND fk_cols.column_name=c.column_name)
ORDER BY table_schema, table_name, ordinal_position;

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.
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