Need Count Based on Date Range

dwgnome

Active Member
Joined
Dec 18, 2005
Messages
441
I need a formula to sum the number of valid data points based on a specified date range.

I was able to compute the total sum for a specified date range within a larger data set and avoid any errors within the data set (range) using the SUM formula as shown:

Code:
=SUM(IF((Daily!$A$733:$A$1097<=D762+7)*(Daily!$A$733:$A$1097>=D762),IF(NOT(ISERROR(Daily!$B$733:$B$1097)),Daily!$B$733:$B$1097,0)))

Now I need to do the same to get the count of the number of data points that made the sum from within a larger data set but just can't seem come up with what I need.

The following formula at E768 works perfectly when I confine the range to just the dates used in the sum formula above. However I need to correlate the number of data points with the date range consistent with the SUM formula above.

Code:
=COUNTIF(B762:B768,">0")

For resons beyond this scope, the #DIV/0! error cannot be avoided within the dataset. So please do not suggest fixing what causes the error in first place.

A sample of the data is shown below:


Daily

<TABLE style="BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 2pt; PADDING-RIGHT: 2pt; FONT-FAMILY: Arial,Arial; FONT-SIZE: 10pt" border=1 cellSpacing=0 cellPadding=0><COLGROUP><COL style="WIDTH: 30px; FONT-WEIGHT: bold"><COL style="WIDTH: 89px"><COL style="WIDTH: 73px"><COL style="WIDTH: 22px"><COL style="WIDTH: 74px"><COL style="WIDTH: 94px"><COL style="WIDTH: 94px"></COLGROUP><TBODY><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt; FONT-WEIGHT: bold"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD><TD>E</TD><TD>F</TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">759</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">1/27/2011</TD><TD style="TEXT-ALIGN: center; FONT-FAMILY: Verdana">1,018.80</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">760</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">1/28/2011</TD><TD style="TEXT-ALIGN: center; FONT-FAMILY: Verdana">1,018.60</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">761</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">1/29/2011</TD><TD style="TEXT-ALIGN: center; FONT-FAMILY: Verdana">1,014.40</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">762</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">1/30/2011</TD><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #ffcc00; FONT-FAMILY: Verdana">1,014.40</TD><TD></TD><TD style="TEXT-ALIGN: right">1/30/2011</TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">763</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">1/31/2011</TD><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #ffcc00; FONT-FAMILY: Verdana">1,014.10</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">764</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">2/1/2011</TD><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #ffcc00; FONT-FAMILY: Verdana">1,016.10</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">765</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">2/2/2011</TD><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #ffcc00; FONT-FAMILY: Verdana">1,019.50</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">766</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">2/3/2011</TD><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #ffcc00; FONT-FAMILY: Verdana">1,019.90</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">767</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">2/4/2011</TD><TD style="BACKGROUND-COLOR: #ffcc00; FONT-FAMILY: Verdana">#DIV/0!</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">768</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">2/5/2011</TD><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #ffcc00; FONT-FAMILY: Verdana">1,020.90</TD><TD></TD><TD style="TEXT-ALIGN: right">6,104.90</TD><TD style="TEXT-ALIGN: center">6</TD><TD style="TEXT-ALIGN: center; COLOR: #800080">1017.483</TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">769</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">2/6/2011</TD><TD style="TEXT-ALIGN: center; FONT-FAMILY: Verdana">1,022.00</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">770</TD><TD style="TEXT-ALIGN: center; FONT-WEIGHT: bold">2/7/2011</TD><TD style="TEXT-ALIGN: center; FONT-FAMILY: Verdana">1,021.00</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR></TBODY></TABLE>
<TABLE style="BORDER-BOTTOM-STYLE: groove; BORDER-BOTTOM-COLOR: #00ff00; BACKGROUND-COLOR: #fffcf9; BORDER-TOP-COLOR: #00ff00; BORDER-LEFT-STYLE: groove; FONT-FAMILY: Arial; BORDER-TOP-STYLE: groove; COLOR: #000000; BORDER-RIGHT-COLOR: #00ff00; BORDER-RIGHT-STYLE: groove; FONT-SIZE: 10pt; BORDER-LEFT-COLOR: #00ff00"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-FAMILY: Arial; FONT-SIZE: 9pt" border=1 cellSpacing=0 cellPadding=2><TBODY><TR style="BACKGROUND-COLOR: #cacaca; FONT-SIZE: 10pt"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>B767</TD><TD>=8/0</TD></TR><TR><TD>D768</TD><TD>{=SUM(IF((Daily!$A$733:$A$1097<=D762+7)*(Daily!$A$733:$A$1097>=D762),IF(NOT(ISERROR(Daily!$B$733:$B$1097)),Daily!$B$733:$B$1097,0)))}</TD></TR><TR><TD>E768</TD><TD>=COUNTIF(B762:B768,">0")</TD></TR><TR><TD>F768</TD><TD>=D768/E768</TD></TR></TBODY></TABLE></TD></TR><TR><TD>Formula Array:
Produce enclosing { } by entering
formula with CTRL+SHIFT+ENTER!

