Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 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: Counting Precedents and Dependents.
Written by Allen Wyatt (last updated June 24, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
Because Excel allows you to create formulas that refer to other cells, it stands to reason that cells can be dependent on each other. In fact, Excel has two technical terms that are used to define the relationship between cells: precedents and dependents.
Precedents are those cells on which a formula is based. Thus, if cell A5 contains the formula =A3 + A4, then both A3 and A4 are precedents for cell A5. Dependents are the reverse of precedents. Thus, in this example, cell A5 is a dependent of cells A3 and A4. You can use the auditing tools in Excel to graphically depict these relationships between cells, as described in other issues of ExcelTips.
What if you want to know how many dependents and precedents there are in a worksheet, however? There is no Excel command that displays this information. You can use a macro to calculate and display this information, however. The following macro will do just that:
Sub CountDependentsPrecedents()
Dim ws As Worksheet
Dim lDep As Long
Dim lPre As Long
On Error GoTo err
For Each ws In Worksheets
ws.Select
lDep = 0
lPre = 0
lDep = Range("a1:xfd1048576").Dependents.Count
lPre = Range("a1:xfd1048576").Precedents.Count
MsgBox "Worksheet: " & ActiveSheet.Name & vbCr & _
"Dependents: " & lDep & vbCr & _
"Precedents: " & lPre
Next ws
Exit Sub
err:
Resume Next
End Sub
When you run this macro, it steps through each worksheet in your workbook and displays the number of dependents and precedents in each.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6196) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Counting Precedents and Dependents.
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!
Addresses used in a formula can be either relative or absolute. If you need to switch between the two types of ...
Discover MoreUsing a formula to find information in a text value is easy. Using a formula to find either of two text values within a ...
Discover MoreWant to sum the values in the same cell on a range of worksheets? It's not as easy as summing a range on the same ...
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 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 © 2025 Sharon Parq Associates, Inc.
Comments