Thread: Re: Help!!! Trying to "SELECT" and get a tree structure back.

Re: Help!!! Trying to "SELECT" and get a tree structure back.

From
joe.celko@trilogy.com (--CELKO--)
Date:
>> The table causing my headache:CREATE TABLE app_components 
(id            NUMERIC(7) NOT NULL PRIMARY KEY,name          VARCHAR(100) NOT NULL,description   VARCHAR(500)
NULL,parent_id    NUMERIC(7) NULL               REFERENCES app_components(id)               ON DELETE
CASCADE,CONSTRAINTappcomp_name_u UNIQUE (name, parent_id)); <<
 



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),
salaryDECIMAL(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
NOTNULL 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
ANDP2.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 via a cursor.

DECLARE PrintTree CURSOR FOR SELECT COUNT(P2.emp) AS indentation, P1.lft, P1.emp   FROM Personnel AS P1, Personnel AS
P2WHERE 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 ENDWHERE 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 TreeWHERE boss IS NULL;

DELETE FROM TreeWHERE 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
INSERTINTO Stack      SELECT (current_top + 1), MIN(T1.emp), counter, NULL        FROM Stack AS S1, Tree AS T1
WHERES1.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
andset 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)


Re: Re: Help!!! Trying to "SELECT" and get a tree structure back.

From
Markus Wagner
Date:
Hi Joe,

what if you want to insert a node somewhere in the tree?
You have to update all nodes, right?

Markus

On Friday 29 June 2001 21:06, --CELKO-- wrote:
>
>             Albert (1,12)
>             /        \
>           /            \
>     Bert (2,3)    Chuck (4,11)
>                    /    |   \
>                  /      |     \
>                /        |       \
>              /          |         \
>         Donna (5,6)  Eddie (7,8)  Fred (9,10)
>


Re: Re: Help!!! Trying to "SELECT" and get a tree structure back.

From
Mark Stosberg
Date:
--CELKO-- wrote:
> 
> >> The table causing my headache:
> 
>  CREATE TABLE app_components
> (id            NUMERIC(7) NOT NULL PRIMARY KEY,
>  name          VARCHAR(100) NOT NULL,
>  description   VARCHAR(500) NULL,
>  parent_id     NUMERIC(7) NULL
>                REFERENCES app_components(id)
>                ON DELETE CASCADE,
>  CONSTRAINT appcomp_name_u UNIQUE (name, parent_id)); <<

I first tried the above approach to model trees in SQL, which also
caused me 
headaches. The recursion needed to find all the ancestors for a given
id was slow.  So I bought and looked through Joe Celko's book (who recently
posted on this topic). I implemented his ideas, and found that they were
better than the method above (and faster, as he says), but I still
wasn't satisfied. First, I didn't like that the notion wasn't easily
parsable for me. Updating and deleting categories felt like hacks, and
moving a category seemed like too much work. So I kept looking for new
ideas to model trees in SQL. On my third try, I found a solution I was
happy with, which I'll call the "sort key" method. I first read about it here:

http://philip.greenspun.com/wtr/dead-trees/53013.htm
(Search for "Sort keys deserve some discussion") on this page

The sort key is a single string that gives you the location of a node in
a tree. 
Used in conjunction with a parent_id, I found that most of the questions
I was asking were easy to answer: Who is my parent? Who are all my
ancestors? Who are my immediate children? How many descendants do I
have? Who are siblings? Furthermore, it's fairly straightforward to
manipulate items using this structure, and queries are fast-- most
questions can answered with one SQL statement. Finally, the sort_keys
are fairly human parsable, which is nice. The trade-off for all these
features is that you have a fixed number of immediate children for any
parent (based on how many characters are used for each piece of the sort
key). I think in my application to categorize data, each parent can only
have 62 immediate children. I can live with that. 

Cascade is a complete (free) Perl/Postgres application using this scheme
if you are interested in seeing these ideas in action. It's homepage is here:
http://summersault.com/software/cascade/

You'll be able to get a demo and source code from there. 

Thanks,
 -mark
http://mark.stosberg.com/