Skip to content
  • Categories
  • Recent
  • Tags
  • Popular
  • World
  • Users
  • Groups
Skins
  • Light
  • Cerulean
  • Cosmo
  • Flatly
  • Journal
  • Litera
  • Lumen
  • Lux
  • Materia
  • Minty
  • Morph
  • Pulse
  • Sandstone
  • Simplex
  • Sketchy
  • Spacelab
  • United
  • Yeti
  • Zephyr
  • Dark
  • Cyborg
  • Darkly
  • Quartz
  • Slate
  • Solar
  • Superhero
  • Vapor

  • Default (No Skin)
  • No Skin
Collapse
Code Project
  1. Home
  2. Database & SysAdmin
  3. Database
  4. OR in a JOIN

OR in a JOIN

Scheduled Pinned Locked Moved Database
databasesql-serversysadminalgorithmsregex
29 Posts 7 Posters 0 Views 1 Watching
  • Oldest to Newest
  • Newest to Oldest
  • Most Votes
Reply
  • Reply as topic
Log in to reply
This topic has been deleted. Only users with topic management privileges can see it.
  • P PIEBALDconsult

    I added it to the post with some clarification.

    P Offline
    P Offline
    Paul Conrad
    wrote on last edited by
    #20

    Coolness! I will check it out soon and see if there's anything I can add to this thread in terms of a solution :)

    ""Real programmers just throw a bunch of 1s and 0s at the computer to see what sticks" - Pete O'Hanlon

    1 Reply Last reply
    0
    • P PIEBALDconsult

      I'm having some trouble with a JOIN that involves an OR (in SQL Server). For example:

      SELECT *
      FROM TableA A
      INNER JOIN TableB B
      ON A.Field1=B.Field1
      OR A.Field2=B.Field2

      Quite correctly this produces two output rows for each row in TableA that matches TableB via both Field1 and Field2* -- but for this JOIN I want to output only one row when both match (preferably the result of the Field1 match, and only report the Field2 match if Field1 doesn't match). * Clarification -- when it matches two rows in TableB; one via Field1 and the other via Field2. I haven't done much searching for pointers because I don't think it's possible, however I'm posting here just in case someone here knows of a way or a simple (SQL only) work-around. Edit -- Here's an example:

      SELECT * FROM TableA

      ID Field1 Field2


      10 A E
      11 E D
      12 A D

      SELECT * FROM TableB

      ID Field1 Field2


      20 A B
      21 C D

      10 will match only 20 ; 11 will match only 21 ; 12 will match both 20 and 21 -- so I want 20.

      ID Field1 Field2 ID Field1 Field2
      10 A E 20 A B <-- I want this row
      11 E D 21 C D <-- I want this row
      12 A D 20 A B <-- I want this row
      12 A D 21 C D <-- I don't want this row

      Luc's and pmpdesign's suggestions yield the same output. Here's a variation of Bernhard's suggestion, which seems to work:

      WITH cte1 AS
      (
      SELECT A.ID aID
      , A.Field1 aField1
      , A.Field2 aField2
      , B.ID bID
      , B.Field1 bField1
      , B.Field2 bField2
      FROM TableA A
      INNER JOIN TableB B
      ON A.Field1=B.Field1
      )
      , cte2 AS
      (
      SELECT A.ID aID
      , A.Field1 aField1
      , A.Field2 aField2
      , B.ID bID
      , B.Field1 bField1
      , B.Field2 bField2
      FROM TableA A
      INNER JOIN TableB B
      ON A.Field2=B.Field2
      )
      SELECT *
      FROM cte1
      UNION ALL
      SELECT C2.*
      FROM cte2 C2
      LEFT OUTER JOIN cte1 C1
      ON C2.aID=C1.aID
      WHERE C1.aID IS NULL

      P Offline
      P Offline
      Paul Conrad
      wrote on last edited by
      #21

      PIEBALDconsult wrote:

      so I want 20

      Do you want 20 in both rows with the Id from Table A being 10, and 12?

      ""Real programmers just throw a bunch of 1s and 0s at the computer to see what sticks" - Pete O'Hanlon

      P 1 Reply Last reply
      0
      • P PIEBALDconsult

        Chris Meech wrote:

        should eliminate any duplicates.

        Except it doesn't. I have added some clarification and sample data to my post.

        C Offline
        C Offline
        Chris Meech
        wrote on last edited by
        #22

        It will remove the duplicates of the resultant set, but now that I've read your example, that is not quite what you are after. In your example once the row with ID 12 from table A matched on FieldA for the row with ID 20, you don't want to include it anymore where it might match on FieldB.

        Chris Meech I am Canadian. [heard in a local bar] In theory there is no difference between theory and practice. In practice there is. [Yogi Berra] posting about Crystal Reports here is like discussing gay marriage on a catholic church’s website.[Nishant Sivakumar]

        1 Reply Last reply
        0
        • P Paul Conrad

          PIEBALDconsult wrote:

          so I want 20

          Do you want 20 in both rows with the Id from Table A being 10, and 12?

          ""Real programmers just throw a bunch of 1s and 0s at the computer to see what sticks" - Pete O'Hanlon

          P Offline
          P Offline
          PIEBALDconsult
          wrote on last edited by
          #23

          Yes.

          1 Reply Last reply
          0
          • P PIEBALDconsult

            I'm having some trouble with a JOIN that involves an OR (in SQL Server). For example:

            SELECT *
            FROM TableA A
            INNER JOIN TableB B
            ON A.Field1=B.Field1
            OR A.Field2=B.Field2

            Quite correctly this produces two output rows for each row in TableA that matches TableB via both Field1 and Field2* -- but for this JOIN I want to output only one row when both match (preferably the result of the Field1 match, and only report the Field2 match if Field1 doesn't match). * Clarification -- when it matches two rows in TableB; one via Field1 and the other via Field2. I haven't done much searching for pointers because I don't think it's possible, however I'm posting here just in case someone here knows of a way or a simple (SQL only) work-around. Edit -- Here's an example:

            SELECT * FROM TableA

            ID Field1 Field2


            10 A E
            11 E D
            12 A D

            SELECT * FROM TableB

            ID Field1 Field2


            20 A B
            21 C D

            10 will match only 20 ; 11 will match only 21 ; 12 will match both 20 and 21 -- so I want 20.

            ID Field1 Field2 ID Field1 Field2
            10 A E 20 A B <-- I want this row
            11 E D 21 C D <-- I want this row
            12 A D 20 A B <-- I want this row
            12 A D 21 C D <-- I don't want this row

            Luc's and pmpdesign's suggestions yield the same output. Here's a variation of Bernhard's suggestion, which seems to work:

            WITH cte1 AS
            (
            SELECT A.ID aID
            , A.Field1 aField1
            , A.Field2 aField2
            , B.ID bID
            , B.Field1 bField1
            , B.Field2 bField2
            FROM TableA A
            INNER JOIN TableB B
            ON A.Field1=B.Field1
            )
            , cte2 AS
            (
            SELECT A.ID aID
            , A.Field1 aField1
            , A.Field2 aField2
            , B.ID bID
            , B.Field1 bField1
            , B.Field2 bField2
            FROM TableA A
            INNER JOIN TableB B
            ON A.Field2=B.Field2
            )
            SELECT *
            FROM cte1
            UNION ALL
            SELECT C2.*
            FROM cte2 C2
            LEFT OUTER JOIN cte1 C1
            ON C2.aID=C1.aID
            WHERE C1.aID IS NULL

            L Offline
            L Offline
            Luc Pattyn
            wrote on last edited by
            #24

            Your modified message is much clearer. And this is what works for me:

            SELECT * FROM TableA A INNER JOIN TableB B ON A.Field1=B.Field1
            UNION ALL
            SELECT * FROM TableA A INNER JOIN TableB B ON A.Field2=B.Field2
            WHERE NOT A.ID IN (SELECT A.ID FROM TableA A INNER JOIN TableB B ON A.Field1=B.Field1)

            just 3 SELECTs, no LEFT PS: I failed to get it to work with a CTE on SQL Server... :)

            Luc Pattyn [My Articles] Nil Volentibus Arduum

            B 1 Reply Last reply
            0
            • P PIEBALDconsult

              I'm having some trouble with a JOIN that involves an OR (in SQL Server). For example:

              SELECT *
              FROM TableA A
              INNER JOIN TableB B
              ON A.Field1=B.Field1
              OR A.Field2=B.Field2

              Quite correctly this produces two output rows for each row in TableA that matches TableB via both Field1 and Field2* -- but for this JOIN I want to output only one row when both match (preferably the result of the Field1 match, and only report the Field2 match if Field1 doesn't match). * Clarification -- when it matches two rows in TableB; one via Field1 and the other via Field2. I haven't done much searching for pointers because I don't think it's possible, however I'm posting here just in case someone here knows of a way or a simple (SQL only) work-around. Edit -- Here's an example:

              SELECT * FROM TableA

              ID Field1 Field2


              10 A E
              11 E D
              12 A D

              SELECT * FROM TableB

              ID Field1 Field2


              20 A B
              21 C D

              10 will match only 20 ; 11 will match only 21 ; 12 will match both 20 and 21 -- so I want 20.

              ID Field1 Field2 ID Field1 Field2
              10 A E 20 A B <-- I want this row
              11 E D 21 C D <-- I want this row
              12 A D 20 A B <-- I want this row
              12 A D 21 C D <-- I don't want this row

              Luc's and pmpdesign's suggestions yield the same output. Here's a variation of Bernhard's suggestion, which seems to work:

              WITH cte1 AS
              (
              SELECT A.ID aID
              , A.Field1 aField1
              , A.Field2 aField2
              , B.ID bID
              , B.Field1 bField1
              , B.Field2 bField2
              FROM TableA A
              INNER JOIN TableB B
              ON A.Field1=B.Field1
              )
              , cte2 AS
              (
              SELECT A.ID aID
              , A.Field1 aField1
              , A.Field2 aField2
              , B.ID bID
              , B.Field1 bField1
              , B.Field2 bField2
              FROM TableA A
              INNER JOIN TableB B
              ON A.Field2=B.Field2
              )
              SELECT *
              FROM cte1
              UNION ALL
              SELECT C2.*
              FROM cte2 C2
              LEFT OUTER JOIN cte1 C1
              ON C2.aID=C1.aID
              WHERE C1.aID IS NULL

              J Offline
              J Offline
              Jorgen Andersson
              wrote on last edited by
              #25

              Here's another way to do it:

              WITH CTE AS
              (
              SELECT A.ID aID
              ,A.Field1 aField1
              ,A.Field2 aField2
              ,CASE WHEN L.ID IS NULL THEN R.ID ELSE L.ID end bID
              ,CASE WHEN L.Field1 IS NULL THEN R.field1 ELSE L.Field1 END bField1
              ,CASE WHEN L.Field2 IS NULL THEN R.Field2 ELSE L.Field2 END bField2
              FROM TableB L
              right OUTER JOIN TableA A
              ON l.field1 = a.field1
              left OUTER JOIN TableB R
              ON a.field2 = r.field2
              )
              SELECT aID
              ,aField1
              ,aField2
              ,bID
              ,bField1
              ,bField2
              FROM CTE
              WHERE bid IS NOT null

              The plan indicates that it should be faster, but that's with dummy data. I'm curious about the performance with real data.

              Light moves faster than sound. That is why some people appear bright, until you hear them speak. List of common misconceptions

              L 1 Reply Last reply
              0
              • J Jorgen Andersson

                Here's another way to do it:

                WITH CTE AS
                (
                SELECT A.ID aID
                ,A.Field1 aField1
                ,A.Field2 aField2
                ,CASE WHEN L.ID IS NULL THEN R.ID ELSE L.ID end bID
                ,CASE WHEN L.Field1 IS NULL THEN R.field1 ELSE L.Field1 END bField1
                ,CASE WHEN L.Field2 IS NULL THEN R.Field2 ELSE L.Field2 END bField2
                FROM TableB L
                right OUTER JOIN TableA A
                ON l.field1 = a.field1
                left OUTER JOIN TableB R
                ON a.field2 = r.field2
                )
                SELECT aID
                ,aField1
                ,aField2
                ,bID
                ,bField1
                ,bField2
                FROM CTE
                WHERE bid IS NOT null

                The plan indicates that it should be faster, but that's with dummy data. I'm curious about the performance with real data.

                Light moves faster than sound. That is why some people appear bright, until you hear them speak. List of common misconceptions

                L Offline
                L Offline
                Luc Pattyn
                wrote on last edited by
                #26

                Interesting. IMO it can be simplified further, as the CTE isn't really necessary, so I now have:

                SELECT A.ID aID
                ,A.Field1 aField1
                ,A.Field2 aField2
                ,CASE WHEN L.ID IS NULL THEN R.ID ELSE L.ID end bID
                ,CASE WHEN L.ID IS NULL THEN R.field1 ELSE L.Field1 END bField1
                ,CASE WHEN L.ID IS NULL THEN R.Field2 ELSE L.Field2 END bField2
                FROM TableB L
                RIGHT OUTER JOIN TableA A ON L.Field1 = A.Field1
                LEFT OUTER JOIN TableB R ON A.Field2 = R.Field2
                WHERE L.ID IS NOT NULL OR R.ID IS NOT NULL

                I have your cases depend on the ID field, not the other fields (where null might be valid) :)

                Luc Pattyn [My Articles] Nil Volentibus Arduum

                J 1 Reply Last reply
                0
                • L Luc Pattyn

                  Interesting. IMO it can be simplified further, as the CTE isn't really necessary, so I now have:

                  SELECT A.ID aID
                  ,A.Field1 aField1
                  ,A.Field2 aField2
                  ,CASE WHEN L.ID IS NULL THEN R.ID ELSE L.ID end bID
                  ,CASE WHEN L.ID IS NULL THEN R.field1 ELSE L.Field1 END bField1
                  ,CASE WHEN L.ID IS NULL THEN R.Field2 ELSE L.Field2 END bField2
                  FROM TableB L
                  RIGHT OUTER JOIN TableA A ON L.Field1 = A.Field1
                  LEFT OUTER JOIN TableB R ON A.Field2 = R.Field2
                  WHERE L.ID IS NOT NULL OR R.ID IS NOT NULL

                  I have your cases depend on the ID field, not the other fields (where null might be valid) :)

                  Luc Pattyn [My Articles] Nil Volentibus Arduum

                  J Offline
                  J Offline
                  Jorgen Andersson
                  wrote on last edited by
                  #27

                  I'm getting identical plans, but your version is prettier. :-)

                  Light moves faster than sound. That is why some people appear bright, until you hear them speak. List of common misconceptions

                  1 Reply Last reply
                  0
                  • L Luc Pattyn

                    Your modified message is much clearer. And this is what works for me:

                    SELECT * FROM TableA A INNER JOIN TableB B ON A.Field1=B.Field1
                    UNION ALL
                    SELECT * FROM TableA A INNER JOIN TableB B ON A.Field2=B.Field2
                    WHERE NOT A.ID IN (SELECT A.ID FROM TableA A INNER JOIN TableB B ON A.Field1=B.Field1)

                    just 3 SELECTs, no LEFT PS: I failed to get it to work with a CTE on SQL Server... :)

                    Luc Pattyn [My Articles] Nil Volentibus Arduum

                    B Offline
                    B Offline
                    Bernhard Hiller
                    wrote on last edited by
                    #28

                    That's actually my solution posted above - UNION vs. UNION ALL does not make a difference here, because both queries select all columns from the same table.

                    L 1 Reply Last reply
                    0
                    • B Bernhard Hiller

                      That's actually my solution posted above - UNION vs. UNION ALL does not make a difference here, because both queries select all columns from the same table.

                      L Offline
                      L Offline
                      Luc Pattyn
                      wrote on last edited by
                      #29

                      Sorry, I missed your post, yes it is the same. Good work! :)

                      Luc Pattyn [My Articles] Nil Volentibus Arduum

                      1 Reply Last reply
                      0
                      Reply
                      • Reply as topic
                      Log in to reply
                      • Oldest to Newest
                      • Newest to Oldest
                      • Most Votes


                      • Login

                      • Don't have an account? Register

                      • Login or register to search.
                      • First post
                        Last post
                      0
                      • Categories
                      • Recent
                      • Tags
                      • Popular
                      • World
                      • Users
                      • Groups