1
0
mirror of https://github.com/MariaDB/server.git synced 2025-08-08 11:22:35 +03:00

MDEV-29129: Performance regression starting in 10.6: select order by limit ...

The cause of regression was handling for ROWNUM() function.
For queries like

  SELECT ROWNUM() FROM ... ORDER BY ...

ROWNUM() should be computed before the ORDER BY.
The computation was moved to be before the ORDER BY for any entries in
the select list that had RAND_TABLE_BIT set.

This had a negative impact on queries in form:

  SELECT sp_func() FROM t1 ORDER BY ... LIMIT n

where sp_func() is NOT declared as DETERMINISTIC (and so has
RAND_TABLE_BIT set).

The fix is to require evaluation for sorting only for the ROWNUM()
function. Functions that just have RAND_TABLE_BIT() can be computed
after ORDER BY ... LIMIT is applied.

(think about a possible index that satisfies the ORDER BY clause. In
that case, the the rows would be read in the needed order and we would
stop after reading LIMIT rows, achieving the same effect).
This commit is contained in:
Sergei Petrunia
2022-12-02 18:21:52 +03:00
parent 072b3668ca
commit e0dbec1ce3
11 changed files with 94 additions and 17 deletions

View File

@@ -2696,7 +2696,7 @@ ON p.id = g.p_random
ORDER BY gallery_name ASC
;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 10 Using temporary; Using filesort
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 10 Using filesort
1 PRIMARY p eq_ref PRIMARY PRIMARY 4 g.p_random 1 Using where
2 DERIVED gal ALL NULL NULL NULL NULL 10
3 DEPENDENT SUBQUERY pi ref gallery_id gallery_id 4 test.gal.id 4 Using temporary; Using filesort

View File

@@ -834,13 +834,13 @@ test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status OK
explain SELECT t, next_seq_value() r FROM t1 FORCE INDEX(t) GROUP BY t HAVING r = 1 ORDER BY t1.u;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using temporary; Using filesort
1 SIMPLE t1 index NULL t 5 NULL 8 Using temporary; Using filesort
SELECT t, next_seq_value() r FROM t1 FORCE INDEX(t) GROUP BY t HAVING r = 1 ORDER BY t1.u;
t r
10 1
12 1
14 1
16 1
15 1
17 1
DROP TABLE t1;
DROP FUNCTION next_seq_value;
DROP TABLE series;

View File

@@ -1007,7 +1007,7 @@ SELECT a+SLEEP(0.01) FROM t1
WHERE a IN ( 255, 0 ) OR b BETWEEN 6 AND 129
ORDER BY b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using temporary; Using filesort
1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using filesort
set @show_explain_probe_select_id=1;
SET debug_dbug='+d,show_explain_probe_join_exec_start';
SELECT a+SLEEP(0.01) FROM t1
@@ -1016,7 +1016,7 @@ ORDER BY b;
connection default;
show explain for $thr2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using temporary; Using filesort
1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using filesort
Warnings:
Note 1003 SELECT a+SLEEP(0.01) FROM t1
WHERE a IN ( 255, 0 ) OR b BETWEEN 6 AND 129
@@ -1039,7 +1039,7 @@ ORDER BY b;
connection default;
show explain for $thr2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using temporary; Using filesort
1 SIMPLE t1 index_merge a,b a,b 5,5 NULL 8 Using sort_union(a,b); Using where; Using filesort
Warnings:
Note 1003 SELECT a+SLEEP(0.01) FROM t1
WHERE a IN ( 255, 0 ) OR b BETWEEN 6 AND 129

View File

@@ -8932,3 +8932,43 @@ ERROR 42000: PROCEDURE does not support subqueries or stored functions
DROP TABLE t1;
# End of 10.4 tests
#
#
# MDEV-29129: Performance regression starting in 10.6: unlimited "select order by limit"
#
CREATE TABLE t1 (
lookupId int primary key,
value varchar(255)
);
insert into t1 select seq, seq from seq_1_to_100;
# Note: the function is intentionally NOT declared as DETERMINISTIC
CREATE FUNCTION f1(LOOKUPID_IN INT) RETURNS varchar(255) CHARSET utf8
BEGIN
DECLARE LOOKUP_VALUE VARCHAR(255);
SET LOOKUP_VALUE = (SELECT value FROM t1 WHERE lookupId = LOOKUPID_IN);
set @counter=@counter+1;
RETURN LOOKUP_VALUE;
END;
//
create table t2 (
col1 int,
col2 int
);
insert into t2 select mod(seq,100), seq from seq_1_to_1000;
explain
select f1(col1) from t2 order by col2 desc limit 5;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 ALL NULL NULL NULL NULL 1000 Using filesort
set @counter=0;
select f1(col1) from t2 order by col2 desc limit 5;
f1(col1)
NULL
99
98
97
96
# Must show 5, not 1000:
select @counter;
@counter
5
drop function f1;
drop table t1,t2;

View File

@@ -10519,3 +10519,40 @@ DROP TABLE t1;
--echo # End of 10.4 tests
--echo #
--echo #
--echo # MDEV-29129: Performance regression starting in 10.6: unlimited "select order by limit"
--echo #
CREATE TABLE t1 (
lookupId int primary key,
value varchar(255)
);
insert into t1 select seq, seq from seq_1_to_100;
-- echo # Note: the function is intentionally NOT declared as DETERMINISTIC
delimiter //;
CREATE FUNCTION f1(LOOKUPID_IN INT) RETURNS varchar(255) CHARSET utf8
BEGIN
DECLARE LOOKUP_VALUE VARCHAR(255);
SET LOOKUP_VALUE = (SELECT value FROM t1 WHERE lookupId = LOOKUPID_IN);
set @counter=@counter+1;
RETURN LOOKUP_VALUE;
END;
//
delimiter ;//
create table t2 (
col1 int,
col2 int
);
insert into t2 select mod(seq,100), seq from seq_1_to_1000;
explain
select f1(col1) from t2 order by col2 desc limit 5;
set @counter=0;
select f1(col1) from t2 order by col2 desc limit 5;
--echo # Must show 5, not 1000:
select @counter;
drop function f1;
drop table t1,t2;

View File

@@ -372,14 +372,14 @@ insert into t1 (b) values (10), (30), (10), (10);
set @var := 0;
explain select if(b=@var, 999, b) , @var := b from t1 order by b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using temporary; Using filesort
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using filesort
set @var := 0;
select if(b=@var, 999, b) , @var := b from t1 order by b;
if(b=@var, 999, b) @var := b
10 10
10 10
30 30
999 10
999 10
drop table t1;
create temporary table t1 (id int);
insert into t1 values (2), (3), (3), (4);

View File

@@ -7738,6 +7738,8 @@ bool setup_fields(THD *thd, Ref_ptr_array ref_pointer_array,
thd->lex->current_select->select_list_tables|= item->used_tables();
thd->lex->used_tables|= item->used_tables();
thd->lex->current_select->cur_pos_in_select_list++;
thd->lex->current_select->rownum_in_field_list |= item->with_rownum_func();
}
thd->lex->current_select->is_item_list_lookup= save_is_item_list_lookup;
thd->lex->current_select->cur_pos_in_select_list= UNDEF_POS;

View File

@@ -3002,6 +3002,8 @@ void st_select_lex::init_query()
prep_leaf_list_state= UNINIT;
bzero((char*) expr_cache_may_be_used, sizeof(expr_cache_may_be_used));
select_list_tables= 0;
rownum_in_field_list= 0;
window_specs.empty();
window_funcs.empty();
tvc= 0;

View File

@@ -1344,6 +1344,9 @@ public:
*/
table_map select_list_tables;
/* Set to 1 if any field in field list has ROWNUM() */
bool rownum_in_field_list;
/* namp of nesting SELECT visibility (for aggregate functions check) */
nesting_map name_visibility_map;
table_map with_dep;

View File

@@ -434,7 +434,6 @@ void JOIN::init(THD *thd_arg, List<Item> &fields_arg,
no_order= 0;
simple_order= 0;
simple_group= 0;
rand_table_in_field_list= 0;
ordered_index_usage= ordered_index_void;
need_distinct= 0;
skip_sort_order= 0;
@@ -1434,7 +1433,6 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num,
&all_fields, &select_lex->pre_fix, 1))
DBUG_RETURN(-1);
thd->lex->current_select->context_analysis_place= save_place;
rand_table_in_field_list= select_lex->select_list_tables & RAND_TABLE_BIT;
if (setup_without_group(thd, ref_ptrs, tables_list,
select_lex->leaf_tables, fields_list,
@@ -14807,7 +14805,7 @@ remove_const(JOIN *join,ORDER *first_order, COND *cond,
and some wrong results so better to leave the code as it was
related to ROLLUP.
*/
*simple_order= !join->rand_table_in_field_list;
*simple_order= !join->select_lex->rownum_in_field_list;
if (join->only_const_tables())
return change_list ? 0 : first_order; // No need to sort

View File

@@ -1420,11 +1420,6 @@ public:
GROUP/ORDER BY.
*/
bool simple_order, simple_group;
/*
Set to 1 if any field in field list has RAND_TABLE set. For example if
if one uses RAND() or ROWNUM() in field list
*/
bool rand_table_in_field_list;
/*
ordered_index_usage is set if an ordered index access