WITH key_columns 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 in ('u','p')) t
inner join pg_attribute a on t.target_col = a.attnum and t.target_table_oid = a.attrelid and a.attisdropped = false),
fk_columns 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, regexp_replace(column_name, table_name, '<b>' || table_name || '</b>','g') AS column_name,
substring(column_name from '(nimi|nimetus|kirjeldus|kommentaar|selgitus|lugu|pealkiri|klass|name|comment|description|explanation|story|title|class)$') as generic_column_name
FROM INFORMATION_SCHEMA.columns AS c
WHERE column_name~*'(nimi|nimetus|kirjeldus|kommentaar|selgitus|lugu|pealkiri|klass|name|comment|description|explanation|story|title|class)$'
AND (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
EXISTS (SELECT 1 FROM key_columns AS pk WHERE pk.table_schema=c.table_schema AND pk.table_name=c.table_name AND pk.column_name=c.column_name) AND
NOT EXISTS (SELECT 1 FROM fk_columns AS fk WHERE fk.table_schema=c.table_schema AND fk.table_name=c.table_name AND fk.column_name=c.column_name)
ORDER BY generic_column_name, column_name, table_schema, table_name;