Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Accessing Dependent and Precedent Information.
Written by Allen Wyatt (last updated December 5, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003
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 sActiveCell As String
Dim rDep As Range
Dim lRow As Long
On Error Resume Next
Set rDep = ActiveCell.Dependents
If rDep Is Nothing Then
MsgBox ActiveCell.Address(False, False) & _
" has no dependents"
Exit Sub
End If
On Error GoTo 0
sActiveCell = ActiveCell.Address(False, False)
Worksheets.Add
lRow = 1
Cells(lRow, 1).Value = "Dependents for " & sActiveCell
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 (3121) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Accessing Dependent and Precedent Information.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel Data Analysis and Business Modeling today!
When you starting linking information from one workbook to another, those workbooks become dependent on each other. ...
Discover MoreCells that affect another cell are called precedent cells. If you need to know which cells affect a particular cell, ...
Discover MoreExcel provides some great tools that can help you see the relationships between the formulas in your worksheets. These ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments