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


Exploring Recursive CTEs by Example


Exploring Recursive CTEs by Example

Author
Message
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)

Group: General Forum Members
Points: 7461 Visits: 6431
Comments posted to this topic are about the item Exploring Recursive CTEs by Example


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
Basit Farooq
Basit Farooq
SSC Veteran
SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)SSC Veteran (211 reputation)

Group: General Forum Members
Points: 211 Visits: 818
Thanks for this excellent article.

Regards,

Basit A. Farooq (MSC Computing, MCITP SQL Server 2005 & 2008, MCDBA SQL Server 2000)

http://basitaalishan.com
David McKinney
David McKinney
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1337 Visits: 2090
I love it! Especially the conclusion.

It's time we stopped being afraid to whisper the words 'Recursive CTE' for fear of being heard by the RBAR police! ;-)

Have to go....I hear a knock at the door w00t
rodjkidd
rodjkidd
SSCarpal Tunnel
SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)

Group: General Forum Members
Points: 4299 Visits: 8416
Excellent article Dwain.

Will have to read a few times for it all to sink in though!

Rodders...



nem.schlecht
nem.schlecht
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 136
Great article!
I noticed a little mistake, though. The 2nd example under "Geometric and Arithmetic Sequences and Progressions", you have:

"Another example: 1^1 + 1/2^2 + 1/3^3 + 1/4^4:"

But the very first line of the code is:

"-- Generate first 99 of Power Series: 1+1/2^2+1/3^2+1/4^2 etc."

Note the difference: the first is to the power of the current iteration, the latter (code example) always just squares the current quotient.

Not sure which one you wanted, but I assume the latter as that's what the code and example generate. :-)
Alex Friedman
Alex Friedman
SSC-Enthusiastic
SSC-Enthusiastic (116 reputation)SSC-Enthusiastic (116 reputation)SSC-Enthusiastic (116 reputation)SSC-Enthusiastic (116 reputation)SSC-Enthusiastic (116 reputation)SSC-Enthusiastic (116 reputation)SSC-Enthusiastic (116 reputation)SSC-Enthusiastic (116 reputation)

Group: General Forum Members
Points: 116 Visits: 663
Very interesting, thanks!
DavidP-340734
DavidP-340734
SSC-Enthusiastic
SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)SSC-Enthusiastic (182 reputation)

Group: General Forum Members
Points: 182 Visits: 105
One big caveat is the size of the datasets being used by CTEs. Be very cautions for two reasons: recursive CTE can blow up your temp db when large datasets can’t be written to memory and bad query plans are cached. Query analyzer is not good and building the best query plans with CTEs. I have had to rewrite numerous stored procedures replacing CTE with #temp tables to improve performance and get better results from query analyzer to add missing indexes.
Steven Willis
Steven Willis
SSC Eights!
SSC Eights! (855 reputation)SSC Eights! (855 reputation)SSC Eights! (855 reputation)SSC Eights! (855 reputation)SSC Eights! (855 reputation)SSC Eights! (855 reputation)SSC Eights! (855 reputation)SSC Eights! (855 reputation)

Group: General Forum Members
Points: 855 Visits: 1721
Just yesterday by coincidence I needed a query to parse dynamic XML with different nodes and properties on each run and came up with this procedure using CTEs which is very fast. I'm sure it can be improved and if anyone has suggestions please offer them.



CREATE PROCEDURE dbo.Test_ParseXML

@doc NVARCHAR(MAX)
,@rootnode NVARCHAR(255)

AS
BEGIN

SET NOCOUNT ON

DECLARE
@idoc INT
,@id INT
,@parentid INT

SET @parentid = NULL
SET @id = 1

IF OBJECT_ID('tempdb..#ChildList') IS NOT NULL
DROP TABLE #ChildList

CREATE TABLE #ChildList (
[RowNum] INT IDENTITY(1,1) NOT NULL,
[parentid] INT NULL,
[id] INT NULL,
PRIMARY KEY (RowNum),
UNIQUE (RowNum))

IF OBJECT_ID('tempdb..#NodeList') IS NOT NULL
DROP TABLE #NodeList

CREATE TABLE #NodeList (
[RowNum] INT NOT NULL,
[id] INT NULL,
[parentid] INT NULL,
[nodetype] INT NULL,
[localname] NVARCHAR(MAX) NULL,
[text] NVARCHAR(MAX) NULL,
PRIMARY KEY (RowNum),
UNIQUE (RowNum))


EXEC sp_xml_preparedocument @idoc OUTPUT, @doc

;WITH cte
AS (
SELECT
CAST(p1.parentid AS INT) AS parentid
,CAST(p1.id AS INT) AS id
FROM
OPENXML (@idoc,@rootnode,2) AS p1

UNION ALL

SELECT
CAST(p2.parentid AS INT) AS parentid
,CAST(p2.id AS INT) AS id
FROM
OPENXML (@idoc,@rootnode,2) AS p2
JOIN
cte
ON CAST(cte.id AS INT) = CAST(p2.ParentID AS INT)
WHERE
CAST(p2.parentid AS INT) = @parentid

UNION ALL

SELECT
CAST(p3.parentid AS INT) AS parentid
,CAST(p3.id AS INT) AS id
FROM
OPENXML (@idoc,@rootnode,2) AS p3
JOIN
cte
ON CAST(cte.id AS INT) = CAST(p3.ParentID AS INT)
WHERE
CAST(p3.parentid AS INT) = @parentid

UNION ALL

SELECT
CAST(p4.parentid AS INT) AS parentid
,CAST(p4.id AS INT) AS id
FROM
OPENXML (@idoc,@rootnode,2) AS p4
JOIN
cte
ON CAST(cte.id AS INT) = CAST(p4.ParentID AS INT)
WHERE
CAST(p4.parentid AS INT) = @parentid
)
INSERT INTO #ChildList
SELECT *
FROM cte

