summaryrefslogtreecommitdiff
path: root/mysql-test/t/table_elim.test
blob: 7591870334778e46aa71df347c0e5541d26d8c95 (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
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
#
# Table elimination (MWL#17) tests
#
--disable_warnings
drop table if exists t0, t1, t2, t3;
drop view if exists v1, v2;
--enable_warnings

create table t1 (a int);
insert into t1 values (0),(1),(2),(3);
create table t0 as select * from t1;

create table t2 (a int primary key, b int) 
  as select a, a as b from t1 where a in (1,2);

create table t3 (a int primary key, b int) 
  as select a, a as b from t1 where a in (1,3);

--echo # This will be  eliminated:
explain select t1.a from t1 left join t2 on t2.a=t1.a;
explain extended select t1.a from t1 left join t2 on t2.a=t1.a;

select t1.a from t1 left join t2 on t2.a=t1.a;

--echo # This will not be eliminated as t2.b is in in select list:
explain select * from t1 left join t2 on t2.a=t1.a;

--echo # This will not be eliminated as t2.b is in in order list:
explain select t1.a from t1 left join t2 on t2.a=t1.a order by t2.b;

--echo # This will not be eliminated as t2.b is in group list:
explain select t1.a from t1 left join t2 on t2.a=t1.a group by t2.b;

--echo # This will not be eliminated as t2.b is in the WHERE
explain select t1.a from t1 left join t2 on t2.a=t1.a where t2.b < 3 or t2.b is null;

--echo # Elimination of multiple tables:
explain select t1.a from t1 left join (t2 join t3) on t2.a=t1.a and t3.a=t1.a;

--echo # Elimination of multiple tables (2):
explain select t1.a from t1 left join (t2 join t3 on t2.b=t3.b) on t2.a=t1.a and t3.a=t1.a;

--echo # Elimination when done within an outer join nest:
explain extended
select t0.*
from
  t0 left join (t1 left join (t2 join t3 on t2.b=t3.b) on t2.a=t1.a and
  t3.a=t1.a) on t0.a=t1.a;

--echo # Elimination with aggregate functions
explain select count(*) from t1 left join t2 on t2.a=t1.a;
explain select count(1) from t1 left join t2 on t2.a=t1.a;
explain select count(1) from t1 left join t2 on t2.a=t1.a group by t1.a;

--echo This must not use elimination:
explain select count(1) from t1 left join t2 on t2.a=t1.a group by t2.a;

drop table t0, t1, t2, t3;

# This will stand for elim_facts
create table t0 ( id integer, primary key (id));

# Attribute1, non-versioned
create table t1 (
  id integer,
  attr1 integer,
  primary key (id),
  key (attr1)
);

# Attribute2, time-versioned
create table t2 (
  id integer,
  attr2 integer,
  fromdate date,
  primary key (id, fromdate),
  key (attr2,fromdate)
);

insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
insert into t0 select A.id + 10*B.id from t0 A, t0 B where B.id > 0;

insert into t1 select id, id from t0;
insert into t2 select id, id, date_add('2009-06-22', interval id day) from t0;
insert into t2 select id, id+1, date_add('2008-06-22', interval id day) from t0;

create view v1 as
select 
  f.id, a1.attr1, a2.attr2
from 
  t0 f 
  left join t1 a1 on a1.id=f.id
  left join t2 a2 on a2.id=f.id and 
                     a2.fromdate=(select MAX(fromdate) from
                                  t2 where id=a2.id);
create view v2 as
select 
  f.id, a1.attr1, a2.attr2
from 
  t0 f 
  left join t1 a1 on a1.id=f.id
  left join t2 a2 on a2.id=f.id and 
                     a2.fromdate=(select MAX(fromdate) from
                                  t2 where id=f.id);

--echo This should use one table:
explain select id from v1 where id=2;
--echo This should use one table:
explain extended select id from v1 where id in (1,2,3,4);
--echo This should use facts and a1 tables:
explain extended select id from v1 where attr1 between 12 and 14;
--echo This should use facts, a2 and its subquery:
explain extended select id from v1 where attr2 between 12 and 14;

# Repeat for v2: 

--echo This should use one table:
explain select id from v2 where id=2;
--echo This should use one table:
explain extended select id from v2 where id in (1,2,3,4);
--echo This should use facts and a1 tables:
explain extended select id from v2 where attr1 between 12 and 14;
--echo This should use facts, a2 and its subquery:
explain extended select id from v2 where attr2 between 12 and 14;

drop view v1, v2;
drop table t0, t1, t2;

#
# Tests for the code that uses t.keypartX=func(t.keypartY) equalities to
# make table elimination inferences
#
create table t1 (a int);
insert into t1 values (0),(1),(2),(3);

create table t2 (pk1 int, pk2 int, pk3 int, col int, primary key(pk1, pk2, pk3));
insert into t2 select a,a,a,a from t1;

--echo This must use only t1:
explain select t1.* from t1 left join t2 on t2.pk1=t1.a and 
                                            t2.pk2=t2.pk1+1 and
                                            t2.pk3=t2.pk2+1;

--echo This must use only t1:
explain select t1.* from t1 left join t2 on t2.pk1=t1.a and 
                                            t2.pk3=t2.pk1+1 and
                                            t2.pk2=t2.pk3+1;

--echo This must use both:
explain select t1.* from t1 left join t2 on t2.pk1=t1.a and 
                                            t2.pk3=t2.pk1+1 and
                                            t2.pk2=t2.pk3+t2.col;

--echo This must use only t1:
explain select t1.* from t1 left join t2 on t2.pk2=t1.a and 
                                            t2.pk1=t2.pk2+1 and
                                            t2.pk3=t2.pk1;

drop table t1, t2;
#
# Check that equality propagation is taken into account
#
create table t1 (pk int primary key, col int);
insert into t1 values (1,1),(2,2);

create table t2 like t1;
insert into t2 select * from t1;

create table t3 like t1;
insert into t3 select * from t1;

explain 
select t1.* from t1 left join ( t2 left join t3 on t3.pk=t2.col) on t2.col=t1.col;

explain 
select t1.*, t2.* from t1 left join (t2 left join t3 on t3.pk=t2.col) on t2.pk=t1.col;

explain select t1.* 
from 
  t1 left join ( t2 left join t3 on t3.pk=t2.col or t3.pk=t2.col) 
  on t2.col=t1.col or t2.col=t1.col;

explain select t1.*, t2.* 
from 
  t1 left join 
  (t2 left join t3 on t3.pk=t2.col or t3.pk=t2.col) 
  on t2.pk=t1.col or t2.pk=t1.col;

drop table t1, t2, t3;

--echo # 
--echo # Check things that look like functional dependencies but really are not
--echo # 

create table t1 (a char(10) character set latin1 collate latin1_general_ci primary key);
insert into t1 values ('foo');
insert into t1 values ('bar');

create table t2 (a char(10) character set latin1 collate latin1_general_cs primary key);
insert into t2 values ('foo');
insert into t2 values ('FOO');

-- echo this must not use table elimination:
explain select t1.* from t1 left join t2 on t2.a='foo' collate latin1_general_ci; 

-- echo this must not use table elimination:
explain select t1.* from t1 left join t2 on t2.a=t1.a collate latin1_general_ci; 
drop table t1,t2;

create table t1 (a int primary key);
insert into t1 values (1),(2);
create table t2 (a char(10) primary key);
insert into t2 values ('1'),('1.0');
-- echo this must not use table elimination:
explain select t1.* from t1 left join t2 on t2.a=1;
-- echo this must not use table elimination:
explain select t1.* from t1 left join t2 on t2.a=t1.a;

drop table t1, t2;
# partial unique keys do not work at the moment, although they are able to
# provide one-match guarantees:
create table t1 (a char(10) primary key);
insert into t1 values ('foo'),('bar');

create table t2 (a char(10), unique key(a(2)));
insert into t2 values ('foo'),('bar');

explain select t1.* from t1 left join t2 on t2.a=t1.a;

drop table t1, t2;

--echo #
--echo # check UPDATE/DELETE that look like they could be eliminated
--echo #
create table t1 (a int primary key, b int);
insert into t1 values (1,1),(2,2),(3,3);

create table t2 like t1;
insert into t2 select * from t1;
update t1 left join t2 using (a) set t2.a=t2.a+100;
select * from t1;
select * from t2;

delete from t2;
insert into t2 select * from t1;

delete t2 from t1 left join t2 using (a);
select * from t1;
select * from t2;
drop table t1, t2;

--echo #
--echo # Tests with various edge-case ON expressions
--echo #
create table t1 (a int, b int, c int, d int);
insert into t1 values (0,0,0,0),(1,1,1,1),(2,2,2,2),(3,3,3,3);

create table t2 (pk int primary key, b int) 
  as select a as pk, a as b from t1 where a in (1,2);

create table t3 (pk1 int, pk2 int, b int, unique(pk1,pk2));
insert into t3 select a as pk1, a as pk2, a as b from t1 where a in (1,3);

explain select t1.a from t1 left join t2 on t2.pk=t1.a and t2.b<t1.b;
explain select t1.a from t1 left join t2 on t2.pk=t1.a or t2.b<t1.b;
explain select t1.a from t1 left join t2 on t2.b<t1.b or t2.pk=t1.a;

explain select t1.a from t1 left join t2 on t2.pk between 10 and 20;
explain select t1.a from t1 left join t2 on t2.pk between 0.5 and 1.5;
explain select t1.a from t1 left join t2 on t2.pk between 10 and 10;

explain select t1.a from t1 left join t2 on t2.pk in (10);
explain select t1.a from t1 left join t2 on t2.pk in (t1.a);

explain select t1.a from t1 left join t2 on TRUE;

explain select t1.a from t1 left join t3 on t3.pk1=t1.a and t3.pk2 IS NULL;

drop table t1,t2,t3;

--echo #
--echo # Multi-equality tests 
--echo #
create table t1 (a int, b int, c int, d int);
insert into t1 values (0,0,0,0),(1,1,1,1),(2,2,2,2),(3,3,3,3);

create table t2 (pk int primary key, b int, c int);
insert into t2 select a,a,a from t1 where a in (1,2);

explain 
select t1.* 
from t1 left join t2 on t2.pk=t2.c and t2.b=t1.a and t1.a=t1.b and t2.c=t2.b
where t1.d=1;

explain 
select t1.* 
from 
    t1 
  left join 
    t2 
  on (t2.pk=t2.c and t2.b=t1.a and t1.a=t1.b and t2.c=t2.b) or
     (t2.pk=t2.c and t2.b=t1.a and t1.a=t1.b and t2.c=t2.b) 
where t1.d=1;

--echo #This can't be eliminated:
explain 
select t1.* 
from 
    t1 
  left join 
    t2 
  on (t2.pk=t2.c and t2.b=t1.a and               t2.c=t1.b) or
     (t2.pk=t2.c and               t1.a=t1.b and t2.c=t1.b) 
where t1.d=1;

explain 
select t1.* 
from 
    t1 
  left join 
    t2 
  on (t2.pk=t2.c and t2.b=t1.a and t2.c=t1.b) or
     (t2.pk=t2.c and               t2.c=t1.b) 
;

explain 
select t1.* 
from t1 left join t2 on t2.pk=3 or t2.pk= 4;

explain 
select t1.* 
from t1 left join t2 on t2.pk=3 or t2.pk= 3;

explain 
select t1.* 
from t1 left join t2 on (t2.pk=3 and t2.b=3) or (t2.pk= 4 and t2.b=3);

drop table t1, t2;