VBA to execute macro on multiple ranges

MarkB1

New Member
Joined
Jul 8, 2014
Messages
40
Hello,

I am attempting to execute a macro when any cell within a given two ranges are selected. The private sub works fine when I'm just doing it for A2:A100, but attempting to add range C2:C100 breaks it. How do I properly capture multiple ranges here? Do I use an "Or" statement or some other approach?

Thank you


Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
Const WS_RANGE As String = "A2:A100" Or "C2:C100"   
    On Error GoTo ws_exit
    Application.EnableEvents = False
    If Not Intersect(Target, Me.Range(WS_RANGE)) Is Nothing Then
        With Target
            Call 'My Macro Here
        End With
    End If
ws_exit:
    Application.EnableEvents = True
End Sub
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
try using these 2 lines for your ws_range declaration
Code:
Dim ws_range As Range
Set ws_range = Union(Range("A2:A100"), Range("C2:C100"))

SO full code like this
Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    Dim WS_RANGE As Range
    Set WS_RANGE = Union(Range("A2:A100"), Range("C2:C100"))
    On Error GoTo ws_exit
    Application.EnableEvents = False
    If Not Intersect(Target, Me.Range(WS_RANGE)) Is Nothing Then
        With Target
            Call 'My Macro Here
        End With
    End If
ws_exit:
    Application.EnableEvents = True
End Sub
 
Upvote 0
try using these 2 lines for your ws_range declaration
Code:
Dim ws_range As Range
Set ws_range = Union(Range("A2:A100"), Range("C2:C100"))

SO full code like this
Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    Dim WS_RANGE As Range
    Set WS_RANGE = Union(Range("A2:A100"), Range("C2:C100"))
    On Error GoTo ws_exit
    Application.EnableEvents = False
    If Not Intersect(Target, Me.Range(WS_RANGE)) Is Nothing Then
        With Target
            Call 'My Macro Here
        End With
    End If
ws_exit:
    Application.EnableEvents = True
End Sub

Hello,

Thanks for the help, but when I use this code, the macro is not activating for any cell range (whereas it was activating for the one single range previously). While not efficient I'm sure, I did see that the following worked:

Code:
Const WS_RANGE As String = "A2:A100,C2:C100"

Thanks!
 
Last edited:
Upvote 0
Does this work?

Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    Dim WS_RANGE As Range
    Set WS_RANGE = Union(Range("A2:A100"), Range("C2:C100"))
    On Error GoTo ws_exit
    Application.EnableEvents = False
    If Not Intersect(Target, WS_RANGE) Is Nothing Then
        With Target
            Call 'My Macro Here
        End With
    End If
ws_exit:
    Application.EnableEvents = True
End Sub
 
Upvote 0
Does this work?

Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    Dim WS_RANGE As Range
    Set WS_RANGE = Union(Range("A2:A100"), Range("C2:C100"))
    On Error GoTo ws_exit
    Application.EnableEvents = False
    If Not Intersect(Target, WS_RANGE) Is Nothing Then
        With Target
            Call 'My Macro Here
        End With
    End If
ws_exit:
    Application.EnableEvents = True
End Sub

That's perfect! Thanks for the help!!
 
Upvote 0

Forum statistics

Threads
1,214,659
Messages
6,120,783
Members
448,992
Latest member
prabhuk279

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