dbms/src/Flash/Coprocessor/collectOutputFieldTypes.cpp case tipb::ExecType::TypeWindow: // Window will only be pushed down in mpp mode. // In mpp mode, ExchangeSender or Sender will return output_field_types directly. // If not in mpp mode, window executor type is invalid. throw TiFlashException("Window executor type is invalid in non-mpp mode, should not reach here.", Errors::Coprocessor::Internal);
下面对窗口函数进行实际演示。
测试数据
创建测试表,并写入测试数据。
1 2 3 4 5 6 7 8 9
DROPTABLE if EXISTS student; CREATETABLE if NOTEXISTS student (course VARCHAR(10), mark INT, name VARCHAR(10)); INSERTINTO student VALUES ('Maths', 60, 'Thulile'), ('Maths', 60, 'Pritha'), ('Maths', 70, 'Voitto'), ('Maths', 55, 'Chun'), ('Biology', 60, 'Bilal'), ('Biology', 70, 'Roger');
RANK() / ROW_NUMBER() / DENSE_RANK()
功能描述
RANK():返回分区中当前行的排名,排名可能不连续。
ROW_NUMBER():返回分区中当前行的编号。相同结果顺序排名,编号不相同。
DENSE_RANK():返回分区中当前行的排名。相同结果相同排名。
演示结果
1 2 3 4 5 6 7 8 9 10 11 12
TiDB [test] 21:38:44>SELECTRANK() OVER w AS `rank`, ROW_NUMBER() OVER w AS `row_num`, DENSE_RANK() OVER w AS `dense_rank`, course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +------+---------+------------+---------+------+---------+ | rank | row_num | dense_rank | course | mark | name | +------+---------+------------+---------+------+---------+ |1|1|1| Biology |70| Roger | |2|2|2| Biology |60| Bilal | |1|1|1| Maths |70| Voitto | |2|2|2| Maths |60| Thulile | |2|3|2| Maths |60| Pritha | |4|4|3| Maths |55| Chun | +------+---------+------------+---------+------+---------+ 6rowsinset (0.005 sec)
一般执行计划
1 2 3 4 5 6 7 8 9 10 11 12
TiDB [test] 21:38:46> explain SELECTRANK() OVER w AS `rank`, ROW_NUMBER() OVER w AS `row_num`, DENSE_RANK() OVER w AS `dense_rank`, course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +--------------------------------+----------+-----------+---------------+----------------------------------------------------------------------------------------------------------------------------------------+ | id | estRows | task | access object | operator info | +--------------------------------+----------+-----------+---------------+----------------------------------------------------------------------------------------------------------------------------------------+ | Projection_8 |10000.00| root ||Column#9, Column#8, Column#10, test.student.course, test.student.mark, test.student.name | | └─Window_9 |10000.00| root ||rank()->Column#9, dense_rank()->Column#10over(partitionby test.student.course orderby test.student.mark desc) | | └─Window_10 |10000.00| root ||row_number()->Column#8over(partitionby test.student.course orderby test.student.mark descrowsbetweencurrentrowandcurrentrow) | | └─Sort_14 |10000.00| root || test.student.course, test.student.mark:desc| | └─TableReader_13 |10000.00| root || data:TableFullScan_12 | | └─TableFullScan_12 |10000.00| cop[tikv] |table:student | keep order:false, stats:pseudo | +--------------------------------+----------+-----------+---------------+----------------------------------------------------------------------------------------------------------------------------------------+ 6rowsinset (0.002 sec)
创建 TiFlash 副本后走 MPP 框架的执行计划
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15
TiDB [test] 21:44:13> explain SELECTRANK() OVER w AS `rank`, ROW_NUMBER() OVER w AS `row_num`, DENSE_RANK() OVER w AS `dense_rank`, course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +--------------------------------------+---------+--------------+---------------+----------------------------------------------------------------------------------------------------------------------------------------+ | id | estRows | task | access object | operator info | +--------------------------------------+---------+--------------+---------------+----------------------------------------------------------------------------------------------------------------------------------------+ | Projection_8 |6.00| root ||Column#9, Column#8, Column#10, test.student.course, test.student.mark, test.student.name | | └─TableReader_19 |6.00| root || data:ExchangeSender_18 | | └─ExchangeSender_18 |6.00| mpp[tiflash] || ExchangeType: PassThrough | | └─Window_9 |6.00| mpp[tiflash] ||rank()->Column#9, dense_rank()->Column#10over(partitionby test.student.course orderby test.student.mark desc) | | └─Window_11 |6.00| mpp[tiflash] ||row_number()->Column#8over(partitionby test.student.course orderby test.student.mark descrowsbetweencurrentrowandcurrentrow) | | └─Sort_16 |6.00| mpp[tiflash] || test.student.course, test.student.mark:desc| | └─ExchangeReceiver_15 |6.00| mpp[tiflash] ||| | └─ExchangeSender_14 |6.00| mpp[tiflash] || ExchangeType: HashPartition, Hash Cols: [name: test.student.course, collate: utf8mb4_bin] | | └─TableFullScan_13 |6.00| mpp[tiflash] |table:student | keep order:false, stats:pseudo | +--------------------------------------+---------+--------------+---------------+----------------------------------------------------------------------------------------------------------------------------------------+ 9rowsinset (0.002 sec)
mysql> explain SELECTRANK() OVER w AS `rank`, ROW_NUMBER() OVER w AS `row_num`, DENSE_RANK() OVER w AS `dense_rank`, course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +------+-------------+---------+------+---------------+------+---------+------+------+-----------------+ | id | select_type |table| type | possible_keys | key | key_len |ref|rows| Extra | +------+-------------+---------+------+---------------+------+---------+------+------+-----------------+ |1| SIMPLE | student |ALL|NULL|NULL|NULL|NULL|6|Using temporary | +------+-------------+---------+------+---------------+------+---------+------+------+-----------------+ 1rowinset (0.00 sec)
TiDB [test] 22:08:29>SELECTCUME_DIST() OVER w AS `cume_dist`, PERCENT_RANK() OVER w AS `pct_rank`, course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +-----------+--------------------+---------+------+---------+ | cume_dist | pct_rank | course | mark | name | +-----------+--------------------+---------+------+---------+ |0.5|0| Biology |70| Roger | |1|1| Biology |60| Bilal | |0.25|0| Maths |70| Voitto | |0.75|0.3333333333333333| Maths |60| Thulile | |0.75|0.3333333333333333| Maths |60| Pritha | |1|1| Maths |55| Chun | +-----------+--------------------+---------+------+---------+ 6rowsinset (0.016 sec)
执行计划
1 2 3 4 5 6 7 8 9 10 11 12
TiDB [test] 21:57:56> explain SELECTCUME_DIST() OVER w AS `cume_dist`, PERCENT_RANK() OVER w AS `pct_rank`, course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +--------------------------------+---------+--------------+---------------+------------------------------------------------------------------------------------------------------------------------+ | id | estRows | task | access object | operator info | +--------------------------------+---------+--------------+---------------+------------------------------------------------------------------------------------------------------------------------+ | Projection_6 |6.00| root ||Column#7, Column#8, test.student.course, test.student.mark, test.student.name | | └─Shuffle_13 |6.00| root || execution info: concurrency:4, data sources:[TableReader_11] | | └─Window_7 |6.00| root ||cume_dist()->Column#7, percent_rank()->Column#8over(partitionby test.student.course orderby test.student.mark desc) | | └─Sort_12 |6.00| root || test.student.course, test.student.mark:desc| | └─TableReader_11 |6.00| root || data:TableFullScan_10 | | └─TableFullScan_10 |6.00| cop[tiflash] |table:student | keep order:false, stats:pseudo | +--------------------------------+---------+--------------+---------------+------------------------------------------------------------------------------------------------------------------------+ 6rowsinset (0.002 sec)
TiDB [test] 22:13:04>SELECTFIRST_VALUE(mark) OVER w AS `first`, LAST_VALUE(mark) OVER w AS `last`, NTH_VALUE(mark, 2) OVER w AS `second`, NTILE(2) over w as'ntile', course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +-------+------+--------+-------+---------+------+---------+ |first|last|second| ntile | course | mark | name | +-------+------+--------+-------+---------+------+---------+ |70|70|NULL|1| Biology |70| Roger | |70|60|60|2| Biology |60| Bilal | |70|70|NULL|1| Maths |70| Voitto | |70|60|60|1| Maths |60| Thulile | |70|60|60|2| Maths |60| Pritha | |70|55|60|2| Maths |55| Chun | +-------+------+--------+-------+---------+------+---------+ 6rowsinset (0.021 sec)
执行计划
1 2 3 4 5 6 7 8 9 10 11 12
TiDB [test] 22:12:14> explain SELECTFIRST_VALUE(mark) OVER w AS `first`, LAST_VALUE(mark) OVER w AS `last`, NTH_VALUE(mark, 2) OVER w AS `second`, NTILE(2) over w as'ntile', course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +--------------------------------+---------+--------------+---------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | id | estRows | task | access object | operator info | +--------------------------------+---------+--------------+---------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ | Projection_8 |6.00| root ||Column#10, Column#11, Column#12, Column#9, test.student.course, test.student.mark, test.student.name | | └─Window_9 |6.00| root ||first_value(test.student.mark)->Column#10, last_value(test.student.mark)->Column#11, nth_value(test.student.mark, 2)->Column#12over(partitionby test.student.course orderby test.student.mark descrangebetween unbounded preceding andcurrentrow) | | └─Window_10 |6.00| root ||ntile(2)->Column#9over(partitionby test.student.course orderby test.student.mark desc) | | └─Sort_16 |6.00| root || test.student.course, test.student.mark:desc| | └─TableReader_15 |6.00| root || data:TableFullScan_14 | | └─TableFullScan_14 |6.00| cop[tiflash] |table:student | keep order:false, stats:pseudo | +--------------------------------+---------+--------------+---------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ 6rowsinset (0.001 sec)
LAG() / LEAD()
功能描述
LAG():返回分区中滞后于当前行的参数的值。
LEAD():返回分区中领先于当前行的参数的值。
执行结果
1 2 3 4 5 6 7 8 9 10 11 12
TiDB [test] 22:16:14>SELECTLAG(mark) OVER w AS `lag`, LEAD(mark) OVER w AS `lead`, course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +------+------+---------+------+---------+ | lag | lead | course | mark | name | +------+------+---------+------+---------+ |NULL|60| Biology |70| Roger | |70|NULL| Biology |60| Bilal | |NULL|60| Maths |70| Voitto | |70|60| Maths |60| Thulile | |60|55| Maths |60| Pritha | |60|NULL| Maths |55| Chun | +------+------+---------+------+---------+ 6rowsinset (0.020 sec)
执行计划
1 2 3 4 5 6 7 8 9 10 11 12
TiDB [test] 22:13:25> explain SELECTLAG(mark) OVER w AS `lag`, LEAD(mark) OVER w AS `lead`, course, mark, name FROM student window w AS (PARTITIONBY course ORDERBY mark DESC); +--------------------------------+---------+--------------+---------------+--------------------------------------------------------------------------------------------------------------------------------------------+ | id | estRows | task | access object | operator info | +--------------------------------+---------+--------------+---------------+--------------------------------------------------------------------------------------------------------------------------------------------+ | Projection_6 |6.00| root ||Column#7, Column#8, test.student.course, test.student.mark, test.student.name | | └─Shuffle_13 |6.00| root || execution info: concurrency:4, data sources:[TableReader_11] | | └─Window_7 |6.00| root ||lag(test.student.mark)->Column#7, lead(test.student.mark)->Column#8over(partitionby test.student.course orderby test.student.mark desc) | | └─Sort_12 |6.00| root || test.student.course, test.student.mark:desc| | └─TableReader_11 |6.00| root || data:TableFullScan_10 | | └─TableFullScan_10 |6.00| cop[tiflash] |table:student | keep order:false, stats:pseudo | +--------------------------------+---------+--------------+---------------+--------------------------------------------------------------------------------------------------------------------------------------------+ 6rowsinset (0.003 sec)
常见数据库对窗口函数的支持情况
通过对几款常用数据库的调研比对,均支持常见的 11 种窗口函数。
#
窗口函数
TiDB(>3.0)
TiDB MPP(>6.1)
MySQL(>8.0)
1
RANK()
Y
Y
Y
2
ROW_NUMBER()
Y
Y
Y
3
DENSE_RANK()
Y
Y
Y
4
CUME_DIST()
Y
cannot
Y
5
PERCENT_RANK()
Y
cannot
Y
6
FIRST_VALUE()
Y
cannot
Y
7
LAST_VALUE()
Y
cannot
Y
8
NTH_VALUE()
Y
cannot
Y
9
NTILE()
Y
cannot
Y
10
LAG()
Y
cannot
Y
11
LEAD()
Y
cannot
Y
12
MEDIAN
cannot
cannot
cannot
13
PERCENTILE_CONT
cannot
cannot
cannot
14
PERCENTILE_DISC
cannot
cannot
cannot
总结
通过将窗口函数下推到 MPP 计算框架,减轻 TiDB Server 的单点计算压力,将计算压力分摊到各个 TiFlash 节点,从而支持并行计算,提升查询性能。