The list of all the queries

Table inheritance (path view)

Query goal: Find in case of each base table that participates in a table inheritance hierarchy the path to the table from the top-level table. Use table inheritance carefully because, for instance, certain constraints are not inherited and must be redefined on child tables. Also make sure that the identifier of each child table in an inheritance hierarchy is a hyponym of the identifier of its parent table.
Notes about the query: The query finds transitive closure of tables. In other words it finds all possible paths between tables where it is possible to reach from one table to another based on parent-child relationships that have been established by using table inheritance.
Query type: General (Overview of some aspect of the database.)
Query license: MIT License
Data source: system catalog only
SQL query: Click on query to copy it

WITH RECURSIVE tree AS (
WITH tables_in_inheritance_hierarchy AS (SELECT pn.nspname AS parent_schema, p.oid AS parent_oid, p.relname AS parent_table, pc.nspname AS child_schema, c.oid AS child_oid, c.relname AS child_table
FROM pg_inherits pi INNER JOIN pg_class p ON pi.inhparent=p.oid
INNER JOIN pg_namespace pn ON p.relnamespace=pn.oid
INNER JOIN pg_authid AS ap ON pn.nspowner=ap.oid
INNER JOIN pg_class c ON pi.inhrelid=c.oid
INNER JOIN pg_namespace pc ON c.relnamespace=pc.oid
INNER JOIN pg_authid AS ac ON pc.nspowner=ac.oid
WHERE (pn.nspname='public' OR ap.rolname<>'postgres') 
AND (pc.nspname='public' OR ac.rolname<>'postgres'))
SELECT DISTINCT parent_oid, parent_schema || '.'|| parent_table AS table_in_inhertitance_hierarchy, ''::name AS path,  1 AS depth
FROM tables_in_inheritance_hierarchy AS tih
WHERE NOT EXISTS (SELECT 1
FROM tables_in_inheritance_hierarchy AS tih_check 
WHERE tih.parent_oid=tih_check.child_oid)
UNION ALL SELECT child_oid, child_schema || '.' || child_table AS table_in_inhertitance_hierarchy, tree.path || '/' || tih.parent_schema || '.' || tih.parent_table, tree.depth + 1
FROM tables_in_inheritance_hierarchy AS tih INNER JOIN tree ON tih.parent_oid=tree.parent_oid)
SELECT table_in_inhertitance_hierarchy, tree.path || '/' || tree.table_in_inhertitance_hierarchy AS path, depth-1 AS depth
FROM tree
WHERE depth>1
ORDER BY path;

Collections where the query belongs to

Collection nameCollection description
Find problems about base tablesA selection of queries that return information about the data types, field sizes, default values as well as general structure of base tables. Contains all the types of queries - problem detection, software measure, and general overview
Find problems by overviewQueries 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 .
Lexicon bad smells and linguistic antipatternsQueries made to find the occurrences of lexicon bad smells and linguistic antipatterns

Categories where the query belongs to

Category nameCategory description
NamingQueries of this category provide information about the style of naming.
Table inheritanceQueries of this category provide information about the inheritance between base tables.

Reference materials for further reading

Reference
https://www.postgresql.org/docs/current/tutorial-inheritance.html
https://dba.stackexchange.com/questions/157398/using-table-inheritance-instead-of-mapping-tables/157425#157425
https://stackoverflow.com/questions/3074535/when-to-use-inherited-tables-in-postgresql
Smell "No hyponymy/hypernymy in class hierarchies": Abebe, S.L., Haiduc, S., Tonella, P. and Marcus, A., 2011, September. The effect of lexicon bad smells on concept location in source code. In 2011 IEEE 11th International Working Conference on Source Code Analysis and Manipulation (pp. 125-134). IEEE.

The list of all the queries