Google Groups no longer supports new Usenet posts or subscriptions. Historical content remains viewable.
Dismiss

Joe Celko's Frammis example - Nested Set model

100 views
Skip to first unread message

Melanie Norton

unread,
May 30, 2001, 2:31:58 PM5/30/01
to

I've recently been trying to figure out how to do a parts breakdown into subassemblies. The example that I am trying to emulate for my own application is Joe Celko's frammis example that talks about Nested set models. I understand the concept behind his model but what I don't understand is the rgt and lft column and how he comes up with the numbers that he does for each part. If someone could explain this to me I would greatly appreciate it. Thanks for any help you can provide.


*** Sent via Developersdex http://www.developersdex.com ***
Don't just participate in USENET...get rewarded for it!

Lasse Edsvik

unread,
May 30, 2001, 2:42:09 PM5/30/01
to
Melanie,

It's easier if you have X0 (lft) and X1 (rgt) and draw the values into a
graph on paper......

dX=X1-X0

if dX=1 means you've reached a leaf-node and that it has no childs....

try figuring out (using dX) the relationship between it and the "Level" of
each node...

/Lasse


"Melanie Norton" <melanie...@hotmail.com> wrote in message
news:#fssQbT6AHA.1804@tkmsftngp05...

Isaac Blank

unread,
May 30, 2001, 2:47:51 PM5/30/01
to
I do not think nested sets model will work for you - what you have here is
not a tree structure but rather a directed acyclic graph - which is more
than a tree


"Melanie Norton" <melanie...@hotmail.com> wrote in message
news:#fssQbT6AHA.1804@tkmsftngp05...

I've recently been trying to figure out how to do a parts breakdown into

Melanie Norton

unread,
May 30, 2001, 3:38:30 PM5/30/01
to

Lasse,
Sorry to bother you but I'm alittle lost as to what you are proposing for me to do. I'm fairly new to SQL programming and really need maybe alittle more direction or an example of code if possible.

Thanks,
Melanie

Melanie Norton

unread,
May 30, 2001, 3:53:42 PM5/30/01
to
The reason I am using Joe's nested set model is because in his example he uses it for a parts breakdown which is exactly what I want to do. Also using nested sets allows for you to delete part number and not mess up the structure like a tree. thanks for your reply though.

Melanie

Lasse Edsvik

unread,
May 30, 2001, 4:06:09 PM5/30/01
to
Melanie,

It's ok :)

I'll try to how it as an ascii-graph......

Let's say you have this "tree"

Mama Mo
|
|- Little mo
| |_ Mini mo
|
|_Little mo 2
|_ Mini mo Jr

The X0 (lft) and X1 (rgt) values would look like this (where X0 is to the
left of the name)


(1) Mama Mo (10)
|
|- (2) Little mo (5)
| |_ (3) Mini mo (4)
|
|_ (6) Little mo 2 (9)
|_ (7)Mini mo Jr (8)


And in the table

X0 , X1 , Name
2 5 Little mo
1 10 Mama Mo
3 4 Mini mo
7 8 Mini mo Jr
6 9 Little mo 2


if you run this simple query against that table:

SELECT * FROM Testing ORDER BY X0

you'll see that they end up in the correct order

let's say we add a "Little mo 3" then the tree would look like this:

(1) Mama Mo (12)
|
|- (2) Little mo (5)
| |_ (3) Mini mo (4)
|
|_ (6) Little mo 2 (9)
| |_ (7)Mini mo Jr (8)
|
|- (10) Little mo 3 (11)

Notice the changes made for the values. And also notice that all X0 and X1
values are unique.

I'd love to tell you more about the great Celko-tree but I have a deadline
in 2 days :)

I would recommend you to buy Joe Celko's book SQL For smarties where he
describes this in detail. But the queries for updating the tree and such may
be kinda difficult to understand (even for me). So I suggest you use lots of
paperwork to figure out.

Hope that helps you abit

/Lasse


"Melanie Norton" <melanie...@hotmail.com> wrote in message

news:ew0DcAU6AHA.2096@tkmsftngp05...

Lasse Edsvik

unread,
May 30, 2001, 4:08:30 PM5/30/01
to
Melanie,

here's an article he wrote about it:

http://www.dbmsmag.com/9603d06.html


/Lasse

"Melanie Norton" <melanie...@hotmail.com> wrote in message

news:ew0DcAU6AHA.2096@tkmsftngp05...

Joe Celko

unread,
May 30, 2001, 4:15:45 PM5/30/01
to
>> I understand the concept behind his model but what I don't understand is the rgt and lft column and how he comes up with the numbers that he does for each part. If someone could explain this to me I would greatly appreciate it. <<

The numvers are "between-ness" or containment.

1) Draw a picture (Venn Diagram or Euler circles) of sets inside sets. Then draw a line thru them from left to right; everytime the line cuts across a circle boundary, number it.

2) Write a parenthesized expression and nmumber the parens (either open or close parens) from left to right.

3) Ditto BEGIN-END tokens in a program, HTML, XML or whatever

Here is my stock "cut & paste" answer:

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.

SELECT 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--

SQL guru at Trilogy
===========================
Please post DDL, so that people do not have to guess what the keys, constraints, Declarative Referential Integrity, datatypes, etc. in your schema are.

Joe Celko

unread,
May 30, 2001, 4:15:50 PM5/30/01
to
>> I understand the concept behind his model but what I don't understand is the rgt and lft column and how he comes up with the numbers that he does for each part. If someone could explain this to me I would greatly appreciate it. <<

The numvers are "between-ness" or containment.

BEGIN
DECLARE right_most_sibling INTEGER;

-CELKO--

*** Sent via Developersdex http://www.developersdex.com ***

Joe Celko

unread,
May 30, 2001, 4:18:15 PM5/30/01
to
In particular, the Parts Explosion, is berst donw with

CREATE TABLE Explosion
(assembly_name CHAR(20) NOT NULL PRIMARY KEY,
part_nbr INTEGER
REFERENCES Parts(part_nbr)
ON DELETE SET NULL
ON UPDATE CASCADE,
lft INTEGER NOT NULL UNIQUE CHECK(lft > 0),
rgt INTEGER NOT NULL UNIQUE CHECK(lft < rgt),
UNIQUE (lft, rgt));

This allows the same part to appear in many subassemblies, or to be missing entirely (i.e. "What motor are we using for the Floob driver?" -- "we don't know yet!")


--CELKO--

SQL guru at Trilogy
===========================
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 ***

0 new messages