15 KiB
slug | sidebar_position | sidebar_label |
---|---|---|
/en/sql-reference/functions/arithmetic-functions | 5 | Arithmetic |
Arithmetic Functions
Arithmetic functions work for any two operands of type UInt8
, UInt16
, UInt32
, UInt64
, Int8
, Int16
, Int32
, Int64
, Float32
, or Float64
.
Before performing the operation, both operands are casted to the result type. The result type is determined as follows (unless specified differently in the function documentation below):
- If both operands are up to 32 bits wide, the size of the result type will be the size of the next bigger type following the bigger of the
two operands (integer size promotion). For example,
UInt8 + UInt16 = UInt32
orFloat32 * Float32 = Float64
. - If one of the operands has 64 or more bits, the size of the result type will be the same size as the bigger of the two operands. For
example,
UInt32 + UInt128 = UInt128
orFloat32 * Float64 = Float64
. - If one of the operands is signed, the result type will also be signed, otherwise it will be signed. For example,
UInt32 * Int32 = Int64
.
These rules make sure that the result type will be the smallest type which can represent all possible results. While this introduces a risk of overflows around the value range boundary, it ensures that calculations are performed quickly using the maximum native integer width of 64 bit. This behavior also guarantees compatibility with many other databases which provide 64 bit integers (BIGINT) as the biggest integer type.
Example:
SELECT toTypeName(0), toTypeName(0 + 0), toTypeName(0 + 0 + 0), toTypeName(0 + 0 + 0 + 0)
┌─toTypeName(0)─┬─toTypeName(plus(0, 0))─┬─toTypeName(plus(plus(0, 0), 0))─┬─toTypeName(plus(plus(plus(0, 0), 0), 0))─┐
│ UInt8 │ UInt16 │ UInt32 │ UInt64 │
└───────────────┴────────────────────────┴─────────────────────────────────┴──────────────────────────────────────────┘
Overflows are produced the same way as in C++.
plus
Calculates the sum of two values a
and b
.
Syntax
plus(a, b)
It is possible to add an integer and a date or date with time. The former operation increments the number of days in the date, the latter operation increments the number of seconds in the date with time.
Alias: a + b
(operator)
minus
Calculates the difference of two values a
and b
. The result is always signed.
Similar to plus
, it is possible to subtract an integer from a date or date with time.
Syntax
minus(a, b)
Alias: a - b
(operator)
multiply
Calculates the product of two values a
and b
.
Syntax
multiply(a, b)
Alias: a * b
(operator)
divide
Calculates the quotient of two values a
and b
. The result type is always Float64. Integer division is provided by the intDiv
function.
Division by 0 returns inf
, -inf
, or nan
.
Syntax
divide(a, b)
Alias: a / b
(operator)
intDiv
Performs an integer division of two values a
by b
, i.e. computes the quotient rounded down to the next smallest integer.
The result has the same width as the dividend (the first parameter).
An exception is thrown when dividing by zero, when the quotient does not fit in the range of the dividend, or when dividing a minimal negative number by minus one.
Syntax
intDiv(a, b)
Example
Query:
SELECT
intDiv(toFloat64(1), 0.001) AS res,
toTypeName(res)
┌──res─┬─toTypeName(intDiv(toFloat64(1), 0.001))─┐
│ 1000 │ Int64 │
└──────┴─────────────────────────────────────────┘
SELECT
intDiv(1, 0.001) AS res,
toTypeName(res)
Received exception from server (version 23.2.1):
Code: 153. DB::Exception: Received from localhost:9000. DB::Exception: Cannot perform integer division, because it will produce infinite or too large number: While processing intDiv(1, 0.001) AS res, toTypeName(res). (ILLEGAL_DIVISION)
intDivOrZero
Same as intDiv
but returns zero when dividing by zero or when dividing a minimal negative number by minus one.
Syntax
intDivOrZero(a, b)
modulo
Calculates the remainder of the division of two values a
by b
.
The result type is an integer if both inputs are integers. If one of the inputs is a floating-point number, the result type is Float64.
The remainder is computed like in C++. Truncated division is used for negative numbers.
An exception is thrown when dividing by zero or when dividing a minimal negative number by minus one.
Syntax
modulo(a, b)
Alias: a % b
(operator)
moduloOrZero
Like modulo but returns zero when the divisor is zero.
Syntax
moduloOrZero(a, b)
positiveModulo(a, b)
Like modulo but always returns a non-negative number.
This function is 4-5 times slower than modulo
.
Syntax
positiveModulo(a, b)
Alias:
positive_modulo(a, b)
pmod(a, b)
Example
Query:
SELECT positiveModulo(-1, 10)
Result:
┌─positiveModulo(-1, 10)─┐
│ 9 │
└────────────────────────┘
negate
Negates a value a
. The result is always signed.
Syntax
negate(a)
Alias: -a
abs
Calculates the absolute value of a
. Has no effect if a
is of an unsigned type. If a
is of a signed type, it returns an unsigned number.
Syntax
abs(a)
gcd
Returns the greatest common divisor of two values a
and b
.
An exception is thrown when dividing by zero or when dividing a minimal negative number by minus one.
Syntax
gcd(a, b)
lcm(a, b)
Returns the least common multiple of two values a
and b
.
An exception is thrown when dividing by zero or when dividing a minimal negative number by minus one.
Syntax
lcm(a, b)
max2
Returns the bigger of two values a
and b
. The returned value is of type Float64.
Syntax
max2(a, b)
Example
Query:
SELECT max2(-1, 2);
Result:
┌─max2(-1, 2)─┐
│ 2 │
└─────────────┘
min2
Returns the smaller of two values a
and b
. The returned value is of type Float64.
Syntax
min2(a, b)
Example
Query:
SELECT min2(-1, 2);
Result:
┌─min2(-1, 2)─┐
│ -1 │
└─────────────┘
multiplyDecimal
Multiplies two decimals a
and b
. The result value will be of type Decimal256.
The scale of the result can be explicitly specified by result_scale
. If result_scale
is not specified, it is assumed to be the maximum scale of the input values.
This function work significantly slower than usual multiply
. In case no control over the result precision is needed and/or fast computation is desired, consider using multiply
.
Syntax
multiplyDecimal(a, b[, result_scale])
Arguments
Returned value
- The result of multiplication with given scale. Decimal256.
Example
┌─multiplyDecimal(toDecimal256(-12, 0), toDecimal32(-2.1, 1), 1)─┐
│ 25.2 │
└────────────────────────────────────────────────────────────────┘
Differences compared to regular multiplication:
SELECT toDecimal64(-12.647, 3) * toDecimal32(2.1239, 4);
SELECT toDecimal64(-12.647, 3) as a, toDecimal32(2.1239, 4) as b, multiplyDecimal(a, b);
Result:
┌─multiply(toDecimal64(-12.647, 3), toDecimal32(2.1239, 4))─┐
│ -26.8609633 │
└───────────────────────────────────────────────────────────┘
┌───────a─┬──────b─┬─multiplyDecimal(toDecimal64(-12.647, 3), toDecimal32(2.1239, 4))─┐
│ -12.647 │ 2.1239 │ -26.8609 │
└─────────┴────────┴──────────────────────────────────────────────────────────────────┘
SELECT
toDecimal64(-12.647987876, 9) AS a,
toDecimal64(123.967645643, 9) AS b,
multiplyDecimal(a, b);
SELECT
toDecimal64(-12.647987876, 9) AS a,
toDecimal64(123.967645643, 9) AS b,
a * b;
Result:
┌─────────────a─┬─────────────b─┬─multiplyDecimal(toDecimal64(-12.647987876, 9), toDecimal64(123.967645643, 9))─┐
│ -12.647987876 │ 123.967645643 │ -1567.941279108 │
└───────────────┴───────────────┴───────────────────────────────────────────────────────────────────────────────┘
Received exception from server (version 22.11.1):
Code: 407. DB::Exception: Received from localhost:9000. DB::Exception: Decimal math overflow: While processing toDecimal64(-12.647987876, 9) AS a, toDecimal64(123.967645643, 9) AS b, a * b. (DECIMAL_OVERFLOW)
divideDecimal
Divides two decimals a
and b
. The result value will be of type Decimal256.
The scale of the result can be explicitly specified by result_scale
. If result_scale
is not specified, it is assumed to be the maximum scale of the input values.
This function work significantly slower than usual divide
. In case no control over the result precision is needed and/or fast computation is desired, consider using divide
.
Syntax
divideDecimal(a, b[, result_scale])
Arguments
Returned value
- The result of division with given scale. Decimal256.
Example
┌─divideDecimal(toDecimal256(-12, 0), toDecimal32(2.1, 1), 10)─┐
│ -5.7142857142 │
└──────────────────────────────────────────────────────────────┘
Differences compared to regular division:
SELECT toDecimal64(-12, 1) / toDecimal32(2.1, 1);
SELECT toDecimal64(-12, 1) as a, toDecimal32(2.1, 1) as b, divideDecimal(a, b, 1), divideDecimal(a, b, 5);
Result:
┌─divide(toDecimal64(-12, 1), toDecimal32(2.1, 1))─┐
│ -5.7 │
└──────────────────────────────────────────────────┘
┌───a─┬───b─┬─divideDecimal(toDecimal64(-12, 1), toDecimal32(2.1, 1), 1)─┬─divideDecimal(toDecimal64(-12, 1), toDecimal32(2.1, 1), 5)─┐
│ -12 │ 2.1 │ -5.7 │ -5.71428 │
└─────┴─────┴────────────────────────────────────────────────────────────┴────────────────────────────────────────────────────────────┘
SELECT toDecimal64(-12, 0) / toDecimal32(2.1, 1);
SELECT toDecimal64(-12, 0) as a, toDecimal32(2.1, 1) as b, divideDecimal(a, b, 1), divideDecimal(a, b, 5);
Result:
DB::Exception: Decimal result's scale is less than argument's one: While processing toDecimal64(-12, 0) / toDecimal32(2.1, 1). (ARGUMENT_OUT_OF_BOUND)
┌───a─┬───b─┬─divideDecimal(toDecimal64(-12, 0), toDecimal32(2.1, 1), 1)─┬─divideDecimal(toDecimal64(-12, 0), toDecimal32(2.1, 1), 5)─┐
│ -12 │ 2.1 │ -5.7 │ -5.71428 │
└─────┴─────┴────────────────────────────────────────────────────────────┴────────────────────────────────────────────────────────────┘
byteSwap
Reverses the bytes of an integer, i.e. changes its endianness.
Syntax
byteSwap(a)
Example
byteSwap(3351772109)
Result:
┌─byteSwap(3351772109)─┐
│ 3455829959 │
└──────────────────────┘
The above example can be worked out in the following manner:
- Convert the base-10 integer to its equivalent hexadecimal format in big-endian format, i.e. 3351772109 -> C7 C7 FB CD (4 bytes)
- Reverse the bytes, i.e. C7 C7 FB CD -> CD FB C7 C7
- Convert the result back to an integer assuming big-endian, i.e. CD FB C7 C7 -> 3455829959
One use case of this function is reversing IPv4s:
┌─toIPv4(byteSwap(toUInt32(toIPv4('205.251.199.199'))))─┐
│ 199.199.251.205 │
└───────────────────────────────────────────────────────┘