Everybody that has had to do some numeric calculations in SQL
will have encountered this simple problem: divide an integer by
another integer and round down the outcome to the nearest
integer. In many cases people write it like this:
FLOOR(a/b)
Simple enough, right? First we do the division a/b
,
then we round down using the function FLOOR()
.
Update: My claim that TRUNCATE(a/b, 0)
is equivalent
to FLOOR(a/b)
is false! It maybe true when the
outcome of the division is a positive number, but in case of a
negative number, TRUNCATE()
will only lose the
decimals (resulting in a higher negative number) and
FLOOR()
will still round down.
Thanks Kai!
However, there is a better way.
We can use the integer division operator DIV
instead of the ordinary division
operator /
. Because this is an integer division,
there is no need for an extra function to lose the decimals, and
the expression is simply:
a DIV b
This approach has a number of advantages:
-
- It is explicit. By looking at the expression we know
immediately that the result will be an integer, and that
a
andb
are meant to be integers too.
- It is easier to read. Because we don't need another function
and parenthesis, this expression is easier on the eyes, something
that you will appreciate if the expression is not simply
FLOOR(a/b)
but something likeFLOOR(SUM(a)/SUM(IFNULL(b,0)))
- It is fast! The
DIV
operation does not have to deal with complex floating point math, and will be much faster on most microprocessors
To prove the last point, take a look at the results of a simple
benchmark. I simply used the BENCHMARK()
function and
executed:
mysql> SELECT BENCHMARK(10000000,1234567 DIV 7) ;
+-----------------------------------+
| BENCHMARK(10000000,1234567 DIV 7) |
+-----------------------------------+
| 0 |
+-----------------------------------+
1 row in set (0.83 sec)
mysql> SELECT BENCHMARK(10000000,1234567 / 7) ;
+---------------------------------+
| BENCHMARK(10000000,1234567 / 7) |
+---------------------------------+
| 0 |
+---------------------------------+
1 row in set (7.26 sec)
mysql> SELECT BENCHMARK(10000000,FLOOR(1234567 / 7)) ;
+----------------------------------------+
| BENCHMARK(10000000,FLOOR(1234567 / 7)) |
+----------------------------------------+
| 0 |
+----------------------------------------+
1 row in set (8.80 sec)
I repeated this two more times and averaged the time spent, and
then made this little graph of the results:
The results show that DIV
is
about 9 to 10 times faster than the ordinary division operator,
and that adding FLOOR()
function makes the entire
expression another 10% slower.
Now, I don't think the performance benefit is of much practical
significance. You may see a slight improvement for large datasets
using multiple division operations, but in many cases the
ordinary query processing will probably have a much larger part
in the total time spent. But still, DIV
is faster,
easier to read and more explicit if you want to solve this type
of problem.