Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Query Help Expand / Collapse
Author
Message
Posted Thursday, November 29, 2012 11:50 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, June 25, 2013 9:13 PM
Points: 190, Visits: 637
I've a table like below:

CREATE TABLE #Emp
( Emp char(6), UplineEmp char(6), Lvl tinyint) ;

insert #Emp ([Emp], [UplineEmp], Lvl)
values
('209156' ,'003033' ,17)
, ('209156' ,'152870' ,16)
, ('209156' ,'147013' ,15)
, ('209156' ,'209156' ,5 )
/*******/
, ('211840' ,'003033' ,17)
, ('211840' ,'033616' ,15)
, ('211840' ,'211627' ,7 )
, ('211840' ,'211840' ,5 ) ;

Result set should be:
CREATE TABLE #AR
(
AgtNum varchar(20), DirectUpline Varchar(20),
Lvl0 Varchar(20), Lvl1 Varchar(20)
, Lvl2 Varchar(20),Lvl3 Varchar(20)
, Lvl4 Varchar(20), Lvl5 Varchar(20)
)

INSERT #AR
VALUES ('209156', '147013', '003033', '152870','147013',NULL,NULL,NULL)
, ('211840', '211627', '003033', '033616','211627',NULL,NULL,NULL)

SELECT * FROM #AR

Employees have a row with themselves as an upline, so the direct upline is an employee one level up (using the Lvl column).

Lvl0 column in result set is the top level employee, all other level columns should be populated respectively. NULL should be shown when hierarchy is ragged.

Can you please help me with a decently running query, I could write only a cursor and it's slow with over 2million rows I have.

Appreciate your time.
Post #1390751
Posted Thursday, November 29, 2012 12:25 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 8:56 PM
Points: 13,078, Visits: 12,529
Nice job posting ddl and sample data along with desired output. However it is totally unclear what the logic should be here.

This looks somewhat like an adjacency list except it is recursive and incomplete. What is the logic of having an Emp and UplineEmp be the same? What is the logic that determines DirectUpline? What about Lvl0 - Lvl5?


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1390776
Posted Thursday, November 29, 2012 3:04 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 11:21 AM
Points: 1,945, Visits: 3,062
I've a table like below:


No, it is not a table because it has no key. The column names do not follow ISO-11179 rules and it has no integrity constraints.

Can you please help me with a decently running query, I could write only a cursor and it's slow with over 2 million rows I have.


There are many ways to represent a tree or hierarchy in SQL. This is called an adjacency list model and it looks like this:

CREATE TABLE OrgChart
(emp_name CHAR(10) NOT NULL PRIMARY KEY,
boss_emp_name CHAR(10) REFERENCES OrgChart(emp_name),
salary_amt DECIMAL(6,2) DEFAULT 100.00 NOT NULL,
<< horrible cycle constraints >>);

OrgChart
emp_name boss_emp_name salary_amt
==============================
'Albert' NULL 1000.00
'Bert' 'Albert' 900.00
'Chuck' 'Albert' 900.00
'Donna' 'Chuck' 800.00
'Eddie' 'Chuck' 700.00
'Fred' 'Chuck' 600.00

This approach will wind up with really ugly code -- CTEs hiding recursive procedures, horrible cycle prevention code, etc. The root of your problem is not knowing that rows are not records, that SQL uses sets and trying to fake pointer chains with some vague, magical non-relational "id".

This matches the way we did it in old file systems with pointer chains. Non-RDBMS programmers are comfortable with it because it looks familiar -- it looks like records and not rows.

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.

