Table 14.10 Mathematical Functions
| Name | Description | 
|---|---|
| ABS() | Return the absolute value | 
| ACOS() | Return the arc cosine | 
| ASIN() | Return the arc sine | 
| ATAN() | Return the arc tangent | 
| ATAN2(),ATAN() | Return the arc tangent of the two arguments | 
| CEIL() | Return the smallest integer value not less than the argument | 
| CEILING() | Return the smallest integer value not less than the argument | 
| CONV() | Convert numbers between different number bases | 
| COS() | Return the cosine | 
| COT() | Return the cotangent | 
| CRC32() | Compute a cyclic redundancy check value | 
| DEGREES() | Convert radians to degrees | 
| EXP() | Raise to the power of | 
| FLOOR() | Return the largest integer value not greater than the argument | 
| LN() | Return the natural logarithm of the argument | 
| LOG() | Return the natural logarithm of the first argument | 
| LOG10() | Return the base-10 logarithm of the argument | 
| LOG2() | Return the base-2 logarithm of the argument | 
| MOD() | Return the remainder | 
| PI() | Return the value of pi | 
| POW() | Return the argument raised to the specified power | 
| POWER() | Return the argument raised to the specified power | 
| RADIANS() | Return argument converted to radians | 
| RAND() | Return a random floating-point value | 
| ROUND() | Round the argument | 
| SIGN() | Return the sign of the argument | 
| SIN() | Return the sine of the argument | 
| SQRT() | Return the square root of the argument | 
| TAN() | Return the tangent of the argument | 
| TRUNCATE() | Truncate to specified number of decimal places | 
        All mathematical functions return NULL in the
        event of an error.
