Triangle join on same table

  • Hello,

    I have a problem that I need to have a solution for. The problem today is performance.

    I have a row with approx 3 million rows looking like this

    Id1, Id2

    1, 3

    1, 2

    1, 4

    1, 7

    2, 5

    2, 9

    3, 1

    3, 2

    5, 1

    9, 1

    etc.

    Its basically a list of apartments matching eachother for swapping. So apartment 1 want to swap with apartment 2, 3, 4, 7.. Apartment 2 want to swap with 5, 9 etc..

    What I want to achieve here is to build triangle or rectangles for swap.

    Meaning, I want to see how many swap alternatives Id(1) has building a triangle or rectangle chain something like this:

    Triangle:

    Id1 (my id), Id2, Id3

    1, 2, 5

    1, 2, 9

    5 and 9 must have a match for 1 (5, 1 & 9, 1).

    I hope you understand. I have done this today using 2 joins, but its slow as hell on large amount of datas.

    I've read something about CTE but have no clue on how it works yet.

    Thanks in advance.

  • As a first time poster, you should learn to follow forum etiquette and read up on posting questions with DDL and consumable sample data. There are many links you can find this information on. As it is Christmas and I'm feeling charitable, I'll help you out this time.

    I'm not going to promise that the following will be any faster than your JOIN, but it might be, or at the very least is another alternative to try.

    -- DDL

    CREATE TABLE #ApartmentSwaps (Id1 INT, Id2 INT

    ,PRIMARY KEY (id1, id2))

    -- Consumable sample data

    INSERT INTO #ApartmentSwaps

    SELECT 1, 3 UNION ALL SELECT 1, 2 UNION ALL SELECT 1, 4

    UNION ALL SELECT 1, 7 UNION ALL SELECT 2, 5 UNION ALL SELECT 2, 9

    UNION ALL SELECT 3, 1 UNION ALL SELECT 3, 2 UNION ALL SELECT 5, 1

    UNION ALL SELECT 9, 1

    DECLARE @MyID INT = 1

    SELECT id1, id2, id3

    FROM #ApartmentSwaps

    CROSS APPLY (SELECT id3=id1 FROM #ApartmentSwaps WHERE id2 = @MyID) a

    WHERE id1 = @MyID AND id1 <> id2 AND id2 <> id3 AND id1 <> id3

    -- Always use temp tables in your questions and remember to drop them

    DROP TABLE #ApartmentSwaps

    Note how I specified a PRIMARY KEY on the table, which creates a CLUSTERED INDEX. This should help the query perform better.

    You could also do this with a set-based WHILE loop, and I've seen cases where that beats out the JOIN and CROSS APPLY attacks to this kind of a problem.

    Also, beware of parameter-sniffing the way I've written the query (using @MyID). You may also want to try the same query with OPTION (RECOMPILE) to see if it runs any faster.


    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 2 posts - 1 through 1 (of 1 total)

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