next level indicator

next level indicator

Post by Cind » Wed, 10 Apr 2002 01:55:16



I need a sprocs to return me the subcategory name  and
indicator about if there is a subcategory under that
subcategory (bit value) . what should I do?

create table tblcategory
(categoryid int)

insert into tblcategory values (0)
insert into tblcategory values (1)
insert into tblcategory values (2)
insert into tblcategory values (3)
insert into tblcategory values (4)
insert into tblcategory values (5)

create table tblcategoryconfig
(categoryid int,
subcategoryid int,
node int)

insert into tblcategoryconfig values (0,1,1)
insert into tblcategoryconfig values (0,2,1)
insert into tblcategoryconfig values (1,3,2)
insert into tblcategoryconfig values (1,4,2)
insert into tblcategoryconfig values (4,5,3)

for instance, if I get input paramenter  categoryid = 0
I should get a record set

subcategoryid,  subcategoryindicator
 1                      1
 2                      1

if input is categoryid = 1

I should get a record set

subcategoryid,  subcategoryindicator
 3                      0      -- no sub under this
 4                      1      -- sub 5  under this

any suggestion?  Thanks in advance!

Cindy

 
 
 

next level indicator

Post by Joe Celk » Wed, 10 Apr 2002 02:59:00


1) Stop using that silly "tbl-" prefix; you are not writing in BASIC or
early version of FORTRAN.

2) Learn to declare tables with keys; if you do not have a key it is not
a table!!  Also, stop making EVERY column NULL-able.  

3) 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 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.htm
l

http://searchdatabase.techtarget.com/tip/1,289483,sid13_gci801943,00.htm
l

--CELKO--
 ===========================
 Please post DDL, so that people do not have to guess what the keys,
constraints, Declarative Referential Integrity, datatypes, etc. in your
schema are.

*** Sent via Developersdex http://www.developersdex.com ***
Don't just participate in USENET...get rewarded for it!

 
 
 

next level indicator

Post by lindawi » Wed, 10 Apr 2002 15:50:00


Cindy,

Maybe you can do somethign like this:


as
select  subcategoryid,  
        case when exists (select * from tblcategoryconfig c2
                          where c1.subcategoryid = c2.categoryid)
        then 1 else 0 end subcategoryindicator
from    tblcategoryconfig c1

order by subcategoryid
go
exec listsubcategories 0
exec listsubcategories 1
go
drop procedure listsubcategories

Linda

 
 
 

next level indicator

Post by Cind » Fri, 12 Apr 2002 06:27:20


I really like your idea. but I have another question for
you.  if a child has more than one parents. the method you
showed here won't work. so is there any better design to
take care this issue.  Thanks!

Cindy

>-----Original Message-----
>1) Stop using that silly "tbl-" prefix; you are not
writing in BASIC or
>early version of FORTRAN.

>2) Learn to declare tables with keys; if you do not have
a key it is not
>a table!!  Also, stop making EVERY column NULL-able.  

>3) 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.

- Show quoted text -

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

- Show quoted text -

>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_gc
i537290,00.htm
>l

>http://searchdatabase.techtarget.com/tip/1,289483,sid13_gc
i801943,00.htm
>l

>--CELKO--
> ===========================
> Please post DDL, so that people do not have to guess
what the keys,
>constraints, Declarative Referential Integrity,

datatypes, etc. in your

- Show quoted text -

>schema are.

>*** Sent via Developersdex http://www.developersdex.com
***
>Don't just participate in USENET...get rewarded for it!
>.

 
 
 

next level indicator

Post by Joe Celk » Fri, 12 Apr 2002 23:46:27


Quote:>> if a child has more than one parent, the method you

showed here won't work. <<

Then you do not have a category hierarchy, by definition.  The nature of
a tree is that every node has one and only one parent unless it is the
root, and then it has none.  

However, since you are spliting out the structure (Org Chart) from the
nodes (Personnel), you have options.  The first is to allow the same
node to appear in several places in the tree.  Example: a parts
explosion that uses the same size*in different sub-assemblies.

The other option is to have more than one heirarchy on the same set of
nodes.  My favorite example was a shoe company that had one hierarchy
for reporting in the manufacturing side of the house (very static, based
on physical construction) and another for sales (very dynamic, based on
fads and fashion).  For manufacturing, a steel-toed work boot was one
product category.  For sales, a small steel-toed work boot was a totally
different product from a large steel-toed work boot; the small ones sold
to *aged girls in fancy show stores, the large ones sold to men in
construction trades.  

--CELKO--
 ===========================
 Please post DDL, so that people do not have to guess what the keys,
constraints, Declarative Referential Integrity, datatypes, etc. in your
schema are.

*** Sent via Developersdex http://www.veryComputer.com/ ***
Don't just participate in USENET...get rewarded for it!