XL2000: Visual Basic Macro to List Circular References (213826)
The information in this article applies to:
This article was previously published under Q213826 SUMMARY
In a Microsoft Excel 2000 worksheet, when a formula in a cell refers to the same
cell the formula occupies, either directly or indirectly, a circular reference is created. In Excel 2000, tracing tools are provided on the Auditing toolbar to help you locate unwanted circular references. Another way you can trace circular references is to create a Microsoft Visual Basic for Applications macro that produces a list of all cells containing circular references that occur in a single worksheet.
MORE INFORMATIONMicrosoft provides programming examples for illustration only, without warranty either
expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes
that you are familiar with the programming language being demonstrated and the
tools used to create and debug procedures. Microsoft support professionals can
help explain the functionality of a particular procedure, but they will not
modify these examples to provide added functionality or construct procedures to
meet your specific needs. If you have limited programming experience, you may
want to contact a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
Finding Circular References
Precedents are the cells referenced, directly or indirectly, by a formula.
A circular reference occurs whenever the cell containing the circular
reference formula is included in the formula's precedents.
The following sample Visual Basic macro generates a new sheet in a workbook
and lists all circular references found on the active worksheet. The macro
does this by testing each formula in the sheet to see if the cell
containing the formula intersects the precedents of the formula.
NOTE: A limitation of this method is that the Precedents property in Visual Basic for Applications can only find precedents on the active sheet. The macro will not find a circular reference that is caused by a remote reference.
Sample Visual Basic Procedure
On a module sheet, enter the following Visual Basic code:
Sub FindCircRefs()
' Get source information.
sourcesheet = ActiveSheet.Name
Sheets.Add
' Get destination information.
destsheet = ActiveSheet.Name
destrange = ActiveCell.Address
' Return to source.
Worksheets(sourcesheet).Activate
rowcount = 0
' Trap for error in "result", indicating no circular reference.
On Error GoTo notcircular
' Loop through every used cell in source.
For Each Item In ActiveSheet.UsedRange
' Check to see if cell contains a formula.
If Left(Item.Formula, 1) = "=" Then
' If cell intersects with precedents, cell has circular
' reference.
result = Intersect(ActiveSheet.Range(Item.Address), _
ActiveSheet.Range(Item.Precedents.Address))
Worksheets(destsheet).Range(destrange).Offset(rowcount, _
0).Value = Item.Address(False, False)
Worksheets(destsheet).Range(destrange).Offset(rowcount, _
1).Value = "'" & Item.Formula
rowcount = rowcount + 1
' Skip to here if not circular.
skipitem:
End If
Next
Exit Sub
' If error in "result", go here.
notcircular:
' Skip cells that do not contain circular references.
Resume skipitem
End Sub
To use this macro, run the FindCircRefs macro from the Microsoft Excel
worksheet for which you want to find circular references. A new sheet is
added to the active workbook, listing the cell addresses of circular
references in column A and the formula at that address in column B. If no
circular references are found, the new sheet is empty.
REFERENCESFor more information about circular references and locating cells that contain them, click Microsoft Excel Help on the
Help menu, type locate cells that create a circular reference in the Office Assistant or
the Answer Wizard, and then click Search to view the topics
returned.
Modification Type: | Minor | Last Reviewed: | 10/11/2006 |
---|
Keywords: | kbdtacode kbhowto kbProgramming KB213826 |
---|
|