Find how many base tables are referenced from a base table by using foreign keys.
Notes
In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser.
Type
Sofware measure (Numeric values (software measures) about the database)
WITH fk as (select
(select nspname from pg_namespace where oid=f.relnamespace) as foreign_schema,
f.relname as foreign_table,
f.oid as foreign_table_oid,
o.confkey AS foreign_col,
(select nspname from pg_namespace where oid=c.relnamespace) as target_schema,
c.relname as target_table,
c.oid as target_table_oid,
o.conkey AS target_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_class f on f.oid = o.confrelid
where o.contype = 'f'),
fk_unnest as (select foreign_schema, foreign_table, foreign_table_oid, foreign_col, foreign_col_num, target_schema, target_table, target_table_oid, target_col, target_col_num, ordin
from fk, unnest(fk.foreign_col, fk. target_col) with ordinality as f(foreign_col_num, target_col_num, ordin)),
fk_with_names as (select foreign_schema, foreign_table, string_agg(a_foreign.attname,',' order by ordin) as foreign_col, target_schema, target_table, string_agg(a_target.attname,',' order by ordin) as target_col
from fk_unnest fk inner join pg_attribute a_foreign on fk.foreign_col_num = a_foreign.attnum and fk.foreign_table_oid = a_foreign.attrelid and a_foreign.attisdropped = false
inner join pg_attribute a_target on fk.target_col_num = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false
group by foreign_schema, foreign_table, target_schema, target_table)
select target_schema, target_table, Count(*) AS nr_of_referenced, string_agg(foreign_schema || '.' || foreign_table || '.' || foreign_col,'; ' ORDER BY foreign_schema, foreign_table) AS referenced
from fk_with_names
group by target_schema, target_table
order by Count(*) desc, target_schema, target_table;
Collections
This query belongs to the following collections:
Name
Description
Find problems by overview
Queries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems or not .
Find quick numeric overview of the database
Queries that return numeric values showing mostly the number of different types of database objects in the database
Categories
This query is classified under the following categories:
Name
Description
Comfortability of database evolution
Queries of this category provide information about the means that influence database evolution.
Relationships between tables
Queries 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.
Structure of base tables
Queries of this category provide information about the structuring of base tables at the database conceptual level