Consulting

Results 1 to 4 of 4

Thread: Solved: How to run macro for 2 event changes

  1. #1
    VBAX Newbie
    Joined
    Sep 2010
    Posts
    4
    Location

    Solved: How to run macro for 2 event changes

    Hello!

    My question is how to write the VBA code to be able to enter times without colons and dates without slashes all in the same worksheet. I've already got code for both times and dates and each code works well independently. The problem is that I want to be able to run both codes on the same worksheet at the same time. It's my understanding that I can't run 2 worksheet_change event handlers so I assume I must have to combine the codes somehow. I'm not sure how to do that. Below are my VBA Codes. How do I combine them into one code?

    MY TIME CODE
    [VBA]Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    Dim TimeStr As String
    On Error GoTo EndMacro
    If Application.Intersect(Target, Range("I2:J9999")) 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 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[/vba]

    MY DATE CODE
    [vba]Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    Dim DateStr As String
    On Error GoTo EndMacro2
    If Application.Intersect(Target, Range("M2:N9999")) 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(.Formula)
    Case 4 ' e.g., 9298 = 2-Sep-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 1) & "/" & Right(.Formula, 2)
    Case 5 ' e.g., 11298 = 12-Jan-1998 NOT 2-Nov-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 2) & "/" & Right(.Formula, 2)
    Case 6 ' e.g., 090298 = 2-Sep-1998
    DateStr = Left(.Formula, 2) & "/" & _
    Mid(.Formula, 3, 2) & "/" & Right(.Formula, 2)
    Case 7 ' e.g., 1231998 = 23-Jan-1998 NOT 3-Dec-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 2) & "/" & Right(.Formula, 4)
    Case 8 ' e.g., 09021998 = 2-Sep-1998
    DateStr = Left(.Formula, 2) & "/" & _
    Mid(.Formula, 3, 2) & "/" & Right(.Formula, 4)
    Case Else
    Err.Raise 0
    End Select
    .Formula = DateValue(DateStr)
    End If
    End With
    Application.EnableEvents = True
    Exit Sub
    EndMacro2:
    MsgBox "You did not enter a valid date."
    Application.EnableEvents = False
    End Sub[/VBA]


    Thank you for your help!
    Last edited by Bob Phillips; 09-09-2010 at 07:58 AM. Reason: Added VBA tags

  2. #2
    VBAX Tutor lynnnow's Avatar
    Joined
    Jan 2005
    Location
    Mumbai, Maharashtra, India
    Posts
    299
    Location
    Why can't you just format the cell to not insert the colons for time and slashes for the date?

    On the range of cells, format cell as custom "hhmmss" and "mmddyyyy" respectively and you are done with the formatting without colons and slashes.

  3. #3
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    [vba]

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

    On Error GoTo EndMacro

    If Target.Cells.Count > 1 Then Exit Sub
    If Target.Value = "" Then Exit Sub

    Application.EnableEvents = False

    With Target

    If Not Intersect(Target, Range("I2:J9999")) Is Nothing Then

    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 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
    ElseIf Not Intersect(Target, Range("M2:N9999")) Is Nothing Then

    If .HasFormula = False Then

    Select Case Len(.Formula)

    Case 4 ' e.g., 9298 = 2-Sep-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 1) & "/" & Right(.Formula, 2)

    Case 5 ' e.g., 11298 = 12-Jan-1998 NOT 2-Nov-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 2) & "/" & Right(.Formula, 2)

    Case 6 ' e.g., 090298 = 2-Sep-1998
    DateStr = Left(.Formula, 2) & "/" & _
    Mid(.Formula, 3, 2) & "/" & Right(.Formula, 2)

    Case 7 ' e.g., 1231998 = 23-Jan-1998 NOT 3-Dec-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 2) & "/" & Right(.Formula, 4)

    Case 8 ' e.g., 09021998 = 2-Sep-1998
    DateStr = Left(.Formula, 2) & "/" & _
    Mid(.Formula, 3, 2) & "/" & Right(.Formula, 4)

    Case Else
    Err.Raise 0
    End Select

    .Formula = DateValue(DateStr)
    End If
    End If
    End With

    Application.EnableEvents = True
    Exit Sub
    EndMacro:
    MsgBox "You did not enter a valid time"
    Application.EnableEvents = True
    End Sub
    [/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  4. #4
    VBAX Newbie
    Joined
    Sep 2010
    Posts
    4
    Location
    Thank you xld!! This is perfect! I can now enter both the time and dates without colons and slashes, having Excel do it for me.

    I appreciate your help!

    Quote Originally Posted by xld
    [vba]

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

    On Error GoTo EndMacro

    If Target.Cells.Count > 1 Then Exit Sub
    If Target.Value = "" Then Exit Sub

    Application.EnableEvents = False

    With Target

    If Not Intersect(Target, Range("I2:J9999")) Is Nothing Then

    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 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
    ElseIf Not Intersect(Target, Range("M2:N9999")) Is Nothing Then

    If .HasFormula = False Then

    Select Case Len(.Formula)

    Case 4 ' e.g., 9298 = 2-Sep-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 1) & "/" & Right(.Formula, 2)

    Case 5 ' e.g., 11298 = 12-Jan-1998 NOT 2-Nov-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 2) & "/" & Right(.Formula, 2)

    Case 6 ' e.g., 090298 = 2-Sep-1998
    DateStr = Left(.Formula, 2) & "/" & _
    Mid(.Formula, 3, 2) & "/" & Right(.Formula, 2)

    Case 7 ' e.g., 1231998 = 23-Jan-1998 NOT 3-Dec-1998
    DateStr = Left(.Formula, 1) & "/" & _
    Mid(.Formula, 2, 2) & "/" & Right(.Formula, 4)

    Case 8 ' e.g., 09021998 = 2-Sep-1998
    DateStr = Left(.Formula, 2) & "/" & _
    Mid(.Formula, 3, 2) & "/" & Right(.Formula, 4)

    Case Else
    Err.Raise 0
    End Select

    .Formula = DateValue(DateStr)
    End If
    End If
    End With

    Application.EnableEvents = True
    Exit Sub
    EndMacro:
    MsgBox "You did not enter a valid time"
    Application.EnableEvents = True
    End Sub
    [/vba]

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •