Change Cell Reference of Named Range with VBA

MacroMan007

New Member
Joined
Aug 5, 2005
Messages
35
Hello and thanks in advance for any help you can give me.

What I am trying to do, is to simply change the cell reference of a named range from 1 column to the immediate column to the right, but with VBA. I have Googled this, but keep on finding ways to make a dynamic named range and I don't believe that's exactly what I'm looking for here.
So, if the Named Range COpC is in cell Y2 (R2C25), I want to change it to Z2 (R2C26), without me having to manually change the code in the VBA editor. So, the next time the code is run, the named range will refer to Z2 and I will want it to change to AA2 and so on...
Is deleting the named range and recreating it one column to its right best, or is there a way to change the reference dynamically with VB.

Here's the code I have so far that I have to manually change after running it each time.

Sub ChangeRef()
Application.Goto Reference:="COpC"
'Current Location of COpC = Y2 or R2C25
ActiveWorkbook.Names("COpC").Delete
ActiveCell.Offset(0, 1).Range("A1").Select
'New location will always be 1 column to the right.
ActiveWorkbook.Names.Add Name:="COpC", RefersToR1C1:= _
"='OpsPart'!R2C26"
End Sub

Anyway, thanks for your help.

Jay
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Is this what you need?
Code:
Sub ChangeRef()
    With ActiveWorkbook.Names("COpC")
        .RefersToR1C1 = "=OpsPart!" & .RefersToRange.Offset(, 1).Address(1, 1, xlR1C1)
    End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,827
Messages
6,181,198
Members
453,022
Latest member
RobertV1609

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