Visual Basic Macro to List Circular References (125848)
The information in this article applies to:
- Microsoft Excel 97 for Windows
- Microsoft Excel for Windows 95
- Microsoft Excel for Windows 5.0
- Microsoft Excel 98 Macintosh Edition
This article was previously published under Q125848 SUMMARY
In a Microsoft Excel worksheet, when a formula in a cell refers to the same
cell it occupies, either directly or indirectly, a circular reference is
created. In Microsoft Excel versions 5.0 and later, 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. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers 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 requirements.
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 below 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 will
be 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 will be empty.
Modification Type: | Minor | Last Reviewed: | 10/11/2006 |
---|
Keywords: | kbdtacode kbhowto kbProgramming KB125848 |
---|
|