Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Changing Huge Numbers of Hyperlinks.
Written by Allen Wyatt (last updated December 26, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003
Wendy has a single Excel worksheet that contains over 1,200 hyperlinks to TIFF files. (These are hyperlinks, not regular links.) Excel hiccupped and had to shut down, so Emily used the AutoSaved files to recover the previously saved file. Now all the previously working hyperlinks don't work. She had the hyperlinks to the images on a shared network drive, but the AutoSave changed the hyperlinks to reference the C: drive. She wonders if there is an easy way to fix them back to the shared network drive.
At first blush it might seem that you could use Excel's regular Find and Replace feature to find the hard drive designation (as in file://c:) and replace it with a network drive (as in file://shareddrive). The problem is that this approach only addresses part of the problem—it only changes the displayed portion of the hyperlink, not the underlying hyperlink itself. The only way you can get to the hyperlink itself is through the use of a macro.
Assuming that all the hyperlinks that need changing are on the same worksheet, then you can use the following macro:
Sub FixHyperlinks1() Dim wks As Worksheet Dim hl As Hyperlink Dim sOld As String Dim sNew As String Set wks = ActiveSheet sOld = "c:\" sNew = "S:\Network\" For Each hl In wks.Hyperlinks hl.Address = Replace(hl.Address, sOld, sNew) Next hl End Sub
All you need to do is change the values assigned to the sOld and sNew variables. If you get an error when you try to run the macro—an error with the line containing the Replace function—it is because the Replace function isn't available in all versions of Excel. In that case you should use the following macro, instead:
Sub FixHyperlinks2() Dim wks As Worksheet Dim hl As Hyperlink Dim sOld As String Dim sNew As String Set wks = ActiveSheet sOld = "c:\" sNew = "S:\Network\" For Each hl In wks.Hyperlinks hl.Address = Application.WorksheetFunction. _ Substitute(hl.Address, sOld, sNew) Next hl End Sub
Note that the only difference is the use of the Substitute worksheet function.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8622) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Changing Huge Numbers of Hyperlinks.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
Make a hyperlink to a cell in your workbook, edit the structure of that workbook a bit, and you may find that the ...
Discover MoreHyperlinks in a worksheet can be helpful or essential, depending on the nature of your data. If you create a link to a ...
Discover MoreCreating a drop-down list with Excel's data validation feature can be a nice touch for a worksheet. What if you want the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments