The list of all the queries

One true lookup table

Query goal: Find tables that contain all (or most) of the classifier values and tables that refer to these.
Notes about the query: The query finds tables that name contains word classifier or lookup and there must be more than one foreign key constraints in other tables that refer to the table. The query uses PostgreSQL system catalog tables not information_schema views in order to give precise answer even if foreign key constraints in different tables have the same name. In SQL a foreign key is an ordered set of columns that must contain at least one column. The query result preserves the order of columns in the key. In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser.
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: Create a separate classifier (lookup) table for each classifier type.
Data source: system catalog only
SQL query: Click on query to copy it

WITH fk as (select
o.conname,
(select nspname from pg_namespace where oid=f.relnamespace) as foreign_schema,
f.relname as foreign_table,
f.oid as foreign_table_oid,
o.confkey AS foreign_col,
(select nspname from pg_namespace where oid=c.relnamespace) as target_schema,
c.relname as target_table,
c.oid as target_table_oid,
o.conkey AS target_col,
CASE WHEN o.confupdtype='a' THEN 'NO ACTION'
WHEN o.confupdtype='r' THEN 'RESTRICT'
WHEN o.confupdtype='c' THEN 'CASCADE'
WHEN o.confupdtype='n' THEN 'SET NULL'
WHEN o.confupdtype='d' THEN 'SET DEFAULT' END AS on_update,
CASE WHEN o.confdeltype='a' THEN 'NO ACTION'
WHEN o.confdeltype='r' THEN 'RESTRICT'
WHEN o.confdeltype='c' THEN 'CASCADE'
WHEN o.confdeltype='n' THEN 'SET NULL'
WHEN o.confdeltype='d' THEN 'SET DEFAULT' END AS on_delete
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_class f on f.oid = o.confrelid
where o.contype = 'f'),
fk_unnest as (select conname, foreign_schema, foreign_table,  foreign_table_oid, foreign_col, foreign_col_num, target_schema, target_table, target_table_oid, target_col, target_col_num, ordin, on_update, on_delete
from fk, unnest(fk.foreign_col, fk. target_col) with ordinality as f(foreign_col_num, target_col_num, ordin)),
fk_with_names as (select conname, foreign_schema, foreign_table, string_agg(a_foreign.attname, ', ' order by ordin) as foreign_col, target_schema, target_table, string_agg(a_target.attname, ', ' order by ordin) as target_col, on_update, on_delete
from fk_unnest fk inner join pg_attribute a_foreign on fk.foreign_col_num = a_foreign.attnum and fk.foreign_table_oid = a_foreign.attrelid and a_foreign.attisdropped = false
inner join pg_attribute a_target on fk.target_col_num = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false
group by conname, foreign_schema, foreign_table, target_schema, target_table,on_update, on_delete),
classifiers as (select conname, foreign_schema, foreign_table, foreign_col, target_schema, target_table, target_col, on_update, on_delete
from fk_with_names
where foreign_table~*'(klassifikaator|classifier|lookup)' and foreign_schema || '.' || foreign_table<>target_schema || '.' || target_table)
select foreign_schema as classifier_schema, foreign_table as classifier_table, foreign_col as classifier_key, string_agg(target_schema || '.' || target_table || '.(' || target_col || ') ON UPDATE ' || on_update || ' ON DELETE ' || on_delete,';<br>' order by target_schema, target_table) as referencing_tables, Count(*) AS number_of_referencing_tables
from classifiers
group by foreign_schema, foreign_table, foreign_col
having count(*)>1
order by count(*) DESC, foreign_schema, foreign_table;

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
Classifier tablesQueries of this category provide information about registration of classifiers.
Comfortability of database evolutionQueries of this category provide information about the means that influence database evolution.
Comfortability of data managementQueries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient.
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.

Reference materials for further reading

Reference
https://www.red-gate.com/simple-talk/sql/t-sql-programming/look-up-tables-in-sql-/ Section "One True look-up Table" is dedicated to the single Classifier table
The first mistake from here: https://www.red-gate.com/simple-talk/sql/database-administration/five-simple-database-design-errors-you-should-avoid/
https://www.itprotoday.com/sql-server/designing-performance-lookup-tables
https://www.apress.com/us/blog/all-blog-posts/best-practices-for-using-simple-lookup-tables/13323426
https://www.sqlservercentral.com/articles/lookup-table-madness
https://www.sqlservercentral.com/articles/a-lookup-strategy-defined

The list of all the queries