Reverse Index & Match

Blcook6383

New Member
Joined
Apr 2, 2018
Messages
5
I need to match a value in an array to a value in the first row. See Below:


MedicalDentalVoluntaryVoluntary (2)Voluntary (3)Voluntary (4)
MedicalDentalPediatric DentalBasic LifeAFLAC
STD
LTD

<tbody>
</tbody>


<colgroup><col><col><col><col span="3"></colgroup><tbody>
</tbody>
For example, I want to be able to lookup "Pediatric Dental" and obtain "Voluntary (2)".

There are 2 caveats:
1 - "Pediatric Dental" can show up in other columns and rows below the first row (not just the second row of column four) and
2 - "Pediatric Dental" will only show in one place in the entire array below the first row.


I've used "=INDEX($C$43:$H$43,1,MATCH("Pediatric Dental",$C$44:$H$47,0))" and
"=INDEX($C$43:$H$43,,MATCH("Pediatric Dental",INDEX($C$44:$H$47,MATCH("Pediatric Dental",$C$44:$H$47,0),),0))"

but the problem is that I cannot match from an array it seems.
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
As you surmised, MATCH doesn't work on a 2-D array. You can try something like this:

=INDEX($C$43:$H$43,AGGREGATE(15,6,(COLUMN($C$44:$H$47)-COLUMN($C$44)+1)/($C$44:$H$47="Pediatric Dental"),1))
 
Upvote 0
You could also use this. But like Eric's solution, if there's more than 1 occurrence of "Pediatric Dental", you're stuck. In this solution, the very last "1" below is the nth value for the SMALL function. So if there were say 2 occurrences and you wanted the last occurrence of Pediatric Dental, you could change the 1 to 2, etc.

=INDEX(C43:H43,0,SMALL(IF(C44:H47="Pediatric Dental",COLUMN(C43:H3)-MIN(COLUMN(C43:H3))+1),1))
Ctrl+Shift+Enter


There is an extensive thread on this very topic on mrexcel from 2010, which also offers VBA solutions. You may find that helpful for dealing with the multiple occurrences.

https://www.mrexcel.com/forum/excel-questions/516742-how-return-results-position-2d-array.html

James
 
Upvote 0

Forum statistics

Threads
1,213,515
Messages
6,114,080
Members
448,548
Latest member
harryls

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