Find & Replace in named ranges

gazingdown

Board Regular
Joined
May 21, 2003
Messages
109
I need to update all my named ranges. Bascially, every named range that has $AB in it, I want to replace with $IV.

Any way to do this quickly as I don't fancy doing it by hand (lots of workbooks I need to update :( )
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
Something like this? (Adapt as needed.)

<font face=Courier New><SPAN style="color:#00007F">Sub</SPAN> UpdateNamedRangeAddresses()
    <SPAN style="color:#00007F">Dim</SPAN> n <SPAN style="color:#00007F">As</SPAN> Name
    <SPAN style="color:#00007F">For</SPAN> <SPAN style="color:#00007F">Each</SPAN> n <SPAN style="color:#00007F">In</SPAN> ThisWorkbook.Names
        <SPAN style="color:#00007F">If</SPAN> InStr(1, n.RefersTo, "$AB") <SPAN style="color:#00007F">Then</SPAN>
            n.RefersTo = Replace(n.RefersTo, "$AB", "$IV")
        <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN>
    <SPAN style="color:#00007F">Next</SPAN> n
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN>

</FONT>
 
Upvote 0
Greg Truby said:
Something like this? (Adapt as needed.)

<font face=Courier New><SPAN style="color:#00007F">Sub</SPAN> UpdateNamedRangeAddresses()
<SPAN style="color:#00007F">Dim</SPAN> n <SPAN style="color:#00007F">As</SPAN> Name
<SPAN style="color:#00007F">For</SPAN> <SPAN style="color:#00007F">Each</SPAN> n <SPAN style="color:#00007F">In</SPAN> ThisWorkbook.Names
<SPAN style="color:#00007F">If</SPAN> InStr(1, n.RefersTo, "$AB") <SPAN style="color:#00007F">Then</SPAN>
n.RefersTo = Replace(n.RefersTo, "$AB", "$IV")
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN>
<SPAN style="color:#00007F">Next</SPAN> n
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN>

</FONT>

Tried this Greg, but at least in my 97 it doesn't like the REPLACE and coughed up SUB OR FUNCTION NOT DEFINED. Couldn't figure out how to utilize worksheetfuntion.replace in this instance either.
 
Upvote 0
Sorry - didn't know you were on '97. Does this work?

<font face=Courier New>

<SPAN style="color:#00007F">Sub</SPAN> UpdateNamedRangeAddresses97()
    <SPAN style="color:#00007F">Dim</SPAN> n <SPAN style="color:#00007F">As</SPAN> Name
    <SPAN style="color:#00007F">For</SPAN> <SPAN style="color:#00007F">Each</SPAN> n <SPAN style="color:#00007F">In</SPAN> ThisWorkbook.Names
        <SPAN style="color:#00007F">If</SPAN> InStr(1, n.RefersTo, "$AB") <SPAN style="color:#00007F">Then</SPAN>
            n.RefersTo = Application.WorksheetFunction.Substitute(n.RefersTo, "$AB", "$IV")
        <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN>
    <SPAN style="color:#00007F">Next</SPAN> n
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN>

</FONT>
 
Upvote 0
Bob - I hadn't noticed you weren't the OP. But then I'm doped up on cold medicine today - so I'm a bit dafter than usual. Glad it worked.
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,208
Members
448,554
Latest member
Gleisner2

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