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 Jobs Completed On a Date.
Written by Allen Wyatt (last updated June 26, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Rob keeps statistics on each job he completes each day. For instance, he tracks the exact number of hours and minutes spent on each job by entering a start time (column B) and finish time (column C) for each job in the format: 05/11/20 11:25 am. In a separate column (column G) he has the date for each day of the month. To the right of each date (in column H) he wants to show how many jobs he completed on each of the calendar dates. Rob wonders what formula he would use to figure out this count.
This task is not as easy as it might seem at first. The reason is because of the way in which the start and end times are being stored. Column B contains both the start date and time in the same column, in the format "05/11/20 11:25 am" and column C contains both the ending date and time in the same format. You might think you can use the COUNTIF function in column G, in this manner:
=COUNTIF(C$2:C$1000,G2)
This won't work, however. The reason is simple—column G (cell G2, in this instance) contains a date, with no time. For instance, it might contain the date 05/11/20. When this is compared to cell C2, which might contain 05/11/20 11:25 am, they are not the same. Remember that Excel is doing the comparison based on the date and time serial number stored in each cell. Given the example values just mentioned, cell G2 would contain a serial number of 39217 and cell C2 would contain a serial number of 39217.47569. Since these two values are not the same, COUNTIF doesn't count them as equal.
Obviously, one solution would be to add another column that contained only the ending dates for each job, without a time. Then you could use the COUNTIF function in your formula since you'd be comparing "apples to apples," so to speak. But there is a solution that doesn't require using an intermediate result in a new column. This approach uses the COUNTIFS function, which applies two criteria to all the cells in a range:
=COUNTIFS(C$2:C$1000,">=" & G2,C$2:C$1000,"<" & (G2+1))
This formula uses two criteria, effectively seeing if whatever is in the cells in column C is greater than or equal to the value in G2 yet less than G2+1. In other words, it counts everything that occurs during the day specified in G2.
Another approach is to make sure that the integer value of whatever is in column C is compared with the dates stored in column G. This can be done by using the SUMPRODUCT function, in this manner:
=SUMPRODUCT((INT(C$2:C$1000)=G2)*1)
The integer of each of the values in the range C2:C1000 is compared to the date in G2, giving an array of True and False values. Multiplying each of these by 1 turns the True and False values into 1 and 0 values, respectively. The formula then sums these products, giving the desired count.
If you prefer, you could also use the following formula, which performs essentially the same task using SUMPRODUCT:
=SUMPRODUCT(--(INT(C$2:C$1000)=G2))
One of the benefits of using either the COUNTIFS function or the SUMPRODUCT function to determine a result is that you don't need to use an array formula. Some people, however, prefer to use array formulas. If you like to use them, then you can use either of the following:
=COUNT(IF(INT(C$2:C$1000)=INT(G2),1,FALSE)) =SUM(IF(ROUNDDOWN(C$2:C$1000,0)=G2,1,0))
Remember that array formulas must be entered into a cell using Ctrl+Shift+Enter.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10422) 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 Jobs Completed On a Date.
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!
If you have a lot of values in a single row, you might want to pull the last non-zero value from that row. There are a ...
Discover MoreExcel includes the powerful INDIRECT function which can be used to assemble references to other cells in your workbook. ...
Discover MoreOperators are used in formulas to instruct Excel what to do to arrive at a result. Not all operators are evaluated in the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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