Oracle select command equivalent in Sql server help

Oracle select command equivalent in Sql server help

Post by Haris Kusum » Mon, 03 Dec 2001 21:54:22



Hi,

Can you tell me what is the equivalent the following oracle command in
sqlserver 2000, please

SELECT company_id, name
FROM company
WHERE state = 'WA'
CONNECT BY parent_company_id = prior company_id
START WITH company_id = 1


Thanks in advance

Regards
- Haris -

 
 
 

Oracle select command equivalent in Sql server help

Post by lindawi » Tue, 04 Dec 2001 02:42:07


Haris,

SQL Server does not support anything equivalent for expanding hierarchies.
If you can get a hold of "Advanced Transact-SQL for SQL Server 2000" by
Itzik Ben-Gan & Tom Moreau (ISBN 1-893115-82-8), you will find a whole
chapter devoted to processing hierarchies. Itzik posted an excerpt from the
book in this thread:

http://groups.google.com/groups?q=+%22hierarchy%22+author:itzik+autho...
an&hl=en&rnum=1&selm=OblRqzS8AHA.1028%40tkmsftngp07

Linda


> Hi,

> Can you tell me what is the equivalent the following oracle command in
> sqlserver 2000, please

> SELECT company_id, name
> FROM company
> WHERE state = 'WA'
> CONNECT BY parent_company_id = prior company_id
> START WITH company_id = 1


> Thanks in advance

> Regards
> - Haris -


 
 
 

Oracle select command equivalent in Sql server help

Post by frederic brouar » Tue, 04 Dec 2001 02:51:57


Hi men,

CONNECT BY is a non standard SQL Statement only for Oracle.
You can use a SQL 3 approach (I did not know if SQL 2000 use it) with the
keywords RECURSIVE and CYCLE.
Another way is to make a tree inside a table without the classical approach
of referencing the father but with the technic of the intervals.
This is describe in a paper I made (in french) readable at :
http://sqlpro.multimania.com/Tree/SQL_tree.htm
In english, Joe Celko had made a paper in SQL for smarties (Morgan Kaufman
books).
This technic does not need any recursive SQL order to find anything you want
in a tree with only one query !!!

A +

--
Fred BROUARD - dit Le Perroquet - Livre "SQL" Collection rfrence
Editeur Campus Press - 2001-09-01 :
http://sqlpro.multimania.com/bookSQL.html
Site Web & Forum SQLpro (SQL)     : http://sqlpro.multimania.com
Expert Paradox spcialiste Delphi : http://perso.club-internet.fr/brouardf



> Hi,

> Can you tell me what is the equivalent the following oracle command in
> sqlserver 2000, please

> SELECT company_id, name
> FROM company
> WHERE state = 'WA'
> CONNECT BY parent_company_id = prior company_id
> START WITH company_id = 1


> Thanks in advance

> Regards
> - Haris -

 
 
 

Oracle select command equivalent in Sql server help

Post by BP Margoli » Tue, 04 Dec 2001 07:16:45


Haris,

Check out the section "Expanding Hierarchies" in the SQL Server Books
Online.

-------------------------------------------
BP Margolin
Please reply only to the newsgroups.
When posting, inclusion of SQL (CREATE TABLE ..., INSERT ..., etc.) which
can be cut and pasted into Query Analyzer is appreciated.


> Hi,

> Can you tell me what is the equivalent the following oracle command in
> sqlserver 2000, please

> SELECT company_id, name
> FROM company
> WHERE state = 'WA'
> CONNECT BY parent_company_id = prior company_id
> START WITH company_id = 1


> Thanks in advance

> Regards
> - Haris -

 
 
 

Oracle select command equivalent in Sql server help

Post by Joe Celk » Tue, 04 Dec 2001 07:19:10


This is a hidden cursor which is proprietary, non-relational and seriously limited.  

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;

6. To convert an adjacency list model into a nested set model, use a push down stack algorithm.  Assume that we have these tables:

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)

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

 
 
 

Oracle select command equivalent in Sql server help

Post by Steve Dassi » Tue, 04 Dec 2001 07:48:28



Quote:> You can use a SQL 3 approach (I did not know if SQL 2000 ?>use it) with

the keywords RECURSIVE and CYCLE.

Do you know any product that has implemented this?

Steve