Skip to content

Commit

Permalink
WL#11322 SUPPORT LOOSE INDEX RANGE SCANS FOR LOW CARDINALITY.
Browse files Browse the repository at this point in the history
  • Loading branch information
Sergey Glukhov committed Jun 27, 2018
1 parent 5bbe3c3 commit 6d069bc
Show file tree
Hide file tree
Showing 83 changed files with 7,194 additions and 295 deletions.
43 changes: 43 additions & 0 deletions mysql-test/include/skip_scan_data.inc
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
eval CREATE TABLE t (a INT, b INT, c INT, d INT, e INT, PRIMARY KEY(a, b, c, d), KEY(b, d)) ENGINE=$engine;

--disable_query_log
CREATE TEMPORARY TABLE a (a INT);
let $i=10;
while ($i)
{
--eval INSERT INTO a VALUES ($i)
dec $i;
}

CREATE TEMPORARY TABLE b (a INT);
let $i=5;
while ($i)
{
--eval INSERT INTO b VALUES ($i)
dec $i;
}

CREATE TEMPORARY TABLE c (a INT);
let $i=5;
while ($i)
{
--eval INSERT INTO c VALUES ($i)
dec $i;
}

CREATE TEMPORARY TABLE d (a INT);
let $i=10;
while ($i)
{
--eval INSERT INTO d VALUES ($i)
dec $i;
}

INSERT INTO t SELECT a.a, b.a, c.a, d.a, d.a FROM a, b, c, d;

DROP TEMPORARY TABLE a, b, c, d;

--enable_query_log

ANALYZE TABLE t;

41 changes: 41 additions & 0 deletions mysql-test/include/skip_scan_query.inc
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
set optimizer_switch = 'skip_scan=on';
--eval EXPLAIN $query
FLUSH STATUS;
--disable_result_log
--eval $query
--enable_result_log
SHOW STATUS LIKE 'handler_read%';
--disable_query_log
--eval CREATE TABLE skip_scan $query
--enable_query_log

set optimizer_switch = 'skip_scan=off';
--eval EXPLAIN $query
FLUSH STATUS;
--disable_result_log
--eval $query
--enable_result_log
SHOW STATUS LIKE 'handler_read%';
--disable_query_log
--eval CREATE TABLE no_skip_scan $query
--enable_query_log

--let $diff_tables= test.skip_scan, test.no_skip_scan
--source include/diff_tables.inc

--eval EXPLAIN $hint_query
FLUSH STATUS;
--disable_result_log
--eval $hint_query
--enable_result_log
SHOW STATUS LIKE 'handler_read%';
--disable_query_log
--eval CREATE TABLE hint_skip_scan $hint_query
--enable_query_log

--let $diff_tables= test.hint_skip_scan, test.no_skip_scan
--source include/diff_tables.inc

--disable_query_log
DROP TABLE skip_scan, no_skip_scan, hint_skip_scan;
--enable_query_log
183 changes: 183 additions & 0 deletions mysql-test/include/skip_scan_test.inc
Original file line number Diff line number Diff line change
@@ -0,0 +1,183 @@
--source include/skip_scan_data.inc

# These queries should do loose index scans.

# Skip scan is used if 'skip_scan=on'
--let $query= SELECT b, d FROM t WHERE d < 2
--let $hint_query= SELECT /*+ SKIP_SCAN(t) */ b, d FROM t WHERE d < 2
--source include/skip_scan_query.inc

# Skip scan is used if 'skip_scan=on'
--let $query = SELECT b, d FROM t WHERE d > 4
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, d FROM t WHERE d > 4
--source include/skip_scan_query.inc

# Skip scan is not used if 'skip_scan=on' due to cost
--let $query = SELECT a, b, c, d FROM t WHERE a = 5 AND d <= 3
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a = 5 AND d <= 3
--source include/skip_scan_query.inc

# Skip scan is not used if 'skip_scan=on' due to cost
--let $query = SELECT a, b, c, d FROM t WHERE a = 5 AND d >= 98
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a = 5 AND d >= 98
--source include/skip_scan_query.inc

# Skip scan is not used if 'skip_scan=on' due to cost
--let $query = SELECT a, b, c, d FROM t WHERE a IN (1, 5) AND d >= 98
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a IN (1, 5) AND d >= 98
--source include/skip_scan_query.inc

# Skip scan is not used if 'skip_scan=on' due to cost
--let $query = SELECT a, b, c, d FROM t WHERE a IN (1, 3, 5) AND d >= 98
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a IN (1, 3, 5) AND d >= 98
--source include/skip_scan_query.inc

