Re: Storing a tree

Поиск
Список
Период
Сортировка
От Christian Meunier
Тема Re: Storing a tree
Дата
Msg-id 9sect9$1fet$1@news.tht.net
обсуждение исходный текст
Ответ на Storing a tree  (Antonio Fiol Bonnín <fiol@w3ping.com>)
Ответы Re: Storing a tree  (Micah Yoder <yodermk@home.com>)
Re: Storing a tree  (knut.suebert@web.de)
Список pgsql-general
Instead of the adjacency model, you can try the nested sets one.
Here is the Celko's article on this issue:

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 via a cursor.

DECLARE PrintTree CURSOR FOR
SELECT COUNT(P2.emp) AS indentation, P1.lft, 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.


"Antonio Fiol Bonn�n" <fiol@w3ping.com> wrote in message
news:3BEA7B0E.A6EFA5E6@w3ping.com...
> Hello,
>
> I have found a problem today to which I am unable to find the solution.
> I write to this list looking for help.
>
> I have been using PostgreSQL for about a year or so, and I manage a
> quite large database. I usually design extensions to it, create new
> tables and views, indexes, and many more. In short, it's not my first
> database application.
>
> I would like to store a tree in the database. A tree much like a
> directory tree, with un unknown depth.
>
> However, in my case, the order of the leafs (left to right) is
> important.
>
> I tried to implement the tree as a table:
>
> CREATE TABLE tree ( father_id int, son_id int );
>
> Then, I can easily find all sons for a father. Even in correct order:
>
> SELECT son_id FROM tree WHERE father_id=1234 ORDER BY son_id;
>
> Even if I wish to use another ordering, I could:
>
> CREATE TABLE tree (father_id int, son_id int );
> CREATE TABLE people ( person_id int, name text, age int );
> and then
> SELECT people.person_id, people.name, people.age FROM tree, people WHERE
> tree.father_id=1234 AND tree.son_id=people.person_id
> ORDER BY people.age;
>
> For one generation, all works well. I could also extend that up to 2
> generations, but not until the sons have no more sons. Could someone
> help me find a way to output the data in the following way ?
>
>
> Peter, 90
> John (Peter's son), 65
> Richard (John's son), 44
> William (John's son), 45
> Philip (William's son), 20
> Tony (Peter's son), 70
> Other (Tony's son), 50
>
> Two things are crucial: ORDER and MULTIPLE GENERATIONS.
>
> The genealogic example is given only to avoid explaining the complexity
> of our application design. We are a company specialized in web server
> performance monitoring, so genealogic studies is not our core business
> ;-) This way, I thought I could simplify the understanding of the
> problem.
>
> I am certain that others have been faced to similar problems, so
> probably someone may help me.
>
> Thank you all for any lights you can shed on this problem.
>
> Antonio Fiol
>
> P.S. Other similar problems I can think of:
>
> Relation Boss --> Employee (though depth is finite in this case).
>
> History of people owning an object (though only one "son" per "father",
> so no ordering issue)
>
> A directory tree (without any files).
>
>
>
>
> ---------------------------(end of broadcast)---------------------------
> TIP 2: you can get off all lists at once with the unregister command
>     (send "unregister YourEmailAddressHere" to majordomo@postgresql.org)



В списке pgsql-general по дате отправления:

Предыдущее
От: "mike sears"
Дата:
Сообщение: searching multiple tables and databases
Следующее
От: qradius@qnet.com.pe
Дата:
Сообщение: Problem with function