January 16, 2014 at 6:58 am
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
January 16, 2014 at 7:37 am
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
January 16, 2014 at 7:46 am
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.
January 16, 2014 at 6:07 pm
My cat Grumpy will not be pleased that you left him out. 😀
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 17, 2014 at 3:19 am
Sorry 'bout that.
People around here questioned where Doc Jr and Doc Jr Jr came from....
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply