Worksheet change time format

K

KiwiGirl

Hi all
I have looked through all the related questions, and found most of my answer
on the cpearson website. You've nearly solved my problem except...
I can't figure out how to change the code to enter seconds every time. I've
changed Case 1 and 2 and they work fine, its the rest that I can't work out
how to change. I've managed to get the seconds in the right place in case 3,
but the minutes go into the hours column. I haven't attempted to change the
other cases as yet.
This is for a winch challenge scoring program which is a time based event.
It would be great if I could also have the .seconds also?

You guys are great
Thanks
KiwiGirl

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
Dim TimeStr As String

On Error GoTo EndMacro
If Application.Intersect(Target,
Range("D3:D41,J3:J41,P3:p41,V3:V41,AB3:AB41,AH3:AH41,AN3:AN41,AT3:AT41,AZ3:AZ41,BF3:BF41,BL3:BL41,BR3:BR41,BX3:BX41,CD3:CD41,CJ3:CJ41,CP3:CP41,DB3:DB41,DH3:DH41,DN3:DN41")) 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
If Target.Value = "dnf" Then
Exit Sub
End If
If Target.Value = "dns" 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:00:0" & .Value
Case 2 ' e.g., 12 = 00:12 AM
TimeStr = "00:00:0" & .Value
Case 3 ' e.g., 735 = 7:35 AM
TimeStr = Left(.Value, 1) & ":0:00" & _
Right(.Value, 2)
Case 4 ' e.g., 1234 = 12:34
TimeStr = Left(.Value, 2) & ":" & _
Mid(.Value, 2, 2) & ":" & Right(.Value, 2)
Case 5 ' e.g., 12345 = 1:23:45 NOT 12:03:45
TimeStr = Left(.Value, 1) & ":" & _
Mid(.Value, 2, 2) & ":" & Right(.Value, 2)
Case 6 ' e.g., 123456 = 12:34:56
TimeStr = Left(.Value, 2) & ":" & _
Mid(.Value, 3, 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
End Sub
 
P

Per Jessen

Hi KiwiGirl

Try this:

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
Dim TimeStr As String

On Error GoTo EndMacro
If Application.Intersect(Target, Range("D3:D41, J3:J41, P3:p41, V3:V41,
AB3:AB41, AH3: AH41 , AN3: AN41 , AT3: AT41 , AZ3: AZ41 , BF3: BF41 , BL3:
BL41 , BR3: BR41 , BX3: BX41 , CD3: CD41 , CJ3: CJ41 , CP3: CP41 , DB3:
DB41 , DH3: DH41 , DN3: DN41 ")) 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
If Target.Value = "dnf" Or Target.Value = "dns" 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:00:0" & .Value
Case 2 ' e.g., 12 = 00:12 AM
TimeStr = "00:00:" & .Value
Case 3 ' e.g., 735 = 7:35 AM
TimeStr = "00:0" & Left(.Value, 1) & ":" _
& Right(.Value, 2)
Case 4 ' e.g., 1234 = 12:34
TimeStr = "00:" & Left(.Value, 2) & ":" & Right(.Value, 2)
Case 5 ' e.g., 12345 = 1:23:45 NOT 12:03:45
TimeStr = Left(.Value, 1) & ":" & _
Mid(.Value, 2, 2) & ":" & Right(.Value, 2)
Case 6 ' e.g., 123456 = 12:34:56
TimeStr = Left(.Value, 2) & ":" & _
Mid(.Value, 3, 2) & ":" & Right(.Value, 2)
Case Else
.Value = ""
GoTo EndMacro
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
End Sub

Regards,
Per
 
K

KiwiGirl

Hi Per
Thanks for answering so quickly.
I copied your code and now when I enter 213 for example, I get 0:00:00 in
the cell.
Is there a special format I need to apply also. Currrently at h:mm:ss
Much appreciated.... :)
KiwiGirl
 
R

Rick Rothstein

If Application.Intersect(Target, Range
"D3:D41,J3:J41,P3:p41,V3:V41,AB3:AB41,AH3:AH41,AN3:AN41,AT3:AT41,AZ3:AZ41,BF3:BF41,BL3:BL41,BR3:BR41,BX3:BX41,CD3:CD41,CJ3:CJ41,CP3:CP41,DB3:DB41,DH3:DH41,DN3:DN41"))

Just thought you might find it interesting to know that instead of typing in
all those range addresses in, you could have done this...

' Declare these variable with the rest of your Dim statements
Dim X As Long
Dim R As Range
'.....
'.....
Set R = Range("D3:D41")
For X = 1 To 19
Set R = Union(R, R.Offset(0, 6))
Next
If Intersect(Target, R) Is Nothing Then Exit Sub
'
' Put the rest of your code here
'

In the above code, R would end up a reference to the range you created by
typing all those addresses in.
 
P

Per Jessen

Hi KiwiGirl

No special format needed.
Check if the cell where the number is entered is intersecting with the
desired range.

Regards,
Per
 
K

KiwiGirl

Per
I had that right, but I had an error in the sub name which I couldn't see
because I had scrolled past it.
All working perfectly now....

Thank you very much... you're a life saver!!!

KiwiGirl
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top