- Excel Version
- 365
- 2019
- 2016
- 2013
Cyclic references do show up. It is not difficult to inadvertedly create one.
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.
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.
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
Let us consider cell
LINK to the spreadsheet featured above.
Jerzy Tyszkiewicz
- 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.
Cell Formulas | ||
---|---|---|
Range | Formula | |
A2:A4 | A2 | =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 | ||||||||
---|---|---|---|---|---|---|---|---|
A | B | C | D | E | F | |||
1 | Work area, where cycles might emerge | Cell-level warning | Range-level warning | Reference cell | ||||
2 | 1 | 1 | 0 | 2020-01-01 17:43:31 | 2020-01-01 17:43:31 | 2020-01-01 17:43:35 | ||
3 | 2 | 2 | 1 | 2020-01-01 17:43:35 | ||||
4 | 3 | 3 | 1 | 2020-01-01 17:43:35 | ||||
Sheet1 |
Cell Formulas | ||
---|---|---|
Range | Formula | |
E2 | E2 | =IF(COUNTA(A2:C4)=COUNTA(A2:C4),$F$2,$F$2) |
F2 | F2 | =NOW() |
A2:A4 | A2 | =OFFSET($A$1,B2,C2,1,1) |
D2:D4 | D2 | =IF(ISERROR(A2),$F$2,$F$2) |
Cells with Conditional Formatting | ||||
---|---|---|---|---|
Cell | Condition | Cell Format | Stop If True | |
E2 | Cell Value | <$F$2 | text | NO |
D2:D4 | Cell Value | <$F$2 | text | NO |
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:- The spreadsheet is recomputed, including an update to
F2
, whose value increases. - Neither
A2
norD2
are recomputed, due to the cycle being there. - The new value in
F2
becomes larger than the value inD2
, hence conditional formatting is applied toD2
, indicating that cycle.
A2
is neither a part of a cycle nor depends on one, the following cascade of events is triggered:- The spreadsheet is recomputed, including an update to
F2
, whose value increases. A2
andD2
are recomputed, too, and moreover afterF2
, due to data dependence.- The value in
F2
cannot be larger than the value inD2
, hence conditional formatting is not applied toD2
and there is no warning about a cycle affectingA2
.
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