Need help returning multiple criterial using sumifs and or Index/Match

Kyosti

Board Regular
Joined
Jun 2, 2008
Messages
86
I need help with this data I have created. This is a Table, so lets say "Table1":

ReportDateEmployeeNameTrans1
Trans2Trans3Trans4Trans5Trans6Trans7
8/1/14Rep1
8/1/14Rep2
8/1/14Rep321
8/1/14Rep4212
8/1/14Rep5
8/1/14Rep6
8/1/14Rep7
8/1/14Rep8
8/1/14Rep93
8/1/14Rep10
8/1/14Rep11
8/1/14Rep1211463
8/1/14Rep1311
8/1/14Rep14
8/1/14Rep15
8/1/14Rep16444
8/1/14Rep1752
8/1/14Rep1816
8/1/14Rep19
8/1/14Rep201
8/1/14Rep218
8/1/14Rep22
8/1/14Rep23
8/1/14Rep24
8/1/14Rep25
8/1/14Rep261675
8/1/14Rep275
8/1/14Rep282
8/1/14Rep2912121
8/1/14Rep30

<colgroup><col><col><col span="7"></colgroup><tbody>
</tbody>


I need to be able to return the value for a specific rep, on a specific date, by transaction. What I have so far is this:

=SUMIFS(Table1[Trans1],Table1[ReportDate],A2,Table1[EmployeeName],A1)

What I need to do is be able to make the formula work using "Trans1" as a variable so it can look at a cell such as A3 to find the correct column. So A1 is the name, A2 is the date, and A3 would be the transaction type it needs to find and return the value for.

Please help!!!:mad:
 
Last edited:

Some videos you may like

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.

pgc01

MrExcel MVP
Joined
Apr 25, 2006
Messages
19,884
Hi

You could simply use Indirect() and build the column reference this way:

=SUMIFS(INDIRECT("Table1["&A3&"]"),Table1[ReportDate],A2,Table1[EmployeeName],A1)

This will work, but the formula is volatile and inefficient. If you have big tables you'll notice how the workbook slows down.

A much better solution is to look for the column in the header row:

=SUMIFS(INDEX(Table1[#Data],0,MATCH(A3,Table1[#Headers],0)),Table1[ReportDate],A2,Table1[EmployeeName],A1)

Please try
 

Watch MrExcel Video

Forum statistics

Threads
1,123,481
Messages
5,601,918
Members
414,482
Latest member
morkar

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