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 fractional 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 following 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 (10101) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Converting Numeric Values to Times.
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!
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 MoreYou know what time it is, right? (Quick; look at your watch!) What if you want to know what time it is in Greenwich, ...
Discover MoreDates and times are often standardized on UTC time, which is analogous to GMT times. How to convert such times to your ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-10-27 10:15:43
Michel Saulnier
You are amazing thank you for posting all these tips
2020-10-27 07:23:23
Willy Vanhaelen
With the macro in my previous comment you will have to pre-format your selection or do it after running the macro. This two line version will do it for you. Adjust the format code to your liking.
Sub NumberToTime2()
Selection = Evaluate("INT(" & Selection.Address & "/100)/24+MOD(" & Selection.Address & ",100)/1440")
Selection.NumberFormat = "h:mm AM/PM"
End Sub
2020-10-27 06:35:01
Willy Vanhaelen
For people who are happy with the hh:mm format, this one liner macro will do the job:
Sub NumberToTime()
Selection = Evaluate("INT(" & Selection.Address & "/100)/24+MOD(" & Selection.Address & ",100)/1440")
End Sub
2018-02-22 11:06:21
Peter Atherton
Willy Vanhaelen
Yes thanks Willy, I just never use that format and did not think ahead.
2018-02-22 06:49:50
Willy Vanhaelen
@Peter Atherton
Your formula only works if the civilian time is entered as text like 06:14. It doesn't work if in cell B3 you enter for instance 6:14 or 6:14 AM or 6:14 PM or 06:14 PM. It doesn't work at all with Excel time such as 9:14 which is in fact 0.26.
My formula posted 2017.04.23 work correctly in all circumstances.
2018-02-21 11:36:00
Peter Atherton
Dave Manuel
Another shorter way
=MID(B3,1,2)&MID(B3,4,2)
2018-02-20 03:26:18
Michael (Micky) Avidan
@Scott Johnson,
I had a TIPO.
The REPLACE Formula should refere to cell A7 instead of A4.
(see Figure 1 below)
----------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” Excel MVP – Excel (2009-2018)
ISRAEL
Figure 1.
2018-02-20 03:22:33
Michael (Micky) Avidan
@Scott Johnson,
Try my suggestion in the following picture.
Cell D7 proves that it does not matter if the Time is presented as "Text".
(see Figure 1 below)
----------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” Excel MVP – Excel (2009-2018)
ISRAEL
Figure 1.
2018-02-19 11:29:36
Scott Johnson
i need to convert 144004 to time 14:40:04. What formula would allow me to do this?
2017-04-23 08:01:31
Willy Vanhaelen
@Dave Manuel
This schould do the job:
=TEXT(HOUR(A1),"00")&TEXT(MINUTE(A1),"00")
2017-04-22 06:58:15
Dave Manuel
Slick way to convert military time to civilian time. How about civilian time to military?
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 © 2021 Sharon Parq Associates, Inc.
Comments