</TD></TR></TBODY></TABLE>

Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4


Can someone please help!
 

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
I need a formula to sum the number of valid data points based on a specified date range.

I was able to compute the total sum for a specified date range within a larger data set and avoid any errors within the data set (range) using the SUM formula as shown:

=SUM(IF((Daily!$A$733:$A$1097<=D762+7)*(Daily!$A$733:$A$1097>=D762),IF(NOT(ISERROR(Daily!$B$733:$B$1097)),Daily!$B$733:$B$1097,0)))

Now I need to do the same to get the count of the number of data points that made the sum from within a larger data set but just can't seem come up with what I need.

The following formula at E768 works perfectly when I confine the range to just the dates used in the sum formula above. However I need to correlate the number of data points with the date range consistent with the SUM formula above.

=COUNTIF(B762:B768,">0")

For resons beyond this scope, the #DIV/0! error cannot be avoided within the dataset. So please do not suggest fixing what causes the error in first place.

A sample of the data is shown below:


Daily

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 89px"><COL style="WIDTH: 73px"><COL style="WIDTH: 22px"><COL style="WIDTH: 74px"><COL style="WIDTH: 94px"><COL style="WIDTH: 94px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD><TD>E</TD><TD>F</TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">759</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">1/27/2011</TD><TD style="FONT-FAMILY: Verdana; TEXT-ALIGN: center">1,018.80</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">760</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">1/28/2011</TD><TD style="FONT-FAMILY: Verdana; TEXT-ALIGN: center">1,018.60</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">761</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">1/29/2011</TD><TD style="FONT-FAMILY: Verdana; TEXT-ALIGN: center">1,014.40</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">762</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">1/30/2011</TD><TD style="FONT-FAMILY: Verdana; BACKGROUND-COLOR: #ffcc00; TEXT-ALIGN: center">1,014.40</TD><TD></TD><TD style="TEXT-ALIGN: right">1/30/2011</TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">763</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">1/31/2011</TD><TD style="FONT-FAMILY: Verdana; BACKGROUND-COLOR: #ffcc00; TEXT-ALIGN: center">1,014.10</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">764</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">2/1/2011</TD><TD style="FONT-FAMILY: Verdana; BACKGROUND-COLOR: #ffcc00; TEXT-ALIGN: center">1,016.10</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">765</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">2/2/2011</TD><TD style="FONT-FAMILY: Verdana; BACKGROUND-COLOR: #ffcc00; TEXT-ALIGN: center">1,019.50</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">766</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">2/3/2011</TD><TD style="FONT-FAMILY: Verdana; BACKGROUND-COLOR: #ffcc00; TEXT-ALIGN: center">1,019.90</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">767</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">2/4/2011</TD><TD style="FONT-FAMILY: Verdana; BACKGROUND-COLOR: #ffcc00">#DIV/0!</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">768</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">2/5/2011</TD><TD style="FONT-FAMILY: Verdana; BACKGROUND-COLOR: #ffcc00; TEXT-ALIGN: center">1,020.90</TD><TD></TD><TD style="TEXT-ALIGN: right">6,104.90</TD><TD style="TEXT-ALIGN: center">6</TD><TD style="COLOR: #800080; TEXT-ALIGN: center">1017.483</TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">769</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">2/6/2011</TD><TD style="FONT-FAMILY: Verdana; TEXT-ALIGN: center">1,022.00</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 20px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">770</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">2/7/2011</TD><TD style="FONT-FAMILY: Verdana; TEXT-ALIGN: center">1,021.00</TD><TD></TD><TD></TD><TD></TD><TD></TD></TR></TBODY></TABLE>
<TABLE style="FONT-SIZE: 10pt; BORDER-LEFT-COLOR: #00ff00; BORDER-BOTTOM-COLOR: #00ff00; COLOR: #000000; BORDER-TOP-STYLE: groove; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-RIGHT-STYLE: groove; BORDER-LEFT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-RIGHT-COLOR: #00ff00; BORDER-BOTTOM-STYLE: groove"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-SIZE: 9pt; FONT-FAMILY: Arial" cellSpacing=0 cellPadding=2 border=1><TBODY><TR style="FONT-SIZE: 10pt; BACKGROUND-COLOR: #cacaca"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>B767</TD><TD>=8/0</TD></TR><TR><TD>D768</TD><TD>{=SUM(IF((Daily!$A$733:$A$1097<=D762+7)*(Daily!$A$733:$A$1097>=D762),IF(NOT(ISERROR(Daily!$B$733:$B$1097)),Daily!$B$733:$B$1097,0)))}</TD></TR><TR><TD>E768</TD><TD>=COUNTIF(B762:B768,">0")</TD></TR><TR><TD>F768</TD><TD>=D768/E768</TD></TR></TBODY></TABLE></TD></TR><TR><TD>Formula Array:
Produce enclosing { } by entering
formula with CTRL+SHIFT+ENTER!



