XL2000: How to Programmatically Modify Hyperlink Addresses on a Worksheet (247507)



The information in this article applies to:

  • Microsoft Excel 2000

This article was previously published under Q247507

SUMMARY

This article demonstrates how to use Microsoft Visual Basic for Applications (VBA) to update or replace hyperlinks throughout a workbook or on only a single worksheet.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.

Sample Code

By using VBA to update hyperlinks instead of doing so manually, you can help ensure the accuracy and consistency of your links. To do this, follow these steps:
  1. On the Tools menu, point to Macro, and then click Visual Basic Editor.
  2. In the Project window of the Visual Basic Editor, right-click the Excel object that you want to update (this can be a single sheet in your workbook, the entire workbook, or the project), point to Insert, and then click Module.
  3. Type the following code in the module

    NOTE: Set the oldtext variable to match at least some portion of the hyperlink text that you want to update or change. (This is the text from the Text To Display box of the Insert Hyperlink wizard.) Set the newtext variable to the updated hyperlink text.
    Sub HyperLinkChange()
       Dim oldtext As String
       Dim newtext As String
       Dim h As Hyperlink
    
    ' These can be any text portion of a hyperlink, such as ".com" or ".org".
           oldtext = "http://www.microsoft.com/" 
           newtext = "http://www.msn.com/" 
    
    ' Check all hyperlinks on active sheet.
           For Each h In ActiveSheet.Hyperlinks
           x = InStr(1, h.Address, oldtext)
           If x > 0 Then
               If h.TextToDisplay = h.Address Then
                    h.TextToDisplay = newtext
               End If
               h.Address = Application.WorksheetFunction. _
               Substitute(h.Address, oldtext, newtext)
           End If
           Next
    End Sub
    					
  4. Press ALT+F11 to switch to Excel.
  5. On the Tools menu, point to Macro, and then click Macros.
  6. In the Run Macro dialog box, click HyperlinkChange, and then click Run.
  7. Check your hyperlinks to be sure they have been updated.
Depending on where you place your code module, you can either update all the hyperlinks in the workbook or only on a specific sheet. If you notice that some of your links are not updated, check to see whether your module is associated with the entire workbook or only with one sheet.

REFERENCES

For more information about how to use the sample code in this article, click the article number below to view the article in the Microsoft Knowledge Base:

212536 OFF2000: How to Run Sample Code from Knowledge Base Articles


Modification Type:MinorLast Reviewed:10/10/2006
Keywords:kbdtacode kbhowto KB247507