The list of all the queries

Potentially a classifier is missing (based on field sizes)

Query 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.
Query type: General (Overview of some aspect of the database.)
Query 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: Click on query to copy it

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)

SELECT table_schema, table_name, Count(*) AS nr_of_columns, 
string_agg(column_name || ' ' || data_type || '(' || character_maximum_length || ')',';<br>' ORDER BY ordinal_position) AS columns
FROM INFORMATION_SCHEMA.columns AS c
WHERE (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 data_type ~* 'char' 
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)
GROUP BY table_schema, table_name
ORDER BY table_schema, table_name;

Collections where the query belongs to

Collection nameCollection description
Find problems by overviewQueries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems or not .

Categories where the query belongs to

Category nameCategory description
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

The list of all the queries