Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Counting Dates in a Range

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Counting Dates in a Range.

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 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:

  1. Place a blank row at the top of your data, which pushes everything down by one cell.
  2. With your dates now in cells B2:B102, select cell B1 and place a label, such as MyDates, in the cell.
  3. Format cell B1 as desired.
  4. Select the entire range, including the label (cells B1:B102).
  5. Using the Name Box (just above the row headers and to the left of the column headers) define a name for the range. The name should be the same as the name you used in step 2 (MyDates).
  6. In cells D1 and E1, place your label name (MyDates).
  7. In cell D2 enter a greater-than sign and the lower date for your range of dates, as in ">4/1/2002" (without the quote marks).
  8. In cell E2 enter a less-than sign and the upper date for your range of dates, as in "<6/1/2002" (without the quote marks).
  9. In cell E4, enter the following formula:
     =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 (2818) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Counting Dates in a Range.

Related Tips:

Save Time! ExcelTips has been published weekly since late 1998. Past issues of ExcelTips are available in convenient ExcelTips archives. Have your own enhanced archive of ExcelTips at your fingertips, available to use at any time! Check out ExcelTips Archives today!

 

Comments for this tip:

david    16 Dec 2013, 12:00
I have table with about 2000 rows which contains a cell for date of a job, ther person who completed it, and other information in that row, per job.

I'm trying to build a chart next to it which gives me a count of the number of jobs per month, and a count of the number of jobs for each person per month.

i'm finding a lot of other date criteria formulas for excel, but haven't found this one yet.

Any help?

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 3+4? (To prevent automated submissions and spam.)
 
          Commenting Terms
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2013)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2013)

Our Products

Premium Newsletters

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2014 Sharon Parq Associates, Inc.