Find first match from one range in another range and return related value

cparsons1

New Member
Joined
Jan 18, 2019
Messages
3
I need to find the first instance of a named range that occurs in a table and return another value from that table on the same row.

Two Named Ranges Cat1 and Cat2

Cat 1Cat 2
Type AType E
Type BType F
Type CType G
Type D

<colgroup><col width="64" span="2" style="width:48pt"> </colgroup><tbody>
</tbody>

I need to search Column A in this table and return the first time something from Cat1 appears and return the value from column B that corresponds to the match. I have looked through many examples of Index Match but I have not been able to find this scenario.

AB
1TypeVolume
2Type E200
3Type G300
4Type C400
5Type F500
6Type F600
7Type F700
8Type F800
9Type F900
10Type A1000
11Type G1100
12Type G1200
13Type G1300
14Type G1400
15Type G1500
16
17
18
19
20

<colgroup><col width="64" span="3" style="width:48pt"> </colgroup><tbody>
</tbody>
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Welcome to the forum.

Try:


ABCDEFGHI
1TypeVolumeCat 1Cat 2Cat1st Match
2Type E200Type AType ECat_1400
3Type G300Type BType FCat_2200
4Type C400Type CType G
5Type F500Type D
6Type F600
7Type F700
8Type F800
9Type F900
10Type A1000
11Type G1100
12Type G1200
13Type G1300
14Type G1400
15Type G1500

<tbody>
</tbody>
Sheet21

Worksheet Formulas
CellFormula
H2=IFERROR(INDEX($B$2:$B$15,AGGREGATE(15,6,MATCH(INDIRECT(G2),$A$2:$A$15,0),1)),"No match")

<tbody>
</tbody>

<tbody>
</tbody>



Note that the D2:D5 is Cat_1, and E2:E4 is Cat_2. Without the underscores, those are invalid names in more recent versions of Excel. This raises another point, since the AGGREGATE function is also only available since version 2010. But it's possible to do it without AGGREGATE if need be.

Hope this helps.
 
Upvote 0
How about


Excel 2013/2016
ABCDEFG
1TypeVolumeCat 1Cat 2
2Type E200400Type AType E
3Type G300Type BType F
4Type C400Type CType G
5Type F500Type D
6Type F600
7Type F700
8Type F800
9Type F900
10Type A1000
11Type G1100
12Type G1200
13Type G1300
14Type G1400
15Type G1500
End
Cell Formulas
RangeFormula
D2{=INDEX(B2:B15,MATCH(1,--(A2:A15=F2:F5),0))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Fluff, I don't believe that will work if the first match is more than 4 rows down. For example, if A4 were "Type X", then I'd expect the result to be 1000, since A10 has "Type A" in it. In fact, I think it only coincidentally works since "Type C" is on the same row in both ranges. You'd need to do something like A2:A15=TRANSPOSE(F2:F5) to check everything against everything, then use MMULT to roll up the results.
 
Last edited:
Upvote 0
Thanks! I'm trying this but where does the 15,6 come from?
Sheet21

Worksheet Formulas
CellFormula
H2=IFERROR(INDEX($B$2:$B$15,AGGREGATE(15,6,MATCH(INDIRECT(G2),$A$2:$A$15,0),1)),"No match")

<tbody>
</tbody>

<tbody>
</tbody>



Note that the D2:D5 is Cat_1, and E2:E4 is Cat_2. Without the underscores, those are invalid names in more recent versions of Excel. This raises another point, since the AGGREGATE function is also only available since version 2010. But it's possible to do it without AGGREGATE if need be.

Hope this helps.[/QUOTE]
 
Upvote 0
I've been trying this but it returns a 0 (zero). The Cat1 range is actually a named range from another sheet and is in AY7:AY41. Also, I'm not familiar with the use of --.
 
Upvote 0
AGGREGATE is one of the most complicated functions, since it can do 19 different functions. The 15 says which function to do, in this case the SMALL function. The 6 means to ignore errors. The MATCH function looks for every value in Cat_1 in the range A2:A15. If it finds it, it returns the position. If it doesn't, it returns #N/A, so the 6 is needed to ignore the #N/A values. Incidentally, the non-AGGREGATE version is:

=IFERROR(INDEX($B$2:$B$15,SMALL(IFERROR(MATCH(INDIRECT(I2),$A$2:$A$15,0),2^21),1)),"No match")

which you have to enter using Control+Shift+Enter.

See this link for more about AGGREGATE:
https://support.office.com/en-us/article/aggregate-function-43b9278e-6aa7-4f17-92b6-e19993fa26df
 
Upvote 0
Here's an alternate formula based on Fluff's idea:

=INDEX(B2:B15,MATCH(1,--(MMULT(--(A2:A15=TRANSPOSE(F2:F5)),ROW(F2:F5))>0),0))
confirmed by pressing Control+Shift+Enter.

But see if you get one of the others working first, since I think they'd be more efficient.
 
Upvote 0
Fluff, I don't believe that will work if the first match is more than 4 rows down. For example, if A4 were "Type X", then I'd expect the result to be 1000, since A10 has "Type A" in it. In fact, I think it only coincidentally works since "Type C" is on the same row in both ranges. You'd need to do something like A2:A15=TRANSPOSE(F2:F5) to check everything against everything, then use MMULT to roll up the results.
Thanks for that Eric, you're quite right.
(y)
 
Upvote 0

Forum statistics

Threads
1,215,054
Messages
6,122,897
Members
449,097
Latest member
dbomb1414

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