Re: Tree structure in Relational DB design

From: Costin Cozianu <c_cozianu_at_hotmail.com>
Date: 9 Jun 2002 20:08:40 -0700
Message-ID: <2cf20de8.0206091908.1552256e_at_posting.google.com>


Oh,not again.

While Mr. Celko might be so proud of his invention with nested sets, I think it's well past time to cut the crap and stop spreading misinformation about relational databases with regards to this subject.

First of all, Mr. Celko conveniently fails to mention that his nested sets model fails miserably if the hierarchy it needs to model is subject to a lot of update activity (inserting new nodes, deleting, moving branches, etc ), because then it needs to "renumber" a lots of nodes.

An elementary improvement might be brought to Mr. Celko's model by declaring the rgt and lft column as double precision floats instead of integers. Then inserts under a certain node and other tree modifications can be done a lot more conveniently, without affecting the whole tree structure.

Second, Mr Celoko falsely claims that the adjacency list model is denormalized "in several ways". That's plain non-sense. It would only be true, if we could drop all the definitions of normal forms that are well established in database theory books, and adhere to his fuzzy ideas of what constitutes "normalized" .

I'd be very curious to see if Mr. Celko can demonstrate, if he will or if he can at all, what normal form, as defined in standard database theory books (C.J. Date; Abiteboul, Hull & Vianu; Elmasri & Navathe; etc), is broken by the OrgChart he described below.

As commonly accepted a table is normalized if it is in the 5NF. The highest normalization possible is Domain Key Normal Form, but since generally one cannot normalize a schema up to DKNF , the 5NF is considered enough to say about a schema that is normalized.

The OrgChart in adjacency list model as he describes below is in 5NF. Although he constructs a strawman here, because the common practice is not to put the hierarchy information in the same table (let's say with Employee information in this case), but in a separate table, and more so because ususally a hierarchy has an existence that is separate from the objects that occupy the nodes of the hierarchy. In this example the hierarchy of positions in the enterprise is separate from the persons that occupy positions at any given time.

Be that as it may, but even with his conveniently constructed straw man, he still falsely claims that the table is "denormalized" and "in several ways". No, it is not. Therefore, inspite Mr. Celko's authoritative voice on news group, the adjacency list model is perfectly sound and normalized.

In reality, when one models a hierarchy one has to choose a representation that makeas a compromise between the performance of updates to the tree structure and the performance of queries against the tree structure.

The adjacency list model has the best performance for updates but might pose some inconveniences in expressing recursive queries (like "get all employees that are subordinated directly or indirectly to employee X"), especially in older databases. However, in newer databases, this isn't a problem (Oracle has had a CONNECT BY cluase for hierarchies for quite some time, and in Oracle 9i support has been improved, and IBM DB2 v7.x supports recursive queries ).

If you have a largely static hierarchy structure, you might use your nested set
model very well, although in this case there is another structure that performs better. You just create a string artifical primary key where the key of the parent is the prefix for all the children.

For example, if an enterprise has 7 subdivision on the first level you number them '1','2', ... '7'. On the second level you'll have '1.1', 1.2, ... 1.x, 2.1, ... '7.x'. In this case a query for a parent node let's say '1.2' and all its direct or indirect children is solved by a simple clause

   WHERE Node_key LIKE '1.2%'
which is easily optimized and generates a index based range access. The only difficulty is to generate the proper keys, but this can be easily solved at the application level or by a stored procedure.

Whereas I would be very curious to see how Mr. Celko sees the equivalent query optimized and executed efficiently:

 SELECT O1.*
    FROM OrgChart AS O1, OrgChart AS O2
   WHERE O1.lft BETWEEN O2.lft AND O2.rgt      AND O2.emp = :myemployee;

The solution with establishing the hierarchy by the property of string keys of being prefixes of all the children key, is far from perfect if the hierarchy is again subject to heavy updates, but in case of largely stable hierarchies it performs quite well (I have reasons to suspect it performs a lot better than Mr. Celko's nested sets model).

And further more it kind of breaks Dr. Codd's information principle that every information should be represented explicitly as a value in a particular column of a particular row. To account for this principle the hierarchical relation would then have to be represented explicitly only in the adjacency list model (the nested set model fails as well), but in practice since we're not dealing with relational databases anyways, we have to adjust to what we have at hand.

The theoretically "right" solution is to use the adjacency list mode, and hope that RDBMSes will eventually come up with the right solution not only to express a recursive query (which can be done currently), but also to index and optimize for speedy retrieval of such queries.

Costin Cozianu

71062.1056_at_compuserve.com (--CELKO--) wrote in message news:<c0d87ec0.0206080913.6b4dc008_at_posting.google.com>...
> >> I need to model a hierarchical, treelike relationship . <<
>
> The usual example of a tree structure in SQL books is called an
> adjacency list model and it looks like this:
>
> CREATE TABLE OrgChart
> (emp CHAR(10) NOT NULL PRIMARY KEY,
> boss CHAR(10) DEFAULT NULL REFERENCES OrgChart(emp),
> salary DECIMAL(6,2) NOT NULL DEFAULT 100.00);
>
> OrgChart
> 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 OrgChart 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
> emps are adjacent to each other.
>
> CREATE TABLE OrgChart
> (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) );
>
> OrgChart
> 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 OrgChart 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 OrgChart 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 OrgChart),
> 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.

