SUMIFS with date periods and names as criteria

add456

New Member
Joined
Feb 6, 2015
Messages
3
Hi everyone, I am trying to use the SUMIFS formula to capture sums with 1) date criteria (i.e. all hours between Date 1 and Date 2) and specific names (i.e. upwards of 40 distinct names).

I have attached a worksheet sample below. For example, I would like to know the total number of hours for Adam Smith for the month of September. Note that the month period varies based on accounting month so I cannot use a typical September start and end date. See Columns M and N ==> I included the specific date periods that would be helpful.

I entered the formula used (see Adam Smith formula). I receive a #VALUE! error message. I tried the formula with a smaller set of names and manually entered the name (i.e. "Adam Smith") but with 40+ names and people coming in and going out, manually entering names cannot be best practice. Any help with this would greatly be appreciated.

Thanks everyone!!!!!



Columns
A BCDE
FGHIJKLMN
1-Sep2-Sep3-Sep4-Sep5-Sep6-Sep2-Nov9-Nov10-NovStartEnd
Adam Smith1367219225532September1-Sep25-Sep
Brian Davis12421033319October26-Sep30-Oct
George Washington44244382911124420November31-Oct27-Nov
Target Answer
September TotalNovember TotalSeptember TotalOctober TotalNovember Total
Adam Smith=SUMIFS(B3:J5, A3:A5,A8,B2:J2,">="&M2,B2:J2,"<="&N2)470109
Brian Davis19055
George Washington168076

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


<colgroup><col><col><col><col span="3"><col><col span="2"><col></colgroup><tbody>
</tbody>
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Maybe this


A
B
C
D
E
F
G
H
I
J
K
L
M
N
1
2
01/set​
02/set​
03/set​
04/set​
05/set​
06/set​
02/nov​
09/nov​
10/nov​
Start​
End​
3
Adam Smith​
1​
3​
6​
7​
21​
9​
22​
55​
32​
September​
01/set​
25/set​
4
Brian Davis​
1​
2​
4​
2​
10​
33​
3​
19​
October​
26/set​
30/out​
5
George Washington​
44​
2​
44​
38​
29​
11​
12​
44​
20​
November​
31/out​
27/nov​
6
7
September​
October​
November​
8
Adam Smith​
47​
0​
109​
9
Brian Davis​
19​
0​
55​
10
George Washington​
168​
0​
76​
11

Formula in B8
=SUMPRODUCT(($B$3:$J$5)*($A$3:$A$5=$A8)*($B$2:$J$2>=INDEX($M$3:$M$5,MATCH(B$7,$L$3:$L$5,0)))*($B$2:$J$2<=INDEX($N$3:$N$5,MATCH(B$7,$L$3:$L$5,0))))
copy across till D8 and down

Hope this helps

M.
 
Upvote 0
Hey bud!

I have also solved this with a combo of index/match and sumifs. In the top-left cell I have =SUMIFS(INDEX($B$2:$J$4,MATCH($A7,$A$2:$A$4,0),),$B$1:$J$1,">="&M$7,$B$1:$J$1,"<="&M$8) (correct cell references as appropriate). I have transposed the look-up table to make it easier to copy the formula across.

Essentially, what is going on here are that there are two lookups. Firstly, the index match finds the row that matches the employee name. Then, the sumifs uses that row to find the cells matching the date constraints.

Cheers!
Marcus


1-Sep2-Sep3-Sep4-Sep5-Sep6-Sep2-Nov9-Nov10-NovStartEnd
Adam Smith1367219225532September1-Sep25-Sep
Brian Davis12421033319October26-Sep30-Oct
George Washington44244382911124420November31-Oct27-Nov
SeptemberOctoberNovemberSeptember TotalOctober TotalNovember TotalSeptemberOctoberNovember
Adam Smith470109470109Start1-Sep26-Sep31-Oct
Brian Davis1905519055End25-Sep30-Oct27-Nov
George Washington168076168076

<tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,213,482
Messages
6,113,908
Members
448,532
Latest member
9Kimo3

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