Correcting time input by users

G

Greg H.

I have a worksheet where employees will be entering in times. I do
caculations based on these times and I would like a way so if the user enters
inthe time like "10:00pm" that excel will correct it to display "10:00 pm".
Is there a way to check for this?
 
S

Sandy Mann

Would something like this do what you want?:

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
If Intersect(Target, Range("F:F")) Is Nothing Then Exit Sub
If Target.Cells.Count > 1 Then Exit Sub

If IsNumeric(Target) Then Exit Sub

If Right(UCase(Target.Value), 2) = "AM" Then _
Target.Value = Left(Target.Value, Len(Target.Value) - 2) & " AM"

If Right(UCase(Target.Value), 2) = "PM" Then _
Target.Value = Left(Target.Value, Len(Target.Value) - 2) & " PM"
End Sub

It also works for just 10pm

--
HTH

Sandy
In Perth, the ancient capital of Scotland
and the crowning place of kings

(e-mail address removed)
Replace @mailinator.com with @tiscali.co.uk
 
S

Sandy Mann

Better make that:

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
If Intersect(Target, Range("F:F")) Is Nothing Then Exit Sub
If Target.Cells.Count > 1 Then Exit Sub

If IsNumeric(Target) Then Exit Sub

On Error GoTo GetOut

Application.EnableEvents = False

If Right(UCase(Target.Value), 2) = "AM" Then _
Target.Value = Left(Target.Value, Len(Target.Value) - 2) & " AM"

If Right(UCase(Target.Value), 2) = "PM" Then _
Target.Value = Left(Target.Value, Len(Target.Value) - 2) & " PM"
GetOut:
Application.EnableEvents = True
End Sub

--
HTH

Sandy
In Perth, the ancient capital of Scotland
and the crowning place of kings

(e-mail address removed)
Replace @mailinator.com with @tiscali.co.uk
 
G

Greg H.

That is perfect. Thanks so much

Sandy Mann said:
Better make that:

Private Sub Worksheet_Change(ByVal Target As Excel.Range)
If Intersect(Target, Range("F:F")) Is Nothing Then Exit Sub
If Target.Cells.Count > 1 Then Exit Sub

If IsNumeric(Target) Then Exit Sub

On Error GoTo GetOut

Application.EnableEvents = False

If Right(UCase(Target.Value), 2) = "AM" Then _
Target.Value = Left(Target.Value, Len(Target.Value) - 2) & " AM"

If Right(UCase(Target.Value), 2) = "PM" Then _
Target.Value = Left(Target.Value, Len(Target.Value) - 2) & " PM"
GetOut:
Application.EnableEvents = True
End Sub

--
HTH

Sandy
In Perth, the ancient capital of Scotland
and the crowning place of kings

(e-mail address removed)
Replace @mailinator.com with @tiscali.co.uk
 
S

Sandy Mann

Glad that it worked for you, thanks for the feedback.

--

Sandy
In Perth, the ancient capital of Scotland
and the crowning place of kings

(e-mail address removed)
Replace @mailinator.com with @tiscali.co.uk
 
R

Rick Rothstein \(MVP - VB\)

If Right(UCase(Target.Value), 2) = "AM" Then _
Target.Value = Left(Target.Value, Len(Target.Value) - 2) & "
AM"

If Right(UCase(Target.Value), 2) = "PM" Then _
Target.Value = Left(Target.Value, Len(Target.Value) - 2) & "
PM"

I believe you can replace the above code lines with this single line...

Target.Value = CDate(Target.Value)

and it will successfully handle 10:00p and 10:00a also. Of course, it
returns the seconds as well, but the cell can be Custom Formatted to handle
that; or we could just do it in code...

Target.Value = Replace(CDate(Target.Value), ":00 ", " ")

Rick
 
R

Rick Rothstein \(MVP - VB\)

Also, in thinking about it, instead of this test...
If IsNumeric(Target) Then Exit Sub

maybe this one would be more robust...

If Not IsDate(Target.Value) Then Exit Sub

Rick
 
S

Sandy Mann

Very good Rick. My XL97 doesn't like Replace being used like that but
something to remember when I become posh. <g>

--

Sandy
In Perth, the ancient capital of Scotland
and the crowning place of kings

(e-mail address removed)
Replace @mailinator.com with @tiscali.co.uk
 
S

Sandy Mann

Yes CDate worked fine.

Thanks for the links, I will check them out.

--
HTH

Sandy
In Perth, the ancient capital of Scotland
and the crowning place of kings

(e-mail address removed)
Replace @mailinator.com with @tiscali.co.uk
 

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