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: Entering or Importing Times without Colons.

Entering or Importing Times without Colons

Written by Allen Wyatt (last updated December 7, 2019)
This tip applies to Excel 97, 2000, 2002, and 2003


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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2412) 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: Entering or Importing Times without Colons.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Using a Single Instance of Excel with Two Monitors

Working on a computer system that has multiple monitors can help increase your productivity. If you want to work with ...

Discover More

Unlinking an Excel Chart Automatically

When Excel charts are linked in a Word document, they update every time the document is opened. Here's how to unlink the ...

Discover More

Rounding to Two Significant Digits

Excel provides a variety of functions you can use to round values in any number of ways. It does not, however, provide a ...

Discover More

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!

More ExcelTips (menu)

Displaying a Result as Minutes and Seconds

When you use a formula to come up with a result that you want displayed as a time, it can be tricky figuring out how to ...

Discover More

Combining and Formatting Times

Excel allows you to store times in your worksheets. If you have your times stored in one column and an AM/PM indicator in ...

Discover More

Dealing with Large Numbers of Seconds

When adding values to a time to calculate a new time, you may naturally choose to use the TIME function. This can cause ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 2 + 2?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.