summaryrefslogtreecommitdiff
path: root/mysql-test/main/desc_index_range.test
blob: ec52e254fe797f2c40bf85b833d13d235b308000 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
#
# Tests for range access and descending indexes
#
--source include/have_sequence.inc
--source include/have_innodb.inc

# The test uses optimizer trace:
--source include/not_embedded.inc

create table t1 (
  a int,
  key (a desc)
);
insert into t1 select seq from seq_1_to_1000;

set optimizer_trace=1;
explain select * from t1 force index(a) where a in (2, 4, 6);

#enable after fix MDEV-27871
--disable_view_protocol
select json_detailed(json_extract(trace, '$**.range_access_plan.ranges'))
from information_schema.optimizer_trace;
--enable_view_protocol
set optimizer_trace=default;

--echo # These should go in reverse order:
select * from t1 force index(a) where a in (2, 4, 6);
drop table t1;

--echo #
--echo # Multi-part key tests
--echo #
create table t1 (
  a int not null,
  b int not null,
  key ab(a, b desc)
);

insert into t1 select A.seq, B.seq*10 from seq_1_to_10 A, seq_1_to_10 B;

#enable after fix MDEV-27871
--disable_view_protocol
set optimizer_trace=1;
explain select * from t1 force index(ab) where a>=8 and b>=50;
select json_detailed(json_extract(trace, '$**.range_access_plan.ranges'))
from information_schema.optimizer_trace;

explain select * from t1 force index(ab) where a>=8 and b<=50;
select json_detailed(json_extract(trace, '$**.range_access_plan.ranges'))
from information_schema.optimizer_trace;
--enable_view_protocol

select * from t1 force index(ab) where a>=8 and b<=50;
select * from t1 ignore index(ab) where a>=8 and b<=50 order by a, b desc;

#enable after fix MDEV-27871
--disable_view_protocol
explain
select * from t1 where a between 2 and 4 and b between 50 and 80;
select json_detailed(json_extract(trace, '$**.range_access_plan.ranges'))
from information_schema.optimizer_trace;
--enable_view_protocol

select * from t1 where a between 2 and 4 and b between 50 and 80;

drop table t1;

create table t2 (
  a int not null,
  b int not null,
  key ab(a desc, b desc)
);
insert into t2 select A.seq, B.seq*10 from seq_1_to_10 A, seq_1_to_10 B;

#enable after fix MDEV-27871
--disable_view_protocol
explain
select * from t2 where a between 2 and 4;
select json_detailed(json_extract(trace, '$**.range_access_plan.ranges'))
from information_schema.optimizer_trace;

explain
select * from t2 where a between 2 and 4 and b between 50 and 80;
select json_detailed(json_extract(trace, '$**.range_access_plan.ranges'))
from information_schema.optimizer_trace;
--enable_view_protocol

drop table t2;

--echo #
--echo # Check that "Using index for group-by" is disabled (it's not supported, yet)
--echo #
CREATE TABLE t1 (p int NOT NULL, a int NOT NULL, PRIMARY KEY (p,a desc));
insert into t1 select 2,seq from seq_0_to_1000;
EXPLAIN select MIN(a) from t1 where p = 2 group by p;
#enable after fix MDEV-27871
--disable_view_protocol
select json_detailed(json_extract(trace, '$**.potential_group_range_indexes'))
from information_schema.optimizer_trace;
--enable_view_protocol
drop table t1;

set optimizer_trace=default;

--echo #
--echo # MDEV-27426: Wrong result upon query using index_merge with DESC key
--echo #

CREATE TABLE t1 (pk INT, a INT, b int, KEY(a), PRIMARY KEY(pk DESC))
ENGINE=InnoDB;
INSERT INTO t1 VALUES (1,4,5),(2,9,6),(3,NULL,7),(4,NULL,8);

SELECT * FROM t1 WHERE pk > 10 OR a > 0;
DROP TABLE t1;


--echo #
--echo #  MDEV-27529: Wrong result upon query using index_merge with DESC key (#2)
--echo #

create table t1 (
  pk int, 
  a int, 
  b int,
  primary key(pk desc),
  key(a),
  key(b)
) engine=innodb;

insert into t1 values (0, 111111, 255);

insert into t1 select seq+50000, NULL, seq+1000 from seq_1_to_260;

insert into t1 values (10000, NULL, 255);
insert into t1 select seq+20000, seq+20000, seq+20000 from seq_1_to_1500;

analyze table t1;

--echo # Must use ROR-intersect:
explain select * from t1 where b = 255 AND a IS NULL;
select * from t1 where b = 255 AND a IS NULL;

drop table t1;