INSERT INTO #NodeList
SELECT
#ChildList.RowNum
,xmllist.id
,xmllist.parentid
,xmllist.nodetype
,xmllist.localname
,CAST(xmllist.[text] AS NVARCHAR(MAX)) AS [text]
FROM #ChildList
INNER JOIN
OPENXML (@idoc,@rootnode,2) AS xmllist
ON #ChildList.id = xmllist.id
WHERE
#ChildList.RowNum > 0


;WITH RecursiveNodes(RowNum,id,parentid,nodepath,localname,[text],nodetype)
AS (
SELECT
#NodeList.RowNum
,#NodeList.id
,#NodeList.parentid
,CAST('/' + REPLACE(REPLACE(REPLACE(REPLACE(#NodeList.localname,'&',''),'?',''),' ',''),'.','') AS NVARCHAR(255)) AS nodepath
,#NodeList.localname
,CAST(#NodeList.[text] AS NVARCHAR(MAX)) AS [text]
,0 AS nodetype
FROM #ChildList
INNER JOIN
#NodeList
ON #ChildList.id = #NodeList.id
WHERE
#NodeList.parentid IS NULL
AND #ChildList.RowNum > 0
AND #NodeList.RowNum > 0

UNION ALL

SELECT
n.RowNum
,n.id
,n.parentid
,CAST(r.nodepath + '/'+ REPLACE(REPLACE(REPLACE(REPLACE(n.localname,'&',''),'?',''),' ',''),'.','') AS NVARCHAR(255)) AS nodepath
,n.localname
,n.[text]
,n.nodetype
FROM #NodeList AS n
INNER JOIN
RecursiveNodes AS r
ON n.parentid = r.id
WHERE
n.RowNum > 0
AND r.RowNum > 0
AND n.parentid >= 0
)

SELECT
ROW_NUMBER() OVER (ORDER BY Result.RowNum) AS RowNum
,Result.id
,Result.parentid
,Result.nodepath
,Result.nodename
,Result.property
,Result.value
,Result.nodecontents
FROM
(
SELECT
rn.RowNum
,rn.id
,rn.parentid
,rn.nodepath
,(CASE
WHEN rn.nodetype = 0 THEN rn.localname
WHEN rn.nodetype = 1 THEN rn.localname
ELSE NULL
END) AS nodename
,(CASE
WHEN rn.nodetype = 2 THEN rn.localname
ELSE NULL
END) AS property
,(CASE
WHEN rn.nodetype = 2 THEN (SELECT [text] FROM RecursiveNodes WHERE parentid = rn.id)
ELSE NULL
END) AS value
,(CASE
WHEN rn.nodetype = 1 THEN (SELECT TOP(1) [text] FROM RecursiveNodes WHERE parentid = rn.id)
ELSE NULL
END) AS nodecontents
FROM
RecursiveNodes AS rn
WHERE
rn.localname <> '#text'
) AS Result
WHERE
Result.id >= 0

/*

EXEC dbo.Test_ParseXML
'<ReportPackage type="report">
<ReferenceId>XYZ-123</ReferenceId>
<Reports>
<ReportId>123</ReportId>
<Categories>
<Category>Real Estate</Category>
<Category>Restaurants</Category>
</Categories>
<Transactions>
<Transaction name="TxId">987654</Transaction>
</Transactions>
</Reports>
<CompanyData>
<CompanyCategory type="real estate">
<CompanyName>ABC Realty</CompanyName>
</CompanyCategory>
<DemographicDetail>
<StateID issuingAuthority="NC">123445555</StateID>
<DateExpires>2014-12-31</DateExpires>
</DemographicDetail>
</CompanyData>
<ReviewStatus>
<ReviewLevel>4.7</ReviewLevel>
<NumberReviews>1234</NumberReviews>
<ReviewStatus>Recommended</ReviewStatus>
</ReviewStatus>
</ReportPackage>',
'/ReportPackage'

*/

END



Peter H
Peter H
Grasshopper
Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)

Group: General Forum Members
Points: 23 Visits: 62
Great article, thanks. I really enjoyed going through that.

I am looking for CTE's that will give me formulae for different predictive analysis routines.

here is a slight coding problem, the first select in the following code should not have the "Union".

-- Add an additional origin and destination node
INSERT INTO #Edges
UNION ALL SELECT '0', 'N', 15 -- ABS(CHECKSUM(NEWID())) % 100 + 25


MCTSQL
MCTSQL
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 120
FINALLY!!! Someone who loves burning up the CPU as much as I do! :-D

As a token of gratitude, feel free to add my recursive string parser to your excursions into recursions. :-)

create function [sql].[StringToTable](
@string nvarchar(max),
@delimiter nvarchar(1))
returns table
/* t@sqlPROCtologist.com

Usage:
declare @str nvarchar(max)='a,bc,def,ghij,klmno,pqrstu,vwxyz,0123,456,78,9';
select * from [sql].[StringToTable](@str,',') option(maxrecursion 32767);
*/
as return(
with cte as(
select
convert(int,1) as [start],
charindex(@delimiter, @string+@delimiter,1) as [end],
substring(@string+@delimiter,1,charindex(@delimiter,@string+@delimiter,1)) as [string]
union all select
convert(int,[end]+1) as [start],
charindex(@delimiter,@string+@delimiter,[end]+1) as [end],
substring(@string+@delimiter,[end]+1,charindex(@delimiter,@string+@delimiter,[end]+1)-[end]) as [string]
from cte where [end]+1<=len(@string+@delimiter)
)
select left(string,len(string)-1) as [String] from cte);
go


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