Index Match 3 criteria... works until the third changes

Ronnie12345

New Member
Joined
Mar 24, 2017
Messages
18
Hi all,

My first question here - long time reader!

I'm struggling to get an index match formula with three criteria to work. It works fine, matching the three variables until the third one varies.


The formula I'm using is

INDEX($C$5:$N$16,MATCH($B20,$B$5:$B$16,0),MATCH(D$19,$C$3:$N$3,0),MATCH(D$18,$C$4:$N$4,0))

The array C5:N16 is the first table below
The three matches are looking up using cells in the second table
Match 1: B20 is the date
Match 2: D19 is the country
Match 3: D18 is the fruit

All is well until the fruit changes.


TABLEFranceFranceFranceFranceSpainSpainSpainSpainItalyItalyItalyItaly
ApplesPearsBananasKiwisApplesPearsBananasKiwisApplesPearsBananasKiwis
Jan-17100110131025103710491061107310851097110911211133
Feb-17100210141026103810501062107410861098111011221134
Mar-17100310151027103910511063107510871099111111231135
Apr-17100410161028104010521064107610881100111211241136
May-17100510171029104110531065107710891101111311251137
Jun-17100610181030104210541066107810901102111411261138
Jul-17100710191031104310551067107910911103111511271139
Aug-17100810201032104410561068108010921104111611281140
Sep-17100910211033104510571069108110931105111711291141
Oct-17101010221034104610581070108210941106111811301142
Nov-17101110231035104710591071108310951107111911311143
Dec-17101210241036104810601072108410961108112011321144

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

TABLE 2

ApplesApplesApplesPearsPearsPearsBananasBananasBananasKiwisKiwisKiwis
FranceSpainItalyFranceSpainItalyFranceSpainItalyFranceSpainItaly
Jan-17100110491097#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Feb-17100210501098#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Mar-17100310511099#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Apr-17100410521100#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
May-17100510531101#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Jun-17100610541102#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Jul-17100710551103#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Aug-17100810561104#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Sep-17100910571105#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Oct-17101010581106#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Nov-17101110591107#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!
Dec-17101210601108#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!#REF!

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


I've had a hunt around and can't find this exact question being asked before so apologies if it has.
Can anyone help, please?

Cheers,
Ronnie
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
I would use SUMPRODUCT here


Excel 2010
ABCDEFGHIJKLM
1TABLEFranceFranceFranceFranceSpainSpainSpainSpainItalyItalyItalyItaly
2ApplesPearsBananasKiwisApplesPearsBananasKiwisApplesPearsBananasKiwis
3Jan-17100110131025103710491061107310851097110911211133
4Feb-17100210141026103810501062107410861098111011221134
5Mar-17100310151027103910511063107510871099111111231135
6Apr-17100410161028104010521064107610881100111211241136
7May-17100510171029104110531065107710891101111311251137
8Jun-17100610181030104210541066107810901102111411261138
9Jul-17100710191031104310551067107910911103111511271139
10Aug-17100810201032104410561068108010921104111611281140
11Sep-17100910211033104510571069108110931105111711291141
12Oct-17101010221034104610581070108210941106111811301142
13Nov-17101110231035104710591071108310951107111911311143
14Dec-17101210241036104810601072108410961108112011321144
15
16
17TABLE 2
18ApplesApplesApplesPearsPearsPearsBananasBananasBananasKiwisKiwisKiwis
19FranceSpainItalyFranceSpainItalyFranceSpainItalyFranceSpainItaly
20Jan-17100110491097101310611109102510731121103710851133
21Feb-17100210501098101410621110102610741122103810861134
22Mar-17100310511099101510631111102710751123103910871135
23Apr-17100410521100101610641112102810761124104010881136
24May-17100510531101101710651113102910771125104110891137
25Jun-17100610541102101810661114103010781126104210901138
26Jul-17100710551103101910671115103110791127104310911139
27Aug-17100810561104102010681116103210801128104410921140
28Sep-17100910571105102110691117103310811129104510931141
29Oct-17101010581106102210701118103410821130104610941142
30Nov-17101110591107102310711119103510831131104710951143
31Dec-17101210601108102410721120103610841132104810961144
Sheet1
Cell Formulas
RangeFormula
B20=SUMPRODUCT(($B$2:$M$2=B$18)*($B$1:$M$1=B$19)*($A$3:$A$14=$A20)*($B$3:$M$14))
 
Upvote 0
If you wanted to use an INDEX MATCH formula, one working solution looks like this:

=INDEX($B$3:$M$14,MATCH($A20,$A$3:$A$14,0),MATCH(B$18&B$19,$B$2:$M$2&$B$1:$M$1,0)) Ctrl Shift Enter

The parameters of the INDEX function are: "array", "row number", "column number"

Note that the references in this formula are based off of post #2.
 
Last edited:
Upvote 0
Enter the formula and press Ctrl+Shift+Enter. Not just enter.

=INDEX($C$5:$N$16,MATCH($B20,$B$5:$B$16,0),MATCH(C$18&C$19,$C$4:$N$4&$C$3:$N$3,0))
 
Upvote 0

Forum statistics

Threads
1,215,172
Messages
6,123,428
Members
449,099
Latest member
COOT

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