SUMIF month criteria, how?

dwest100

Board Regular
Joined
Jan 2, 2005
Messages
138
Hi,
using SUMIF, the comparison column contains dates in mm/dd/yyyy format.
I want to use the month from that column as the SUMIF criteria.

I tinkered with the MONTH() function to no avail.

Any ideas how to do it?

Thanks!
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Try
Code:
=SUMPRODUCT(IF(MONTH(A1:A10)=1,B1:B10))
Enter code with Ctrl-Shift-Enter.

A1:A10 = dates
B1:B10 = summable numbers
1 = month
 
Upvote 0
=SUMPRODUCT(IF(MONTH(A1:A10)=1,B1:B10))

You can dispense with the IF, then you don't need CSE, i.e.

=SUMPRODUCT(--(MONTH(A1:A10)=1),B1:B10)

Note: Empty cells are deemed to be a January date so you might also want to check that A1:A10 is a date, i.e.

=SUMPRODUCT(ISNUMBER(A1:A10)*(MONTH(A1:A10)=1),B1:B10)

...or add a year check

=SUMPRODUCT((YEAR(A1:A10)=2008)*(MONTH(A1:A10)=1),B1:B10)
 
Upvote 0
Thanks dafan.
What do you mean by enter code with ctrl-shift-enter? Don't I just enter this as a formula?
 
Upvote 0
With array formulas you need to Ctrl-Shift-Enter. check out the article on CSE-formulas here: http://www.mrexcel.com/tip011.shtml

Barry: What does -- do here? Im not really familiar with SUMPRODUCT but I thought this would be a good situation to use it.
 
Upvote 0
Some options...

[1] Build a pivot table, grouping dates by months.

Lets the comparison column be A and the column to sum B (Why not give them self right away?)...

[2]

=SUMIF(A:A,">="&E2,B:B)-SUMIF(A:A,">="&F2,B:B)

where E2 is the month of interest specified as: 2008-01-01 and F2 as 2008-02-01.

[3]

Control+shift+enter, not just enter...
Code:
=SUM(
   IF(ISNUMBER($A$2:$A$500),
   IF($A$2:$A$500-DAY($A$2:$A$500)+1=E2,
     $B$2:$B$500)))
Hi,
using SUMIF, the comparison column contains dates in mm/dd/yyyy format.
I want to use the month from that column as the SUMIF criteria.

I tinkered with the MONTH() function to no avail.

Any ideas how to do it?

Thanks!
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,496
Messages
6,113,993
Members
448,539
Latest member
alex78

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