You prove nothing, following this logic any schema at all that has foreign keys is denormalized because if we update/delete the primary key in the master table we have to propagate the changes.

However, you know very well, this is no proof of denormalization, by any definition.

> 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 emps with ovals, then nest
> subordinate ovals inside each other. The root will be the largest oval
> and will contain every other emp. The leaf emps 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 emp, 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 emp 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 emp, he puts a
> number in the cell on the side that he is visiting and increments his
> counter. Each emp 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
> OrgChart.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 emps 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 O2.*
> FROM OrgChart AS O1, OrgChart AS O2
> WHERE O1.lft BETWEEN O2.lft AND O2.rgt
> AND O1.emp = :myemployee;
>
> 2. The employee and all subordinates. There is a nice symmetry here.
>
> SELECT O1.*
> FROM OrgChart AS O1, OrgChart AS O2
> WHERE O1.lft BETWEEN O2.lft AND O2.rgt
> AND O2.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 O2.emp, SUM(S1.salary)
> FROM OrgChart AS O1, OrgChart AS O2,
> Salaries AS S1
> WHERE O1.lft BETWEEN O2.lft AND O2.rgt
> AND O1.emp = S1.emp
> GROUP BY O2.emp;
>
> 4. To find the level of each emp, so you can print the tree as an
> indented listing.
>
> DECLARE Out_Tree CURSOR FOR
> SELECT O1.lft, COUNT(O2.emp) AS indentation, O1.emp
> FROM OrgChart AS O1, OrgChart AS O2
> WHERE O1.lft BETWEEN O2.lft AND O2.rgt
> GROUP BY O1.emp
> ORDER BY O1.lft;
>
> 5. The nested set model has an implied ordering of siblings which the
> adjacency list model does not. To insert a new emp as the rightmost
> sibling.
>
> UPDATE OrgChart
> SET lft = lft + 2,
> rgt = rgt + 2
> WHERE rgt >= (SELECT rgt -- right_most_sibling
> FROM OrgChart
> WHERE emp = :your_boss);
>
> INSERT INTO OrgChart (emp, lft, rgt)
> VALUES ('New Guy', right_most_sibling, (right_most_sibling + 1))
> END;
>
> 6. To convert a nested sets model into an adjacency list model:
>
> SELECT B.emp AS boss, P.emp
> FROM OrgChart AS P
> LEFT OUTER JOIN
> OrgChart AS B
> ON B.lft
> = (SELECT MAX(lft)
> FROM OrgChart AS S
> WHERE P.lft > S.lft
> AND P.lft < S.rgt);
>
> For details, see the chapter in my book JOE CELKO'S SQL FOR SMARTIES
> (Morgan-Kaufmann, 1999, second edition)
>
> http://searchdatabase.techtarget.com/tip/1,289483,sid13_gci537290,00.html
>
> http://searchdatabase.techtarget.com/tip/1,289483,sid13_gci801943,00.html
Received on Mon Jun 10 2002 - 05:08:40 CEST

Original text of this message