ClickHouse/docs/en/sql-reference/functions/arithmetic-functions.md

Ignoring revisions in .git-blame-ignore-revs. Click here to bypass and see the normal blame view.

346 lines
14 KiB
Markdown
Raw Normal View History

2020-04-03 13:23:32 +00:00
---
2022-08-28 14:53:34 +00:00
slug: /en/sql-reference/functions/arithmetic-functions
sidebar_position: 34
sidebar_label: Arithmetic
2020-04-03 13:23:32 +00:00
---
2022-06-02 10:55:18 +00:00
# Arithmetic Functions
For all arithmetic functions, the result type is calculated as the smallest number type that the result fits in, if there is such a type. The minimum is taken simultaneously based on the number of bits, whether it is signed, and whether it floats. If there are not enough bits, the highest bit type is taken.
Example:
2020-03-20 10:10:48 +00:00
``` sql
SELECT toTypeName(0), toTypeName(0 + 0), toTypeName(0 + 0 + 0), toTypeName(0 + 0 + 0 + 0)
```
2020-03-20 10:10:48 +00:00
``` text
┌─toTypeName(0)─┬─toTypeName(plus(0, 0))─┬─toTypeName(plus(plus(0, 0), 0))─┬─toTypeName(plus(plus(plus(0, 0), 0), 0))─┐
│ UInt8 │ UInt16 │ UInt32 │ UInt64 │
└───────────────┴────────────────────────┴─────────────────────────────────┴──────────────────────────────────────────┘
```
Arithmetic functions work for any pair of types from UInt8, UInt16, UInt32, UInt64, Int8, Int16, Int32, Int64, Float32, or Float64.
Overflow is produced the same way as in C++.
2022-06-02 10:55:18 +00:00
## plus(a, b), a + b operator
Calculates the sum of the numbers.
You can also add integer numbers with a date or date and time. In the case of a date, adding an integer means adding the corresponding number of days. For a date with time, it means adding the corresponding number of seconds.
2022-06-02 10:55:18 +00:00
## minus(a, b), a - b operator
Calculates the difference. The result is always signed.
2020-03-20 10:10:48 +00:00
You can also calculate integer numbers from a date or date with time. The idea is the same see above for plus.
2022-06-02 10:55:18 +00:00
## multiply(a, b), a \* b operator
Calculates the product of the numbers.
2022-06-02 10:55:18 +00:00
## divide(a, b), a / b operator
Calculates the quotient of the numbers. The result type is always a floating-point type.
2020-03-20 10:10:48 +00:00
It is not integer division. For integer division, use the intDiv function.
When dividing by zero you get inf, -inf, or nan.
2022-06-02 10:55:18 +00:00
## intDiv(a, b)
Calculates the quotient of the numbers. Divides into integers, rounding down (by the absolute value).
Returns an integer of the type of 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.
**Example**
Query:
```sql
SELECT
intDiv(toFloat64(1), 0.001) AS res,
toTypeName(res)
```
```response
┌──res─┬─toTypeName(intDiv(toFloat64(1), 0.001))─┐
│ 1000 │ Int64 │
└──────┴─────────────────────────────────────────┘
```
```sql
SELECT
intDiv(1, 0.001) AS res,
toTypeName(res)
```
```response
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)
```
2022-06-02 10:55:18 +00:00
## intDivOrZero(a, b)
2020-03-20 10:10:48 +00:00
Differs from intDiv in that it returns zero when dividing by zero or when dividing a minimal negative number by minus one.
2022-06-02 10:55:18 +00:00
## modulo(a, b), a % b operator
Calculates the remainder when dividing `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 is a floating-point number.
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.
2022-06-02 10:55:18 +00:00
## moduloOrZero(a, b)
2020-02-25 10:15:24 +00:00
Differs from [modulo](#modulo) in that it returns zero when the divisor is zero.
2020-02-25 10:15:24 +00:00
2023-01-05 16:10:20 +00:00
## positiveModulo(a, b), positive_modulo(a, b), pmod(a, b)
Calculates the remainder when dividing `a` by `b`. Similar to the function `modulo` except that `positive_modulo` always returns a non-negative number.
2023-01-05 16:10:20 +00:00
Notice that `positive_modulo` is 4-5 times slower than `modulo`. You should not use `positive_modulo` unless you want to get a positive result and don't care about performance too much.
**Example**
Query:
```sql
SELECT positiveModulo(-1, 10)
```
Result:
```text
┌─positiveModulo(-1, 10)─┐
│ 9 │
└────────────────────────┘
```
2022-06-02 10:55:18 +00:00
## negate(a), -a operator
Calculates a number with the reverse sign. The result is always signed.
2022-06-02 10:55:18 +00:00
## abs(a)
2021-05-27 19:44:11 +00:00
Calculates the absolute value of the number (a). That is, if a \< 0, it returns -a. For unsigned types it does not do anything. For signed integer types, it returns an unsigned number.
2022-06-02 10:55:18 +00:00
## gcd(a, b)
Returns the greatest common divisor of the numbers.
An exception is thrown when dividing by zero or when dividing a minimal negative number by minus one.
2022-06-02 10:55:18 +00:00
## lcm(a, b)
Returns the least common multiple of the numbers.
An exception is thrown when dividing by zero or when dividing a minimal negative number by minus one.
2022-06-02 10:55:18 +00:00
## max2
2021-10-19 22:42:05 +00:00
Compares two values and returns the maximum. The returned value is converted to [Float64](../../sql-reference/data-types/float.md).
**Syntax**
```sql
max2(value1, value2)
```
**Arguments**
- `value1` — First value. [Int/UInt](../../sql-reference/data-types/int-uint.md) or [Float](../../sql-reference/data-types/float.md).
- `value2` — Second value. [Int/UInt](../../sql-reference/data-types/int-uint.md) or [Float](../../sql-reference/data-types/float.md).
**Returned value**
2021-10-19 23:00:54 +00:00
- The maximum of two values.
2021-10-19 22:42:05 +00:00
Type: [Float](../../sql-reference/data-types/float.md).
**Example**
Query:
```sql
SELECT max2(-1, 2);
```
Result:
```text
┌─max2(-1, 2)─┐
│ 2 │
└─────────────┘
```
2022-06-02 10:55:18 +00:00
## min2
2021-10-19 22:42:05 +00:00
Compares two values and returns the minimum. The returned value is converted to [Float64](../../sql-reference/data-types/float.md).
**Syntax**
```sql
2023-02-11 11:58:39 +00:00
min2(value1, value2)
2021-10-19 22:42:05 +00:00
```
**Arguments**
- `value1` — First value. [Int/UInt](../../sql-reference/data-types/int-uint.md) or [Float](../../sql-reference/data-types/float.md).
- `value2` — Second value. [Int/UInt](../../sql-reference/data-types/int-uint.md) or [Float](../../sql-reference/data-types/float.md).
**Returned value**
2021-10-19 23:00:54 +00:00
- The minimum of two values.
2021-10-19 22:42:05 +00:00
Type: [Float](../../sql-reference/data-types/float.md).
**Example**
Query:
```sql
2021-10-22 14:56:10 +00:00
SELECT min2(-1, 2);
2021-10-19 22:42:05 +00:00
```
Result:
```text
2021-10-22 14:56:10 +00:00
┌─min2(-1, 2)─┐
│ -1 │
2021-10-19 22:42:05 +00:00
└─────────────┘
```
2022-10-19 10:55:24 +00:00
## multiplyDecimal(a, b[, result_scale])
2022-11-23 22:23:59 +00:00
Performs multiplication on two decimals. Result value will be of type [Decimal256](../../sql-reference/data-types/decimal.md).
Result scale can be explicitly specified by `result_scale` argument (const Integer in range `[0, 76]`). If not specified, the result scale is the max scale of given arguments.
2022-10-19 10:55:24 +00:00
2022-11-01 13:40:26 +00:00
:::note
2022-11-23 22:23:59 +00:00
These functions work significantly slower than usual `multiply`.
In case you don't really need controlled precision and/or need fast computation, consider using [multiply](#multiply)
2022-11-01 13:40:26 +00:00
:::
2022-10-19 10:55:24 +00:00
**Syntax**
```sql
multiplyDecimal(a, b[, result_scale])
2022-11-23 22:23:59 +00:00
```
**Arguments**
- `a` — First value: [Decimal](../../sql-reference/data-types/decimal.md).
- `b` — Second value: [Decimal](../../sql-reference/data-types/decimal.md).
- `result_scale` — Scale of result: [Int/UInt](../../sql-reference/data-types/int-uint.md).
**Returned value**
- The result of multiplication with given scale.
Type: [Decimal256](../../sql-reference/data-types/decimal.md).
**Example**
```text
┌─multiplyDecimal(toDecimal256(-12, 0), toDecimal32(-2.1, 1), 1)─┐
│ 25.2 │
└────────────────────────────────────────────────────────────────┘
```
**Difference from regular multiplication:**
```sql
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);
```
```text
┌─multiply(toDecimal64(-12.647, 3), toDecimal32(2.1239, 4))─┐
│ -26.8609633 │
└───────────────────────────────────────────────────────────┘
┌─multiplyDecimal(toDecimal64(-12.647, 3), toDecimal32(2.1239, 4))─┐
│ -26.8609 │
└──────────────────────────────────────────────────────────────────┘
```
```sql
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;
```
```text
┌─────────────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(a, b[, result_scale])
Performs division on two decimals. Result value will be of type [Decimal256](../../sql-reference/data-types/decimal.md).
Result scale can be explicitly specified by `result_scale` argument (const Integer in range `[0, 76]`). If not specified, the result scale is the max scale of given arguments.
:::note
These function work significantly slower than usual `divide`.
In case you don't really need controlled precision and/or need fast computation, consider using [divide](#divide).
:::
**Syntax**
```sql
2022-10-19 10:55:24 +00:00
divideDecimal(a, b[, result_scale])
```
**Arguments**
- `a` — First value: [Decimal](../../sql-reference/data-types/decimal.md).
- `b` — Second value: [Decimal](../../sql-reference/data-types/decimal.md).
- `result_scale` — Scale of result: [Int/UInt](../../sql-reference/data-types/int-uint.md).
**Returned value**
2022-11-23 22:23:59 +00:00
- The result of division with given scale.
2022-10-19 10:55:24 +00:00
Type: [Decimal256](../../sql-reference/data-types/decimal.md).
**Example**
```text
┌─divideDecimal(toDecimal256(-12, 0), toDecimal32(2.1, 1), 10)─┐
│ -5.7142857142 │
└──────────────────────────────────────────────────────────────┘
```
2022-11-22 14:30:44 +00:00
2022-11-23 22:23:59 +00:00
**Difference from regular division:**
2022-11-22 14:30:44 +00:00
```sql
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);
```
```text
┌─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 │
└─────┴─────┴────────────────────────────────────────────────────────────┴────────────────────────────────────────────────────────────┘
```
```sql
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);
```
```text
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 │
└─────┴─────┴────────────────────────────────────────────────────────────┴────────────────────────────────────────────────────────────┘
```