SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Recursive select Query


Recursive select Query

Author
Message
bhakti-sonu
bhakti-sonu
SSC Journeyman
SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)

Group: General Forum Members
Points: 96 Visits: 78
A--
|
|-B --
| |-E
| |-F
| ---
|-C--
--- |-D
Suppose this is my hierarchy of Employees. Employee D ReportsTo C and Employee E & F Reports To B. Employee B & C Reports to A.
if i loggin as Employee A then i want to get Records of SalesReport of all the Employees Reports to A and the Employees Reports to his Subordinates and also their Subordinate. That is All records for the abouve given hierarchy.

can I write the Recursive query for this is SQL
RBarryYoung
RBarryYoung
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19092 Visits: 9518
Yes. You will need to use recursive CTE's (Common Table Expressions).

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Saurabh Dwivedy
Saurabh Dwivedy
Mr or Mrs. 500
Mr or Mrs. 500 (582 reputation)Mr or Mrs. 500 (582 reputation)Mr or Mrs. 500 (582 reputation)Mr or Mrs. 500 (582 reputation)Mr or Mrs. 500 (582 reputation)Mr or Mrs. 500 (582 reputation)Mr or Mrs. 500 (582 reputation)Mr or Mrs. 500 (582 reputation)

Group: General Forum Members
Points: 582 Visits: 340
bhakti (5/8/2009)
A--
|
|-B --
| |-E
| |-F
| ---
|-C--
--- |-D
Suppose this is my hierarchy of Employees. Employee D ReportsTo C and Employee E & F Reports To B. Employee B & C Reports to A.
if i loggin as Employee A then i want to get Records of SalesReport of all the Employees Reports to A and the Employees Reports to his Subordinates and also their Subordinate. That is All records for the abouve given hierarchy.

can I write the Recursive query for this is SQL


Usually there are more than one ways of solving a given problem. In order that discussions are not reduced to mere theoretical concepts, please elaborate the underlying data structure a bit more so we can propose concrete solutions.

I hope my comment will be taken in the right spirit.

Regards

Saurabh Dwivedy
___________________________________________________________

My Blog: http://tinyurl.com/dwivedys

For better, quicker answers, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537

Be Happy!
Atif-ullah Sheikh
Atif-ullah Sheikh
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4118 Visits: 5201
CTE will do the job. But need more information about inputs and outputs. For reference, I am assuming the following data structure.


CREATE TABLE #DestinationDept
(
[DestinationDeptID] [int] IDENTITY(1,1) NOT NULL,
[SNO] [int] NOT NULL,
[Desc] [nvarchar](100) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
[ParentID] [int] NULL
)

Insert into #DestinationDept (SNO,[Desc],ParentID)
Select 1,'A',NULL Union all
Select 2,'B',1 Union all
Select 3,'E',2 Union all
Select 4,'F',2 Union all
Select 5,'C',1 Union all
Select 6,'D',5 Union All
Select 7,'H',4


--Select * from #DestinationDept

;with c as (Select DestinationDeptID,ParentID From #DestinationDept where ParentID = 2
UNION ALL Select cs.DestinationDeptID,cs.ParentID From #DestinationDept as CS
Inner Join c on c.DestinationDeptID = cs.ParentID
)
Select * from #DestinationDept As c2
Where C2.DestinationDeptID in (Select c.DestinationDeptID from c)


drop table #DestinationDept




----------------------------------------------------------------------------------------------------------------------------------------------------------------------

Sometimes, winning is not an issue but trying.

You can check my BLOG here


ta.bu.shi.da.yu
ta.bu.shi.da.yu
Mr or Mrs. 500
Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)

Group: General Forum Members
Points: 529 Visits: 494
Hi Atif, in many ways I'm still a relative newbie to SQL Server... your example of a recursive CTE is probably an old technique to some of the regulars, but I'm sure glad I've found out about it!

However, I was wondering if this is guaranteed to maintain the tree order as provided by Bhaki

i.e.


A
|
|=B
| |=E
| \=F
|
|=C
\=D

.



Random Technical Stuff
Atif-ullah Sheikh
Atif-ullah Sheikh
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4118 Visits: 5201
The solution I provided might help. But, as said by other posters, the data structure is required. I posted on my assumption that;

B is descendent of A
E and F are Decendents of B
C is decendent of A
and
D is decendent of C

Now asuming this, I understood that if the OP queries B, he/she needs to get the complete hirarchy from B and its decendents and its decendents' decendents and so on....

I hope the same thing was required...

----------------------------------------------------------------------------------------------------------------------------------------------------------------------

Sometimes, winning is not an issue but trying.

You can check my BLOG here


Mark Cowne
Mark Cowne
Hall of Fame
Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)

Group: General Forum Members
Points: 3744 Visits: 24474
See if this helps


CREATE TABLE #Employees(Employee CHAR(1) NOT NULL PRIMARY KEY, ReportsTo CHAR(1))
INSERT INTO #Employees(Employee, ReportsTo)
SELECT 'A',NULL UNION ALL
SELECT 'B','A' UNION ALL
SELECT 'C','A' UNION ALL
SELECT 'D','C' UNION ALL
SELECT 'E','B' UNION ALL
SELECT 'F','B'


DECLARE @Start CHAR(1)
SET @Start='A';

WITH CTE AS
(SELECT 0 AS Depth, Employee, ReportsTo, CAST(Employee AS VARCHAR(MAX)) AS FullPath
FROM #Employees
WHERE Employee=@Start
UNION ALL
SELECT C.Depth+1, A.Employee,A.ReportsTo, C.FullPath + '\' + CAST(A.Employee AS VARCHAR(MAX))
FROM #Employees A
INNER JOIN CTE C ON A.ReportsTo = C.Employee)
SELECT Employee,ReportsTo
FROM CTE
ORDER BY FullPath



____________________________________________________

Deja View - The strange feeling that somewhere, sometime you've optimised this query before

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537




ta.bu.shi.da.yu
ta.bu.shi.da.yu
Mr or Mrs. 500
Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)

Group: General Forum Members
Points: 529 Visits: 494
Hey... I tried that. :-) Doesn't work if F reports to B.

Random Technical Stuff
Atif-ullah Sheikh
Atif-ullah Sheikh
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4118 Visits: 5201

Hey... I tried that. Doesn't work if F reports to B.


To Who...?

----------------------------------------------------------------------------------------------------------------------------------------------------------------------

Sometimes, winning is not an issue but trying.

You can check my BLOG here


ta.bu.shi.da.yu
ta.bu.shi.da.yu
Mr or Mrs. 500
Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)Mr or Mrs. 500 (529 reputation)

Group: General Forum Members
Points: 529 Visits: 494
Atif Sheikh (5/12/2009)

Hey... I tried that. Doesn't work if F reports to B.


To Who...?


Er... sorry. Got that badly wrong. Doesn't work if B reports to F.

Random Technical Stuff
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