self join

E

eb1mom

I have a table with long list of single parts that will be
used in sets. I believe I need to create a self join field
to create sets. I searched knowledge base but must not be
phrasing correctly. Could you direct me to information on
how to create a self join. Thanks
 
C

Chris

Hopefully this helps:

Quote:

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.

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 theadjacency list model does not. To insert
a new node, G1, under part G. We can insert one node at a
time like this:

BEGIN ATOMIC
DECLARE right_most_sibling INTEGER;

SET right_most_sibling
= (SELECT rgt
FROM Frammis
WHERE part = 'G');
UPDATE Frammis
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 Frammis (part, qty, wgt, lft, rgt)
VALUES ('G1', 3, 4, parent, (parent + 1));
COMMIT WORK;
END;

The idea is to spread the lft and rgt numbers after the
youngest child of the parent, G in this case, over by two
to make room for the new addition, G1. This procedure
will add the new node to the rightmost child position,
which helps to preserve the idea of an age order among the
siblings.

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_gci
537290,00.htm


http://searchdatabase.techtarget.com/tip/1,289483,sid13_gci
801943,00.htm

--CELKO--
 
R

Roger Carlson

If you simply want to know how to physically create a self-join in Access,
show the same table in the query builder twice. The second time you add it,
it will add a "1" to the end. Don't worry about it. Then just click and
drag between the tables as usual.
 
J

John Vinson

I have a table with long list of single parts that will be
used in sets. I believe I need to create a self join field
to create sets. I searched knowledge base but must not be
phrasing correctly. Could you direct me to information on
how to create a self join. Thanks

I don't think a self join is really appropriate here; instead, I think
you may need a "Sets" table. Some questions:

- Can a Set contain Sets as components? Can those Sets contain Sets?
If so, you have a "Bill of Materials" structure, and the adjacency
model posted by Chris will be worth some (admittedly mind-stretching!)
study.

- If not, does a given part belong to only one Set? Or might a "left
handed 3cm widget" be a part of several different Sets?
 
E

eb1mom

All parts are assigned to single set almost for life. The
only exception would be a broken part junked out and
remaining part assigned a new life partner. Sets are two
parts that are used together. Right widget, left widget.
Used as a set, remachined and used as a set over and over
until they are too small to be remachined. They are
identifed by foundry number. I am attempting to assign set
number to widgets. IE set#1 could be made up of widget
foundry#52 and widget foundry#342.There is a lot of other
information associated with widget so it still needs to
retain foundryID. When in use the two widgets must be
EXACTLY the same size which is why we assign to a set.
 
J

John Vinson

All parts are assigned to single set almost for life. The
only exception would be a broken part junked out and
remaining part assigned a new life partner. Sets are two
parts that are used together. Right widget, left widget.
Used as a set, remachined and used as a set over and over
until they are too small to be remachined. They are
identifed by foundry number. I am attempting to assign set
number to widgets. IE set#1 could be made up of widget
foundry#52 and widget foundry#342.There is a lot of other
information associated with widget so it still needs to
retain foundryID. When in use the two widgets must be
EXACTLY the same size which is why we assign to a set.

Three possible solutions:

- Create a table of Sets; assign each Part a SetID as a link to that
part's set.

- If it's ALWAYS, without *any* exception, pairs - then you could add
a PairMate field of the same data type as the FoundryID; each part
would have its opposite number in this field. This is a bit risky
since there's no assurance (in the structure of your table) that the
relationship is reciprocal.

- Still for pairs: define the right part first, and have a link in
each "left" widget record to its corresponding "right".
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top