• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Multiple Subs in Worksheet

Richard S

New Member
Hi

I am trying to put two subs onto a worksheet, but the second one does not work as it appears to be being added as a (General) instruction rather than Worksheet?

Apologies if this is really basic but I just can't see where I am going wrong - help appreciated.

The 1st sub is used to convert numeric entry to time, the 2nd is to filter the data based on the value selected from a drop down cell in the same sheet. This calls a macro that I know works.

VBA code is as follows:

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

On Error GoTo EndMacro
If Application.Intersect(Target, Range("I:J")) 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

Private Sub Filter(ByVal Target As Range)
If Target.Address = "$E$6" Then
Call Roster_Filter_On
End If
End Sub
 
There's specific worksheet event which fires code. Which, Filter isn't one of.
By selecting Worksheet, you can see list of available events.

upload_2015-12-1_7-35-56.png
 
There's specific worksheet event which fires code. Which, Filter isn't one of.
By selecting Worksheet, you can see list of available events.

View attachment 24682

Thanks but I am I right in thinking that both of my subs should be set as Worksheet_Change? When I do this I get an ambiguity error.
If I use Worksheet_SelectionChange for the 2nd sub the macro runs before a new value can be selected
 
You must combine the two into one routine. Perhaps this:

Code:
Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    Dim TimeStr               As String
    Dim cell                  As Range
    On Error GoTo EndMacro
    If Not Application.Intersect(Target, Range("I:J")) Is Nothing Then

        Application.EnableEvents = False
        For Each cell In Application.Intersect(Target, Range("I:J")).Cells
            With cell
                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
        Next cell
        Application.EnableEvents = True
       
    ElseIf Target.Address = "$E$6" Then
        Call Roster_Filter_On
    End If
   
    Exit Sub
   
EndMacro:
    MsgBox "You did not enter a valid time"
    Application.EnableEvents = True
End Sub
 
Back
Top