Time Colon VBA

Brian from Maui

MrExcel MVP
Joined
Feb 16, 2002
Messages
8,459
Trying to revise a code to automatically add a colon and decimal point.

Cell is Custom Formatted as [mm]:ss.00

Want to just enter six digits and the colon and decimal point would be added with the code.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("timeCells")) Is Nothing Then Exit Sub
    If Target.Count > 1 Then Exit Sub
    Application.EnableEvents = False
    With Target
    If Len(Target) = 6 Then .Value = Left(.Value, 2) & ":" & Mid(.Value, 2) & "." & Right(.Value, 2)
    Application.EnableEvents = True
    End With
End Sub

Obviuosly not not working. Can someone correct this? TIA
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
Don't use mid because it will display the third, fourth, fifth, and sixth character before the period.
Use left(mid(.value,2),2)&"."
 
Upvote 0
For some reason when I enter 182200, it changes to 19:22.00

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("timeCells")) Is Nothing Then Exit Sub
    If Target.Count > 1 Then Exit Sub
    Application.EnableEvents = False
    With Target
    If Len(Target) = 6 Then .Value = Left(.Value, 2) & ":" & Left(Mid(.Value, 2), 2) & "." & Right(.Value, 2)
    Application.EnableEvents = True
    End With
End Sub
 
Upvote 0
Maybe ...

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim rInt        As Range
    Dim cell        As Range

    Set rInt = Intersect(Target, Me.Range("timeCells"))
    If Not rInt Is Nothing Then
        On Error GoTo Oops
        Application.EnableEvents = False
        
        For Each cell In rInt
            cell.Value = Evaluate("--""0:" & WorksheetFunction.Text(cell.Value, "0\:00\.0") & """")
        Next cell

Oops:
        Application.EnableEvents = True
    End If
End Sub

E.g.,

A​
B​
2​
98:06.7​
98067​
3​
66:01.5​
66015​
4​
20:56.8​
20568​
5​
21:32.3​
20923​
6​
36:16.1​
36161​

I copied values from col B to col A.
 
Upvote 0
Trying to revise a code to automatically add a colon and decimal point.
Cell is Custom Formatted as [mm]:ss.00
Want to just enter six digits and the colon and decimal point would be added with the code.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim t As Range
    If Intersect(Target, Range("timeCells")) Is Nothing Then Exit Sub
    Application.EnableEvents = False
    For Each t In Target
        t.Value = Format(t.Value, "0\:00\.00")
    Next
    Application.EnableEvents = True
End Sub

The For Each In Target is use when modifying more than one cell at the same time; for example, paste-special-value.

Note: It probably would be prudent to bulletproof the code with some diligent checks (e.g. IsNumeric) and/or On Error handling.
 
Upvote 0
Maybe ...

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim rInt        As Range
    Dim cell        As Range

    Set rInt = Intersect(Target, Me.Range("timeCells"))
    If Not rInt Is Nothing Then
        On Error GoTo Oops
        Application.EnableEvents = False
        
        For Each cell In rInt
            cell.Value = Evaluate("--""0:" & WorksheetFunction.Text(cell.Value, "0\:00\.0") & """")
        Next cell

Oops:
        Application.EnableEvents = True
    End If
End Sub

E.g.,


A​

B​

2​

98:06.7​

98067​

3​

66:01.5​

66015​

4​

20:56.8​

20568​

5​

21:32.3​

20923​

6​

36:16.1​

36161​

<TBODY>
</TBODY>


I copied values from col B to col A.

When I enter 182200, I get 26236800:00.00.

Seems to be using the 182200 as days.........
 
Upvote 0
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim t As Range
    If Intersect(Target, Range("timeCells")) Is Nothing Then Exit Sub
    Application.EnableEvents = False
    For Each t In Target
        t.Value = Format(t.Value, "0\:00\.00")
    Next
    Application.EnableEvents = True
End Sub

The For Each In Target is use when modifying more than one cell at the same time; for example, paste-special-value.

Note: It probably would be prudent to bulletproof the code with some diligent checks (e.g. IsNumeric) and/or On Error handling.


Thanks joeu, but I'm a nob when it comes to VBA. I sort of revised this code I had.
 
Upvote 0
I was Custom Formatting the cells as

"00\:00\.00"

then converting with =TEXT(A1,"00\:00\.00")+0

which works OK, but the person I'm helping just wanted to enter numbers in a cell and not convert.
 
Upvote 0
Code:
When I enter 182200, I get 26236800:00.00
When I enter 182200 and the cell is formatted as [m]:ss.0, I get 182:20.0
 
Upvote 0
Note: It probably would be prudent to bulletproof the code with some diligent checks (e.g. IsNumeric) and/or On Error handling.

Thanks joeu, but I'm a nob when it comes to VBA. I sort of revised this code I had.

If you are asking how to bulletproof the code I suggested, try:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim t As Range
    If Intersect(Target, Range("timeCells")) Is Nothing Then Exit Sub
    Application.EnableEvents = False
    On Error GoTo oops
    For Each t In Target
        t.Value = Format(t.Value, "0\:00\.00")
nexttarget:
    Next
    Application.EnableEvents = True
    Exit Sub
oops:
    Resume nexttarget
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,237
Members
448,555
Latest member
RobertJones1986

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top