IF and Index Match

jamesmev

Board Regular
Joined
Apr 9, 2015
Messages
233
Office Version
  1. 365
Platform
  1. Windows
I am trying to avoid using vlookup... That might be the most over used statement in Excel world.

I have a sheet where I need the result if two criteria are met.
For simplicity I'll try to explain below

A B C
NAME Date Total



So if you have on sheet 1 "Name" and it falls within "Date" it provides "total"

Any help would be appreciated... This might be one of those .... DUH formula's but - my brain is broken.
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
Are you looking to return a single value, sum multiple values that meet the name and date requirements, or something else?

I personally think vlookup is useful for certain situations...it's simple.
 
Upvote 0
Maybe something like one of the below formulas (it would help to post an example with the expected resulted).

The INDEX AGGREGATE formula in C8 will work in Excel 2010 or later.
If you have an earlier ver. then maybe something like the formula in C9 which must be entered with CTRL-SHIFT-ENTER.
Excel Workbook
ABC
1NAMEDateTotal
2Mary Smith2/5/201945
3Becky Jones3/5/201956
4Sam Spade3/1/201968
5
6
7Lookup
8Becky Jones3/5/201956
956
Sheet
 
Upvote 0
Maybe something like one of the below formulas (it would help to post an example with the expected resulted).

The INDEX AGGREGATE formula in C8 will work in Excel 2010 or later.
If you have an earlier ver. then maybe something like the formula in C9 which must be entered with CTRL-SHIFT-ENTER.

ABC
1NAMEDateTotal
2Mary Smith2/5/201945
3Becky Jones3/5/201956
4Sam Spade3/1/201968
5
6
7Lookup
8Becky Jones3/5/201956
9 56

<colgroup><col style="width:30px; "><col style="width:90px;"><col style="width:86px;"><col style="width:76px;"></colgroup><tbody>
</tbody>

Spreadsheet Formulas
CellFormula
C8=INDEX($C$2:$C$4,AGGREGATE(15,6,(ROW($A$2:$A$4)-ROW($A$2)+1)/(($A$2:$A$4=$A$8)*($B$2:$B$4=$B$8)),1))
C9{=INDEX($C$2:$C$4,MATCH(1,($A$2:$A$4=A8)*($B$2:$B$4=$B$8),0))}

<tbody>
</tbody>
Formula Array:
Produce enclosing
{ } by entering
formula with CTRL+SHIFT+ENTER!

<tbody>
</tbody>


Excel tables to the web >> Excel Jeanie HTML 4

The Aggregate works perfectly. I am running into an issue that the data is a Pivot.. Is there a way to combat that? I am getting a NUM error?
Any Ideas?
 
Upvote 0
It appears to be the reference to a secondary sheet. . . The formula lives on Sheet 1 - - - the data lives on Sheet 2. When I reference the 2nd sheet is where I'm getting the issue. The Pivot isn't creating the problem.
 
Upvote 0
See if this example helps using 2 sheets.

Excel Workbook
ABC
1Lookup
2Becky Jones3/5/201956
Sheet1
Excel Workbook
ABC
1NAMEDateTotal
2Mary Smith2/5/201945
3Becky Jones3/5/201956
4Sam Spade3/1/201968
Sheet2
 
Upvote 0
Thank you. I appreciate it. I believe this has been resolved. Great help!
 
Upvote 0
You're welcome. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,551
Messages
6,114,272
Members
448,558
Latest member
aivin

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