Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations Mike Lewis on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

trouble with matching in a query 1

Status
Not open for further replies.

teach314

Technical User
Jul 29, 2011
183
CA

Consider table tblA to the left. Each ID has rows 1 to 6. For each ID, the 6 values of
valx and valy form 3 matching pairs, each written both 'forwards' and 'backwards'.
For ID = 91, the three matching pairs are (24, 19), (18, 20), (21, 16).

I want to get output like the table tblB shown at right. This shows the row values
corresponding to the matched pairs. To avoid duplicates, I keep rowx < rowy.

Code:
tblA                                               tblB              

ID    row    valx    valy                           ID      rowx     rowy            
--------------------------                          ---------------------                
91     1      24      19                            91       1        3                                 
91     2      18      20                            91       2        6         
91     3      19      24                            91       4        5      
91     4      21      16            
91     5      16      21                            92  etc... 
91     6      20      18
                                   
92     1      21      16                         
92     2      20      18                    
... etc...

Many thanks for any clues. My coding is a bit rusty, and I just can't get this to work.

Teach314
 
Self-join the table, the sql below should be visible in design view too:
Code:
SELECT tblA.ID, tblA.row AS rowx, tblA_1.row AS rowy
FROM tblA INNER JOIN tblA AS tblA_1 ON (tblA.valx = tblA_1.valy) AND (tblA.ID = tblA_1.ID)
WHERE (((tblA.row)<[tblA_1].[row]))
ORDER BY tblA.ID, tblA.row;


combo
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top