Re: Ordering dependency problem

From: --CELKO-- <71062.1056_at_compuserve.com>
Date: 17 Jan 2002 10:44:05 -0800
Message-ID: <c0d87ec0.0201171044.656f8b4_at_posting.google.com>


Let me add some DDL for your example:

CREATE TABLE Personnel
(job_nbr INTEGER NOT NULL PRIMARY KEY,
 employee CHAR(10) NOT NULL DEFAULT 'none',  boss CHAR(10) NOT NULL DEFAULT 'none',
 salary DECIMAL (12,4) NOT NULL);

INSERT INTO Personnel VALUES (1, 'Smith', 'Brown', 10.0000);
INSERT INTO Personnel VALUES (2, 'Jones', 'none', 9.0000);
INSERT INTO Personnel VALUES (3, 'Brown', 'Jones', 11.0000);

>> ... do an update which gives a 20% pay cut to all employees who earn more than their managers. ... The problem is: the update result will be different due to the different record sequences in the disk pages. For case(1) only Brown's salary is changed, for case(2), Brown and Smith's salary will be changed. <<

In SQL, all the rows are changed at once:

 UPDATE Personnel

    SET salary = salary * 0.8000
  WHERE salary > (SELECT salary

                    FROM Personnel AS P2
                   WHERE P2.employee = Personnel.boss);

The usual implimentation is to make a pass to match the qualified rows, as the data stands at that time:

 (2, 'Jones', 'none', 9.0000)
 (1, 'Smith', 'Brown', 10.0000)              
 (3, 'Brown', 'Jones', 11.0000) <==

Then apply the SET clause:

 (2, 'Jones', 'none', 9.0000)
 (1, 'Smith', 'Brown', 10.0000)              
 (3, 'Brown', 'Jones',  8.8000) <==

The real problem is that this is not a normalized table!! A poor model.

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

Your table would become:

CREATE TABLE Personnel
(employee CHAR(10) NOT NULL PRIMARY KEY,  lft INTEGER NOT NULL,
 rgt INTEGER NOT NULL,
 salary DECIMAL (12,4) NOT NULL);

INSERT INTO Personnel VALUES ('Smith', 3, 4, 10.0000);              
INSERT INTO Personnel VALUES ('Jones', 1, 6, 9.0000);
INSERT INTO Personnel VALUES ('Brown', 2, 5, 11.0000);

Now, you can enforce the rule about managers being paid more that subordinates:

 UPDATE Personnel

    SET salary = salary * 0.8000
  WHERE salary

        > ANY (SELECT salary
                 FROM Personnel AS P2
                WHERE Personnel.lft
                      BETWEEN P2.lft AND P2.rgt);

pass one:

('Jones', 1, 6, 9.0000) 
('Brown', 2, 5, 11.0000) <==
('Smith', 3, 4, 10.0000) <==

pass two:

('Jones', 1, 6, 9.0000) 
('Brown', 2, 5, 8.8000) 
('Smith', 3, 4, 8.0000) 

I think this is the answer you wanted. Butif you wanted to scale donw everyone's salary to be less than any of their superiors, you will have to work harder. Received on Thu Jan 17 2002 - 19:44:05 CET

Original text of this message