• If you would like to post, please check out the MrExcel Message Board FAQ and click here to register.
    If you forgot your password, you can reset your password.
  • Excel articles and downloadable files provided in the articles have not been reviewed by MrExcel Publishing. Please apply the provided methods / codes and open the files at your own risk.
    If you have any questions regarding an article, please use the Article Discussion section.
J.Ty.

Cyclic references in Excel, Excel for Android and Excel online

Cyclic references do show up. It is not difficult to inadvertedly create one.

  • Excel for desktop most of the time tells us about the fact immediately and demonstrates where the cycle is. However, if the cycle is created by values which are spilled to neighboring cells, we get only a warning, but Excel's built-in error checker does not show the cycle.
  • Excel for Android tells us about that, but does not locate the cycle.
  • Excel online does not tell us anything, but silently refuses to recalculate all cells on the cycle and ones that depend on them.
  • However, even Excel for desktop and for Android stop recalculating affected formulas and issuing warnings about subsequent cycles, if we ignore the first pop-up.

This short article describes what to do in order to get always a warning and a location of the cycle.

Let us first start with a small calculation, where data changes can introduce a lot of mess, including cyclic references of various kinds.

Book1
ABC
1Work area, where cycles might emerge
2220
3211
4331
Sheet1
Cell Formulas
RangeFormula
A2:A4A2=OFFSET($A$1,B2,C2,1,1)


It is clearly impossible to get warnings about cycles by formulas, because any formula which depends on a cycle will not be recomputed. However, there is another mechanism, which keeps working even for cells which are parts of cycles. It is conditional formatting and we use it in our solution.

We can construct warnings for individual cells, and for whole ranges. The following example shows both types.

Book1
ABCDEF
1Work area, where cycles might emergeCell-level warningRange-level warningReference cell
21102020-01-01 17:43:312020-01-01 17:43:312020-01-01 17:43:35
32212020-01-01 17:43:35
43312020-01-01 17:43:35
Sheet1
Cell Formulas
RangeFormula
E2E2=IF(COUNTA(A2:C4)=COUNTA(A2:C4),$F$2,$F$2)
F2F2=NOW()
A2:A4A2=OFFSET($A$1,B2,C2,1,1)
D2:D4D2=IF(ISERROR(A2),$F$2,$F$2)
Cells with Conditional Formatting
CellConditionCell FormatStop If True
E2Cell Value<$F$2textNO
D2:D4Cell Value<$F$2textNO


We need a formula which will produce a new value whenever it is recomputed. NOW() is a good candidate, and we will use it.
All warnings share the reference cell F2, which includes this function.

Let us consider cell D2. It serves as a warning for cell A2. Its formula =IF(ISERROR(A2);$F$2;$F$2) depends on A2. The ISERROR function is used to assure identical bahvior no matter if A2 is an error value or not. If after a change to the spreadsheet that cell is a part of a cycle or depends on one, the following cascade of events is triggered:
  1. The spreadsheet is recomputed, including an update to F2, whose value increases.
  2. Neither A2 nor D2 are recomputed, due to the cycle being there.
  3. The new value in F2 becomes larger than the value in D2, hence conditional formatting is applied to D2, indicating that cycle.
If after a change to the spreadsheet A2 is neither a part of a cycle nor depends on one, the following cascade of events is triggered:
  1. The spreadsheet is recomputed, including an update to F2, whose value increases.
  2. A2 and D2 are recomputed, too, and moreover after F2, due to data dependence.
  3. The value in F2 cannot be larger than the value in D2, hence conditional formatting is not applied to D2 and there is no warning about a cycle affecting A2.
The range level warning in E2 works very much the same, except that its formula depends on the whole range it controls. COUNTA is used to set up this dependence, being a function which never evaluates to an error, even if there are errors among its arguments.

LINK to the spreadsheet featured above.

Jerzy Tyszkiewicz
Excel Version
365, 2019, 2016, 2013
Author
J.Ty.
Views
258
First release
Last update
Rating
0.00 star(s) 0 ratings

Some videos you may like

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top