Click here to Skip to main content
15,886,919 members
Please Sign up or sign in to vote.
2.00/5 (3 votes)
See more:
Id is unique. NextID stores the noxt ID value. When NextID value is Null, there the path Ends.

Input:
ID	NextID
1	5
2	Null
3	6
4	7
5	8
6	9
7	Null
8	Null
9	10
10	Null

Output:
a. 1 --> 5 --> 8 
b. 2
C. 3 -->6 -->9 -->10
d. 4-->7
e. 8

Sample code to run:
SQL
INSERT Data VALUES
    ('1','5'),
    ('2','Null'),
    ('3','6'),
    ('4','7'),
    ('5','8'),
    ('6','9'),
    ('7','Null'),
    ('8','Null'),
    ('9','10'),
    ('10','Null')


What I have tried:

SQL
;WITH RecursivePaths AS 
(
    SELECT ID, NextID, CAST(ID AS VARCHAR(MAX)) AS Path 
    FROM Data 
    WHERE ID = 3 -- Starting point, adjust as needed

    UNION ALL

    SELECT t.ID, t.NextID, r.Path + ' --> ' + CAST(t.ID AS VARCHAR(MAX)) 
    FROM Data t 
    JOIN RecursivePaths r ON t.ID = r.NextID 
    WHERE t.NextID IS NOT NULL 
)
SELECT Path FROM RecursivePaths
Here I have to give starting ID which is not desired.
Posted
Updated 16-Nov-23 0:37am
v2
Comments
Richard Deeming 16-Nov-23 6:40am    
Why are 5, 6, 7, 9, and 10 not included as starting points in your expected output?

If that's just an oversight in your question, then you just need to remove the WHERE ID = 3 line.

Oh, and also correct the condition in the recursive part: WHERE r.NextID Is Not Null
smaranika 16-Nov-23 6:51am    
Hi,

I am getting all possible paths.
But I need only the below paths as output.
a. 1 --> 5 --> 8
b. 2
C. 3 -->6 -->9 -->10
d. 4-->7
e. 8

Refer : https://dbfiddle.uk/on1WyfUp

1 solution

To get the list of paths without including any sub-paths, you could try the following:

1. Reverse the recursion - start with the records with no NextID and work backwards.

2. Find the longest path for each "leaf" node.

Eg:
SQL
WITH RecursivePaths As
(
    SELECT
        ID,
        ID As Leaf,
        CAST(ID AS VARCHAR(MAX)) AS Path
    FROM
        Data
    WHERE
        NextID Is Null

    UNION ALL

    SELECT
        D.ID,
        R.Leaf,
        CAST(D.ID AS VARCHAR(MAX)) + ' --> ' + R.Path
    FROM
        RecursivePaths As R
        INNER JOIN Data As D ON D.NextID = R.ID
),
SortedPaths As
(
    SELECT
        Leaf,
        Path,
        ROW_NUMBER() OVER (PARTITION BY Leaf ORDER BY Len(Path) DESC) As RN
    FROM
        RecursivePaths
)
SELECT
    Path
FROM
    SortedPaths
WHERE
    RN = 1
;
Output:
3 --> 6 --> 9 --> 10
2
4 --> 7
1 --> 5 --> 8
db<>fiddle[^]

NB: This doesn't match the output in your question, which includes 8 twice. I am assuming that's an error in your question. Otherwise, you need to explain why you want to include that specific node in both the 1 ⇒ 5 ⇒ 8 path and also on its own.
 
Share this answer
 
Comments
smaranika 16-Nov-23 7:10am    
Hi,
Here 8 may occur twice as given in data. 8 here has also self recursion
Richard Deeming 16-Nov-23 8:04am    
Then your data is wrong. You have no way to know which ID = '8' record your NextID = '8' refers to.
Richard Deeming 16-Nov-23 8:12am    
NB: Neither your question nor your DBFiddle show 8 occuring twice, nor having self-recursion.

You can't expect to get an answer to your question if you miss out half of the question, and don't provide an example that mirrors your expectations!
Maciej Los 16-Nov-23 10:13am    
5ed!
Andre Oosthuizen 16-Nov-23 12:32pm    
Same +5!

This content, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)



CodeProject, 20 Bay Street, 11th Floor Toronto, Ontario, Canada M5J 2N8 +1 (416) 849-8900