Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Recursive SQL Expand / Collapse
Author
Message
Posted Friday, May 10, 2013 3:45 AM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 10:59 PM
Points: 112, Visits: 468
Hi All,

Need help on some recursive Data. I would need to get 4 records out of below available If I pass value 395. Since, for 395, COlD (Child of ColA) has value 394. Again we check ColaA for 394 and find the corresponding value in ColD which is 347. Again in ColA 347 corresponds to 0 value in ColD. Total of 4 records.

ColA        ColB    ColC        ColD       ColE           ColF
347 AA 25 0 0 0
362 BB 25 347 0 50
363 CC 25 362 0 51
364 DD 25 347 0 50
365 EE 25 364 0 51
367 FF 25 365 0 54
369 GG 25 347 0 50
373 HH 25 347 0 50
374 II 25 373 0 51
375 JJ 25 374 0 54
376 KK 25 374 0 54
394 LL 25 347 0 50
395 MM 25 394 0 51


I beleive Using While loop this can be done. Any suggestions ?
Post #1451495
Posted Friday, May 10, 2013 3:52 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 1:43 AM
Points: 6,890, Visits: 14,254
syedathariqbal (5/10/2013)
Hi All,

Need help on some recursive Data. I would need to get 4 records out of below available If I pass value 395. Since, for 395, COlD (Child of ColA) has value 394. Again we check ColaA for 394 and find the corresponding value in ColD which is 347. Again in ColA 347 corresponds to 0 value in ColD. Total of 4 records.

ColA        ColB    ColC        ColD       ColE           ColF
347 AA 25 0 0 0
362 BB 25 347 0 50
363 CC 25 362 0 51
364 DD 25 347 0 50
365 EE 25 364 0 51
367 FF 25 365 0 54
369 GG 25 347 0 50
373 HH 25 347 0 50
374 II 25 373 0 51
375 JJ 25 374 0 54
376 KK 25 374 0 54
394 LL 25 347 0 50
395 MM 25 394 0 51


I beleive Using While loop this can be done. Any suggestions ?


Sure: set this table up as a CREATE TABLE & INSERTs to populate it, test that the script executes without errors, then post it here.


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1451499
Posted Friday, May 10, 2013 4:19 AM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 10:59 PM
Points: 112, Visits: 468
Here it is....

CREATE TABLE [dbo].[tmpTable](
[ColA] [nchar](10) NOT NULL,
[ColB] [nchar](10) NULL,
[ColC] [nchar](10) NULL,
[ColD] [nchar](10) NULL,
[ColE] [nchar](10) NULL,
[ColF] [nchar](10) NULL,
CONSTRAINT [PK_tmpTable] PRIMARY KEY CLUSTERED
(
[ColA] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'347 ', N'A ', N'25 ', N'0 ', N'0 ', N'0 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'362 ', N'B ', N'25 ', N'347 ', N'0 ', N'50 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'363 ', N'C ', N'25 ', N'362 ', N'0 ', N'51 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'364 ', N'D ', N'25 ', N'347 ', N'0 ', N'50 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'365 ', N'E ', N'25 ', N'364 ', N'0 ', N'51 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'367 ', N'F ', N'25 ', N'365 ', N'0 ', N'54 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'369 ', N'G ', N'25 ', N'347 ', N'0 ', N'50 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'373 ', N'H ', N'25 ', N'347 ', N'0 ', N'50 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'374 ', N'I ', N'25 ', N'373 ', N'0 ', N'51 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'375 ', N'J ', N'25 ', N'374 ', N'0 ', N'54 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'376 ', N'K ', N'25 ', N'374 ', N'0 ', N'50 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'394 ', N'L ', N'25 ', N'347 ', N'0 ', N'50 ')
INSERT [dbo].[tmpTable] ([ColA], [ColB], [ColC], [ColD], [ColE], [ColF]) VALUES (N'395 ', N'M ', N'25 ', N'394 ', N'0 ', N'51 ')


Post #1451507
Posted Friday, May 10, 2013 4:50 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 2:58 PM
Points: 1,683, Visits: 19,607


I get 3 rows not 4, maybe I'm missing something.


DECLARE @Start INT = 395;

WITH Recur AS (
SELECT [ColA], [ColB], [ColC], [ColD], [ColE], [ColF]
FROM [dbo].[tmpTable]
WHERE [ColA] = @Start

UNION ALL

SELECT t.[ColA], t.[ColB], t.[ColC], t.[ColD], t.[ColE], t.[ColF]
FROM [dbo].[tmpTable] t
INNER JOIN Recur r ON r.[ColD] = t.[ColA])
SELECT [ColA], [ColB], [ColC], [ColD], [ColE], [ColF]
FROM Recur;



____________________________________________________

How to get the best help on a forum

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

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1451516
Posted Friday, May 10, 2013 4:53 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 1:43 AM
Points: 6,890, Visits: 14,254
Thanks...
WITH Resolver AS (
SELECT
[Level] = 1,
[Route] = CAST(RTRIM(t.ColA) AS VARCHAR(25)),
t.ColA, t.ColB, t.ColC, t.ColD, t.ColE, t.ColF
FROM tmpTable t
WHERE ColA = 395
UNION ALL
SELECT
[Level] = r.[Level] + 1,
[Route] = CAST(r.[Route] + '>' + CAST(RTRIM(t.ColA) AS VARCHAR(25)) AS VARCHAR(25)),
t.ColA, t.ColB, t.ColC, t.ColD, t.ColE, t.ColF
FROM Resolver r
INNER JOIN tmpTable t ON t.ColA = r.ColD
)
SELECT *
FROM Resolver
ORDER BY [Level], ColA;
-- three rows are returned: There is no row with value=0 in ColA.



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1451517
Posted Friday, May 10, 2013 4:54 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 1:43 AM
Points: 6,890, Visits: 14,254
Quick work, Mark

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1451518
Posted Friday, May 10, 2013 5:46 AM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: 2 days ago @ 10:59 PM
Points: 112, Visits: 468
Thanks Chris and Mark. Exactly what I needed.
Post #1451536
Posted Friday, May 10, 2013 3:44 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 7:27 AM
Points: 35,769, Visits: 32,437
syedathariqbal (5/10/2013)
Thanks Chris and Mark. Exactly what I needed.


The next question would be.... do you know how it works?


--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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1451758
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse