Goal Find columns that are not covered by a primary key, unique, and foreign key constraint but have a textual type with the maximum field size 3 or less and where the column name does not refer to names or comments. Return only data about these columns where there is no table with a similar name. Return data only about tables that could be referenced from more than one table.
Notes The query considers both column names in English and Estonian.
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 Perhaps there should be a classifier table that is used to register permitted values in this column + a foreign key constraint.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH keys as (select 
o.conname,
(select nspname from pg_namespace where oid=m.relnamespace) as key_schema,
m.relname as key_table, 
m.oid as key_table_oid,
o.conkey AS key_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_class m on m.oid = o.conrelid
where o.contype in ('u','p', 'f')  and o.conrelid in (select oid from pg_class c where c.relkind = 'r')),
keys_unnest as (select conname, key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
from keys, unnest(keys.key_col) with ordinality as k(key_col_num, ordin)),
keys_with_names as (select key_schema as table_schema, key_table as table_name, a_key.attname as column_name
from keys_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false),
base_tables AS (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))

SELECT column_name || ' ' || data_type || '(' || character_maximum_length || ')' AS column_spec, Count(*) AS nr_of_occurrences, string_agg(table_schema || '.' || table_name,';
' ORDER BY table_schema, table_name) AS tables FROM INFORMATION_SCHEMA.columns AS c WHERE (table_schema, table_name) IN (SELECT table_schema, table_name FROM base_tables) AND data_type ~* 'char' AND column_name!~'(comment|description|name|kommentaar|kirjeldus|nimi)' AND character_maximum_length<=3 AND NOT EXISTS (SELECT * FROM keys_with_names AS kwn WHERE kwn.table_schema=c.table_schema AND kwn.table_name=c.table_name AND kwn.column_name=c.column_name) AND NOT EXISTS (SELECT * FROM base_tables AS b WHERE c.column_name ILIKE '%' || b.table_name || '%') GROUP BY column_spec HAVING Count(*)>1 ORDER BY Count(*) DESC, column_spec;
Collections

This query belongs to the following collections:

NameDescription
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

This query is classified under the following categories:

NameDescription
Classifier tablesQueries of this category provide information about registration of classifiers.
Field sizeQueries of this category provide information about the maximum size of values that can be recorded in column fields
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).