- Returns the absolute value of - X, or- NULLif- Xis- NULL.- The result type is derived from the argument type. An implication of this is that - ABS(-9223372036854775808)produces an error because the result cannot be stored in a signed- BIGINTvalue.- mysql> SELECT ABS(2); -> 2 mysql> SELECT ABS(-32); -> 32- This function is safe to use with - BIGINTvalues.
- Returns the arc cosine of - X, that is, the value whose cosine is- X. Returns- NULLif- Xis not in the range- -1to- 1, or if- Xis- NULL.- 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 is- X. Returns- NULLif- Xis not in the range- -1to- 1, or if- Xis- NULL.- 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 is- X. Returns- NULLif- Xis- NULL- mysql> SELECT ATAN(2); -> 1.1071487177941 mysql> SELECT ATAN(-2); -> -1.1071487177941
- Returns the arc tangent of the two variables - Xand- Y. It is similar to calculating the arc tangent of- Y/- X- NULLif- Xor- Yis- NULL.- mysql> SELECT ATAN(-2,2); -> -0.78539816339745 mysql> SELECT ATAN2(PI(),0); -> 1.5707963267949
- Returns the smallest integer value not less than - X. Returns- NULLif- Xis- NULL.- mysql> SELECT CEILING(1.23); -> 2 mysql> SELECT CEILING(-1.23); -> -1- For exact-value numeric arguments, the return value has an exact-value numeric type. For string or floating-point arguments, the return value has a floating-point type. 
- Converts numbers between different number bases. Returns a string representation of the number - N, converted from base- from_baseto base- to_base. Returns- NULLif any argument is- NULL. The argument- Nis interpreted as an integer, but may be specified as an integer or a string. The minimum base is- 2and the maximum base is- 36. If- from_baseis a negative number,- Nis regarded as a signed number. Otherwise,- Nis treated as unsigned.- CONV()works with 64-bit precision.- CONV()returns- NULLif any of its arguments are- NULL.- mysql> SELECT CONV('a',16,2); -> '1010' mysql> SELECT CONV('6E',18,8); -> '172' mysql> SELECT CONV(-17,10,-18); -> '-H' mysql> SELECT CONV(10+'10'+'10'+X'0a',10,10); -> '40'
- Returns the cosine of - X, where- Xis given in radians. Returns- NULLif- Xis- NULL.- mysql> SELECT COS(PI()); -> -1
- Returns the cotangent of - X. Returns- NULLif- Xis- NULL.- mysql> SELECT COT(12); -> -1.5726734063977 mysql> SELECT COT(0); -> out-of-range error
- Computes a cyclic redundancy check value and returns a 32-bit unsigned value. The result is - NULLif the argument is- NULL. 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. Returns- NULLif- Xis- NULL.- 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. The inverse of this function is- LOG()(using a single argument only) or- LN().- If - Xis- NULL, this function returns- NULL.- 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. Returns- NULLif- Xis- NULL.- mysql> SELECT FLOOR(1.23), FLOOR(-1.23); -> 1, -2- For exact-value numeric arguments, the return value has an exact-value numeric type. For string or floating-point arguments, the return value has a floating-point type. 
- Formats the number - Xto a format like- '#,###,###.##', rounded to- Ddecimal places, and returns the result as a string. For details, see Section 14.8, “String Functions and Operators”.
- This function can be used to obtain a hexadecimal representation of a decimal number or a string; the manner in which it does so varies according to the argument's type. See this function's description in Section 14.8, “String Functions and Operators”, for details. 
- Returns the natural logarithm of - X; that is, the base-e logarithm of- X. If- Xis less than or equal to 0.0E0, the function returns- NULLand a warning “Invalid argument for logarithm” is reported. Returns- NULLif- Xis- NULL.- mysql> SELECT LN(2); -> 0.69314718055995 mysql> SELECT LN(-2); -> NULL- This function is synonymous with - LOG(. The inverse of this function is the- X)- EXP()function.
- If called with one parameter, this function returns the natural logarithm of - X. If- Xis less than or equal to 0.0E0, the function returns- NULLand a warning “Invalid argument for logarithm” is reported. Returns- NULLif- Xor- Bis- NULL.- The inverse of this function (when called with a single argument) is the - EXP()function.- mysql> SELECT LOG(2); -> 0.69314718055995 mysql> SELECT LOG(-2); -> NULL- If called with two parameters, this function returns the logarithm of - Xto the base- B. If- Xis less than or equal to 0, or if- Bis less than or equal to 1, then- NULLis returned.- mysql> SELECT LOG(2,65536); -> 16 mysql> SELECT LOG(10,100); -> 2 mysql> SELECT LOG(1,100); -> NULL- LOG(is equivalent to- B,- X)- LOG(.- X) / LOG(- B)
- Returns the base-2 logarithm of - X- Xis less than or equal to 0.0E0, the function returns- NULLand a warning “Invalid argument for logarithm” is reported. Returns- NULLif- Xis- NULL.- mysql> SELECT LOG2(65536); -> 16 mysql> SELECT LOG2(-100); -> NULL- LOG2()is useful for finding out how many bits a number requires for storage. This function is equivalent to the expression- LOG(.- X) / LOG(2)
- Returns the base-10 logarithm of - X. If- Xis less than or equal to 0.0E0, the function returns- NULLand a warning “Invalid argument for logarithm” is reported. Returns- NULLif- Xis- NULL.- mysql> SELECT LOG10(2); -> 0.30102999566398 mysql> SELECT LOG10(100); -> 2 mysql> SELECT LOG10(-100); -> NULL
- Modulo operation. Returns the remainder of - Ndivided by- M. Returns- NULLif- Mor- Nis- NULL.- mysql> SELECT MOD(234, 10); -> 4 mysql> SELECT 253 % 7; -> 1 mysql> SELECT MOD(29,9); -> 2 mysql> SELECT 29 MOD 9; -> 2- This function is safe to use with - BIGINTvalues.- 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- MOD(returns- N,0)- NULL.
- Returns the value of π (pi). The default number of decimal places displayed is seven, but MySQL uses the full double-precision value internally. - Because the return value of this function is a double-precision value, its exact representation may vary between platforms or implementations. This also applies to any expressions making use of - PI(). See Section 13.1.4, “Floating-Point Types (Approximate Value) - FLOAT, DOUBLE”.- mysql> SELECT PI(); -> 3.141593 mysql> SELECT PI()+0.000000000000000000; -> 3.141592653589793000
- Returns the value of - Xraised to the power of- Y. Returns- NULLif- Xor- Yis- NULL.- mysql> SELECT POW(2,2); -> 4 mysql> SELECT POW(2,-2); -> 0.25
- This is a synonym for - POW().
- Returns the argument - X, converted from degrees to radians. (Note that π radians equals 180 degrees.) Returns- NULLif- Xis- NULL.- mysql> SELECT RADIANS(90); -> 1.5707963267949
- Returns a random floating-point value - vin the range- 0<=- v<- 1.0. To obtain a random integer- Rin the range- i<=- R<- j, use the expression- FLOOR(−- i+ RAND() * (- j- i))- 7<=- R<- 12, use the following statement:- SELECT FLOOR(7 + (RAND() * 5));- If an integer argument - Nis specified, it is used as the seed value:- With a constant initializer argument, the seed is initialized once when the statement is prepared, prior to execution. 
- With a nonconstant initializer argument (such as a column name), the seed is initialized with the value for each invocation of - RAND().
 - One implication of this behavior is that for equal argument values, - RAND(returns the same value each time, and thus produces a repeatable sequence of column values. In the following example, the sequence of values produced by- N)- RAND(3)is the same both places it occurs.- mysql> CREATE TABLE t (i INT); Query OK, 0 rows affected (0.42 sec) mysql> INSERT INTO t VALUES(1),(2),(3); Query OK, 3 rows affected (0.00 sec) Records: 3 Duplicates: 0 Warnings: 0 mysql> SELECT i, RAND() FROM t; +------+------------------+ | i | RAND() | +------+------------------+ | 1 | 0.61914388706828 | | 2 | 0.93845168309142 | | 3 | 0.83482678498591 | +------+------------------+ 3 rows in set (0.00 sec) mysql> SELECT i, RAND(3) FROM t; +------+------------------+ | i | RAND(3) | +------+------------------+ | 1 | 0.90576975597606 | | 2 | 0.37307905813035 | | 3 | 0.14808605345719 | +------+------------------+ 3 rows in set (0.00 sec) mysql> SELECT i, RAND() FROM t; +------+------------------+ | i | RAND() | +------+------------------+ | 1 | 0.35877890638893 | | 2 | 0.28941420772058 | | 3 | 0.37073435016976 | +------+------------------+ 3 rows in set (0.00 sec) mysql> SELECT i, RAND(3) FROM t; +------+------------------+ | i | RAND(3) | +------+------------------+ | 1 | 0.90576975597606 | | 2 | 0.37307905813035 | | 3 | 0.14808605345719 | +------+------------------+ 3 rows in set (0.01 sec)- RAND()in a- WHEREclause is evaluated for every row (when selecting from one table) or combination of rows (when selecting from a multiple-table join). Thus, for optimizer purposes,- RAND()is not a constant value and cannot be used for index optimizations. For more information, see Section 10.2.1.20, “Function Call Optimization”.- Use of a column with - RAND()values in an- ORDER BYor- GROUP BYclause may yield unexpected results because for either clause a- RAND()expression can be evaluated multiple times for the same row, each time returning a different result. If the goal is to retrieve rows in random order, you can use a statement like this:- SELECT * FROM tbl_name ORDER BY RAND();- To select a random sample from a set of rows, combine - ORDER BY RAND()with- LIMIT:- SELECT * FROM table1, table2 WHERE a=b AND c<d ORDER BY RAND() LIMIT 1000;- RAND()is not meant to be a perfect random generator. It is a fast way to generate random numbers on demand that is portable between platforms for the same MySQL version.- This function is unsafe for statement-based replication. A warning is logged if you use this function when - binlog_formatis set to- STATEMENT.
