Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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.

Counting Precedents and Dependents

by Allen Wyatt
(last updated April 11, 2015)

2

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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6196) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Counting Precedents and Dependents.

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

Controlling How Excel Interprets Percentages

When entering data in a worksheet, Excel tries to figure out how your entry can best be shown on the screen. When it comes to ...

Discover More

Editing While Spell-Checking

When you run a spell-check on a document, you may end up seeing other things that need to be edited. Never fear; you can do ...

Discover More

Maintaining Text Formatting in a Lookup

Want to maintain the formatting used in one cell when you use formulas to reference that text in another cell? The answer is ...

Discover More

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 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Finding the Sum of a Sequential Integer Range

In mathematics, the sum of a range of sequential integers, starting with 1, is known as a triangular number or Gaussian ...

Discover More

Adding Up Tops and Bottoms

When you are working with sequenced values in a list, you'll often want to take some action based on the top X or bottom Y ...

Discover More

Segregating Numbers According to Their Sign

Remember your number line from your early years in school? Some numbers can be below zero (negative numbers) and others above ...

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}] 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 two more than 4?

2015-04-12 21:58:53

Col Delane

Below is a modified version of the code, which: (1) advises the user as to the type of any unexpected error encountered, (2) allows the macro to continue if there are no precedents or dependents on the active sheet (otherwise it bombs out due to the error), (3) incorporates Nir's suggestion, and (4) allows the user to exit gracefully after testing any sheet.

Sub CountDependentsPrecedentsBySheet()

'Define Procedure Variables
Dim wbk As Workbook
Dim ws As Worksheet
Dim lDep As Long
Dim lPre As Long
Dim MsgResp

On Error GoTo ErrorHandler

Set wbk = ActiveWorkbook

For Each ws In wbk.Worksheets
ws.Select
lDep = 0
lPre = 0

On Error Resume Next
lDep = Cells.Dependents.Count
lPre = Cells.Precedents.Count
On Error GoTo ErrorHandler

Select Case MsgBox("Worksheet name: " & ActiveSheet.Name & vbCr & vbCr & _
"No. of Precedents: " & lPre & vbCr & vbCr & _
"No. of Dependents: " & lDep, vbOKCancel + vbInformation, "Count of Precedents & Dependents")

Case vbOK
'Do nothing >> continue
Case vbCancel
GoTo ExitPoint
End Select

Next ws

ExitPoint: '-------------------->>>>>>>>>-------------------->>>>>>>>>-------------------->>>>>>>>> Exit Sub
On Error GoTo 0
Exit Sub

ErrorHandler:
MsgBox Prompt:=Now & ":" & vbLf & vbLf & "Error " & err.Number & " (" & err.Description & ")" & vbLf & vbLf & "in procedure named 'CountDependentsPrecedentsbySheet'" & vbLf & vbLf & "in workbook named " & ThisWorkbook.Name, Buttons:=vbOKOnly + vbExclamation, Title:="VBA Error"
Application.StatusBar = False
Resume ExitPoint

End Sub


2015-04-12 01:17:51

nir liberman

shorter / easier:
lDep = Cells.Dependents.Count
lPre = Cells.Precedents.Count


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.