</TD></TR></TBODY></TABLE>

Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4


Can someone please help!
Not sure what you're wanting to count. This will count dates that are within the date range AND there's a numeric value in the corresponding cell in column B.

Maybe this array formula**:

=SUM(IF(Daily!$A$733:$A$1097>=D762,IF(Daily!$A$733:$A$1097<=D762+7,IF(ISNUMBER(Daily!$B$733:$B$1097),1))))

You can write the sum formula** like this:

=SUM(IF(Daily!$A$733:$A$1097>=D762,IF(Daily!$A$733:$A$1097<=D762+7,IF(ISNUMBER(Daily!$B$733:$B$1097),Daily!$B$733:$B$1097))))

** array formulas need to be entered using the key
combination of CTRL,SHIFT,ENTER (not just ENTER).
Hold down both the CTRL key and the SHIFT key
then hit ENTER.
 
Upvote 0
Exactly what I was looking for! :)

Just wondering if there is a way to use the AVERAGE or DAVERAGE functions to combine the two formulas into one cell and still avoid the errors?
 
Upvote 0
Exactly what I was looking for! :)

Just wondering if there is a way to use the AVERAGE or DAVERAGE functions to combine the two formulas into one cell and still avoid the errors?

Control+shift+enter, not just enter:

=AVERAGE(IF(Daily!$A$733:$A$1097>=D762,IF(Daily!$A$733:$A$1097<=D762+7,IF(ISNUMBER(Daily!$B$733:$B$1097),Daily!$B$733:$B$1097))))
 
Upvote 0
That is spot on! Appears to be quite robust averaging formula.

I just realize that I do not want zero values to be averaged. Is there a way to include that as well?

Many thanks.
 
Upvote 0
That is spot on! Appears to be quite robust averaging formula.

I just realize that I do not want zero values to be averaged. Is there a way to include that as well?

Many thanks.

For values > 0...

Control+shift+enter:

=AVERAGE(IF(Daily!$A$733:$A$1097>=D762,IF(Daily!$A$733:$A$1097<=D762+7,IF(ISNUMBER(Daily!$B$733:$B$1097),IF(Daily!$B$733:$B$1097>0,Daily!$B$733:$B$1097)))))
 
Upvote 0
Not sure if I need to start a new thread, but it is related to the original thread and the original post information /setup.

For the cases when there is no data within the corresponding specified date range or if there are no dates in the specified date range the AVERAGE formula displays #DIV/0!. To avoid the display, I could use ISERROR(formula,"",formula) approach, however, I am looking for a way to use a counter of some sort to identify those cases and have either null ("") or "No Data" displayed. I attempted the following before the AVERAGE portion but it does not work.

Code:
IF(COUNT(IF(MONTH('Daily NG Btu'!$A$6:$A$1145)=MONTH(D5),YEAR(A5)))

While this formula addresses the monthly average, the layout is similar to the weekly average from Aladin's and T. Valko's last post. Can somebody come up with a solution for the weekly average formula (see Aladin or T. Valko's formula earlier in this post) using either COUNTIF, FREQUENCY or some other way to check for the presence of data and divert the message to state "No Data" for these two cases?

Your help would be most appreciated. I am using Excel 2003.
 
Upvote 0

Forum statistics

Threads
1,214,983
Messages
6,122,583
Members
449,089
Latest member
Motoracer88

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