Query goal: | Depth of referential tree of a database schema is the longest referential path between the tables in this schema (Piattini et al., 2001). In other words, it is the biggest value among the DRT(T) values of all the tables of the schema. |
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. The query assumes that these relationships have been enforced in the database by declaring foreign key (referential) constraints. The query takes into account that the path may cross the borders of schemas. Thus, it determines the longest path within the schema. |
Query type: | Sofware measure (Numeric values (software measures) about the database) |
Query license: | MIT License |
Data source: | system catalog only |
SQL query: | Click on query to copy it
WITH RECURSIVE transitive_closure AS ( WITH foo AS (SELECT o.conrelid AS child, nl.nspname AS child_table_schema, cl.relname AS child_table, o.confrelid AS parent, nf.nspname AS parent_table_schema, cf.relname AS parent_table FROM pg_constraint AS o INNER JOIN pg_class AS cl ON o.conrelid=cl.oid INNER JOIN pg_namespace AS nl ON cl.relnamespace=nl.oid INNER JOIN pg_class AS cf ON o.confrelid=cf.oid INNER JOIN pg_namespace AS nf ON cf.relnamespace=nf.oid WHERE o.contype='f') SELECT child, parent, child_table_schema, child_table, parent_table_schema, parent_table, 1 AS depth, child || '.' || parent || '.' AS path_string, child_table_schema || '.' || child_table || '/' || parent_table_schema || '.' || parent_table || '/' AS path_string_long FROM foo UNION ALL SELECT tc.child, e.parent, tc.child_table_schema, tc.child_table, e.parent_table_schema, e.parent_table, tc.depth + 1, tc.path_string || e.parent || '.' AS path_string, tc.path_string_long || e.parent_table_schema|| '.' || e.parent_table || '/' AS path_string_long FROM foo AS e INNER JOIN transitive_closure AS tc ON e.child = tc.parent WHERE tc.path_string NOT LIKE '%' || e.parent || '.%'), paths AS (SELECT child_table_schema AS table_schema, child_table, parent_table, depth, rtrim(path_string_long,'.') AS path FROM transitive_closure WHERE child_table_schema=parent_table_schema), paths_in_schema AS (SELECT table_schema, child_table, parent_table, depth, path FROM paths WHERE path~('^(' || table_schema || '[.][^/]+/)+$')) SELECT table_schema, parent_table, child_table, depth, path FROM paths_in_schema WHERE depth=(SELECT Max(depth) AS m FROM paths_in_schema AS p WHERE p.table_schema=paths_in_schema.table_schema) ORDER BY table_schema, child_table, depth, parent_table; |
Collection name | Collection description |
---|---|
Find problems about integrity constraints | A selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview |
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 |
Category name | Category description |
---|---|
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. |
Reference |
---|
Piattini, M., Calero, C., Sahraoui, H. A., & Lounis, H. (2001). Object-relational database metrics. L'Objet, 7(4), 477-496. |