Change Link in batch of workbooks

  • Thread starter Thread starter Trish Smith
  • Start date Start date
T

Trish Smith

Hi everyone,

I posted last week and Ron de Bruin pointed me to his website for code that
looped thru files in a folder which was just what I needed.

I've just come back to this bit of work now and realised that the original
code allows you to select the source of the old link and then of the new
link.

I would like to automate this and the old link will be the same for all 40
or so of the wkbks in the folder. The new link will be the active workbook.

ActiveWorkbook.ChangeLink Name:="C:\testing\Source.xls", _
newname:=strnewlink, _
Type:=xlLinkTypeExcelLinks

How do I write it so that newname is the active workbook each time?

Many thanks
 
Hi Roger,

Thanks for the reply.

Does it matter where in the code I place the set statement. Should I put it
in with the change link block or should I put it with all the declarations at
the top?

Thanks again
 
Hi Roger,

I tried putting the set statement directly after the declarationas and got a
compile error - object required

Any idea what I've doen wrong?
 
Hi Trish

Do you want to remove the links so they point to the cells in the same workbook
 
Hi Ron,

Yes. What I've got are about 40 workbooks each with between 7 and 11 sheets.

I have data coming as single sheet workbboks which I collate using some of
your code. Then to save on time I've got a template with macros to add the
analysis sheets to each of the workbooks. The analysis sheets of the
workbooks have lookup formulas relating back to the original template. So
then the idea is that I change the link source from template to each of the
workbooks so it looks up its own data.

Hope that makes sense :-)

Cheers
 
Hi Trish

Untested but this will work i think

mybook.ChangeLink Name:="'C:\testing\Source.xls'", _
newname:=mybook.FullName, _
Type:=xlLinkTypeExcelLinks


Sub Example()
Dim MyPath As String, FilesInPath As String
Dim MyFiles() As String, Fnum As Long
Dim mybook As Workbook
Dim CalcMode As Long
Dim sh As Worksheet
Dim ErrorYes As Boolean

'Fill in the path\folder where the files are
MyPath = "C:\Users\Ron\test"

'Add a slash at the end if the user forget it
If Right(MyPath, 1) <> "\" Then
MyPath = MyPath & "\"
End If

'If there are no Excel files in the folder exit the sub
FilesInPath = Dir(MyPath & "*.xl*")
If FilesInPath = "" Then
MsgBox "No files found"
Exit Sub
End If

'Fill the array(myFiles)with the list of Excel files in the folder
Fnum = 0
Do While FilesInPath <> ""
Fnum = Fnum + 1
ReDim Preserve MyFiles(1 To Fnum)
MyFiles(Fnum) = FilesInPath
FilesInPath = Dir()
Loop

'Change ScreenUpdating, Calculation and EnableEvents
With Application
CalcMode = .Calculation
.Calculation = xlCalculationManual
.ScreenUpdating = False
.EnableEvents = False
End With

'Loop through all files in the array(myFiles)
If Fnum > 0 Then
For Fnum = LBound(MyFiles) To UBound(MyFiles)
Set mybook = Nothing
On Error Resume Next
Set mybook = Workbooks.Open(MyPath & MyFiles(Fnum))
On Error GoTo 0

If Not mybook Is Nothing Then


'Change links in mybook
On Error Resume Next

mybook.ChangeLink Name:="'C:\testing\Source.xls'", _
newname:=mybook.FullName, _
Type:=xlLinkTypeExcelLinks


If Err.Number > 0 Then
ErrorYes = True
Err.Clear
'Close mybook without saving
mybook.Close savechanges:=False
Else
'Save and close mybook
mybook.Close savechanges:=True
End If
On Error GoTo 0
Else
'Not possible to open the workbook
ErrorYes = True
End If

Next Fnum
End If

If ErrorYes = True Then
MsgBox "There are problems in one or more files, possible problem:" _
& vbNewLine & "protected workbook/sheet or a sheet/range that not exist"
End If

'Restore ScreenUpdating, Calculation and EnableEvents
With Application
.ScreenUpdating = True
.EnableEvents = True
.Calculation = CalcMode
End With
End Sub




--

Regards Ron de Bruin
http://www.rondebruin.nl/tips.htm


Trish Smith said:
Hi Ron,

Yes. What I've got are about 40 workbooks each with between 7 and 11 sheets.

I have data coming as single sheet workbboks which I collate using some of
your code. Then to save on time I've got a template with macros to add the
analysis sheets to each of the workbooks. The analysis sheets of the
workbooks have lookup formulas relating back to the original template. So
then the idea is that I change the link source from template to each of the
workbooks so it looks up its own data.

Hope that makes sense :-)

Cheers
 
Hi Ron,

Thank you so much! :-)

I feel VERY ungrateful asking but, once the code has looped through all
files the error message shows up - I can definitely live with this but it
would be good to see how you would amend code to avoid this.

Thank you once again for code here and on your website
 
Hi Trish

Can you tell me what error
Let me know and I will test it for you tomorrow after work.

Bed time for me soon
 
Whoops!

Need to put brain in gear before opening mouth!

One of my files had a misnamed tab so obviously needed error message.

Will take another look - sorry Ron! and thank you again
 
I think you mean the msgbox in my code

If there is for example a workbook in the folder with no links it will set ErrorYes = True
and display the msgbox.
You can delete the msgbox line if you want

Good night
 
Back
Top