Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Accessing Dependent and Precedent Information.
Written by Allen Wyatt (last updated February 28, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
David rightly notes that Excel provides auditing tools (Trace Dependents and Trace Precedents) that are a very helpful way of keeping track of what is happening in large worksheets. However, the actual interface just lists out the cells in a small area, and David cannot easily copy out this list of cells to analyze and manipulate it. When he uses Trace Dependents on an important cell in a large worksheet, the small dialog box can contain several hundred references. David wonders if there is a relatively easy way of getting this information into a more usable format, like a blank worksheet or another workbook.
There is obviously no way to do this with native Excel commands, but you can create a macro that will extract the information you desire. The following macro will list the dependent cells for whatever cell is selected when you run the macro:
Sub ListDependents() Dim rArea As Range Dim rCell As Range Dim rDep As Range Dim lRow As Long Dim sCellAddr As String sCellAddr = ActiveCell.Address(False, False) On Error Resume Next Set rDep = ActiveCell.Dependents If rDep Is Nothing Then MsgBox sCellAddr & " has no dependents" Exit Sub End If On Error GoTo 0 Worksheets.Add lRow = 1 Cells(lRow, 1).Value = "Dependents for " & sCellAddr For Each rArea In rDep For Each rCell In rArea lRow = lRow + 1 Cells(lRow, 1) = rCell.Address(False, False) Next Next Set rArea = Nothing Set rCell = Nothing Set rDep = Nothing End Sub
When the macro is first run, it checks to see if there are any dependents for the cell. If there aren't, then you are notified, and the macro is exited. If there are dependents, then a new worksheet is added to the workbook and the dependents of the cell are added to the worksheet.
If you want the macro to instead list precedents, all you need to do is change the all instances of "Dependents" in the macro to "Precedents."
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8271) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Accessing Dependent and Precedent Information.
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!
Want to know what is happening in certain cells in your worksheet? Using the Watch Window is a great way to keep an eye ...
Discover MoreExcel provides some great tools that can help you see the relationships between the formulas in your worksheets. These ...
Discover MoreSome worksheets are better understood through the spoken word or with musical accompaniment. Sound files can be easily ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-03-02 09:38:46
Craig M Bower
@J. Woolley
Thank you.
2023-03-01 10:31:20
J. Woolley
https://excelribbon.tips.net/T008271_Accessing_Dependent_and_Precedent_Information.html
@Craig Bower
Yes. The ReportDents macro in My Excel Toolbox will trace direct precedents and dependents for each cell in the active sheet's Selection and report results in a separate '...dents' worksheet with each row including hyperlinks to the source cell and its precedent or dependent target range (which might be on a different worksheet or workbook). For example, if 'Sheet1'!$A$1 contains the formula
=SUM('Sheet2'!$B$1:$B$9)
then the '...dents' sheet will include hyperlinks to 'Sheet1'!$A$1 and its precedent range 'Sheet2'!$B$1:$B$9.
See https://sites.google.com/view/MyExcelToolbox/
2023-02-28 10:06:25
Craig Bower
I like the macro presented in this tip, but I note that it only will trace the dependents located on the worksheet of the selected cell. It does not list the dependents located on other worksheets of the workbook. Is there a way to list the dependents on other worksheets? Most of the time when I use the actual tracing interface, you are not able to read the entire traced cell name listed.
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments