Using range names with Worksheet_Change

ElvisSteel

Board Regular
Joined
Mar 23, 2009
Messages
122
Hi,

I need to run some code whenever a user changes the value in certain cells.
Currently the code is...
Code:
If Not Intersect(Target, Range("C4")) Is Nothing Then
  Do Something
End If
or sometimes...
Code:
 If ActiveCell.Address = "$C$4" Then
  Do Something
End If
which work fine, but I want to refer to a defined name rather than C4, so that if the address changes due to inserting/deleting rows or columns I don't have to change the code.
Is this possible?
I have tried
Code:
If Not Intersect(Target, Range("RangeName")) Is Nothing Then
  Do Something
End If

Have I missed something obvious?

Thanks
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
Hi

How is the name defined?

Perhaps;

Code:
If Not Intersect(Target, [COLOR=red]Sheets("Sheet1").[/COLOR]Range("RangeName")) Is Nothing Then
 
Upvote 0
Jon,

Thanks for such a prompt response.

The original error I am getting is:
Method 'Range' of object '_worksheet' failed

After making your suggested change to include the sheet name I now get:
Application-defined or object-defined error

The range name in question is scoped to the workbook.

Thanks
 
Upvote 0
There is bound to be an easier way but all I could think of is:

Code:
[COLOR="Blue"]Private[/COLOR] [COLOR="Blue"]Sub[/COLOR] Worksheet_SelectionChange([COLOR="Blue"]ByVal[/COLOR] Target [COLOR="Blue"]As[/COLOR] Range)
    [COLOR="Blue"]Dim[/COLOR] strRngAddress [COLOR="Blue"]As[/COLOR] [COLOR="Blue"]String[/COLOR]
    strRngAddress = ActiveWorkbook.Names("test").RefersTo
    strRngAddress = [COLOR="Blue"]Mid[/COLOR](strRngAddress, 3, [COLOR="Blue"]Len[/COLOR](strRngAddress) - 3)
    
    [COLOR="Blue"]If[/COLOR] [COLOR="Blue"]Not[/COLOR] Application.Intersect(Target, Range(strRngAddress)) [COLOR="Blue"]Is[/COLOR] [COLOR="Blue"]Nothing[/COLOR] [COLOR="Blue"]Then[/COLOR]
        [COLOR="Blue"]MsgBox[/COLOR] "beep"
    [COLOR="Blue"]End[/COLOR] [COLOR="Blue"]If[/COLOR]
[COLOR="Blue"]End[/COLOR] [COLOR="Blue"]Sub[/COLOR]
 
Upvote 0

Forum statistics

Threads
1,214,605
Messages
6,120,476
Members
448,967
Latest member
visheshkotha

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