how can i avoid cartesian join?

  • Hi,

    I have two tables and both of these table contains user phone information.

    There is not a single column value is common in both of these table on which i can join tables. Both of these table contains 6 record each and i know the key value for both of these tables, i mean USER_KEY.

    Now i want to generate a report where i can show phone nos from both of these table side by side. If i join these table like

    select phone_no from tableA,tableB

    where tableA.user_key=100 and tableB.user_key=1001

    then i am getting 36 records which is correct. but i want to avoid this cartesian join and just want query to return me 6 records.

    Your help is appreciated.

    Thanks

  • Heh... it's easy and I'll tell you... right after you tell me why you'd want to do such a thing... you know... what are the business requirements that require this to be done? I'd show you up front, but I've found that once people have their answer, they won't answer my question. This is a two way street and I like to know these things. 😛 Thanks for your time.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Allrite, here is the justification.

    Business wants to compare the data between these two tables and business user are not SQL friendly thats why they asked me to generate a report or an excel sheet where it will show data side by side.

    Hope this will clear you my requirement.

    Thanks

  • Perfect... thanks... here's how to do it...

    ;WITH

    cteTableA AS

    (

    SELECT ROW_NUMBER() OVER (ORDER BY Phone_No) AS RowNumber,

    Phone_No

    FROM dbo.TableA

    WHERE User_Key = 100

    )

    ,

    cteTableB AS

    (

    SELECT ROW_NUMBER() OVER (ORDER BY Phone_No) AS RowNumber,

    Phone_No

    FROM dbo.TableB

    WHERE User_Key = 1001

    )

    SELECT a.Phone_No, b.Phone_No

    FROM cteTableA

    FULL OUTER JOIN cteTableB

    ON a.RowNum = b.RowNum

    Lemme know if you have any questions about how or why it works.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Ya kinda left things hanging here... did that work for you or what? 😉

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 5 posts - 1 through 5 (of 5 total)

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