# Skip scan is not used if 'skip_scan=on' due to cost
--let $query = SELECT a, b, c, d FROM t WHERE a IN (1, 5) AND b IN (1, 2) AND d >= 98
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a IN (1, 5) AND b IN (1, 2) AND d >= 98
--source include/skip_scan_query.inc

# Skip scan is not used if 'skip_scan=on' due to cost
--let $query = SELECT a, b, c, d FROM t WHERE a IN (1, 2, 3, 4, 5) AND b IN (1, 2, 3) AND d >= 98
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a IN (1, 2, 3, 4, 5) AND b IN (1, 2, 3) AND d >= 98
--source include/skip_scan_query.inc

# Skip scan is not used if 'skip_scan=on' due to cost
--let $query = SELECT a, b, c, d FROM t WHERE a = 5 AND b = 2 AND d >= 98
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a = 5 AND b = 2 AND d >= 98
--source include/skip_scan_query.inc

# Skip scan is used if 'skip_scan=on'
--let $query = SELECT a+1, b, c, d FROM t WHERE a = 5 AND d < 3
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a+1, b, c, d FROM t WHERE a = 5 AND d < 3
--source include/skip_scan_query.inc

# Skip scan is not used if 'skip_scan=on' due to cost
--let $query = SELECT b, c, d FROM t WHERE a = 5 AND d < 3
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND d < 3
--source include/skip_scan_query.inc

# Skip scan is used if 'skip_scan=on'
--let $query = SELECT a, b, c, d FROM t WHERE a = b AND d >= 98
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a = b AND d >= 98
--source include/skip_scan_query.inc

# Skip scan is used if 'skip_scan=on'
--let $query = SELECT b, c, d FROM t WHERE a = 5 AND c > 10 AND d < 3
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND c > 10 AND d < 3
--source include/skip_scan_query.inc

# Skip scan is used if 'skip_scan=on'
--let $query = SELECT b, c, d FROM t WHERE a = 5 AND c > 10 AND d < 3 ORDER BY d, c
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND c > 10 AND d < 3 ORDER BY d, c
--source include/skip_scan_query.inc

# Skip scan is used if 'skip_scan=on'
--let $query = SELECT b, c, d FROM t WHERE a = 5 AND c > 1 AND d < 3 ORDER BY d, c * -1
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND c > 1 AND d < 3 ORDER BY d, c * -1
--source include/skip_scan_query.inc

# Skip scan is not used since field 'e' is not part of the index.
--let $query = SELECT e FROM t WHERE a = 5 AND d <= 3
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ e FROM t WHERE a = 5 AND d <= 3
--source include/skip_scan_query.inc

# Skip scan is not used since field 'e' is not part of the index.
--let $query = SELECT b, c, d FROM t WHERE a = 5 AND c > 10 AND d < 3 ORDER BY d, c, e
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND c > 10 AND d < 3 ORDER BY d, c, e
--source include/skip_scan_query.inc

# Testing aggregate functions.
--let $query = SELECT count(a), count(b), count(c) FROM t WHERE a = 5 AND c > 10 AND d < 3
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ count(a), count(b), count(c) FROM t WHERE a = 5 AND c > 10 AND d < 3
--source include/skip_scan_query.inc

--let $query = SELECT min(a), max(b), min(c) FROM t WHERE a = 5 AND c > 10 AND d < 3
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ min(a), max(b), min(c) FROM t WHERE a = 5 AND c > 10 AND d < 3
--source include/skip_scan_query.inc

--let $query = SELECT sum(a), sum(b), sum(c) FROM t WHERE a = 5 AND c > 10 AND d < 3
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ sum(a), avg(b), sum(c) FROM t WHERE a = 5 AND c > 10 AND d < 3
--source include/skip_scan_query.inc

--let $query = SELECT count(*) FROM t WHERE d < 2;
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ count(*) FROM t WHERE d < 2;
--source include/skip_scan_query.inc

