Written by Allen Wyatt (last updated August 23, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Ken would like to display the contents of a cell based on the time of day. For instance, if cell C1 contains the NOW function (for the time of day), in another cell he would like a formula that checks that time. If it is before 5:00 pm, then the formula displays the contents of cell E1. If the time is after 5:00 pm, then the formula displays the contents of cell F1. Ken is not sure how to work out the IF statement so that it checks the time properly.
The key to accomplishing this task is remembering how Excel stores times and dates internally. When you use the NOW function, it returns a serial number that represents the current date and time. Everything in that serial number to the left of the decimal point is the date, and everything to the right is the time. Get rid of the date portion before doing your comparison, and you are then comparing apples to apples (so to speak).
One way to get rid of the date portion of the serial number is in this manner:
=IF(C1-INT(C1)<TIME(17,0,0),E1,F1)
The TIME function returns only the time portion of a date/time serial number for whatever hours, minutes, and seconds you specify in the parameters. Since you want 5:00 pm, then only the hours portion needs to be set to 17.
Another way to strip out the date portion of the serial number is to use the MOD function, in this manner:
=IF(MOD(C1,1)<TIME(17,0,0),E1,F1)
The function returns the remainder after dividing the value in C1 by 1. The remainder, in this case, is everything to the right of the decimal point—the time.
Perhaps the easiest way to do the comparison, however, is to skip any math on the value in C1 altogether. Instead, utilize the HOUR function, in this manner:
=IF(HOUR(C1)<17,E1,F1)
The HOUR function examines the date/time serial number in cell C1 and returns a value of 0 through 23, depending on the hour of the day represented by that serial number. Compare this to 17 (the value of the 5:00 pm hour) and your formula can display the desired value based on the time of day.
It is important to remember that the NOW function (on which your formula hinges) is updated only when the worksheet is updated. This means that if your worksheet is updated at 4:55 pm and then not updated again until 5:10 pm, then during that 15 minutes the formula will return the "before 5:00 pm" value because it doesn't yet know it is after 5:00 pm until the recalculation.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12889) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
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!
Excel worksheets can be used to keep track of all sorts of information. You may want to use it, for instance, to track ...
Discover MoreNeed to know if a cell contains a time value? Excel doesn't contain an intrinsic worksheet function to answer the ...
Discover MoreIt is no secret that you can store time values in an Excel worksheet. But do you really know how small of a time value ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-08-24 14:11:58
J. Woolley
@Rusty
As you probably know, pressing Ctrl+Shift+: (Ctrl+Shift+Colon) enters the current time into the cell as a constant with Custom format "hh:mm am/pm" (region dependent).
The following 3 formulas give the current time as a decimal number with General format:
=NOW()-TODAY()
=NOW()-TRUNC((NOW()))
=NOW()-INT((NOW()))
With Excel 2021+, the last function can be simplified:
=LET(X,NOW(),X-INT(X))
The following formula gives the current time with (not very useful) Custom format "mm/dd/yy hh:mm" (region dependent):
=MOD(NOW(),1)
All 5 formulas are volatile. In each case the formula's cell can be formatted as Time (Ctrl+Shift+@), or press Ctrl+1 to open the Format Cells dialog.
My Excel Toolbox includes the following volatile function to return the current time:
=TimeNow([NumberFormat],[AutoUpdate])
NumberFormat is an optional Custom format for the formula's cell as text like "hh:mm:ss" or "hh:mm am/pm" or specify "ShortTime" or "LongTime" (case ignored) for regional settings; if omitted, existing cell format will not be altered.
If optional AutoUpdate is TRUE, the worksheet will recalculate every 10 seconds (use with caution); default is FALSE.
See https://sites.google.com/view/MyExcelToolbox
2023-08-23 09:35:25
Rusty
If one wishes to remove the digits to the left of the decimal to remove the "date" portion of the =NOW() function, or any other date/time value, I find the easiest way is to use the "TRUNC" function. Assuming the original date/time value is in cell A1, the following formula will result in the time only: "=+A1-TRUNC(A1)". The TRUNC function removes all digits to the right of the decimal leaving the integer which, when subtracted from the original value, leaves only the digits to the right of the decimal, in this case, the time.
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 © 2023 Sharon Parq Associates, Inc.
Comments