SelectDB Enterprise
参考手册
SQL 函数
标量函数
数值函数
WIDTH_BUCKET

WIDTH_BUCKET

描述

构造等宽直方图,其中直方图范围被划分为相同大小的区间,并在计算后返回表达式的值所在的桶号。特殊情况:

  • 该函数返回一个整数值或空值(如果任何输入为空值则返回空值)。

语法

WIDTH_BUCKET(<expr>, <min_value>, <max_value>, <num_buckets>)

参数

参数说明
<expr>创建直方图的表达式。此表达式必须计算为数值或可隐式转换为数值的值,此值的范围必须为 -(2^53 - 1)2^53 - 1 (含)
<min_value>表达式可接受范围的最低值点。参数必须为数值且不等于<max_value>,范围必须为 -(2^53 - 1) to 2^53 - 1 (含)). 此外,最高值点与最低值点的差必须小于 2^53 (例如: abs(max_value - min_value) < 2^53)
<max_value>表达式可接受范围的最高值点。参数必须为数值且不等于<min_value>,范围必须为 -(2^53 - 1) to 2^53 - 1 (含)). 此外,最高值点与最低值点的差必须小于 2^53 (例如: abs(max_value - min_value) < 2^53)
<num_buckets>分桶的数量,必须是正整数值。将表达式中的一个值分配给每个存储桶,然后该函数返回相应的存储桶编号

返回值

返回表达式值所在的桶号。当表达式超出范围时,函数返回规则如下:

  • 如果表达式的值小于min_value返回0.
  • 如果表达式的值大于或等于max_value返回num_buckets + 1.
  • 如果任意参数为null返回null.

举例

DROP TABLE IF EXISTS width_bucket_test;
 
CREATE TABLE IF NOT EXISTS width_bucket_test (
`k1` int NULL COMMENT "",
`v1` date NULL COMMENT "",
`v2` double NULL COMMENT "",
`v3` bigint NULL COMMENT ""
) ENGINE=OLAP
DUPLICATE KEY(`k1`)
DISTRIBUTED BY HASH(`k1`) BUCKETS 1
PROPERTIES (
"replication_allocation" = "tag.location.default: 1",
"storage_format" = "V2"
);
 
INSERT INTO width_bucket_test VALUES  
(1, "2022-11-18", 290000.00, 290000),
(2, "2023-11-18", 320000.00, 320000),
(3, "2024-11-18", 399999.99, 399999), 
(4, "2025-11-18", 400000.00, 400000), 
(5, "2026-11-18", 470000.00, 470000), 
(6, "2027-11-18", 510000.00, 510000), 
(7, "2028-11-18", 610000.00, 610000), 
(8, null, null, null);
SELECT * FROM width_bucket_test ORDER BY k1;                                      
+------+------------+-----------+--------+
| k1   | v1         | v2        | v3     |
+------+------------+-----------+--------+
|    1 | 2022-11-18 |    290000 | 290000 |
|    2 | 2023-11-18 |    320000 | 320000 |
|    3 | 2024-11-18 | 399999.99 | 399999 |
|    4 | 2025-11-18 |    400000 | 400000 |
|    5 | 2026-11-18 |    470000 | 470000 |
|    6 | 2027-11-18 |    510000 | 510000 |
|    7 | 2028-11-18 |    610000 | 610000 |
|    8 | NULL       |      NULL |   NULL |
+------+------------+-----------+--------+
SELECT k1, v1, v2, v3, width_bucket(v1, date('2023-11-18'), date('2027-11-18'), 4) AS w FROM width_bucket_test ORDER BY k1;
+------+------------+-----------+--------+------+
| k1   | v1         | v2        | v3     | w    |
+------+------------+-----------+--------+------+
|    1 | 2022-11-18 |    290000 | 290000 |    0 |
|    2 | 2023-11-18 |    320000 | 320000 |    1 |
|    3 | 2024-11-18 | 399999.99 | 399999 |    2 |
|    4 | 2025-11-18 |    400000 | 400000 |    3 |
|    5 | 2026-11-18 |    470000 | 470000 |    4 |
|    6 | 2027-11-18 |    510000 | 510000 |    5 |
|    7 | 2028-11-18 |    610000 | 610000 |    5 |
|    8 | NULL       |      NULL |   NULL | NULL |
+------+------------+-----------+--------+------+
SELECT k1, v1, v2, v3, width_bucket(v2, 200000, 600000, 4) AS w FROM width_bucket_test ORDER BY k1;
+------+------------+-----------+--------+------+
| k1   | v1         | v2        | v3     | w    |
+------+------------+-----------+--------+------+
|    1 | 2022-11-18 |    290000 | 290000 |    1 |
|    2 | 2023-11-18 |    320000 | 320000 |    2 |
|    3 | 2024-11-18 | 399999.99 | 399999 |    2 |
|    4 | 2025-11-18 |    400000 | 400000 |    3 |
|    5 | 2026-11-18 |    470000 | 470000 |    3 |
|    6 | 2027-11-18 |    510000 | 510000 |    4 |
|    7 | 2028-11-18 |    610000 | 610000 |    5 |
|    8 | NULL       |      NULL |   NULL | NULL |
+------+------------+-----------+--------+------+
SELECT k1, v1, v2, v3, width_bucket(v3, 200000, 600000, 4) AS w FROM width_bucket_test ORDER BY k1;
+------+------------+-----------+--------+------+
| k1   | v1         | v2        | v3     | w    |
+------+------------+-----------+--------+------+
|    1 | 2022-11-18 |    290000 | 290000 |    1 |
|    2 | 2023-11-18 |    320000 | 320000 |    2 |
|    3 | 2024-11-18 | 399999.99 | 399999 |    2 |
|    4 | 2025-11-18 |    400000 | 400000 |    3 |
|    5 | 2026-11-18 |    470000 | 470000 |    3 |
|    6 | 2027-11-18 |    510000 | 510000 |    4 |
|    7 | 2028-11-18 |    610000 | 610000 |    5 |
|    8 | NULL       |      NULL |   NULL | NULL |
+------+------------+-----------+--------+------+
© 2025 北京飞轮数据科技有限公司 京ICP备2022004029号 | Apache、Apache Doris 以及相关开源项目名称均为 Apache 基金会商标