Re: recursive relationship

From: <joe_celko_at_my-deja.com>
Date: 2000/01/12
Message-ID: <85isu1$m68$1_at_nnrp1.deja.com>


>> I do not understand very well the concept of a recursive
relationship. Could someone please explain and give me an example? <<

There are two fundamental ways to define something: (1) Intention and (2) Extension. An Intentional definition gives a list of the elements in the relationship ("THIS is what I mean!"). An Extentional definition gives a rule to determine if an element is or is not in the relationship. Recursion is a special kind of extentional definition. It uses the rule itself to define the rule. For example, the factorial function can be recursively defined by the rule that

 n! := IF (n = 0)

       THEN 1
       ELSE n *(n-1)!
       END IF;

 4! = 4 * 3!
    = 4 * 3 * 2!
    = 4 * 3 * 2 * 1!

There are also many kinds of recursion -- simple, primitive, nonprimitive,  etc. -- if you want to bored to death, ask a mathematician about them. All finite recursive definitions must have a "fixed point", which is something that stops recursing (i.e. (n=0) in this example).

>> A sample sql statement that creates a table with such a
relationship would be appreciated too. <<

This will take a bit more time than I have right now, but get a good book on DB2 and look up the WITH operator, which is part of the SQL-99 specification. DB2 is the only product that has this operator, as far as I know. It is very powerful and it lets you do queries on top of the results queries. That is a recursive query.

Oracle has a CONNECT BY operator which is similar in the weakest possible way.

Now, for tables, most people mean that the table holds a hierarchical relationship (organizational chart, Bill of Materials, etc.).

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:

 CREATE TABLE Personnel
 (emp CHAR(10) PRIMARY KEY,
  boss CHAR(10), -- this column is unneeded & denormalizes the table
  salary DECIMAL(6,2) NOT NULL,
  lft INTEGER NOT NULL,
  rgt INTEGER NOT NULL);

 Personnel
 emp boss salary lft rgt


 Albert   NULL     1000.00   1   12
 Bert     Albert    900.00   2    3
 Chuck    Albert    900.00   4   11
 Donna    Chuck     800.00   5    6
 Eddie    Chuck     700.00   7    8
 Fred     Chuck     600.00   9   10

 which 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)

This (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. The 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.

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 havehierarchical reports. For example, the total salaries which each employee controls:

 SELECT P2.emp, SUM(P1.salary)
   FROM Personnel AS P1, Personnel AS P2   WHERE P1.lft BETWEEN P2.lft AND P2.rgt   GROUP BY P2.emp;

This will be two to three orders of magnitude faster than the adjacency list model.

For details, see the chapter in my book JOE CELKO'S SQL FOR SMARTIES by Joe Celko, Morgan-Kaufmann, 1995, ISBN 1-55860-323-9 or my columns in DBMS magazine in 1996 March, April, May and June issues. I went into details as to how to manipulate this model.

--CELKO-- Sent via Deja.com http://www.deja.com/
Before you buy. Received on Wed Jan 12 2000 - 00:00:00 CET

Original text of this message