Vlookup multiple matches based on multiple conditions

Shetara

New Member
Joined
Feb 17, 2017
Messages
43
Hello I need a formula for the following. I need to pull the name with multiple criteria. For example I need to know from MGM who by name has No-Action. Can anyone help please?

Sheet 1:

ABC

Name

Org.
Action
JohnsonMGMNo-Action
RobinsonCDFActive
WilliamsMGMNo-Action
TuckBPMPending
WrightLOIProcessing

<tbody>
</tbody>

Sheet 2: Output:
A​
Name
Johnson
Williams

<tbody>
</tbody>
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
maybe something like...

Unknown
ABCD
1NameOrg.Action
2JohnsonMGMNo-Action
3RobinsonCDFActive
4WilliamsMGMNo-Action
5TuckBPMPending
6WrightLOIProcessing
7
8Name
9Johnson
10Williams

<tbody>
</tbody>
Sheet1

Array Formulas
CellFormula
A9{=IFERROR(INDEX(Sheet1!$A$2:$A$6,SMALL(IF(Sheet1!$C$2:$C$6="No-Action",ROW(Sheet1!$A$2:$A$6)-ROW(Sheet1!$A$2)+1),ROWS($A$9:A9))),"")}

<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>
 
Upvote 0
Thanks. I need to also match it to MGM. The criteria's are Org. must be MGM and Action must be No Action to return a list of name. Can you help again with a formula?
 
Upvote 0
I must have missed the "MGM" bit

Unknown
ABCD
1NameOrg.Action
2JohnsonMGMNo-Action
3RobinsonCDFActive
4WilliamsMGMNo-Action
5TuckBPMPending
6WrightLOIProcessing
7
8Name
9Johnson
10Williams

<tbody>
</tbody>
Sheet1

Array Formulas
CellFormula
A9{=IFERROR(INDEX(Sheet1!$A$2:$A$6,SMALL(IF(Sheet1!$B$2:$B$6="MGM",IF(Sheet1!$C$2:$C$6="No-Action",ROW(Sheet1!$A$2:$A$6)-ROW(Sheet1!$A$2)+1)),ROWS($A$9:A9))),"")}

<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>
 
Upvote 0
For some reason it's coming back as an empty cell. Do you think its due to the fact that I my output is on a separate sheet?
 
Upvote 0
just make sure the sheetname you are referencing matches whats in the formula.

I wrote it as if your data was located on sheet1

its also an array and requires control shift enter, not just enter

you would also need to update this bit ROWS($A$9:A9) to be the cell you put the first formula in before you drag it down
 
Last edited:
Upvote 0
Its still coming back as a blank cell. Do I need to put AND in the formula being that it has two lookup criteria's? Thanks.
 
Upvote 0

Forum statistics

Threads
1,217,440
Messages
6,136,625
Members
450,022
Latest member
Joel1122331

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