May 10, 2013 at 3:46 am
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 ?
May 10, 2013 at 3:52 am
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.
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
May 10, 2013 at 4:19 am
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 ')
May 10, 2013 at 4:50 am
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;
____________________________________________________
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/61537May 10, 2013 at 4:53 am
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.
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
May 10, 2013 at 4:54 am
Quick work, Mark 😉
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
May 10, 2013 at 5:46 am
Thanks Chris and Mark. Exactly what I needed.
May 10, 2013 at 3:44 pm
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
Change is inevitable... Change for the better is not.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply