Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Counting Dates in a Range.
Written by Allen Wyatt (last updated February 13, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
If you have a range of cells that are filled with random, non-sorted dates, you may want to figure out how many of those dates fall between a start date and an end date. For instance, if B1:B101 contains the random dates, cell E1 contains the start date, and cell E2 contains the end date, you may want to know what type of formula you can use in cell E4 to return the number of dates in B1:B101 that fall between E1 and E2.
There are actually several different ways you can arrive at a solution. The first, of course, would be to use the COUNTIFS function, in this manner:
=COUNTIFS(B1:B101,">="&E1,B1:B101,"<="&E2)
The formula returns a count of dates in the range, just as you want. The problem with COUNTIFS, though, is that it is a relatively new addition to Excel, first becoming available in Excel 2013. If you are using an older version of the program (or if someone else using your workbook is using an older version), then you need a different solution. The balance of the approaches in this tip will work with all versions of Excel, but are particularly appropriate for the older (pre-2013) versions.
The first approach would be to simply add a formula in each cell to the right of the dates in column B, and have that formula return a 1 if the date is between E1 and E2, or a 0 if not. You could then sum the column to get the desired count. You would use the following formula in each cell to the right of the dates:
=IF(AND(B1>=E$1,B1<=E$2),1,0)
This particular formula goes into cell C1, and can then be copied down to cells C2 through C101. Then, in cell E4, all you would need to do is use the following formula:
=SUM(C1:C101)
The drawback to this, of course, is that the additional values in C1:C101 can play havoc with the appearance of a carefully crafted worksheet. Fortunately there are ways to find the proper result without the need to use an intermediate value.
One way is to use an array formula. The following formula, placed in cell E4, will do the trick. All you need to do is remember to enter the formula using Shift+Ctrl+Enter. (This signifies to Excel that you are entering an array formula.)
=COUNT(IF((B1:B101>$E$1)*(B1:B101<$E$2),B1:B101))
If you prefer to not use an array formula, you can use the following standard COUNTIF-based formula in E4:
=-COUNT(B1:B101)+COUNTIF(B1:B101,">"&E1)+COUNTIF(B1:B101,"<"&E2)
When you enter this formula, Excel will assume that you are returning a date value, and will therefore helpfully format the cell as a date. All you need to do to correct this is to use Format | Cell to format the cell using something besides a date format, such as General.
The formula works by counting all dates that are after the early date plus all dates that are before the late date. This essentially counts all dates once and double-counts the desired selection. By subtracting the number of dates in the range (at the beginning of the formula), the formula effectively eliminates all but the desired result.
If you prefer, you can also use the DCOUNT function to return the desired count. This, however, is just a bit more involved. Unlike the earlier solutions, DCOUNT relies on the use of named ranges. Follow these steps:
=DCOUNT(MyDates,1,D1:E2)
The DCOUNT function uses the criteria you specified in D1:E2 to examine the data range defined as MyDates and return the count of cells that meets those criteria.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11839) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Counting Dates in a Range.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
There are calendar days and then there are business days. Excel provides two functions (NETWORKDAYS and NETWORKDAYS.INTL) ...
Discover MoreWant to know which day of the month is the first business day? The easiest way to determine the date is to use the ...
Discover MoreExcel provides quite a bit of flexibility in how you can format dates. Even so, some dates simply cannot be formatted ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-02-15 15:37:31
David Bonin
= SUMPRODUCT(( B1:B101 >= $E$1) * ( B1:B101 <= $E$2 ))
<or>
= SUMPRODUCT( - - ( B1:B101 >= $E$1), - - ( B1:B101 <= $E$2 ))
Either way, this is entered as a normal (non-array) formula.
The first formula creates two internal arrays of TRUE and FALSE values and multiplies each pair of elements together, which is equivalent to a Boolean AND. Boolean math returns a similar internal array 1's and 0's corresponding to whether each date in B1:B101 is between E1 and E2. SUMPRODUCT() sums that all up and gives the count you want.
The second formula is very similar except the two internal arrays of TRUE and FALSE values are converted by the double negation "- -" to 1's and 0's. SUMPRODUCT() then multiplies each pair of elements in the internal arrays and sums that up to give you the count you want.
2021-02-14 18:16:48
Nathan A Buchheit
Tried it for a very long column (2000) but it did not count every one that fit the criteria. Missed 4 out of the 15 that were present. Any idea why?
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments