Forum Discussion
Mysterious bug on excel calculation, on a vlookup
As you can see on the excel file, the value on A7 and A8 looks like a 100% like the one on A11 and A12. But when using the VLookup with it, it gets to different results!
This makes many errors on calculations on our company, recently detected.
Would be nice to know what happend and how to fix it!, maybe it's something with hidden decimals floating point?
Glarrain wrote: ``A7 and A8 looks like a 100% like the one on A11 and A12``
And looks can be deceiving.
The problem has nothing to do with errant characters (which would result in #VALUE errors, anyway), and using the Excel VALUE or VLOOKUP(...,TRUE) function might work-around the problem only by coincidence.
Instead, this is just yet-another example of binary (floating-point) arithmetic anomalies.
The work-around is: whenever you expect a calculation to be accurate to some number of decimal places, explicitly round to that number of decimal places -- and not to arbitrary number, as some people suggest. For whole percentage values, round to 2 decimal places (because 12% is 0.12). For percentage values that should be accurate to 2 percentage decimal places, round to 4 decimal places (because 12.34% is 0.1234).
It appears that the values in A7 and A8 had been calculated (somewhere), then copy-and-pasted-value into A7 and A8. And the calculated values are infinitesimally smaller (-1.11E-16) than how the values appear, even when formatted to display 15 significant digits. We can see such differences with formulas of the form =SUM(A7,-(A7&"")) formatted as Scientific or General.
(That works because the expression A7&"" returns the value formatted with up to 15 significant digits. That is Excel's arbitrary formatting limit. It is not the limit of numeric precision, as many documents state incorrectly.)
Additionally, VLOOKUP is among the many Excel functions that compare exact binary values, not the values arbitrarily rounded to up to 15 significant digits, as compare operators ("=", ">=", etc) and the *IF[S] functions do (COUNTIF, SUMIFS, etc).
Since the value in A7 is infinitesimally less than the value in A4 (exactly 100%), VLOOKUP(...,TRUE) returns the value in column B (B3) that corresponds to the largest value less than 100%, namely 95% in A3.
Since the (same) value in A8 is infinitesimally different from the value in A4, VLOOKUP(...,FALSE) returns #N/A because it fails to find an exactly binary match.
In both cases, one work-around is to use ROUND(A7,4) and ROUND(A8,4) if you want to allow for accuracy to fractional percentages (2 percentage decimal places), as you format them.
Another solution is to explicitly round the calculations that sourced the values in A7 and A8. You do not show us those formulas.
Neither solution is more "right" or "wrong". The choice is yours to make, depending on your intentions.
11 Replies
- JoeUser2004Bronze Contributor
Glarrain wrote: ``A7 and A8 looks like a 100% like the one on A11 and A12``
And looks can be deceiving.
The problem has nothing to do with errant characters (which would result in #VALUE errors, anyway), and using the Excel VALUE or VLOOKUP(...,TRUE) function might work-around the problem only by coincidence.
Instead, this is just yet-another example of binary (floating-point) arithmetic anomalies.
The work-around is: whenever you expect a calculation to be accurate to some number of decimal places, explicitly round to that number of decimal places -- and not to arbitrary number, as some people suggest. For whole percentage values, round to 2 decimal places (because 12% is 0.12). For percentage values that should be accurate to 2 percentage decimal places, round to 4 decimal places (because 12.34% is 0.1234).
It appears that the values in A7 and A8 had been calculated (somewhere), then copy-and-pasted-value into A7 and A8. And the calculated values are infinitesimally smaller (-1.11E-16) than how the values appear, even when formatted to display 15 significant digits. We can see such differences with formulas of the form =SUM(A7,-(A7&"")) formatted as Scientific or General.
(That works because the expression A7&"" returns the value formatted with up to 15 significant digits. That is Excel's arbitrary formatting limit. It is not the limit of numeric precision, as many documents state incorrectly.)
Additionally, VLOOKUP is among the many Excel functions that compare exact binary values, not the values arbitrarily rounded to up to 15 significant digits, as compare operators ("=", ">=", etc) and the *IF[S] functions do (COUNTIF, SUMIFS, etc).
Since the value in A7 is infinitesimally less than the value in A4 (exactly 100%), VLOOKUP(...,TRUE) returns the value in column B (B3) that corresponds to the largest value less than 100%, namely 95% in A3.
Since the (same) value in A8 is infinitesimally different from the value in A4, VLOOKUP(...,FALSE) returns #N/A because it fails to find an exactly binary match.
In both cases, one work-around is to use ROUND(A7,4) and ROUND(A8,4) if you want to allow for accuracy to fractional percentages (2 percentage decimal places), as you format them.
Another solution is to explicitly round the calculations that sourced the values in A7 and A8. You do not show us those formulas.
Neither solution is more "right" or "wrong". The choice is yours to make, depending on your intentions.
- Detlef_LewinSilver Contributor
The real values in A7 and A8 are 0.99999999999999989 and 0.99999999999999989.
The values were probably copied from another source.
- mtarlerSilver Contributor
Detlef_Lewin and JoeUser2004 , you both indicate that the value is a round off error. how did you determine that? I expanded the number of decimal places and did not see that:
is there some other trick i should be using to check for that?
Furthermore, that doesn't explain why NUMBERVALUE() or --TRIM() applied to that cell would fix that issue since if it really is 0.999999... neither of those functions would change or fix that.
- JoeUser2004Bronze Contributor
(With critical corrections for posterity.)
mtarler wrote: ``that doesn't explain why NUMBERVALUE() or --TRIM() applied to that cell would fix that issue since if it really is 0.999999... neither of those functions would change or fix that``.
Sorry, I overlooked that question.
They work-around the problem because they cause Excel to return the value rounded to 15 significant digits. In this case, 1 - 2^-53 (approx 0.99999999999999989) rounds to exactly 1, which is a binary match for the value in A4 (100%).
But as I said before, that is only by coincidence.
Consider the following example.
Enter =1 + 2^-52 into A4. That might be the result of a calculation that we expected to be exactly 100%.
Then, with =1 - 2^-53 in A7, note that VLOOKUP(NUMBERVALUE(A7),A4,1,FALSE) and VLOOKUP(NUMBERVALUE(A7),A4,1,TRUE) still return #N/A (no match).
The reason is: NUMBERVALUE(A7) rounds A7 to exactly 1 (100%), but it does not match the exact binary value in A4.
In contrast, if we enter exactly 1 into A4, both VLOOKUPs return 1 (match) because the binary values now match.
- JoeUser2004Bronze Contributor
Detlef_Lewin wrote: ``A7 and A8 are 0.99999999999999989 and 0.99999999999999989``.
Not really. That is just a 17-digit approximation, which is sufficient to reproduce the binary value exactly. We can see those values in the XML file that "xslx" files are stored as, as you know.
But the exact decimal representation of the binary values is 0.999999999999999,88897769753748434595763683319091796875.
(I use period for the decimal place and comma to demarcate the first 15 significant digits.)
- Detlef_LewinSilver Contributor
But the exact decimal representation of the binary values is 0.999999999999999,88897769753748434595763683319091796875.Where did you get this value from?
- mtarlerSilver Contributor
I don't have a good satisfying answer. They look the same and everything I do seems to indicate they are the same BUT A7 and A8 are text or something. If you re-type the value in it works fine, if you change the formula to
=VLOOKUP(NUMBERVALUE(A7),$A$2:$B$4,2,TRUE)
or
=VLOOKUP(--CLEAN(A7),$A$2:$B$4,2,TRUE)
they work.
Is it possible you used a keyboard or computer set to a different language or extended keyset where the characters are actually in the extended range?I apologize for the EDIT notifications: but basically I noticed that I was wrong on the 2nd option above because I originally thought --A7 worked but it didn't and only worked if I also used the CLEAN() function which further points to my question above about another language keyboard or if you imported data. CLEAN specifically removes non-printable characters in the low range of ASCII.