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: Checking for Time Input.
Written by Allen Wyatt (last updated April 17, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Excel provides a number of functions that return True or False depending on the content of a cell. For instance, ISBLANK returns True if a cell is empty, ISERR returns True if a cell contains an error value, and ISTEXT returns True if a cell contains text. You may wonder if it is possible to determine if a cell contains a time.
The short answer is no, you cannot—Excel contains no function to indicate if a cell contains a time. The reason is quite simple: Times and dates in Excel are technically nothing but numbers. A date is any number in the range 1 to 2958465, which represent the dates of 1/1/1900 through 12/31/9999. If you add a decimal portion to the number, then that represents a time (0 is midnight, 0.25 is 6:00 am, 0.5 is noon, etc.).
Knowing the range of values that can be used for dates and times, along with the fact that a cell containing a time should be formatted properly to display a time, you can create a formula that will indicate if a cell contains a time:
=IF(AND(CELL("format",B2)>="D6",CELL("format",B2)<="D9"), "Time Format","Not Time Format")
This formula checks the formatting applied to cell B2. If the formatting is one of the commonly used formats for times, then it returns the text "Time Format." If a different formatting is used, then the formula returns "Not Time Format."
A different approach is to check whether the value in cell B2 is a valid time value. You can do that by using a formula such as the following:
=IF(TIMEVALUE(TEXT(B2,"hh:mm:ss"))=B2, "Time Entry", "Not a Time Entry")
The function works fine as long as cell B2 contains only a time. If the cell contains both a date and time, then the function always returns "Not a Time Entry."
To get the best of both worlds—checking formats and the value in the cell—consider making a user-defined function in VBA. The reason is simple: VBA includes the IsDate function which not only looks at the current range of the number, but also checks to see that the cell is formatted as a date. The following macro provides an example as to how you could create such a function:
Function IsTime(rng As Range) As Boolean Dim sValue As String sValue = rng.Cells(1).Text On Error Resume Next IsTime = IsDate(TimeValue(sValue)) On Error GoTo 0 End Function
To use the function, use the following formula in a cell:
=IsTime(B2)
The function reads how the value is displayed (using the text property of the cell object) and then tries to convert it with the TIMEVALUE function. If that is a date (determined by the IsDate function) then the display is a valid time. If it is not a date, VBA generates an error, which the code is programmed to ignore.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9699) 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: Checking for Time Input.
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!
In some industries it is necessary to work with time resolutions of less than a second. If you need to keep track of such ...
Discover MoreWork with times in a worksheet and you will eventually want to start working with elapsed times. Here's an explanation of ...
Discover MoreIf you need to input humongous times into a worksheet, you may run into a problem if you need to enter times greater than ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-10-30 10:33:14
J. Woolley
Also, see https://excelribbon.tips.net/T011817_Conditionally_Formatting_Cells_Containing_Dates.html
2022-10-30 04:47:24
Peter Atherton
Scott H
Your formulas return 'Time Format' even if the cell is blank or contains a number. The Cell(("Format",ref) is the way to go.
G =: is general
D1 = Date & Time
D9 = Time
2022-10-30 00:01:03
Scott H
How about this. It should work in most cases. I have only tested this for time cells. It needs to be tested for date and date time cells
=IF (ISERROR(HOUR(A2)) ,"Not Time Format" ,"Time Format")
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