diff options
author | Vicențiu Ciorbaru <vicentiu@mariadb.org> | 2016-09-22 14:21:18 +0200 |
---|---|---|
committer | Vicențiu Ciorbaru <vicentiu@mariadb.org> | 2016-09-24 15:12:34 +0200 |
commit | 3dd3a5da0e9fbd8a24a178b2b295b5a385beba5e (patch) | |
tree | 37deca84f2ffe304421f72b5c3a41daf6cb2948e | |
parent | e992464f27c12abca621f420dc9650189173ab86 (diff) | |
download | mariadb-git-3dd3a5da0e9fbd8a24a178b2b295b5a385beba5e.tar.gz |
MDEV-9935: Window functions: assertion failure with empty OVER () clause
Make window functions work with an empty over clause by forcing
a sort on the first column of the current join_tab. This is a temporary
fix until we get window functions to work with big tables.
-rw-r--r-- | mysql-test/r/win_empty_over.result | 145 | ||||
-rw-r--r-- | mysql-test/t/win_empty_over.test | 66 | ||||
-rw-r--r-- | sql/sql_window.cc | 26 | ||||
-rw-r--r-- | sql/sql_window.h | 3 |
4 files changed, 237 insertions, 3 deletions
diff --git a/mysql-test/r/win_empty_over.result b/mysql-test/r/win_empty_over.result new file mode 100644 index 00000000000..8df2c1f4329 --- /dev/null +++ b/mysql-test/r/win_empty_over.result @@ -0,0 +1,145 @@ +create table t1 ( +pk int primary key, +a int, +b int, +c char(10), +d decimal(10, 3), +e real +); +insert into t1 values +( 1, 0, 1, 'one', 0.1, 0.001), +( 2, 0, 2, 'two', 0.2, 0.002), +( 3, 0, 3, 'three', 0.3, 0.003), +( 4, 1, 2, 'three', 0.4, 0.004), +( 5, 1, 1, 'two', 0.5, 0.005), +( 6, 1, 1, 'one', 0.6, 0.006), +( 7, 2, NULL, 'n_one', 0.5, 0.007), +( 8, 2, 1, 'n_two', NULL, 0.008), +( 9, 2, 2, NULL, 0.7, 0.009), +(10, 2, 0, 'n_four', 0.8, 0.010), +(11, 2, 10, NULL, 0.9, NULL); +select pk, row_number() over () from t1; +pk row_number() over () +1 1 +2 2 +3 3 +4 4 +5 5 +6 6 +7 7 +8 8 +9 9 +10 10 +11 11 +explain FORMAT=JSON select pk, row_number() over () from t1; +EXPLAIN +{ + "query_block": { + "select_id": 1, + "window_functions_computation": { + "sorts": { + "filesort": { + "sort_key": "pk" + } + }, + "temporary_table": { + "table": { + "table_name": "t1", + "access_type": "index", + "key": "PRIMARY", + "key_length": "4", + "used_key_parts": ["pk"], + "rows": 11, + "filtered": 100, + "using_index": true + } + } + } + } +} +explain FORMAT=JSON select row_number() over (), pk from t1; +EXPLAIN +{ + "query_block": { + "select_id": 1, + "window_functions_computation": { + "sorts": { + "filesort": { + "sort_key": "`row_number() over ()`" + } + }, + "temporary_table": { + "table": { + "table_name": "t1", + "access_type": "index", + "key": "PRIMARY", + "key_length": "4", + "used_key_parts": ["pk"], + "rows": 11, + "filtered": 100, + "using_index": true + } + } + } + } +} +select row_number() over () from (select 4) as t; +row_number() over () +1 +select min(a) over (), max(a) over (), a, row_number() over () +from t1 +where a = 0; +min(a) over () max(a) over () a row_number() over () +0 0 0 1 +0 0 0 2 +0 0 0 3 +select a, min(a) over (), max(a) over (), row_number() over () +from t1 +where a = 0; +a min(a) over () max(a) over () row_number() over () +0 0 0 1 +0 0 0 2 +0 0 0 3 +select min(a) over () + 1, max(a) over (), row_number() over () +from t1 +where a = 0; +min(a) over () + 1 max(a) over () row_number() over () +1 0 1 +1 0 2 +1 0 3 +select min(a) over () + a, max(a) over (), row_number() over () +from t1 +where a = 1; +min(a) over () + a max(a) over () row_number() over () +2 1 1 +2 1 2 +2 1 3 +select a + min(a) over (), max(a) over (), row_number() over () +from t1 +where a = 1; +a + min(a) over () max(a) over () row_number() over () +2 1 1 +2 1 2 +2 1 3 +select a + min(a) over () from t1 where a = 1; +a + min(a) over () +2 +2 +2 +create view win_view +as (select a, min(a) over () from t1 where a = 1); +select * from win_view; +a min(a) over () +1 1 +1 1 +1 1 +drop view win_view; +create view win_view +as (select a, max(a + 1) over () from t1 where a = 1); +select * from win_view; +a max(a + 1) over () +1 3 +1 3 +1 3 +drop view win_view; +drop table t1; diff --git a/mysql-test/t/win_empty_over.test b/mysql-test/t/win_empty_over.test new file mode 100644 index 00000000000..91344d76865 --- /dev/null +++ b/mysql-test/t/win_empty_over.test @@ -0,0 +1,66 @@ +create table t1 ( + pk int primary key, + a int, + b int, + c char(10), + d decimal(10, 3), + e real +); + +insert into t1 values +( 1, 0, 1, 'one', 0.1, 0.001), +( 2, 0, 2, 'two', 0.2, 0.002), +( 3, 0, 3, 'three', 0.3, 0.003), +( 4, 1, 2, 'three', 0.4, 0.004), +( 5, 1, 1, 'two', 0.5, 0.005), +( 6, 1, 1, 'one', 0.6, 0.006), +( 7, 2, NULL, 'n_one', 0.5, 0.007), +( 8, 2, 1, 'n_two', NULL, 0.008), +( 9, 2, 2, NULL, 0.7, 0.009), +(10, 2, 0, 'n_four', 0.8, 0.010), +(11, 2, 10, NULL, 0.9, NULL); + +select pk, row_number() over () from t1; +explain FORMAT=JSON select pk, row_number() over () from t1; +explain FORMAT=JSON select row_number() over (), pk from t1; + +select row_number() over () from (select 4) as t; + +--sorted_result +select min(a) over (), max(a) over (), a, row_number() over () +from t1 +where a = 0; + +--sorted_result +select a, min(a) over (), max(a) over (), row_number() over () +from t1 +where a = 0; + +--sorted_result +select min(a) over () + 1, max(a) over (), row_number() over () +from t1 +where a = 0; + +--sorted_result +select min(a) over () + a, max(a) over (), row_number() over () +from t1 +where a = 1; + +--sorted_result +select a + min(a) over (), max(a) over (), row_number() over () +from t1 +where a = 1; + +select a + min(a) over () from t1 where a = 1; + +create view win_view +as (select a, min(a) over () from t1 where a = 1); +select * from win_view; +drop view win_view; + +create view win_view +as (select a, max(a + 1) over () from t1 where a = 1); +select * from win_view; +drop view win_view; + +drop table t1; diff --git a/sql/sql_window.cc b/sql/sql_window.cc index 5d929101e10..15045924e83 100644 --- a/sql/sql_window.cc +++ b/sql/sql_window.cc @@ -2509,7 +2509,8 @@ bool Window_funcs_sort::exec(JOIN *join) bool Window_funcs_sort::setup(THD *thd, SQL_SELECT *sel, - List_iterator<Item_window_func> &it) + List_iterator<Item_window_func> &it, + JOIN_TAB *join_tab) { Window_spec *spec; Item_window_func *win_func= it.peek(); @@ -2547,6 +2548,27 @@ bool Window_funcs_sort::setup(THD *thd, SQL_SELECT *sel, ORDER* sort_order= concat_order_lists(thd->mem_root, spec->partition_list->first, spec->order_list->first); + if (sort_order == NULL) // No partition or order by clause. + { + /* TODO(cvicentiu) This is used as a way to allow an empty OVER () + clause for window functions. However, a better approach is + to not call Filesort at all in this case and just read whatever order + the temporary table has. + Due to cursors not working for out_of_memory cases (yet!), we have to run + filesort to generate a sort buffer of the results. + In this case we sort by the first field of the temporary table. + We should have this field available, even if it is a window_function + field. We don't care of the particular sorting result in this case. + */ + ORDER *order= (ORDER *)alloc_root(thd->mem_root, sizeof(ORDER)); + memset(order, 0, sizeof(*order)); + Item *item= new (thd->mem_root) Item_field(thd, join_tab->table->field[0]); + order->item= (Item **)alloc_root(thd->mem_root, 2 * sizeof(Item *)); + order->item[1]= NULL; + order->item[0]= item; + order->field= join_tab->table->field[0]; + sort_order= order; + } filesort= new (thd->mem_root) Filesort(sort_order, HA_POS_ERROR, true, NULL); /* Apply the same condition that the subsequent sort has. */ @@ -2574,7 +2596,7 @@ bool Window_funcs_computation::setup(THD *thd, while (iter.peek()) { if (!(srt= new Window_funcs_sort()) || - srt->setup(thd, sel, iter)) + srt->setup(thd, sel, iter, tab)) { return true; } diff --git a/sql/sql_window.h b/sql/sql_window.h index c3847240e9a..b94a1fc6dc4 100644 --- a/sql/sql_window.h +++ b/sql/sql_window.h @@ -186,7 +186,8 @@ private: class Window_funcs_sort : public Sql_alloc { public: - bool setup(THD *thd, SQL_SELECT *sel, List_iterator<Item_window_func> &it); + bool setup(THD *thd, SQL_SELECT *sel, List_iterator<Item_window_func> &it, + st_join_table *join_tab); bool exec(JOIN *join); void cleanup() { delete filesort; } |