The list of all the queries

The name of the base table that implements a binary relationship type does not explain the meaning of the relationship

Query goal: Find base tables that implement a binary relationship type (have two foreign keys) and the name of the table consist of the names of tables that this (intermediate) table connect. The names should be derived from the domain. For instance, instead of name Course_Lecturer it is better to have name Teaching.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Low (Many false-positive results)
Query license: MIT License
Fixing suggestion: Rename the table. Use a domain concept in the name.
Data source: system catalog only
SQL query: Click on query to copy it

with two_fk as (select c.relnamespace as target_schema_oid, c.oid as target_table_oid
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype = 'f' 
group by target_schema_oid, target_table_oid
having count(*)=2),
fk as (select 
(select nspname from pg_namespace where oid=f.relnamespace) as foreign_schema,
f.relname as foreign_table,
(select nspname from pg_namespace where oid=c.relnamespace) as target_schema,
c.relname as target_table
from pg_constraint o inner join pg_class f on f.oid = o.confrelid
inner join pg_class c on c.oid = o.conrelid
where o.contype = 'f'  and
(c.relnamespace, c.oid) in (select target_schema_oid, target_table_oid from two_fk)),
fk_with_names as (select fk1.foreign_schema as foreign_schema1, fk1.foreign_table as foreign_table1, 
fk2.foreign_schema as foreign_schema2, fk2.foreign_table as foreign_table2, 
fk1.target_schema, fk1.target_table
from fk as fk1, fk as fk2
where fk1.target_schema=fk2.target_schema and fk1.target_table=fk2.target_table and fk1.foreign_table>fk2.foreign_table)
select foreign_schema1, foreign_table1, foreign_schema2, foreign_table2,  target_schema, target_table as suspected_table_name
from fk_with_names
where target_table ILIKE foreign_table1 || '%' || foreign_table2 or 
target_table ILIKE foreign_table2 || '%' || foreign_table1
order by target_schema, target_table;

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.
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 where the query belongs to

Category nameCategory description
NamingQueries of this category provide information about the style of naming.
Relationships between tablesQueries of this category provide information about how database tables are connected to each other and whether such connections have been explicitly defined and whether it has been done correctly.

Reference materials for further reading

Reference
https://www.sqlstyle.guide/

The list of all the queries