Copy Worksheet Save & break links

pignchick

New Member
Joined
Sep 24, 2014
Messages
10
I am looking for some vba code that will allow me to break all the links in a worksheet and then save the file in the same folder/file path but add Excel to the end of the file path.

For example; If I have an excel worksheet named test.xlsm with 20 tabs, I want to save a copy of that entire worksheet in the same folder as test.xlsm, but rename the worksheet as test excel.xls, and break the links in all 20 tabs.

The purpose of this exercise is to archive data, in case the links get messed up.

Any ideas?
 
Last edited:

Some videos you may like

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK

timfritsch

Active Member
Joined
Jun 10, 2004
Messages
343
Try:

Code:
Sub BreakLinks()
Dim wb As Workbook

Set wb = Application.ActiveWorkbook

  If Not IsEmpty(wb.LinkSources(xlExcelLinks)) Then
    For Each link In wb.LinkSources(xlExcelLinks)
        wb.BreakLink link, xlLinkTypeExcelLinks
    Next link
  End If
End Sub

Tim
 

pignchick

New Member
Joined
Sep 24, 2014
Messages
10
That code answers part of my question. However, I still need to save this version with links removed as another file in the same folder. What coding should I add to the code already provided?
 

timfritsch

Active Member
Joined
Jun 10, 2004
Messages
343
Try:

Code:
Sub BreakLinksandSave()
Dim wb As Workbook, fName as string

Set wb = Application.ActiveWorkbook

  If Not IsEmpty(wb.LinkSources(xlExcelLinks)) Then
    For Each link In wb.LinkSources(xlExcelLinks)
        wb.BreakLink link, xlLinkTypeExcelLinks
    Next link
  End If

  fname = left(activeworkbook.name,len(activeworkbook.Name)-5) & "-EXCEL" & right(activeworkbook.Name,5)

  activeworkbook.saveas fname
End Sub

Tim
 

pignchick

New Member
Joined
Sep 24, 2014
Messages
10
Thanks Tim, that code worked very well. Only 1 thing, how do I choose the file path? Right now it's saving the copy to my documents. I would like to put it on a shared drive, and in the same folder as the source file.
 

timfritsch

Active Member
Joined
Jun 10, 2004
Messages
343
Replace activeworkbook.name with activeworkbook.fullname (all three instances). That will save the file to the same folder as the source.

Tim
 

pignchick

New Member
Joined
Sep 24, 2014
Messages
10
Also, what would be the correct code to keep the original and not the version with the excel ending open after the macro is run? The version without links is mainly for archive purposes.
 

timfritsch

Active Member
Joined
Jun 10, 2004
Messages
343
Here you go:

Code:
Sub BreakLinksandSave()
  Dim link As Variant, wb As Workbook, origFile As String, newFile As String
  
  Set wb = Application.ActiveWorkbook
  
  If Not IsEmpty(wb.LinkSources(xlExcelLinks)) Then
    For Each link In wb.LinkSources(xlExcelLinks)
      wb.BreakLink link, xlLinkTypeExcelLinks
    Next link
  End If
  
  origFile = ActiveWorkbook.FullName
  
  newFile = Left(origFile, Len(origFile) - 5) & "-EXCEL" & Right(origFile, 5)
  
  ActiveWorkbook.SaveAs newFile
  newFile = ActiveWorkbook.Name
  
  Workbooks.Open (origFile)
  Workbooks(newFile).Close False
End Sub

Tim
 

pignchick

New Member
Joined
Sep 24, 2014
Messages
10
Something must be slightly off in the logic. When I run the new code I get the newFile to remain open without the links. I was hoping that the origFile would be open at the end with links still in the file and that the newFile would be closed with links broken.
 

timfritsch

Active Member
Joined
Jun 10, 2004
Messages
343
I've improved the code a little, removing the Update Links? message when opening the original file. In my testing, everything seems to work fine - original file name and path is stored, file is renamed, original file is opened, renamed file is closed.

To test on your end, step through the code with the <F8> key.


Code:
Sub BreakLinksandSave()
  Dim link As Variant, wb As Workbook, origFile As String, newFile As String
  
  Set wb = Application.ActiveWorkbook
  
  If Not IsEmpty(wb.LinkSources(xlExcelLinks)) Then
    For Each link In wb.LinkSources(xlExcelLinks)
      wb.BreakLink link, xlLinkTypeExcelLinks
    Next link
  End If
  
  origFile = wb.FullName
  
  newFile = Left(origFile, Len(origFile) - 5) & "-EXCEL" & Right(origFile, 5)
  
  ActiveWorkbook.SaveAs newFile
  newFile = ActiveWorkbook.Name
  
  Application.DisplayAlerts = False
  Workbooks.Open origFile, UpdateLinks:=True
  Application.DisplayAlerts = True
  
  Workbooks(newFile).Close False
End Sub

Tim
 

Watch MrExcel Video

Forum statistics

Threads
1,099,738
Messages
5,470,451
Members
406,700
Latest member
Mark Rob

This Week's Hot Topics

Top