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/
*/
Labels: hierarchy, sql server 2008, trees