• lmeinke (11/12/2013)


    On a quick read through I noticed your data type is int. This would drop the leading zeros on many of my skus. When I run this with the varchar type I get:

    Msg 240, Level 16, State 1, Line 1

    Types don't match between the anchor and the recursive part in column "STD SKU" of recursive query "rCTE".

    I'll keep working through this but thought I'd throw that out there if you have a quick reply.

    Thanks,

    That error is pretty simple to resolve by CASTing the NULL assignment to ITEM2 in the rCTE anchor to a VARCHAR type, the same as your item codes.

    DECLARE @T1 TABLE (ITEM1 VARCHAR(20), ITEM2 VARCHAR(20));

    INSERT INTO @T1

    SELECT '0224180','0224181'

    UNION ALL SELECT '0224180','0224190'

    UNION ALL SELECT '0224181','0224180'

    UNION ALL SELECT '0224181','0224190'

    UNION ALL SELECT '0224190','0224180'

    UNION ALL SELECT '0224190','0224181'

    UNION ALL SELECT '0202294','0202295'

    UNION ALL SELECT '0202295','0202294'

    UNION ALL SELECT '0209250','0209251'

    UNION ALL SELECT '0209251','0209250';

    WITH rCTE AS

    (

    SELECT n=0, ITEM

    ,rn=ROW_NUMBER() OVER (ORDER BY (SELECT NULL))

    ,ITEM1=ITEM

    ,ITEM2=CAST(NULL AS VARCHAR(20))

    FROM

    (

    SELECT DISTINCT ITEM=MIN(b.ITEM1)

    FROM

    (

    SELECT ITEM1, ITEM2, rn=ROW_NUMBER() OVER (ORDER BY (SELECT NULL))

    FROM @T1

    ) a

    CROSS APPLY

    (

    SELECT ITEM1=CASE WHEN ITEM1 < ITEM2 THEN ITEM1 ELSE ITEM2 END

    ,ITEM2=CASE WHEN ITEM1 < ITEM2 THEN ITEM2 ELSE ITEM1 END

    FROM @T1 b

    WHERE a.ITEM1 IN (b.ITEM1, b.ITEM2)

    ) b

    GROUP BY rn

    ) a

    UNION ALL

    SELECT n+1, b.ITEM1, rn, b.ITEM1, b.ITEM2

    FROM rCTE a

    JOIN @T1 b ON a.ITEM = b.ITEM1

    WHERE n <= 1

    UNION ALL

    SELECT n+1, b.ITEM1, rn, b.ITEM1, b.ITEM2

    FROM rCTE a

    JOIN @T1 b ON a.ITEM = b.ITEM2

    WHERE n <= 1

    )

    SELECT DISTINCT ITEM1, ITEM2, ID=rn

    FROM rCTE

    WHERE n = 2

    ORDER BY rn, ITEM1, ITEM2;

    I would love to hear how this performs against your 98K rows.

    Edit: Minor edit to the sample data.


    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