Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, 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 Times within a Range.

Counting Times within a Range

Written by Allen Wyatt (last updated July 29, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


William has a list of times in column A. He needs a way to find how many of the times fall within a time range, such as between 8:30 am and 9:00 am. He tried using COUNTIF and a few other functions, but couldn't get the formulas to work right.

There are actually a few different ways you can count the times within the desired range, including using the COUNTIF function. In fact, here are two different ways you could construct the formula using COUNTIF:

=COUNTIF(A1:A100,">="&TIME(8,30,0))-COUNTIF(A1:A100,">"&TIME(9,0,0))
=COUNTIF(A1:A100,">=08:30")-COUNTIF(A1:A100,">09:00")

Either one will work fine; they only differ in how the starting and ending times for the range are specified. The key to the formulas is to grab a count of the times that are greater than the earliest boundary of the range and then subtract from that the times that are greater than the upper boundary.

You can shorten the formula by using the COUNTIFS function instead:

=COUNTIFS(A1:A100,">=8:30",A1:A100,"<=9:00")

You could also use the SUMPRODUCT function to get the desired result, in this manner:

=SUMPRODUCT((A1:A100>=8.5/24) * (A1:A100<=9/24))

This approach only works if the values in the range A1:A100 contain only time values. If there are dates stored in the cells as well, then it may not work because of the way that Excel stores dates internally. If the range does include dates, then you need to modify the formula to take that into account:

=SUMPRODUCT((ROUND(MOD(A1:A100,1),10)>=8.5/24) * (ROUND(MOD(A1:A100,1),10)<=9/24))

Finally, you could skip formulas altogether and use Excel's filtering capabilities. Apply a custom filter and you can specify that you only want times within the range you need. These are then displayed and you can easily count the results.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12398) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Counting Times within a Range.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Quickly Dumping Array Contents

Variable arrays are used quite often in macros. If you use an array once in your macro and then need to reuse it for ...

Discover More

Converting Numeric Values to Times

If you have a bunch of times entered into cells without the colon between the hours and minutes, chances are good that ...

Discover More

Visually Showing a Protection Status

Need to know if a worksheet or workbook is currently protected? Excel provides some tell-tale signs, but here are some ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Checking for Time Input

Need to know if a cell contains a time value? Excel doesn't contain an intrinsic worksheet function to answer the ...

Discover More

Working with Elapsed Time

Work with times in a worksheet and you will eventually want to start working with elapsed times. Here's an explanation of ...

Discover More

Determining If a Date and Time is within Working Hours

Excel is great at working with times and dates. Sometimes, though, it can be a bit tricky to figure out how to work with ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is three more than 2?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.