INDEX and MATCH with multiple criteria is not returning required results

Sean15

Well-known Member
Joined
Jun 25, 2005
Messages
609
Office Version
  1. 2019
Platform
  1. Windows
Hi:

The formulas in range J26:L28 are not returning the required results. Could you help please?


INDEX & MATCH with multiple criteria.xlsx
EFGHIJKL
21derekexec1250
22markpayroll1425
23paulIT5300
24
25ITexecpayroll
26derek#REF!1250#REF!
27mark#REF!1425#REF!
28paul#REF!5300#REF!
29
Sheet1
Cell Formulas
RangeFormula
J26:L28J26=INDEX($G$21:$G$23,MATCH($I26,$E$21:$E$23,0), MATCH(J$25,$F$21:$F$23,0))
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.

StephenCrump

MrExcel MVP
Joined
Sep 18, 2013
Messages
4,192
Office Version
  1. 365
Platform
  1. Windows
It's not clear what you're trying to do. What are your required results in J26:L28?
 

Habtest

Board Regular
Joined
Jul 30, 2020
Messages
180
Office Version
  1. 2016
Platform
  1. Windows
Is this what you are looking for?
Book1
EFGHIJKL
21derekexec1,250
22markpayroll1,425
23paulIT5,300
24
25ITexecpayroll
26derek 1,250
27mark 1,425
28paul5,300
Sheet1
Cell Formulas
RangeFormula
J26:L28J26=IFERROR(INDEX($G$21:$G$23,MATCH(1,($E$21:$E$23=$I26)*($F$21:$F$23=J$25),0)),"")
Press CTRL+SHIFT+ENTER to enter array formulas.
 

Alex Blakenburg

Well-known Member
Joined
Feb 23, 2021
Messages
1,147
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

Yes, but is a non array formula available? I don't want to use CTRL+SHIFT+ENTER to enter formula.

Does this do what you had in mind ?

20210722 Lookup MultiCriteria.xlsx
EFGHIJKLM
21derekexec1250
22markpayroll1425
23paulIT5300
24
25ITexecpayroll
26derek 1250 
27mark  1425
28paul5300  
29
Sheet1
Cell Formulas
RangeFormula
J26:L28J26=IFERROR(LOOKUP(2,1/(($E$21:$E$23=$I26)*($F$21:$F$23=J$25)),$G$21:$G$23),"")
 

plshelpexcel

New Member
Joined
Aug 24, 2018
Messages
6
Office Version
  1. 365
Platform
  1. Windows
Perhaps this could also work for you:

Book2
EFGHIJKL
21derekexec1250
22markpayroll1425
23paulIT5300
24
25ITexecpayroll
26derek-1,250-
27mark--1,425
28paul5,300--
Sheet1
Cell Formulas
RangeFormula
J26:L28J26=+SUMIFS($G$21:$G$23,$E$21:$E$23,$I26,$F$21:$F$23,J$25)
 
Solution

Forum statistics

Threads
1,136,765
Messages
5,677,615
Members
419,707
Latest member
Anna vib

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
Top