- Rounds the argument - Xto- Ddecimal places. The rounding algorithm depends on the data type of- X.- Ddefaults to 0 if not specified.- Dcan be negative to cause- Ddigits left of the decimal point of the value- Xto become zero. The maximum absolute value for- Dis 30; any digits in excess of 30 (or -30) are truncated. If- Xor- Dis- NULL, the function returns- NULL.- 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); -> 20 mysql> SELECT ROUND(.12345678901234567890123456789012345, 35); -> 0.123456789012345678901234567890- The return value has the same type as 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): - mysql> SELECT ROUND(150.000,2), ROUND(150,2); +------------------+--------------+ | ROUND(150.000,2) | ROUND(150,2) | +------------------+--------------+ | 150.00 | 150 | +------------------+--------------+- ROUND()uses the following rules depending on the type of the first argument:- For exact-value numbers, - ROUND()uses the “round half away from zero” 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 a fractional part exactly halfway between two integers 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 Section 14.24, “Precision Math”. - The data type returned by - ROUND()(and- TRUNCATE()) is determined according to the rules listed here:- When the first argument is of any integer type, the return type is always - BIGINT.
- When the first argument is of any floating-point type or of any non-numeric type, the return type is always - DOUBLE.
- When the first argument is a - DECIMALvalue, the return type is also- DECIMAL.
- The type attributes for the return value are also copied from the first argument, except in the case of - DECIMAL, when the second argument is a constant value.- When the desired number of decimal places is less than the scale of the argument, the scale and the precision of the result are adjusted accordingly. - In addition, for - ROUND()(but not for the- TRUNCATE()function), the precision is extended by one place to accommodate rounding that increases the number of significant digits. If the second argument is negative, the return type is adjusted such that its scale is 0, with a corresponding precision. For example,- ROUND(99.999, 2)returns- 100.00—the first argument is- DECIMAL(5, 3), and the return type is- DECIMAL(5, 2).- If the second argument is negative, the return type has scale 0 and a corresponding precision; - ROUND(99.999, -1)returns- 100, which is- DECIMAL(3, 0).
 
- Returns the sign of the argument as - -1,- 0, or- 1, depending on whether- Xis negative, zero, or positive. Returns- NULLif- Xis- NULL.- mysql> SELECT SIGN(-32); -> -1 mysql> SELECT SIGN(0); -> 0 mysql> SELECT SIGN(234); -> 1
- Returns the sine of - X, where- Xis given in radians. Returns- NULLif- Xis- NULL.- mysql> SELECT SIN(PI()); -> 1.2246063538224e-16 mysql> SELECT ROUND(SIN(PI())); -> 0
- Returns the square root of a nonnegative number - X. If- Xis- NULL, the function returns- NULL.- mysql> SELECT SQRT(4); -> 2 mysql> SELECT SQRT(20); -> 4.4721359549996 mysql> SELECT SQRT(-16); -> NULL
- Returns the tangent of - X, where- Xis given in radians. Returns- NULLif- Xis- NULL.- mysql> SELECT TAN(PI()); -> -1.2246063538224e-16 mysql> SELECT TAN(PI()+1); -> 1.5574077246549
- Returns the number - X, truncated to- Ddecimal places. If- Dis- 0, the result has no decimal point or fractional part.- Dcan be negative to cause- Ddigits left of the decimal point of the value- Xto become zero. If- Xor- Dis- NULL, the function returns- NULL.- 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); -> 1028- All numbers are rounded toward zero. - The data type returned by - TRUNCATE()follows the same rules that determine the return type of the- ROUND()function; for details, see the description for- ROUND().