` | Optional. A variable-length parameter, used to filter different values of the dimension column |
+
+## Return Value
+
+Returns a set of BITMAP type.
+
+## Example
+
+```sql
+select ORTHOGONAL_BITMAP_UNION_COUNT(members) from tag_map where tag_group in ( 1150000, 1150001, 390006);
+```
+
+```text
++------------------------------------------+
+| orthogonal_bitmap_union_count(`members`) |
++------------------------------------------+
+| 286957811 |
++------------------------------------------+
+```
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/percentile-approx.md b/docs/sql-manual/sql-functions/aggregate-functions/percentile-approx.md
index 627ebc09797a1..e0810d31d902e 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/percentile-approx.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/percentile-approx.md
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -24,33 +22,73 @@ specific language governing permissions and limitations
under the License.
-->
-## PERCENTILE_APPROX
-### Description
-#### Syntax
+## Description
+
+The `PERCENTILE_APPROX` function is used to calculate approximate percentiles, primarily for large datasets. Compared to the `PERCENTILE` function, it has the following features:
+
+1. Memory Efficiency: Uses fixed-size memory, maintaining low memory consumption even when processing high-cardinality columns (large data volumes)
+2. Performance Advantage: Suitable for processing large-scale datasets with faster computation
+3. Adjustable Precision: Balance between precision and performance through the compression parameter
+
+
+## Syntax
+
+```sql
+PERCENTILE_APPROX(, [, ])
+```
+
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The column to calculate percentiles for |
+| `` | Percentile value, range `[0.0, 1.0]`, e.g., `0.99` represents the `99th` percentile |
+| `` | Optional parameter, compression level, range `[2048, 10000]`, higher values increase precision but consume more memory. If not specified or out of range, uses `10000` |
+
+## Return Value
-`PERCENTILE_APPROX(expr, DOUBLE p[, DOUBLE compression])`
+Returns a `DOUBLE` value representing the calculated approximate percentile.
-Return the approximation of the point p, where the value of P is between 0 and 1.
+## Examples
-Compression param is optional and can be setted to a value in the range of [2048, 10000]. The bigger compression you set, the more precise result and more time cost you will get. If it is not setted or not setted in the correct range, PERCENTILE_APPROX function will run with a default compression param of 10000.
+```sql
+-- Create sample table
+CREATE TABLE response_times (
+ request_id INT,
+ response_time DECIMAL(10, 2)
+) DUPLICATE KEY(`request_id`)
+DISTRIBUTED BY HASH(`request_id`) BUCKETS AUTO
+PROPERTIES (
+ "replication_allocation" = "tag.location.default: 1"
+);
-This function uses fixed size memory, so less memory can be used for columns with high cardinality, and can be used to calculate statistics such as tp99.
+-- Insert sample data
+INSERT INTO response_times VALUES
+(1, 10.5),
+(2, 15.2),
+(3, 20.1),
+(4, 25.8),
+(5, 30.3),
+(6, 35.7),
+(7, 40.2),
+(8, 45.9),
+(9, 50.4),
+(10, 100.6);
-### example
+-- Calculate 99th percentile using different compression levels
+SELECT
+ percentile_approx(response_time, 0.99) as p99_default, -- Default compression
+ percentile_approx(response_time, 0.99, 2048) as p99_fast, -- Lower compression, faster
+ percentile_approx(response_time, 0.99, 10000) as p99_accurate -- Higher compression, more accurate
+FROM response_times;
```
-MySQL > select `table`, percentile_approx(cost_time,0.99) from log_statis group by `table`;
-+---------------------+---------------------------+
-| table | percentile_approx(`cost_time`, 0.99) |
-+----------+--------------------------------------+
-| test | 54.22 |
-+----------+--------------------------------------+
-
-MySQL > select `table`, percentile_approx(cost_time,0.99, 4096) from log_statis group by `table`;
-+---------------------+---------------------------+
-| table | percentile_approx(`cost_time`, 0.99, 4096.0) |
-+----------+--------------------------------------+
-| test | 54.21 |
-+----------+--------------------------------------+
+
+```text
++-------------------+-------------------+-------------------+
+| p99_default | p99_fast | p99_accurate |
++-------------------+-------------------+-------------------+
+| 100.5999984741211 | 100.5999984741211 | 100.5999984741211 |
++-------------------+-------------------+-------------------+
```
-### keywords
-PERCENTILE_APPROX,PERCENTILE,APPROX
+
+
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/percentile-array.md b/docs/sql-manual/sql-functions/aggregate-functions/percentile-array.md
index 42c697a84e464..70039bda6b239 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/percentile-array.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/percentile-array.md
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -24,29 +22,68 @@ specific language governing permissions and limitations
under the License.
-->
-## PERCENTILE_ARRAY
-### Description
-#### Syntax
+## Description
+
+The `PERCENTILE_ARRAY` function calculates exact percentile arrays, allowing multiple percentile values to be computed at once. This function is primarily suitable for small datasets.
-`ARRAY_DOUBLE PERCENTILE_ARRAY(expr, ARRAY_DOUBLE p)`
+Key features:
+1. Exact Calculation: Provides exact percentile results rather than approximations
+2. Batch Processing: Can calculate multiple percentiles in a single operation
+3. Scope: Best suited for handling small-scale datasets
-Calculate exact percentiles, suitable for small data volumes. Sorts the specified column in descending order first, then takes the exact pth percentile.
-The return value is the result of sequentially taking the specified percentages in the array p.
-Parameter Description:
-expr: Required. Columns whose values are of type integer (up to bigint).
-p: The exact percentile is required, an array of constants, taking the value [0.0, 1.0].
-### example
+## Syntax
+
+```sql
+PERCENTILE_ARRAY(, )
```
-mysql> select percentile_array(k1,[0.3,0.5,0.9]) from baseall;
-+----------------------------------------------+
-| percentile_array(`k1`, ARRAY(0.3, 0.5, 0.9)) |
-+----------------------------------------------+
-| [5.2, 8, 13.6] |
-+----------------------------------------------+
-1 row in set (0.02 sec)
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The column to calculate the percentile for |
+| `` | Percentile array, each element must be in the range `[0.0, 1.0]`, e.g., `[0.5, 0.95, 0.99]` |
+
+## Return Value
+
+Return a `DOUBLE` type array, containing the calculated percentile values.
+
+## Examples
+
+```sql
+-- Create sample table
+CREATE TABLE sales_data (
+ id INT,
+ amount DECIMAL(10, 2)
+) DUPLICATE KEY(`id`)
+DISTRIBUTED BY HASH(`id`) BUCKETS AUTO
+PROPERTIES (
+ "replication_allocation" = "tag.location.default: 1"
+);
+
+-- Insert sample data
+INSERT INTO sales_data VALUES
+(1, 10.5),
+(2, 15.2),
+(3, 20.1),
+(4, 25.8),
+(5, 30.3),
+(6, 35.7),
+(7, 40.2),
+(8, 45.9),
+(9, 50.4),
+(10, 100.6);
+
+-- Calculate multiple percentiles
+SELECT percentile_array(amount, [0.25, 0.5, 0.75, 0.9]) as percentiles
+FROM sales_data;
```
-### keywords
-PERCENTILE_ARRAY
+```text
++-----------------------------------------+
+| percentiles |
++-----------------------------------------+
+| [21.25, 32.5, 43.75, 54.99999999999998] |
++-----------------------------------------+
+```
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/percentile.md b/docs/sql-manual/sql-functions/aggregate-functions/percentile.md
index e773da48b8e05..2af92dd63354b 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/percentile.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/percentile.md
@@ -1,7 +1,7 @@
---
{
- "title": "PERCENTILE",
- "language": "en"
+ "title": "PERCENTILE",
+ "language": "en"
}
---
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/percentile_approx_weighted.md b/docs/sql-manual/sql-functions/aggregate-functions/percentile_approx_weighted.md
index ae807db60062e..56aa8965c703f 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/percentile_approx_weighted.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/percentile_approx_weighted.md
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -24,36 +22,76 @@ specific language governing permissions and limitations
under the License.
-->
-## PERCENTILE_APPROX_WEIGHTED
-### description
-#### Syntax
+## Description
+
+The `PERCENTILE_APPROX_WEIGHTED` function calculates weighted approximate percentiles, primarily used in scenarios where value importance needs to be considered. It is a weighted version of `PERCENTILE_APPROX`, allowing a weight to be specified for each value.
+
+Key features:
+1. Weight Support: Each value can be assigned a corresponding weight, affecting the final percentile calculation
+2. Memory Efficiency: Uses fixed-size memory, suitable for processing large-scale data
+3. Adjustable Precision: Balance between precision and performance through the compression parameter
+
+## Syntax
+
+```sql
+PERCENTILE_APPROX_WEIGHTED(, , [, ])
+```
+
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The column to calculate the percentile for |
+| `` | Weight column, must be positive numbers |
+| `` | Percentile value, range `[0.0, 1.0]`, e.g., `0.99` represents the `99`th percentile |
+| `` | Optional parameter, compression ratio, range `[2048, 10000]`. The higher the value, the higher the precision, but the greater the memory consumption. If not specified or outside the range, use `10000`. |
-`PERCENTILE_APPROX_WEIGHTED(expr, w ,DOUBLE p [, DOUBLE compression])`
+## Return Value
+Return a `DOUBLE` type value, representing the calculated weighted approximate percentile.
-The function is similar to PERCENTILE_APPROX, with the only difference being an additional parameter w, which represents the number of times expr appears.
-Note that the value of parameter W needs to be greater than 0. If the value of a row is less than or equal to 0 during the calculation process, the current row will be skipped.
+## Examples
-### example
+```sql
+-- Create sample table
+CREATE TABLE weighted_scores (
+ student_id INT,
+ score DECIMAL(10, 2),
+ weight INT
+) DUPLICATE KEY(student_id)
+DISTRIBUTED BY HASH(student_id) BUCKETS AUTO
+PROPERTIES (
+ "replication_allocation" = "tag.location.default: 1"
+);
+
+-- Insert example data
+INSERT INTO weighted_scores VALUES
+(1, 85.5, 1), -- Normal homework score, weight 1
+(2, 90.0, 2), -- Important homework score, weight 2
+(3, 75.5, 1),
+(4, 95.5, 3), -- Very important homework, weight 3
+(5, 88.0, 2),
+(6, 92.5, 2),
+(7, 78.0, 1),
+(8, 89.5, 2),
+(9, 94.0, 3),
+(10, 83.5, 1);
+
+-- Calculate weighted scores distribution
+SELECT
+ -- Calculate 90th percentile for different compression ratios
+ percentile_approx_weighted(score, weight, 0.9) as p90_default, -- Default compression ratio
+ percentile_approx_weighted(score, weight, 0.9, 2048) as p90_fast, -- Lower compression ratio, faster
+ percentile_approx_weighted(score, weight, 0.9, 10000) as p90_accurate -- Higher compression ratio, more accurate
+FROM weighted_scores;
```
-mysql >select * from quantile_weighted_table order by k;
-+------+------+
-| k | w |
-+------+------+
-| 1 | 2 |
-| 3 | 1 |
-| 5 | 2 |
-+------+------+
-
-
-mysql >select percentile_approx_weighted(k,w,0.55) from quantile_weighted_table;
-+----------------------------------------------------------------------------------------+
-| percentile_approx_weighted(cast(k as DOUBLE), cast(w as DOUBLE), cast(0.55 as DOUBLE)) |
-+----------------------------------------------------------------------------------------+
-| 3.3333332538604736 |
-+----------------------------------------------------------------------------------------+
+```text
++------------------+------------------+------------------+
+| p90_default | p90_fast | p90_accurate |
++------------------+------------------+------------------+
+| 95.3499984741211 | 95.3499984741211 | 95.3499984741211 |
++------------------+------------------+------------------+
```
-### keywords
-PERCENTILE_APPROX,PERCENTILE,APPROX,PERCENTILE_APPROX_WEIGHTED
+
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/quantile-union.md b/docs/sql-manual/sql-functions/aggregate-functions/quantile-union.md
index 1eb0e3aee78b5..b70301d9518cf 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/quantile-union.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/quantile-union.md
@@ -1,6 +1,6 @@
---
{
- "title": "quantile_union",
+ "title": "QUANTILE_UNION",
"language": "en"
}
---
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -23,3 +21,73 @@ KIND, either express or implied. See the License for the
specific language governing permissions and limitations
under the License.
-->
+
+## Description
+
+The `QUANTILE_UNION` function is used to merge intermediate results from multiple quantile calculations. This function typically works in conjunction with `QUANTILE_STATE` and is particularly useful in scenarios requiring multi-stage quantile calculations.
+
+## Syntax
+
+```sql
+QUANTILE_UNION()
+```
+
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The intermediate state generated by the `TO_QUANTILE_STATE` function. |
+
+## Return Value
+
+Returns an aggregation state that can be used for further quantile calculations. The result of this function remains a `QUANTILE_STATE`.
+
+## Example
+
+```sql
+-- Create sample table
+CREATE TABLE response_times (
+ request_id INT,
+ response_time DOUBLE,
+ region STRING
+) DUPLICATE KEY(request_id)
+DISTRIBUTED BY HASH(request_id) BUCKETS AUTO
+PROPERTIES (
+ "replication_allocation" = "tag.location.default: 1"
+);
+
+-- Insert sample data
+INSERT INTO response_times VALUES
+(1, 10.5, 'east'),
+(2, 15.2, 'east'),
+(3, 20.1, 'west'),
+(4, 25.8, 'east'),
+(5, 30.3, 'west'),
+(6, 35.7, 'east'),
+(7, 40.2, 'west'),
+(8, 45.9, 'east'),
+(9, 50.4, 'west'),
+(10, 100.6, 'east');
+
+-- Calculate 50th percentile of response times by region
+SELECT
+ region,
+ QUANTILE_PERCENT(
+ QUANTILE_UNION(
+ TO_QUANTILE_STATE(response_time, 2048)
+ ),
+ 0.5
+ ) AS median_response_time
+FROM response_times
+GROUP BY region;
+
+```
+
+```text
++--------+----------------------+
+| region | median_response_time |
++--------+----------------------+
+| west | 35.25 |
+| east | 30.75 |
++--------+----------------------+
+```
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/regr-intercept.md b/docs/sql-manual/sql-functions/aggregate-functions/regr-intercept.md
index a6f79566c2601..5f3a375df418f 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/regr-intercept.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/regr-intercept.md
@@ -1,6 +1,6 @@
---
{
- "title": "regr_intercept",
+ "title": "REGR_INTERCEPT",
"language": "en"
}
---
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -23,3 +21,62 @@ KIND, either express or implied. See the License for the
specific language governing permissions and limitations
under the License.
-->
+
+## Description
+
+Returns the intercept of the univariate linear regression line for non-null pairs in a group. It is computed for non-null pairs using the following formula:
+
+`AVG(y) - REGR_SLOPE(y, x) * AVG(x)`
+
+Where `x` is the independent variable and y is the dependent variable.
+
+## Syntax
+
+```sql
+REGR_INTERCEPT(, )
+```
+
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The dependent variable. This must be an expression that can be evaluated to a numeric type. |
+| `` | The independent variable. This must be an expression that can be evaluated to a numeric type. |
+
+## Return Value
+
+Return a `DOUBLE` value, representing the intercept of the univariate linear regression line for non-null pairs in a group.
+
+## Examples
+
+```sql
+-- Create sample table
+CREATE TABLE test_regr_intercept (
+ `id` int,
+ `x` int,
+ `y` int
+) DUPLICATE KEY (`id`)
+DISTRIBUTED BY HASH(`id`) BUCKETS AUTO
+PROPERTIES (
+ "replication_allocation" = "tag.location.default: 1"
+);
+
+-- Insert sample data
+INSERT INTO test_regr_intercept VALUES
+(1, 18, 13),
+(2, 14, 27),
+(3, 12, 2),
+(4, 5, 6),
+(5, 10, 20);
+
+-- Calculate the linear regression intercept of x and y
+SELECT REGR_INTERCEPT(y, x) FROM test_regr_intercept;
+```
+
+```text
++-------------------------+
+| regr_intercept(y, x) |
++-------------------------+
+| 5.512931034482759 |
++-------------------------+
+```
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/regr-slope.md b/docs/sql-manual/sql-functions/aggregate-functions/regr-slope.md
index 976774da85635..57b6f115938ea 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/regr-slope.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/regr-slope.md
@@ -1,6 +1,6 @@
---
{
- "title": "regr_slope",
+ "title": "REGR_SLOPE",
"language": "en"
}
---
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -23,3 +21,59 @@ KIND, either express or implied. See the License for the
specific language governing permissions and limitations
under the License.
-->
+
+## Description
+
+Returns the slope of the linear regression line for non-null pairs in a group.
+
+
+## Syntax
+
+```sql
+REGR_SLOPE(, )
+```
+
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The dependent variable. This must be an expression that can be evaluated to a numeric type. |
+| `` | The independent variable. This must be an expression that can be evaluated to a numeric type. |
+
+## Return Value
+
+Returns a `DOUBLE` value representing the slope of the linear regression line.
+
+## Examples
+
+```sql
+-- Create example table
+CREATE TABLE test_regr_slope (
+ `id` int,
+ `x` int,
+ `y` int
+) DUPLICATE KEY (`id`)
+DISTRIBUTED BY HASH(`id`) BUCKETS AUTO
+PROPERTIES (
+ "replication_allocation" = "tag.location.default: 1"
+);
+
+-- Insert example data
+INSERT INTO test_regr_slope VALUES
+(1, 18, 13),
+(2, 14, 27),
+(3, 12, 2),
+(4, 5, 6),
+(5, 10, 20);
+
+-- Calculate the linear regression slope of x and y
+SELECT REGR_SLOPE(y, x) FROM test_regr_slope;
+```
+
+```text
++----------------------+
+| regr_slope(y, x) |
++----------------------+
+| 0.6853448275862069 |
++----------------------+
+```
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/retention.md b/docs/sql-manual/sql-functions/aggregate-functions/retention.md
index 6f0ea487838aa..043a6ffc8c8b9 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/retention.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/retention.md
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -24,118 +22,72 @@ specific language governing permissions and limitations
under the License.
-->
-## RETENTION
-
-RETENTION
-
-### Description
-#### Syntax
-
-`retention(event1, event2, ... , eventN);`
+## Description
The `retention` function takes as arguments a set of conditions from 1 to 32 arguments of type `UInt8` that indicate whether a certain condition was met for the event. Any condition can be specified as an argument.
The conditions, except the first, apply in pairs: the result of the second will be true if the first and second are true, of the third if the first and third are true, etc.
-To put it simply, the first digit of the return value array indicates whether `event1` is true or false, the second digit represents the truth and falseness of `event1` and `event2`, and the third digit represents whether `event1` is true or false and `event3` is true False and, and so on. If `event1` is false, return an array full of zeros.
+To put it simply, the first digit of the return value array indicates whether `event_1` is true or false, the second digit represents the truth and falseness of `event_1` and `event_2`, and the third digit represents whether `event_1` is true or false and `event_3` is true False and, and so on. If `event_1` is false, return an array full of zeros.
-#### Arguments
+## Syntax
-`event` — An expression that returns a `UInt8` result (1 or 0).
+```sql
+RETENTION( [, , ... , ]);
+```
-##### Returned value
+## Parameters
-An array of 1s and 0s with a maximum length of 32 bits, the final output array has the same length as the input parameter.
+| Parameter | Description |
+| -- | -- |
+| `` | The `n`th event condition, of type `UInt8` and value 1 or 0. |
-1 — Condition was met for the event.
+## Returned value
-0 — Condition wasn’t met for the event.
+An array of 1 and 0 with a maximum length of 32, where the final output array length matches the input parameter length.
-### example
+- 1: Condition is met.
+- 0: Condition is not met.
-```sql
-DROP TABLE IF EXISTS retention_test;
+## Examples
+```sql
+-- Create sample table
CREATE TABLE retention_test(
- `uid` int COMMENT 'user id',
- `date` datetime COMMENT 'date time'
- )
-DUPLICATE KEY(uid)
-DISTRIBUTED BY HASH(uid) BUCKETS 3
+ `uid` int COMMENT 'user id',
+ `date` datetime COMMENT 'date time'
+) DUPLICATE KEY(uid)
+DISTRIBUTED BY HASH(uid) BUCKETS AUTO
PROPERTIES (
- "replication_num" = "1"
-);
-
-INSERT into retention_test (uid, date) values (0, '2022-10-12'),
- (0, '2022-10-13'),
- (0, '2022-10-14'),
- (1, '2022-10-12'),
- (1, '2022-10-13'),
- (2, '2022-10-12');
-
-SELECT * from retention_test;
-
-+------+---------------------+
-| uid | date |
-+------+---------------------+
-| 0 | 2022-10-14 00:00:00 |
-| 0 | 2022-10-13 00:00:00 |
-| 0 | 2022-10-12 00:00:00 |
-| 1 | 2022-10-13 00:00:00 |
-| 1 | 2022-10-12 00:00:00 |
-| 2 | 2022-10-12 00:00:00 |
-+------+---------------------+
-
+ "replication_allocation" = "tag.location.default: 1"
+);
+
+-- Insert sample data
+INSERT into retention_test values
+(0, '2022-10-12'),
+(0, '2022-10-13'),
+(0, '2022-10-14'),
+(1, '2022-10-12'),
+(1, '2022-10-13'),
+(2, '2022-10-12');
+
+-- Calculate user retention
SELECT
uid,
- retention(date = '2022-10-12')
- AS r
- FROM retention_test
- GROUP BY uid
- ORDER BY uid ASC;
-
-+------+------+
-| uid | r |
-+------+------+
-| 0 | [1] |
-| 1 | [1] |
-| 2 | [1] |
-+------+------+
-
-SELECT
- uid,
- retention(date = '2022-10-12', date = '2022-10-13')
- AS r
- FROM retention_test
- GROUP BY uid
- ORDER BY uid ASC;
-
-+------+--------+
-| uid | r |
-+------+--------+
-| 0 | [1, 1] |
-| 1 | [1, 1] |
-| 2 | [1, 0] |
-+------+--------+
-
-SELECT
- uid,
- retention(date = '2022-10-12', date = '2022-10-13', date = '2022-10-14')
- AS r
- FROM retention_test
- GROUP BY uid
- ORDER BY uid ASC;
-
-+------+-----------+
-| uid | r |
-+------+-----------+
-| 0 | [1, 1, 1] |
-| 1 | [1, 1, 0] |
-| 2 | [1, 0, 0] |
-+------+-----------+
-
+ RETENTION(date = '2022-10-12') AS r,
+ RETENTION(date = '2022-10-12', date = '2022-10-13') AS r2,
+ RETENTION(date = '2022-10-12', date = '2022-10-13', date = '2022-10-14') AS r3
+FROM retention_test
+GROUP BY uid
+ORDER BY uid ASC;
```
-### keywords
-
-RETENTION
+```text
++------+------+--------+-----------+
+| uid | r | r2 | r3 |
++------+------+--------+-----------+
+| 0 | [1] | [1, 1] | [1, 1, 1] |
+| 1 | [1] | [1, 1] | [1, 1, 0] |
+| 2 | [1] | [1, 0] | [1, 0, 0] |
++------+------+--------+-----------+
+```
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/sequence-count.md b/docs/sql-manual/sql-functions/aggregate-functions/sequence-count.md
index 68abb404dcaad..d0a55625aeb96 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/sequence-count.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/sequence-count.md
@@ -1,6 +1,6 @@
---
{
- "title": "SEQUENCE-COUNT",
+ "title": "SEQUENCE_COUNT",
"language": "en"
}
---
@@ -22,11 +22,7 @@ specific language governing permissions and limitations
under the License.
-->
-## SEQUENCE-COUNT
-### Description
-#### Syntax
-
-`sequence_count(pattern, timestamp, cond1, cond2, ...);`
+## Description
Counts the number of event chains that matched the pattern. The function searches event chains that do not overlap. It starts to search for the next chain after the current chain is matched.
@@ -34,188 +30,140 @@ Counts the number of event chains that matched the pattern. The function searche
Events that occur at the same second may lay in the sequence in an undefined order affecting the result.
-#### Arguments
+## Syntax
+
+```sql
+SEQUENCE_COUNT(, , [, , ..., ]);
+```
+
+## Parameters
-`pattern` — Pattern string.
+| Parameter | Description |
+| -- | -- |
+| `` | Pattern string, see **Pattern syntax** below. |
+| `` | Column considered to contain time data. Typical data types are `Date` and `DateTime`. You can also use any of the supported UInt data types. |
+| `` | Conditions that describe the chain of events. Data type: `UInt8`. You can pass up to 32 condition arguments. The function takes only the events described in these conditions into account. If the sequence contains data that isn’t described in a condition, the function skips them. |
**Pattern syntax**
-`(?N)` — Matches the condition argument at position N. Conditions are numbered in the `[1, 32]` range. For example, `(?1)` matches the argument passed to the `cond1` parameter.
-
-`.*` — Matches any number of events. You do not need conditional arguments to count this element of the pattern.
+- `(?N)` — Matches the condition argument at position N. Conditions are numbered in the `[1, 32]` range. For example, `(?1)` matches the argument passed to the `cond_1` parameter.
-`(?t operator value)` — Sets the time in seconds that should separate two events.
+- `.*` — Matches any number of events. You do not need conditional arguments to count this element of the pattern.
-We define `t` as the difference in seconds between two times, For example, pattern `(?1)(?t>1800)(?2)` matches events that occur more than 1800 seconds from each other. pattern `(?1)(?t>10000)(?2)` matches events that occur more than 10000 seconds from each other. An arbitrary number of any events can lay between these events. You can use the `>=`, `>`, `<`, `<=`, `==` operators.
+- `(?t operator value)` — Sets the time in seconds that should separate two events.
-`timestamp` — Column considered to contain time data. Typical data types are `Date` and `DateTime`. You can also use any of the supported UInt data types.
+- We define `t` as the difference in seconds between two times, For example, pattern `(?1)(?t>1800)(?2)` matches events that occur more than 1800 seconds from each other. pattern `(?1)(?t>10000)(?2)` matches events that occur more than 10000 seconds from each other. An arbitrary number of any events can lay between these events. You can use the `>=`, `>`, `<`, `<=`, `==` operators.
-`cond1`, `cond2` — Conditions that describe the chain of events. Data type: `UInt8`. You can pass up to 32 condition arguments. The function takes only the events described in these conditions into account. If the sequence contains data that isn’t described in a condition, the function skips them.
-#### Returned value
+## Return Value
Number of non-overlapping event chains that are matched.
-### example
+## Examples
-**count examples**
+**Matching examples**
```sql
-DROP TABLE IF EXISTS sequence_count_test2;
-
-CREATE TABLE sequence_count_test2(
- `uid` int COMMENT 'user id',
- `date` datetime COMMENT 'date time',
- `number` int NULL COMMENT 'number'
- )
-DUPLICATE KEY(uid)
-DISTRIBUTED BY HASH(uid) BUCKETS 3
+-- Create sample table
+CREATE TABLE sequence_count_test1(
+ `uid` int COMMENT 'user id',
+ `date` datetime COMMENT 'date time',
+ `number` int NULL COMMENT 'number'
+) DUPLICATE KEY(uid)
+DISTRIBUTED BY HASH(uid) BUCKETS AUTO
PROPERTIES (
"replication_num" = "1"
);
-INSERT INTO sequence_count_test2(uid, date, number) values (1, '2022-11-02 10:41:00', 1),
- (2, '2022-11-02 13:28:02', 2),
- (3, '2022-11-02 16:15:01', 1),
- (4, '2022-11-02 19:05:04', 2),
- (5, '2022-11-02 20:08:44', 3);
-
-SELECT * FROM sequence_count_test2 ORDER BY date;
-
-+------+---------------------+--------+
-| uid | date | number |
-+------+---------------------+--------+
-| 1 | 2022-11-02 10:41:00 | 1 |
-| 2 | 2022-11-02 13:28:02 | 2 |
-| 3 | 2022-11-02 16:15:01 | 1 |
-| 4 | 2022-11-02 19:05:04 | 2 |
-| 5 | 2022-11-02 20:08:44 | 3 |
-+------+---------------------+--------+
-
-SELECT sequence_count('(?1)(?2)', date, number = 1, number = 3) FROM sequence_count_test2;
-
-+----------------------------------------------------------------+
-| sequence_count('(?1)(?2)', `date`, `number` = 1, `number` = 3) |
-+----------------------------------------------------------------+
-| 1 |
-+----------------------------------------------------------------+
-
-SELECT sequence_count('(?1)(?2)', date, number = 1, number = 2) FROM sequence_count_test2;
-
-+----------------------------------------------------------------+
-| sequence_count('(?1)(?2)', `date`, `number` = 1, `number` = 2) |
-+----------------------------------------------------------------+
-| 2 |
-+----------------------------------------------------------------+
-
-SELECT sequence_count('(?1)(?t>=10000)(?2)', date, number = 1, number = 2) FROM sequence_count_test1;
+-- Insert sample data
+INSERT INTO sequence_count_test1(uid, date, number) values
+(1, '2022-11-02 10:41:00', 1),
+(2, '2022-11-02 13:28:02', 2),
+(3, '2022-11-02 16:15:01', 1),
+(4, '2022-11-02 19:05:04', 2),
+(5, '2022-11-02 20:08:44', 3);
+
+-- Query example
+SELECT
+ SEQUENCE_COUNT('(?1)(?2)', date, number = 1, number = 3) as c1,
+ SEQUENCE_COUNT('(?1)(?2)', date, number = 1, number = 2) as c2,
+ SEQUENCE_COUNT('(?1)(?t>=3600)(?2)', date, number = 1, number = 2) as c3
+FROM sequence_count_test1;
+```
-+---------------------------------------------------------------------------+
-| sequence_count('(?1)(?t>=3600)(?2)', `date`, `number` = 1, `number` = 2) |
-+---------------------------------------------------------------------------+
-| 2 |
-+---------------------------------------------------------------------------+
+```text
++------+------+------+
+| c1 | c2 | c3 |
++------+------+------+
+| 1 | 2 | 2 |
++------+------+------+
```
-**not count examples**
+**Non-matching examples**
```sql
-DROP TABLE IF EXISTS sequence_count_test1;
-
-CREATE TABLE sequence_count_test1(
- `uid` int COMMENT 'user id',
- `date` datetime COMMENT 'date time',
- `number` int NULL COMMENT 'number'
- )
-DUPLICATE KEY(uid)
-DISTRIBUTED BY HASH(uid) BUCKETS 3
+-- Create sample table
+CREATE TABLE sequence_count_test2(
+ `uid` int COMMENT 'user id',
+ `date` datetime COMMENT 'date time',
+ `number` int NULL COMMENT 'number'
+) DUPLICATE KEY(uid)
+DISTRIBUTED BY HASH(uid) BUCKETS AUTO
PROPERTIES (
"replication_num" = "1"
);
-INSERT INTO sequence_count_test1(uid, date, number) values (1, '2022-11-02 10:41:00', 1),
- (2, '2022-11-02 11:41:00', 7),
- (3, '2022-11-02 16:15:01', 3),
- (4, '2022-11-02 19:05:04', 4),
- (5, '2022-11-02 21:24:12', 5);
-
-SELECT * FROM sequence_count_test1 ORDER BY date;
-
-+------+---------------------+--------+
-| uid | date | number |
-+------+---------------------+--------+
-| 1 | 2022-11-02 10:41:00 | 1 |
-| 2 | 2022-11-02 11:41:00 | 7 |
-| 3 | 2022-11-02 16:15:01 | 3 |
-| 4 | 2022-11-02 19:05:04 | 4 |
-| 5 | 2022-11-02 21:24:12 | 5 |
-+------+---------------------+--------+
-
-SELECT sequence_count('(?1)(?2)', date, number = 1, number = 2) FROM sequence_count_test1;
-
-+----------------------------------------------------------------+
-| sequence_count('(?1)(?2)', `date`, `number` = 1, `number` = 2) |
-+----------------------------------------------------------------+
-| 0 |
-+----------------------------------------------------------------+
-
-SELECT sequence_count('(?1)(?2).*', date, number = 1, number = 2) FROM sequence_count_test1;
-
-+------------------------------------------------------------------+
-| sequence_count('(?1)(?2).*', `date`, `number` = 1, `number` = 2) |
-+------------------------------------------------------------------+
-| 0 |
-+------------------------------------------------------------------+
-
-SELECT sequence_count('(?1)(?t>3600)(?2)', date, number = 1, number = 7) FROM sequence_count_test1;
+-- Insert sample data
+INSERT INTO sequence_count_test2(uid, date, number) values
+(1, '2022-11-02 10:41:00', 1),
+(2, '2022-11-02 11:41:00', 7),
+(3, '2022-11-02 16:15:01', 3),
+(4, '2022-11-02 19:05:04', 4),
+(5, '2022-11-02 21:24:12', 5);
+
+-- Query example
+SELECT
+ SEQUENCE_COUNT('(?1)(?2)', date, number = 1, number = 2) as c1,
+ SEQUENCE_COUNT('(?1)(?2).*', date, number = 1, number = 2) as c2,
+ SEQUENCE_COUNT('(?1)(?t>3600)(?2)', date, number = 1, number = 7) as c3
+FROM sequence_count_test2;
+```
-+--------------------------------------------------------------------------+
-| sequence_count('(?1)(?t>3600)(?2)', `date`, `number` = 1, `number` = 7) |
-+--------------------------------------------------------------------------+
-| 0 |
-+--------------------------------------------------------------------------+
+```text
++------+------+------+
+| c1 | c2 | c3 |
++------+------+------+
+| 0 | 0 | 0 |
++------+------+------+
```
-**special examples**
+**Special examples**
```sql
-DROP TABLE IF EXISTS sequence_count_test3;
-
+-- Create sample table
CREATE TABLE sequence_count_test3(
- `uid` int COMMENT 'user id',
- `date` datetime COMMENT 'date time',
- `number` int NULL COMMENT 'number'
- )
-DUPLICATE KEY(uid)
-DISTRIBUTED BY HASH(uid) BUCKETS 3
+ `uid` int COMMENT 'user id',
+ `date` datetime COMMENT 'date time',
+ `number` int NULL COMMENT 'number'
+) DUPLICATE KEY(uid)
+DISTRIBUTED BY HASH(uid) BUCKETS AUTO
PROPERTIES (
"replication_num" = "1"
);
-INSERT INTO sequence_count_test3(uid, date, number) values (1, '2022-11-02 10:41:00', 1),
- (2, '2022-11-02 11:41:00', 7),
- (3, '2022-11-02 16:15:01', 3),
- (4, '2022-11-02 19:05:04', 4),
- (5, '2022-11-02 21:24:12', 5);
-
-SELECT * FROM sequence_count_test3 ORDER BY date;
-
-+------+---------------------+--------+
-| uid | date | number |
-+------+---------------------+--------+
-| 1 | 2022-11-02 10:41:00 | 1 |
-| 2 | 2022-11-02 11:41:00 | 7 |
-| 3 | 2022-11-02 16:15:01 | 3 |
-| 4 | 2022-11-02 19:05:04 | 4 |
-| 5 | 2022-11-02 21:24:12 | 5 |
-+------+---------------------+--------+
-```
-
-Perform the query:
+-- Insert sample data
+INSERT INTO sequence_count_test3(uid, date, number) values
+(1, '2022-11-02 10:41:00', 1),
+(2, '2022-11-02 11:41:00', 7),
+(3, '2022-11-02 16:15:01', 3),
+(4, '2022-11-02 19:05:04', 4),
+(5, '2022-11-02 21:24:12', 5);
-```sql
-SELECT sequence_count('(?1)(?2)', date, number = 1, number = 5) FROM sequence_count_test3;
+-- Query example
+SELECT SEQUENCE_COUNT('(?1)(?2)', date, number = 1, number = 5) FROM sequence_count_test3;
+```
+```text
+----------------------------------------------------------------+
| sequence_count('(?1)(?2)', `date`, `number` = 1, `number` = 5) |
+----------------------------------------------------------------+
@@ -228,8 +176,10 @@ This is a very simple example. The function found the event chain where number 5
Now, perform this query:
```sql
-SELECT sequence_count('(?1)(?2)', date, number = 1, number = 5, number = 4) FROM sequence_count_test3;
+SELECT SEQUENCE_COUNT('(?1)(?2)', date, number = 1, number = 5, number = 4) FROM sequence_count_test3;
+```
+```text
+------------------------------------------------------------------------------+
| sequence_count('(?1)(?2)', `date`, `number` = 1, `number` = 5, `number` = 4) |
+------------------------------------------------------------------------------+
@@ -240,15 +190,13 @@ SELECT sequence_count('(?1)(?2)', date, number = 1, number = 5, number = 4) FROM
The result is kind of confusing. In this case, the function couldn’t find the event chain matching the pattern, because the event for number 4 occurred between 1 and 5. If in the same case we checked the condition for number 6, the sequence would count the pattern.
```sql
-SELECT sequence_count('(?1)(?2)', date, number = 1, number = 5, number = 6) FROM sequence_count_test3;
+SELECT SEQUENCE_COUNT('(?1)(?2)', date, number = 1, number = 5, number = 6) FROM sequence_count_test3;
+```
+```text
+------------------------------------------------------------------------------+
| sequence_count('(?1)(?2)', `date`, `number` = 1, `number` = 5, `number` = 6) |
+------------------------------------------------------------------------------+
| 1 |
+------------------------------------------------------------------------------+
```
-
-### keywords
-
-SEQUENCE_COUNT
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/sequence-match.md b/docs/sql-manual/sql-functions/aggregate-functions/sequence-match.md
index c088fc2e746f2..a36a00a42f737 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/sequence-match.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/sequence-match.md
@@ -22,11 +22,7 @@ specific language governing permissions and limitations
under the License.
-->
-## SEQUENCE-MATCH
-### Description
-#### Syntax
-
-`sequence_match(pattern, timestamp, cond1, cond2, ...);`
+## Description
Checks whether the sequence contains an event chain that matches the pattern.
@@ -34,190 +30,135 @@ Checks whether the sequence contains an event chain that matches the pattern.
Events that occur at the same second may lay in the sequence in an undefined order affecting the result.
-#### Arguments
-`pattern` — Pattern string.
+## Syntax
-**Pattern syntax**
+```sql
+SEQUENCE_MATCH(, , [, , ..., ])
+```
-`(?N)` — Matches the condition argument at position N. Conditions are numbered in the `[1, 32]` range. For example, `(?1)` matches the argument passed to the `cond1` parameter.
+## Parameters
-`.*` — Matches any number of events. You do not need conditional arguments to match this element of the pattern.
+| Parameter | Description |
+| -- | -- |
+| `` | Pattern string. See **Pattern syntax** below. |
+| `` | Column considered to contain time data. Typical data types are `Date` and `DateTime`. You can also use any of the supported UInt data types. |
+| `` | Conditions that describe the chain of events. Data type: `UInt8`. You can pass up to 32 condition arguments. The function takes only the events described in these conditions into account. If the sequence contains data that isn’t described in a condition, the function skips them. |
-`(?t operator value)` — Sets the time in seconds that should separate two events.
+**Pattern syntax**
-We define `t` as the difference in seconds between two times, For example, pattern `(?1)(?t>1800)(?2)` matches events that occur more than 1800 seconds from each other. pattern `(?1)(?t>10000)(?2)` matches events that occur more than 10000 seconds from each other. An arbitrary number of any events can lay between these events. You can use the `>=`, `>`, `<`, `<=`, `==` operators.
+- `(?N)` — Matches the condition argument at position N. Conditions are numbered in the `[1, 32]` range. For example, `(?1)` matches the argument passed to the `cond1` parameter.
-`timestamp` — Column considered to contain time data. Typical data types are `Date` and `DateTime`. You can also use any of the supported UInt data types.
+- `.*` — Matches any number of events. You do not need conditional arguments to match this element of the pattern.
-`cond1`, `cond2` — Conditions that describe the chain of events. Data type: `UInt8`. You can pass up to 32 condition arguments. The function takes only the events described in these conditions into account. If the sequence contains data that isn’t described in a condition, the function skips them.
+- `(?t operator value)` — Sets the time in seconds that should separate two events.
-#### Returned value
+- We define `t` as the difference in seconds between two times, For example, pattern `(?1)(?t>1800)(?2)` matches events that occur more than 1800 seconds from each other. pattern `(?1)(?t>10000)(?2)` matches events that occur more than 10000 seconds from each other. An arbitrary number of any events can lay between these events. You can use the `>=`, `>`, `<`, `<=`, `==` operators.
-1, if the pattern is matched.
+## Return value
-0, if the pattern isn’t matched.
+1: if the pattern is matched.
-### example
+0: if the pattern isn’t matched.
-**match examples**
+## Examples
-```sql
-DROP TABLE IF EXISTS sequence_match_test1;
+**Match examples**
+```sql
CREATE TABLE sequence_match_test1(
- `uid` int COMMENT 'user id',
- `date` datetime COMMENT 'date time',
- `number` int NULL COMMENT 'number'
- )
-DUPLICATE KEY(uid)
-DISTRIBUTED BY HASH(uid) BUCKETS 3
+ `uid` int COMMENT 'user id',
+ `date` datetime COMMENT 'date time',
+ `number` int NULL COMMENT 'number'
+) DUPLICATE KEY(uid)
+DISTRIBUTED BY HASH(uid) BUCKETS AUTO
PROPERTIES (
"replication_num" = "1"
);
-INSERT INTO sequence_match_test1(uid, date, number) values (1, '2022-11-02 10:41:00', 1),
- (2, '2022-11-02 13:28:02', 2),
- (3, '2022-11-02 16:15:01', 1),
- (4, '2022-11-02 19:05:04', 2),
- (5, '2022-11-02 20:08:44', 3);
-
-SELECT * FROM sequence_match_test1 ORDER BY date;
-
-+------+---------------------+--------+
-| uid | date | number |
-+------+---------------------+--------+
-| 1 | 2022-11-02 10:41:00 | 1 |
-| 2 | 2022-11-02 13:28:02 | 2 |
-| 3 | 2022-11-02 16:15:01 | 1 |
-| 4 | 2022-11-02 19:05:04 | 2 |
-| 5 | 2022-11-02 20:08:44 | 3 |
-+------+---------------------+--------+
+INSERT INTO sequence_match_test1(uid, date, number) values
+(1, '2022-11-02 10:41:00', 1),
+(2, '2022-11-02 13:28:02', 2),
+(3, '2022-11-02 16:15:01', 1),
+(4, '2022-11-02 19:05:04', 2),
+(5, '2022-11-02 20:08:44', 3);
-SELECT sequence_match('(?1)(?2)', date, number = 1, number = 3) FROM sequence_match_test1;
-+----------------------------------------------------------------+
-| sequence_match('(?1)(?2)', `date`, `number` = 1, `number` = 3) |
-+----------------------------------------------------------------+
-| 1 |
-+----------------------------------------------------------------+
-
-SELECT sequence_match('(?1)(?2)', date, number = 1, number = 2) FROM sequence_match_test1;
-
-+----------------------------------------------------------------+
-| sequence_match('(?1)(?2)', `date`, `number` = 1, `number` = 2) |
-+----------------------------------------------------------------+
-| 1 |
-+----------------------------------------------------------------+
-
-SELECT sequence_match('(?1)(?t>=3600)(?2)', date, number = 1, number = 2) FROM sequence_match_test1;
+SELECT
+sequence_match('(?1)(?2)', date, number = 1, number = 3) as c1,
+sequence_match('(?1)(?2)', date, number = 1, number = 2) as c2,
+sequence_match('(?1)(?t>=3600)(?2)', date, number = 1, number = 2) as c3
+FROM sequence_match_test1;
+```
-+---------------------------------------------------------------------------+
-| sequence_match('(?1)(?t>=3600)(?2)', `date`, `number` = 1, `number` = 2) |
-+---------------------------------------------------------------------------+
-| 1 |
-+---------------------------------------------------------------------------+
+```text
++------+------+------+
+| c1 | c2 | c3 |
++------+------+------+
+| 1 | 1 | 1 |
++------+------+------+
```
-**not match examples**
+**Not match examples**
```sql
-DROP TABLE IF EXISTS sequence_match_test2;
-
CREATE TABLE sequence_match_test2(
- `uid` int COMMENT 'user id',
- `date` datetime COMMENT 'date time',
- `number` int NULL COMMENT 'number'
- )
-DUPLICATE KEY(uid)
-DISTRIBUTED BY HASH(uid) BUCKETS 3
+ `uid` int COMMENT 'user id',
+ `date` datetime COMMENT 'date time',
+ `number` int NULL COMMENT 'number'
+) DUPLICATE KEY(uid)
+DISTRIBUTED BY HASH(uid) BUCKETS AUTO
PROPERTIES (
"replication_num" = "1"
);
-INSERT INTO sequence_match_test2(uid, date, number) values (1, '2022-11-02 10:41:00', 1),
- (2, '2022-11-02 11:41:00', 7),
- (3, '2022-11-02 16:15:01', 3),
- (4, '2022-11-02 19:05:04', 4),
- (5, '2022-11-02 21:24:12', 5);
-
-SELECT * FROM sequence_match_test2 ORDER BY date;
-
-+------+---------------------+--------+
-| uid | date | number |
-+------+---------------------+--------+
-| 1 | 2022-11-02 10:41:00 | 1 |
-| 2 | 2022-11-02 11:41:00 | 7 |
-| 3 | 2022-11-02 16:15:01 | 3 |
-| 4 | 2022-11-02 19:05:04 | 4 |
-| 5 | 2022-11-02 21:24:12 | 5 |
-+------+---------------------+--------+
-
-SELECT sequence_match('(?1)(?2)', date, number = 1, number = 2) FROM sequence_match_test2;
-
-+----------------------------------------------------------------+
-| sequence_match('(?1)(?2)', `date`, `number` = 1, `number` = 2) |
-+----------------------------------------------------------------+
-| 0 |
-+----------------------------------------------------------------+
-
-SELECT sequence_match('(?1)(?2).*', date, number = 1, number = 2) FROM sequence_match_test2;
-
-+------------------------------------------------------------------+
-| sequence_match('(?1)(?2).*', `date`, `number` = 1, `number` = 2) |
-+------------------------------------------------------------------+
-| 0 |
-+------------------------------------------------------------------+
-
-SELECT sequence_match('(?1)(?t>3600)(?2)', date, number = 1, number = 7) FROM sequence_match_test2;
+INSERT INTO sequence_match_test2(uid, date, number) values
+(1, '2022-11-02 10:41:00', 1),
+(2, '2022-11-02 11:41:00', 7),
+(3, '2022-11-02 16:15:01', 3),
+(4, '2022-11-02 19:05:04', 4),
+(5, '2022-11-02 21:24:12', 5);
+
+SELECT
+sequence_match('(?1)(?2)', date, number = 1, number = 2) as c1,
+sequence_match('(?1)(?2).*', date, number = 1, number = 2) as c2,
+sequence_match('(?1)(?t>3600)(?2)', date, number = 1, number = 7) as c3
+FROM sequence_match_test2;
+```
-+--------------------------------------------------------------------------+
-| sequence_match('(?1)(?t>3600)(?2)', `date`, `number` = 1, `number` = 7) |
-+--------------------------------------------------------------------------+
-| 0 |
-+--------------------------------------------------------------------------+
+```text
++------+------+------+
+| c1 | c2 | c3 |
++------+------+------+
+| 0 | 0 | 0 |
++------+------+------+
```
-**special examples**
+**Special examples**
```sql
-DROP TABLE IF EXISTS sequence_match_test3;
-
CREATE TABLE sequence_match_test3(
- `uid` int COMMENT 'user id',
- `date` datetime COMMENT 'date time',
- `number` int NULL COMMENT 'number'
- )
-DUPLICATE KEY(uid)
-DISTRIBUTED BY HASH(uid) BUCKETS 3
+ `uid` int COMMENT 'user id',
+ `date` datetime COMMENT 'date time',
+ `number` int NULL COMMENT 'number'
+) DUPLICATE KEY(uid)
+DISTRIBUTED BY HASH(uid) BUCKETS AUTO
PROPERTIES (
"replication_num" = "1"
);
-INSERT INTO sequence_match_test3(uid, date, number) values (1, '2022-11-02 10:41:00', 1),
- (2, '2022-11-02 11:41:00', 7),
- (3, '2022-11-02 16:15:01', 3),
- (4, '2022-11-02 19:05:04', 4),
- (5, '2022-11-02 21:24:12', 5);
-
-SELECT * FROM sequence_match_test3 ORDER BY date;
-
-+------+---------------------+--------+
-| uid | date | number |
-+------+---------------------+--------+
-| 1 | 2022-11-02 10:41:00 | 1 |
-| 2 | 2022-11-02 11:41:00 | 7 |
-| 3 | 2022-11-02 16:15:01 | 3 |
-| 4 | 2022-11-02 19:05:04 | 4 |
-| 5 | 2022-11-02 21:24:12 | 5 |
-+------+---------------------+--------+
-```
+INSERT INTO sequence_match_test3(uid, date, number) values
+(1, '2022-11-02 10:41:00', 1),
+(2, '2022-11-02 11:41:00', 7),
+(3, '2022-11-02 16:15:01', 3),
+(4, '2022-11-02 19:05:04', 4),
+(5, '2022-11-02 21:24:12', 5);
-Perform the query:
-
-```sql
-SELECT sequence_match('(?1)(?2)', date, number = 1, number = 5) FROM sequence_match_test3;
+SELECT sequence_match('(?1)(?2)', date, number = 1, number = 5)
+FROM sequence_match_test3;
+```
+```text
+----------------------------------------------------------------+
| sequence_match('(?1)(?2)', `date`, `number` = 1, `number` = 5) |
+----------------------------------------------------------------+
@@ -230,8 +171,11 @@ This is a very simple example. The function found the event chain where number 5
Now, perform this query:
```sql
-SELECT sequence_match('(?1)(?2)', date, number = 1, number = 5, number = 4) FROM sequence_match_test3;
+SELECT sequence_match('(?1)(?2)', date, number = 1, number = 5, number = 4)
+FROM sequence_match_test3;
+```
+```text
+------------------------------------------------------------------------------+
| sequence_match('(?1)(?2)', `date`, `number` = 1, `number` = 5, `number` = 4) |
+------------------------------------------------------------------------------+
@@ -242,15 +186,14 @@ SELECT sequence_match('(?1)(?2)', date, number = 1, number = 5, number = 4) FROM
The result is kind of confusing. In this case, the function couldn’t find the event chain matching the pattern, because the event for number 4 occurred between 1 and 5. If in the same case we checked the condition for number 6, the sequence would match the pattern.
```sql
-SELECT sequence_match('(?1)(?2)', date, number = 1, number = 5, number = 6) FROM sequence_match_test3;
+SELECT sequence_match('(?1)(?2)', date, number = 1, number = 5, number = 6)
+FROM sequence_match_test3;
+```
+```text
+------------------------------------------------------------------------------+
| sequence_match('(?1)(?2)', `date`, `number` = 1, `number` = 5, `number` = 6) |
+------------------------------------------------------------------------------+
| 1 |
+------------------------------------------------------------------------------+
```
-
-### keywords
-
-SEQUENCE_MATCH
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/skew.md b/docs/sql-manual/sql-functions/aggregate-functions/skew.md
index 7185ca7f00287..6b05a54dbbeb1 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/skew.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/skew.md
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -24,50 +22,79 @@ specific language governing permissions and limitations
under the License.
-->
-## skewness,skew,skew_pop
-### Description
+## Description
Returns the [skewness](https://en.wikipedia.org/wiki/Skewness) of the expr expression.
-The forumula used for this function is `3-th centrol moment / ((variance)^{1.5})`, when variance is zero, `skewness` will return `NULL`.
+The forumula used for this function is `3-th centrol moment / ((variance)^{1.5})`, when variance is zero, `SKEWNESS` will return `NULL`.
-### Syntax
+**Related Commands**
-`skewness(expr)`
+[kurt](./kurt.md)
-### Arguments
+## Alias
-TinyInt/SmallInt/Integer/BigInt/Float/Double, Decimal will be casted to a float number.
+- SKEW
+- SKEW_POP
-### Return value
+## Syntax
-`Double`
-
-### Example
```sql
-create table statistic_test (tag int, val1 double not null, val2 double null)
- distributed by hash(tag) properties("replication_num"="1")
+SKEWNESS()
+```
+
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The column to be calculated skewness |
+
+## Return Value
-insert into statistic_test values (1, -10, -10),
- (2, -20, NULL),
- (3, 100, NULL),
- (4, 100, NULL),
- (5, 1000,1000);
+Returns the skewness of the expr expression, which is a `Double` type.
-// NULL is ignored
-select skew(val1), skew(val2) from statistic_test
---------------
+## Examples
+```sql
+CREATE TABLE statistic_test(
+ tag int,
+ val1 double not null,
+ val2 double null
+) DISTRIBUTED BY HASH(tag)
+PROPERTIES (
+ "replication_num"="1"
+);
+
+INSERT INTO statistic_test VALUES
+(1, -10, -10),
+(2, -20, NULL),
+(3, 100, NULL),
+(4, 100, NULL),
+(5, 1000,1000);
+
+-- NULL is ignored
+SELECT
+ skew(val1),
+ skew(val2)
+FROM statistic_test;
+```
+```text
+--------------------+--------------------+
| skew(val1) | skew(val2) |
+--------------------+--------------------+
| 1.4337199628825619 | 1.1543940205711711 |
+--------------------+--------------------+
-1 row in set (0.01 sec)
+```
-// Each group just has one row, result is NULL
-select skew(val1), skew(val2) from statistic_test group by tag
---------------
+```sql
+-- Each group just has one row, result is NULL
+SELECT
+ skew(val1),
+ skew(val2)
+FROM statistic_test
+GROUP BY tag;
+```
+```text
+------------+------------+
| skew(val1) | skew(val2) |
+------------+------------+
@@ -77,8 +104,4 @@ select skew(val1), skew(val2) from statistic_test group by tag
| NULL | NULL |
| NULL | NULL |
+------------+------------+
-5 rows in set (0.04 sec)
-```
-### Related Commands
-
-[kurt](./kurt.md)
\ No newline at end of file
+```
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/stddev-samp.md b/docs/sql-manual/sql-functions/aggregate-functions/stddev-samp.md
index 086c7b4d84113..45be4c6c9c7d5 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/stddev-samp.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/stddev-samp.md
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -24,23 +22,54 @@ specific language governing permissions and limitations
under the License.
-->
-## STDDEV_SAMP
-### Description
-#### Syntax
+## Description
+
+Returns the sample standard deviation of the expr expression
-`STDDEV SAMP (expr)`
+## Syntax
+```sql
+STDDEV_SAMP()
+```
-Returns the sample standard deviation of the expr expression
+## Parameters
-### example
+| Parameter | Description |
+| -- | -- |
+| `` | The value to be calculated standard deviation |
+
+## Return Value
+
+Return the sample standard deviation of the expr expression
+
+### Examples
+```sql
+-- Create sample tables
+CREATE TABLE score_table (
+ student_id INT,
+ score DOUBLE
+) DISTRIBUTED BY HASH(student_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- Insert test data
+INSERT INTO score_table VALUES
+(1, 85),
+(2, 90),
+(3, 82),
+(4, 88),
+(5, 95);
+
+-- Calculate the sample standard deviation of all students' scores
+SELECT STDDEV_SAMP(score) as score_stddev
+FROM score_table;
```
-MySQL > select stddev_samp(scan_rows) from log_statis group by datetime;
-+--------------------------+
-| stddev_samp(`scan_rows`) |
-+--------------------------+
-| 2.372044195280762 |
-+--------------------------+
+
+```text
++-------------------+
+| score_stddev |
++-------------------+
+| 4.949747468305831 |
++-------------------+
```
-### keywords
-STDDEV SAMP,STDDEV,SAMP
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/stddev.md b/docs/sql-manual/sql-functions/aggregate-functions/stddev.md
index d22a6d771792a..f31d41efacf49 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/stddev.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/stddev.md
@@ -13,9 +13,7 @@ regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
-
http://www.apache.org/licenses/LICENSE-2.0
-
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
@@ -24,30 +22,58 @@ specific language governing permissions and limitations
under the License.
-->
-## STDDEV,STDDEV_POP
-### Description
-#### Syntax
+## Description
-`stddev (expl)`
+Returns the standard deviation of the expr expression
+## Alias
-Returns the standard deviation of the expr expression
+- STDDEV_POP
+
+## Syntax
+
+```sql
+STDDEV()
+```
-### example
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The value to be calculated standard deviation |
+
+## Return Value
+
+Return the standard deviation of the expr expression
+
+## Examples
+```sql
+-- Create sample tables
+CREATE TABLE score_table (
+ student_id INT,
+ score DOUBLE
+) DISTRIBUTED BY HASH(student_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- Insert test data
+INSERT INTO score_table VALUES
+(1, 85),
+(2, 90),
+(3, 82),
+(4, 88),
+(5, 95);
+
+-- Calculate the standard deviation of all students' scores
+SELECT STDDEV(score) as score_stddev
+FROM score_table;
```
-MySQL > select stddev(scan_rows) from log_statis group by datetime;
-+---------------------+
-| stddev(`scan_rows`) |
-+---------------------+
-| 2.3736656687790934 |
-+---------------------+
-
-MySQL > select stddev_pop(scan_rows) from log_statis group by datetime;
-+-------------------------+
-| stddev_pop(`scan_rows`) |
-+-------------------------+
-| 2.3722760595994914 |
-+-------------------------+
+
+```text
++-------------------+
+| score_stddev |
++-------------------+
+| 4.427188724235729 |
++-------------------+
```
-### keywords
-STDDEV,STDDEV_POP,POP
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/sum.md b/docs/sql-manual/sql-functions/aggregate-functions/sum.md
index 10802b4707ae3..669c0dbdd724b 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/sum.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/sum.md
@@ -24,23 +24,55 @@ specific language governing permissions and limitations
under the License.
-->
-## SUM
-### Description
-#### Syntax
+## Description
-`Sum (Expr)`
+Used to return the sum of all values of the selected field
+## Syntax
-Used to return the sum of all values of the selected field
+```sql
+SUM()
+```
+
+## Parameters
+
+| Parameter | Description |
+| --- | --- |
+| `` | The field to calculate the sum of |
-### example
+## Return Value
+
+Return the sum of all values of the selected field.
+
+## Examples
+```sql
+-- Create sample tables
+CREATE TABLE sales_table (
+ product_id INT,
+ price DECIMAL(10,2),
+ quantity INT
+) DISTRIBUTED BY HASH(product_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- Insert test data
+INSERT INTO sales_table VALUES
+(1, 99.99, 2),
+(2, 159.99, 1),
+(3, 49.99, 5),
+(4, 299.99, 1),
+(5, 79.99, 3);
+
+-- Calculate the total sales amount
+SELECT SUM(price * quantity) as total_sales
+FROM sales_table;
```
-MySQL > select sum(scan_rows) from log_statis group by datetime;
-+------------------+
-| sum(`scan_rows`) |
-+------------------+
-| 8217360135 |
-+------------------+
+
+```text
++-------------+
+| total_sales |
++-------------+
+| 1149.88 |
++-------------+
```
-### keywords
-SUM
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/sum0.md b/docs/sql-manual/sql-functions/aggregate-functions/sum0.md
index 745b70b3043c6..adf052f8b98d6 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/sum0.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/sum0.md
@@ -1,7 +1,6 @@
---
{
- "title": "sum0
- ",
+ "title": "SUM0",
"language": "en"
}
---
@@ -24,3 +23,60 @@ KIND, either express or implied. See the License for the
specific language governing permissions and limitations
under the License.
-->
+
+## Description
+
+Used to return the sum of all values of the selected field. Unlike the SUM function, when all input values are NULL, SUM0 returns 0 instead of NULL.
+
+## Syntax
+
+```sql
+SUM0()
+```
+
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The field to calculate the sum of |
+
+## Return Value
+
+Returns the sum of all values of the selected field. If all values are NULL, returns 0.
+
+## Examples
+
+```sql
+-- Create example table
+CREATE TABLE sales_table (
+ product_id INT,
+ price DECIMAL(10,2),
+ quantity INT,
+ discount DECIMAL(10,2)
+) DISTRIBUTED BY HASH(product_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- Insert test data
+INSERT INTO sales_table VALUES
+(1, 99.99, 2, NULL),
+(2, 159.99, 1, NULL),
+(3, 49.99, 5, NULL),
+(4, 299.99, 1, NULL),
+(5, 79.99, 3, NULL);
+
+-- Compare SUM and SUM0
+SELECT
+ SUM(discount) as sum_discount, -- Returns NULL
+ SUM0(discount) as sum0_discount -- Returns 0
+FROM sales_table;
+```
+
+```text
++--------------+---------------+
+| sum_discount | sum0_discount |
++--------------+---------------+
+| NULL | 0.00 |
++--------------+---------------+
+```
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/topn-array.md b/docs/sql-manual/sql-functions/aggregate-functions/topn-array.md
index 0cb0b177a8b31..f3710a434434e 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/topn-array.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/topn-array.md
@@ -24,38 +24,60 @@ specific language governing permissions and limitations
under the License.
-->
-## TOPN_ARRAY
-### description
-#### Syntax
+## Description
-`ARRAY topn_array(expr, INT top_num[, INT space_expand_rate])`
+TOPN_ARRAY returns an array of the N most frequent values in the specified column. It is an approximate calculation function that returns results ordered by count in descending order.
-The topn function uses the Space-Saving algorithm to calculate the top_num frequent items in expr,
-and return an array about the top n nums, which is an approximation
+## Syntax
-The space_expand_rate parameter is optional and is used to set the number of counters used in the Space-Saving algorithm
+```sql
+TOPN_ARRAY(, [, ])
```
-counter numbers = top_num * space_expand_rate
-```
-The higher value of space_expand_rate, the more accurate result will be. The default value is 50
-### example
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The column or expression to be counted. |
+| `` | The number of the most frequent values to return. It must be a positive integer. |
+| `` | Optional parameter, which is used to set the number of counters used in the Space-Saving algorithm. `counter_numbers = top_num * space_expand_rate` , the larger the value of space_expand_rate, the more accurate the result, and the default value is 50. |
+
+## Return Value
+
+Return an array containing the N most frequent values.
+
+## Examples
+```sql
+-- Create sample table
+CREATE TABLE page_visits (
+ page_id INT,
+ user_id INT,
+ visit_date DATE
+) DISTRIBUTED BY HASH(page_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- Insert test data
+INSERT INTO page_visits VALUES
+(1, 101, '2024-01-01'),
+(2, 102, '2024-01-01'),
+(1, 103, '2024-01-01'),
+(3, 101, '2024-01-01'),
+(1, 104, '2024-01-01'),
+(2, 105, '2024-01-01'),
+(1, 106, '2024-01-01'),
+(4, 107, '2024-01-01');
+
+-- Find top 3 most visited pages
+SELECT TOPN_ARRAY(page_id, 3) as top_pages
+FROM page_visits;
```
-mysql> select topn_array(k3,3) from baseall;
-+--------------------------+
-| topn_array(`k3`, 3) |
-+--------------------------+
-| [3021, 2147483647, 5014] |
-+--------------------------+
-1 row in set (0.02 sec)
-
-mysql> select topn_array(k3,3,100) from baseall;
-+--------------------------+
-| topn_array(`k3`, 3, 100) |
-+--------------------------+
-| [3021, 2147483647, 5014] |
-+--------------------------+
-1 row in set (0.02 sec)
+
+```text
++-----------+
+| top_pages |
++-----------+
+| [1, 2, 4] |
++-----------+
```
-### keywords
-TOPN, TOPN_ARRAY
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/topn-weighted.md b/docs/sql-manual/sql-functions/aggregate-functions/topn-weighted.md
index 805ba0ac134ca..627abf9ce9ad0 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/topn-weighted.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/topn-weighted.md
@@ -24,37 +24,61 @@ specific language governing permissions and limitations
under the License.
-->
-## TOPN_WEIGHTED
-### description
-#### Syntax
+## Description
-`ARRAY topn_weighted(expr, BigInt weight, INT top_num[, INT space_expand_rate])`
+The TOPN_WEIGHTED function returns the N most frequent values in the specified column with weighted counting. Unlike the regular TOPN function, TOPN_WEIGHTED allows adjusting the importance of values through weights.
-The topn_weighted function is calculated using the Space-Saving algorithm, and the sum of the weights in expr is the result of the top n numbers, which is an approximate value
+## Syntax
-The space_expand_rate parameter is optional and is used to set the number of counters used in the Space-Saving algorithm
+```sql
+TOPN_WEIGHTED(, , [, ])
```
-counter numbers = top_num * space_expand_rate
-```
-The higher value of space_expand_rate, the more accurate result will be. The default value is 50
-### example
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The column or expression to be counted |
+| `` | The column or expression to adjust the weight |
+| `` | The number of the most frequent values to return. It must be a positive integer. |
+| `` | Optional, the value to set the counter_numbers used in the Space-Saving algorithm. `counter_numbers = top_num * space_expand_rate`. The value of space_expand_rate should be greater than 1, and the default value is 50. |
+
+## Return Value
+
+Return an array containing values and weighted counts.
+
+## Examples
+```sql
+-- create example table
+CREATE TABLE product_sales (
+ product_id INT,
+ sale_amount DECIMAL(10,2),
+ sale_date DATE
+) DISTRIBUTED BY HASH(product_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- insert test data
+INSERT INTO product_sales VALUES
+(1, 100.00, '2024-01-01'),
+(2, 50.00, '2024-01-01'),
+(1, 150.00, '2024-01-01'),
+(3, 75.00, '2024-01-01'),
+(1, 200.00, '2024-01-01'),
+(2, 80.00, '2024-01-01'),
+(1, 120.00, '2024-01-01'),
+(4, 90.00, '2024-01-01');
+
+-- find the top 3 products with highest sales amount
+SELECT TOPN_WEIGHTED(product_id, sale_amount, 3) as top_products
+FROM product_sales;
```
-mysql> select topn_weighted(k5,k1,3) from baseall;
-+------------------------------+
-| topn_weighted(`k5`, `k1`, 3) |
-+------------------------------+
-| [0, 243.325, 100.001] |
-+------------------------------+
-1 row in set (0.02 sec)
-
-mysql> select topn_weighted(k5,k1,3,100) from baseall;
-+-----------------------------------+
-| topn_weighted(`k5`, `k1`, 3, 100) |
-+-----------------------------------+
-| [0, 243.325, 100.001] |
-+-----------------------------------+
-1 row in set (0.02 sec)
+
+```text
++--------------+
+| top_products |
++--------------+
+| [1, 2, 4] |
++--------------+
```
-### keywords
-TOPN, TOPN_WEIGHTED
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/topn.md b/docs/sql-manual/sql-functions/aggregate-functions/topn.md
index 8ca8840b44533..eb25148fe58d2 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/topn.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/topn.md
@@ -24,38 +24,59 @@ specific language governing permissions and limitations
under the License.
-->
-## TOPN
-### description
-#### Syntax
+## Description
-`topn(expr, INT top_num[, INT space_expand_rate])`
+The TOPN function returns the N most frequent values in the specified column. It is an approximate calculation function that returns results ordered by count in descending order.
-The topn function uses the Space-Saving algorithm to calculate the top_num frequent items in expr, and the result is the
-frequent items and their occurrence times, which is an approximation
+## Syntax
-The space_expand_rate parameter is optional and is used to set the number of counters used in the Space-Saving algorithm
+```sql
+TOPN(, [, ])
```
-counter numbers = top_num * space_expand_rate
-```
-The higher value of space_expand_rate, the more accurate result will be. The default value is 50
-### example
-```
-MySQL [test]> select topn(keyword,10) from keyword_table where date>= '2020-06-01' and date <= '2020-06-19' ;
-+------------------------------------------------------------------------------------------------------------+
-| topn(`keyword`, 10) |
-+------------------------------------------------------------------------------------------------------------+
-| a:157, b:138, c:133, d:133, e:131, f:127, g:124, h:122, i:117, k:117 |
-+------------------------------------------------------------------------------------------------------------+
-
-MySQL [test]> select date,topn(keyword,10,100) from keyword_table where date>= '2020-06-17' and date <= '2020-06-19' group by date;
-+------------+-----------------------------------------------------------------------------------------------+
-| date | topn(`keyword`, 10, 100) |
-+------------+-----------------------------------------------------------------------------------------------+
-| 2020-06-19 | a:11, b:8, c:8, d:7, e:7, f:7, g:7, h:7, i:7, j:7 |
-| 2020-06-18 | a:10, b:8, c:7, f:7, g:7, i:7, k:7, l:7, m:6, d:6 |
-| 2020-06-17 | a:9, b:8, c:8, j:8, d:7, e:7, f:7, h:7, i:7, k:7 |
-+------------+-----------------------------------------------------------------------------------------------+
+## Parameters
+| Parameter | Description |
+| -- | -- |
+| `` | The column or expression to be counted. |
+| `` | The number of the most frequent values to return. It must be a positive integer. |
+| `` | Optional parameter, which is used to set the number of counters used in the Space-Saving algorithm. `counter_numbers = top_num * space_expand_rate` , the larger the value of space_expand_rate, the more accurate the result, and the default value is 50. |
+
+## Return Value
+
+Returns a JSON string containing values and their corresponding occurrence counts.
+
+## Examples
+```sql
+-- Create sample table
+CREATE TABLE page_visits (
+ page_id INT,
+ user_id INT,
+ visit_date DATE
+) DISTRIBUTED BY HASH(page_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- Insert test data
+INSERT INTO page_visits VALUES
+(1, 101, '2024-01-01'),
+(2, 102, '2024-01-01'),
+(1, 103, '2024-01-01'),
+(3, 101, '2024-01-01'),
+(1, 104, '2024-01-01'),
+(2, 105, '2024-01-01'),
+(1, 106, '2024-01-01'),
+(4, 107, '2024-01-01');
+
+-- Find top 3 most visited pages
+SELECT TOPN(page_id, 3) as top_pages
+FROM page_visits;
```
-### keywords
-TOPN
\ No newline at end of file
+
+```text
++---------------------+
+| top_pages |
++---------------------+
+| {"1":4,"2":2,"4":1} |
++---------------------+
+```
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/var-samp.md b/docs/sql-manual/sql-functions/aggregate-functions/var-samp.md
index 8fe7ad5a39f7e..40b7abfae8dd0 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/var-samp.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/var-samp.md
@@ -1,6 +1,6 @@
---
{
- "title": "VARIANCE_SAMP,VARIANCE_SAMP",
+ "title": "VAR_SAMP,VARIANCE_SAMP",
"language": "en"
}
---
@@ -24,23 +24,62 @@ specific language governing permissions and limitations
under the License.
-->
-## VARIANCE_SAMP,VARIANCE_SAMP
-### Description
-#### Syntax
+## Description
-`VAR SAMP (expr)`
+The VAR_SAMP function calculates the sample variance of a specified expression. Unlike VARIANCE (population variance), VAR_SAMP uses n-1 as the divisor, which is considered an unbiased estimate of the population variance in statistics.
+## Alias
-Returns the sample variance of the expr expression
+- VARIANCE_SAMP
-### example
+## Syntax
+
+```sql
+VAR_SAMP()
```
-MySQL > select var_samp(scan_rows) from log_statis group by datetime;
-+-----------------------+
-| var_samp(`scan_rows`) |
-+-----------------------+
-| 5.6227132145741789 |
-+-----------------------+
+
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | The column or expression to calculate sample variance for. Must be numeric type |
+
+## Return Value
+Returns a DOUBLE value representing the calculated sample variance.
+
+## Examples
+```sql
+-- Create sample table
+CREATE TABLE student_scores (
+ student_id INT,
+ score DECIMAL(4,1)
+) DISTRIBUTED BY HASH(student_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- Insert test data
+INSERT INTO student_scores VALUES
+(1, 85.5),
+(2, 92.0),
+(3, 78.5),
+(4, 88.0),
+(5, 95.5),
+(6, 82.0),
+(7, 90.0),
+(8, 87.5);
+
+-- Calculate sample variance of student scores
+SELECT
+ VAR_SAMP(score) as sample_variance,
+ VARIANCE(score) as population_variance
+FROM student_scores;
+```
+
+```text
++------------------+---------------------+
+| sample_variance | population_variance |
++------------------+---------------------+
+| 29.4107142857143 | 25.73437500000001 |
++------------------+---------------------+
```
-### keywords
-VAR SAMP, VARIANCE SAMP,VAR,SAMP,VARIANCE
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/variance.md b/docs/sql-manual/sql-functions/aggregate-functions/variance.md
index f58da61bf708f..5e43d59eddfd8 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/variance.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/variance.md
@@ -24,30 +24,59 @@ specific language governing permissions and limitations
under the License.
-->
-## VARIANCE,VAR_POP,VARIANCE_POP
-### Description
-#### Syntax
+## Description
-`VARIANCE(expr)`
+The VARIANCE function calculates the statistical variance of the specified expression. It measures how far a set of numbers are spread out from their arithmetic mean.
+## Alias
-Returns the variance of the expr expression
+- VAR_POP
+- VARIANCE_POP
-### example
+## Syntax
+
+```sql
+VARIANCE()
```
-MySQL > select variance(scan_rows) from log_statis group by datetime;
-+-----------------------+
-| variance(`scan_rows`) |
-+-----------------------+
-| 5.6183332881176211 |
-+-----------------------+
-
-MySQL > select var_pop(scan_rows) from log_statis group by datetime;
-+----------------------+
-| var_pop(`scan_rows`) |
-+----------------------+
-| 5.6230744719006163 |
-+----------------------+
+
+## Parameters
+| Parameter | Description |
+| -- | -- |
+| `` | The column or expression to calculate variance for. Must be numeric type |
+
+## Return Value
+Returns a DOUBLE value representing the calculated variance.
+
+## Examples
+```sql
+-- Create sample table
+CREATE TABLE student_scores (
+ student_id INT,
+ score DECIMAL(4,1)
+) DISTRIBUTED BY HASH(student_id)
+PROPERTIES (
+ "replication_num" = "1"
+);
+
+-- Insert test data
+INSERT INTO student_scores VALUES
+(1, 85.5),
+(2, 92.0),
+(3, 78.5),
+(4, 88.0),
+(5, 95.5),
+(6, 82.0),
+(7, 90.0),
+(8, 87.5);
+-- Calculate variance of student scores
+SELECT VARIANCE(score) as score_variance
+FROM student_scores;
+```
+
+```text
++-------------------+
+| score_variance |
++-------------------+
+| 25.73437499999998 |
++-------------------+
```
-### keywords
-VARIANCE,VAR_POP,VARIANCE_POP,VAR,POP
diff --git a/docs/sql-manual/sql-functions/aggregate-functions/window-funnel.md b/docs/sql-manual/sql-functions/aggregate-functions/window-funnel.md
index 47d440b958049..4e4e361e72f37 100644
--- a/docs/sql-manual/sql-functions/aggregate-functions/window-funnel.md
+++ b/docs/sql-manual/sql-functions/aggregate-functions/window-funnel.md
@@ -11,19 +11,9 @@
Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License. -->
-## WINDOW FUNCTION WINDOW_FUNNEL
-### description
+## Description
-Searches for event chains in a sliding time window and calculates the maximum number of events that occurred from the chain.
-
-- window is the length of time window in seconds.
-- mode can be one of the followings:
- - "default": Defualt mode.
- - "deduplication": If the same event holds for the sequence of events, then such repeating event interrupts further processing. E.g. the array parameter is [event1='A', event2='B', event3='C', event4='D'], and the original event chain is "A-B-C-B-D". Since event B repeats, the filtered event chain can only be "A-B-C" and the max event level is 3.
- - "fixed": Don't allow interventions of other events. E.g. the array parameter is [event1='A', event2='B', event3='C', event4='D'], and the original event chain is A->B->D->C, it stops finding A->B->C at the D and the max event level is 2.
- - "increase": Apply conditions only to events with strictly increasing timestamps.
-- timestamp_column specifies column of DATETIME type, sliding time window works on it.
-- evnetN is boolean expression like eventID = 1004.
+The WINDOW_FUNNEL function analyzes user behavior sequences by searching for event chains within a specified time window and calculating the maximum number of completed steps in the event chain. This function is particularly useful for conversion funnel analysis, such as analyzing user conversion from website visits to final purchases.
The function works according to the algorithm:
@@ -31,15 +21,35 @@ The function works according to the algorithm:
- If events from the chain occur sequentially within the window, the counter is incremented. If the sequence of events is disrupted, the counter is not incremented.
- If the data has multiple event chains at varying points of completion, the function will only output the size of the longest chain.
+## Syntax
+
```sql
-window_funnel(window, mode, timestamp_column, event1, event2, ... , eventN)
+WINDOW_FUNNEL(, , , [, event_2, ... , event_n])
```
-### example
+## Parameters
+
+| Parameter | Description |
+| -- | -- |
+| `` | window is the length of time window in seconds |
+| `` | There are four modes in total, `default`, `deduplication`, `fixed`, and `increase`. For details, please refer to the **Mode** below. |
+| `` | timestamp specifies column of DATETIME type, sliding time window works on it |
+| `` | evnet_n is boolean expression like eventID = 1004 |
+
+**Mode**
+ - `default`: Defualt mode.
+ - `deduplication`: If the same event holds for the sequence of events, then such repeating event interrupts further processing. E.g. the array parameter is [event1='A', event2='B', event3='C', event4='D'], and the original event chain is "A-B-C-B-D". Since event B repeats, the filtered event chain can only be "A-B-C" and the max event level is 3.
+ - `fixed`: Don't allow interventions of other events. E.g. the array parameter is [event1='A', event2='B', event3='C', event4='D'], and the original event chain is A->B->D->C, it stops finding A->B->C at the D and the max event level is 2.
+ - `increase`: Apply conditions only to events with strictly increasing timestamps.
-#### example1: default mode
+## Return Value
+Returns an integer representing the maximum number of consecutive steps completed within the specified time window.
-Using the ```default``` mode, find out the maximum number of consecutive events corresponding to different ```user_id```, with a time window of ```5``` minutes:
+## Examples
+
+### example1: default mode
+
+Using the `default` mode, find out the maximum number of consecutive events corresponding to different `user_id`, with a time window of `5` minutes:
```sql
CREATE TABLE events(
@@ -82,7 +92,9 @@ GROUP BY
user_id
order BY
user_id;
+```
+```text
+---------+-------+
| user_id | level |
+---------+-------+
@@ -93,11 +105,11 @@ order BY
+---------+-------+
```
-For ```uesr_id=100123```, because the time when the ```payment``` event occurred exceeds the time window, the matched event chain is ```login-visit-order```.
+For `uesr_id=100123`, because the time when the `payment` event occurred exceeds the time window, the matched event chain is `login-visit-order`.
-#### example2: deduplication mode
+### example2: deduplication mode
-Use the ```deduplication``` mode to find out the maximum number of consecutive events corresponding to different user_ids, with a time window of 1 hour:
+Use the `deduplication` mode to find out the maximum number of consecutive events corresponding to different user_ids, with a time window of 1 hour:
```sql
CREATE TABLE events(
@@ -141,7 +153,9 @@ GROUP BY
user_id
order BY
user_id;
+```
+```text
+---------+-------+
| user_id | level |
+---------+-------+
@@ -151,11 +165,11 @@ order BY
| 100127 | 2 |
+---------+-------+
```
-For ```uesr_id=100123```, after matching the ```visit``` event, the ```login``` event appears repeatedly, so the matched event chain is ```login-visit```.
+For `uesr_id=100123`, after matching the `visit` event, the `login` event appears repeatedly, so the matched event chain is `login-visit`.
-#### example3: fixed mode
+### example3: fixed mode
-Use the ```fixed``` mode to find out the maximum number of consecutive events corresponding to different ```user_id```, with a time window of ```1``` hour:
+Use the `fixed` mode to find out the maximum number of consecutive events corresponding to different `user_id`, with a time window of `1` hour:
```sql
CREATE TABLE events(
@@ -199,7 +213,9 @@ GROUP BY
user_id
order BY
user_id;
+```
+```text
+---------+-------+
| user_id | level |
+---------+-------+
@@ -209,11 +225,11 @@ order BY
| 100127 | 2 |
+---------+-------+
```
-For ```uesr_id=100123```, after matching the ```order``` event, the event chain is interrupted by the ```login2``` event, so the matched event chain is ```login-visit-order```.
+For `uesr_id=100123`, after matching the `order` event, the event chain is interrupted by the `login2` event, so the matched event chain is `login-visit-order`.
-#### example4: increase mode
+### example4: increase mode
-Use the ```increase``` mode to find out the maximum number of consecutive events corresponding to different ```user_id```, with a time window of ```1``` hour:
+Use the `increase` mode to find out the maximum number of consecutive events corresponding to different `user_id`, with a time window of `1` hour:
```sql
CREATE TABLE events(
@@ -256,7 +272,9 @@ GROUP BY
user_id
order BY
user_id;
+```
+```text
+---------+-------+
| user_id | level |
+---------+-------+
@@ -266,9 +284,4 @@ order BY
| 100127 | 2 |
+---------+-------+
```
-For ```uesr_id=100123```, the timestamp of the ```payment``` event and the timestamp of the ```order``` event occur in the same second and are not incremented, so the matched event chain is ```login-visit-order```.
-
-
-### keywords
-
- WINDOW,FUNCTION,WINDOW_FUNNEL
+For `uesr_id=100123`, the timestamp of the `payment` event and the timestamp of the `order` event occur in the same second and are not incremented, so the matched event chain is `login-visit-order`.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-add.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-add.md
index ddd3ee704c4b1..9863806bac137 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-add.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-add.md
@@ -24,27 +24,37 @@ specific language governing permissions and limitations
under the License.
-->
-## hours_add
-### description
-#### Syntax
+## Description
-`DATETIME HOURS_ADD(DATETIME date, INT hours)`
+Returns a new datetime value that is the result of adding a specified number of hours to the input datetime.
-Add specified hours from date time or date
+## Syntax
-The parameter date can be DATETIME or DATE, and the return type is DATETIME.
+```sql
+HOURS_ADD(, )
+```
-### example
+## Parameters
-```
-mysql> select hours_add("2020-02-02 02:02:02", 1);
-+-------------------------------------+
-| hours_add('2020-02-02 02:02:02', 1) |
-+-------------------------------------+
-| 2020-02-02 03:02:02 |
-+-------------------------------------+
-```
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, which can be of type DATETIME or DATE |
+| `` | The number of hours to add, of type INT |
+
+## Return Value
-### keywords
+Returns a value of type DATETIME, representing the time value after adding the specified number of hours to the input datetime.
- HOURS_ADD
+## Example
+
+```sql
+SELECT HOURS_ADD('2020-02-02 02:02:02', 1);
+```
+
+```text
++------------------------------------------------------------+
+| hours_add(cast('2020-02-02 02:02:02' as DATETIMEV2(0)), 1) |
++------------------------------------------------------------+
+| 2020-02-02 03:02:02 |
++------------------------------------------------------------+
+```
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-diff.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-diff.md
index f299f8d15c6d8..78e690f7bf8ea 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-diff.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-diff.md
@@ -24,25 +24,37 @@ specific language governing permissions and limitations
under the License.
-->
-## hours_diff
-### description
-#### Syntax
+## Description
-`INT hours_diff(DATETIME enddate, DATETIME startdate)`
+Calculates the difference in hours between the start time and the end time.
-The difference between the start time and the end time is a few hours
+## Syntax
-### example
-
-```
-mysql> select hours_diff('2020-12-25 22:00:00','2020-12-25 21:00:00');
-+----------------------------------------------------------+
-| hours_diff('2020-12-25 22:00:00', '2020-12-25 21:00:00') |
-+----------------------------------------------------------+
-| 1 |
-+----------------------------------------------------------+
+```sql
+HOURS_DIFF(, )
```
-### keywords
+## Parameters
+
+| Parameter | Description |
+|------------|-------------------------------------------------|
+| `` | The end time, which can be of type DATETIME or DATE |
+| `` | The start time, which can be of type DATETIME or DATE |
+
+## Return Value
+
+Returns an INT type representing the number of hours between the start time and the end time.
+
+## Example
+
+```sql
+SELECT HOURS_DIFF('2020-12-25 22:00:00', '2020-12-25 21:00:00');
+```
- hours_diff
+```text
++--------------------------------------------------------------------------------------------------------+
+| hours_diff(cast('2020-12-25 22:00:00' as DATETIMEV2(0)), cast('2020-12-25 21:00:00' as DATETIMEV2(0))) |
++--------------------------------------------------------------------------------------------------------+
+| 1 |
++--------------------------------------------------------------------------------------------------------+
+```
\ No newline at end of file
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-sub.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-sub.md
index 7bb2ba1f75d0b..234d0c5ef41cd 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-sub.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/hours-sub.md
@@ -24,27 +24,37 @@ specific language governing permissions and limitations
under the License.
-->
-## hours_sub
-### description
-#### Syntax
+## Description
-`DATETIME HOURS_SUB(DATETIME date, INT hours)`
+Returns a new datetime value that is the result of subtracting a specified number of hours from the input datetime.
-Subtracts a specified number of hours from a datetime or date
+## Syntax
-The parameter date can be DATETIME or DATE, and the return type is DATETIME.
+```sql
+HOURS_SUB(, )
+```
-### example
+## Parameters
-```
-mysql> select hours_sub("2020-02-02 02:02:02", 1);
-+-------------------------------------+
-| hours_sub('2020-02-02 02:02:02', 1) |
-+-------------------------------------+
-| 2020-02-02 01:02:02 |
-+-------------------------------------+
-```
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, which can be of type DATETIME or DATE |
+| `` | The number of hours to subtract, of type INT |
+
+## Return Value
-### keywords
+Returns a value of type DATETIME, representing the time value after subtracting the specified number of hours from the input datetime.
- HOURS_SUB
+## Example
+
+```sql
+SELECT HOURS_SUB('2020-02-02 02:02:02', 1);
+```
+
+```text
++------------------------------------------------------------+
+| hours_sub(cast('2020-02-02 02:02:02' as DATETIMEV2(0)), 1) |
++------------------------------------------------------------+
+| 2020-02-02 01:02:02 |
++------------------------------------------------------------+
+```
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/last-day.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/last-day.md
index 0eb3956f4bb84..6e2dc10cf0e09 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/last-day.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/last-day.md
@@ -22,28 +22,40 @@ specific language governing permissions and limitations
under the License.
-->
-## last_day
-### Description
-#### Syntax
+## Description
-`DATE last_day(DATETIME date)`
+Returns the date of the last day of the month for the given input date. The returned day varies depending on the month:
+- 28th - For February in non-leap years
+- 29th - For February in leap years
+- 30th - For April, June, September, and November
+- 31st - For January, March, May, July, August, October, and December
-Return the last day of the month, the return day may be :
-'28'(February and not a leap year),
-'29'(February and a leap year),
-'30'(April, June, September, November),
-'31'(January, March, May, July, August, October, December)
-
-### example
+## Syntax
+```sql
+LAST_DAY()
```
-mysql > select last_day('2000-02-03');
-+-------------------+
-| last_day('2000-02-03 00:00:00') |
-+-------------------+
-| 2000-02-29 |
-+-------------------+
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | Input datetime value, type can be DATETIME or DATE |
+
+## Return Value
+
+Returns a value of type DATE representing the last day of the month for the given input date.
+
+## Example
+
+```sql
+SELECT LAST_DAY('2000-02-03');
```
-### keywords
- LAST_DAY,DAYS
+```text
++-----------------------------------------------+
+| last_day(cast('2000-02-03' as DATETIMEV2(0))) |
++-----------------------------------------------+
+| 2000-02-29 |
++-----------------------------------------------+
+```
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/makedate.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/makedate.md
index 83b091409d934..19461f14de550 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/makedate.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/makedate.md
@@ -24,22 +24,42 @@ specific language governing permissions and limitations
under the License.
-->
-## makedate
-### Description
-#### Syntax
-`DATE MAKEDATE(INT year, INT dayofyear)`
+## Description
-Returns a date, given year and day-of-year values. dayofyear must be greater than 0 or the result is NULL.
+Returns a date based on the specified year and the day of the year (dayofyear).
-### example
+Special cases:
+- Returns NULL when `dayofyear` is less than or equal to 0.
+- Automatically rolls over to the next year if `dayofyear` exceeds the number of days in the year.
+
+## Syntax
+
+```sql
+MAKEDATE(, )
+```
+
+## Parameters
+
+| Parameter | Description |
+|-------------|-------------------------------------------|
+| `` | The specified year, of type INT |
+| `` | The day of the year (1-366), of type INT |
+
+## Return Value
+
+Returns a value of type DATE, constructed from the specified year and the given day of the year.
+
+## Example
+
+```sql
+SELECT MAKEDATE(2021, 1), MAKEDATE(2021, 100), MAKEDATE(2021, 400);
```
-mysql> select makedate(2021,1), makedate(2021,100), makedate(2021,400);
+
+```text
+-------------------+---------------------+---------------------+
| makedate(2021, 1) | makedate(2021, 100) | makedate(2021, 400) |
+-------------------+---------------------+---------------------+
| 2021-01-01 | 2021-04-10 | 2022-02-04 |
+-------------------+---------------------+---------------------+
```
-### keywords
- MAKEDATE
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microsecond.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microsecond.md
index a99ad0b4c8e33..2a5191e01cb5e 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microsecond.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microsecond.md
@@ -24,25 +24,37 @@ specific language governing permissions and limitations
under the License.
-->
-## microsecond
-### description
-#### Syntax
-`INT MICROSECOND(DATETIMEV2 date)`
+## Description
-Returns microsecond information in the time type.
+Extracts the microsecond part from a datetime value. The returned range is from 0 to 999999.
-The parameter is Datetime type
+## Syntax
-### example
+```sql
+MICROSECOND()
+```
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, of type DATETIMEV2, with a precision greater than 0 |
+
+## Return Value
+Returns an INT type representing the microsecond part of the datetime value. The range is from 0 to 999999. For inputs with a precision less than 6, the missing digits are padded with zeros.
+
+## Example
+
+```sql
+SELECT MICROSECOND(CAST('1999-01-02 10:11:12.000123' AS DATETIMEV2(6))) AS microsecond;
```
-mysql> select microsecond(cast('1999-01-02 10:11:12.000123' as datetimev2(6))) as microsecond;
+
+```text
+-------------+
| microsecond |
+-------------+
| 123 |
+-------------+
```
-### keywords
- MICROSECOND
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-add.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-add.md
index 106e015dfa70d..f0fef6608c18e 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-add.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-add.md
@@ -24,27 +24,42 @@ specific language governing permissions and limitations
under the License.
-->
-## microseconds_add
-### description
-#### Syntax
-`DATETIMEV2 microseconds_add(DATETIMEV2 basetime, INT delta)`
-- basetime: Base time whose type is DATETIMEV2
-- delta: Microseconds to add to basetime
-- Return type of this function is DATETIMEV2
+## Description
-### example
+Adds a specified number of microseconds to a datetime value and returns a new datetime value.
+
+## Syntax
+
+```sql
+MICROSECONDS_ADD(, )
```
-mysql> select now(3), microseconds_add(now(3), 100000);
-+-------------------------+----------------------------------+
-| now(3) | microseconds_add(now(3), 100000) |
-+-------------------------+----------------------------------+
-| 2023-02-21 11:35:56.556 | 2023-02-21 11:35:56.656 |
-+-------------------------+----------------------------------+
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, of type DATETIMEV2 |
+| `` | The number of microseconds to add, of type INT; 1 second = 1,000,000 microseconds |
+
+## Return Value
+
+Returns a value of type DATETIMEV2, representing the time value after adding the specified number of microseconds to the input datetime. The precision of the return value is the same as that of the input parameter basetime.
+
+## Example
+
+```sql
+SELECT NOW(3) AS current_time, MICROSECONDS_ADD(NOW(3), 100000) AS after_add;
```
-`now(3)` returns current time as type DATETIMEV2 with precision 3d,`microseconds_add(now(3), 100000)` means 100000 microseconds after current time
-### keywords
- microseconds_add
+```text
++-------------------------+----------------------------+
+| current_time | after_add |
++-------------------------+----------------------------+
+| 2025-01-16 11:48:10.505 | 2025-01-16 11:48:10.605000 |
++-------------------------+----------------------------+
+```
-
\ No newline at end of file
+**Note:**
+- `NOW(3)` returns the current time with a precision of 3 decimal places.
+- After adding 100000 microseconds (0.1 seconds), the time increases by 0.1 seconds.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-diff.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-diff.md
index 7a48fc117b59c..04254f2cd54d0 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-diff.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-diff.md
@@ -24,26 +24,41 @@ specific language governing permissions and limitations
under the License.
-->
-## microseconds_diff
-### description
-#### Syntax
-`INT microseconds_diff(DATETIME enddate, DATETIME startdate)`
+## Description
-How many microseconds is the difference between the start time and the end time.
+Calculates the microsecond difference between two datetime values. The result is the number of microseconds from `` subtracted from ``.
-### example
+## Syntax
+```sql
+MICROSECONDS_DIFF(, )
```
-mysql> select microseconds_diff('2020-12-25 21:00:00.623000','2020-12-25 21:00:00.123000');
+
+## Parameters
+
+| Parameter | Description |
+|------------|-------------------------------------------------|
+| `` | The end time, of type DATETIMEV2 |
+| `` | The start time, of type DATETIMEV2 |
+
+## Return Value
+
+Returns an INT type representing the microsecond difference between the two times.
+- Returns a positive number if `` is greater than ``.
+- Returns a negative number if `` is less than ``.
+- 1 second = 1,000,000 microseconds.
+
+## Example
+
+```sql
+SELECT MICROSECONDS_DIFF('2020-12-25 21:00:00.623000', '2020-12-25 21:00:00.123000');
+```
+
+```text
+-----------------------------------------------------------------------------------------------------------------------------+
-| microseconds_diff(cast('2020-12-25 21:00:00.623000' as DATETIMEV2(6)), cast('2020-12-25 21:00:00.123000' as DATETIMEV2(6))) |
+| microseconds_diff(cast('2020-12-25 21:00:00.623000' as DATETIMEV2(3)), cast('2020-12-25 21:00:00.123000' as DATETIMEV2(3))) |
+-----------------------------------------------------------------------------------------------------------------------------+
| 500000 |
+-----------------------------------------------------------------------------------------------------------------------------+
-1 row in set (0.12 sec)
```
-
-### keywords
-
- microseconds_diff
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-sub.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-sub.md
index 439bc2a37429b..c7a61d509bce4 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-sub.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/microseconds-sub.md
@@ -24,25 +24,43 @@ specific language governing permissions and limitations
under the License.
-->
-## microseconds_sub
-### description
-#### Syntax
-`DATETIMEV2 microseconds_sub(DATETIMEV2 basetime, INT delta)`
-- basetime: Base time whose type is DATETIMEV2
-- delta: Microseconds to subtract from basetime
-- Return type of this function is DATETIMEV2
+## Description
-### example
+Subtracts a specified number of microseconds from a datetime value and returns a new datetime value.
+
+## Syntax
+
+```sql
+MICROSECONDS_SUB(, )
+```
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, of type DATETIMEV2 |
+| `` | The number of microseconds to subtract, of type INT; 1 second = 1,000,000 microseconds |
+
+## Return Value
+
+Returns a value of type DATETIMEV2, representing the time value after subtracting the specified number of microseconds from the input datetime. The precision of the return value is the same as that of the input parameter basetime.
+
+## Example
+
+```sql
+SELECT NOW(3) AS current_time, MICROSECONDS_SUB(NOW(3), 100000) AS after_sub;
```
-mysql> select now(3), microseconds_sub(now(3), 100000);
-+-------------------------+----------------------------------+
-| now(3) | microseconds_sub(now(3), 100000) |
-+-------------------------+----------------------------------+
-| 2023-02-25 02:03:05.174 | 2023-02-25 02:03:05.074 |
-+-------------------------+----------------------------------+
+
+```text
++-------------------------+----------------------------+
+| current_time | after_sub |
++-------------------------+----------------------------+
+| 2025-01-16 11:52:22.296 | 2025-01-16 11:52:22.196000 |
++-------------------------+----------------------------+
```
-`now(3)` returns current time as type DATETIMEV2 with precision `3`,`microseconds_sub(now(3), 100000)` means 100000 microseconds before current time
-### keywords
- microseconds_sub
+**Note:**
+- `NOW(3)` returns the current time with a precision of 3 decimal places.
+- After subtracting 100000 microseconds (0.1 seconds), the time decreases by 0.1 seconds.
+- The function's result is dependent on the precision of the input time.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-add.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-add.md
index 4d2c2f27d2221..bdd66319310ce 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-add.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-add.md
@@ -24,28 +24,43 @@ specific language governing permissions and limitations
under the License.
-->
-## milliseconds_add
-### description
-#### Syntax
-`DATETIMEV2 milliseconds_add(DATETIMEV2 basetime, INT delta)`
-- basetime: Base time whose type is DATETIMEV2
-- delta:Milliseconds to add to basetime
-- Return type of this function is DATETIMEV2
+## Description
-### example
+Adds a specified number of milliseconds to a datetime value and returns a new datetime value.
+
+## Syntax
+
+```sql
+MILLISECONDS_ADD(, )
+```
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, of type DATETIMEV2 |
+| `` | The number of milliseconds to add, of type INT; 1 second = 1,000 milliseconds = 1,000,000 microseconds |
+
+## Return Value
+
+Returns a value of type DATETIMEV2, representing the time value after adding the specified number of milliseconds to the input datetime. The precision of the return value is the same as that of the input parameter basetime.
+
+## Example
+
+```sql
+SELECT MILLISECONDS_ADD('2023-09-08 16:02:08.435123', 1);
```
-mysql> select milliseconds_add('2023-09-08 16:02:08.435123', 1);
+
+```text
+--------------------------------------------------------------------------+
| milliseconds_add(cast('2023-09-08 16:02:08.435123' as DATETIMEV2(6)), 1) |
+--------------------------------------------------------------------------+
| 2023-09-08 16:02:08.436123 |
+--------------------------------------------------------------------------+
-1 row in set (0.04 sec)
```
-
-### keywords
- milliseconds_add
-
-
\ No newline at end of file
+**Note:**
+- In the example, after adding 1 millisecond, the time increases from .435123 to .436123.
+- 1 millisecond equals 1000 microseconds.
+- The function's result is dependent on the precision of the input time; the example uses a precision of 6 decimal places.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-diff.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-diff.md
index 94f4b678e3a47..071bf8fac6e77 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-diff.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-diff.md
@@ -24,26 +24,47 @@ specific language governing permissions and limitations
under the License.
-->
-## milliseconds_diff
-### description
-#### Syntax
-`INT milliseconds_diff(DATETIME enddate, DATETIME startdate)`
+## Description
-How many milliseconds is the difference between the start time and the end time?
+Calculates the millisecond difference between two datetime values. The result is the number of milliseconds from `` subtracted from ``.
-### example
+## Syntax
+```sql
+MILLISECONDS_DIFF(, )
```
-mysql> select milliseconds_diff('2020-12-25 21:00:00.623000','2020-12-25 21:00:00.123000');
+
+## Parameters
+
+| Parameter | Description |
+|------------|-------------------------------------------------|
+| `` | The end time, of type DATETIMEV2 |
+| `` | The start time, of type DATETIMEV2 |
+
+## Return Value
+
+Returns an INT type representing the millisecond difference between the two times.
+- Returns a positive number if `` is greater than ``.
+- Returns a negative number if `` is less than ``.
+- 1 second = 1,000 milliseconds.
+- 1 millisecond = 1,000 microseconds.
+
+## Example
+
+```sql
+SELECT MILLISECONDS_DIFF('2020-12-25 21:00:00.623000', '2020-12-25 21:00:00.123000');
+```
+
+```text
+-----------------------------------------------------------------------------------------------------------------------------+
-| milliseconds_diff(cast('2020-12-25 21:00:00.623000' as DATETIMEV2(6)), cast('2020-12-25 21:00:00.123000' as DATETIMEV2(6))) |
+| milliseconds_diff(cast('2020-12-25 21:00:00.623000' as DATETIMEV2(3)), cast('2020-12-25 21:00:00.123000' as DATETIMEV2(3))) |
+-----------------------------------------------------------------------------------------------------------------------------+
| 500 |
+-----------------------------------------------------------------------------------------------------------------------------+
-1 row in set (0.03 sec)
```
-### keywords
-
- milliseconds_diff
+**Note:**
+- The time difference in the example is 0.5 seconds, which equals 500 milliseconds.
+- The function's result is dependent on the precision of the input time; the example uses a precision of 3 decimal places.
+- The result only returns the millisecond difference and does not include the microsecond part.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-sub.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-sub.md
index 500579d5a07cb..806b96d80ad5c 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-sub.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/milliseconds-sub.md
@@ -24,18 +24,35 @@ specific language governing permissions and limitations
under the License.
-->
-## milliseconds_sub
-### description
-#### Syntax
-`DATETIMEV2 milliseconds_sub(DATETIMEV2 basetime, INT delta)`
-- basetime: Base time whose type is DATETIMEV2
-- delta: Milliseconds to subtract from basetime
-- Return type of this function is DATETIMEV2
+## Description
-### example
+Subtracts a specified number of milliseconds from a datetime value and returns a new datetime value.
+
+## Syntax
+
+```sql
+MILLISECONDS_SUB(, )
+```
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, of type DATETIMEV2 |
+| `` | The number of milliseconds to subtract, of type INT; 1 second = 1,000 milliseconds = 1,000,000 microseconds |
+
+## Return Value
+
+Returns a value of type DATETIMEV2, representing the time value after subtracting the specified number of milliseconds from the input datetime. The precision of the return value is the same as that of the input parameter basetime.
+
+## Example
+
+```sql
+SELECT MILLISECONDS_SUB('2023-09-08 16:02:08.435123', 1);
```
-mysql> select milliseconds_sub('2023-09-08 16:02:08.435123', 1);
+
+```text
+--------------------------------------------------------------------------+
| milliseconds_sub(cast('2023-09-08 16:02:08.435123' as DATETIMEV2(6)), 1) |
+--------------------------------------------------------------------------+
@@ -44,8 +61,8 @@ mysql> select milliseconds_sub('2023-09-08 16:02:08.435123', 1);
1 row in set (0.11 sec)
```
-
-### keywords
- milliseconds_sub
-
-
\ No newline at end of file
+**Note:**
+- In the example, after subtracting 1 millisecond, the time decreases from .435123 to .434123.
+- 1 millisecond equals 1000 microseconds.
+- The function's result is dependent on the precision of the input time; the example uses a precision of 6 decimal places.
+- The result retains microsecond-level precision.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute-ceil.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute-ceil.md
index 36e8b809e1ca6..e2eb8911a3ed5 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute-ceil.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute-ceil.md
@@ -1,6 +1,6 @@
---
{
- "title": "minute_ceil",
+ "title": "MINUTE_CEIL",
"language": "en"
}
---
@@ -24,39 +24,51 @@ specific language governing permissions and limitations
under the License.
-->
-## minute_ceil
-### description
-#### Syntax
+
+## Description
+
+Rounds up a datetime value to the nearest specified minute interval. If a starting time (origin) is provided, it uses that time as the reference for calculating the interval.
+
+## Syntax
```sql
-DATETIME MINUTE_CEIL(DATETIME datetime)
-DATETIME MINUTE_CEIL(DATETIME datetime, DATETIME origin)
-DATETIME MINUTE_CEIL(DATETIME datetime, INT period)
-DATETIME MINUTE_CEIL(DATETIME datetime, INT period, DATETIME origin)
+MINUTE_CEIL()
+MINUTE_CEIL(, )
+MINUTE_CEIL(, )
+MINUTE_CEIL(, , )
```
-Convert the date to the nearest rounding up time of the specified time interval period.
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The datetime value to round up, of type DATETIME or DATETIMEV2 |
+| `` | The minute interval value, of type INT, representing the number of minutes in each interval |
+| `` | The starting point for the interval, of type DATETIME or DATETIMEV2; defaults to 0001-01-01 00:00:00 |
-- datetime: a valid date expression.
-- period: specifies how many minutes each cycle consists of.
-- origin: starting from 0001-01-01T00:00:00.
+## Return Value
-### example
+Returns a value of type DATETIMEV2, representing the rounded-up datetime value based on the specified minute interval. The precision of the return value is the same as that of the input parameter datetime.
+## Example
+
+```sql
+SELECT MINUTE_CEIL("2023-07-13 22:28:18", 5);
```
-mysql> select minute_ceil("2023-07-13 22:28:18", 5);
+
+```text
+--------------------------------------------------------------+
| minute_ceil(cast('2023-07-13 22:28:18' as DATETIMEV2(0)), 5) |
+--------------------------------------------------------------+
| 2023-07-13 22:30:00 |
+--------------------------------------------------------------+
-1 row in set (0.21 sec)
```
-### keywords
-
- MINUTE_CEIL, MINUTE, CEIL
+**Note:**
+- If no period is specified, it defaults to a 1-minute interval.
+- The period must be a positive integer.
+- The result is always rounded up to a future time.
-### Best Practice
+## Best Practices
See also [date_ceil](./date_ceil)
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute-floor.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute-floor.md
index afe9f8ac3e89c..bf644db01d0f3 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute-floor.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute-floor.md
@@ -1,6 +1,6 @@
---
{
- "title": "minute_floor",
+ "title": "MINUTE_FLOOR",
"language": "en"
}
---
@@ -24,39 +24,52 @@ specific language governing permissions and limitations
under the License.
-->
-## minute_floor
-### description
-#### Syntax
+
+## Description
+
+Rounds down a datetime value to the nearest specified minute interval. If a starting time (origin) is provided, it uses that time as the reference for calculating the interval.
+
+## Syntax
```sql
-DATETIME MINUTE_FLOOR(DATETIME datetime)
-DATETIME MINUTE_FLOOR(DATETIME datetime, DATETIME origin)
-DATETIME MINUTE_FLOOR(DATETIME datetime, INT period)
-DATETIME MINUTE_FLOOR(DATETIME datetime, INT period, DATETIME origin)
+MINUTE_FLOOR()
+MINUTE_FLOOR(, )
+MINUTE_FLOOR(, )
+MINUTE_FLOOR(, , )
```
-Convert the date to the nearest rounding down time of the specified time interval period.
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The datetime value to round down, of type DATETIME or DATETIMEV2 |
+| `` | The minute interval value, of type INT, representing the number of minutes in each interval |
+| `` | The starting point for the interval, of type DATETIME or DATETIMEV2; defaults to 0001-01-01 00:00:00 |
-- datetime: a valid date expression.
-- period: specifies how many minutes each cycle consists of.
-- origin: starting from 0001-01-01T00:00:00.
+## Return Value
-### example
+Returns a value of type DATETIMEV2, representing the rounded-down datetime value.
+## Example
+
+```sql
+SELECT MINUTE_FLOOR("2023-07-13 22:28:18", 5);
```
-mysql> select minute_floor("2023-07-13 22:28:18", 5);
+
+```text
+---------------------------------------------------------------+
| minute_floor(cast('2023-07-13 22:28:18' as DATETIMEV2(0)), 5) |
+---------------------------------------------------------------+
| 2023-07-13 22:25:00 |
+---------------------------------------------------------------+
-1 row in set (0.06 sec)
```
-### keywords
-
- MINUTE_FLOOR, MINUTE, FLOOR
+**Note:**
+- If no period is specified, it defaults to a 1-minute interval.
+- The period must be a positive integer.
+- The result is always rounded down to a past time.
+- Unlike MINUTE_CEIL, MINUTE_FLOOR always discards the portion that exceeds the interval.
-### Best Practice
+## Best Practices
See also [date_floor](./date_floor)
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute.md
index cfa348e739933..09a224da048d2 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minute.md
@@ -27,21 +27,39 @@ under the License.
## Description
-Returns minute information in the time type, ranging from 0,59
+Extracts the minute part from a datetime value. The returned value ranges from 0 to 59.
-The parameter is Date or Datetime or Time type
## Syntax
-`INT MINUTE(DATETIME date)`
+
+```sql
+MINUTE()
+```
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, which can be of type DATE, DATETIME, DATETIMEV2, or TIME |
+
+## Return Value
+
+Returns an INT type representing the minute value, with a range of 0-59.
## Example
```sql
-mysql> select minute('2018-12-31 23:59:59');
-+-----------------------------+
-| minute('2018-12-31 23:59:59') |
-+-----------------------------+
-| 59 |
-+-----------------------------+
+SELECT MINUTE('2018-12-31 23:59:59');
```
-## Keywords
- MINUTE
+
+```text
++------------------------------------------------------+
+| minute(cast('2018-12-31 23:59:59' as DATETIMEV2(0))) |
++------------------------------------------------------+
+| 59 |
++------------------------------------------------------+
+```
+
+**Note:**
+- The input parameter can be of various time-related types.
+- The returned value is always an integer between 0 and 59.
+- If the input parameter is NULL, the function returns NULL.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-add.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-add.md
index 7c4636db8c855..04479f476828a 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-add.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-add.md
@@ -24,27 +24,43 @@ specific language governing permissions and limitations
under the License.
-->
-## minutes_add
-### description
-#### Syntax
-`DATETIME MINUTES_ADD(DATETIME date, INT minutes)`
+## Description
-Add specified minutes from date time or date
+Adds a specified number of minutes to a datetime value and returns a new datetime value.
-The parameter date can be DATETIME or DATE, and the return type is DATETIME.
-
-### example
+## Syntax
+```sql
+MINUTES_ADD(, )
```
-mysql> select minutes_add("2020-02-02", 1);
-+---------------------------------------+
-| minutes_add('2020-02-02 00:00:00', 1) |
-+---------------------------------------+
-| 2020-02-02 00:01:00 |
-+---------------------------------------+
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `` | The input datetime value, which can be of type DATE, DATETIME, or DATETIMEV2 |
+| `` | The number of minutes to add, of type INT; can be positive or negative |
+
+## Return Value
+
+Returns a value of type DATETIME, representing the datetime value after adding the specified number of minutes.
+
+## Example
+
+```sql
+SELECT MINUTES_ADD("2020-02-02", 1);
```
-### keywords
+```text
++-----------------------------------------------------+
+| minutes_add(cast('2020-02-02' as DATETIMEV2(0)), 1) |
++-----------------------------------------------------+
+| 2020-02-02 00:01:00 |
++-----------------------------------------------------+
+```
- MINUTES_ADD
+**Note:**
+- When the number of minutes added is negative, it effectively subtracts the corresponding number of minutes.
+- The function automatically handles cases that cross hours and days.
+- If the input parameter is NULL, the function returns NULL.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-diff.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-diff.md
index b8c7fd1c1b880..ff3ccd818844f 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-diff.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-diff.md
@@ -24,25 +24,45 @@ specific language governing permissions and limitations
under the License.
-->
-## minutes_diff
-### description
-#### Syntax
-`INT minutes_diff(DATETIME enddate, DATETIME startdate)`
+## Description
-The difference between the start time and the end time is a few minutes
+Calculates the minute difference between two datetime values. The result is the number of minutes from `` subtracted from ``.
-### example
+## Syntax
+```sql
+MINUTES_DIFF(, )
```
-mysql> select minutes_diff('2020-12-25 22:00:00','2020-12-25 21:00:00');
-+------------------------------------------------------------+
-| minutes_diff('2020-12-25 22:00:00', '2020-12-25 21:00:00') |
-+------------------------------------------------------------+
-| 60 |
-+------------------------------------------------------------+
+
+## Parameters
+
+| Parameter | Description |
+|------------|-------------------------------------------------|
+| `` | The end time, which can be of type DATE, DATETIME, or DATETIMEV2 |
+| `` | The start time, which can be of type DATE, DATETIME, or DATETIMEV2 |
+
+## Return Value
+
+Returns an INT type representing the minute difference between the two times.
+- Returns a positive number if `` is greater than ``.
+- Returns a negative number if `` is less than ``.
+
+## Example
+
+```sql
+SELECT MINUTES_DIFF('2020-12-25 22:00:00', '2020-12-25 21:00:00');
```
-### keywords
+```text
++----------------------------------------------------------------------------------------------------------+
+| minutes_diff(cast('2020-12-25 22:00:00' as DATETIMEV2(0)), cast('2020-12-25 21:00:00' as DATETIMEV2(0))) |
++----------------------------------------------------------------------------------------------------------+
+| 60 |
++----------------------------------------------------------------------------------------------------------+
+```
- minutes_diff
+**Note:**
+- The calculation only considers complete minutes; seconds and milliseconds are ignored.
+- If either input parameter is NULL, the function returns NULL.
+- It can handle time differences that span days, months, or years.
diff --git a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-sub.md b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-sub.md
index 42612d96f501f..0d502ca9a0697 100644
--- a/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-sub.md
+++ b/docs/sql-manual/sql-functions/scalar-functions/date-time-functions/minutes-sub.md
@@ -24,27 +24,44 @@ specific language governing permissions and limitations
under the License.
-->
-## minutes_sub
-### description
-#### Syntax
-`DATETIME MINUTES_SUB(DATETIME date, INT minutes)`
+## Description
-Subtracts a specified number of minutes from a datetime or date
+Subtracts a specified number of minutes from a datetime value and returns a new datetime value.
-The parameter date can be DATETIME or DATE, and the return type is DATETIME.
-
-### example
+## Syntax
+```sql
+MINUTES_SUB(, )
```
-mysql> select minutes_sub("2020-02-02 02:02:02", 1);
-+---------------------------------------+
-| minutes_sub('2020-02-02 02:02:02', 1) |
-+---------------------------------------+
-| 2020-02-02 02:01:02 |
-+---------------------------------------+
+
+## Parameters
+
+| Parameter | Description |
+|-----------|--------------------------------------------------|
+| `