This post may contain affiliate links. Please read my disclosure for more info.
Advertisement:

Edit links in Word using VBA

Edit links in Word using Excel VBA

Edit link in Word using VBA

Last week we looked at linking Excel directly to Word documents.  This can create significant time saving as the Word document updates automatically whenever the Excel file changes.  The problem comes when we want to change the file path of the linked document, as it is necessary to change the links one by one.  But, we can use VBA to automate this process.

The VBA code below has been included twice, once for using within Excel and once for using within Word.


Advertisement:

Here are a few notes for using the code:

  • The Excel code has been written using Late Binding.  Which means it should run by itself; you do not need to create references to the Word Object library.
  • When changing file paths remember to end the file path with a slash “\”

 

Edit the linked documents using Word VBA

To open the Visual Basic editor in Word press Alt + F11.  Right-click on ThisDocument for your document and select Insert -> Module.


Advertisement:

Word VBA insert Module

Copy the code below into the code window.

Word VBA Editor With Code


Advertisement:

For this code work you just need to update the oldFilePath and newFilePath variables to meet your requirements.

Sub UpdateWordLinks()

Dim newFilePath As String
Dim oldFilePath As String
Dim sourceFileName As String
Dim newFileName As String
Dim wrdDocument As Document
Dim i As Integer

'The old file path as a string (the text to be replaced)
oldFilePath = "String of\File Path\To Be Replaced\Excel File.xlsx"

'The new file path as a string (the text to replace with)
newFilePath = "String of\New File Path\Excel File 2.xlsx"

'Set the variable to the Word Document
Set wrdDocument = ThisDocument

'Use Replace to change the oldFilePath to the newFilePath on the Field code
For i = 1 To wrdDocument.Fields.Count
    wrdDocument.Fields(i).LinkFormat.SourceFullName _
    = Replace(wrdDocument.Fields(i).LinkFormat.SourceFullName, _
    oldFilePath, newFilePath)
Next i

'Update the links
wrdDocument.Fields.Update

End Sub

 

Editing the linked documents from Excel using VBA

You may decide that Excel is a better location to keep the code for editing links.  In Excel, press ALT + F11 to open the Excel Visual Basic Editor.  Click Insert -> Module. Copy the code below into the new Module.

For this code work you just need to update the sourceFileName, oldFilePath and newFilePath variables to meet your requirements.

Sub UpdateWordLinks()

Dim oldFilePath As String
Dim newFilePath As String
Dim sourceFileName As String
Dim newFileName As String
Dim wrdApp As Object
Dim wrdDocument As Object
Dim i As Integer

'The file name and path of the file to update
sourceFileName = "C:\Users\marks\Documents\Test Word Link 1.docx"

'The old file path as a string (the text to be replaced)
oldFilePath = "C:\Users\marks\Documents\Test Word Link.xlsx"

'The new file path as a string (the text to replace with)
newFilePath = "C:\Users\marks\Documents\P1\Test Word Link P1.xlsx"

'Set the variable to the Word Application
Set wrdApp = CreateObject("Word.Application")

'Make the Word application visible
wrdApp.Visible = True

'Set the variable to the Word Document
Set wrdDocument = wrdApp.Documents.Open(sourceFileName)

'Use Replace to change the oldFilePath to the newFilePath on the Field code
For i = 1 To wrdDocument.Fields.Count
    wrdDocument.Fields(i).LinkFormat.SourceFullName _
    = Replace(wrdDocument.Fields(i).LinkFormat.SourceFullName, _
    oldFilePath, newFilePath)
Next i

'Update the links
wrdDocument.Fields.Update

'Save, close and quit the application
wrdDocument.Save
wrdDocument.Close
wrdApp.Quit

'Release the memory
Set wrdApp = Nothing
Set wrdDocument = Nothing

End Sub