--------------article -----------------------
Tree-structured queries are definitely non-relational
enough to kill Codd and make him roll in his grave). Also,
this feature is not often found in other database
offerings.
The LEVEL pseudo-column is an indication of how deep in
the tree one is. Oracle can handle queries with a depth of
up to 255 levels. Look at this example:
select LEVEL, EMPNO, ENAME, MGR
from EMP
connect by prior EMPNO = MGR
start with MGR is NULL;
The usual example of a tree structure in SQL books is called an
adjacency list model and it looks like this:
CREATE TABLE Personnel
(emp CHAR(10) NOT NULL PRIMARY KEY,
boss CHAR(10) DEFAULT NULL REFERENCES Personnel(emp),
salary DECIMAL(6,2) NOT NULL DEFAULT 100.00);
Personnel
emp boss salary
===========================
'Albert' 'NULL' 1000.00
'Bert' 'Albert' 900.00
'Chuck' 'Albert' 900.00
'Donna' 'Chuck' 800.00
'Eddie' 'Chuck' 700.00
'Fred' 'Chuck' 600.00
Another way of representing trees is to show them as nested sets. Since
SQL is a set oriented language, this is a better model than the usual
adjacency list approach you see in most text books. Let us define a
simple Personnel table like this, ignoring the left (lft) and right
(rgt) columns for now. This problem is always given with a column for
the employee and one for his boss in the textbooks. This table without
the lft and rgt columns is called the adjacency list model, after the
graph theory technique of the same name; the pairs of nodes are adjacent
to each other.
CREATE TABLE Personnel
(emp CHAR(10) NOT NULL PRIMARY KEY,
lft INTEGER NOT NULL UNIQUE CHECK (lft > 0),
rgt INTEGER NOT NULL UNIQUE CHECK (rgt > 1),
CONSTRAINT order_okay CHECK (lft < rgt) );
Personnel
emp lft rgt
======================
'Albert' 1 12
'Bert' 2 3
'Chuck' 4 11
'Donna' 5 6
'Eddie' 7 8
'Fred' 9 10
The organizational chart would look like this as a directed graph:
Albert (1,12)
/ \
/ \
Bert (2,3) Chuck (4,11)
/ | \
/ | \
/ | \
/ | \
Donna (5,6) Eddie (7,8) Fred (9,10)
The first table is denormalized in several ways. We are modeling both
the personnel and the organizational chart in one table. But for the
sake of saving space, pretend that the names are job titles and that we
have another table which describes the personnel that hold those
positions.
Another problem with the adjacency list model is that the boss and
employee columns are the same kind of thing (i.e. names of personnel),
and therefore should be shown in only one column in a normalized table.
To prove that this is not normalized, assume that "Chuck" changes his
name to "Charles"; you have to change his name in both columns and
several places. The defining characteristic of a normalized table is
that you have one fact, one place, one time.
The final problem is that the adjacency list model does not model
subordination. Authority flows downhill in a hierarchy, but If I fire
Chuck, I disconnect all of his subordinates from Albert. There are
situations (i.e. water pipes) where this is true, but that is not the
expected situation in this case.
To show a tree as nested sets, replace the nodes with ovals, then nest
subordinate ovals inside each other. The root will be the largest oval
and will contain every other node. The leaf nodes will be the innermost
ovals with nothing else inside them and the nesting will show the
hierarchical relationship. The rgt and lft columns (I cannot use the
reserved words LEFT and RIGHT in SQL) are what shows the nesting.
If that mental model does not work, then imagine a little worm crawling
anti-clockwise along the tree. Every time he gets to the left or right
side of a node, he numbers it. The worm stops when he gets all the way
around the tree and back to the top.
This is a natural way to model a parts explosion, since a final assembly
is made of physically nested assemblies that final break down into
separate parts.
At this point, the boss column is both redundant and denormalized, so it
can be dropped. Also, note that the tree structure can be kept in one
table and all the information about a node can be put in a second table
and they can be joined on employee number for queries.
To convert the graph into a nested sets model think of a little worm
crawling along the tree. The worm starts at the top, the root, makes a
complete trip around the tree. When he comes to a node, he puts a
number in the cell on the side that he is visiting and increments his
counter. Each node will get two numbers, one of the right side and one
for the left. Computer Science majors will recognize this as a modified
preorder tree traversal algorithm. Finally, drop the unneeded
Personnel.boss column which used to represent the edges of a graph.
This has some predictable results that we can use for building queries.
The root is always (left = 1, right = 2 * (SELECT COUNT(*) FROM
TreeTable)); leaf nodes always have (left + 1 = right); subtrees are
defined by the BETWEEN predicate; etc. Here are two common queries
which can be used to build others:
1. An employee and all their Supervisors, no matter how deep the tree.
SELECT P2.*
FROM Personnel AS P1, Personnel AS P2
WHERE P1.lft BETWEEN P2.lft AND P2.rgt
AND P1.emp = :myemployee;
2. The employee and all subordinates. There is a nice symmetry here.
SELECT P2.*
FROM Personnel AS P1, Personnel AS P2
WHERE P1.lft BETWEEN P2.lft AND P2.rgt
AND P2.emp = :myemployee;
3. Add a GROUP BY and aggregate functions to these basic queries and you
have hierarchical reports. For example, the total salaries which each
employee controls:
SELECT P2.emp, SUM(S1.salary)
FROM Personnel AS P1, Personnel AS P2,
Salaries AS S1
WHERE P1.lft BETWEEN P2.lft AND P2.rgt
AND P1.emp = S1.emp
GROUP BY P2.emp;
4. To find the level of each node, so you can print the tree as an
indented listing.
DECLARE Out_Tree CURSOR FOR
SELECT P1.lft, COUNT(P2.emp) AS indentation, P1.emp
FROM Personnel AS P1, Personnel AS P2
WHERE P1.lft BETWEEN P2.lft AND P2.rgt
GROUP BY P1.emp
ORDER BY P1.lft;
5. The nested set model has an implied ordering of siblings which the
adjacency list model does not. To insert a new node as the rightmost
sibling.
BEGIN
DECLARE right_most_sibling INTEGER;
SET right_most_sibling
= (SELECT rgt
FROM Personnel
WHERE emp = :your_boss);
UPDATE Personnel
SET lft = CASE WHEN lft > right_most_sibling
THEN lft + 2
ELSE lft END,
rgt = CASE WHEN rgt >= right_most_sibling
THEN rgt + 2
ELSE rgt END
WHERE rgt >= right_most_sibling;
INSERT INTO Personnel (emp, lft, rgt)
VALUES ('New Guy', right_most_sibling, (right_most_sibling + 1))
END;
6. To convert an adjacency list model into a nested set model, use a
push down stack algorithm. Assume that we have these tables:
-- Tree holds the adjacency model
CREATE TABLE Tree
(emp CHAR(10) NOT NULL,
boss CHAR(10));
INSERT INTO Tree
SELECT emp, boss FROM Personnel;
-- Stack starts empty, will holds the nested set model
CREATE TABLE Stack
(stack_top INTEGER NOT NULL,
emp CHAR(10) NOT NULL,
lft INTEGER,
rgt INTEGER);
BEGIN ATOMIC
DECLARE counter INTEGER;
DECLARE max_counter INTEGER;
DECLARE current_top INTEGER;
SET counter = 2;
SET max_counter = 2 * (SELECT COUNT(*) FROM Tree);
SET current_top = 1;
INSERT INTO Stack
SELECT 1, emp, 1, NULL
FROM Tree
WHERE boss IS NULL;
DELETE FROM Tree
WHERE boss IS NULL;
WHILE counter <= (max_counter - 2)
LOOP IF EXISTS (SELECT *
FROM Stack AS S1, Tree AS T1
WHERE S1.emp = T1.boss
AND S1.stack_top = current_top)
THEN
BEGIN -- push when top has subordinates and set lft value
INSERT INTO Stack
SELECT (current_top + 1), MIN(T1.emp), counter, NULL
FROM Stack AS S1, Tree AS T1
WHERE S1.emp = T1.boss
AND S1.stack_top = current_top;
DELETE FROM Tree
WHERE emp = (SELECT emp
FROM Stack
WHERE stack_top = current_top + 1);
SET counter = counter + 1;
SET current_top = current_top + 1;
END
ELSE
BEGIN -- pop the stack and set rgt value
UPDATE Stack
SET rgt = counter,
stack_top = -stack_top -- pops the stack
WHERE stack_top = current_top
SET counter = counter + 1;
SET current_top = current_top - 1;
END IF;
END LOOP;
END;
This approach will be two to three orders of magnitude faster than the
adjacency list model for subtree and aggregate operations.
For details, see the chapter in my book JOE CELKO'S SQL FOR SMARTIES
(Morgan-Kaufmann, 1999, second edition)
--CELKO--
===========================
Please post DDL, so that people do not have to guess what the keys,
constraints, Declarative Referential Integrity, datatypes, etc. in your
schema are.
*** Sent via Developersdex http://www.developersdex.com ***
Don't just participate in USENET...get rewarded for it!
You don't describe in detail what sort of tree-structured queries you might
want, but perhaps the section "Expanding Hierarchies" in the SQL Server
Books Online might help.
Joe has posted his usual about the adjacency list model, but you might also
want to take a look at "Advanced Transact-SQL for SQL Server 2000" by Itzik
Ben-Gan and Tom Moreau.
The book has an entire chapter on structuring trees in SQL Server, along
with T-SQL code.
BTW, Joe's book is not SQL Server specific, and uses ANSI SQL code, which
you should be able to convert to T-SQL without huge difficulty, but still
does require an extra step.
-------------------------------------------
BP Margolin
Please reply only to the newsgroups.
When posting, inclusion of SQL (CREATE TABLE ..., INSERT ..., etc.) which
can be cut and pasted into Query Analyzer is appreciated.
"dan" <d...@emedia-solutions.biz> wrote in message
news:987e01c19d37$cc1ed7a0$35ef2ecf@TKMSFTNGXA11...
Joe Celko" <71062...@compuserve.com> wrote in message
news:e7gv8zTnBHA.1608@tkmsftngp04...
The approach is fantastic, I have one Question for every one.
How if any Manager is put under some other manager with all its staff?
Basically I want to move any Node of Tree to any other node.
Without this, I am unable to use this Approach
Thanks
Gagan
"Joe Celko" <71062...@compuserve.com> wrote in message
news:e7gv8zTnBHA.1608@tkmsftngp04...
Yes, it is possible to move subtrees inside the nested sets model for
hierarchies. But we need to get some preliminary things out of the way
first. The nested sets model needs a few auxiliary tables to help it.
The first is
CREATE VIEW LftRgt (i)
AS SELECT lft FROM Tree
UNION ALL
SELECT rgt FROM Tree;
This is all lft and rgt values in a single column. Since we should have
no duplicates, we use a UNION ALL to construct the VIEW. Yes, LftRgt
can be written as a derived table inside queries, but there are
advantages to using a VIEW. Self-joins are much easier to construct.
Code is easier to read. If more than one user needs this table, it can
be materialized only once by the SQL engine.
The next table is a working table to hold subtrees that we extract from
the original tree. This could be declared as a local temporary table,
but it would lose the benefit of a PRIMARY KEY declaration.
CREATE TABLE WorkingTree
(root CHAR(2) NOT NULL,
node CHAR(2) NOT NULL,
lft INTEGER NOT NULL,
rgt INTEGER NOT NULL,
PRIMARY KEY (root, node));
The root column is going to be the value of the root node of the
extracted subtree. This gives us a fast way to find an entire subtree
via part of the primary key. While this is not important for the stored
procedure discussed here, it is useful for other operations that involve
multiple extracted subtrees.
Here is a sample tree to use as test data. The whole thing is based on
the idea that the nodes are the primary key of the table; you can design
a nested set model with (lft, rgt) as the primary key instead. I am not
going to worry about that now.
CREATE TABLE Tree
(node CHAR(2) NOT NULL DEFAULT '??'
PRIMARY KEY,
lft INTEGER NOT NULL UNIQUE CHECK (lft > 0),
rgt INTEGER NOT NULL UNIQUE CHECK (rgt > 1),
CHECK (lft < rgt));
INSERT INTO Tree VALUES ('A', 1, 28);
INSERT INTO Tree VALUES ('B', 2, 5);
INSERT INTO Tree VALUES ('C', 6, 19);
INSERT INTO Tree VALUES ('D', 20, 27);
INSERT INTO Tree VALUES ('E', 3, 4);
INSERT INTO Tree VALUES ('F', 7, 16);
INSERT INTO Tree VALUES ('G', 17, 18);
INSERT INTO Tree VALUES ('H', 21, 26);
INSERT INTO Tree VALUES ('I', 8, 9);
INSERT INTO Tree VALUES ('J', 10, 15);
INSERT INTO Tree VALUES ('K', 22, 23);
INSERT INTO Tree VALUES ('L', 24, 25);
INSERT INTO Tree VALUES ('M', 11, 12);
INSERT INTO Tree VALUES ('N', 13, 14);
Let me move right to the commented code. The input parameters are the
root node of the subtree being moved and the node which is to become its
new parent. In this procedure, there is an assumption that new sibling
are added on the right side of the immediate subordinates, so that
siblings are ordered by their age.
CREATE PROCEDURE MoveSubtree (@my_root CHAR(2), @new_parent CHAR(2))
AS
BEGIN
DECLARE @right_most_sibling INTEGER,
@subtree_size INTEGER;
-- clean out and rebuild working tree
DELETE FROM WorkingTree;
INSERT INTO WorkingTree (root, node, lft, rgt)
SELECT @my_root,
T1.node,
T1.lft - (SELECT MIN(lft)
FROM Tree
WHERE node = @my_root),
T1.rgt - (SELECT MIN(lft)
FROM Tree
WHERE node = @my_root)
FROM Tree AS T1, Tree AS T2
WHERE T1.lft BETWEEN T2.lft AND T2.rgt
AND T2.node = @my_root;
-- Cannot move a subtree to itself, infinite recursion
IF (@new_parent IN (SELECT node FROM WorkingTree))
BEGIN
PRINT 'Cannot move a subtree to itself, infinite recursion';
DELETE FROM WorkingTree;
RETURN;
END;
-- remove the subtree from original tree
DELETE FROM Tree
WHERE node IN (SELECT node FROM WorkingTree);
-- get size and location for inserting working tree into new slot
SET @right_most_sibling
= (SELECT rgt
FROM Tree
WHERE node = @new_parent);
SET @subtree_size = (SELECT (MAX(rgt)+1) FROM WorkingTree);
-- make a gap in the tree
UPDATE Tree
SET lft = CASE WHEN lft > @right_most_sibling
THEN lft + @subtree_size
ELSE lft END,
rgt = CASE WHEN rgt >= @right_most_sibling
THEN rgt + @subtree_size
ELSE rgt END
WHERE rgt >= @right_most_sibling;
-- insert the subtree and renumber its rows
INSERT INTO Tree (node, lft, rgt)
SELECT node,
lft + @right_most_sibling,
rgt + @right_most_sibling
FROM WorkingTree;
-- clean out working tree table
DELETE FROM WorkingTree;
-- close gaps in tree
UPDATE Tree
SET lft = (SELECT COUNT(*)
FROM LftRgt
WHERE LftRgt.i <= Tree.lft),
rgt = (SELECT COUNT(*)
FROM LftRgt
WHERE LftRgt.i <= Tree.rgt);
END; -- of MoveSubtree
As a minor note, the variables @right_most_sibling and @subtree_size
could have been replaced with their scalar subqueries in the UPDATE and
INSERT INTO statements that follow their assignments. But that would
make the code much harder to read at the cost of only a slight boost in
performance.
The code is generic enough that translating it from T-SQL dialect to
another SQL product's 4GL should not be a major problem.
--CELKO--
See another posting for the stored procedure.
>> 2.how to find any level child node. in this case, I input parent node
ID and level. <<
The basic level query is simply:
SELECT P1.node, COUNT(P2.node) AS lvl
FROM Tree AS P1, Tree AS P2
WHERE P1.lft BETWEEN P2.lft AND P2.rgt
GROUP BY P1.node;
Did you want levels in the tree, or relative levels from a given node?
1 Create Gap: Push out the lft/rgt nodes from the new parent up (by
the amount of the branch size we're moving).
2 Move: Move the lft/rgt's of the moving branch to the new space.
3 Remove Gaps:
It will get a little tricky when you're moving the branch lower
because the branch is included in the lft/rgt's to be pushed up to
first make the gap.
Thanks,
Fletch
CREATE PROCEDURE MoveSubtree @my_root CHAR(2), @new_parent CHAR(2)
AS
DECLARE
@origin_lft INT,
@origin_rgt INT,
@new_parent_rgt INT
SELECT @origin_lft = lft, @origin_rgt = rgt
FROM Tree
WHERE node = @my_root;
SELECT @new_parent_rgt = rgt
FROM Tree
WHERE node = @new_parent;
UPDATE Tree SET
lft = lft + CASE
WHEN @new_parent_rgt < @origin_lft THEN CASE
WHEN lft BETWEEN @origin_lft AND @origin_rgt THEN
@new_parent_rgt - @origin_lft
WHEN lft BETWEEN @new_parent_rgt AND @origin_lft - 1 THEN
@origin_rgt - @origin_lft + 1
ELSE 0
END
WHEN @new_parent_rgt > @origin_rgt THEN CASE
WHEN lft BETWEEN @origin_lft AND @origin_rgt THEN
@new_parent_rgt - @origin_rgt - 1
WHEN lft BETWEEN @origin_rgt + 1 AND @new_parent_rgt - 1 THEN
@origin_lft - @origin_rgt - 1
ELSE 0 END
ELSE 0 END,
rgt = rgt + CASE
WHEN @new_parent_rgt < @origin_lft THEN CASE
WHEN rgt BETWEEN @origin_lft AND @origin_rgt THEN
@new_parent_rgt - @origin_lft
WHEN rgt BETWEEN @new_parent_rgt AND @origin_lft - 1 THEN
@origin_rgt - @origin_lft + 1
ELSE 0 END
WHEN @new_parent_rgt > @origin_rgt THEN CASE
WHEN rgt BETWEEN @origin_lft AND @origin_rgt THEN
@new_parent_rgt - @origin_rgt - 1
WHEN rgt BETWEEN @origin_rgt + 1 AND @new_parent_rgt - 1 THEN
@origin_lft - @origin_rgt - 1
ELSE 0 END
ELSE 0 END;
--
Alejandro Izaguirre Martín
ale...@terra.es
Yes, and Alejandro Izaguirre just posted the answer to your question. I
present the solution in (painful) details first because people have a
hard time folding it all into one statement. In fact, you could drop
the first two SELECT statements in his procedure and use scalar subquery
expressions in the UPDATE statement. But it would be hard for a human
being to read and might choke a parser.
Notice that if you try to move a tree under itself (for example, EXEC
MoveTree 'C', 'G'), nothing happens, but you do not get an error message
either.
Your next programming exercise is to write a routine that will swap two
siblings that are next to each other under their parent in one UPDATE
statement. Hint: you already have the right size gap available.
Thanks for your replies gentlemen... and yes, this human nearly chokes
on the nice code Alejandro Izaguirre posted.
I did notice the code runs through the entire set. Could we find tune
it a bit and eliminate the rows that don't change (in front and back )
by appending a "WHERE" statement?
> Notice that if you try to move a tree under itself (for example, EXEC
> MoveTree 'C', 'G'), nothing happens, but you do not get an error message
> either.
...And tack on a test for infinite recursion, resulting in the updated
code:
CREATE PROCEDURE MoveSubtree @my_root CHAR(2), @new_parent CHAR(2)
AS
DECLARE
@origin_lft INT,
@origin_rgt INT,
@new_parent_rgt INT,
@new_parent_lft INT
SELECT @origin_lft = lft, @origin_rgt = rgt
FROM Tree
WHERE node = @my_root;
SELECT @new_parent_lft = lft, @new_parent_rgt = rgt
FROM Tree
WHERE node = @new_parent;
-- Cannot move a subtree to itself, infinite recursion
IF @new_parent_lft > @origin_lft AND @new_parent_rgt < @origin_rgt
BEGIN
PRINT 'Cannot move a subtree to itself, infinite recursion';
RETURN;
END;
UPDATE Tree SET
WHERE rgt >= CASE WHEN @new_parent_lft < @origin_lft THEN
@new_parent_lft ELSE @origin_lft END
AND lft <= CASE WHEN @new_parent_rgt > @origin_rgt THEN
@new_parent_rgt ELSE @origin_rgt END;
GO
>
> Your next programming exercise is to write a routine that will swap two
> siblings that are next to each other under their parent in one UPDATE
> statement. Hint: you already have the right size gap available.
>
some time soon... system is in temporary over load.... over load.
Fletcher Klap
I have not played with that yet, but let's think about it.
0) The subtree does not move; that was the case in Alejandro's procedure
where you tried to put the subtree under one of its own nodes.
1) The gap is to the left of the subtree to be moved.
2) The gap is to the right of the subtree to be moved.
Nodes to the left of the gap do not get re-numbered; nodes to the right
of the gap get re-numbered. So we leave the nodes to left of the gap
alone.
(code snipped)
> -- Cannot move a subtree to itself, infinite recursion
> IF @new_parent_lft > @origin_lft AND @new_parent_rgt < @origin_rgt
> BEGIN
> PRINT 'Cannot move a subtree to itself, infinite recursion';
> RETURN;
> END;
(code snipped)
> WHERE rgt >= CASE WHEN @new_parent_lft < @origin_lft THEN
> @new_parent_lft ELSE @origin_lft END
> AND lft <= CASE WHEN @new_parent_rgt > @origin_rgt THEN
> @new_parent_rgt ELSE @origin_rgt END;
> GO
I placed all the logic in a single UPDATE statement with nested cases just
for fun, but I think it is more sensible, and at least equally efficient, to
check whether the new parent is to the left or to the right of the subtree.
I have changed the code to do just that, and added WHERE clauses a bit more
selective than those you proposed. The thing that still bothers me about all
this is that we are applying exactly the same transformation to lft and rgt,
using duplicate code.
CREATE PROCEDURE MoveSubtree @my_root CHAR(2), @new_parent CHAR(2)
AS
DECLARE
@origin_lft INT,
@origin_rgt INT,
@new_parent_rgt INT
SELECT @new_parent_rgt = rgt
FROM Tree
WHERE node = @new_parent;
SELECT @origin_lft = lft, @origin_rgt = rgt
FROM Tree
WHERE node = @my_root;
IF @new_parent_rgt < @origin_lft BEGIN
UPDATE Tree SET
lft = lft + CASE
WHEN lft BETWEEN @origin_lft AND @origin_rgt THEN
@new_parent_rgt - @origin_lft
WHEN lft BETWEEN @new_parent_rgt AND @origin_lft - 1 THEN
@origin_rgt - @origin_lft + 1
ELSE 0 END,
rgt = rgt + CASE
WHEN rgt BETWEEN @origin_lft AND @origin_rgt THEN
@new_parent_rgt - @origin_lft
WHEN rgt BETWEEN @new_parent_rgt AND @origin_lft - 1 THEN
@origin_rgt - @origin_lft + 1
ELSE 0 END
WHERE lft BETWEEN @new_parent_rgt AND @origin_rgt
OR rgt BETWEEN @new_parent_rgt AND @origin_rgt;
END
ELSE IF @new_parent_rgt > @origin_rgt BEGIN
UPDATE Tree SET
lft = lft + CASE
WHEN lft BETWEEN @origin_lft AND @origin_rgt THEN
@new_parent_rgt - @origin_rgt - 1
WHEN lft BETWEEN @origin_rgt + 1 AND @new_parent_rgt - 1 THEN
@origin_lft - @origin_rgt - 1
ELSE 0 END,
rgt = rgt + CASE
WHEN rgt BETWEEN @origin_lft AND @origin_rgt THEN
@new_parent_rgt - @origin_rgt - 1
WHEN rgt BETWEEN @origin_rgt + 1 AND @new_parent_rgt - 1 THEN
@origin_lft - @origin_rgt - 1
ELSE 0 END
WHERE lft BETWEEN @origin_lft AND @new_parent_rgt
OR rgt BETWEEN @origin_lft AND @new_parent_rgt;
END
ELSE BEGIN
PRINT 'Cannot move a subtree to itself, infinite recursion';
RETURN;
END
--
Alejandro Izaguirre Martín
ale...@terra.es
Thanks, Joe.
I have just read your post about the book on the nested sets model you are
preparing. Feel free to use anything I have posted.