Goal This query identifies junction tables with semantically redundant names, specifically targeting those whose names contain the word "join". The structure of a many-to-many table (typically two foreign keys forming a composite primary key) is inherently declarative of its role as a join mechanism. Including the word "join" in the name is superfluous and violates the principle of naming based on the entity or relationship being modeled, not the implementation detail.
Notes The query considers both column names in English and Estonian.
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 For the tables identified by the query, the recommended action is to rename them to better align with conceptual modeling principles. The preferred approach is to select a name that represents the business relationship or entity being modeled. For instance, a table linking users and roles should be named user_role or role_assignment. If a suitable conceptual name is not readily apparent, a fallback solution is to simply remove the superfluous word "join" from the current name.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
with keys as (select 
(select nspname from pg_namespace where oid=c.relnamespace) as key_schema,
c.relname as key_table, 
c.oid as key_table_oid,
o.conkey AS key_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype in ('u', 'p') and cardinality(o.conkey)=1),
keys_unnest as (select 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
),
fk as (select 
(select nspname from pg_namespace where oid=c.relnamespace) as key_schema,
c.relname as key_table, 
c.oid as key_table_oid,
o.conkey AS key_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype='f'),
fk_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
from fk, unnest(fk.key_col) with ordinality as k(key_col_num, ordin)),
fk_with_names AS (select key_schema AS table_schema, key_table AS table_name, a_key.attname AS column_name
from fk_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),
key_not_fk AS (select table_schema, table_name, column_name
from keys_with_names
except select table_schema, table_name, column_name
from fk_with_names),
surrogate_key AS (SELECT c.table_schema, c.table_name , c.column_name
FROM information_schema.columns c
LEFT JOIN information_schema.domains d USING (domain_schema, domain_name)
INNER JOIN information_schema.schemata s
ON c.table_schema=s.schema_name
WHERE  (coalesce (c.column_default, d.domain_default) ILIKE '%nextval%'  OR c.is_identity='YES')
AND c.data_type IN ('smallint','integer','bigint')
AND (c.table_schema = 'public'
OR s.schema_owner<>'postgres')
AND EXISTS (SELECT *
FROM key_not_fk AS k
WHERE k.table_schema=c.table_schema
AND k.table_name=c.table_name
AND k.column_name=c.column_name)),
allowed_cols AS (SELECT table_schema, table_name, column_name
FROM surrogate_key
UNION SELECT table_schema, table_name, column_name
FROM fk_with_names),
allowed_cols_grouped AS (SELECT table_schema, table_name, string_agg(column_name, ',' ORDER BY column_name) AS columns
FROM allowed_cols
GROUP BY table_schema, table_name),
at_least_two_fk as (select n.nspname as table_schema, c.relname as table_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_namespace as n on n.oid=c.relnamespace
where o.contype = 'f'
group by n.nspname, c.relname
having count(*)>1),
potential_tables AS (SELECT table_schema, table_name, string_agg(column_name, ',' ORDER BY column_name) AS columns
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 (table_schema, table_name) IN (SELECT table_schema, table_name
FROM  at_least_two_fk)
GROUP BY table_schema, table_name)
SELECT potential_tables.* , EXISTS (SELECT * FROM INFORMATION_SCHEMA.table_constraints AS tc
WHERE tc.table_schema=potential_tables.table_schema 
AND tc.table_name=potential_tables.table_name
AND tc.constraint_type IN ('PRIMARY KEY','UNIQUE')) AS has_key 
FROM potential_tables INNER JOIN allowed_cols_grouped USING (table_schema, table_name, columns)
WHERE table_name~*'(join|seo)'
ORDER BY table_schema, table_name;

Collections

This query belongs to the following collections:

NameDescription
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

This query is classified under the following categories:

NameDescription
NamingQueries of this category provide information about the style of naming.