Please Note: This article is written for users of the following Microsoft Excel versions: 2007 and 2010. 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: Entering or Importing Times without Colons.
When you enter a time into a cell, Excel keys on the presence of the colon between the hour and minute portions of the time. Because of the position of the colon on the keyboard, however, entering a colon for each time value that you enter can slow you down—particularly if you have quite a few time values to enter.
For this reason, you may wonder if there is a way to skip entering the colon and either have them entered automatically or entered all at once. Entering them automatically takes a bit more doing, requiring the use of a macro, and will be covered shortly. Entering the colons all at once can be done with a formula, as in the following:
=TIMEVALUE(REPLACE(A1,3,0,":"))
This formula assumes that the time value (without a colon) is in cell A1, and that it is comprised of four digits. Thus, if cell A1 contains a value such as 1422, then the formula returns 14:22 as an actual time value. (You may need to format the cell as a time value.)
If your original entry cell might contain a time that uses only three digits, such as 813 instead of 0813, then you need to use a slightly different formula:
=TIME(LEFT(A1,LEN(A1)-2),RIGHT(A1,2),0)
If you prefer for the insertion of the colons to happen automatically, you can use a macro. You can create a macro that will examine a range of cells where you plan on adding dates to the worksheet, and then insert the colon in the entry. This is done by creating a macro that is triggered by the SheetChange event. The following macro is one such:
Private Sub Workbook_SheetChange(ByVal Sh As Object, _ ByVal Target As Excel.Range) Dim TimeStr As String On Error GoTo EndMacro If Application.Intersect(Target, Range("C7:D15")) Is Nothing Then Exit Sub End If If Target.Cells.Count > 1 Then Exit Sub End If If Target.Value = "" Then Exit Sub End If Application.EnableEvents = False With Target If .HasFormula = False Then Select Case Len(.Value) Case 1 ' e.g., 1 = 00:01 AM TimeStr = "00:0" & .Value Case 2 ' e.g., 12 = 00:12 AM TimeStr = "00:" & .Value Case 3 ' e.g., 735 = 7:35 AM TimeStr = Left(.Value, 1) & ":" & _ Right(.Value, 2) Case 4 ' e.g., 1234 = 12:34 TimeStr = Left(.Value, 2) & ":" & _ Right(.Value, 2) Case Else Err.Raise 0 End Select .Value = TimeValue(TimeStr) End If End With Application.EnableEvents = True Exit Sub EndMacro: MsgBox "You did not enter a valid time" Application.EnableEvents = True ActiveCell.Offset(-1, 0).Select End Sub
The first thing the macro does is to check to see if the data that was just entered was in the range C7:D15. If it wasn't, then the macro exits. It also checks to make sure that there is only a single cell selected and that the cell isn't empty. If all these criteria are met,, then the macro checks the length of the value in the cell and pads it out with leading zeroes, as necessary. This macro is based on a macro found at Chip Pearson's site, here:
http://cpearson.com/excel/DateTimeEntry.htm
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12205) applies to Microsoft Excel 2007 and 2010. You can find a version of this tip for the older menu interface of Excel here: Entering or Importing Times without Colons.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
It 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 MoreWhen adding values to a time to calculate a new time, you may naturally choose to use the TIME function. This can cause ...
Discover MoreExcel allows you to store times in your worksheets. If you have your times stored in one column and an AM/PM indicator in ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-07-23 16:18:10
Shannon
What about the PM column? Where do we enter the code. It doesn't work when I enter this into just a module. So I entered it into ThisWorkbook and that worked, but only for the am column. Any help would be appreciated. Thanks, Shannon
2015-10-31 13:57:57
Furthering on Roy Proctor's Idea. I added an autocoorect entry for the symbol (backslash, if I recall correctly. So I enter times a lot, and the shifted colon is a pain, so I enter 1030 and autocorrect changes it to 10:30. Ta-da. No macros!
I chose the backslash because I cannot ever remember using it in Excel, although I can see it biting me if I type a path in Word or Outlook, like M:My DocsFilename.txt
2015-05-11 08:26:12
Nadine Claesssens
I had the same problem too and found another solution: in one column (A) I enter the time, either minutes eg 15 or hours and minutes eg 345, no need to enter 4 digits if you only have say 40 minutes of 2h50min, you just enter 1,2,3 or 4 numbers. In an additional column I entered the formula which I believe works fine: =(round(((A1/100)-0,5),0)+((mod(A1,100)/60)))/24
2015-04-23 11:54:50
gerdami
@Bill Multack & @Roy Procktor
Awesome! Thanks.
2015-04-21 13:16:14
Roland
What about if you want to display a time value with six digits (as in hh:mm:ss or 02:30:59)? Can someone please show how that would be done?
2015-04-21 09:59:37
Bill Multack
Just saw Roy Procktor's comment. Ingenious! It interfers with "..." because it will change the first two periods to a colon before the third period. I added another auto-correct that changes ":." to "...". Problem solved!
2015-04-21 07:43:11
Michael (Micky) Avidan
If you intend to displaying the time (without Calculation) then, to my opinion, the easiest way is to customize format the intended range as: ##:##
Typing 1436 will end with: 14:36
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
2014-01-11 05:02:12
Roy Prockter
For manual time entries, I have achieved the desired result by setting an auto-correct entry that changes 2 consecutive decimal points (periods in US usage I think) as a colon, so when I enter, say, 17..55 the auto-correct changes it to 17:55 and Excel accepts it as a time value - the point/period is on the numeric keypad so easy to reach during numeric entry. ( it is on British keyboards anyway!)
Only drawback is that auto-correct changes any entry of 2 points/periods to a colon, but that hardly ever occurs.
2012-10-15 08:41:22
Peter Moran
Hi Allen,
Some actual experience has taught me that this macro, like Chip Pearson's original, has one key deficiency - it rejects the entry of a valid time with colons, which should also be accepted!
However the addition of the following code immediately before:
"Application.EnableEvents = False"
will allow a time with colons to be accepted.
If IsDate(Target.Value) = True Then
' e.g., Colon(s) entered, a formatted time, so no action required
Exit Sub
End If
Experience is a good teacher!
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