Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Hierarchy without cursor/loop


Hierarchy without cursor/loop

Author
Message
ansaryarshad
ansaryarshad
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 18
Hi Experts

I have a situation in which I want to avoid cursors/loops .Suppose I have a table in the below format
Node Parent_Node
A
B A
C B
D C
E
F E
G F
H G

Here A and E are the parent root nodes(Lets call them root nodes) which does not have any parent node and from which all nodes originate . Now I want to find out the root node for any given node.For e.g I want output like belw

Node Parent_Node
A A
B A
C A
D A
E E
F E
G E
H E

BR
Arshad
Thom A
Thom A
SSCarpal Tunnel
SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)

Group: General Forum Members
Points: 4040 Visits: 4618
Something like this?
CREATE TABLE #EMP (EmpID CHAR(1),
MgrID CHAR(1));
GO

INSERT INTO #EMP
VALUES
('A',NULL),
('B','A'),
('C','B'),
('D','C'),
('E',NULL),
('F','E'),
('G','F'),
('H','G');

GO

SELECT *
FROM #EMP;
GO

WITH Hierachy AS(
SELECT E.EmpID,
E.EmpID AS MgrID,
E.EmpID AS MstID,
1 AS HLevel
FROM #EMP E
WHERE E.MgrID IS NULL

UNION ALL

SELECT E.EmpID,
H.EmpID AS MgrID,
H.MstID,
H.Hlevel + 1 AS HLevel
FROM #EMP E
JOIN Hierachy H ON E.MgrID = H.EmpID
)
SELECT H.EmpID,
--H.MgrID,
H.MstID
FROM Hierachy H
ORDER BY H.EmpID;
GO

DROP TABLE #EMP
GO





Thom~

Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

There are 10 types of people in the world. Those that understand Binary, and those that don't.

Please always remember to encapsulate your code in IFCode Markup. For example [code="sql"] [/code].

Click here to read Jeff's Guide on how to post SQL questions, and get swift and helpful answers from the community
Luis Cazares
Luis Cazares
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13748 Visits: 18796
Here's an option that might work better than a rCTE. This article was written from experience on a problem very similar to what you're describing.
It uses a loop, but it's a very efficient loop because it is set-based. Check it out and let me know if you have any questions. I'll try to make the author to reply Smile.
http://www.sqlservercentral.com/articles/set-based+loop/127670/


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
ansaryarshad
ansaryarshad
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 18
Hi Thom,

Thanks for the post . But the condtion

E.MgrID = H.EmpID
will not work for Node C as its Parent Node is B which is not in H table

BR
Arshad
Luis Cazares
Luis Cazares
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13748 Visits: 18796
ansaryarshad - Monday, March 20, 2017 12:01 PM
Hi Thom,

Thanks for the post . But the condtion

E.MgrID = H.EmpID
will not work for Node C as its Parent Node is B which is not in H table

BR
Arshad


I don't understand what you're talking about. Thom's code works as expected and I'm sure that he tested it before posting.
What do you mean when you state that the condition will not work?



Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)

Group: General Forum Members
Points: 70670 Visits: 40738
ansaryarshad - Monday, March 20, 2017 12:01 PM
Hi Thom,

Thanks for the post . But the condtion

E.MgrID = H.EmpID
will not work for Node C as its Parent Node is B which is not in H table

BR
Arshad


Did you actually try running the code? Seems to work for me.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Thom A
Thom A
SSCarpal Tunnel
SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)

Group: General Forum Members
Points: 4040 Visits: 4618


Luis Cazares - Monday, March 20, 2017 12:17 PM
ansaryarshad - Monday, March 20, 2017 12:01 PM
Hi Thom,

Thanks for the post . But the condtion

E.MgrID = H.EmpID
will not work for Node C as its Parent Node is B which is not in H table

BR
Arshad


I don't understand what you're talking about. Thom's code works as expected and I'm sure that he tested it before posting.
What do you mean when you state that the condition will not work?


Luis is right,. I did test it. Did you, ansaryarshad? If so, what were the results you got and what was the SQL you ran? Wondering if you modified it incorrectly.

On a different note, Luis, found your articule quite interesting. I avoid hierarchy data as much as I can, so I can't see any applications for myself, but if the OP does have as many users as you did, then would be worth while him making use of.



Thom~

Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

There are 10 types of people in the world. Those that understand Binary, and those that don't.

Please always remember to encapsulate your code in IFCode Markup. For example [code="sql"] [/code].

Click here to read Jeff's Guide on how to post SQL questions, and get swift and helpful answers from the community
ansaryarshad
ansaryarshad
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 18
Hi Thom,
Sorry for the reply.
I am coming from an SAP HANA background where CTEs are still evolving . We dont have the option of doing recursive CTE or rCTES (Frankly I was not aware that there existed something like rCTEs).
I tried to breakup your rCTE and did individual select statements.Obviously that did not work ..

BR
Arshad
Luis Cazares
Luis Cazares
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13748 Visits: 18796
ansaryarshad - Wednesday, March 22, 2017 3:52 AM
Hi Thom,
Sorry for the reply.
I am coming from an SAP HANA background where CTEs are still evolving . We dont have the option of doing recursive CTE or rCTES (Frankly I was not aware that there existed something like rCTEs).
I tried to breakup your rCTE and did individual select statements.Obviously that did not work ..

BR
Arshad


Did you tried the method that I explained in the article? It's simple, does not require CTEs and will be very fast.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)SSC Guru (70K reputation)

Group: General Forum Members
Points: 70670 Visits: 40738
ansaryarshad - Wednesday, March 22, 2017 3:52 AM
Hi Thom,
Sorry for the reply.
I am coming from an SAP HANA background where CTEs are still evolving . We dont have the option of doing recursive CTE or rCTES (Frankly I was not aware that there existed something like rCTEs).
I tried to breakup your rCTE and did individual select statements.Obviously that did not work ..

BR
Arshad


Are you working in SQL Server for this problem or not?

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search