if ($engine == 'innodb' )
{
--echo Testing DESC index with skip scan.
ALTER TABLE t DROP PRIMARY KEY;
ALTER TABLE t DROP KEY b;
ALTER TABLE t ADD PRIMARY KEY(a DESC, b, c DESC, d);
ANALYZE TABLE t;

--let $query = SELECT b, c, d FROM t WHERE a = 5 AND c > 3 AND d < 3;
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND c > 3 AND d < 3;
--source include/skip_scan_query.inc

--let $query = SELECT b, c, d FROM t WHERE a = 5 AND c < 3 AND d < 3;
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND c < 3 AND d < 3;
--source include/skip_scan_query.inc

--let $query = SELECT b, c, d FROM t WHERE a = 5 AND c = 3 AND d < 3;
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND c = 3 AND d < 3;
--source include/skip_scan_query.inc

--let $query = SELECT b, c, d FROM t WHERE a = 5 AND c BETWEEN 3 AND 5 AND d < 3;
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE a = 5 AND c BETWEEN 3 AND 5 AND d < 3;
--source include/skip_scan_query.inc

--let $query = SELECT b, c, d FROM t WHERE c BETWEEN 3 AND 5 AND d < 3;
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE c BETWEEN 3 AND 5 AND d < 3;
--source include/skip_scan_query.inc

--let $query = SELECT b, c, d FROM t WHERE d < 3;
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ b, c, d FROM t WHERE d < 3;
--source include/skip_scan_query.inc

--let $query = SELECT a, b, c, d FROM t WHERE a IN (1, 3, 5) AND d >= 5
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a IN (1, 3, 5) AND d >= 5
--source include/skip_scan_query.inc

--let $query = SELECT a, b, c, d FROM t WHERE a IN (1, 5, 3) AND b IN (1, 2) AND d >= 5
--let $hint_query = SELECT /*+ SKIP_SCAN(t) */ a, b, c, d FROM t WHERE a IN (1, 5, 3) AND b in (1, 2) AND d >= 5
--source include/skip_scan_query.inc
}

set optimizer_switch = default;
DROP TABLE t;

if ($engine == 'innodb' )
{
--echo Testing DESC index with skip scan and NULL range.
CREATE TABLE t1 (a INT, b INT, c INT, d INT, e INT);

INSERT INTO t1 VALUES
(NULL, 1, 1, 3, 4), (NULL, 2, 1, 4, 5),
(1, 2, 1, 3, 4), (2, 2, 1, 4, 5),
(5, 2, 3, 3, 4), (2, 2, 1, 4, 11),
(8, 2, 1, 3, 4), (7, 2, 1, 4, 9);

INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;

ALTER TABLE t1 ADD KEY k1(a DESC, b, c DESC, d, e DESC);
ANALYZE TABLE t1;

--let $query = SELECT a, b, c, d FROM t1 WHERE (a IN (1, 5) or a IS NULL) AND b in (1, 2) AND d BETWEEN 2 AND 5
--let $hint_query = SELECT /*+ SKIP_SCAN(t1) */ a, b, c, d FROM t1 WHERE (a IN (1, 5) or a IS NULL) AND b in (1, 2) AND d BETWEEN 2 AND 5
--source include/skip_scan_query.inc

ALTER TABLE t1 DROP KEY k1;
ALTER TABLE t1 ADD KEY k1(a, b DESC, c, d DESC, e);
ANALYZE TABLE t1;

--let $query = SELECT a, b, c, d FROM t1 WHERE (a IN (1, 5) or a IS NULL) AND b in (1, 2) AND d BETWEEN 2 AND 5
--let $hint_query = SELECT /*+ SKIP_SCAN(t1) */ a, b, c, d FROM t1 WHERE (a IN (1, 5) or a IS NULL) AND b in (1, 2) AND d BETWEEN 2 AND 5
--source include/skip_scan_query.inc

set optimizer_switch = default;
DROP TABLE t1;
}
2 changes: 1 addition & 1 deletion mysql-test/r/group_min_max.result
Original file line number Diff line number Diff line change
Expand Up @@ -1532,7 +1532,7 @@ where exists ( select * from t2 where t2.c > 'b1' )
group by a1,a2,b;
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 NULL range idx_t1_1,idx_t1_2 idx_t1_1 147 NULL 17 100.00 Using index for group-by
2 SUBQUERY t2 NULL index NULL idx_t2_1 163 NULL 164 33.33 Using where; Using index
2 SUBQUERY t2 NULL index idx_t2_1 idx_t2_1 163 NULL 164 33.33 Using where; Using index
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`a1` AS `a1`,`test`.`t1`.`a2` AS `a2`,`test`.`t1`.`b` AS `b`,min(`test`.`t1`.`c`) AS `min(c)`,max(`test`.`t1`.`c`) AS `max(c)` from `test`.`t1` where 1 group by `test`.`t1`.`a1`,`test`.`t1`.`a2`,`test`.`t1`.`b`
explain select a1,a2,b,min(c),max(c) from t1 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
Expand Down
Loading

0 comments on commit 6d069bc

Please sign in to comment.