The list of all the queries

Gratuitous context in the names of non-foreign key and non-candidate key columns

Query goal: Find the names on base table columns that are not a part of a candidate key and a foreign key and that contain the name of the table. Exclude very general column names (for instance, nimi, nimetus, kommentaar, kirjeldus, name, comment, description). In case of these using the table name in the column name is not a problem because it simplifies writing the queries based on the tables. In this case one does not have to rename the columns in the query result.
Notes about the query: In the query result (b) tag is used to mark the table name within the column name. The query considers both column names in English and Estonian.
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: Rename the columns. For instance, instead of having column person_surname in the table Person use the name surname. Use a consistent style of naming.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

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
FROM INFORMATION_SCHEMA.columns AS c
WHERE column_name ILIKE '%' || table_name || '\_%' 
AND column_name NOT ILIKE table_name || '\_nimi'
AND column_name NOT ILIKE table_name || '\_nimetus'
AND column_name NOT ILIKE table_name || '\_kommentaar'
AND column_name NOT ILIKE table_name || '\_kirjeldus'
AND column_name NOT ILIKE table_name || '\_name'
AND column_name NOT ILIKE table_name || '\_comment'
AND column_name NOT ILIKE table_name || '\_description'
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
NOT 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 table_schema, table_name, column_name;

Collections where the query belongs to

Collection nameCollection description
Find problems about namesA selection of queries that return information about the names of database objects. Contains all the types of queries - problem detection, software measure, and general overview.

Categories where the query belongs to

Category nameCategory description
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.
NamingQueries of this category provide information about the style of naming.

Reference materials for further reading

Reference
The corresponding code problem in case of cleaning code is "Don’t Add Gratuitous Context". (Robert C. Martin, Clean Code)

The list of all the queries