CREATE TABLE OrgChart
(emp_name 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_name lft rgt
======================
'Albert' 1 12
'Bert' 2 3
'Chuck' 4 11
'Donna' 5 6
'Eddie' 7 8
'Fred' 9 10

The (lft, rgt) pairs are like tags in a mark-up language, or parens in algebra, BEGIN-END blocks in Algol-family programming languages, etc. -- they bracket a sub-set. This is a set-oriented approach to trees in a set-oriented language.

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 adjacency list 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_emp_name and employee columns are the same kind of thing (i.e. identifiers 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, and 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 (lft, rgt) columns (I cannot use the reserved words LEFT and RIGHT in SQL) are what show the nesting. This is like XML, HTML or parentheses.

At this point, the boss_emp_name 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 OrgChart.boss_emp_name 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 O2.*
FROM OrgChart AS O1, OrgChart AS O2
WHERE O1.lft BETWEEN O2.lft AND O2.rgt
AND O1.emp_name = :in_emp_name;

2. The employee and all their 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_name = :in_emp_name;

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_name, SUM(S1.salary_amt)
FROM OrgChart AS O1, OrgChart AS O2,
Salaries AS S1
WHERE O1.lft BETWEEN O2.lft AND O2.rgt
AND S1.emp_name = O2.emp_name
GROUP BY O2.emp_name;

4. To find the level and the size of the subtree rooted at each emp_name, so you can print the tree as an indented listing.

SELECT O1.emp_name,
SUM(CASE WHEN O2.lft BETWEEN O1.lft AND O1.rgt
THEN O2.sale_amt ELSE 0.00 END) AS sale_amt_tot,
SUM(CASE WHEN O2.lft BETWEEN O1.lft AND O1.rgt
THEN 1 ELSE 0 END) AS subtree_size,
SUM(CASE WHEN O1.lft BETWEEN O2.lft AND O2.rgt
THEN 1 ELSE 0 END) AS lvl
FROM OrgChart AS O1, OrgChart AS O2
GROUP BY O1.emp_name;

5. The nested set model has an implied ordering of siblings which the adjacency 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 rightmost_spread INTEGER;

SET rightmost_spread
= (SELECT rgt
FROM Frammis
WHERE part = 'G');
UPDATE Frammis
SET lft = CASE WHEN lft > rightmost_spread
THEN lft + 2
ELSE lft END,
rgt = CASE WHEN rgt >= rightmost_spread
THEN rgt + 2
ELSE rgt END
WHERE rgt >= rightmost_spread;

INSERT INTO Frammis (part, lft, rgt)
VALUES ('G1', rightmost_spread, (rightmost_spread + 1));
COMMIT WORK;
END;

The idea is to spread the (lft, 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_name AS boss_emp_name, E.emp_name
FROM OrgChart AS E
LEFT OUTER JOIN
OrgChart AS B
ON B.lft
= (SELECT MAX(lft)
FROM OrgChart AS S
WHERE E.lft > S.lft
AND E.lft < S.rgt);

7. To find the immediate parent of a node:

SELECT MAX(P2.lft), MIN(P2.rgt)
FROM Personnel AS P1, Personnel AS P2
WHERE P1.lft BETWEEN P2.lft AND P2.rgt
AND P1.emp_name = @my_emp_name;

I have a book on TREES & HIERARCHIES IN SQL which you can get at Amazon.com right now. It has a lot of other programming idioms for nested sets, like levels, structural comparisons, re-arrangement procedures, etc.


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1390881
Posted Friday, November 30, 2012 1:41 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Tuesday, October 7, 2014 10:53 PM
Points: 3,421, Visits: 5,359
This resolves the simple case you've given us, however I suspect it may not be the solution to your problem.

;WITH CTE AS (
SELECT AgentNum
,Lvl0=MAX(CASE n WHEN 1 THEN UplineEmp END)
,Lvl1=MAX(CASE n WHEN 2 THEN UplineEmp END)
,Lvl2=MAX(CASE n WHEN 3 THEN UplineEmp END)
,Lvl3=MAX(CASE n WHEN 4 THEN UplineEmp END)
,Lvl4=MAX(CASE n WHEN 5 THEN UplineEmp END)
,Lvl5=MAX(CASE n WHEN 6 THEN UplineEmp END)
FROM (
SELECT AgentNum=Emp, UplineEmp, Lvl
,n=CASE WHEN Emp=UplineEmp THEN 0
ELSE ROW_NUMBER() OVER (PARTITION BY Emp ORDER BY Lvl DESC) END
FROM #Emp) a
GROUP BY AgentNum)
SELECT AgentNum
,DirectUpline=COALESCE(Lvl5, Lvl4, Lvl3, Lvl2, Lvl1, Lvl0)
,Lvl0, Lvl1, Lvl2, Lvl3, Lvl4, Lvl5
FROM CTE


It won't work if you need to resolve multiple levels of hiearchy but you haven't given us any data or expected results for a case like that.

If you give us more, perhaps we can take it to the next level.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1391095
Posted Friday, November 30, 2012 8:57 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, June 25, 2013 9:13 PM
Points: 190, Visits: 637
Thanks All.

Dwain - Query works for me, but i don't think i understand what you mean by resolving multiple levels of hierarchy - my ignorance. I always have a predefined number of levels in the hierarchy. So, I'm thinking it should always work.
Post #1391398
Posted Sunday, December 2, 2012 1:04 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Tuesday, October 7, 2014 10:53 PM
Points: 3,421, Visits: 5,359
UnionAll (11/30/2012)
Thanks All.

Dwain - Query works for me, but i don't think i understand what you mean by resolving multiple levels of hierarchy - my ignorance. I always have a predefined number of levels in the hierarchy. So, I'm thinking it should always work.


If it works then it works. I think earlier posters didn't recognize that hiearchy depth was fixed in your sample data so that is why I posted what I did to show that no recursion was needed (if not additional depth applies).



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1391703
Posted Monday, December 3, 2012 9:50 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 11:21 AM
Points: 1,945, Visits: 3,062
I always have a predefined number of levels in the hierarchy.


Then each of these levels is an attribute and it gets its own column. You do not build fake pointer chains.


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1392044
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse