The list of all the queries

Do not leave out the referential constraints (based on classifiers)

Query goal: Find non-key and non-foreign columns of base tables with a textual column and small field size in case of which there is a table with the name that is similar to the column name. Perhaps the table is a classifier table and the column should have a foreign key constraint referencing to the table.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Low (Many false-positive results)
Query license: MIT License
Fixing suggestion: Declare foreign key constraint to the column.
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),
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 table_schema, table_name, column_name || ' ' || data_type || '(' || character_maximum_length || ')' AS column_spec,

(SELECT string_agg (table_schema || '.' || table_name,';' ORDER BY table_schema, table_name) AS t
FROM base_tables AS b
WHERE c.column_name ILIKE '%' || b.table_name || '%') AS potential_referenced_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 character_maximum_length<=4
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 EXISTS (SELECT *
FROM base_tables AS b
WHERE c.column_name ILIKE '%' || b.table_name || '%'
AND NOT (
b.table_schema=c.table_schema
AND b.table_name=c.table_name))
ORDER BY table_schema, table_name, ordinal_position;

Collections where the query belongs to

Collection nameCollection description
Find problems about integrity constraintsA selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview

Categories where the query belongs to

Category nameCategory description
Classifier tablesQueries of this category provide information about registration of classifiers.
Relationships between tablesQueries of this category provide information about how database tables are connected to each other and whether such connections have been explicitly defined and whether it has been done correctly.
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