[doc] add doc for array func.

Signed-off-by: clundro <859287553@qq.com>
This commit is contained in:
clundro 2023-04-18 02:10:41 +08:00 committed by cluster
parent f5e07f84ff
commit 0ecb766de6

View File

@ -18,7 +18,7 @@ empty([x])
An array is considered empty if it does not contain any elements.
:::note
:::note
Can be optimized by enabling the [optimize_functions_to_subcolumns](../../operations/settings/settings.md#optimize-functions-to-subcolumns) setting. With `optimize_functions_to_subcolumns = 1` the function reads only [size0](../../sql-reference/data-types/array.md#array-size) subcolumn instead of reading and processing the whole array column. The query `SELECT empty(arr) FROM TABLE;` transforms to `SELECT arr.size0 = 0 FROM TABLE;`.
:::
@ -26,11 +26,11 @@ The function also works for [strings](string-functions.md#empty) or [UUID](uuid-
**Arguments**
- `[x]` — Input array. [Array](../data-types/array.md).
- `[x]` — Input array. [Array](../data-types/array.md).
**Returned value**
- Returns `1` for an empty array or `0` for a non-empty array.
- Returns `1` for an empty array or `0` for a non-empty array.
Type: [UInt8](../data-types/int-uint.md).
@ -62,7 +62,7 @@ notEmpty([x])
An array is considered non-empty if it contains at least one element.
:::note
:::note
Can be optimized by enabling the [optimize_functions_to_subcolumns](../../operations/settings/settings.md#optimize-functions-to-subcolumns) setting. With `optimize_functions_to_subcolumns = 1` the function reads only [size0](../../sql-reference/data-types/array.md#array-size) subcolumn instead of reading and processing the whole array column. The query `SELECT notEmpty(arr) FROM table` transforms to `SELECT arr.size0 != 0 FROM TABLE`.
:::
@ -70,11 +70,11 @@ The function also works for [strings](string-functions.md#notempty) or [UUID](uu
**Arguments**
- `[x]` — Input array. [Array](../data-types/array.md).
- `[x]` — Input array. [Array](../data-types/array.md).
**Returned value**
- Returns `1` for a non-empty array or `0` for an empty array.
- Returns `1` for a non-empty array or `0` for an empty array.
Type: [UInt8](../data-types/int-uint.md).
@ -118,38 +118,41 @@ Accepts zero arguments and returns an empty array of the appropriate type.
Accepts an empty array and returns a one-element array that is equal to the default value.
## range(end), range(\[start, \] end \[, step\])
Returns an array of numbers from `start` to `end - 1` by `step`. The supported types are [UInt8, UInt16, UInt32, UInt64, Int8, Int16, Int32, Int64](../data-types/int-uint.md).
**Syntax**
``` sql
range([start, ] end [, step])
```
**Arguments**
- `start` — The first element of the array. Optional, required if `step` is used. Default value: 0.
- `end` — The number before which the array is constructed. Required.
- `step` — Determines the incremental step between each element in the array. Optional. Default value: 1.
- `start` — The first element of the array. Optional, required if `step` is used. Default value: 0.
- `end` — The number before which the array is constructed. Required.
- `step` — Determines the incremental step between each element in the array. Optional. Default value: 1.
**Returned value**
- Array of numbers from `start` to `end - 1` by `step`.
- Array of numbers from `start` to `end - 1` by `step`.
**Implementation details**
- All arguments `start`, `end`, `step` must be below data types: `UInt8`, `UInt16`, `UInt32`, `UInt64`,`Int8`, `Int16`, `Int32`, `Int64`, as well as elements of the returned array, which's type is a super type of all arguments's.
- An exception is thrown if query results in arrays with a total length of more than number of elements specified by the [function_range_max_elements_in_block](../../operations/settings/settings.md#settings-function_range_max_elements_in_block) setting.
- All arguments `start`, `end`, `step` must be below data types: `UInt8`, `UInt16`, `UInt32`, `UInt64`,`Int8`, `Int16`, `Int32`, `Int64`, as well as elements of the returned array, which's type is a super type of all arguments's.
- An exception is thrown if query results in arrays with a total length of more than number of elements specified by the [function_range_max_elements_in_block](../../operations/settings/settings.md#settings-function_range_max_elements_in_block) setting.
**Examples**
Query:
``` sql
SELECT range(5), range(1, 5), range(1, 5, 2), range(-1, 5, 2);
```
Result:
```txt
┌─range(5)────┬─range(1, 5)─┬─range(1, 5, 2)─┬─range(-1, 5, 2)─┐
│ [0,1,2,3,4] │ [1,2,3,4] │ [1,3] │ [-1,1,3] │
@ -176,7 +179,7 @@ arrayConcat(arrays)
**Arguments**
- `arrays` Arbitrary number of arguments of [Array](../../sql-reference/data-types/array.md) type.
- `arrays` Arbitrary number of arguments of [Array](../../sql-reference/data-types/array.md) type.
**Example**
<!-- -->
@ -226,19 +229,19 @@ hasAll(set, subset)
**Arguments**
- `set` Array of any type with a set of elements.
- `subset` Array of any type with elements that should be tested to be a subset of `set`.
- `set` Array of any type with a set of elements.
- `subset` Array of any type with elements that should be tested to be a subset of `set`.
**Return values**
- `1`, if `set` contains all of the elements from `subset`.
- `0`, otherwise.
- `1`, if `set` contains all of the elements from `subset`.
- `0`, otherwise.
**Peculiar properties**
- An empty array is a subset of any array.
- `Null` processed as a value.
- Order of values in both of arrays does not matter.
- An empty array is a subset of any array.
- `Null` processed as a value.
- Order of values in both of arrays does not matter.
**Examples**
@ -264,18 +267,18 @@ hasAny(array1, array2)
**Arguments**
- `array1` Array of any type with a set of elements.
- `array2` Array of any type with a set of elements.
- `array1` Array of any type with a set of elements.
- `array2` Array of any type with a set of elements.
**Return values**
- `1`, if `array1` and `array2` have one similar element at least.
- `0`, otherwise.
- `1`, if `array1` and `array2` have one similar element at least.
- `0`, otherwise.
**Peculiar properties**
- `Null` processed as a value.
- Order of values in both of arrays does not matter.
- `Null` processed as a value.
- Order of values in both of arrays does not matter.
**Examples**
@ -301,24 +304,25 @@ In other words, the functions will check whether all the elements of `array2` ar
the `hasAll` function. In addition, it will check that the elements are observed in the same order in both `array1` and `array2`.
For Example:
- `hasSubstr([1,2,3,4], [2,3])` returns 1. However, `hasSubstr([1,2,3,4], [3,2])` will return `0`.
- `hasSubstr([1,2,3,4], [1,2,3])` returns 1. However, `hasSubstr([1,2,3,4], [1,2,4])` will return `0`.
**Arguments**
- `array1` Array of any type with a set of elements.
- `array2` Array of any type with a set of elements.
- `array1` Array of any type with a set of elements.
- `array2` Array of any type with a set of elements.
**Return values**
- `1`, if `array1` contains `array2`.
- `0`, otherwise.
- `1`, if `array1` contains `array2`.
- `0`, otherwise.
**Peculiar properties**
- The function will return `1` if `array2` is empty.
- `Null` processed as a value. In other words `hasSubstr([1, 2, NULL, 3, 4], [2,3])` will return `0`. However, `hasSubstr([1, 2, NULL, 3, 4], [2,NULL,3])` will return `1`
- Order of values in both of arrays does matter.
- The function will return `1` if `array2` is empty.
- `Null` processed as a value. In other words `hasSubstr([1, 2, NULL, 3, 4], [2,3])` will return `0`. However, `hasSubstr([1, 2, NULL, 3, 4], [2,NULL,3])` will return `1`
- Order of values in both of arrays does matter.
**Examples**
@ -484,7 +488,7 @@ arrayPopBack(array)
**Arguments**
- `array` Array.
- `array` Array.
**Example**
@ -508,7 +512,7 @@ arrayPopFront(array)
**Arguments**
- `array` Array.
- `array` Array.
**Example**
@ -532,8 +536,8 @@ arrayPushBack(array, single_value)
**Arguments**
- `array` Array.
- `single_value` A single value. Only numbers can be added to an array with numbers, and only strings can be added to an array of strings. When adding numbers, ClickHouse automatically sets the `single_value` type for the data type of the array. For more information about the types of data in ClickHouse, see “[Data types](../../sql-reference/data-types/index.md#data_types)”. Can be `NULL`. The function adds a `NULL` element to an array, and the type of array elements converts to `Nullable`.
- `array` Array.
- `single_value` A single value. Only numbers can be added to an array with numbers, and only strings can be added to an array of strings. When adding numbers, ClickHouse automatically sets the `single_value` type for the data type of the array. For more information about the types of data in ClickHouse, see “[Data types](../../sql-reference/data-types/index.md#data_types)”. Can be `NULL`. The function adds a `NULL` element to an array, and the type of array elements converts to `Nullable`.
**Example**
@ -557,8 +561,8 @@ arrayPushFront(array, single_value)
**Arguments**
- `array` Array.
- `single_value` A single value. Only numbers can be added to an array with numbers, and only strings can be added to an array of strings. When adding numbers, ClickHouse automatically sets the `single_value` type for the data type of the array. For more information about the types of data in ClickHouse, see “[Data types](../../sql-reference/data-types/index.md#data_types)”. Can be `NULL`. The function adds a `NULL` element to an array, and the type of array elements converts to `Nullable`.
- `array` Array.
- `single_value` A single value. Only numbers can be added to an array with numbers, and only strings can be added to an array of strings. When adding numbers, ClickHouse automatically sets the `single_value` type for the data type of the array. For more information about the types of data in ClickHouse, see “[Data types](../../sql-reference/data-types/index.md#data_types)”. Can be `NULL`. The function adds a `NULL` element to an array, and the type of array elements converts to `Nullable`.
**Example**
@ -582,11 +586,11 @@ arrayResize(array, size[, extender])
**Arguments:**
- `array` — Array.
- `size` — Required length of the array.
- If `size` is less than the original size of the array, the array is truncated from the right.
- If `size` is larger than the initial size of the array, the array is extended to the right with `extender` values or default values for the data type of the array items.
- `extender` — Value for extending an array. Can be `NULL`.
- `array` — Array.
- `size` — Required length of the array.
- If `size` is less than the original size of the array, the array is truncated from the right.
- If `size` is larger than the initial size of the array, the array is extended to the right with `extender` values or default values for the data type of the array items.
- `extender` — Value for extending an array. Can be `NULL`.
**Returned value:**
@ -682,10 +686,10 @@ SELECT arraySort([1, nan, 2, NULL, 3, nan, -4, NULL, inf, -inf]);
└───────────────────────────────────────────────────────────┘
```
- `-Inf` values are first in the array.
- `NULL` values are last in the array.
- `NaN` values are right before `NULL`.
- `Inf` values are right before `NaN`.
- `-Inf` values are first in the array.
- `NULL` values are last in the array.
- `NaN` values are right before `NULL`.
- `Inf` values are right before `NaN`.
Note that `arraySort` is a [higher-order function](../../sql-reference/functions/index.md#higher-order-functions). You can pass a lambda function to it as the first argument. In this case, sorting order is determined by the result of the lambda function applied to the elements of the array.
@ -739,7 +743,7 @@ SELECT arraySort((x, y) -> -y, [0, 1, 2], [1, 2, 3]) as res;
└─────────┘
```
:::note
:::note
To improve sorting efficiency, the [Schwartzian transform](https://en.wikipedia.org/wiki/Schwartzian_transform) is used.
:::
@ -783,10 +787,10 @@ SELECT arrayReverseSort([1, nan, 2, NULL, 3, nan, -4, NULL, inf, -inf]) as res;
└───────────────────────────────────────┘
```
- `Inf` values are first in the array.
- `NULL` values are last in the array.
- `NaN` values are right before `NULL`.
- `-Inf` values are right before `NaN`.
- `Inf` values are first in the array.
- `NULL` values are last in the array.
- `NaN` values are right before `NULL`.
- `-Inf` values are right before `NaN`.
Note that the `arrayReverseSort` is a [higher-order function](../../sql-reference/functions/index.md#higher-order-functions). You can pass a lambda function to it as the first argument. Example is shown below.
@ -802,8 +806,8 @@ SELECT arrayReverseSort((x) -> -x, [1, 2, 3]) as res;
The array is sorted in the following way:
1. At first, the source array (\[1, 2, 3\]) is sorted according to the result of the lambda function applied to the elements of the array. The result is an array \[3, 2, 1\].
2. Array that is obtained on the previous step, is reversed. So, the final result is \[1, 2, 3\].
1. At first, the source array (\[1, 2, 3\]) is sorted according to the result of the lambda function applied to the elements of the array. The result is an array \[3, 2, 1\].
2. Array that is obtained on the previous step, is reversed. So, the final result is \[1, 2, 3\].
The lambda function can accept multiple arguments. In this case, you need to pass the `arrayReverseSort` function several arrays of identical length that the arguments of lambda function will correspond to. The resulting array will consist of elements from the first input array; elements from the next input array(s) specify the sorting keys. For example:
@ -819,8 +823,8 @@ SELECT arrayReverseSort((x, y) -> y, ['hello', 'world'], [2, 1]) as res;
In this example, the array is sorted in the following way:
1. At first, the source array (\[hello, world\]) is sorted according to the result of the lambda function applied to the elements of the arrays. The elements that are passed in the second array (\[2, 1\]), define the sorting keys for corresponding elements from the source array. The result is an array \[world, hello\].
2. Array that was sorted on the previous step, is reversed. So, the final result is \[hello, world\].
1. At first, the source array (\[hello, world\]) is sorted according to the result of the lambda function applied to the elements of the arrays. The elements that are passed in the second array (\[2, 1\]), define the sorting keys for corresponding elements from the source array. The result is an array \[world, hello\].
2. Array that was sorted on the previous step, is reversed. So, the final result is \[hello, world\].
Other examples are shown below.
@ -867,7 +871,7 @@ arrayDifference(array)
**Arguments**
- `array` [Array](https://clickhouse.com/docs/en/data_types/array/).
- `array` [Array](https://clickhouse.com/docs/en/data_types/array/).
**Returned values**
@ -919,7 +923,7 @@ arrayDistinct(array)
**Arguments**
- `array` [Array](https://clickhouse.com/docs/en/data_types/array/).
- `array` [Array](https://clickhouse.com/docs/en/data_types/array/).
**Returned values**
@ -987,8 +991,8 @@ arrayReduce(agg_func, arr1, arr2, ..., arrN)
**Arguments**
- `agg_func` — The name of an aggregate function which should be a constant [string](../../sql-reference/data-types/string.md).
- `arr` — Any number of [array](../../sql-reference/data-types/array.md) type columns as the parameters of the aggregation function.
- `agg_func` — The name of an aggregate function which should be a constant [string](../../sql-reference/data-types/string.md).
- `arr` — Any number of [array](../../sql-reference/data-types/array.md) type columns as the parameters of the aggregation function.
**Returned value**
@ -1052,13 +1056,13 @@ arrayReduceInRanges(agg_func, ranges, arr1, arr2, ..., arrN)
**Arguments**
- `agg_func` — The name of an aggregate function which should be a constant [string](../../sql-reference/data-types/string.md).
- `ranges` — The ranges to aggretate which should be an [array](../../sql-reference/data-types/array.md) of [tuples](../../sql-reference/data-types/tuple.md) which containing the index and the length of each range.
- `arr` — Any number of [Array](../../sql-reference/data-types/array.md) type columns as the parameters of the aggregation function.
- `agg_func` — The name of an aggregate function which should be a constant [string](../../sql-reference/data-types/string.md).
- `ranges` — The ranges to aggretate which should be an [array](../../sql-reference/data-types/array.md) of [tuples](../../sql-reference/data-types/tuple.md) which containing the index and the length of each range.
- `arr` — Any number of [Array](../../sql-reference/data-types/array.md) type columns as the parameters of the aggregation function.
**Returned value**
- Array containing results of the aggregate function over specified ranges.
- Array containing results of the aggregate function over specified ranges.
Type: [Array](../../sql-reference/data-types/array.md).
@ -1108,8 +1112,8 @@ Converts an array of arrays to a flat array.
Function:
- Applies to any depth of nested arrays.
- Does not change arrays that are already flat.
- Applies to any depth of nested arrays.
- Does not change arrays that are already flat.
The flattened array contains all the elements from all source arrays.
@ -1123,7 +1127,7 @@ Alias: `flatten`.
**Arguments**
- `array_of_arrays` — [Array](../../sql-reference/data-types/array.md) of arrays. For example, `[[1,2,3], [4,5]]`.
- `array_of_arrays` — [Array](../../sql-reference/data-types/array.md) of arrays. For example, `[[1,2,3], [4,5]]`.
**Examples**
@ -1185,13 +1189,13 @@ arrayZip(arr1, arr2, ..., arrN)
**Arguments**
- `arrN` — [Array](../../sql-reference/data-types/array.md).
- `arrN` — [Array](../../sql-reference/data-types/array.md).
The function can take any number of arrays of different types. All the input arrays must be of equal size.
**Returned value**
- Array with elements from the source arrays grouped into [tuples](../../sql-reference/data-types/tuple.md). Data types in the tuple are the same as types of the input arrays and in the same order as arrays are passed.
- Array with elements from the source arrays grouped into [tuples](../../sql-reference/data-types/tuple.md). Data types in the tuple are the same as types of the input arrays and in the same order as arrays are passed.
Type: [Array](../../sql-reference/data-types/array.md).
@ -1213,7 +1217,7 @@ Result:
## arrayAUC
Calculate AUC (Area Under the Curve, which is a concept in machine learning, see more details: https://en.wikipedia.org/wiki/Receiver_operating_characteristic#Area_under_the_curve).
Calculate AUC (Area Under the Curve, which is a concept in machine learning, see more details: <https://en.wikipedia.org/wiki/Receiver_operating_characteristic#Area_under_the_curve>).
**Syntax**
@ -1433,12 +1437,12 @@ arrayMin([func,] arr)
**Arguments**
- `func` — Function. [Expression](../../sql-reference/data-types/special-data-types/expression.md).
- `arr` — Array. [Array](../../sql-reference/data-types/array.md).
- `func` — Function. [Expression](../../sql-reference/data-types/special-data-types/expression.md).
- `arr` — Array. [Array](../../sql-reference/data-types/array.md).
**Returned value**
- The minimum of function values (or the array minimum).
- The minimum of function values (or the array minimum).
Type: if `func` is specified, matches `func` return value type, else matches the array elements type.
@ -1488,12 +1492,12 @@ arrayMax([func,] arr)
**Arguments**
- `func` — Function. [Expression](../../sql-reference/data-types/special-data-types/expression.md).
- `arr` — Array. [Array](../../sql-reference/data-types/array.md).
- `func` — Function. [Expression](../../sql-reference/data-types/special-data-types/expression.md).
- `arr` — Array. [Array](../../sql-reference/data-types/array.md).
**Returned value**
- The maximum of function values (or the array maximum).
- The maximum of function values (or the array maximum).
Type: if `func` is specified, matches `func` return value type, else matches the array elements type.
@ -1543,12 +1547,12 @@ arraySum([func,] arr)
**Arguments**
- `func` — Function. [Expression](../../sql-reference/data-types/special-data-types/expression.md).
- `arr` — Array. [Array](../../sql-reference/data-types/array.md).
- `func` — Function. [Expression](../../sql-reference/data-types/special-data-types/expression.md).
- `arr` — Array. [Array](../../sql-reference/data-types/array.md).
**Returned value**
- The sum of the function values (or the array sum).
- The sum of the function values (or the array sum).
Type: for decimal numbers in source array (or for converted values, if `func` is specified) — [Decimal128](../../sql-reference/data-types/decimal.md), for floating point numbers — [Float64](../../sql-reference/data-types/float.md), for numeric unsigned — [UInt64](../../sql-reference/data-types/int-uint.md), and for numeric signed — [Int64](../../sql-reference/data-types/int-uint.md).
@ -1598,12 +1602,12 @@ arrayAvg([func,] arr)
**Arguments**
- `func` — Function. [Expression](../../sql-reference/data-types/special-data-types/expression.md).
- `arr` — Array. [Array](../../sql-reference/data-types/array.md).
- `func` — Function. [Expression](../../sql-reference/data-types/special-data-types/expression.md).
- `arr` — Array. [Array](../../sql-reference/data-types/array.md).
**Returned value**
- The average of function values (or the array average).
- The average of function values (or the array average).
Type: [Float64](../../sql-reference/data-types/float.md).
@ -1641,6 +1645,22 @@ Result:
Returns an array of partial sums of elements in the source array (a running sum). If the `func` function is specified, then the values of the array elements are converted by `func(arr1[i], …, arrN[i])` before summing.
**Syntax**
``` sql
arrayCumSum(arr)
```
**Arguments**
- `arr` — [Array](../../sql-reference/data-types/array.md) of numeric values.
**Returned value**
- Returns an array of partial sums of elements in the source array.
Type: [UInt\*](https://clickhouse.com/docs/en/data_types/int_uint/#uint-ranges), [Int\*](https://clickhouse.com/docs/en/data_types/int_uint/#int-ranges), [Float\*](https://clickhouse.com/docs/en/data_types/float/).
Example:
``` sql
@ -1659,6 +1679,22 @@ Note that the `arrayCumSum` is a [higher-order function](../../sql-reference/fun
Same as `arrayCumSum`, returns an array of partial sums of elements in the source array (a running sum). Different `arrayCumSum`, when then returned value contains a value less than zero, the value is replace with zero and the subsequent calculation is performed with zero parameters. For example:
**Syntax**
``` sql
arrayCumSumNonNegative(arr)
```
**Arguments**
- `arr` — [Array](../../sql-reference/data-types/array.md) of numeric values.
**Returned value**
- Returns an array of non-negative partial sums of elements in the source array.
Type: [UInt\*](https://clickhouse.com/docs/en/data_types/int_uint/#uint-ranges), [Int\*](https://clickhouse.com/docs/en/data_types/int_uint/#int-ranges), [Float\*](https://clickhouse.com/docs/en/data_types/float/).
``` sql
SELECT arrayCumSumNonNegative([1, 1, -4, 1]) AS res
```
@ -1668,6 +1704,7 @@ SELECT arrayCumSumNonNegative([1, 1, -4, 1]) AS res
│ [1,2,0,1] │
└───────────┘
```
Note that the `arraySumNonNegative` is a [higher-order function](../../sql-reference/functions/index.md#higher-order-functions). You can pass a lambda function to it as the first argument.
## arrayProduct
@ -1682,11 +1719,11 @@ arrayProduct(arr)
**Arguments**
- `arr` — [Array](../../sql-reference/data-types/array.md) of numeric values.
- `arr` — [Array](../../sql-reference/data-types/array.md) of numeric values.
**Returned value**
- A product of array's elements.
- A product of array's elements.
Type: [Float64](../../sql-reference/data-types/float.md).