tricky many to many query

  • I have a complex query to put together and need some help. I have a table like the one below which is many to many. Essentially two primary columns (assume named left and right)

    left right

    ---- -------

    1 .... 2

    2 .... 3

    3 .... 4

    1 .... 4

    1 .... 5

    5 .... 4

    6 .... 4

    Assuming I know the id on the left (1) and the id on the right (4) I need to find all paths for the combination and return them in a delimited string as below. Something like:

    1/2/3/4 but also 1/4 and 1/5/4

    The number of paths is only likely to be 3 or 4 and no more. I'm guessing I need to do something recursive and save the path at each level.

    Any ideas on a good (and fast) way to do this?

    thanks

  • Something like this perhaps?

    DECLARE @Paths TABLE (

    INT,

    INT)

    INSERT INTO @Paths

    SELECT 1 , 2

    UNION ALL SELECT 2 , 3

    UNION ALL SELECT 3 , 4

    UNION ALL SELECT 1 , 4

    UNION ALL SELECT 1 , 5

    UNION ALL SELECT 5 , 4

    UNION ALL SELECT 6 , 4

    ;WITH C AS (

    SELECT n=1,

    ,

    ,[Path]=CAST(

    AS VARCHAR(8000)) + '/' + CAST(

    AS VARCHAR(8000))

    FROM @Paths

    UNION ALL

    SELECT n+1, C.

    , a.

    , [Path] + '/' + CAST(a.

    AS VARCHAR(8000))

    FROM C

    INNER JOIN @Paths a ON C.

    = a.

    )

    SELECT *

    FROM C

    WHERE LEFT([Path], 1) = '1' AND RIGHT([Path], 1) = '4'


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • thank you. I had something similar to that so was heading in the right direction but as they say the devil is in the details.

    I'll check it against my table and see what I get.

    thanks,

    PS. nice fish!

  • kevin 20860 (2/11/2013)


    thank you. I had something similar to that so was heading in the right direction but as they say the devil is in the details.

    I'll check it against my table and see what I get.

    thanks,

    PS. nice fish!

    You're welcome. Obviously what I did won't handle IDs once they get to be greater than 9, but I think you can probably figure out a way to handle that (add leading zeroes).

    Fish: 45kg Mekong Catfish + Thanks.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • Dwain (or anyone!)

    Is there any way to detect an prevent this crashing on a circular reference? I need to have it support a circular ref but using this method above causes an error.

    thanks

  • Thanks Dwain,

    This does solve all routeplanning problems 😛

    Well at least it is a good start to solve all routeplanning problems.

    Thanks

    Ben

    Sidestep:

    I have often been thinking how I would solve a routeplanning problem using SQL-server. And more important how I would optimize the routeplanning problem.

    Your solution is a fairly elegant solution to show that this can be done easily if the number number of nodes is limited.

    I have designed (but not build) algoritms for the fasted and the shortest routes. And also have made optimisation to find a solution as fast as possible, but which is not guaranteed to be the best solution.

    And solutions which work fairly wel and guarantee the best solution which can be calculated.

  • kevin 20860 (4/4/2013)


    Dwain (or anyone!)

    Is there any way to detect an prevent this crashing on a circular reference? I need to have it support a circular ref but using this method above causes an error.

    thanks

    The short answer is I don't think so. It might be possible to remove circular references if you can detect them but that would be challenging depending on the number of nodes to traverse.

    I have developed a looping solution that might work. Honestly this thread doesn't really cause me to recollect much as its nearly 6 months old. I do recognize the solution I gave from my article on generate n-Tuples (http://www.sqlservercentral.com/articles/sql+n-Tuples/89809/).

    I am not 100% certain the looping solution would be applicable but I'll give you a hint. I used an EXCEPT to remove cases when a circular reference was encountered.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • ben.brugman (4/4/2013)


    Thanks Dwain,

    This does solve all routeplanning problems 😛

    Thanks

    Ben

    If it did then I'd be well on my way to fortune and glory. Alas, that is not the case.

    The article in my link on recursive CTEs below has a solution to the classic transportation problem. And there are probably ways to improve upon it, given sufficient time and energy.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • Cheers Dwain. I'll take a look at your link and see if I can work it into my solution. This stuff just wrecks my head 🙂

  • Ok not sure If I've got it right but if I add "where a.left not in (select id from dbo.ufn_Split(c.path) )" after the Inner join it appears to work ok. The split function takes the comma delimited list and returns one item per row.

    I'll do a lot more checking to make sure it works in all situations. Might also change the "in" to "exists" as that is probably more effecient.

    ;WITH C AS (

    SELECT n=1,

    ,

    ,[Path]=CAST(

    AS VARCHAR(8000)) + '/' + CAST(

    AS VARCHAR(8000))

    FROM @Paths

    UNION ALL

    SELECT n+1, C.

    , a.

    , [Path] + '/' + CAST(a.

    AS VARCHAR(8000))

    FROM C

    INNER JOIN @Paths a ON C.

    = a.

    where a.left not in (select id from dbo.ufn_Split(c.path) )

    )

  • kevin 20860 (4/4/2013)


    Ok not sure If I've got it right but if I add "where a.left not in (select id from dbo.ufn_Split(c.path) )" after the Inner join it appears to work ok. The split function takes the comma delimited list and returns one item per row.

    I'll do a lot more checking to make sure it works in all situations. Might also change the "in" to "exists" as that is probably more effecient.

    ;WITH C AS (

    SELECT n=1,

    ,

    ,[Path]=CAST(

    AS VARCHAR(8000)) + '/' + CAST(

    AS VARCHAR(8000))

    FROM @Paths

    UNION ALL

    SELECT n+1, C.

    , a.

    , [Path] + '/' + CAST(a.

    AS VARCHAR(8000))

    FROM C

    INNER JOIN @Paths a ON C.

    = a.

    where a.left not in (select id from dbo.ufn_Split(c.path) )

    )

    A quick hint if you want to improve efficiency. Replace ufn_Split with DelimitedSplit8K:

    http://www.sqlservercentral.com/articles/Tally+Table/72993/


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

Viewing 11 posts - 1 through 10 (of 10 total)

You must be logged in to reply to this topic. Login to reply