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


Recursive query question


Recursive query question

Author
Message
sqlpadawan_1
sqlpadawan_1
SSC-Enthusiastic
SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)

Group: General Forum Members
Points: 102 Visits: 1024
I stuck on a recursive query. I'm trying to pull a parent and all of the subsequent levels.

My data looks like this:

Number Name ParentNumber
------- ----- -------------
111 Snow White NULL
222 Sleepy 111
333 Dopey 111
444 Doc 111
555 Doc Jr 444

I want to see Snow White, all of the dwarfs, and doc jr (who reports to doc). My query looks like this:


CREATE TABLE tempdb.dbo.[People]
(
[Number] [nvarchar](50) NULL
,[Name] [nvarchar](75) NULL
,[ParentNumber] [nvarchar](50) NULL
);

INSERT INTO tempdb.dbo.People
( Number, Name, ParentNumber )
VALUES ( '111', 'Snow White', NULL )
, ( '222', 'Sleepy', '111' )
, ( '333', 'Dopey', '111' )
, ( '444', 'Doc', '111' )
, ( '555', 'Doc Jr', '444' );

WITH ctePeople
AS ( SELECT Number
,Name
,CAST (NULL AS NVARCHAR(50)) AS ParentNumber
,1 AS CustLevel
FROM tempdb.dbo.People
WHERE ParentNumber IS NULL
UNION ALL
SELECT bic.Number
,bic.Name
,cte.Number AS ParentNumber
,cte.CustLevel + 1
FROM tempdb.dbo.People bic
INNER JOIN ctePeople cte ON bic.ParentNumber = cte.Number
WHERE bic.ParentNumber IS NOT NULL
)
SELECT *
FROM ctePeople
WHERE Number = '111'
OR ParentNumber = '111'
ORDER BY CustLevel;



How do I get Doc Jr?

Thanks,
Kevin
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16510 Visits: 16985
Your code works perfectly fine. It was not returning Doc jr because you filtered it out in your where clause. The easiest way here is to add filtering to the first portion of your cte.


declare @Number int = 111;

WITH ctePeople
AS ( SELECT Number
,Name
,CAST (NULL AS NVARCHAR(50)) AS ParentNumber
,1 AS CustLevel
FROM tempdb.dbo.People
WHERE ParentNumber IS NULL
            and Number = @Number
UNION ALL
SELECT bic.Number
,bic.Name
,cte.Number AS ParentNumber
,cte.CustLevel + 1
FROM tempdb.dbo.People bic
INNER JOIN ctePeople cte ON bic.ParentNumber = cte.Number
WHERE bic.ParentNumber IS NOT NULL
)
SELECT *
FROM ctePeople
--WHERE Number = '111'
-- OR ParentNumber = '111'
ORDER BY CustLevel;



_______________________________________________________________

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)
sqlpadawan_1
sqlpadawan_1
SSC-Enthusiastic
SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)

Group: General Forum Members
Points: 102 Visits: 1024
Thanks for the reply.

The reason for the filter, I don't want to return the whole table. If I add a few more records, and only want Snow White and the punks:



DROP TABLE tempdb.dbo.People;

CREATE TABLE tempdb.dbo.[People]
(
[Number] [nvarchar](50) NULL
,[Name] [nvarchar](75) NULL
,[ParentNumber] [nvarchar](50) NULL
);

INSERT INTO tempdb.dbo.People
( Number, Name, ParentNumber )
VALUES ( '111', 'Snow White', NULL )
, ( '222', 'Sleepy', '111' )
, ( '333', 'Dopey', '111' )
, ( '444', 'Doc', '111' )
, ( '555', 'Doc Jr', '444' )
, ( '666', 'Doc Jr Jr', '555' )
, ( '1111', 'Uncle Scrooge', NULL )
, ( '2222', 'Huey', '1111' )
, ( '3333', 'Duey', '1111' )
, ( '4444', 'Luey', '1111' )
;


WITH ctePeople
AS ( SELECT Number
,Name
,CAST (NULL AS NVARCHAR(50)) AS ParentNumber
,1 AS CustLevel
FROM tempdb.dbo.People
WHERE ParentNumber IS NULL AND Number = '111'
UNION ALL
SELECT bic.Number
,bic.Name
,cte.Number AS ParentNumber
,cte.CustLevel + 1
FROM tempdb.dbo.People bic
INNER JOIN ctePeople cte ON bic.ParentNumber = cte.Number
WHERE bic.ParentNumber IS NOT NULL
)
SELECT *
FROM ctePeople cte
--WHERE Number = '111'
-- OR ParentNumber = '111'
ORDER BY CustLevel;




I think I answered my own question by filtering the top root select in the cte.

This gives me the Snow White hierarchy and leaves the ducks out.
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4231 Visits: 6431
My cat Grumpy will not be pleased that you left him out. :-D


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!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
sqlpadawan_1
sqlpadawan_1
SSC-Enthusiastic
SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)SSC-Enthusiastic (102 reputation)

Group: General Forum Members
Points: 102 Visits: 1024
Sorry 'bout that.

People around here questioned where Doc Jr and Doc Jr Jr came from....
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