Hierarchies in SQL Server 2008
Graphs, tree algorithms and structures have been used for long time in databases to solve hierarchy related problems. Adjacency list, nested sets, materialized path, and other hybrid methods offer different capabilities to help.
SQL Server 2008 adds a new feature to help with modeling hierarchical relationships: the HIERARCHYID data type. It provides compact storage and convenient methods to manipulate hierarchies. In a way it is very much like optimized materialized path. In addition the SqlHierarchyId CLR data type is available for client applications.
While HIERARCHYID has a lot to offer in terms of operations with hierarchical data, it is important to understand a few basic concepts:
– HIERARCHYID can have only a single root (although easy to work around by adding sub-roots)
– It does not automatically represent a tree, the application has to define the relationships and enforce all rules
– The application needs to maintain the consistency
Here is a one example of employee hierarchy to illustrate the usage of HIERARCHYID and the related methods for manipulation of hierarchies.
CREATE TABLE Employees (
emp_id INT NOT NULL PRIMARY KEY,
emp_name VARCHAR(35),
manager_id INT REFERENCES Employees(emp_id),
org_chart_path HIERARCHYID);
/*
The primary key prevents cyclic paths.
Another way is using a CHECK constraint.
CHECK (org_chart_path.ToString() NOT LIKE '%/' + CAST(emp_id AS VARCHAR(10)) + '/_%')
*/
-- Insert the top level manager as hierarchy root
INSERT INTO Employees
VALUES (1, 'Jeff Brown', NULL, hierarchyid::GetRoot());
-- Insert John who reports to the top level manager
INSERT INTO Employees
VALUES (2, 'John Doe', 1,
(SELECT hierarchyid::GetRoot().GetDescendant(NULL, NULL)
FROM Employees));
-- Insert Peter at the same level as John
DECLARE @mgr HIERARCHYID = (SELECT org_chart_path
FROM Employees
WHERE emp_name = 'John Doe');
INSERT INTO Employees
VALUES (3, 'Peter Hanna', 1,
(SELECT hierarchyid::GetRoot().GetDescendant(@mgr, NULL)
FROM Employees
WHERE org_chart_path = hierarchyid::GetRoot()));
-- Insert Richard as reporting to John
INSERT INTO Employees
VALUES (4, 'Richard Burns', 2,
hierarchyid::Parse('/1/1/')); -- Also: CAST('/1/1/' AS HIERARCHYID)
SELECT emp_id, emp_name,
manager_id, org_chart_path,
org_chart_path.GetAncestor(1) AS emp_manager,
hierarchyid::GetRoot() AS top_manager,
org_chart_path.GetDescendant(NULL, NULL) AS emp_descendant,
org_chart_path.GetLevel() AS emp_level,
org_chart_path.ToString() AS emp_org_path
FROM Employees;
/*
emp_id emp_name manager_id org_chart_path emp_manager top_manager emp_descendant emp_level emp_org_path
------ ---------------- ----------- --------------- ------------- ------------ --------------- --------- ------------
1 Jeff Brown NULL 0x NULL 0x 0x58 0 /
2 John Doe 1 0x58 0x 0x 0x5AC0 1 /1/
3 Peter Hanna 1 0x68 0x 0x 0x6AC0 1 /2/
4 Richard Burns 2 0x5AC0 0x58 0x 0x5AD6 2 /1/1/
*/
-- Move Richard to report to Peter
DECLARE @new_mgr HIERARCHYID = (SELECT org_chart_path
FROM Employees
WHERE emp_name = 'Peter Hanna');
UPDATE Employees
SET org_chart_path = org_chart_path.Reparent(org_chart_path.GetAncestor(1),
@new_mgr)
WHERE emp_name = 'Richard Burns';
SELECT emp_id, emp_name,
manager_id, org_chart_path,
org_chart_path.GetAncestor(1) AS emp_manager,
hierarchyid::GetRoot() AS top_manager,
org_chart_path.GetDescendant(NULL, NULL) AS emp_descendant,
org_chart_path.GetLevel() AS emp_level,
org_chart_path.ToString() AS emp_org_path
FROM Employees;
/*
emp_id emp_name manager_id org_chart_path emp_manager top_manager emp_descendant emp_level emp_org_path
------- --------------- ----------- ----------------- ------------- ------------ ---------------- --------- ------------
1 Jeff Brown NULL 0x NULL 0x 0x58 0 /
2 John Doe 1 0x58 0x 0x 0x5AC0 1 /1/
3 Peter Hanna 1 0x68 0x 0x 0x6AC0 1 /2/
4 Richard Burns 2 0x6AC0 0x68 0x 0x6AD6 2 /2/1/
*/
From the above example it is very easy to see the similarity between materialized path and HIERARCHYID when the HIERARCHYID is converted to the character format using the ToString() method. Converting hierarchy from traditional parent/child format to HIERARCHYID is simple using recursive CTEs (very similar to building a materialized path).
Note:
This code has been tested with SQL Server 2008 CTP 6 (February 2008). As of SQL Server 2008 Release Candidate 0 (June 2008) the method Reparent() has been replaced with the method GetReparentedValue(). It is called using the same parameters and returns the same value.
Additional resources:
Using hierarchyid Data Types
http://msdn.microsoft.com/en-us/library/bb677173(SQL.100).aspx
Working with hierarchyid Data
http://msdn.microsoft.com/en-us/library/bb677212(SQL.100).aspx
This can help you with soring simple parent Child relationship. What if a Child can have multiple parents ?
This comment has been removed by the author.