Date Formula with SUMIF

DJ'sGiGi

Board Regular
Joined
May 25, 2007
Messages
92
Is there a reason Excel won't perform the SUMIF function on a cell with a date formula? In the example below, Excel ignores the SUMIF when I have a formula A6:A18. But if I simply type in values, it calculates fine. My entries are serial dates formatted as a date. I’ve even tried =SUMIF($A$6:$A$18,”=”&A6,$B$6:$B$18) and that doesn’t work either.

<PRE>
9/16/2014 OFF 0.00 "=SUMIF($A$6:$A$18,A6,$B$6:$B$18)"
9/17/2014 0.50 0.50
9/17/2014 0.75 0.75
9/18/2014 0.25 0.25
9/18/2014 0.00
0.00
0.00 </PRE>

Assistance is appreciated.
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
If the dates are serial then I suspect the culprit is encoded TIME data.
You can check this by changing the cell formatting to general and see if the value is an INTEGER or if it has decimal information (Decimal values represent times)
If you want to consider 9/17/14 9:00AM equal to 9/17/14 10:00AM then you need to work with the INTEGER portion only with a formula such as the following...

=SUMPRODUCT(--(INT($A$6:$A$18)=INT(A7)),$B$6:$B$18)
 
Upvote 0
If the dates are serial then I suspect the culprit is encoded TIME data.
You can check this by changing the cell formatting to general and see if the value is an INTEGER or if it has decimal information (Decimal values represent times)
If you want to consider 9/17/14 9:00AM equal to 9/17/14 10:00AM then you need to work with the INTEGER portion only with a formula such as the following...

=SUMPRODUCT(--(INT($A$6:$A$18)=INT(A7)),$B$6:$B$18)


BiocideJ,

You are correct, when formatted as general, I get a decimal value. However, your formula returns a #VALUE (even if I enter it as an array.) Also, what does the -- represent between the 2 parens after sumproduct?

Thanks.
 
Upvote 0
If it is giving an error then there must be some non-numeric value in either A6:A18 or B6:B18 which is preventing the SUM portion of the SUMPRODUCT from working.

Also, I noticed that =SUMPRODUCT(--(INT($A$6:$A$18)=INT(A7)),$B$6:$B$18)
should be
=SUMPRODUCT(--(INT($A$6:$A$18)=INT(A6)),$B$6:$B$18)

The -- forces the logical expression (A6:18=A6) to convert from a series of TRUE & FALSE to a series of 1 and 0 so they can be correctly multiplied by the range B6:B18

i.e.
=--TRUE evaluates to 1
and
=--FALSE evaluates to 0
 
Upvote 0
If it is giving an error then there must be some non-numeric value in either A6:A18 or B6:B18 which is preventing the SUM portion of the SUMPRODUCT from working.

Also, I noticed that =SUMPRODUCT(--(INT($A$6:$A$18)=INT(A7)),$B$6:$B$18)
should be
=SUMPRODUCT(--(INT($A$6:$A$18)=INT(A6)),$B$6:$B$18)

The -- forces the logical expression (A6:18=A6) to convert from a series of TRUE & FALSE to a series of 1 and 0 so they can be correctly multiplied by the range B6:B18

i.e.
=--TRUE evaluates to 1
and
=--FALSE evaluates to 0

Correct you are sir! The formula stops calculating the date after the end of the billing period. So in effect, it's returning an error. Guess I need to add an if(iserror) statement.
 
Upvote 0

Forum statistics

Threads
1,214,940
Messages
6,122,352
Members
449,080
Latest member
Armadillos

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