SELECT<WindowFunction> OVER (PARTITION BY <expr_list> ORDER BY <expr_list> [ASC / DESC] [<WindowFrame>])FROMtb_test_window;
select studentid,departmentid,classid,math,row_number() over(partition by departmentid,classid order by math) as row_numfrom student_scores;
Frame | ROWS 场景 | RANGE 场景 |
CURRENT ROW | 当前行。 | 与当前行相同的所有行。 |
UNBOUNDED PRECEDING | 到第一行。 | 到第一行。 |
UNBOUNDED FOLLOWING | 到最后一行。 | 到最后一行。 |
<N> PRECEDING | 前 N 行。 | 到大于等于 OrderBy 列值减去<N>得到的值对应的行。 |
<N> FOLLOWING | 后 N 行。 | 到小于等于 OrderBy 列值加上<N>得到的值对应的行。 |
函数名称 | 功能描述 | 函数参数 | 支持类型 |
ROW_NUMBER() | 对每个分区内数据标记行号。 | - | - |
RANK() | 对每个分区内数据非密集型排序。 | - | - |
DENSE_RANK() | 对每个分区内数据密集型排序。 | - | - |
LEAD(<expr>,<offset>,<default>) | 计算当前行的后<offset>行的值,没有满足行则返回<default>。 | [必选] <expr>:计算列。 | 所有类型(三参数除了 Time 类型)。 |
| | [可选] <offset>:当前行向后偏移行,缺省为1。 | 数值类型。 |
| | [可选] <default>:不满足计算行默认返回值,缺省返回 NULL。 | 与 <expr> 类型一致。 |
LAG(<expr>,<offset>,<default>) | 计算当前行的前<offset>行的值,没有满足行则返回<default>。 | [必选] <expr>:计算列。 | 所有类型(三参数除了 Time 类型)。 |
| | [可选] <offset>:当前行向前偏移行,缺省为1。 | 数值类型。 |
| | [可选] <default>:不满足计算行默认返回值,缺省返回 NULL。 | 与 <expr> 类型一致。 |
FIRST_VALUE(<expr>) | 计算分区窗口内第一个值。 | [必选] <expr>:计算列。 | 所有类型。 |
LAST_VALUE(<expr>) | 计算分区窗口内最后一个值。 | [必选] <expr>:计算列。 | 所有类型。 |
MIN(<expr>) | 计算分区窗口OrderBy列最小值对应行的<expr>值。 | [必选] <expr>:计算列。 | 所有类型。 |
MAX(<expr>) | 计算分区窗口OrderBy列最大值对应行的<expr>值。 | [必选] <expr>:计算列。 | 所有类型。 |
COUNT(<expr>) | 计算分区窗口内数据总行数。 | [必选] <expr>:计算列。 | 所有类型。 |
SUM(<expr>) | 计算分区窗口内数据总和。 | [必选] <expr>:计算列。 | 数值类型。 |
AVG(<expr>) | 计算分区窗口内数据平均值。 | [必选] <expr>:计算列。 | 数值类型。 |
drop table if exists test.tb_window;create table test.tb_window (c1 int not null primary key, c2 int, c3 int);create table test.tb_window (c1 Int32, c2 Nullable(Int32), c3 Nullable(Int32)) engine = LibraTree order by (c1);insert into test.tb_window values (1, 1, 1), (2, 1, 1), (3, 1, 2), (4, 1, 4), (5, 1, 6), (6, 1, 6);
-- 案例语句mysql> select c2, c3, COUNT(c1) over (partition by c2 order by c3 ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING) cn from test.tb_window;+----+----+----+| c2 | c3 | cn |+----+----+----+| 1 | 1 | 3 | -- 窗口行索引范围: current -> 之后2行 [0 ~ 2]| 1 | 1 | 3 | -- 窗口行索引范围: current -> 之后2行 [1 ~ 3]| 1 | 2 | 3 | -- 窗口行索引范围: current -> 之后2行 [2 ~ 4]| 1 | 4 | 3 | -- 窗口行索引范围: current -> 之后2行 [3 ~ 5]| 1 | 6 | 2 | -- 窗口行索引范围: current -> 之后1行 [4 ~ 5] (后边只有一行)| 1 | 6 | 1 | -- 窗口行索引范围: current (后边没有数据)+----+----+----+6 rows in set (0.06 sec)
-- 案例语句mysql> select c2, c3, COUNT(c1) over (partition by c2 order by c3 RANGE BETWEEN CURRENT ROW AND 2 FOLLOWING) cn from test.tb_window;+----+----+----+| c2 | c3 | cn |+----+----+----+| 1 | 1 | 3 | -- 窗口行索引范围: current -> 3对应的行索引之间的行数据 [0 ~ 2]| 1 | 1 | 3 || 1 | 2 | 2 | -- 窗口行索引范围: current -> 4对应的行索引之间的行数据 [2 ~ 3]| 1 | 4 | 3 | -- 窗口行索引范围: current -> 6对应的行索引之间的行数据 [3 ~ 5]| 1 | 6 | 2 | -- 窗口行索引范围: current -> 8对应的行索引之间的行数据 [4 ~ 5]| 1 | 6 | 2 |+----+----+----+6 rows in set (0.06 sec)
-- 案例语句mysql> select c2, c3, ROW_NUMBER() over (partition by c2 order by c3) rn from test.tb_window;+----+----+------+| c2 | c3 | rn |+----+----+------+| 1 | 1 | 1 || 1 | 1 | 2 || 1 | 2 | 3 || 1 | 4 | 4 || 1 | 6 | 5 || 1 | 6 | 6 |+----+----+------+6 rows in set (0.04 sec)
-- 案例语句selectc2, c3,RANK() over (partition by c2 order by c3) rk,DENSE_RANK() over (partition by c2 order by c3) drkfrom test.tb_window;+------+------+------+------+| c2 | c3 | rk | drk |+------+------+------+------+| 1 | 1 | 1 | 1 || 1 | 1 | 1 | 1 || 1 | 2 | 3 | 2 || 1 | 4 | 4 | 3 || 1 | 6 | 5 | 4 || 1 | 6 | 5 | 4 |+------+------+------+------+6 rows in set (0.05 sec)
-- 案例语句mysql> selectc2, c3,LEAD(c3) over (partition by c2 order by c3) ld,LAG(c3) over (partition by c2 order by c3) lgfrom test.tb_window;+------+------+------+------+| c2 | c3 | ld | lg |+------+------+------+------+| 1 | 1 | 1 | NULL || 1 | 1 | 2 | 1 || 1 | 2 | 4 | 1 || 1 | 4 | 6 | 2 || 1 | 6 | 6 | 4 || 1 | 6 | NULL | 6 |+------+------+------+------+6 rows in set (0.11 sec)
-- 案例语句mysql> selectc2, c3,LEAD(c3, 2) over (partition by c2 order by c3) ld,LAG(c3, 2) over (partition by c2 order by c3) lgfrom test.tb_window;+------+------+------+------+| c2 | c3 | ld | lg |+------+------+------+------+| 1 | 1 | 2 | NULL || 1 | 1 | 4 | NULL || 1 | 2 | 6 | 1 || 1 | 4 | 6 | 1 || 1 | 6 | NULL | 2 || 1 | 6 | NULL | 4 |+------+------+------+------+6 rows in set (0.07 sec)
-- 案例语句mysql> selectc2, c3,LEAD(c3, 2, 1000) over (partition by c2 order by c3) ld,LAG(c3, 2, 1000) over (partition by c2 order by c3) lgfrom test.tb_window;+------+------+------+------+| c2 | c3 | ld | lg |+------+------+------+------+| 1 | 1 | 2 | 1000 || 1 | 1 | 4 | 1000 || 1 | 2 | 6 | 1 || 1 | 4 | 6 | 1 || 1 | 6 | 1000 | 2 || 1 | 6 | 1000 | 4 |+------+------+------+------+6 rows in set (0.10 sec)
-- 案例语句mysql> selectc2, c3,FIRST_VALUE(c3) over (partition by c2 order by c3 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) fv,LAST_VALUE(c3) over (partition by c2 order by c3 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) lvfrom test.tb_window;+------+------+------+------+| c2 | c3 | fv | lv |+------+------+------+------+| 1 | 1 | 1 | 6 || 1 | 1 | 1 | 6 || 1 | 2 | 1 | 6 || 1 | 4 | 1 | 6 || 1 | 6 | 1 | 6 || 1 | 6 | 1 | 6 |+------+------+------+------+6 rows in set (0.07 sec)
-- 案例语句mysql> selectc2, c3,MIN(c3) over (partition by c2 order by c3 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) mi,MAX(c3) over (partition by c2 order by c3 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) mafrom test.tb_window;+------+------+------+------+| c2 | c3 | mi | ma |+------+------+------+------+| 1 | 1 | 1 | 6 || 1 | 1 | 1 | 6 || 1 | 2 | 1 | 6 || 1 | 4 | 1 | 6 || 1 | 6 | 1 | 6 || 1 | 6 | 1 | 6 |+------+------+------+------+6 rows in set (0.07 sec)
-- 案例语句mysql> select c2, c3, COUNT(c3) over (partition by c2 order by c3 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) c from test.tb_window;+------+------+----+| c2 | c3 | c |+------+------+----+| 1 | 1 | 6 || 1 | 1 | 6 || 1 | 2 | 6 || 1 | 4 | 6 || 1 | 6 | 6 || 1 | 6 | 6 |+------+------+----+6 rows in set (0.04 sec)
-- 案例语句mysql> select c2, c3, SUM(c3) over (partition by c2 order by c3 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) s from test.tb_window;+------+------+------+| c2 | c3 | s |+------+------+------+| 1 | 1 | 20 || 1 | 1 | 20 || 1 | 2 | 20 || 1 | 4 | 20 || 1 | 6 | 20 || 1 | 6 | 20 |+------+------+------+6 rows in set (0.06 sec)
-- 案例语句mysql> select c2, c3, AVG(c3) over (partition by c2 order by c3 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) a from test.tb_window;+------+------+--------+| c2 | c3 | a |+------+------+--------+| 1 | 1 | 3.3333 || 1 | 1 | 3.3333 || 1 | 2 | 3.3333 || 1 | 4 | 3.3333 || 1 | 6 | 3.3333 || 1 | 6 | 3.3333 |+------+------+--------+6 rows in set (0.06 sec)
本页内容是否解决了您的问题?