Count instances of a rows that falls between 2 dates

Robb

Board Regular
Joined
Feb 17, 2002
Messages
145
My formula does not work correctly because it doesn't count all instances from Sheet A and I'm not sure why.

Sheet B contains my Date Criteria & formula to count the instances:
A16 = 25 May 2015
B16 = 29 May 2015

=COUNTIFS(Sheet A!$J$5:$J$5000,">="&A$16,Sheet A!$J$5:$J$5000,"<="&B$16,Sheet A!$D$5:$D$5000,"Bug")

Sheet A contains all the raw data:
D = Types of Issue (Bug, Improvement, Task, etc)
J = Created Date

Why would it count 16 out of 27?
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.

Asala42

Well-known Member
Joined
Feb 26, 2002
Messages
2,318
The formula looks okay on the surface. I'd check the data again. Use a filter on the above example to isolate the 27 you expect. Some possibilities are:

- Some dates are being treated as text. The 16 might equate to those equal to the above 2 dates only for example.
- Some entries might be not actually exact (such as trailing spaces: "Bug " vs "Bug")
 

Robb

Board Regular
Joined
Feb 17, 2002
Messages
145
You are on to something.
- dates are in my raw data sheet are displaying like this 5/29/2015 2:47:00 PM, not sure if that makes a difference. When I formatted the column into a date format it still didn't resolve the problem. However, when I typed the actual date over the raw data date, my 27 count appeared. Must have something to do with the format of the date or is treated like a text....thanks!!
 

Snakehips

Well-known Member
Joined
May 17, 2009
Messages
5,160
Office Version
  1. 2013
Platform
  1. Windows
Robb,

I think you will find that it is the time element of your 'date' that is causing the issue.

Try the following that uses the integer of your date/time values so that the time element is ignored when testing >= & <=

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>C</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: right;;">5</td></tr></tbody></table><p style="width:4.2em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet B</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C16</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">(<font color="Red">SheetA!$D$5:$D$5000="Bug"</font>)*(<font color="Red">INT(<font color="Green">SheetA!$J$5:$J$5000</font>)>=A16</font>)*(<font color="Red">INT(<font color="Green">SheetA!$J$5:$J$5000</font>)<=B16</font>)</font>)</td></tr></tbody></table></td></tr></table><br />

Hope that helps.
 

Robb

Board Regular
Joined
Feb 17, 2002
Messages
145

ADVERTISEMENT

Thanks Snakehips, time element on the date was the problem and your formula returns the correct value. Thanks for everyone's input and help!
 

Robb

Board Regular
Joined
Feb 17, 2002
Messages
145
I can't figure out how to use multiple criteria with SUMPRODUCT formula.

Sheet A contains all the raw data:
D = Issue Type (Bug, Improvement, Task, etc)
E = Issue Status (Open, In Progress, Reopened, Resolved, Closed)
J = Created Date (format = 5/29/2015 2:47:16 PM)

I need to count the following:
Count all Bug issues that are <> CLOSED and date is less than Jun 1st

D = "Bug" Where
E = "Open + In Progress + Reopened + Resolved" AND
J = Less Than 01-Jun-15
 

Snakehips

Well-known Member
Joined
May 17, 2009
Messages
5,160
Office Version
  1. 2013
Platform
  1. Windows
Robb,

For that scenario try......
<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th><th>J</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">Date</td><td style=";">Bug Count</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">01/06/2015</td><td style="text-align: right;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Issue</td><td style=";">Status</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Date</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Bug</td><td style=";">Open</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">25/05/2015</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Task</td><td style=";">Resolved</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">26/05/2015</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Task</td><td style=";">Open</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">03/01/2015</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Improvement</td><td style=";">Open</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">04/01/2015</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Bug</td><td style=";">Open</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">26/05/2015</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Bug</td><td style=";">Closed</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">26/05/2015</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Task</td><td style=";">Open</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">07/01/2015</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Bug</td><td style=";">Open</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">01/06/2015</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">SheetA</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">B2</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">(<font color="Red">SheetA!$D$5:$D$5000="Bug"</font>)*(<font color="Red">INT(<font color="Green">SheetA!$J$5:$J$5000</font>)<A2</font>)*(<font color="Red">SheetA!$E$5:$E$5000<>"Closed"</font>)</font>)</td></tr></tbody></table></td></tr></table><br />

In basic terms, each bracketed element, separated by '*', of the SUMPRODUCT expression returns an array of values.
The '*' both acts as a logical AND and converts TRUE's and FALSE's within the arrays to 1's and 0's so as to allow a numeric result.
(Using a '+' to separate parameter arrays equates to a logical OR)

Hope that helps.
 

Watch MrExcel Video

Forum statistics

Threads
1,129,685
Messages
5,637,803
Members
416,983
Latest member
LessThanAverageUser

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