The usual arithmetic operators are available. The precision of the result is determined according to the following rules:
-
Note that in the case of
-
,+
, and*
, the result is calculated withBIGINT
(64-bit) precision if both arguments are integers. -
If one of the arguments is an unsigned integer, and the other argument is also an integer, the result is an unsigned integer.
-
If any of the operands of a
+
,-
,/
,*
,%
is a real or string value, then the precision of the result is the precision of the argument with the maximum precision. -
In multiplication and division, the precision of the result when using two integer values is the precision of the first argument + the value of the
div_precision_increment
global variable. For example, the expression5.05 / 0.0014
would have a precision of six decimal places (4.047976
).
These rules are applied for each operation, such that nested
calculations imply the precision of each component. Hence,
(14620 / 9432456) / (24250 / 9432456)
, would
resolve first to (0.0014) / (0.0026)
, with
the final result having 8 decimal places
(0.57692308
).
Because of these rules and the method they are applied, care should be taken to ensure that components and sub-components of a calculation use the appropriate level of precision. See Section 12.8, “Cast Functions and Operators”.
-
Addition:
mysql>
SELECT 3+5;
-> 8 -
Subtraction:
mysql>
SELECT 3-5;
-> -2 -
Unary minus. This operator changes the sign of the argument.
mysql>
SELECT - 2;
-> -2Note: If this operator is used with a
BIGINT
, the return value is also aBIGINT
. This means that you should avoid using–
on integers that may have the value of –263. -
Multiplication:
mysql>
SELECT 3*5;
-> 15 mysql>SELECT 18014398509481984*18014398509481984.0;
-> 324518553658426726783156020576256.0 mysql>SELECT 18014398509481984*18014398509481984;
-> 0The result of the last expression is incorrect because the result of the integer multiplication exceeds the 64-bit range of
BIGINT
calculations. (See Section 11.2, “Numeric Types”.) -
Division:
mysql>
SELECT 3/5;
-> 0.60Division by zero produces a
NULL
result:mysql>
SELECT 102/(1-1);
-> NULLA division is calculated with
BIGINT
arithmetic only if performed in a context where its result is converted to an integer. -
Integer division. Similar to
FLOOR()
, but is safe withBIGINT
values.mysql>
SELECT 5 DIV 2;
-> 2
All mathematical functions return NULL
in the
event of an error.
-
Returns the absolute value of
X
.mysql>
SELECT ABS(2);
-> 2 mysql>SELECT ABS(-32);
-> 32This function is safe to use with
BIGINT
values. -
Returns the arc cosine of
X
, that is, the value whose cosine isX
. ReturnsNULL
ifX
is not in the range-1
to1
.mysql>
SELECT ACOS(1);
-> 0 mysql>SELECT ACOS(1.0001);
-> NULL mysql>SELECT ACOS(0);
-> 1.5707963267949 -
Returns the arc sine of
X
, that is, the value whose sine isX
. ReturnsNULL
ifX
is not in the range-1
to1
.mysql>
SELECT ASIN(0.2);
-> 0.20135792079033 mysql>SELECT ASIN('foo');
+-------------+ | ASIN('foo') | +-------------+ | 0 | +-------------+ 1 row in set, 1 warning (0.00 sec) mysql>SHOW WARNINGS;
+---------+------+-----------------------------------------+ | Level | Code | Message | +---------+------+-----------------------------------------+ | Warning | 1292 | Truncated incorrect DOUBLE value: 'foo' | +---------+------+-----------------------------------------+ -
Returns the arc tangent of
X
, that is, the value whose tangent isX
.mysql>
SELECT ATAN(2);
-> 1.1071487177941 mysql>SELECT ATAN(-2);
-> -1.1071487177941 -
Returns the arc tangent of the two variables
X
andY
. It is similar to calculating the arc tangent ofY
/X
, except that the signs of both arguments are used to determine the quadrant of the result.mysql>
SELECT ATAN(-2,2);
-> -0.78539816339745 mysql>SELECT ATAN2(PI(),0);
-> 1.5707963267949 -
Returns the smallest integer value not less than
X
.mysql>
SELECT CEILING(1.23);
-> 2 mysql>SELECT CEIL(-1.23);
-> -1These two functions are synonymous. Note that the return value is converted to a
BIGINT
. -
Returns the cosine of
X
, whereX
is given in radians.mysql>
SELECT COS(PI());
-> -1 -
Returns the cotangent of
X
.mysql>
SELECT COT(12);
-> -1.5726734063977 mysql>SELECT COT(0);
-> NULL -
Computes a cyclic redundancy check value and returns a 32-bit unsigned value. The result is
NULL
if the argument isNULL
. The argument is expected to be a string and (if possible) is treated as one if it is not.mysql>
SELECT CRC32('MySQL');
-> 3259397556 mysql>SELECT CRC32('mysql');
-> 2501908538 -
Returns the argument
X
, converted from radians to degrees.mysql>
SELECT DEGREES(PI());
-> 180 mysql>SELECT DEGREES(PI() / 2);
-> 90 -
Returns the value of e (the base of natural logarithms) raised to the power of
X
.mysql>
SELECT EXP(2);
-> 7.3890560989307 mysql>SELECT EXP(-2);
-> 0.13533528323661 mysql>SELECT EXP(0);
-> 1 -
Returns the largest integer value not greater than
X
.mysql>
SELECT FLOOR(1.23);
-> 1 mysql>SELECT FLOOR(-1.23);
-> -2Note that the return value is converted to a
BIGINT
. -
FORMAT(
X
,D
)Formats the number
X
to a format like'#,###,###.##'
, rounded toD
decimal places, and returns the result as a string. For details, see Section 12.3, “String Functions”. -
Returns the natural logarithm of
X
; that is, the base-e logarithm ofX
.mysql>
SELECT LN(2);
-> 0.69314718055995 mysql>SELECT LN(-2);
-> NULLThis function is synonymous with
LOG(
X
). -
If called with one parameter, this function returns the natural logarithm of
X
.mysql>
SELECT LOG(2);
-> 0.69314718055995 mysql>SELECT LOG(-2);
-> NULLIf called with two parameters, this function returns the logarithm of
X
for an arbitrary baseB
.mysql>
SELECT LOG(2,65536);
-> 16 mysql>SELECT LOG(10,100);
-> 2LOG(
B
,X
) is equivalent toLOG(
X
) / LOG(B
). -
Returns the base-2 logarithm of
X
.mysql>
SELECT LOG2(65536);
-> 16 mysql>SELECT LOG2(-100);
-> NULLLOG2()
is useful for finding out how many bits a number requires for storage. This function is equivalent to the expressionLOG(
X
) / LOG(2). -
Returns the base-10 logarithm of
X
.mysql>
SELECT LOG10(2);
-> 0.30102999566398 mysql>SELECT LOG10(100);
-> 2 mysql>SELECT LOG10(-100);
-> NULLLOG10(
X
) is equivalent toLOG(10,
X
). -
Modulo operation. Returns the remainder of
N
divided byM
.mysql>
SELECT MOD(234, 10);
-> 4 mysql>SELECT 253 % 7;
-> 1 mysql>SELECT MOD(29,9);
-> 2 mysql>SELECT 29 MOD 9;
-> 2This function is safe to use with
BIGINT
values.MOD()
also works on values that have a fractional part and returns the exact remainder after division:mysql>
SELECT MOD(34.5,3);
-> 1.5 -
Returns the value of π (pi). The default number of decimal places displayed is seven, but MySQL uses the full double-precision value internally.
mysql>
SELECT PI();
-> 3.141593 mysql>SELECT PI()+0.000000000000000000;
-> 3.141592653589793116 -
Returns the value of
X
raised to the power ofY
.mysql>
SELECT POW(2,2);
-> 4 mysql>SELECT POW(2,-2);
-> 0.25 -
Returns the argument
X
, converted from degrees to radians. (Note that π radians equals 180 degrees.)mysql>
SELECT RADIANS(90);
-> 1.5707963267949 -
Returns a random floating-point value
v
between0
and1
inclusive (that is, in the range0
<=v
<=1.0
). If an integer argumentN
is specified, it is used as the seed value, which produces a repeatable sequence.mysql>
SELECT RAND();
-> 0.9233482386203 mysql>SELECT RAND(20);
-> 0.15888261251047 mysql>SELECT RAND(20);
-> 0.15888261251047 mysql>SELECT RAND();
-> 0.63553050033332 mysql>SELECT RAND();
-> 0.70100469486881 mysql>SELECT RAND(20);
-> 0.15888261251047To obtain a random integer
R
in the rangei
<=R
<=j
, use the expressionFLOOR(
i
+ RAND() * (j
–i
). For example, to obtain a random integer in the range of 7 to 12 inclusive, you could use the following statement:SELECT FLOOR(7 + (RAND() * 5));
You cannot use a column with
RAND()
values in anORDER BY
clause, becauseORDER BY
would evaluate the column multiple times. However, you can retrieve rows in random order like this:mysql>
SELECT * FROM
tbl_name
ORDER BY RAND();ORDER BY RAND()
combined withLIMIT
is useful for selecting a random sample from a set of rows:mysql>
SELECT * FROM table1, table2 WHERE a=b AND c<d
->ORDER BY RAND() LIMIT 1000;
Note that
RAND()
in aWHERE
clause is re-evaluated every time theWHERE
is executed.RAND()
is not meant to be a perfect random generator, but instead is a fast way to generate ad hoc random numbers which is portable between platforms for the same MySQL version. -
Returns the argument
X
, rounded to the nearest integer. With two arguments, returnsX
rounded toD
decimal places.D
can be negative to causeD
digits left of the decimal point of the valueX
to become zero.mysql>
SELECT ROUND(-1.23);
-> -1 mysql>SELECT ROUND(-1.58);
-> -2 mysql>SELECT ROUND(1.58);
-> 2 mysql>SELECT ROUND(1.298, 1);
-> 1.3 mysql>SELECT ROUND(1.298, 0);
-> 1 mysql>SELECT ROUND(23.298, -1);
-> 20The return type is the same type as that of the first argument (assuming that it is integer, double, or decimal). This means that for an integer argument, the result is an integer (no decimal places).
Before MySQL 5.0.3, the behavior of
ROUND()
when the argument is halfway between two integers depends on the C library implementation. Different implementations round to the nearest even number, always up, always down, or always toward zero. If you need one kind of rounding, you should use a well-defined function such asTRUNCATE()
orFLOOR()
instead.As of MySQL 5.0.3,
ROUND()
uses the precision math library for exact-value arguments when the first argument is a decimal value:-
For exact-value numbers,
ROUND()
uses the “round half up” or “round toward nearest” rule: A value with a fractional part of .5 or greater is rounded up to the next integer if positive or down to the next integer if negative. (In other words, it is rounded away from zero.) A value with a fractional part less than .5 is rounded down to the next integer if positive or up to the next integer if negative. -
For approximate-value numbers, the result depends on the C library. On many systems, this means that
ROUND()
uses the "round to nearest even" rule: A value with any fractional part is rounded to the nearest even integer.
The following example shows how rounding differs for exact and approximate values:
mysql>
SELECT ROUND(2.5), ROUND(25E-1);
+------------+--------------+ | ROUND(2.5) | ROUND(25E-1) | +------------+--------------+ | 3 | 2 | +------------+--------------+For more information, see Chapter 21, Precision Math.
-
-
Returns the sign of the argument as
-1
,0
, or1
, depending on whetherX
is negative, zero, or positive.mysql>
SELECT SIGN(-32);
-> -1 mysql>SELECT SIGN(0);
-> 0 mysql>SELECT SIGN(234);
-> 1 -
Returns the sine of
X
, whereX
is given in radians.mysql>
SELECT SIN(PI());
-> 1.2246063538224e-16 mysql>SELECT ROUND(SIN(PI()));
-> 0 -
Returns the square root of a non-negative number
X
.mysql>
SELECT SQRT(4);
-> 2 mysql>SELECT SQRT(20);
-> 4.4721359549996 mysql>SELECT SQRT(-16);
-> NULL -
Returns the tangent of
X
, whereX
is given in radians.mysql>
SELECT TAN(PI());
-> -1.2246063538224e-16 mysql>SELECT TAN(PI()+1);
-> 1.5574077246549 -
Returns the number
X
, truncated toD
decimal places. IfD
is0
, the result has no decimal point or fractional part.D
can be negative to causeD
digits left of the decimal point of the valueX
to become zero.mysql>
SELECT TRUNCATE(1.223,1);
-> 1.2 mysql>SELECT TRUNCATE(1.999,1);
-> 1.9 mysql>SELECT TRUNCATE(1.999,0);
-> 1 mysql>SELECT TRUNCATE(-1.999,1);
-> -1.9 mysql>SELECT TRUNCATE(122,-2);
-> 100 mysql>SELECT TRUNCATE(10.28*100,0);
-> 1028All numbers are rounded toward zero.