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;