Skip to content

Commit 2010aeb

Browse files
author
Nimita Joshi
committed
Bug#34306497 - Low limit heuristic used unnecessarily with descending scans
Issue: The low limit heuristic is not working well for order by desc as it chooses the wrong index. Analysis: Because of the low limit we relook at the access method that is chosen which in this case is the index. If the chosen range scan can provide the order we skip the heuristic. At this point since const optimization is not done the optimizer thinks the current range scan cannot provide order so it relooks at other options. Since the primary key can provide the order it chooses that one. Fix: Since const optimisation is not done when we check if an index can provide order, the key part of the index and the order by field did not match. The fix is to check if the index can provide the order by skipping constant key parts preceding to the specified order by expression. Later we check if the best range scan can provide order by reversing it. Change-Id: I1f967670c195f49fe39284e17e2d3c70030ad466
1 parent a0ad705 commit 2010aeb

File tree

4 files changed

+169
-9
lines changed

4 files changed

+169
-9
lines changed

mysql-test/r/myisam_explain_json_non_select_all.result

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4264,6 +4264,7 @@ EXPLAIN
42644264
"filtered": "100.00",
42654265
"index_condition": "((`test`.`t2`.`i` > 10) and (`test`.`t2`.`i` <= 18))",
42664266
"backward_index_scan": true,
4267+
"using_MRR": true,
42674268
"cost_info": {
42684269
"read_cost": "1.46",
42694270
"eval_cost": "0.80",
@@ -5301,6 +5302,7 @@ EXPLAIN
53015302
"filtered": "100.00",
53025303
"index_condition": "((`test`.`t2`.`i` > 10) and (`test`.`t2`.`i` <= 18))",
53035304
"backward_index_scan": true,
5305+
"using_MRR": true,
53045306
"cost_info": {
53055307
"read_cost": "1.46",
53065308
"eval_cost": "0.80",

mysql-test/r/order_by_limit.result

Lines changed: 85 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -555,3 +555,88 @@ Warnings:
555555
Note 1003 /* select#1 */ select `test`.`test`.`a` AS `a`,`test`.`test`.`b` AS `b`,`test`.`test`.`c` AS `c`,`test`.`test`.`d` AS `d` from `test`.`test` where ((`test`.`test`.`c` = DATE'2022-06-13') and (`test`.`test`.`a` > 222)) order by `test`.`test`.`c`,`test`.`test`.`a` limit 10
556556
DROP PROCEDURE insertProc;
557557
DROP TABLE test;
558+
#
559+
# Bug#34306497 - Low limit heuristic used unnecessarily with descending scans
560+
#
561+
CREATE TABLE t1 (f1 INTEGER, f2 INTEGER, PRIMARY KEY (f1), KEY(f2, f1));
562+
INSERT INTO t1 (
563+
WITH RECURSIVE
564+
a(i) AS (SELECT 0 UNION ALL SELECT i+1 FROM a WHERE i < 9 ),
565+
b(i) AS (SELECT x.i + y.i * 10 + z.i * 100 FROM a x, a y, a z)
566+
SELECT b.i, b.i %2 FROM b ORDER BY i);
567+
ANALYZE TABLE t1;
568+
Table Op Msg_type Msg_text
569+
test.t1 analyze status OK
570+
EXPLAIN SELECT * FROM t1 WHERE f2 = 1 AND f1 <= 100 ORDER BY f1 DESC LIMIT 1;
571+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
572+
1 SIMPLE t1 NULL range PRIMARY,f2 f2 9 NULL 50 100.00 Using where; Backward index scan; Using index
573+
Warnings:
574+
Note 1003 /* select#1 */ select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2` from `test`.`t1` where ((`test`.`t1`.`f2` = 1) and (`test`.`t1`.`f1` <= 100)) order by `test`.`t1`.`f1` desc limit 1
575+
SELECT * FROM t1 WHERE f2 = 1 AND f1 <= 100 ORDER BY f1 DESC LIMIT 1;
576+
f1 f2
577+
99 1
578+
CREATE TABLE t2 (
579+
f1 INTEGER,
580+
f2 INTEGER,
581+
f3 INTEGER,
582+
f4 INTEGER,
583+
f5 INTEGER,
584+
PRIMARY KEY (f1), KEY(f2,f3,f4,f5,f1));
585+
INSERT INTO t2 (
586+
WITH RECURSIVE a (i) AS (SELECT 0 UNION ALL SELECT i+1 FROM a WHERE i < 9 ),
587+
b (i) AS (SELECT x.i + y.i * 10 + z.i * 100 FROM a x, a y, a z)
588+
SELECT b.i, b.i%2, b.i%3, b.i%4, b.i%5 FROM b ORDER BY i);
589+
ANALYZE TABLE t2;
590+
Table Op Msg_type Msg_text
591+
test.t2 analyze status OK
592+
EXPLAIN SELECT * FROM t2
593+
WHERE f3 = 1 AND f2 = 1 AND f4 = 3 AND f5 IN(2,3) ORDER BY f4 DESC LIMIT 1;
594+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
595+
1 SIMPLE t2 NULL range f2 f2 20 NULL 33 100.00 Using where; Backward index scan; Using index
596+
Warnings:
597+
Note 1003 /* select#1 */ select `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3`,`test`.`t2`.`f4` AS `f4`,`test`.`t2`.`f5` AS `f5` from `test`.`t2` where ((`test`.`t2`.`f4` = 3) and (`test`.`t2`.`f2` = 1) and (`test`.`t2`.`f3` = 1) and (`test`.`t2`.`f5` in (2,3))) order by `test`.`t2`.`f4` desc limit 1
598+
SELECT * FROM t2
599+
WHERE f3 = 1 AND f2 = 1 AND f4 = 3 AND f5 IN(2,3) ORDER BY f4 DESC LIMIT 1;
600+
f1 f2 f3 f4 f5
601+
943 1 1 3 3
602+
EXPLAIN SELECT * FROM t2
603+
WHERE f2 = 1 AND f3 = 2 AND f4 = 3 AND f5 IN(2,3) ORDER BY f3,f4 DESC LIMIT 1;
604+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
605+
1 SIMPLE t2 NULL range f2 f2 20 NULL 33 100.00 Using where; Using index
606+
Warnings:
607+
Note 1003 /* select#1 */ select `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3`,`test`.`t2`.`f4` AS `f4`,`test`.`t2`.`f5` AS `f5` from `test`.`t2` where ((`test`.`t2`.`f4` = 3) and (`test`.`t2`.`f3` = 2) and (`test`.`t2`.`f2` = 1) and (`test`.`t2`.`f5` in (2,3))) order by `test`.`t2`.`f3`,`test`.`t2`.`f4` desc limit 1
608+
SELECT * FROM t2
609+
WHERE f2 = 1 AND f3 = 2 AND f4 = 3 AND f5 IN(2,3) ORDER BY f3,f4 DESC LIMIT 1;
610+
f1 f2 f3 f4 f5
611+
47 1 2 3 2
612+
EXPLAIN SELECT * FROM t2
613+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 AND f5 IN(2,3) ORDER BY f2,f3 DESC LIMIT 1;
614+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
615+
1 SIMPLE t2 NULL range f2 f2 10 NULL 166 2.00 Using where; Backward index scan; Using index
616+
Warnings:
617+
Note 1003 /* select#1 */ select `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3`,`test`.`t2`.`f4` AS `f4`,`test`.`t2`.`f5` AS `f5` from `test`.`t2` where ((`test`.`t2`.`f4` = 3) and (`test`.`t2`.`f2` = 1) and (`test`.`t2`.`f3` > 1) and (`test`.`t2`.`f5` in (2,3))) order by `test`.`t2`.`f2`,`test`.`t2`.`f3` desc limit 1
618+
SELECT * FROM t2
619+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 AND f5 IN(2,3) ORDER BY f2,f3 DESC LIMIT 1;
620+
f1 f2 f3 f4 f5
621+
983 1 2 3 3
622+
EXPLAIN SELECT * FROM t2
623+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 ORDER BY f2,f3,f5 DESC LIMIT 1;
624+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
625+
1 SIMPLE t2 NULL range f2 f2 10 NULL 166 10.00 Using where; Using index; Using filesort
626+
Warnings:
627+
Note 1003 /* select#1 */ select `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3`,`test`.`t2`.`f4` AS `f4`,`test`.`t2`.`f5` AS `f5` from `test`.`t2` where ((`test`.`t2`.`f4` = 3) and (`test`.`t2`.`f2` = 1) and (`test`.`t2`.`f3` > 1)) order by `test`.`t2`.`f2`,`test`.`t2`.`f3`,`test`.`t2`.`f5` desc limit 1
628+
SELECT * FROM t2
629+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 ORDER BY f2,f3,f5 DESC LIMIT 1;
630+
f1 f2 f3 f4 f5
631+
59 1 2 3 4
632+
EXPLAIN SELECT * FROM t2
633+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 ORDER BY f2 DESC ,f3 DESC ,f5 DESC LIMIT 1;
634+
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
635+
1 SIMPLE t2 NULL range f2 f2 10 NULL 166 10.00 Using where; Backward index scan; Using index
636+
Warnings:
637+
Note 1003 /* select#1 */ select `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3`,`test`.`t2`.`f4` AS `f4`,`test`.`t2`.`f5` AS `f5` from `test`.`t2` where ((`test`.`t2`.`f4` = 3) and (`test`.`t2`.`f2` = 1) and (`test`.`t2`.`f3` > 1)) order by `test`.`t2`.`f2` desc,`test`.`t2`.`f3` desc,`test`.`t2`.`f5` desc limit 1
638+
SELECT * FROM t2
639+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 ORDER BY f2 DESC ,f3 DESC ,f5 DESC LIMIT 1;
640+
f1 f2 f3 f4 f5
641+
959 1 2 3 4
642+
DROP TABLE t1,t2;

mysql-test/t/order_by_limit.test

Lines changed: 67 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -436,3 +436,70 @@ EXPLAIN SELECT * FROM test WHERE c = '2022-06-13' AND a > 222 ORDER BY c, a LIM
436436

437437
DROP PROCEDURE insertProc;
438438
DROP TABLE test;
439+
440+
--echo #
441+
--echo # Bug#34306497 - Low limit heuristic used unnecessarily with descending scans
442+
--echo #
443+
444+
CREATE TABLE t1 (f1 INTEGER, f2 INTEGER, PRIMARY KEY (f1), KEY(f2, f1));
445+
446+
INSERT INTO t1 (
447+
WITH RECURSIVE
448+
a(i) AS (SELECT 0 UNION ALL SELECT i+1 FROM a WHERE i < 9 ),
449+
b(i) AS (SELECT x.i + y.i * 10 + z.i * 100 FROM a x, a y, a z)
450+
SELECT b.i, b.i %2 FROM b ORDER BY i);
451+
452+
ANALYZE TABLE t1;
453+
454+
let query =
455+
SELECT * FROM t1 WHERE f2 = 1 AND f1 <= 100 ORDER BY f1 DESC LIMIT 1;
456+
457+
eval EXPLAIN $query;
458+
eval $query;
459+
460+
CREATE TABLE t2 (
461+
f1 INTEGER,
462+
f2 INTEGER,
463+
f3 INTEGER,
464+
f4 INTEGER,
465+
f5 INTEGER,
466+
PRIMARY KEY (f1), KEY(f2,f3,f4,f5,f1));
467+
468+
INSERT INTO t2 (
469+
WITH RECURSIVE a (i) AS (SELECT 0 UNION ALL SELECT i+1 FROM a WHERE i < 9 ),
470+
b (i) AS (SELECT x.i + y.i * 10 + z.i * 100 FROM a x, a y, a z)
471+
SELECT b.i, b.i%2, b.i%3, b.i%4, b.i%5 FROM b ORDER BY i);
472+
473+
ANALYZE TABLE t2;
474+
475+
let query =
476+
SELECT * FROM t2
477+
WHERE f3 = 1 AND f2 = 1 AND f4 = 3 AND f5 IN(2,3) ORDER BY f4 DESC LIMIT 1;
478+
eval EXPLAIN $query;
479+
eval $query;
480+
481+
let query =
482+
SELECT * FROM t2
483+
WHERE f2 = 1 AND f3 = 2 AND f4 = 3 AND f5 IN(2,3) ORDER BY f3,f4 DESC LIMIT 1;
484+
eval EXPLAIN $query;
485+
eval $query;
486+
487+
let query =
488+
SELECT * FROM t2
489+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 AND f5 IN(2,3) ORDER BY f2,f3 DESC LIMIT 1;
490+
eval EXPLAIN $query;
491+
eval $query;
492+
493+
let query =
494+
SELECT * FROM t2
495+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 ORDER BY f2,f3,f5 DESC LIMIT 1;
496+
eval EXPLAIN $query;
497+
eval $query;
498+
499+
let query =
500+
SELECT * FROM t2
501+
WHERE f2 = 1 AND f3 > 1 AND f4 = 3 ORDER BY f2 DESC ,f3 DESC ,f5 DESC LIMIT 1;
502+
eval EXPLAIN $query;
503+
eval $query;
504+
505+
DROP TABLE t1,t2;

sql/sql_optimizer.cc

Lines changed: 15 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -1819,11 +1819,13 @@ int test_if_order_by_key(ORDER_with_src *order_src, TABLE *table, uint idx,
18191819
/*
18201820
Skip key parts that are constants in the WHERE clause if these are
18211821
already removed in the ORDER expression by check_field_is_const().
1822+
If they are not removed in the ORDER expression yet, then we skip
1823+
the constant keyparts that are not part of the ORDER expression.
18221824
*/
1823-
if (order_src->is_const_optimized()) {
1824-
for (; const_key_parts & 1 && key_part < key_part_end;
1825-
const_key_parts >>= 1)
1826-
key_part++;
1825+
for (; const_key_parts & 1 && key_part < key_part_end &&
1826+
(order_src->is_const_optimized() || key_part->field != field);
1827+
const_key_parts >>= 1) {
1828+
key_part++;
18271829
}
18281830

18291831
/* Avoid usage of prefix index for sorting a partition table */
@@ -1850,11 +1852,13 @@ int test_if_order_by_key(ORDER_with_src *order_src, TABLE *table, uint idx,
18501852
/*
18511853
Skip key parts that are constants in the WHERE clause if these are
18521854
already removed in the ORDER expression by check_field_is_const().
1855+
If they are not removed in the ORDER expression yet, then we skip
1856+
the constant keyparts that are not part of the ORDER expression.
18531857
*/
1854-
if (order_src->is_const_optimized()) {
1855-
for (; const_key_parts & 1 && key_part < key_part_end;
1856-
const_key_parts >>= 1)
1857-
key_part++;
1858+
for (; const_key_parts & 1 && key_part < key_part_end &&
1859+
(order_src->is_const_optimized() || key_part->field != field);
1860+
const_key_parts >>= 1) {
1861+
key_part++;
18581862
}
18591863
/*
18601864
The primary and secondary key parts were all const (i.e. there's
@@ -9776,7 +9780,9 @@ static bool make_join_query_block(JOIN *join, Item *cond) {
97769780
*/
97779781
if (read_direction == 1 ||
97789782
(read_direction == -1 &&
9779-
is_reverse_sorted_range(tab->range_scan()))) {
9783+
reverse_sort_possible(tab->range_scan()) &&
9784+
!make_reverse(get_used_key_parts(tab->range_scan()),
9785+
tab->range_scan()))) {
97809786
recheck_reason = DONT_RECHECK;
97819787
}
97829788
}

0 commit comments

Comments
 (0)