Goal This query validates column naming conventions. It returns a row only for tables that have an inconsistent mix of column naming styles—specifically, where some columns (that are not part of a primary or foreign key) are prefixed with the table name and others are not.
Notes The query considers both column names in English and Estonian. The query lists both column names that begin with the table name and column names that do not.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion Make sure that table name is used consistently in the column names.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
WITH primary_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 ('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
),
columns AS (SELECT table_schema, table_name, column_name 
FROM INFORMATION_SCHEMA.columns AS c
WHERE (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 primary_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)),
stats AS (
SELECT Count(*) FILTER (WHERE column_name ~*  ('^' || table_name || '.{0,1}_')) AS nr_of_columns_that_start_table_name ,
string_agg(table_schema || '.' || table_name || '.' || column_name, ';
' ORDER BY table_name, column_name) FILTER (WHERE column_name ~* (table_name || '.{0,1}_')) AS columns_that_start_table_name, Count(*) FILTER (WHERE column_name !~* ('^' || table_name || '.{0,1}_')) AS nr_of_columns_that_do_not_start_table_name FROM columns) SELECT * FROM stats WHERE EXISTS (SELECT * FROM columns WHERE column_name ~* ('^' || table_name || '.{0,1}_')) AND EXISTS (SELECT * FROM columns WHERE column_name !~* ('^' || table_name || '.{0,1}_'));
Categories

This query is classified under the following categories:

NameDescription
InconsistenciesQueries of this catergory provide information about inconsistencies of solving the same problem in different places.
NamingQueries of this category provide information about the style of naming.