1

I am using Firebird 3.0.4 (both in Windows and Linux) and I have the following procedure that clearly demonstrates my problem with floating point numbers, and that also demonstrates a possible workaround:

create or alter procedure test_float returns (res double precision,
  res1 double precision,
  res2 double precision)
as

declare variable z1 double precision;
declare variable z2 double precision;
declare variable z3 double precision;

begin

  z1=15;
  z2=1.1;
  z3=0.49;
  res=z1*z2*z3; /* one expects res to be 8.085, but internally, inside the procedure
                   it is represented as 8.084999999999.
                   The procedure-internal representation is repaired when then
                   res is sent to the output of the procedure, but the procedure-internal
                   representation (which is worng) impacts the further calculations */
  res1=round(res, 2);
  res2=round(round(res, 8), 2);

  suspend;

end

On can see the result of the procedure with:

  select proc.res, proc.res1, proc.res2
  from test_float proc

The result is

RES     RES1    RES2
8,085   8,08    8,09

But one can expect that RES2 should be 8.09.

One can clearly see that the internal representation of the res contains 8.0849999 (e.g. one can assign res to the exception message and then raise this exception), it is repaired during output but it leads to the failed calculations when such variable is used in the further calculations.

RES2 demonstrates the repair: I can always apply ROUND(..., 8) to repair the internal representation. I am ready to go with this solution, but my question is - is it acceptable workaround (when the outer ROUND is with strictly less than 5 decimal places) or is there better workaround.

All my tests pass with this workaround, but the feeling is bad.

Of course, I know the minimum that every programmer should know about floats (there is article about that) and I know that one should not use double for business calculations.

Mark Rotteveel
  • 100,966
  • 191
  • 140
  • 197
TomR
  • 2,696
  • 6
  • 34
  • 87

1 Answers1

2

This is an inherent problem with calculating with floating point numbers, and is not specific to Firebird. The problem is that the calculation of 15 * 1.1 * 0.49 using double precision numbers is not exactly 8.085. In fact, if you would do 8.085 - RES, you'd get a value that is (approximately) 1.776356839400251e-015 (although likely your client will just present it as 0.00000000).

You would get similar results in different languages. For example, in Java

DecimalFormat df = new DecimalFormat("#.00");
df.format(15 * 1.1 * 0.49);

will also produce 8.08 for exactly the same reason.

Also, if you would change the order of operations, you would get a different result. For example using 15 * 0.49 * 1.1 would produce 8.085 and round to 8.09, so the actual results would match your expectations.

Given round itself also returns a double precision, this isn't really a good way to handle this in your SQL code, because the rounded value with a higher number of decimals might still yield a value slightly less than what you'd expect because of how floating point numbers work, so the double round may still fail for some numbers even if the presentation in your client 'looks' correct.

If you purely want this for presentation purposes, it might be better to do this in your frontend, but alternatively you could try tricks like adding a small value and casting to decimal, for example something like:

cast(RES + 1e-10 as decimal(18,2))

However this still has rounding issues, because it is impossible to distinguish between values that genuinely are 8.08499999999 (and should be rounded down to 8.08), and values where the result of calculation just happens to be 8.08499999999 in floating point, while it would be 8.085 in exact numerics (and therefor need to be rounded up to 8.09).

In a similar vein, you could try to use double casting to decimal (eg cast(cast(res as decimal(18,3)) as decimal(18,2))), or casting the decimal and then rounding (eg round(cast(res as decimal(18,3)), 2). This would be a bit more consistent than double rounding because the first cast will convert to exact numerics, but again this has similar downside as mentioned above.

Although you don't want to hear this answer, if you want exact numeric semantics, you shouldn't be using floating point types.

Mark Rotteveel
  • 100,966
  • 191
  • 140
  • 197