The Hierarchical clause sets the conditions for recursive queries on a table object in which a hierarchy of parent-child dependencies exists among the rows. SELECT statements that include this clause are called hierarchical queries.
The table object on which the hierarchical query operates must be specified in the FROM clause of the SELECT statement. The table object is typically a self-referencing table in which one or more columns acts as a foreign key constraint for another column (or for a subset of the columns) in the same table.
A hierarchical query operates on rows in which one or more column values correspond to nodes within a logical structure of parent-child relationships. If parent rows have multiple children, sibling relationships exist among child rows of the same parent. These relationships might reflect, for example, the reporting structure among employees and managers within the divisions and management levels of an organization.
You cah read more at Hierarchical Clause
1 Example of a Hierarchical Data Set
The gantt
table in the following example is a simple data model to
store hierachical information.
CREATE TABLE gantt ( ID INTEGER NOT NULL, parentID INTEGER, orderID INTEGER NOT NULL, priority CHAR(1) NOT NULL, taskname VARCHAR(25), leader VARCHAR(20), start DATE NOT NULL, end DATE NOT NULL, completed DECIMAL(5,2) NOT NULL ); INSERT INTO gantt VALUES (1, NULL, 1, "", "" , "Root Node", MDY(1,1,3000), MDY(1, 1, 3000), 0); INSERT INTO gantt VALUES (2, 1, 1, "M", "Analisys" , "", MDY(9,1,2022), MDY(9,6,2022), 100); INSERT INTO gantt VALUES (3, 2, 1, "M", "Set Kick-Off Meeting" , "Alex B.", MDY(9,2,2022), MDY(9,3,2022), 80); INSERT INTO gantt VALUES (4, 2, 1, "M", "Agree on Objectives" , "Frank C.", MDY(9,4,2022), MDY(9,7,2022), 0); INSERT INTO gantt VALUES (5, 2, 1, "M", "Requirements planning" , "Jacob S.", MDY(9,7,2022), MDY(9,12,2022), 50); INSERT INTO gantt VALUES (6, 5, 1, "M", "Detailed Reqs." , "Jacob S.", MDY(9,10,2022), MDY(9,15,2022), 80); INSERT INTO gantt VALUES (7, 5, 1, "M", "Hardware Reqs." , "Jacob S.", MDY(9,11,2022), MDY(9,12,2022), 0); INSERT INTO gantt VALUES (8, 5, 1, "M", "Technical Reqs." , "Frank C.", MDY(9,17,2022), MDY(9,21,2022), 50); INSERT INTO gantt VALUES (9, 2, 1, "M", "Staffing" , "Alex B.", MDY(9,16,2022), MDY(9,17,2022), 0); INSERT INTO gantt VALUES (10, 1, 1, "M", "Development" , "", MDY(9,22,2022), MDY(10,5, 2022), 0); INSERT INTO gantt VALUES (11, 10, 1, "M", "DB Development" , "Shari W.", MDY(9,22,2022), MDY(9,24,2022), 25); INSERT INTO gantt VALUES (12, 10, 1, "M", "API Development" , "Shari W.", MDY(9,23,2022), MDY(9,27,2022), 10); INSERT INTO gantt VALUES (13, 10, 1, "M", "UI Client" , "Alex B.", MDY(9,25,2022), MDY(9,29,2022), 0); INSERT INTO gantt VALUES (14, 10, 1, "M", "Testing" , "Kennedy K.", MDY(9,24,2022), MDY(10,2,2022), 0); INSERT INTO gantt VALUES (15, 10, 1, "M", "Dev. Complete" , "Jacob S.", MDY(10,2,2022), MDY(10,5,2022), 0); INSERT INTO gantt VALUES (16, 1, 1, "M", "Deployment" , "", MDY(10,5,2022), MDY(10,17, 2022), 0); INSERT INTO gantt VALUES (17, 16, 1, "M", "Hardware Config." , "Alex B.", MDY(10,10,2022), MDY(10,12,2022), 0); INSERT INTO gantt VALUES (18, 16, 1, "M", "System Testing" , "Kennedy K.", MDY(10,11,2022), MDY(10,14,2022), 0); INSERT INTO gantt VALUES (19, 1, 1, "M", "Support" , "", MDY(10,14,2022),MDY(12,24,2022), 0); INSERT INTO gantt VALUES (20, 19, 1, "M", "Acvanced formation" , "John M.", MDY(10,14,2022), MDY(10,20,2022), 0); INSERT INTO gantt VALUES (21, 19, 1, "M", "Phone Support" , "N/A", MDY(12,1,2022), MDY(12,9,2022), 0);
Now, we can use the CONNECT BY clause for performing recursive operations in hierarchical queries.
SELECT id, parentid, orderid, level, LPAD(' ', 2 * LEVEL - 1) || TRIM(taskname) name, leader, start, end, end-start duration FROM gantt START WITH id = 1 CONNECT BY PRIOR id = parentID ORDER BY id
+----------+----------+----------+-------+----------------------------------------+--------------------+----------+----------+----------+
|id |parentid |orderid |level |name |leader |start |end |duration |
+----------+----------+----------+-------+----------------------------------------+--------------------+----------+----------+----------+
| 1| | 1| 1| | |2019-01-01|2019-01-20| 19|
| 2| 1| 1| 2| Analisys | |2019-01-01|2019-01-20| 19|
| 3| 2| 1| 3| Set Kick-Off Meeting |Alex B. |2022-09-02|2022-09-03| 1|
| 4| 2| 1| 3| Agree on Objectives |Frank C. |2022-09-03|2022-09-07| 4|
| 5| 2| 1| 3| Requirements plannin |Jacob S. |2022-09-07|2022-09-12| 5|
| 6| 5| 1| 4| Detailed Reqs. |Jacob S. |2022-09-07|2022-09-12| 5|
| 7| 5| 1| 4| Hardware Reqs. |Jacob S. |2022-09-09|2022-09-11| 2|
| 8| 5| 1| 4| Technical Reqs. |Frank C. |2022-09-17|2022-09-21| 4|
| 9| 2| 1| 3| Staffing |Alex B. |2022-09-16|2022-09-17| 1|
| 10| 1| 1| 2| Development | |2019-01-01|2019-01-20| 19|
| 11| 10| 1| 3| DB Development |Shari W. |2022-09-22|2022-09-24| 2|
| 12| 10| 1| 3| API Development |Shari W. |2022-09-23|2022-09-27| 4|
| 13| 10| 1| 3| UI Client |Alex B. |2022-09-25|2022-09-29| 4|
| 14| 10| 1| 3| Testing |Kennedy K. |2022-09-24|2022-10-02| 8|
| 15| 10| 1| 3| Dev. Complete |Jacob S. |2022-10-02|2022-10-05| 3|
| 16| 1| 1| 2| Deployment | |2019-01-01|2019-01-20| 19|
| 17| 16| 1| 3| Hardware Config. |Alex B. |2022-10-05|2022-10-07| 2|
| 18| 16| 1| 3| System Testing |Kennedy K. |2022-10-06|2022-10-09| 3|
+----------+----------+----------+-------+----------------------------------------+--------------------+----------+----------+----------+