A formula to do a 3 way match and bring a value

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Option 1:

Select the I15:L15 range and enter this formula:

=INDEX(OFFSET(E4:H9,0,MATCH(I12,E2:AO2,0)-1),MATCH(E14,A4:A9,0),0)

change the ranges to match your sheet, especially the E2:AO2 range since I don't know how far to the right it goes, and confirm by pressing Control+Shift+Enter.


Option 2:

Enter this formula in I14:

=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:I15))

Change the ranges as before, but it's an ordinary formula, so just use Enter. Copy it to the next 3 cells.
 
Upvote 0
Hi Eric,

The second one works and bring me a number (563 in this example) but when I copy it to J14 and K14 it still brings me the same value. Its expected to bring the value that matches the top cell (J13 and J14) which in this example is 252 in J14. Cheers.

Regards,
Bobby
 
Upvote 0
Did you copy the original formula, or type it in? A missing or extra $ can make a huge difference. Here's the test sheet I used (and you may consider using one of the screen printing tools, such as the HTML Maker in my signature, in the future to make it easier for people to help):


Book1
ABCDEFGHIJKL
1
2Wed, 04-Sep-19Wed, 11-Sep-19
3KPI 1000KPI 1400KPI 1800ActionKPI 1000KPI 1400KPI 1800Action
4223223223223
5201201201201
600
7449233682449233682
8Perveen Nawaz, Usama5632528151234
976539711627653971162
10
11
12Wed, 04-Sep-19
13KPI 1000KPI 1400KPI 1800Action
14Perveen Nawaz, Usama5632520815
155632520815
165632520815
Sheet9
Cell Formulas
RangeFormula
I15=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:I15))
I16=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),MATCH(I$13,$E$3:$H$3,0))
I14:L14{=INDEX(OFFSET(E4:H9,0,MATCH(I12,E2:AO2,0)-1),MATCH(E14,A4:A9,0),0)}
J15=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:J15))
J16=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),MATCH(J$13,$E$3:$H$3,0))
K15=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:K15))
K16=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),MATCH(K$13,$E$3:$H$3,0))
L15=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:L15))
L16=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),MATCH(L$13,$E$3:$H$3,0))
Press CTRL+SHIFT+ENTER to enter array formulas.


Option 1 is the I14:L14 array formula. I15 is option 2, with J15:L15 showing what they should be after copying I15. I added the row 16 formulas, which use MATCH instead of COLUMNS to determine which heading to use. Hope this helps.
 
Upvote 0
Works now. Problem solved. Cheers Eric you're a star :)


Did you copy the original formula, or type it in? A missing or extra $ can make a huge difference. Here's the test sheet I used (and you may consider using one of the screen printing tools, such as the HTML Maker in my signature, in the future to make it easier for people to help):

ABCDEFGHIJKL
1
2Wed, 04-Sep-19Wed, 11-Sep-19
3KPI 1000KPI 1400KPI 1800ActionKPI 1000KPI 1400KPI 1800Action
4223223223223
5201201201201
600
7449233682449233682
8Perveen Nawaz, Usama5632528151234
976539711627653971162
10
11
12Wed, 04-Sep-19
13KPI 1000KPI 1400KPI 1800Action
14Perveen Nawaz, Usama5632520815
155632520815
165632520815

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

Worksheet Formulas
CellFormula
I15=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:I15))
J15=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:J15))
K15=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:K15))
L15=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),COLUMNS($I15:L15))
I16=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),MATCH(I$13,$E$3:$H$3,0))
J16=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),MATCH(J$13,$E$3:$H$3,0))
K16=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),MATCH(K$13,$E$3:$H$3,0))
L16=INDEX(OFFSET($E$4:$H$9,0,MATCH($I$12,$E$2:$AO$2,0)-1),MATCH($E$14,$A$4:$A$9,0),MATCH(L$13,$E$3:$H$3,0))

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

<tbody>
</tbody>

Array Formulas
CellFormula
I14:L14{=INDEX(OFFSET(E4:H9,0,MATCH(I12,E2:AO2,0)-1),MATCH(E14,A4:A9,0),0)}

<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>



Option 1 is the I14:L14 array formula. I15 is option 2, with J15:L15 showing what they should be after copying I15. I added the row 16 formulas, which use MATCH instead of COLUMNS to determine which heading to use. Hope this helps.
 
Upvote 0

Forum statistics

Threads
1,214,593
Messages
6,120,435
Members
448,961
Latest member
nzskater

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