Index Match - bring back 2nd match

psrs0810

Well-known Member
Joined
Apr 14, 2009
Messages
1,109
I am trying setup an index match but I have 2 of the same value. How can I setup my index match to bring back the second match?
thanks
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Hey, you can offset the table to start at 1 row underneath the first match.

Say you are looking up for the ID value of 15 in a table governed in A1:C10, then this will return the 2nd case of 15 in column A (if there is a 2nd case):

Code:
=INDEX(OFFSET(A1,MATCH(15,A:A,FALSE),0):C10,MATCH(15,OFFSET(A1,MATCH(15,A:A,FALSE),0):A10,FALSE),2)

Will return the value in column B that is from the 2nd value of 15 in column A.
 
Upvote 0
If you know there are exactly 2 matches, you can use the formula in E2 that returns the last match. If there may be more matches, you can use the array formula in F2 which will let you pick which match you want.

ABCDEF
1ListValueKeyLast Value2nd value
2a1b106
3b2
4c3
5d4
6a5
7b6
8e7
9f8
10g9
11b10

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
E2=LOOKUP(2,1/(A2:A11=D2),B2:B11)

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

Array Formulas
CellFormula
F2{=INDEX(B2:B11,SMALL(IF(A2:A11=D2,ROW(A2:A11)-ROW(A2)+1),2))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Upvote 0
Using the data example from Eric W here is another option if you are using Excel ver. 2010 or later.
Excel Workbook
ABCDEF
1ListValueKeyLast Value2nd value
2a1b106
3b2
4c3
5d4
6a5
7b6
8e7
9f8
10g9
11b10
Sheet
 
Upvote 0

Forum statistics

Threads
1,214,583
Messages
6,120,378
Members
448,955
Latest member
BatCoder

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top