Counting number of values between dates based on True/False criteria

Macorden

New Member
Joined
Jan 14, 2011
Messages
37
Greetings. I have a formula that counts the number of times a serial number shows up on a report, but my formula doesn't count a formula twice if it appears. So I need some help, if anyone would be so kind :)

<table border="0" cellpadding="0" cellspacing="0" width="388"><col style="width: 48pt;" span="2" width="64"> <col style="width: 51pt;" width="68"> <col style="width: 48pt;" span="3" width="64"> <tbody><tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; width: 48pt;" height="20" width="64"> </td> <td class="xl65" style="border-left: medium none; width: 48pt;" width="64">a</td> <td class="xl65" style="border-left: medium none; width: 51pt;" width="68">b</td> <td class="xl65" style="border-left: medium none; width: 48pt;" width="64">c</td> <td class="xl65" style="border-left: medium none; width: 48pt;" width="64">d</td> <td class="xl65" style="border-left: medium none; width: 48pt;" width="64">e</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">1</td> <td class="xl65" style="border-top: medium none; border-left: medium none;">S/N</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center">date</td> <td class="xl65" style="border-top: medium none; border-left: medium none;">CMPLTD</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="right">start:</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">1/1/2011</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">2</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="left">100</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">1/2/2011</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center">TRUE</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="right">end:</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">2/1/2011</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">3</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="left">101</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">1/4/2011</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center">TRUE</td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">4</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="left">102</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">1/6/2011</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center">TRUE</td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">5</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="left">103</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">1/6/2011</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center">TRUE</td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">6</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="left">104</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">1/7/2011</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center">FALSE</td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">7</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="left">105</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">1/8/2011</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center">FALSE</td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">8</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="left">100</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">1/10/2011</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center">TRUE</td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl65" style="height: 15pt; border-top: medium none;" align="left" height="20">9</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="left">106</td> <td class="xl66" style="border-top: medium none; border-left: medium none;" align="right">2/1/2011</td> <td class="xl65" style="border-top: medium none; border-left: medium none;" align="center"> FALSE</td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> <td class="xl65" style="border-top: medium none; border-left: medium none;"> </td> </tr> </tbody></table>
What I'm trying to achieve is to count the number of cells in column A if the date in columb B is within the criteria of E1 and E2, and the CMPLTD column is TRUE.

The current formula I use only counts the unique values:
Code:
=SUM(IF(FREQUENCY(IF(B:B>=E1,IF(B:B<E2,IF(C2=TRUE,IF(A:A<>"",MATCH("~"&A:A,A:A&"",0))))),ROW(A:A)-ROW(A1)+1)>0,1))
CSE
Thanks!
 

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
You don't want a unique count, right?

If so, control+shift+enter...

=SUM(IF($B$2:$B$9>=E1,IF($B$2:$B$9<=E2,IF($C$2:$C$9,ISNUMBER($A$2:$A$9)+0))))
 
Upvote 0
No I dont need a unique count. Is there a way to make it count only the FALSE items?

I thought you wanted the TRUE items...

For FALSE items only...

Control+shift+enter, not just enter:

=SUM(IF($B$2:$B$9>=E1,IF($B$2:$B$9<=E2,IF(1-$C$2:$C$9,ISNUMBER($A$2:$A$9)+0))))
 
Upvote 0

Forum statistics

Threads
1,224,602
Messages
6,179,841
Members
452,948
Latest member
UsmanAli786

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