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: Converting Numeric Values to Times.
Written by Allen Wyatt (last updated January 25, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003
Sam has a lot of worksheets that contain times. The problem is that the times are in the format "1300" instead of the format "13:00." Thus, Excel sees them as regular numeric values instead of recognizing them as times. Sam wants them to be converted to actual time values.
There are several ways you can approach this task. One way is to use the TIME function to convert the value to a time, as shown here:
=TIME(LEFT(A1,2),RIGHT(A1,2),)
This formula assumes that the time in cell A1 will always contain four digits. If it does not (for instance, it might be 427 instead of 0427), then the formula needs to be modified slightly:
=TIME(LEFT(A1,LEN(A1)-2),RIGHT(A1,2),)
The formula basically pulls the leftmost digit (or digits) and uses them for the hours argument of the TIME function, and then uses the two rightmost digits for the minutes argument. TIME returns an actual time value, formatted as such in the cell.
A similar formulaic approach can be taken using the TIMEVALUE function:
=TIMEVALUE(REPLACE(A1,LEN(A1)-1,0,":"))
This formula uses REPLACE to insert a colon in the proper place, and then TIMEVALUE converts the result into a time value. You will need to format the resulting cell so that it displays the time as you want.
Another variation on the formulaic approach is to use the TEXT function, in this manner:
=--TEXT(A1,"00\:00")
This returns an actual time value, which you will then need to format properly to be displayed as a time.
Another approach is to simply do the math on the original time to convert it to a time value used by Excel. This is easy once you realize that time values are nothing more than a factional part of a day. Thus, a time value is a number between 0 and 1, derived by dividing the hours by 24 (the hours in a day) and the minutes by 1440 (the minutes in a day). Here is a formula that does that:
=INT(A1/100)/24+MOD(A1,100)/1440
This determines the hour portion of the original value, which is then divided by 24. The minute portion (the part left over from the original value) is then divided by 1440 and added to the first part. You can then format the result as a time, and it works perfectly.
All of the formulas described so far utilize a new column in order to do the conversions. This is handy, but you may want to actually convert the value in-place, without the need for a formula. This is where a macro can come in handy. The follow macro will convert whatever cells you have selected into time values and format the cells appropriately:
Sub NumberToTime() Dim rCell As Range Dim iHours As Integer Dim iMins As Integer For Each rCell In Selection If IsNumeric(rCell.Value) And Len(rCell.Value) > 0 Then iHours = rCell.Value \ 100 iMins = rCell.Value Mod 100 rCell.Value = (iHours + iMins / 60) / 24 rCell.NumberFormat = "h:mm AM/PM" End If Next End Sub
The macro uses an integer division to determine the number of hours (iHours) and stuffs the remainder into iMins. This is then adjusted into a time value and placed back into the cell, which is then formatted as a time. You can change the cell format, if desired, to any of the other time formats supported by Excel.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2775) 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: Converting Numeric Values to Times.
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!
Excel allows you to easily store dates and times in your worksheets. If you have a range of cells that contain times and ...
Discover MoreEnter a time into a cell and you normally include a colon between the hours and minutes. If you want to skip that pesky ...
Discover MoreWhen entering times in a worksheet, you may have a need to round whatever you enter to the nearest 15-minute increment. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-10-18 10:10:22
Jesse
I have a report that is downloading times in this format
26:22:00, however the data is actually minutes and seconds and not hours and minutes, so it should be 0:26:22.
How do i convert 26:22:00 to 0:26:22 as a time for minutes and seconds?
Thanks for your help.
2021-08-06 01:21:42
Robbie
Thanks Allan Wyatt
2021-03-27 13:28:34
Willy Vanhaelen
@Alan
Indeed you are right. I am using Excel 2019 for a while and I forgot to try in an older version. I must admit that I was a bit surprised that I worked that nice right away. I must be more careful about that in the future.
Willy
2021-03-26 06:12:45
@Jeannie
Hello Jeannie
I am not 100% sure I know what you want.
But this combination of Willy’s and Allen Wyatt’s stuff might give you something near what you want
Sub NumberToTime3()
Selection.Value = Evaluate("=If({1},--TEXT(" & Selection.Address & "*100,""00\:00""))")
Selection.NumberFormat = "hh:mm AM/PM"
End Sub
You can get that to happen automatically when you type stuff in, but that needs a bit more explaining.
Alan Elston
2021-03-26 06:06:08
@Willy
Hi Willy,
For Excel from about 2013*** downwards, I think you need one of the tricks to get an array out, otherwise you will get the same result across the entire range, as that result that you were expecting from the first cell
So we need something like If({1},___YourFormula___)
Example: If I have
800
900
1000
_..and then I apply the following.._
Sub NumberToTime3()
Selection = Evaluate("=If({1},--TEXT(" & Selection.Address & ",""00\:00""))")
Selection.NumberFormat = "hh:mm"
End Sub
_.. then I end up with
08.00
09.00
10.00
( If I miss out the If({1},___YourFormula___) then in Excel 2013 downwards I will get
08.00
08.00
08.00
)
*** I am not 100% sure about 2013, but I checked in 2007 and 2010
I think in the past we have found that the extra coercion to get array results out is required for up to 2013
Alan
2021-03-25 08:40:57
Willy Vanhaelen
If the range contains only dates without column you can use this simple one-line macro:
Sub NumberToTime3()
Selection = Evaluate("--TEXT(" & Selection.Address & ",""00\:00"")")
End Sub
It is based on this tip's formula =--TEXT(A1,"00\:00") but de Evaluate method makes it act like an array formula.
This two line version does the formatting for you:
Sub NumberToTime3()
Selection = Evaluate("--TEXT(" & Selection.Address & ",""00\:00"")")
Selection.NumberFormat = "hh:mm"
End Sub
2021-03-24 12:37:27
Jeannie
I'm working on a timesheet form and want to use whole numbers (for instance start time is 8am where i am entering just 8) and I want it to turn into 8:00 am. Is there a way to use that. When I enter in 8 it enters 12:00 am.
2020-12-07 13:53:59
Aidan
HI Allen,
Im using the formula =TIME(LEFT(G2,LEN(G2)-2),RIGHT(G2,2),) because my number format is 24 hours, some of them come up as 100,200 etc. This is a great formula, and works perfect for all times except for 12 midnight. my data shows this as a 0(2400) and with this formula it doesn't work(#VALUE). Is there an easy way to modify this formula to work with that?
2020-08-10 13:44:02
BRAD
TO MAKE ENTRY QUICKER WE WRITE A TIME AS 35922 (35 SECONDS 922 THOUSANDS). IF I'M TRYING TO ADD TIMES PER LAP AND HAVE 5 LAPS, HOW DO WE CONVERT TO TIME IN A SPREADSHEET TO ADD THESE 5 LAPS?
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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