• Break All Links In An Excel Workbook

    Macro Purpose:
    This code quickly replaces all external links in an Excel workbook with their values. It is something that can be very handy when you need to send a heavily linked workbook outside of your immediate network, to a user who doesn't have access to the directory containing the linked files, of if you want to solidify values so that they don't change next time you open the file.

    Note: If you also want to change the colour of the background cell (so that you can see where the link was,) as well as places the original link path in a comment, please see this article.

    Where to place the code:
    This code goes in a standard module.

    Code required:
    Sub BreakLinks()
    'Author       : Ken Puls (www.excelguru.ca)
    'Macro Purpose: Break all links in the active workbook
        Dim vLinks As Variant
        Dim lLink As Long
        ' Define variable as an Excel link type.
        vLinks = ActiveWorkbook.LinkSources(Type:=xlLinkTypeExcelLinks)
        If vLinks = vbNullString Then Exit Sub
        ' Break all links in the active workbook.
        For lLink = LBound(vLinks) To UBound(vLinks)
            ActiveWorkbook.BreakLink _
                    Name:=vLinks(lLink), _
        Next lLink
    End Sub


    I'm afraid that you must be logged in to comment or leave a testimonial. I wish it could be otherwise, but I'm trying to keep my site spam free for everyone's benefit. If you don't yet have an account it's completely free to sign up, and a very quick process. Simply click here to Register. Not only can you post a comment here, but it gives you full access to posts questions in our forum as well!


    If you already have an account, and just haven't logged in yet, what are you waiting for? Login Now!

    Comments 7 Comments
    1. jonrichco's Avatar
      jonrichco -
      Thanks Ken - great concept
      When I added the module, it stopped at the "If vLinks =" row. When I deleted the row, the macro ran well (in Excel 2010 on an 8/64 notebook).

      Much needed! I hope MS has included it in Excel 2013, but I very much doubt it! Thanks again!
    1. Ken Puls's Avatar
      Ken Puls -
      Hi Jon,

      That's interesting. I just tried this in Excel 2010 and Excel 2013 and it worked with a straight copy and run. Not sure why it would be failing on that line for you... you are calling it from Excel I assume. Do you have any references listed as Missing in Tools-->References in the VBE?
    1. jonrichco's Avatar
      jonrichco -
      G'day Ken - only top 4 references in VBE are ticked - VB for applications, MS14 object library, OLE automation and Office 14 object library. Are any others needed? Jon
    1. Ken Puls's Avatar
      Ken Puls -
      No, shouldn't be. I was more concerned that there might be one actually listed as "Missing" in that list. I'm not sure what to suggest, as it seems to work as advertised here. Do you have any add-ins or COM add-ins installed? I wonder if one of them may be interfering...
    1. jonrichco's Avatar
      jonrichco -
      No Add-ins visible. I did disable Zeon as it was interfering with PaperPort I think. Because I upgraded to Win8, maybe something carried over from prior installation of Office. I do also have several Office 2003 programs installed (Access, Visio, Project) and also Photodraw 2000. Anyway, it's not a big problem, as it works fine with the row deleted. Presumably the row is only needed if you try to run the macro on a file with no external links, when it would continue. Even this I doubt would cause problems.
    1. Ken Puls's Avatar
      Ken Puls -
      It's very odd. I haven't tested anything on Win8 yet though. I guess that, as long as it's working it's all good, but it's still weird.
    1. jonrichco's Avatar
      jonrichco -
      Let me know how you go on Win8 - surprised if that makes any difference. BTW I have now got Win8 working better than 7 (after 2 weeks), using the Win8 desktop for >99% of my work.