Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Discovering Dependent Workbooks.

Discovering Dependent Workbooks

Written by Allen Wyatt (last updated July 1, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


1

Beth wonders if there is a way that she can determine if there are other workbooks dependent on the workbook she has open. She knows how to find the precedent links to her open workbook but not the dependent ones. Beth is in a new job and she doesn't want to risk editing a workbook without knowing what other files she may be impacting.

If you have workbook A and workbook B, and workbook B includes a link to workbook A, then workbook B is dependent on workbook A and workbook A is a precedent to workbook B.

In workbook B you can easily find out the links used in the workbook; you would know that workbook A is a precedent to workbook B. As Beth said, she knows how to find out this information.

In workbook A there is no way to determine that workbook B has a link to workbook A and is therefore dependent on workbook A. Thus, it is possible to make changes to workbook A that can, inadvertently, affect workbook B. For instance, you could change a named range or rename a worksheet or delete information you think is no longer needed. When you next open up workbook B, you would be in for a rude surprise because the information that it depended on in workbook A was no longer available.

Some changes you make in workbook A may not affect workbook B. For instance, you should be able to add worksheets, add named ranges, and possibly insert columns or rows. In all these cases Excel may adjust naturally to the changes without affecting workbook B. Problem is, you won't know if there's been a negative effect until you later open workbook B. And you wouldn't even know to open workbook B unless you knew beforehand that there was a relationship between the two workbooks.

One way around the problem is to open all the workbooks you can think of, at the same time, and then use the auditing tools in Excel to check for dependencies. This can work nicely if you have a very limited number of workbooks on your system. It doesn't work that great if you have a lot of workbooks or if the workbooks are on a network.

If you have your workbooks in a set location on your local system (all in a single folder), then you might try using a macro to determine the dependencies. The following steps through all the Excel workbooks in a given directory and identifies workbooks linked to your currently open workbook by formulas.

Sub DiscoverDependentFiles()
    Dim i As Integer
    Dim iFile As String
    Dim fLink As Variant
    Dim sLink As String
    Dim myFldr As String
    Dim curFile As String

    'Change the string here to look
    'for a different link / file name
    sLink = "[FileA.xlsm]"
    curFile = ThisWorkbook.Name
    'Change the string here to look
    'in a different folder
    myFldr = "C:\Users\User\mySub\"

    'Look for both xlsx and xlsm extensions
    iFile = Dir(myFldr & "*.xls?", vbNormal)
    i = 1
    'Loop through all of the files in the folder
    Do While iFile <> ""
        If iFile <> curFile Then
            Workbooks.Open Filename:=myFldr & iFile
            Set fLink = Cells.Find(What:=sLink, _
              After:=ActiveCell, LookIn:=xlFormulas, _
              LookAt:=xlPart, SearchOrder:=xlByRows, _
              SearchDirection:=xlNext, MatchCase:= _
              False, SearchFormat:=False)
            If UCase(TypeName(fLink)) <> UCase("Nothing") Then
                Windows(curFile).Activate
                'Record names of dependent files
                'in your open workbook
                Worksheets(1).Range("D" & (i)).Value = _
                  ActiveWorkbook.Name
                i = i + 1
            End If
            Workbooks(iFile).Close False
        End If
        iFile = Dir
    Loop
End Sub

This approach should work fine in simple situations. In some cases, however, such a macro could provide only a partial solution, because links can be hidden in numerous places—in Excel names, text boxes, charts, and other objects. There is always a chance that something can be left unchecked. The upshot of this is that because your changes could affect other workbooks that are dependent on the one you are changing, you may want to make a backup of the workbook file before making changes.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7799) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Discovering Dependent Workbooks.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Inserting the Author Name

Did you know that Word tries to keep track of who the author of a document is? This information can be easily added to ...

Discover More

Searching a Workbook by Default

When you display the Find tab of the Find and Replace dialog box, you'll notice that any search, by default, will be on ...

Discover More

Finding Related Words

One part of the grammar tools provided with Word is a thesaurus that helps you find all sorts of word variations. One ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Merging Many Workbooks

If you need to combine the contents of a bunch of workbooks into a single workbook, the process can get tedious. Here's a ...

Discover More

Opening Two Workbooks at Once

Do you work with a group of workbooks all the time in Excel? Windows and Excel both provide a plethora of ways you can ...

Discover More

Limiting Where a Workbook is Used

Want to limit who can use your workbook and on what system? Locking down a workbook can be trickier than you might imagine.

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 6 + 5?

2023-07-02 10:32:21

J. Woolley

According to the Tip, "In workbook B you can easily find out the links used in the workbook...." The following dynamic array function in My Excel Toolbox lists external links:
=ListExLinks([SkipReference],[SkipHeader])
Entering that formula in workbook B produces a result that is similar to the Data > Queries & Connections > Edit Links dialog minus its Update column, but ListExLinks optionally adds a Reference column to identify cells that contain a formula referencing the link. If workbook A appears in the list, then B depends on A.
The Tip also says, "In workbook A there is no way to determine that workbook B has a link to workbook A...." Then the Tip provides a macro that uses Find to address this issue. But that macro only searches formulas on the active sheet after each workbook is opened. Since it does not search formulas on all sheets of each workbook, it is accurate only if all workbooks have a single worksheet.
My Excel Toolbox includes the LinksToMe macro to identify all workbooks B with an external data link referencing the active workbook A; therefore, it does not need Find to search all formulas on all sheets of all workbooks.
See https://sites.google.com/view/MyExcelToolbox
And for more on this subject, see https://excelribbon.tips.net/T007639


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.