subselect.test 121 KB
Newer Older
1 2 3 4 5
# Initialise
--disable_warnings
drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t11,t12;
--enable_warnings

bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
6
select (select 2);
7
explain extended select (select 2);
8
SELECT (SELECT 1) UNION SELECT (SELECT 2);
9
explain extended SELECT (SELECT 1) UNION SELECT (SELECT 2);
10
SELECT (SELECT (SELECT 0 UNION SELECT 0));
11
explain extended SELECT (SELECT (SELECT 0 UNION SELECT 0));
monty@mysql.com's avatar
monty@mysql.com committed
12
-- error 1247
13
SELECT (SELECT 1 FROM (SELECT 1) as b HAVING a=1) as a;
monty@mysql.com's avatar
monty@mysql.com committed
14
-- error 1247
15 16
SELECT (SELECT 1 FROM (SELECT 1) as b HAVING b=1) as a,(SELECT 1 FROM (SELECT 1) as c HAVING a=1) as b;
SELECT (SELECT 1),MAX(1) FROM (SELECT 1) as a;
monty@mysql.com's avatar
monty@mysql.com committed
17
-- error 1247
18
SELECT (SELECT a) as a;
19
EXPLAIN EXTENDED SELECT 1 FROM (SELECT 1 as a) as b  HAVING (SELECT a)=1;
Sinisa@sinisa.nasamreza.org's avatar
Sinisa@sinisa.nasamreza.org committed
20
SELECT 1 FROM (SELECT 1 as a) as b HAVING (SELECT a)=1;
21 22
-- error 1054
SELECT (SELECT 1), a;
23
SELECT 1 as a FROM (SELECT 1) as b HAVING (SELECT a)=1;
24
-- error 1054
25
SELECT 1 FROM (SELECT (SELECT a) b) c;
26
SELECT * FROM (SELECT 1 as id) b WHERE id IN (SELECT * FROM (SELECT 1 as id) c ORDER BY id);
monty@mysql.com's avatar
monty@mysql.com committed
27
-- error 1241
28
SELECT * FROM (SELECT 1) a  WHERE 1 IN (SELECT 1,1);
29
SELECT 1 IN (SELECT 1);
Sinisa@sinisa.nasamreza.org's avatar
Sinisa@sinisa.nasamreza.org committed
30
SELECT 1 FROM (SELECT 1 as a) b WHERE 1 IN (SELECT (SELECT a));
31 32 33 34
-- error 1221
select (SELECT 1 FROM (SELECT 1) a PROCEDURE ANALYSE(1));
-- error 1108
SELECT 1 FROM (SELECT 1) a PROCEDURE ANALYSE((SELECT 1));
35
-- error ER_BAD_FIELD_ERROR
36
SELECT (SELECT 1) as a FROM (SELECT 1) b WHERE (SELECT a) IS NULL;
37
-- error ER_BAD_FIELD_ERROR
38
SELECT (SELECT 1) as a FROM (SELECT 1) b WHERE (SELECT a) IS NOT NULL;
39 40 41 42 43 44 45 46 47 48 49 50
SELECT (SELECT 1,2,3) = ROW(1,2,3);
SELECT (SELECT 1,2,3) = ROW(1,2,1);
SELECT (SELECT 1,2,3) < ROW(1,2,1);
SELECT (SELECT 1,2,3) > ROW(1,2,1);
SELECT (SELECT 1,2,3) = ROW(1,2,NULL);
SELECT ROW(1,2,3) = (SELECT 1,2,3);
SELECT ROW(1,2,3) = (SELECT 1,2,1);
SELECT ROW(1,2,3) < (SELECT 1,2,1);
SELECT ROW(1,2,3) > (SELECT 1,2,1);
SELECT ROW(1,2,3) = (SELECT 1,2,NULL);
SELECT (SELECT 1.5,2,'a') = ROW(1.5,2,'a');
SELECT (SELECT 1.5,2,'a') = ROW(1.5,2,'b');
51
SELECT (SELECT 1.5,2,'a') = ROW('1.5b',2,'b');
52
SELECT (SELECT 'b',2,'a') = ROW(1.5,2,'a');
53
SELECT (SELECT 1.5,2,'a') = ROW(1.5,'2','a');
54
SELECT (SELECT 1.5,'c','a') = ROW(1.5,2,'a');
55

monty@mysql.com's avatar
monty@mysql.com committed
56
-- error 1241
57 58
SELECT (SELECT * FROM (SELECT 'test' a,'test' b) a);

59 60
SELECT 1 as a,(SELECT a+a) b,(SELECT b);

61 62 63
create table t1 (a int);
create table t2 (a int, b int);
create table t3 (a int);
64
create table t4 (a int not null, b int not null);
65 66 67
insert into t1 values (2);
insert into t2 values (1,7),(2,7);
insert into t4 values (4,8),(3,8),(5,9);
monty@mysql.com's avatar
monty@mysql.com committed
68
-- error 1247
69
select (select a from t1 where t1.a = a1) as a2, (select b from t2 where t2.b=a2) as a1;
70 71
select (select a from t1 where t1.a=t2.a), a from t2;
select (select a from t1 where t1.a=t2.b), a from t2;
72
select (select a from t1), a, (select 1 union select 2 limit 1) from t2;
73 74 75
select (select a from t3), a from t2;
select * from t2 where t2.a=(select a from t1);
insert into t3 values (6),(7),(3);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
76
select * from t2 where t2.b=(select a from t3 order by 1 desc limit 1);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
77 78
(select * from t2 where t2.b=(select a from t3 order by 1 desc limit 1)) union (select * from t4 order by a limit 2) limit 3;
(select * from t2 where t2.b=(select a from t3 order by 1 desc limit 1)) union (select * from t4 where t4.b=(select max(t2.a)*4 from t2) order by a);
79
explain extended (select * from t2 where t2.b=(select a from t3 order by 1 desc limit 1)) union (select * from t4 where t4.b=(select max(t2.a)*4 from t2) order by a);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
80 81 82
select (select a from t3 where a<t2.a*4 order by 1 desc limit 1), a from t2;
select (select t3.a from t3 where a<8 order by 1 desc limit 1), a from 
(select * from t2 where a>1) as tt;
83
explain extended select (select t3.a from t3 where a<8 order by 1 desc limit 1), a from 
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
84
(select * from t2 where a>1) as tt;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
85 86 87 88
select * from t1 where t1.a=(select t2.a from t2 where t2.b=(select max(a) from t3) order by 1 desc limit 1);
select * from t1 where t1.a=(select t2.a from t2 where t2.b=(select max(a) from t3 where t3.a > t1.a) order by 1 desc limit 1);
select * from t1 where t1.a=(select t2.a from t2 where t2.b=(select max(a) from t3 where t3.a < t1.a) order by 1 desc limit 1);
select b,(select avg(t2.a+(select min(t3.a) from t3 where t3.a >= t4.a)) from t2) from t4;
89
explain extended select b,(select avg(t2.a+(select min(t3.a) from t3 where t3.a >= t4.a)) from t2) from t4;
90 91
select * from t3 where exists (select * from t2 where t2.b=t3.a);
select * from t3 where not exists (select * from t2 where t2.b=t3.a);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
92 93
select * from t3 where a in (select b from t2);
select * from t3 where a not in (select b from t2);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
94 95
select * from t3 where a = some (select b from t2);
select * from t3 where a <> any (select b from t2);
96 97

# Rewrite: select * from t3 where not exists (select b from t2 where a <> b);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
98
select * from t3 where a = all (select b from t2);
99

bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
100 101 102 103 104
select * from t3 where a <> all (select b from t2);
insert into t2 values (100, 5);
select * from t3 where a < any (select b from t2);
select * from t3 where a < all (select b from t2);
select * from t3 where a >= any (select b from t2);
105
explain extended select * from t3 where a >= any (select b from t2);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
106 107
select * from t3 where a >= all (select b from t2);
delete from t2 where a=100;
monty@mysql.com's avatar
monty@mysql.com committed
108
-- error 1241
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
109
select * from t3 where a in (select a,b from t2);
monty@mysql.com's avatar
monty@mysql.com committed
110
-- error 1241
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
111
select * from t3 where a in (select * from t2);
112
insert into t4 values (12,7),(1,7),(10,9),(9,6),(7,6),(3,9),(1,10);
113
# empty set
114 115 116 117 118
select b,max(a) as ma from t4 group by b having b < (select max(t2.a) from t2 where t2.b=t4.b);
insert into t2 values (2,10);
select b,max(a) as ma from t4 group by b having ma < (select max(t2.a) from t2 where t2.b=t4.b);
delete from t2 where a=2 and b=10;
select b,max(a) as ma from t4 group by b having b >= (select max(t2.a) from t2 where t2.b=t4.b);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
119 120 121 122 123 124
create table t5 (a int);
select (select a from t1 where t1.a=t2.a union select a from t5 where t5.a=t2.a), a from t2;
insert into t5 values (5);
select (select a from t1 where t1.a=t2.a union select a from t5 where t5.a=t2.a), a from t2;
insert into t5 values (2);
select (select a from t1 where t1.a=t2.a union select a from t5 where t5.a=t2.a), a from t2;
125
explain extended select (select a from t1 where t1.a=t2.a union select a from t5 where t5.a=t2.a), a from t2;
monty@mysql.com's avatar
monty@mysql.com committed
126
-- error 1242
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
127
select (select a from t1 where t1.a=t2.a union all select a from t5 where t5.a=t2.a), a from t2;
128 129 130 131 132
create table t6 (patient_uq int, clinic_uq int, index i1 (clinic_uq));
create table t7( uq int primary key, name char(25));
insert into t7 values(1,"Oblastnaia bolnitsa"),(2,"Bolnitsa Krasnogo Kresta");
insert into t6 values (1,1),(1,2),(2,2),(1,3);
select * from t6 where exists (select * from t7 where uq = clinic_uq);
133
explain extended select * from t6 where exists (select * from t7 where uq = clinic_uq);
134

135 136 137 138
# not unique fields
-- error 1052
select * from t1 where a= (select a from t2,t4 where t2.b=t4.b);

139
# different tipes & group functions
140
drop table t1,t2,t3;
141 142 143 144 145 146 147 148 149 150 151

CREATE TABLE t3 (a varchar(20),b char(1) NOT NULL default '0');
INSERT INTO t3 VALUES ('W','a'),('A','c'),('J','b');
CREATE TABLE t2 (a varchar(20),b int NOT NULL default '0');
INSERT INTO t2 VALUES ('W','1'),('A','3'),('J','2');
CREATE TABLE t1 (a varchar(20),b date NOT NULL default '0000-00-00');
INSERT INTO t1 VALUES ('W','1732-02-22'),('A','1735-10-30'),('J','1743-04-13');
SELECT * FROM t1 WHERE b = (SELECT MIN(b) FROM t1);
SELECT * FROM t2 WHERE b = (SELECT MIN(b) FROM t2);
SELECT * FROM t3 WHERE b = (SELECT MIN(b) FROM t3);

152
CREATE TABLE `t8` (
153 154 155 156
  `pseudo` varchar(35) character set latin1 NOT NULL default '',
  `email` varchar(60) character set latin1 NOT NULL default '',
  PRIMARY KEY  (`pseudo`),
  UNIQUE KEY `email` (`email`)
157
) ENGINE=MyISAM CHARSET=latin1 ROW_FORMAT=DYNAMIC;
158

159 160 161
INSERT INTO t8 (pseudo,email) VALUES ('joce','test');
INSERT INTO t8 (pseudo,email) VALUES ('joce1','test1');
INSERT INTO t8 (pseudo,email) VALUES ('2joce1','2test1');
162
EXPLAIN EXTENDED SELECT pseudo,(SELECT email FROM t8 WHERE pseudo=(SELECT pseudo FROM t8 WHERE pseudo='joce')) FROM t8 WHERE pseudo=(SELECT pseudo FROM t8 WHERE pseudo='joce');
monty@mysql.com's avatar
monty@mysql.com committed
163
-- error 1241
164 165
SELECT pseudo FROM t8 WHERE pseudo=(SELECT pseudo,email FROM
t8 WHERE pseudo='joce');
monty@mysql.com's avatar
monty@mysql.com committed
166
-- error 1241
167
SELECT pseudo FROM t8 WHERE pseudo=(SELECT * FROM t8 WHERE
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
168
pseudo='joce');
169
SELECT pseudo FROM t8 WHERE pseudo=(SELECT pseudo FROM t8 WHERE pseudo='joce');
monty@mysql.com's avatar
monty@mysql.com committed
170
-- error 1242
171
SELECT pseudo FROM t8 WHERE pseudo=(SELECT pseudo FROM t8 WHERE pseudo LIKE '%joce%');
172

173
drop table if exists t1,t2,t3,t4,t5,t6,t7,t8;
174

bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
175
#searchconthardwarefr3 forumconthardwarefr7
176
CREATE TABLE `t1` (
177 178 179 180 181
  `topic` mediumint(8) unsigned NOT NULL default '0',
  `date` date NOT NULL default '0000-00-00',
  `pseudo` varchar(35) character set latin1 NOT NULL default '',
  PRIMARY KEY  (`pseudo`,`date`,`topic`),
  KEY `topic` (`topic`)
182
) ENGINE=MyISAM ROW_FORMAT=DYNAMIC;
183
INSERT INTO t1 (topic,date,pseudo) VALUES
184
('43506','2002-10-02','joce'),('40143','2002-08-03','joce');
185 186
EXPLAIN EXTENDED SELECT DISTINCT date FROM t1 WHERE date='2002-08-03';
EXPLAIN EXTENDED SELECT (SELECT DISTINCT date FROM t1 WHERE date='2002-08-03');
187 188 189
SELECT DISTINCT date FROM t1 WHERE date='2002-08-03';
SELECT (SELECT DISTINCT date FROM t1 WHERE date='2002-08-03');
SELECT 1 FROM t1 WHERE 1=(SELECT 1 UNION SELECT 1) UNION ALL SELECT 1;
monty@mysql.com's avatar
monty@mysql.com committed
190
-- error 1242
191
SELECT 1 FROM t1 WHERE 1=(SELECT 1 UNION ALL SELECT 1) UNION SELECT 1;
192
EXPLAIN EXTENDED SELECT 1 FROM t1 WHERE 1=(SELECT 1 UNION SELECT 1);
193
drop table t1;
194

195 196
#forumconthardwarefr7 searchconthardwarefr7
CREATE TABLE `t1` (
197 198 199 200
  `numeropost` mediumint(8) unsigned NOT NULL auto_increment,
  `maxnumrep` int(10) unsigned NOT NULL default '0',
  PRIMARY KEY  (`numeropost`),
  UNIQUE KEY `maxnumrep` (`maxnumrep`)
201
) ENGINE=MyISAM ROW_FORMAT=FIXED;
202

203
INSERT INTO t1 (numeropost,maxnumrep) VALUES (40143,1),(43506,2);
204

205
CREATE TABLE `t2` (
206 207 208 209 210
      `mot` varchar(30) NOT NULL default '',
      `topic` mediumint(8) unsigned NOT NULL default '0',
      `date` date NOT NULL default '0000-00-00',
      `pseudo` varchar(35) NOT NULL default '',
       PRIMARY KEY  (`mot`,`pseudo`,`date`,`topic`)
211
    ) ENGINE=MyISAM ROW_FORMAT=DYNAMIC;
212

213 214 215
INSERT INTO t2 (mot,topic,date,pseudo) VALUES ('joce','40143','2002-10-22','joce'), ('joce','43506','2002-10-22','joce');
select numeropost as a FROM t1 GROUP BY (SELECT 1 FROM t1 HAVING a=1);
SELECT numeropost,maxnumrep FROM t1 WHERE exists (SELECT 1 FROM t2 WHERE (mot='joce') AND date >= '2002-10-21' AND t1.numeropost = t2.topic) ORDER BY maxnumrep DESC LIMIT 0, 20;
216
-- error 1054
217
SELECT (SELECT 1) as a FROM (SELECT 1 FROM t1 HAVING a=1) b;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
218 219
-- error 1054
SELECT 1 IN (SELECT 1 FROM t2 HAVING a);
220 221 222

SELECT * from t2 where topic IN (SELECT topic FROM t2 GROUP BY topic);
SELECT * from t2 where topic IN (SELECT topic FROM t2 GROUP BY topic HAVING topic < 4100);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
223
SELECT * from t2 where topic IN (SELECT SUM(topic) FROM t1);
224 225
SELECT * from t2 where topic = any (SELECT topic FROM t2 GROUP BY topic);
SELECT * from t2 where topic = any (SELECT topic FROM t2 GROUP BY topic HAVING topic < 4100);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
226
SELECT * from t2 where topic = any (SELECT SUM(topic) FROM t1);
227 228 229
SELECT * from t2 where topic = all (SELECT topic FROM t2 GROUP BY topic);
SELECT * from t2 where topic = all (SELECT topic FROM t2 GROUP BY topic HAVING topic < 4100);
SELECT *, topic = all (SELECT topic FROM t2 GROUP BY topic HAVING topic < 4100) from t2;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
230 231
SELECT * from t2 where topic = all (SELECT SUM(topic) FROM t2);
SELECT * from t2 where topic <> any (SELECT SUM(topic) FROM t2);
232 233 234 235
SELECT * from t2 where topic IN (SELECT topic FROM t2 GROUP BY topic HAVING topic < 41000);
SELECT * from t2 where topic = any (SELECT topic FROM t2 GROUP BY topic HAVING topic < 41000);
SELECT * from t2 where topic = all (SELECT topic FROM t2 GROUP BY topic HAVING topic < 41000);
SELECT *, topic = all (SELECT topic FROM t2 GROUP BY topic HAVING topic < 41000) from t2;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
236
drop table t1,t2;
237

238 239
#forumconthardwarefr7
CREATE TABLE `t1` (
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
240 241 242 243
  `numeropost` mediumint(8) unsigned NOT NULL auto_increment,
  `maxnumrep` int(10) unsigned NOT NULL default '0',
  PRIMARY KEY  (`numeropost`),
  UNIQUE KEY `maxnumrep` (`maxnumrep`)
244
) ENGINE=MyISAM ROW_FORMAT=FIXED;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
245

246
INSERT INTO t1 (numeropost,maxnumrep) VALUES (1,0),(2,1);
monty@mysql.com's avatar
monty@mysql.com committed
247
-- error 1242
248
select numeropost as a FROM t1 GROUP BY (SELECT 1 FROM t1 HAVING a=1);
monty@mysql.com's avatar
monty@mysql.com committed
249
-- error 1242
250 251
select numeropost as a FROM t1 ORDER BY (SELECT 1 FROM t1 HAVING a=1);
drop table t1;
252

253 254 255 256 257
create table t1 (a int);
insert into t1 values (1),(2),(3);
(select * from t1) union (select * from t1) order by (select a from t1 limit 1);
drop table t1;

258 259 260
#iftest
CREATE TABLE t1 (field char(1) NOT NULL DEFAULT 'b');
INSERT INTO t1 VALUES ();
monty@mysql.com's avatar
monty@mysql.com committed
261
-- error 1242
262
SELECT field FROM t1 WHERE 1=(SELECT 1 UNION ALL SELECT 1 FROM (SELECT 1) a HAVING field='b');
263
drop table t1;
264

265 266
# threadhardwarefr7
CREATE TABLE `t1` (
267 268 269 270 271 272
  `numeropost` mediumint(8) unsigned NOT NULL default '0',
  `numreponse` int(10) unsigned NOT NULL auto_increment,
  `pseudo` varchar(35) NOT NULL default '',
  PRIMARY KEY  (`numeropost`,`numreponse`),
  UNIQUE KEY `numreponse` (`numreponse`),
  KEY `pseudo` (`pseudo`,`numeropost`)
273
) ENGINE=MyISAM;
monty@mysql.com's avatar
monty@mysql.com committed
274
-- error 1247
275
SELECT (SELECT numeropost FROM t1 HAVING numreponse=a),numreponse FROM (SELECT * FROM t1) as a;
276
-- error 1054
277 278 279
SELECT numreponse, (SELECT numeropost FROM t1 HAVING numreponse=a) FROM (SELECT * FROM t1) as a;
SELECT numreponse, (SELECT numeropost FROM t1 HAVING numreponse=1) FROM (SELECT * FROM t1) as a;
INSERT INTO t1 (numeropost,numreponse,pseudo) VALUES (1,1,'joce'),(1,2,'joce'),(1,3,'test');
monty@mysql.com's avatar
monty@mysql.com committed
280
-- error 1242
281 282 283
EXPLAIN EXTENDED SELECT numreponse FROM t1 WHERE numeropost='1' AND numreponse=(SELECT 1 FROM t1 WHERE numeropost='1');
EXPLAIN EXTENDED SELECT MAX(numreponse) FROM t1 WHERE numeropost='1';
EXPLAIN EXTENDED SELECT numreponse FROM t1 WHERE numeropost='1' AND numreponse=(SELECT MAX(numreponse) FROM t1 WHERE numeropost='1');
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
284
drop table t1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
285

286 287
CREATE TABLE t1 (a int(1));
INSERT INTO t1 VALUES (1);
Sinisa@sinisa.nasamreza.org's avatar
Sinisa@sinisa.nasamreza.org committed
288
SELECT 1 FROM (SELECT a FROM t1) b HAVING (SELECT b.a)=1;
bell@sanja.is.com.ua's avatar
Merge  
bell@sanja.is.com.ua committed
289
drop table t1;
290 291 292 293 294 295 296

#update with subselects
create table t1 (a int NOT NULL, b int, primary key (a));
create table t2 (a int NOT NULL, b int, primary key (a));
insert into t1 values (0, 10),(1, 11),(2, 12);
insert into t2 values (1, 21),(2, 22),(3, 23);
select * from t1;
297 298
-- error 1093
update t1 set b= (select b from t1);
monty@mysql.com's avatar
monty@mysql.com committed
299
-- error 1242
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
300
update t1 set b= (select b from t2);
301 302 303 304
update t1 set b= (select b from t2 where t1.a = t2.a);
select * from t1;
drop table t1, t2;

305 306 307 308 309 310 311
#delete with subselects
create table t1 (a int NOT NULL, b int, primary key (a));
create table t2 (a int NOT NULL, b int, primary key (a));
insert into t1 values (0, 10),(1, 11),(2, 12);
insert into t2 values (1, 21),(2, 12),(3, 23);
select * from t1;
select * from t1 where b = (select b from t2 where t1.a = t2.a);
312 313
-- error 1093
delete from t1 where b = (select b from t1);
monty@mysql.com's avatar
monty@mysql.com committed
314
-- error 1242
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
315
delete from t1 where b = (select b from t2);
316 317 318
delete from t1 where b = (select b from t2 where t1.a = t2.a);
select * from t1;
drop table t1, t2;
319

320
#multi-delete with subselects
321

322 323 324 325 326 327 328 329
create table t11 (a int NOT NULL, b int, primary key (a));
create table t12 (a int NOT NULL, b int, primary key (a));
create table t2 (a int NOT NULL, b int, primary key (a));
insert into t11 values (0, 10),(1, 11),(2, 12);
insert into t12 values (33, 10),(22, 11),(2, 12);
insert into t2 values (1, 21),(2, 12),(3, 23);
select * from t11;
select * from t12;
330 331
-- error 1093
delete t11.*, t12.* from t11,t12 where t11.a = t12.a and t11.b = (select b from t12 where t11.a = t12.a);
monty@mysql.com's avatar
monty@mysql.com committed
332
-- error 1242
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
333
delete t11.*, t12.* from t11,t12 where t11.a = t12.a and t11.b = (select b from t2);
334 335 336 337 338
delete t11.*, t12.* from t11,t12 where t11.a = t12.a and t11.b = (select b from t2 where t11.a = t2.a);
select * from t11;
select * from t12;
drop table t11, t12, t2;

339 340 341
#insert with subselects
CREATE TABLE t1 (x int);
create table t2 (a int);
342
create table t3 (b int);
343
insert into t2 values (1);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
344
insert into t3 values (1),(2);
345 346
-- error 1093
INSERT INTO t1 (x) VALUES ((SELECT x FROM t1));
monty@mysql.com's avatar
monty@mysql.com committed
347
-- error 1242
348
INSERT INTO t1 (x) VALUES ((SELECT b FROM t3));
349 350 351 352 353 354 355 356
INSERT INTO t1 (x) VALUES ((SELECT a FROM t2));
select * from t1;
insert into t2 values (1);
INSERT DELAYED INTO t1 (x) VALUES ((SELECT SUM(a) FROM t2));
-- sleep 1
select * from t1;
INSERT INTO t1 (x) select (SELECT SUM(a)+1 FROM t2) FROM t2;
select * from t1;
357
# After this, only data based on old t1 records should have been added.
358
INSERT INTO t1 (x) select (SELECT SUM(x)+2 FROM t1) FROM t2;
359
select * from t1;
360
-- error 1054
361
INSERT DELAYED INTO t1 (x) VALUES ((SELECT SUM(x) FROM t2));
362
INSERT DELAYED INTO t1 (x) VALUES ((SELECT SUM(a) FROM t2));
363 364
-- sleep 1
select * from t1;
365 366 367 368
#
#TODO: should be uncommented after bug 380 fix pushed
#INSERT INTO t1 (x) SELECT (SELECT SUM(a)+b FROM t2) from t3;
#select * from t1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
369
drop table t1, t2, t3;
370 371 372 373

#replace with subselects
CREATE TABLE t1 (x int not null, y int, primary key (x));
create table t2 (a int);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
374
create table t3 (a int);
375
insert into t2 values (1);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
376
insert into t3 values (1),(2);
377
select * from t1;
378 379
-- error 1093
replace into t1 (x, y) VALUES ((SELECT x FROM t1), (SELECT a+1 FROM t2));
monty@mysql.com's avatar
monty@mysql.com committed
380
-- error 1242
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
381
replace into t1 (x, y) VALUES ((SELECT a FROM t3), (SELECT a+1 FROM t2));
382 383 384 385 386 387 388 389 390 391 392 393
replace into t1 (x, y) VALUES ((SELECT a FROM t2), (SELECT a+1 FROM t2));
select * from t1;
replace into t1 (x, y) VALUES ((SELECT a FROM t2), (SELECT a+2 FROM t2));
select * from t1;
replace DELAYED into t1 (x, y) VALUES ((SELECT a+3 FROM t2), (SELECT a FROM t2));
-- sleep 1
select * from t1;
replace DELAYED into t1 (x, y) VALUES ((SELECT a+3 FROM t2), (SELECT a+1 FROM t2));
-- sleep 1
select * from t1;
replace LOW_PRIORITY into t1 (x, y) VALUES ((SELECT a+1 FROM t2), (SELECT a FROM t2));
select * from t1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
394
drop table t1, t2, t3;
395 396

-- error 1096
397
SELECT * FROM (SELECT 1) b WHERE 1 IN (SELECT *);
398

399
CREATE TABLE t2 (id int(11) default NULL, KEY id (id)) ENGINE=MyISAM CHARSET=latin1;
400 401
INSERT INTO t2 VALUES (1),(2);
SELECT * FROM t2 WHERE id IN (SELECT 1);
402
EXPLAIN EXTENDED SELECT * FROM t2 WHERE id IN (SELECT 1);
403 404
SELECT * FROM t2 WHERE id IN (SELECT 1 UNION SELECT 3);
SELECT * FROM t2 WHERE id IN (SELECT 1+(select 1));
405 406
EXPLAIN EXTENDED SELECT * FROM t2 WHERE id IN (SELECT 1+(select 1));
EXPLAIN EXTENDED SELECT * FROM t2 WHERE id IN (SELECT 1 UNION SELECT 3);
407 408
SELECT * FROM t2 WHERE id IN (SELECT 5 UNION SELECT 3);
SELECT * FROM t2 WHERE id IN (SELECT 5 UNION SELECT 2);
409
-- error 1093
410
INSERT INTO t2 VALUES ((SELECT * FROM t2));
monty@mashka.mysql.fi's avatar
monty@mashka.mysql.fi committed
411 412
-- error 1093
INSERT INTO t2 VALUES ((SELECT id FROM t2));
413
SELECT * FROM t2;
414
CREATE TABLE t1 (id int(11) default NULL, KEY id (id)) ENGINE=MyISAM CHARSET=latin1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
415
INSERT INTO t1 values (1),(1);
monty@mysql.com's avatar
monty@mysql.com committed
416
-- error 1242
417 418
UPDATE t2 SET id=(SELECT * FROM t1);
drop table t2, t1;
419 420

#NULL test
421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461
create table t1 (a int);
insert into t1 values (1),(2),(3);
select 1 IN (SELECT * from t1);
select 10 IN (SELECT * from t1);
select NULL IN (SELECT * from t1);
update t1 set a=NULL where a=2;
select 1 IN (SELECT * from t1);
select 3 IN (SELECT * from t1);
select 10 IN (SELECT * from t1);
select 1 > ALL (SELECT * from t1);
select 10 > ALL (SELECT * from t1);
select 1 > ANY (SELECT * from t1);
select 10 > ANY (SELECT * from t1);
drop table t1;
create table t1 (a varchar(20));
insert into t1 values ('A'),('BC'),('DEF');
select 'A' IN (SELECT * from t1);
select 'XYZS' IN (SELECT * from t1);
select NULL IN (SELECT * from t1);
update t1 set a=NULL where a='BC';
select 'A' IN (SELECT * from t1);
select 'DEF' IN (SELECT * from t1);
select 'XYZS' IN (SELECT * from t1);
select 'A' > ALL (SELECT * from t1);
select 'XYZS' > ALL (SELECT * from t1);
select 'A' > ANY (SELECT * from t1);
select 'XYZS' > ANY (SELECT * from t1);
drop table t1;
create table t1 (a float);
insert into t1 values (1.5),(2.5),(3.5);
select 1.5 IN (SELECT * from t1);
select 10.5 IN (SELECT * from t1);
select NULL IN (SELECT * from t1);
update t1 set a=NULL where a=2.5;
select 1.5 IN (SELECT * from t1);
select 3.5 IN (SELECT * from t1);
select 10.5 IN (SELECT * from t1);
select 1.5 > ALL (SELECT * from t1);
select 10.5 > ALL (SELECT * from t1);
select 1.5 > ANY (SELECT * from t1);
select 10.5 > ANY (SELECT * from t1);
462
explain extended select (select a+1) from t1;
463 464 465 466 467 468 469 470 471 472 473 474
select (select a+1) from t1;
drop table t1;

#
# Null with keys
#

CREATE TABLE t1 (a int(11) NOT NULL default '0', PRIMARY KEY  (a));
CREATE TABLE t2 (a int(11) default '0', INDEX (a));
INSERT INTO t1 VALUES (1),(2),(3),(4);
INSERT INTO t2 VALUES (1),(2),(3);
SELECT t1.a, t1.a in (select t2.a from t2) FROM t1;
475
explain extended SELECT t1.a, t1.a in (select t2.a from t2) FROM t1;
476 477 478
CREATE TABLE t3 (a int(11) default '0');
INSERT INTO t3 VALUES (1),(2),(3);
SELECT t1.a, t1.a in (select t2.a from t2,t3 where t3.a=t2.a) FROM t1;
479
explain extended SELECT t1.a, t1.a in (select t2.a from t2,t3 where t3.a=t2.a) FROM t1;
480
drop table t1,t2,t3;
481 482

#LIMIT is not supported now
483
create table t1 (a float);
484
-- error 1235
485
select 10.5 IN (SELECT * from t1 LIMIT 1);
486
-- error 1235
487 488
select 10.5 IN (SELECT * from t1 LIMIT 1 UNION SELECT 1.5);
drop table t1;
489

490 491 492 493 494 495 496 497
create table t1 (a int, b int, c varchar(10));
create table t2 (a int);
insert into t1 values (1,2,'a'),(2,3,'b'),(3,4,'c');
insert into t2 values (1),(2),(NULL);
select a, (select a,b,c from t1 where t1.a=t2.a) = ROW(a,2,'a'),(select c from t1 where a=t2.a)  from t2;
select a, (select a,b,c from t1 where t1.a=t2.a) = ROW(a,3,'b'),(select c from t1 where a=t2.a) from t2;
select a, (select a,b,c from t1 where t1.a=t2.a) = ROW(a,4,'c'),(select c from t1 where a=t2.a) from t2;
drop table t1,t2;
498

499 500 501 502 503 504 505 506 507 508 509
create table t1 (a int, b real, c varchar(10));
insert into t1 values (1, 1, 'a'), (2,2,'b'), (NULL, 2, 'b');
select ROW(1, 1, 'a') IN (select a,b,c from t1);
select ROW(1, 2, 'a') IN (select a,b,c from t1);
select ROW(1, 1, 'a') IN (select b,a,c from t1);
select ROW(1, 1, 'a') IN (select a,b,c from t1 where a is not null);
select ROW(1, 2, 'a') IN (select a,b,c from t1 where a is not null);
select ROW(1, 1, 'a') IN (select b,a,c from t1 where a is not null);
select ROW(1, 1, 'a') IN (select a,b,c from t1 where c='b' or c='a');
select ROW(1, 2, 'a') IN (select a,b,c from t1 where c='b' or c='a');
select ROW(1, 1, 'a') IN (select b,a,c from t1 where c='b' or c='a');
510
-- error 1235
511 512
select ROW(1, 1, 'a') IN (select b,a,c from t1 limit 2);
drop table t1;
513

514 515 516
#
# DO & SET
#
517 518 519
create table t1 (a int);
insert into t1 values (1);
do @a:=(SELECT a from t1);
520
select @a;
521
set @a:=2;
monty@mashka.mysql.fi's avatar
merge  
monty@mashka.mysql.fi committed
522
set @a:=(SELECT a from t1);
523
select @a;
524
drop table t1;
525
-- error 1146
526
do (SELECT a from t1);
527
-- error 1146
monty@mashka.mysql.fi's avatar
merge  
monty@mashka.mysql.fi committed
528
set @a:=(SELECT a from t1);
529 530 531

CREATE TABLE t1 (a int, KEY(a)); 
HANDLER t1 OPEN;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
532
-- error 1064
533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550
HANDLER t1 READ a=((SELECT 1));
HANDLER t1 CLOSE;
drop table t1;

create table t1 (a int);
create table t2 (b int);
insert into t1 values (1),(2);
insert into t2 values (1);
select a from t1 where a in (select a from t1 where a in (select b from t2));
drop table t1, t2;

create table t1 (a int, b int);
create table t2 like t1;
insert into t1 values (1,2),(1,3),(1,4),(1,5);
insert into t2 values (1,2),(1,3);
select * from t1 where row(a,b) in (select a,b from t2);
drop table t1, t2;

551
CREATE TABLE `t1` (`i` int(11) NOT NULL default '0',PRIMARY KEY  (`i`)) ENGINE=MyISAM CHARSET=latin1;
552 553
INSERT INTO t1 VALUES (1);
UPDATE t1 SET i=i+1 WHERE i=(SELECT MAX(i));
554
select * from t1;
555 556 557
drop table t1;

#test of uncacheable subqueries
558
CREATE TABLE t1 (a int(1));
559 560 561
EXPLAIN EXTENDED SELECT (SELECT RAND() FROM t1) FROM t1;
EXPLAIN EXTENDED SELECT (SELECT ENCRYPT('test') FROM t1) FROM t1;
EXPLAIN EXTENDED SELECT (SELECT BENCHMARK(1,1) FROM t1) FROM t1;
562
drop table t1;
563 564 565 566 567 568 569 570 571 572


CREATE TABLE `t1` (
  `mot` varchar(30) character set latin1 NOT NULL default '',
  `topic` mediumint(8) unsigned NOT NULL default '0',
  `date` date NOT NULL default '0000-00-00',
  `pseudo` varchar(35) character set latin1 NOT NULL default '',
  PRIMARY KEY  (`mot`,`pseudo`,`date`,`topic`),
  KEY `pseudo` (`pseudo`,`date`,`topic`),
  KEY `topic` (`topic`)
573
) ENGINE=MyISAM CHARSET=latin1 ROW_FORMAT=DYNAMIC;
574 575 576 577 578 579 580 581 582

CREATE TABLE `t2` (
  `mot` varchar(30) character set latin1 NOT NULL default '',
  `topic` mediumint(8) unsigned NOT NULL default '0',
  `date` date NOT NULL default '0000-00-00',
  `pseudo` varchar(35) character set latin1 NOT NULL default '',
  PRIMARY KEY  (`mot`,`pseudo`,`date`,`topic`),
  KEY `pseudo` (`pseudo`,`date`,`topic`),
  KEY `topic` (`topic`)
583
) ENGINE=MyISAM CHARSET=latin1 ROW_FORMAT=DYNAMIC;
584 585 586 587 588 589

CREATE TABLE `t3` (
  `numeropost` mediumint(8) unsigned NOT NULL auto_increment,
  `maxnumrep` int(10) unsigned NOT NULL default '0',
  PRIMARY KEY  (`numeropost`),
  UNIQUE KEY `maxnumrep` (`maxnumrep`)
590
) ENGINE=MyISAM CHARSET=latin1;
591 592 593 594 595 596 597 598 599 600 601 602 603
INSERT INTO t1 VALUES ('joce','1','','joce'),('test','2','','test');

INSERT INTO t2 VALUES ('joce','1','','joce'),('test','2','','test');

INSERT INTO t3 VALUES (1,1);

SELECT DISTINCT topic FROM t2 WHERE NOT EXISTS(SELECT * FROM t3 WHERE
numeropost=topic);
select * from t1;
DELETE FROM t1 WHERE topic IN (SELECT DISTINCT topic FROM t2 WHERE NOT
EXISTS(SELECT * FROM t3 WHERE numeropost=topic));
select * from t1;

604 605 606 607 608 609 610 611 612 613 614 615 616
drop table t1, t2, t3;

SELECT * FROM (SELECT 1 as a,(SELECT a)) a;
CREATE TABLE t1 SELECT * FROM (SELECT 1 as a,(SELECT 1)) a;
SHOW CREATE TABLE t1;
drop table t1;
CREATE TABLE t1 SELECT * FROM (SELECT 1 as a,(SELECT a)) a;
SHOW CREATE TABLE t1;
drop table t1;
CREATE TABLE t1 SELECT * FROM (SELECT 1 as a,(SELECT a+0)) a;
SHOW CREATE TABLE t1;
drop table t1;
CREATE TABLE t1 SELECT (SELECT 1 as a UNION SELECT 1+1 limit 1,1) as a;
617
select * from t1;
618 619
SHOW CREATE TABLE t1;
drop table t1;
620 621 622

create table t1 (a int);
insert into t1 values (1), (2), (3);
623
explain extended select a,(select (select rand() from t1 limit 1)  from t1 limit 1)
624 625
from t1;
drop table t1;
626 627 628 629 630 631

#
# error in IN
#
-- error 1146
select t1.Continent, t2.Name, t2.Population from t1 LEFT JOIN t2 ON t1.Code = t2.Country  where t2.Population IN (select max(t2.Population) AS Population from t2, t1 where t2.Country = t1.Code group by Continent);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
632 633 634 635 636 637 638 639 640 641 642 643

#
# complex subquery
#

CREATE TABLE t1 (
  ID int(11) NOT NULL auto_increment,
  name char(35) NOT NULL default '',
  t2 char(3) NOT NULL default '',
  District char(20) NOT NULL default '',
  Population int(11) NOT NULL default '0',
  PRIMARY KEY  (ID)
644
) ENGINE=MyISAM;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666

INSERT INTO t1 VALUES (130,'Sydney','AUS','New South Wales',3276207);
INSERT INTO t1 VALUES (131,'Melbourne','AUS','Victoria',2865329);
INSERT INTO t1 VALUES (132,'Brisbane','AUS','Queensland',1291117);

CREATE TABLE t2 (
  Code char(3) NOT NULL default '',
  Name char(52) NOT NULL default '',
  Continent enum('Asia','Europe','North America','Africa','Oceania','Antarctica','South America') NOT NULL default 'Asia',
  Region char(26) NOT NULL default '',
  SurfaceArea float(10,2) NOT NULL default '0.00',
  IndepYear smallint(6) default NULL,
  Population int(11) NOT NULL default '0',
  LifeExpectancy float(3,1) default NULL,
  GNP float(10,2) default NULL,
  GNPOld float(10,2) default NULL,
  LocalName char(45) NOT NULL default '',
  GovernmentForm char(45) NOT NULL default '',
  HeadOfState char(60) default NULL,
  Capital int(11) default NULL,
  Code2 char(2) NOT NULL default '',
  PRIMARY KEY  (Code)
667
) ENGINE=MyISAM;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
668 669

INSERT INTO t2 VALUES ('AUS','Australia','Oceania','Australia and New Zealand',7741220.00,1901,18886000,79.8,351182.00,392911.00,'Australia','Constitutional Monarchy, Federation','Elisabeth II',135,'AU');
670
INSERT INTO t2 VALUES ('AZE','Azerbaijan','Asia','Middle East',86600.00,1991,7734000,62.9,4127.00,4100.00,'Azärbaycan','Federal Republic','Heydär Äliyev',144,'AZ');
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
671 672 673 674

select t2.Continent, t1.Name, t1.Population from t2 LEFT JOIN t1 ON t2.Code = t1.t2  where t1.Population IN (select max(t1.Population) AS Population from t1, t2 where t1.t2 = t2.Code group by Continent); 

drop table t1, t2;
675 676 677 678 679 680 681 682

#
# constants in IN
#
CREATE TABLE `t1` (
  `id` mediumint(8) unsigned NOT NULL auto_increment,
  `pseudo` varchar(35) character set latin1 NOT NULL default '',
  PRIMARY KEY  (`id`),
monty@mysql.com's avatar
monty@mysql.com committed
683
  UNIQUE KEY `pseudo` (`pseudo`)
684
) ENGINE=MyISAM PACK_KEYS=1 ROW_FORMAT=DYNAMIC;
685 686
INSERT INTO t1 (pseudo) VALUES ('test');
SELECT 0 IN (SELECT 1 FROM t1 a);
687
EXPLAIN EXTENDED SELECT 0 IN (SELECT 1 FROM t1 a);
688 689
INSERT INTO t1 (pseudo) VALUES ('test1');
SELECT 0 IN (SELECT 1 FROM t1 a);
690
EXPLAIN EXTENDED SELECT 0 IN (SELECT 1 FROM t1 a);
691
drop table t1;
bell@sanja.is.com.ua's avatar
Merge  
bell@sanja.is.com.ua committed
692

693 694 695
CREATE TABLE `t1` (
  `i` int(11) NOT NULL default '0',
  PRIMARY KEY  (`i`)
696
) ENGINE=MyISAM CHARSET=latin1;
697 698 699 700

INSERT INTO t1 VALUES (1);
UPDATE t1 SET i=i+(SELECT MAX(i) FROM (SELECT 1) t) WHERE i=(SELECT MAX(i));
UPDATE t1 SET i=i+1 WHERE i=(SELECT MAX(i));
701
-- error 1054
702
UPDATE t1 SET t.i=i+(SELECT MAX(i) FROM (SELECT 1) t);
703
select * from t1;
704
drop table t1;
705 706 707 708 709 710

#
# Multi update test
#
CREATE TABLE t1 (
  id int(11) default NULL
711
) ENGINE=MyISAM CHARSET=latin1;
712 713 714 715
INSERT INTO t1 VALUES (1),(1),(2),(2),(1),(3);
CREATE TABLE t2 (
  id int(11) default NULL,
  name varchar(15) default NULL
716
) ENGINE=MyISAM CHARSET=latin1;
717 718 719 720 721

INSERT INTO t2 VALUES (4,'vita'), (1,'vita'), (2,'vita'), (1,'vita');
update t1, t2 set t2.name='lenka' where t2.id in (select id from t1);
select * from t2;
drop table t1,t2;
722 723 724 725 726 727 728 729

#
# correct NULL in <CONSTANT> IN (SELECT ...)
#
create table t1 (a int, unique index indexa (a)); 
insert into t1 values (-1), (-4), (-2), (NULL); 
select -10 IN (select a from t1 FORCE INDEX (indexa)); 
drop table t1;
730 731 732 733 734 735

#
# Test optimization for sub selects
#
create table t1 (id int not null auto_increment primary key, salary int, key(salary));
insert into t1 (salary) values (100),(1000),(10000),(10),(500),(5000),(50000);
736
explain extended SELECT id FROM t1 where salary = (SELECT MAX(salary) FROM t1);
737
drop table t1;
738 739 740 741 742 743 744 745 746 747

CREATE TABLE t1 (
  ID int(10) unsigned NOT NULL auto_increment,
  SUB_ID int(3) unsigned NOT NULL default '0',
  REF_ID int(10) unsigned default NULL,
  REF_SUB int(3) unsigned default '0',
  PRIMARY KEY (ID,SUB_ID),
  UNIQUE KEY t1_PK (ID,SUB_ID),
  KEY t1_FK (REF_ID,REF_SUB),
  KEY t1_REFID (REF_ID)
748
) ENGINE=MyISAM CHARSET=cp1251;
749 750 751
INSERT INTO t1 VALUES (1,0,NULL,NULL),(2,0,NULL,NULL);
SELECT DISTINCT REF_ID FROM t1 WHERE ID= (SELECT DISTINCT REF_ID FROM t1 WHERE ID=2);
DROP TABLE t1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
752

753 754 755 756 757 758 759 760 761 762 763 764 765
#
# uninterruptable update
#
create table t1 (a int, b int);
create table t2 (a int, b int);

insert into t1 values (1,0), (2,0), (3,0);
insert into t2 values (1,1), (2,1), (3,1), (2,2);

update ignore t1 set b=(select b from t2 where t1.a=t2.a);
select * from t1;

drop table t1, t2;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
766

767 768 769 770 771 772 773 774 775 776
#
# reduced subselect in ORDER BY & GROUP BY clauses
#

CREATE TABLE `t1` (
  `id` mediumint(8) unsigned NOT NULL auto_increment,
  `pseudo` varchar(35) NOT NULL default '',
  `email` varchar(60) NOT NULL default '',
  PRIMARY KEY  (`id`),
  UNIQUE KEY `email` (`email`),
monty@mysql.com's avatar
monty@mysql.com committed
777
  UNIQUE KEY `pseudo` (`pseudo`)
778
) ENGINE=MyISAM CHARSET=latin1 PACK_KEYS=1 ROW_FORMAT=DYNAMIC;
779 780 781
INSERT INTO t1 (id,pseudo,email) VALUES (1,'test','test'),(2,'test1','test1');
SELECT pseudo as a, pseudo as b FROM t1 GROUP BY (SELECT a) ORDER BY (SELECT id*1);
drop table if exists t1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
782 783

(SELECT 1 as a) UNION (SELECT 1) ORDER BY (SELECT a+0);
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
784

785 786 787 788 789 790 791 792 793 794
#
# IN subselect optimization test
#
create table t1 (a int not null, b int, primary key (a));
create table t2 (a int not null, primary key (a));
create table t3 (a int not null, b int, primary key (a));
insert into t1 values (1,10), (2,20), (3,30),  (4,40);
insert into t2 values (2), (3), (4), (5);
insert into t3 values (10,3), (20,4), (30,5);
select * from t2 where t2.a in (select a from t1);
795
explain extended select * from t2 where t2.a in (select a from t1);
796
select * from t2 where t2.a in (select a from t1 where t1.b <> 30);
797
explain extended select * from t2 where t2.a in (select a from t1 where t1.b <> 30);
798
select * from t2 where t2.a in (select t1.a from t1,t3 where t1.b=t3.a);
799
explain extended select * from t2 where t2.a in (select t1.a from t1,t3 where t1.b=t3.a);
800
drop table t1, t2, t3;
801
create table t1 (a int, b int, index a (a,b));
802 803 804 805 806 807 808 809 810 811 812 813 814 815 816
create table t2 (a int, index a (a));
create table t3 (a int, b int, index a (a));
insert into t1 values (1,10), (2,20), (3,30), (4,40);
disable_query_log;
# making table large enough
let $1 = 10000;
while ($1)
 {
  eval insert into t1 values (rand()*100000+200,rand()*100000); 
  dec $1;
 }
enable_query_log;
insert into t2 values (2), (3), (4), (5);
insert into t3 values (10,3), (20,4), (30,5);
select * from t2 where t2.a in (select a from t1);
817
explain extended select * from t2 where t2.a in (select a from t1);
818
select * from t2 where t2.a in (select a from t1 where t1.b <> 30);
819
explain extended select * from t2 where t2.a in (select a from t1 where t1.b <> 30);
820
select * from t2 where t2.a in (select t1.a from t1,t3 where t1.b=t3.a);
821
explain extended select * from t2 where t2.a in (select t1.a from t1,t3 where t1.b=t3.a);
822 823 824
insert into t1 values (3,31);
select * from t2 where t2.a in (select a from t1 where t1.b <> 30);
select * from t2 where t2.a in (select a from t1 where t1.b <> 30 and t1.b <> 31);
825
explain extended select * from t2 where t2.a in (select a from t1 where t1.b <> 30);
826
drop table t1, t2, t3;
827

828 829 830 831 832 833 834 835 836 837
#
# alloc_group_fields() working
#
create table t1 (a int, b int);
create table t2 (a int, b int);
create table t3 (a int, b int);
insert into t1 values (0,100),(1,2), (1,3), (2,2), (2,7), (2,-1), (3,10);
insert into t2 values (0,0), (1,1), (2,1), (3,1), (4,1);
insert into t3 values (3,3), (2,2), (1,1); 
select a,(select count(distinct t1.b) as sum from t1,t2 where t1.a=t2.a and t2.b > 0 and t1.a <= t3.b group by t1.a order by sum limit 1) from t3;
838 839
drop table t1,t2,t3;

840 841 842 843 844 845 846 847 848
#
# aggregate functions in HAVING test
#
create table t1 (s1 int);
create table t2 (s1 int);
insert into t1 values (1);
insert into t2 values (1);
select * from t1 where exists (select s1 from t2 having max(t2.s1)=t1.s1);
drop table t1,t2;
849

850 851 852 853 854 855 856 857
#
# update subquery with wrong field (to force name resolving
# in UPDATE name space)
#
create table t1 (s1 int);
create table t2 (s1 int);
insert into t1 values (1);
insert into t2 values (1);
858
-- error 1054
859 860 861
update t1 set  s1 = s1 + 1 where 1 = (select x.s1 as A from t2 WHERE t2.s1 > t1.s1 order by A);
DROP TABLE t1, t2;

862 863 864 865 866 867
#
# collation test
#
CREATE TABLE t1 (s1 CHAR(5) COLLATE latin1_german1_ci,
                 s2 CHAR(5) COLLATE latin1_swedish_ci);
INSERT INTO t1 VALUES ('z','?');
monty@mysql.com's avatar
monty@mysql.com committed
868
-- error 1267
869
select * from t1 where s1 > (select max(s2) from t1);
monty@mysql.com's avatar
monty@mysql.com committed
870
-- error 1267
871 872
select * from t1 where s1 > any (select max(s2) from t1);
drop table t1;
873 874 875 876 877 878 879 880 881 882

#
# aggregate functions reinitialization
#
create table t1(toid int,rd int);
create table t2(userid int,pmnew int,pmtotal int);
insert into t2 values(1,0,0),(2,0,0);
insert into t1 values(1,0),(1,0),(1,0),(1,12),(1,15),(1,123),(1,12312),(1,12312),(1,123),(2,0),(2,0),(2,1),(2,2);
select userid,pmtotal,pmnew, (select count(rd) from t1 where toid=t2.userid) calc_total, (select count(rd) from t1 where rd=0 and toid=t2.userid) calc_new from t2 where userid in (select distinct toid from t1);
drop table t1, t2;
883 884 885 886 887

#
# row union
#
create table t1 (s1 char(5));
monty@mysql.com's avatar
monty@mysql.com committed
888
-- error 1241
889 890 891
select (select 'a','b' from t1 union select 'a','b' from t1) from t1;
insert into t1 values ('tttt');
select * from t1 where ('a','b')=(select 'a','b' from t1 union select 'a','b' from t1);
892
explain extended (select * from t1);
893
(select * from t1);
894
drop table t1;
895 896 897 898

#
# IN optimisation test results
#
899
create table t1 (s1 char(5), index s1(s1));
900 901 902 903
create table t2 (s1 char(5), index s1(s1));
insert into t1 values ('a1'),('a2'),('a3');
insert into t2 values ('a1'),('a2');
select s1, s1 NOT IN (SELECT s1 FROM t2) from t1;
904 905
select s1, s1 = ANY (SELECT s1 FROM t2) from t1;
select s1, s1 <> ALL (SELECT s1 FROM t2) from t1;
906
select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1;
907
explain extended select s1, s1 NOT IN (SELECT s1 FROM t2) from t1;
bell@sanja.is.com.ua's avatar
merge  
bell@sanja.is.com.ua committed
908 909
explain extended select s1, s1 = ANY (SELECT s1 FROM t2) from t1;
explain extended select s1, s1 <> ALL (SELECT s1 FROM t2) from t1;
910
explain extended select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1;
911
drop table t1,t2;
912

913 914 915 916 917 918 919
#
# correct ALL optimisation
#
create table t2 (a int, b int);
create table t3 (a int);
insert into t3 values (6),(7),(3);
select * from t3 where a >= all (select b from t2);
920
explain extended select * from t3 where a >= all (select b from t2);
921 922 923 924 925 926 927 928 929 930 931 932 933 934
select * from t3 where a >= some (select b from t2);
explain extended select * from t3 where a >= some (select b from t2);
select * from t3 where a >= all (select b from t2 group by 1);
explain extended select * from t3 where a >= all (select b from t2 group by 1);
select * from t3 where a >= some (select b from t2 group by 1);
explain extended select * from t3 where a >= some (select b from t2 group by 1);
select * from t3 where NULL >= any (select b from t2);
explain extended select * from t3 where NULL >= any (select b from t2);
select * from t3 where NULL >= any (select b from t2 group by 1);
explain extended select * from t3 where NULL >= any (select b from t2 group by 1);
select * from t3 where NULL >= some (select b from t2);
explain extended select * from t3 where NULL >= some (select b from t2);
select * from t3 where NULL >= some (select b from t2 group by 1);
explain extended select * from t3 where NULL >= some (select b from t2 group by 1);
935
#
936
# optimized static ALL/ANY with grouping
937
#
938 939
insert into t2 values (2,2), (2,1), (3,3), (3,1);
select * from t3 where a > all (select max(b) from t2 group by a);
940
explain extended select * from t3 where a > all (select max(b) from t2 group by a);
941
drop table t2, t3;
942

943 944 945 946
#
# correct used_tables()
#

947
CREATE TABLE `t1` ( `id` mediumint(9) NOT NULL auto_increment, `taskid` bigint(20) NOT NULL default '0', `dbid` int(11) NOT NULL default '0', `create_date` datetime NOT NULL default '0000-00-00 00:00:00', `last_update` datetime NOT NULL default '0000-00-00 00:00:00', PRIMARY KEY  (`id`)) ENGINE=MyISAM CHARSET=latin1 AUTO_INCREMENT=3 ;
948
INSERT INTO `t1` (`id`, `taskid`, `dbid`, `create_date`,`last_update`) VALUES (1, 1, 15, '2003-09-29 10:31:36', '2003-09-29 10:31:36'), (2, 1, 21, now(), now());
949
CREATE TABLE `t2` (`db_id` int(11) NOT NULL auto_increment,`name` varchar(200) NOT NULL default '',`primary_uid` smallint(6) NOT NULL default '0',`secondary_uid` smallint(6) NOT NULL default '0',PRIMARY KEY  (`db_id`),UNIQUE KEY `name_2` (`name`),FULLTEXT KEY `name` (`name`)) ENGINE=MyISAM CHARSET=latin1 AUTO_INCREMENT=2147483647;
950
INSERT INTO `t2` (`db_id`, `name`, `primary_uid`, `secondary_uid`) VALUES (18, 'Not Set 1', 0, 0),(19, 'Valid', 1, 2),(20, 'Valid 2', 1, 2),(21, 'Should Not Return', 1, 2),(26, 'Not Set 2', 0, 0),(-1, 'ALL DB\'S', 0, 0);
951
CREATE TABLE `t3` (`taskgenid` mediumint(9) NOT NULL auto_increment,`dbid` int(11) NOT NULL default '0',`taskid` int(11) NOT NULL default '0',`mon` tinyint(4) NOT NULL default '1',`tues` tinyint(4) NOT NULL default '1',`wed` tinyint(4) NOT NULL default '1',`thur` tinyint(4) NOT NULL default '1',`fri` tinyint(4) NOT NULL default '1',`sat` tinyint(4) NOT NULL default '0',`sun` tinyint(4) NOT NULL default '0',`how_often` smallint(6) NOT NULL default '1',`userid` smallint(6) NOT NULL default '0',`active` tinyint(4) NOT NULL default '1',PRIMARY KEY  (`taskgenid`)) ENGINE=MyISAM CHARSET=latin1 AUTO_INCREMENT=2 ;
952
INSERT INTO `t3` (`taskgenid`, `dbid`, `taskid`, `mon`, `tues`,`wed`, `thur`, `fri`, `sat`, `sun`, `how_often`, `userid`, `active`) VALUES (1,-1, 1, 1, 1, 1, 1, 1, 0, 0, 1, 0, 1);
953
CREATE TABLE `t4` (`task_id` smallint(6) NOT NULL default '0',`description` varchar(200) NOT NULL default '') ENGINE=MyISAM CHARSET=latin1;
954 955 956 957
INSERT INTO `t4` (`task_id`, `description`) VALUES (1, 'Daily Check List'),(2, 'Weekly Status');
select  dbid, name, (date_format(now() , '%Y-%m-%d') - INTERVAL how_often DAY) >= ifnull((SELECT date_format(max(create_date),'%Y-%m-%d') FROM t1 WHERE dbid = b.db_id AND taskid = a.taskgenid), '1950-01-01') from t3 a, t2 b, t4  WHERE dbid = - 1 AND primary_uid = '1' AND t4.task_id = taskid;
SELECT dbid, name FROM t3 a, t2 b, t4 WHERE dbid = - 1 AND primary_uid = '1' AND ((date_format(now() , '%Y-%m-%d') - INTERVAL how_often DAY) >= ifnull((SELECT date_format(max(create_date),'%Y-%m-%d') FROM t1 WHERE dbid = b.db_id AND taskid = a.taskgenid), '1950-01-01')) AND t4.task_id = taskid;
drop table t1,t2,t3,t4;
bell@sanja.is.com.ua's avatar
Merge  
bell@sanja.is.com.ua committed
958

959 960 961
#
# cardinality check
#
962
CREATE TABLE t1 (id int(11) default NULL) ENGINE=MyISAM CHARSET=latin1;
963
INSERT INTO t1 VALUES (1),(5);
964
CREATE TABLE t2 (id int(11) default NULL) ENGINE=MyISAM CHARSET=latin1;
965
INSERT INTO t2 VALUES (2),(6);
monty@mysql.com's avatar
monty@mysql.com committed
966
-- error 1241
967 968
select * from t1 where (1,2,6) in (select * from t2);
DROP TABLE t1,t2;
bell@sanja.is.com.ua's avatar
Merge  
bell@sanja.is.com.ua committed
969

970 971 972 973 974 975
#
# DO and SET with errors
#
create table t1 (s1 int);
insert into t1 values (1);
insert into t1 values (2);
monty@mysql.com's avatar
monty@mysql.com committed
976
-- error 1242
977 978 979
set sort_buffer_size = (select s1 from t1);
do (select * from t1);
drop table t1;
980 981 982 983 984 985 986 987

#
# optimized ALL/ANY with union
#
create table t1 (s1 char);
insert into t1 values ('e');
select * from t1 where 'f' > any (select s1 from t1);
select * from t1 where 'f' > any (select s1 from t1 union select s1 from t1);
988
explain extended select * from t1 where 'f' > any (select s1 from t1 union select s1 from t1);
989
drop table t1;
990 991 992 993

#
# filesort in subquery (restoring join_tab)
#
994
CREATE TABLE t1 (number char(11) NOT NULL default '') ENGINE=MyISAM CHARSET=latin1;
995
INSERT INTO t1 VALUES ('69294728265'),('18621828126'),('89356874041'),('95895001874');
996
CREATE TABLE t2 (code char(5) NOT NULL default '',UNIQUE KEY code (code)) ENGINE=MyISAM CHARSET=latin1;
997 998 999
INSERT INTO t2 VALUES ('1'),('1226'),('1245'),('1862'),('18623'),('1874'),('1967'),('6');
select c.number as phone,(select p.code from t2 p where c.number like concat(p.code, '%') order by length(p.code) desc limit 1) as code from t1 c;
drop table t1, t2;
1000 1001 1002 1003 1004 1005 1006 1007 1008 1009

#
# unresolved field error
#
create table t1 (s1 int); 
create table t2 (s1 int);
-- error 1054
select * from t1 where (select count(*) from t2 where t1.s2) = 1;
-- error 1054
select * from t1 where (select count(*) from t2 group by t1.s2) = 1;
1010
-- error 1054
1011
select count(*) from t2 group by t1.s2;
bell@sanja.is.com.ua's avatar
merge  
bell@sanja.is.com.ua committed
1012
drop table t1, t2;
bell@sanja.is.com.ua's avatar
merge  
bell@sanja.is.com.ua committed
1013

bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1014 1015 1016 1017 1018 1019 1020 1021
#
# fix_fields() in add_ref_to_table_cond()
#
CREATE TABLE t1(COLA FLOAT NOT NULL,COLB FLOAT NOT NULL,COLC VARCHAR(20) DEFAULT NULL,PRIMARY KEY (COLA, COLB));
CREATE TABLE t2(COLA FLOAT NOT NULL,COLB FLOAT NOT NULL,COLC CHAR(1) NOT NULL,PRIMARY KEY (COLA));
INSERT INTO t1 VALUES (1,1,'1A3240'), (1,2,'4W2365');
INSERT INTO t2 VALUES (100, 200, 'C');
SELECT DISTINCT COLC FROM t1 WHERE COLA = (SELECT COLA FROM t2 WHERE COLB = 200 AND COLC ='C' LIMIT 1);
1022
DROP TABLE t1, t2;
1023

hf@deer.(none)'s avatar
hf@deer.(none) committed
1024 1025 1026 1027
CREATE TABLE t1 (a int(1));
INSERT INTO t1 VALUES (1),(1),(1),(1),(1),(2),(3),(4),(5);
SELECT DISTINCT (SELECT a) FROM t1 LIMIT 100;
DROP TABLE t1;
hf@deer.(none)'s avatar
hf@deer.(none) committed
1028

1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039
#
# Bug 2198
#

create table t1 (a int, b decimal(13, 3)); 
insert into t1 values (1, 0.123);
select a, (select max(b) from t1) into outfile "subselect.out.file.1" from t1;
delete from t1;
load data infile "subselect.out.file.1" into table t1;
select * from t1;
drop table t1;
1040 1041 1042 1043 1044

#
# Bug 2479
#

1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055
CREATE TABLE `t1` (
  `id` int(11) NOT NULL auto_increment,
  `id_cns` tinyint(3) unsigned NOT NULL default '0',
  `tipo` enum('','UNO','DUE') NOT NULL default '',
  `anno_dep` smallint(4) unsigned zerofill NOT NULL default '0000',
  `particolare` mediumint(8) unsigned NOT NULL default '0',
  `generale` mediumint(8) unsigned NOT NULL default '0',
  `bis` tinyint(3) unsigned NOT NULL default '0',
  PRIMARY KEY  (`id`),
  UNIQUE KEY `idx_cns_gen_anno` (`anno_dep`,`id_cns`,`generale`,`particolare`),
  UNIQUE KEY `idx_cns_par_anno` (`id_cns`,`anno_dep`,`tipo`,`particolare`,`bis`)
1056
);
1057 1058 1059 1060 1061 1062 1063
INSERT INTO `t1` VALUES (1,16,'UNO',1987,2048,9681,0),(2,50,'UNO',1987,1536,13987,0),(3,16,'UNO',1987,2432,14594,0),(4,16,'UNO',1987,1792,13422,0),(5,16,'UNO',1987,1025,10240,0),(6,16,'UNO',1987,1026,7089,0);
CREATE TABLE `t2` (
  `id` tinyint(3) unsigned NOT NULL auto_increment,
  `max_anno_dep` smallint(6) unsigned NOT NULL default '0',
  PRIMARY KEY  (`id`)
);
INSERT INTO `t2` VALUES (16,1987),(50,1990),(51,1990);
1064

1065
SELECT cns.id, cns.max_anno_dep, cns.max_anno_dep = (SELECT s.anno_dep FROM t1 AS s WHERE s.id_cns = cns.id ORDER BY s.anno_dep DESC LIMIT 1) AS PIPPO FROM t2 AS cns;
1066

serg@serg.mylan's avatar
serg@serg.mylan committed
1067
DROP TABLE t1, t2;
1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078

#
# GLOBAL LIMIT
#
create table t1 (a int);
insert into t1 values (1), (2), (3);
SET SQL_SELECT_LIMIT=1;
select sum(a) from (select * from t1) as a;
select 2 in (select * from t1);
SET SQL_SELECT_LIMIT=default;
drop table t1;
hf@deer.(none)'s avatar
hf@deer.(none) committed
1079

1080
#
1081 1082 1083 1084 1085 1086 1087
# Bug #3118: subselect + order by
#

CREATE TABLE t1 (a int, b int, INDEX (a));
INSERT INTO t1 VALUES (1, 1), (1, 2), (1, 3);
SELECT * FROM t1 WHERE a = (SELECT MAX(a) FROM t1 WHERE a = 1) ORDER BY b;
DROP TABLE t1;
ram@gw.mysql.r18.ru's avatar
merge  
ram@gw.mysql.r18.ru committed
1088

1089 1090 1091 1092 1093
# Item_cond fix field
#
create table t1(val varchar(10));
insert into t1 values ('aaa'), ('bbb'),('eee'),('mmm'),('ppp');
select count(*) from t1 as w1 where w1.val in (select w2.val from t1 as w2 where w2.val like 'm%') and w1.val in (select w3.val from t1 as w3 where w3.val like 'e%');
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1094 1095
drop table t1;

1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110
#
# ref_or_null replacing with ref
#
create table t1 (id int not null, text varchar(20) not null default '', primary key (id));
insert into t1 (id, text) values (1, 'text1'), (2, 'text2'), (3, 'text3'), (4, 'text4'), (5, 'text5'), (6, 'text6'), (7, 'text7'), (8, 'text8'), (9, 'text9'), (10, 'text10'), (11, 'text11'), (12, 'text12');
select * from t1 where id not in (select id from t1 where id < 8);
select * from t1 as tt where not exists (select id from t1 where id < 8 and (id = tt.id or id is null) having id is not null);
explain extended select * from t1 where id not in (select id from t1 where id < 8);
explain extended select * from t1 as tt where not exists (select id from t1 where id < 8 and (id = tt.id or id is null) having id is not null);
insert into t1 (id, text) values (1000, 'text1000'), (1001, 'text1001');
create table t2 (id int not null, text varchar(20) not null default '', primary key (id));
insert into t2 (id, text) values (1, 'text1'), (2, 'text2'), (3, 'text3'), (4, 'text4'), (5, 'text5'), (6, 'text6'), (7, 'text7'), (8, 'text8'), (9, 'text9'), (10, 'text10'), (11, 'text1'), (12, 'text2'), (13, 'text3'), (14, 'text4'), (15, 'text5'), (16, 'text6'), (17, 'text7'), (18, 'text8'), (19, 'text9'), (20, 'text10'),(21, 'text1'), (22, 'text2'), (23, 'text3'), (24, 'text4'), (25, 'text5'), (26, 'text6'), (27, 'text7'), (28, 'text8'), (29, 'text9'), (30, 'text10'), (31, 'text1'), (32, 'text2'), (33, 'text3'), (34, 'text4'), (35, 'text5'), (36, 'text6'), (37, 'text7'), (38, 'text8'), (39, 'text9'), (40, 'text10'), (41, 'text1'), (42, 'text2'), (43, 'text3'), (44, 'text4'), (45, 'text5'), (46, 'text6'), (47, 'text7'), (48, 'text8'), (49, 'text9'), (50, 'text10');
select * from t1 a left join t2 b on (a.id=b.id or b.id is null) join t1 c on (if(isnull(b.id), 1000, b.id)=c.id);
explain extended select * from t1 a left join t2 b on (a.id=b.id or b.id is null) join t1 c on (if(isnull(b.id), 1000, b.id)=c.id);
drop table t1,t2;
bell@sanja.is.com.ua's avatar
merge  
bell@sanja.is.com.ua committed
1111

1112 1113 1114 1115 1116 1117 1118
#
# Static tables & rund() in subqueries
#
create table t1 (a int);
insert into t1 values (1);
explain select benchmark(1000, (select a from t1 where a=sha(rand())));
drop table t1;
hf@deer.(none)'s avatar
hf@deer.(none) committed
1119 1120 1121 1122 1123 1124 1125 1126 1127

#
# bug 3188
#
create table t1(id int);
create table t2(id int);
create table t3(flag int);
-- error 1064
select (select * from t3 where id not null) from t1, t2;
1128
drop table t1,t2,t3;
1129 1130 1131 1132 1133 1134 1135 1136

#
# aggregate functions (Bug #3505)
#
CREATE TABLE t1 (id INT);
CREATE TABLE t2 (id INT);
INSERT INTO t1 VALUES (1), (2);
INSERT INTO t2 VALUES (1);
1137
SELECT t1.id, ( SELECT COUNT(t.id) FROM t2 AS t WHERE t.id = t1.id ) AS c FROM t1 LEFT JOIN t2 USING (id);
1138
SELECT id, ( SELECT COUNT(t.id) FROM t2 AS t WHERE t.id = t1.id ) AS c FROM t1 LEFT JOIN t2 USING (id);
1139
SELECT t1.id, ( SELECT COUNT(t.id) FROM t2 AS t WHERE t.id = t1.id ) AS c FROM t1 LEFT JOIN t2 USING (id) ORDER BY t1.id;
1140
SELECT id, ( SELECT COUNT(t.id) FROM t2 AS t WHERE t.id = t1.id ) AS c FROM t1 LEFT JOIN t2 USING (id) ORDER BY id;
1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159
DROP TABLE t1,t2;

#
# ALL/ANY test
#
CREATE TABLE t1 ( a int, b int );
INSERT INTO t1 VALUES (1,1),(2,2),(3,3);
SELECT a FROM t1 WHERE a > ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a < ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a = ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a >= ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a <= ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a <> ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a > ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a < ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a = ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a >= ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a <= ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a <> ALL ( SELECT a FROM t1 WHERE b = 2 );
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1160
# with index
1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173
ALTER TABLE t1 ADD INDEX (a);
SELECT a FROM t1 WHERE a > ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a < ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a = ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a >= ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a <= ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a <> ANY ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a > ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a < ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a = ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a >= ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a <= ALL ( SELECT a FROM t1 WHERE b = 2 );
SELECT a FROM t1 WHERE a <> ALL ( SELECT a FROM t1 WHERE b = 2 );
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279
# having clause test
SELECT a FROM t1 WHERE a > ANY (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a < ANY (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a = ANY (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a >= ANY (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a <= ANY (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a <> ANY (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a > ALL (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a < ALL (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a = ALL (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a >= ALL (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a <= ALL (SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a <> ALL (SELECT a FROM t1 HAVING a = 2);
# union test
SELECT a FROM t1 WHERE a > ANY (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a < ANY (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a = ANY (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a >= ANY (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a <= ANY (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a <> ANY (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a > ALL (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a < ALL (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a = ALL (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a >= ALL (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a <= ALL (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE a <> ALL (SELECT a FROM t1 WHERE b = 2 UNION SELECT a FROM t1 WHERE b = 2);
# union + having test
SELECT a FROM t1 WHERE a > ANY (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a < ANY (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a = ANY (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a >= ANY (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a <= ANY (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a <> ANY (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a > ALL (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a < ALL (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a = ALL (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a >= ALL (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a <= ALL (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE a <> ALL (SELECT a FROM t1 HAVING a = 2 UNION SELECT a FROM t1 HAVING a = 2);
# row tests
# < > >= <= and = ALL/ <> ANY do not support row operation
-- error 1241
SELECT a FROM t1 WHERE (1,2) > ANY (SELECT a FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE a > ANY (SELECT a,2 FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE (1,2) > ANY (SELECT a,2 FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE (1,2) > ALL (SELECT a FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE a > ALL (SELECT a,2 FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE (1,2) > ALL (SELECT a,2 FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE (1,2) = ALL (SELECT a,2 FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE (1,2) <> ANY (SELECT a,2 FROM t1 WHERE b = 2);
# following should be converted to IN
-- error 1241
SELECT a FROM t1 WHERE (1,2) = ANY (SELECT a FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE a = ANY (SELECT a,2 FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE (1,2) = ANY (SELECT a,2 FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE (1,2) <> ALL (SELECT a FROM t1 WHERE b = 2);
-- error 1241
SELECT a FROM t1 WHERE a <> ALL (SELECT a,2 FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE (1,2) <> ALL (SELECT a,2 FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE (a,1) = ANY (SELECT a,1 FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE (a,1) <> ALL (SELECT a,1 FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE (a,1) = ANY (SELECT a,1 FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE (a,1) <> ALL (SELECT a,1 FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE (a,1) = ANY (SELECT a,1 FROM t1 WHERE b = 2 UNION SELECT a,1 FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE (a,1) <> ALL (SELECT a,1 FROM t1 WHERE b = 2 UNION SELECT a,1 FROM t1 WHERE b = 2);
SELECT a FROM t1 WHERE (a,1) = ANY (SELECT a,1 FROM t1 HAVING a = 2 UNION SELECT a,1 FROM t1 HAVING a = 2);
SELECT a FROM t1 WHERE (a,1) <> ALL (SELECT a,1 FROM t1 HAVING a = 2 UNION SELECT a,1 FROM t1 HAVING a = 2);
# without optimisation
SELECT a FROM t1 WHERE a > ANY (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a < ANY (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a = ANY (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a >= ANY (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a <= ANY (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a <> ANY (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a > ALL (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a < ALL (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a = ALL (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a >= ALL (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a <= ALL (SELECT a FROM t1 WHERE b = 2 group by a);
SELECT a FROM t1 WHERE a <> ALL (SELECT a FROM t1 WHERE b = 2 group by a);
# without optimisation + having
SELECT a FROM t1 WHERE a > ANY (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a < ANY (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a = ANY (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a >= ANY (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a <= ANY (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a <> ANY (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a > ALL (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a < ALL (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a = ALL (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a >= ALL (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a <= ALL (SELECT a FROM t1 group by a HAVING a = 2);
SELECT a FROM t1 WHERE a <> ALL (SELECT a FROM t1 group by a HAVING a = 2);
# EXISTS in string contence
SELECT concat(EXISTS(SELECT a FROM t1 WHERE b = 2 and a.a > t1.a), '-') from t1 a;
SELECT concat(EXISTS(SELECT a FROM t1 WHERE b = 2 and a.a < t1.a), '-') from t1 a;
SELECT concat(EXISTS(SELECT a FROM t1 WHERE b = 2 and a.a = t1.a), '-') from t1 a;
1280
DROP TABLE t1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309
CREATE TABLE t1 ( a double, b double );
INSERT INTO t1 VALUES (1,1),(2,2),(3,3);
SELECT a FROM t1 WHERE a > ANY (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a < ANY (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a = ANY (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a >= ANY (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a <= ANY (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a <> ANY (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a > ALL (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a < ALL (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a = ALL (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a >= ALL (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a <= ALL (SELECT a FROM t1 WHERE b = 2e0);
SELECT a FROM t1 WHERE a <> ALL (SELECT a FROM t1 WHERE b = 2e0);
DROP TABLE t1;
CREATE TABLE t1 ( a char(1), b char(1));
INSERT INTO t1 VALUES ('1','1'),('2','2'),('3','3');
SELECT a FROM t1 WHERE a > ANY (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a < ANY (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a = ANY (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a >= ANY (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a <= ANY (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a <> ANY (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a > ALL (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a < ALL (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a = ALL (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a >= ALL (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a <= ALL (SELECT a FROM t1 WHERE b = '2');
SELECT a FROM t1 WHERE a <> ALL (SELECT a FROM t1 WHERE b = '2');
1310
DROP TABLE t1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1311 1312 1313 1314 1315 1316 1317 1318 1319 1320


#
# SELECT(EXISTS * ...)optimisation
#
create table t1 (a int, b int);
insert into t1 values (1,2),(3,4);
select * from t1 up where exists (select * from t1 where t1.a=up.a);
explain extended select * from t1 up where exists (select * from t1 where t1.a=up.a);
drop table t1;
1321

1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332
#
# Bug #4102: subselect in HAVING
#

CREATE TABLE t1 (t1_a int);
INSERT INTO t1 VALUES (1);
CREATE TABLE t2 (t2_a int, t2_b int, PRIMARY KEY (t2_a, t2_b));
INSERT INTO t2 VALUES (1, 1), (1, 2);
SELECT * FROM t1, t2 table2 WHERE t1_a = 1 AND table2.t2_a = 1
  HAVING table2.t2_b = (SELECT MAX(t2_b) FROM t2 WHERE t2_a = table2.t2_a);
DROP TABLE t1, t2;
ram@gw.mysql.r18.ru's avatar
ram@gw.mysql.r18.ru committed
1333

1334 1335 1336 1337 1338 1339 1340 1341 1342 1343
#
# Test problem with NULL and derived tables (Bug #4097)
#

CREATE TABLE t1 (id int(11) default NULL,name varchar(10) default NULL);
INSERT INTO t1 VALUES (1,'Tim'),(2,'Rebecca'),(3,NULL);
CREATE TABLE t2 (id int(11) default NULL, pet varchar(10) default NULL);
INSERT INTO t2 VALUES (1,'Fido'),(2,'Spot'),(3,'Felix');
SELECT a.*, b.* FROM (SELECT * FROM t1) AS a JOIN t2 as b on a.id=b.id;
drop table t1,t2;
bell@sanja.is.com.ua's avatar
Merge  
bell@sanja.is.com.ua committed
1344

1345 1346 1347 1348 1349 1350
#
# outer fields resolving in INSERT/REPLACE and CRETE with SELECT
#
CREATE TABLE t1 ( a int, b int );
CREATE TABLE t2 ( c int, d int );
INSERT INTO t1 VALUES (1,2), (2,3), (3,4);
1351 1352 1353 1354
SELECT a AS abc, b FROM t1 outr WHERE b = 
  (SELECT MIN(b) FROM t1 WHERE a=outr.a);
INSERT INTO t2 SELECT a AS abc, b FROM t1 outr WHERE b = 
  (SELECT MIN(b) FROM t1 WHERE a=outr.a);
1355
select * from t2;
1356 1357
CREATE TABLE t3 SELECT a AS abc, b FROM t1 outr WHERE b = 
  (SELECT MIN(b) FROM t1 WHERE a=outr.a);
1358
select * from t3;
1359
prepare stmt1 from "INSERT INTO t2 SELECT a AS abc, b FROM t1 outr WHERE b = (SELECT MIN(b) FROM t1 WHERE a=outr.a);";
1360 1361 1362 1363
execute stmt1;
deallocate prepare stmt1;
select * from t2;
drop table t3;
1364
prepare stmt1 from "CREATE TABLE t3 SELECT a AS abc, b FROM t1 outr WHERE b = (SELECT MIN(b) FROM t1 WHERE a=outr.a);";
1365 1366 1367
execute stmt1;
select * from t3;
deallocate prepare stmt1;
1368
DROP TABLE t1, t2, t3;
1369 1370 1371 1372 1373 1374 1375 1376 1377 1378

#
# Aggregate function comparation with ALL/ANY/SOME subselect
#
CREATE TABLE `t1` ( `a` int(11) default NULL) ENGINE=MyISAM DEFAULT CHARSET=latin1;
insert into t1 values (1);
CREATE TABLE `t2` ( `b` int(11) default NULL, `a` int(11) default NULL) ENGINE=MyISAM DEFAULT CHARSET=latin1;
insert into t2 values (1,2);
select t000.a, count(*) `C` FROM t1 t000 GROUP BY t000.a HAVING count(*) > ALL (SELECT count(*) FROM t2 t001 WHERE t001.a=1);
drop table t1,t2;
1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390

#
# BUG#4769 - fulltext in subselect
#
create table t1 (a int not null auto_increment primary key, b varchar(40), fulltext(b)); 
insert into t1 (b) values ('ball'),('ball games'), ('games'), ('foo'), ('foobar'), ('Serg'), ('Sergei'),('Georg'), ('Patrik'),('Hakan'); 
create table t2 (a int); 
insert into t2 values (1),(3),(2),(7); 
select a,b from t1 where match(b) against ('Ball') > 0; 
select a from t2 where a in (select a from t1 where match(b) against ('Ball') > 0); 
drop table t1,t2;

1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402
#
# BUG#5003 - like in subselect
#
CREATE TABLE t1(`IZAVORGANG_ID` VARCHAR(11) CHARACTER SET latin1 COLLATE latin1_bin,`KUERZEL` VARCHAR(10) CHARACTER SET latin1 COLLATE latin1_bin,`IZAANALYSEART_ID` VARCHAR(11) CHARACTER SET latin1 COLLATE latin1_bin,`IZAPMKZ_ID` VARCHAR(11) CHARACTER SET latin1 COLLATE latin1_bin);
CREATE INDEX AK01IZAVORGANG ON t1(izaAnalyseart_id,Kuerzel);
INSERT INTO t1(`IZAVORGANG_ID`,`KUERZEL`,`IZAANALYSEART_ID`,`IZAPMKZ_ID`)VALUES('D0000000001','601','D0000000001','I0000000001');
INSERT INTO t1(`IZAVORGANG_ID`,`KUERZEL`,`IZAANALYSEART_ID`,`IZAPMKZ_ID`)VALUES('D0000000002','602','D0000000001','I0000000001');
INSERT INTO t1(`IZAVORGANG_ID`,`KUERZEL`,`IZAANALYSEART_ID`,`IZAPMKZ_ID`)VALUES('D0000000003','603','D0000000001','I0000000001');
INSERT INTO t1(`IZAVORGANG_ID`,`KUERZEL`,`IZAANALYSEART_ID`,`IZAPMKZ_ID`)VALUES('D0000000004','101','D0000000001','I0000000001');
SELECT `IZAVORGANG_ID` FROM t1 WHERE `KUERZEL` IN(SELECT MIN(`KUERZEL`)`Feld1` FROM t1 WHERE `KUERZEL` LIKE'601%'And`IZAANALYSEART_ID`='D0000000001');
drop table t1;

1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417
#
# Optimized IN with compound index
#
CREATE TABLE `t1` ( `aid` int(11) NOT NULL default '0', `bid` int(11) NOT NULL default '0', PRIMARY KEY  (`aid`,`bid`));
CREATE TABLE `t2` ( `aid` int(11) NOT NULL default '0', `bid` int(11) NOT NULL default '0', PRIMARY KEY  (`aid`,`bid`));
insert into t1 values (1,1),(1,2),(2,1),(2,2);
insert into t2 values (1,2),(2,2);
select * from t1 where t1.aid not in (select aid from t2 where bid=t1.bid);
alter table t2 drop primary key;
alter table t2 add key KEY1 (aid, bid);
select * from t1 where t1.aid not in (select aid from t2 where bid=t1.bid);
alter table t2 drop key KEY1;
alter table t2 add primary key (bid, aid);
select * from t1 where t1.aid not in (select aid from t2 where bid=t1.bid);
drop table t1,t2;
1418

1419 1420 1421 1422 1423 1424 1425 1426 1427
#
# resolving fields of grouped outer SELECT
#
CREATE TABLE t1 (howmanyvalues bigint, avalue int);
INSERT INTO t1 VALUES (1, 1),(2, 1),(2, 2),(3, 1),(3, 2),(3, 3),(4, 1),(4, 2),(4, 3),(4, 4);
SELECT howmanyvalues, count(*) from t1 group by howmanyvalues;
SELECT a.howmanyvalues, (SELECT count(*) from t1 b where b.howmanyvalues = a.howmanyvalues) as mycount from t1 a group by a.howmanyvalues;
CREATE INDEX t1_howmanyvalues_idx ON t1 (howmanyvalues);
SELECT a.howmanyvalues, (SELECT count(*) from t1 b where b.howmanyvalues+1 = a.howmanyvalues+1) as mycount from t1 a group by a.howmanyvalues;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1428 1429
SELECT a.howmanyvalues, (SELECT count(*) from t1 b where b.howmanyvalues = a.howmanyvalues) as mycount from t1 a group by a.howmanyvalues;
SELECT a.howmanyvalues, (SELECT count(*) from t1 b where b.howmanyvalues = a.avalue) as mycount from t1 a group by a.howmanyvalues;
1430
drop table t1;
1431 1432 1433 1434

create table t1 (x int);
select  (select b.x from t1 as b where b.x=a.x) from t1 as a where a.x=2 group by a.x;
drop table t1;
1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447

#
# Test of correct maybe_null flag returning by subquwery for temporary table
# creation
#
CREATE TABLE `t1` ( `master` int(10) unsigned NOT NULL default '0', `map` smallint(6) unsigned NOT NULL default '0', `slave` int(10) unsigned NOT NULL default '0', `access` int(10) unsigned NOT NULL default '0', UNIQUE KEY `access_u` (`master`,`map`,`slave`));
INSERT INTO `t1` VALUES (1,0,0,700),(1,1,1,400),(1,5,5,400),(1,12,12,400),(1,12,32,400),(4,12,32,400);
CREATE TABLE `t2` ( `id` int(10) unsigned NOT NULL default '0', `pid` int(10) unsigned NOT NULL default '0', `map` smallint(6) unsigned NOT NULL default '0', `level` tinyint(4) unsigned NOT NULL default '0', `title` varchar(255) default NULL, PRIMARY KEY  (`id`,`pid`,`map`), KEY `level` (`level`), KEY `id` (`id`,`map`)) ;
INSERT INTO `t2` VALUES (6,5,12,7,'a'),(12,0,0,7,'a'),(12,1,0,7,'a'),(12,5,5,7,'a'),(12,5,12,7,'a');
-- error 1054
SELECT b.sc FROM (SELECT (SELECT a.access FROM t1 a WHERE a.map = op.map AND a.slave = op.pid AND a.master = 1) ac FROM t2 op WHERE op.id = 12 AND op.map = 0) b;
SELECT b.ac FROM (SELECT (SELECT a.access FROM t1 a WHERE a.map = op.map AND a.slave = op.pid AND a.master = 1) ac FROM t2 op WHERE op.id = 12 AND op.map = 0) b;
drop tables t1,t2;
1448 1449 1450 1451 1452 1453 1454 1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466

#
# Test for bug #6462. "Same request on same data returns different
# results." a.k.a. "Proper cleanup of subqueries is missing for 
# SET and DO statements".
#
create table t1 (a int not null, b int not null, c int, primary key (a,b));
insert into t1 values (1,1,1), (2,2,2), (3,3,3);
set @b:= 0;
# Let us check that subquery will use covering index
explain select sum(a) from t1 where b > @b;
# This should not crash -debug server due to failing assertion
set @a:= (select sum(a) from t1 where b > @b);
# And this should not falsely report index usage
explain select a from t1 where c=2;
# Same for DO statement
do @a:= (select sum(a) from t1 where b > @b);
explain select a from t1 where c=2;
drop table t1;
bell@sanja.is.com.ua's avatar
Merge  
bell@sanja.is.com.ua committed
1467

1468 1469 1470 1471 1472 1473
#
# Subselect in non-select command just after connection
#
connect (root,localhost,root,,test,$MASTER_MYPORT,$MASTER_MYSOCK);
connection root;
set @got_val= (SELECT 1 FROM (SELECT 'A' as my_col) as T1 ) ;
1474 1475 1476 1477 1478 1479 1480 1481 1482 1483

#
# primary query with temporary table and subquery with groupping
#
create table t1 (a int, b int);
create table t2 (a int, b int);
insert into t1 values (1,1),(1,2),(1,3),(2,4),(2,5);
insert into t2 values (1,3),(2,1);
select distinct a,b, (select max(b) from t2 where t1.b=t2.a) from t1 order by t1.b;
drop table t1, t2;
1484 1485 1486 1487 1488 1489 1490 1491 1492 1493

#
# subqueries with full text search
#
create table t1 (id int);
create table t2 (id int, body text, fulltext (body));
insert into t1 values(1),(2),(3);
insert into t2 values (1,'test'), (2,'mysql'), (3,'test'), (4,'test');
select count(distinct id) from t1 where id in (select id from t2 where match(body) against ('mysql' in boolean mode));
drop table t2,t1;
bell@sanja.is.com.ua's avatar
merge  
bell@sanja.is.com.ua committed
1494

1495 1496 1497 1498 1499 1500 1501
#
# Equal operation under row and empty subquery
#
create table t1 (s1 int,s2 int);
insert into t1 values (20,15);
select * from t1 where  (('a',null) <=> (select 'a',s2 from t1 where s1 = 0));
drop table t1;
bell@sanja.is.com.ua's avatar
merge  
bell@sanja.is.com.ua committed
1502

1503 1504 1505 1506 1507 1508 1509 1510
#
# ALL/ANY with NULL
#
create table t1 (s1 int);
insert into t1 values (1),(null);
select * from t1 where s1 < all (select s1 from t1);
select s1, s1 < all (select s1 from t1) from t1;
drop table t1;
1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530

#
# reference on changable fields from subquery
#
CREATE TABLE t1 (
  Code char(3) NOT NULL default '',
  Name char(52) NOT NULL default '',
  Continent enum('Asia','Europe','North America','Africa','Oceania','Antarctica','South America') NOT NULL default 'Asia',
  Region char(26) NOT NULL default '',
  SurfaceArea float(10,2) NOT NULL default '0.00',
  IndepYear smallint(6) default NULL,
  Population int(11) NOT NULL default '0',
  LifeExpectancy float(3,1) default NULL,
  GNP float(10,2) default NULL,
  GNPOld float(10,2) default NULL,
  LocalName char(45) NOT NULL default '',
  GovernmentForm char(45) NOT NULL default '',
  HeadOfState char(60) default NULL,
  Capital int(11) default NULL,
  Code2 char(2) NOT NULL default ''
ram@gw.mysql.r18.ru's avatar
ram@gw.mysql.r18.ru committed
1531
) ENGINE=MyISAM;
1532 1533
INSERT INTO t1 VALUES ('XXX','Xxxxx','Oceania','Xxxxxx',26.00,0,0,0,0,0,'Xxxxx','Xxxxx','Xxxxx',NULL,'XX');
INSERT INTO t1 VALUES ('ASM','American Samoa','Oceania','Polynesia',199.00,0,68000,75.1,334.00,NULL,'Amerika Samoa','US Territory','George W. Bush',54,'AS');
1534
INSERT INTO t1 VALUES ('ATF','French Southern territories','Antarctica','Antarctica',7780.00,0,0,NULL,0.00,NULL,'Terres australes françaises','Nonmetropolitan Territory of France','Jacques Chirac',NULL,'TF');
1535 1536
INSERT INTO t1 VALUES ('UMI','United States Minor Outlying Islands','Oceania','Micronesia/Caribbean',16.00,0,0,NULL,0.00,NULL,'United States Minor Outlying Islands','Dependent Territory of the US','George W. Bush',NULL,'UM');
/*!40000 ALTER TABLE t1 ENABLE KEYS */;
1537 1538 1539
SELECT DISTINCT Continent AS c FROM t1 outr WHERE 
  Code <> SOME ( SELECT Code FROM t1 WHERE Continent = outr.Continent AND 
  Population < 200);
1540
drop table t1;
1541

1542
#
sergefp@mysql.com's avatar
sergefp@mysql.com committed
1543 1544
# Test for BUG#7885: Server crash when 'any' subselect compared to
# non-existant field.
1545
#
sergefp@mysql.com's avatar
sergefp@mysql.com committed
1546 1547 1548 1549 1550 1551 1552
create table t1 (a1 int);
create table t2 (b1 int);
--error 1054
select * from t1 where a2 > any(select b1 from t2);
select * from t1 where a1 > any(select b1 from t2);
drop table t1,t2;

1553 1554 1555 1556 1557 1558 1559 1560 1561 1562 1563

#
# Comparison subquery with * and row
#
create table t1 (a integer, b integer);
select (select * from t1) = (select 1,2);
select (select 1,2) = (select * from t1);
# queries whih can be converted to IN
select  row(1,2) = ANY (select * from t1);
select  row(1,2) != ALL (select * from t1);
drop table t1;
1564 1565 1566 1567 1568 1569 1570 1571 1572 1573 1574 1575

#
# Comparison subquery and row with nested rows
#
create table t1 (a integer, b integer);
-- error 1241
select row(1,(2,2)) in (select * from t1 );
-- error 1241
select row(1,(2,2)) = (select * from t1 );
-- error 1241
select (select * from t1) = row(1,(2,2));
drop table t1;
1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591

#
# Forward reference detection
#
create  table t1 (a integer);
insert into t1 values (1);
-- error 1247
select 1 = ALL (select 1 from t1 where 1 = xx ), 1 as xx ;
-- error 1247
select 1 = ALL (select 1 from t1 where 1 = xx ), 1 as xx;
select 1 as xx, 1 = ALL (  select 1 from t1 where 1 = xx );
-- error 1247
select 1 = ALL (select 1 from t1 where 1 = xx ), 1 as xx;
-- error 1247
select 1 = ALL (select 1 from t1 where 1 = xx ), 1 as xx from DUAL;
drop table t1;
sergefp@mysql.com's avatar
sergefp@mysql.com committed
1592

1593
#
sergefp@mysql.com's avatar
sergefp@mysql.com committed
1594
# Test for BUG#8218
1595
#
sergefp@mysql.com's avatar
sergefp@mysql.com committed
1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 1619 1620 1621 1622 1623 1624 1625 1626 1627 1628 1629 1630 1631 1632 1633 1634 1635 1636 1637 1638 1639 1640 1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 1651 1652 1653 1654 1655 1656 1657 1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668 1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 1690 1691
CREATE TABLE t1 (
  categoryId int(11) NOT NULL,
  courseId int(11) NOT NULL,
  startDate datetime NOT NULL,
  endDate datetime NOT NULL,
  createDate datetime NOT NULL,
  modifyDate timestamp NOT NULL,
  attributes text NOT NULL
);
INSERT INTO t1 VALUES (1,41,'2004-02-09','2010-01-01','2004-02-09','2004-02-09',''),
(1,86,'2004-08-16','2004-08-16','2004-08-16','2004-08-16',''),
(1,87,'2004-08-16','2004-08-16','2004-08-16','2004-08-16',''),
(2,52,'2004-03-15','2004-10-01','2004-03-15','2004-09-17',''),
(2,53,'2004-03-16','2004-10-01','2004-03-16','2004-09-17',''),
(2,88,'2004-08-16','2004-08-16','2004-08-16','2004-08-16',''),
(2,89,'2004-08-16','2004-08-16','2004-08-16','2004-08-16',''),
(3,51,'2004-02-09','2010-01-01','2004-02-09','2004-02-09',''),
(5,12,'2004-02-18','2010-01-01','2004-02-18','2004-02-18','');

CREATE TABLE t2 (
  userId int(11) NOT NULL,
  courseId int(11) NOT NULL,
  date datetime NOT NULL
);
INSERT INTO t2 VALUES (5141,71,'2003-11-18'),
(5141,72,'2003-11-25'),(5141,41,'2004-08-06'),
(5141,52,'2004-08-06'),(5141,53,'2004-08-06'),
(5141,12,'2004-08-06'),(5141,86,'2004-10-21'),
(5141,87,'2004-10-21'),(5141,88,'2004-10-21'),
(5141,89,'2004-10-22'),(5141,51,'2004-10-26');


CREATE TABLE t3 (
  groupId int(11) NOT NULL,
  parentId int(11) NOT NULL,
  startDate datetime NOT NULL,
  endDate datetime NOT NULL,
  createDate datetime NOT NULL,
  modifyDate timestamp NOT NULL,
  ordering int(11)
);
INSERT INTO t3 VALUES (12,9,'1000-01-01','3999-12-31','2004-01-29','2004-01-29',NULL);

CREATE TABLE t4 (
  id int(11) NOT NULL,
  groupTypeId int(11) NOT NULL,
  groupKey varchar(50) NOT NULL,
  name text,
  ordering int(11),
  description text,
  createDate datetime NOT NULL,
  modifyDate timestamp NOT NULL
);
INSERT INTO t4 VALUES (9,5,'stationer','stationer',0,'Stationer','2004-01-29','2004-01-29'),
(12,5,'group2','group2',0,'group2','2004-01-29','2004-01-29');

CREATE TABLE t5 (
  userId int(11) NOT NULL,
  groupId int(11) NOT NULL,
  createDate datetime NOT NULL,
  modifyDate timestamp NOT NULL
);
INSERT INTO t5 VALUES (5141,12,'2004-08-06','2004-08-06');

select
  count(distinct t2.userid) pass,
  groupstuff.*,
  count(t2.courseid) crse,
  t1.categoryid, 
  t2.courseid,
  date_format(date, '%b%y') as colhead
from t2   
join t1 on t2.courseid=t1.courseid  
join
(
  select 
    t5.userid,  
    parentid,  
    parentgroup,  
    childid,  
    groupname,  
    grouptypeid  
  from t5 
  join 
  (
     select t4.id as parentid,  
       t4.name as parentgroup,  
       t4.id as childid,  
       t4.name as groupname,  
       t4.grouptypeid  
     from   t4  
  ) as gin on t5.groupid=gin.childid 
) as groupstuff on t2.userid = groupstuff.userid 
group by 
  groupstuff.groupname, colhead , t2.courseid;

1692
drop table t1, t2, t3, t4, t5;
sergefp@mysql.com's avatar
sergefp@mysql.com committed
1693

1694 1695 1696 1697 1698 1699 1700
#
# Transformation in left expression of subquery (BUG#8888)
#
create table t1 (a int);
insert into t1 values (1), (2), (3);
SELECT 1 FROM t1 WHERE (SELECT 1) in (SELECT 1);
drop table t1;
1701

bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1702 1703 1704 1705 1706 1707 1708 1709 1710 1711 1712 1713 1714 1715 1716 1717 1718 1719 1720 1721 1722 1723 1724 1725 1726 1727 1728 1729 1730 1731 1732 1733 1734 1735 1736 1737
#
# subselect into HAVING clause (code covarage improvement)
#
create table t1 (a int);
create table t2 (a int);
insert into t1 values (1),(2);
insert into t2 values (0),(1),(2),(3);
select a from t2 where a in (select a from t1);
select a from t2 having a in (select a from t1);
prepare stmt1 from "select a from t2 where a in (select a from t1)";
execute stmt1;
execute stmt1;
deallocate prepare stmt1;
prepare stmt1 from "select a from t2 having a in (select a from t1)";
execute stmt1;
execute stmt1;
deallocate prepare stmt1;
drop table t1, t2;

#
# single row subqueries and row operations (code covarage improvement)
#
create table t1 (a int, b int);
insert into t1 values (1,2);
-- error 1241
select 1 = (select * from t1);
-- error 1241
select (select * from t1) = 1;
-- error 1241
select (1,2) = (select a from t1);
-- error 1241
select (select a from t1) = (1,2);
-- error 1241
select (1,2,3) = (select * from t1);
-- error 1241
select (select * from t1) = (1,2,3);
1738
drop table t1;
1739 1740 1741 1742 1743 1744 1745 1746 1747 1748 1749 1750 1751 1752 1753 1754 1755 1756 1757 1758 1759 1760 1761 1762

#
# Item_int_with_ref check (BUG#10020)
#
CREATE TABLE `t1` (
  `itemid` bigint(20) unsigned NOT NULL auto_increment,
  `sessionid` bigint(20) unsigned default NULL,
  `time` int(10) unsigned NOT NULL default '0',
  `type` set('A','D','E','F','G','I','L','N','U') collate latin1_general_ci NOT
NULL default '',
  `data` text collate latin1_general_ci NOT NULL,
  PRIMARY KEY  (`itemid`)
) DEFAULT CHARSET=latin1 COLLATE=latin1_general_ci;
INSERT INTO `t1` VALUES (1, 1, 1, 'D', '');
CREATE TABLE `t2` (
  `sessionid` bigint(20) unsigned NOT NULL auto_increment,
  `pid` int(10) unsigned NOT NULL default '0',
  `date` int(10) unsigned NOT NULL default '0',
  `ip` varchar(15) collate latin1_general_ci NOT NULL default '',
  PRIMARY KEY  (`sessionid`)
) DEFAULT CHARSET=latin1 COLLATE=latin1_general_ci;
INSERT INTO `t2` VALUES (1, 1, 1, '10.10.10.1');
SELECT s.ip, count( e.itemid ) FROM `t1` e JOIN t2 s ON s.sessionid = e.sessionid WHERE e.sessionid = ( SELECT sessionid FROM t2 ORDER BY sessionid DESC LIMIT 1 ) GROUP BY s.ip HAVING count( e.itemid ) >0 LIMIT 0 , 30;
drop tables t1,t2;
1763 1764 1765 1766 1767 1768

# BUG#11821 : Select from subselect using aggregate function on an enum
# segfaults:
create table t1 (fld enum('0','1'));
insert into t1 values ('1');
select * from (select max(fld) from t1) as foo;
1769
drop table t1;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
1770

igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
1771 1772 1773 1774 1775 1776 1777 1778 1779 1780 1781 1782 1783 1784
#
# Bug #11867: queries with ROW(,elems>) IN (SELECT DISTINCT <cols> FROM ...)
#

CREATE TABLE t1 (one int, two int, flag char(1));
CREATE TABLE t2 (one int, two int, flag char(1));
INSERT INTO t1 VALUES(1,2,'Y'),(2,3,'Y'),(3,4,'Y'),(5,6,'N'),(7,8,'N');
INSERT INTO t2 VALUES(1,2,'Y'),(2,3,'Y'),(3,4,'Y'),(5,6,'N'),(7,8,'N');

SELECT * FROM t1
  WHERE ROW(one,two) IN (SELECT DISTINCT one,two FROM t2 WHERE flag = 'N');
SELECT * FROM t1
  WHERE ROW(one,two) IN (SELECT DISTINCT one,two FROM t1 WHERE flag = 'N');

monty@mysql.com's avatar
monty@mysql.com committed
1785
insert into t2 values (null,null,'N');
1786 1787 1788 1789 1790 1791
insert into t2 values (null,3,'0');
insert into t2 values (null,5,'0');
insert into t2 values (10,null,'0');
insert into t1 values (10,3,'0');
insert into t1 values (10,5,'0');
insert into t1 values (10,10,'0');
monty@mysql.com's avatar
monty@mysql.com committed
1792
SELECT one,two,ROW(one,two) IN (SELECT one,two FROM t2 WHERE flag = 'N') as 'test' from t1;
1793
SELECT one,two from t1 where ROW(one,two) IN (SELECT one,two FROM t2 WHERE flag = 'N');
monty@mysql.com's avatar
monty@mysql.com committed
1794
SELECT one,two,ROW(one,two) IN (SELECT one,two FROM t2 WHERE flag = 'N' group by one,two) as 'test' from t1;
1795 1796 1797 1798 1799
SELECT one,two,ROW(one,two) IN (SELECT one,two FROM t2 WHERE flag = '0') as 'test' from t1;
SELECT one,two,ROW(one,two) IN (SELECT one,two FROM t2 WHERE flag = '0' group by one,two) as 'test' from t1;
explain extended SELECT one,two,ROW(one,two) IN (SELECT one,two FROM t2 WHERE flag = '0') as 'test' from t1;
explain extended SELECT one,two from t1 where ROW(one,two) IN (SELECT one,two FROM t2 WHERE flag = 'N');
explain extended SELECT one,two,ROW(one,two) IN (SELECT one,two FROM t2 WHERE flag = '0' group by one,two) as 'test' from t1;
igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
1800
DROP TABLE t1,t2;
1801

1802 1803 1804 1805 1806 1807 1808 1809 1810 1811 1812
#
# Bug #12392: where cond with IN predicate for rows and NULL values in table 
#

CREATE TABLE t1 (a char(5), b char(5));
INSERT INTO t1 VALUES (NULL,'aaa'), ('aaa','aaa');

SELECT * FROM t1 WHERE (a,b) IN (('aaa','aaa'), ('aaa','bbb'));

DROP TABLE t1;

igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
1813 1814 1815 1816 1817 1818 1819 1820 1821 1822 1823 1824 1825 1826 1827 1828
#
# Bug #11479: subquery over left join with an empty inner table 
#

CREATE TABLE t1 (a int);
CREATE TABLE t2 (a int, b int);
CREATE TABLE t3 (b int NOT NULL);
INSERT INTO t1 VALUES (1), (2), (3), (4);
INSERT INTO t2 VALUES (1,10), (3,30);

SELECT * FROM t2 LEFT JOIN t3 ON t2.b=t3.b
  WHERE t3.b IS NOT NULL OR t2.a > 10;
SELECT * FROM t1
  WHERE t1.a NOT IN (SELECT a FROM t2 LEFT JOIN t3 ON t2.b=t3.b
                       WHERE t3.b IS NOT NULL OR t2.a > 10);

igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
1829 1830
DROP TABLE t1,t2,t3;

1831 1832 1833 1834 1835 1836 1837 1838 1839 1840 1841 1842 1843
#
# Bug#18503: Queries with a quantified subquery returning empty set may
# return a wrong result. 
#
CREATE TABLE t1 (f1 INT);
CREATE TABLE t2 (f2 INT);
INSERT INTO t1 VALUES (1);
SELECT * FROM t1 WHERE f1 > ALL (SELECT f2 FROM t2);
SELECT * FROM t1 WHERE f1 > ALL (SELECT f2 FROM t2 WHERE 1=0);
INSERT INTO t2 VALUES (1);
INSERT INTO t2 VALUES (2);
SELECT * FROM t1 WHERE f1 > ALL (SELECT f2 FROM t2 WHERE f2=0);
DROP TABLE t1, t2;
1844

1845 1846 1847 1848 1849 1850 1851 1852 1853
#
# Bug#16302: Quantified subquery without any tables gives wrong results
#
select 1 from dual where 1 < any (select 2);
select 1 from dual where 1 < all (select 2);
select 1 from dual where 2 > any (select 1);
select 1 from dual where 2 > all (select 1);
select 1 from dual where 1 < any (select 2 from dual);
select 1 from dual where 1 < all (select 2 from dual where 1!=1);
1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869

# BUG#20975 Wrong query results for subqueries within NOT
create table t1 (s1 char);
insert into t1 values (1),(2);

select * from t1 where (s1 < any (select s1 from t1));
select * from t1 where not (s1 < any (select s1 from t1));

select * from t1 where (s1 < ALL (select s1+1 from t1));
select * from t1 where not(s1 < ALL (select s1+1 from t1));

select * from t1 where (s1+1 = ANY (select s1 from t1));
select * from t1 where NOT(s1+1 = ANY (select s1 from t1));

select * from t1 where (s1 = ALL (select s1/s1 from t1));
select * from t1 where NOT(s1 = ALL (select s1/s1 from t1));
1870
drop table t1;
1871 1872 1873 1874

#
# Bug #16255: Subquery in where
#
1875 1876 1877 1878 1879 1880
create table t1 (
  retailerID varchar(8) NOT NULL,
  statusID   int(10) unsigned NOT NULL,
  changed    datetime NOT NULL,
  UNIQUE KEY retailerID (retailerID, statusID, changed)
);
1881

1882 1883 1884 1885 1886 1887 1888 1889 1890 1891 1892 1893
INSERT INTO t1 VALUES("0026", "1", "2005-12-06 12:18:56");
INSERT INTO t1 VALUES("0026", "2", "2006-01-06 12:25:53");
INSERT INTO t1 VALUES("0037", "1", "2005-12-06 12:18:56");
INSERT INTO t1 VALUES("0037", "2", "2006-01-06 12:25:53");
INSERT INTO t1 VALUES("0048", "1", "2006-01-06 12:37:50");
INSERT INTO t1 VALUES("0059", "1", "2006-01-06 12:37:50");

select * from t1 r1 
  where (r1.retailerID,(r1.changed)) in 
         (SELECT r2.retailerId,(max(changed)) from t1 r2 
          group by r2.retailerId);
drop table t1;
1894

1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905 1906 1907 1908 1909 1910 1911 1912 1913 1914 1915 1916 1917 1918 1919
#
# Bug #21180: Subselect with index for both WHERE and ORDER BY 
#             produces empty result
#
create table t1(a int, primary key (a));
insert into t1 values (10);

create table t2 (a int primary key, b varchar(32), c int, unique key b(c, b));
insert into t2(a, c, b) values (1,10,'359'), (2,10,'35988'), (3,10,'35989');

explain SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r 
  ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' 
             ORDER BY t2.c DESC, t2.b DESC LIMIT 1) WHERE t1.a = 10;
SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r 
  ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' 
            ORDER BY t2.c DESC, t2.b DESC LIMIT 1) WHERE t1.a = 10;

explain SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r 
  ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' 
            ORDER BY t2.c, t2.b LIMIT 1) WHERE t1.a = 10;
SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r 
  ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' 
            ORDER BY t2.c, t2.b LIMIT 1) WHERE t1.a = 10;

drop table t1,t2;
1920

1921 1922 1923 1924 1925 1926 1927 1928 1929 1930 1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955 1956 1957
#
# Bug #21853: assert failure for a grouping query with
#             an ALL/ANY quantified subquery in HAVING 
#

CREATE TABLE t1 (                  
  field1 int NOT NULL,                 
  field2 int NOT NULL,                 
  field3 int NOT NULL,                 
  PRIMARY KEY  (field1,field2,field3)  
);
CREATE TABLE t2 (             
  fieldA int NOT NULL,            
  fieldB int NOT NULL,            
  PRIMARY KEY  (fieldA,fieldB)     
); 

INSERT INTO t1 VALUES
  (1,1,1), (1,1,2), (1,2,1), (1,2,2), (1,2,3), (1,3,1);
INSERT INTO t2 VALUES (1,1), (1,2), (1,3);

SELECT field1, field2, COUNT(*)
  FROM t1 GROUP BY field1, field2;

SELECT field1, field2
  FROM  t1
    GROUP BY field1, field2
      HAVING COUNT(*) >= ALL (SELECT fieldB 
                                FROM t2 WHERE fieldA = field1);
SELECT field1, field2
  FROM  t1
    GROUP BY field1, field2
      HAVING COUNT(*) < ANY (SELECT fieldB 
                               FROM t2 WHERE fieldA = field1);

DROP TABLE t1, t2;

igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
1958 1959 1960 1961 1962 1963 1964 1965 1966 1967 1968 1969 1970 1971 1972 1973 1974
#
# Bug #23478: not top-level IN subquery returning a non-empty result set
#             with possible NULL values by index access from the outer query
#

CREATE TABLE t1(a int, INDEX (a));
INSERT INTO t1 VALUES (1), (3), (5), (7);
INSERT INTO t1 VALUES (NULL);

CREATE TABLE t2(a int);
INSERT INTO t2 VALUES (1),(2),(3);

EXPLAIN SELECT a, a IN (SELECT a FROM t1) FROM t2;
SELECT a, a IN (SELECT a FROM t1) FROM t2;

DROP TABLE t1,t2;

1975 1976 1977 1978 1979 1980 1981 1982 1983 1984 1985 1986 1987 1988 1989 1990
#
# Bug #11302: getObject() returns a String for a sub-query of type datetime
#
CREATE TABLE t1 (a DATETIME);
INSERT INTO t1 VALUES ('1998-09-23'), ('2003-03-25');

CREATE TABLE t2 AS SELECT 
  (SELECT a FROM t1 WHERE a < '2000-01-01') AS sub_a 
   FROM t1 WHERE a > '2000-01-01';
SHOW CREATE TABLE t2;

CREATE TABLE t3 AS (SELECT a FROM t1 WHERE a < '2000-01-01') UNION (SELECT a FROM t1 WHERE a > '2000-01-01'); 
SHOW CREATE TABLE t3;

DROP TABLE t1,t2,t3;

1991 1992 1993 1994 1995 1996 1997 1998 1999 2000 2001 2002
#
# Bug 24670: subquery witout tables but with a WHERE clause
#

CREATE TABLE t1 (a int);
INSERT INTO t1 VALUES (1), (2);

SELECT a FROM t1 WHERE (SELECT 1 FROM DUAL WHERE 1=0) > 0;
SELECT a FROM t1 WHERE (SELECT 1 FROM DUAL WHERE 1=0) IS NULL;
EXPLAIN SELECT a FROM t1 WHERE (SELECT 1 FROM DUAL WHERE 1=0) IS NULL;

DROP TABLE t1;
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2003 2004

#
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2005
# Bug 24653: sorting by expressions containing subselects
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2006 2007 2008 2009 2010 2011 2012 2013 2014 2015 2016
#            that return more than one row
#

CREATE TABLE t1 (a int);
INSERT INTO t1 VALUES (2), (4), (1), (3);

CREATE TABLE t2 (b int, c int);
INSERT INTO t2 VALUES
  (2,1), (1,3), (2,1), (4,4), (2,2), (1,4);

SELECT a FROM t1 ORDER BY (SELECT c FROM t2 WHERE b > 2 );
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2017 2018 2019 2020
--error 1242
SELECT a FROM t1 ORDER BY (SELECT c FROM t2 WHERE b > 1);
SELECT a FROM t1 ORDER BY (SELECT c FROM t2 WHERE b > 2), a;
--error 1242
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2021
SELECT a FROM t1 ORDER BY (SELECT c FROM t2 WHERE b > 1), a;
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2022

igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2023 2024 2025 2026 2027 2028 2029 2030 2031 2032 2033 2034 2035 2036 2037 2038
SELECT b, MAX(c) FROM t2 GROUP BY b, (SELECT c FROM t2 WHERE b > 2);
--error 1242
SELECT b, MAX(c) FROM t2 GROUP BY b, (SELECT c FROM t2 WHERE b > 1);


SELECT a FROM t1 GROUP BY a
  HAVING IFNULL((SELECT b FROM t2 WHERE b > 2),
                (SELECT c FROM t2 WHERE c=a AND b > 2 ORDER BY b)) > 3;
--error 1242
SELECT a FROM t1 GROUP BY a
  HAVING IFNULL((SELECT b FROM t2 WHERE b > 1),
                (SELECT c FROM t2 WHERE c=a AND b > 2 ORDER BY b)) > 3;

SELECT a FROM t1 GROUP BY a
  HAVING IFNULL((SELECT b FROM t2 WHERE b > 4),
                (SELECT c FROM t2 WHERE c=a AND b > 2 ORDER BY b)) > 3;
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2039
--error 1242
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2040 2041 2042 2043
SELECT a FROM t1 GROUP BY a
  HAVING IFNULL((SELECT b FROM t2 WHERE b > 4),
                (SELECT c FROM t2 WHERE c=a AND b > 1 ORDER BY b)) > 3;

malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2044
SELECT a FROM t1
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2045 2046 2047
  ORDER BY IFNULL((SELECT b FROM t2 WHERE b > 2),
                  (SELECT c FROM t2 WHERE c=a AND b > 2 ORDER BY b));
--error 1242
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2048
SELECT a FROM t1
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2049 2050 2051
  ORDER BY IFNULL((SELECT b FROM t2 WHERE b > 1),
                  (SELECT c FROM t2 WHERE c=a AND b > 1 ORDER BY b));

malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2052
SELECT a FROM t1
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2053 2054 2055
  ORDER BY IFNULL((SELECT b FROM t2 WHERE b > 4),
                  (SELECT c FROM t2 WHERE c=a AND b > 2 ORDER BY b));
--error 1242
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2056
SELECT a FROM t1
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2057 2058 2059
  ORDER BY IFNULL((SELECT b FROM t2 WHERE b > 4),
                  (SELECT c FROM t2 WHERE c=a AND b > 1 ORDER BY b));

malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2060
DROP TABLE t1,t2;
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2061

2062
# End of 4.1 tests
igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
2063

bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
2064
#
2065
#decimal-related tests
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
2066
#
2067 2068 2069 2070 2071 2072 2073 2074 2075 2076 2077 2078 2079 2080 2081 2082 2083 2084 2085 2086 2087
create table t1 (df decimal(5,1));
insert into t1 values(1.1);
insert into t1 values(2.2);

select * from t1 where df <= all (select avg(df) from t1 group by df);
select * from t1 where df >= all (select avg(df) from t1 group by df);
drop table t1;

create table t1 (df decimal(5,1));
insert into t1 values(1.1);
select 1.1 * exists(select * from t1);
drop table t1;

CREATE TABLE t1 (
  grp int(11) default NULL,
  a decimal(10,2) default NULL);

insert into t1 values (1, 1), (2, 2), (2, 3), (3, 4), (3, 5), (3, 6), (NULL, NULL);
select * from t1;
select min(a) from t1 group by grp;
drop table t1;
2088 2089 2090 2091 2092 2093 2094 2095 2096 2097 2098 2099 2100 2101 2102 2103 2104 2105 2106 2107 2108

#
# Test for bug #9338: lame substitution of c1 instead of c2 
#

CREATE table t1 ( c1 integer );
INSERT INTO t1 VALUES ( 1 );
INSERT INTO t1 VALUES ( 2 );
INSERT INTO t1 VALUES ( 3 );

CREATE TABLE t2 ( c2 integer );
INSERT INTO t2 VALUES ( 1 );
INSERT INTO t2 VALUES ( 4 );
INSERT INTO t2 VALUES ( 5 );

SELECT * FROM t1 LEFT JOIN t2 ON c1 = c2 WHERE c2 IN (1);

SELECT * FROM t1 LEFT JOIN t2 ON c1 = c2
  WHERE c2 IN ( SELECT c2 FROM t2 WHERE c2 IN ( 1 ) );

DROP TABLE t1,t2;
2109 2110 2111 2112 2113 2114 2115 2116 2117 2118 2119 2120 2121 2122 2123 2124 2125 2126 2127 2128 2129 2130 2131 2132 2133

#
# Test for bug #9516: wrong evaluation of not_null_tables attribute in SQ 
#
CREATE TABLE t1 ( c1 integer );
INSERT INTO t1 VALUES ( 1 );
INSERT INTO t1 VALUES ( 2 );
INSERT INTO t1 VALUES ( 3 );
INSERT INTO t1 VALUES ( 6 ); 
 
CREATE TABLE t2 ( c2 integer );
INSERT INTO t2 VALUES ( 1 );
INSERT INTO t2 VALUES ( 4 );
INSERT INTO t2 VALUES ( 5 );
INSERT INTO t2 VALUES ( 6 );

CREATE TABLE t3 ( c3 integer );
INSERT INTO t3 VALUES ( 7 );
INSERT INTO t3 VALUES ( 8 );

SELECT c1,c2 FROM t1 LEFT JOIN t2 ON c1 = c2 
  WHERE EXISTS (SELECT c3 FROM t3 WHERE c2 IS NULL );

DROP TABLE t1,t2,t3;

2134 2135 2136 2137 2138 2139 2140 2141 2142 2143 2144 2145 2146 2147 2148 2149 2150 2151 2152 2153 2154 2155 2156
#
# Item_int_with_ref check (BUG#10020)
#
CREATE TABLE `t1` (
  `itemid` bigint(20) unsigned NOT NULL auto_increment,
  `sessionid` bigint(20) unsigned default NULL,
  `time` int(10) unsigned NOT NULL default '0',
  `type` set('A','D','E','F','G','I','L','N','U') collate latin1_general_ci NOT
NULL default '',
  `data` text collate latin1_general_ci NOT NULL,
  PRIMARY KEY  (`itemid`)
) DEFAULT CHARSET=latin1 COLLATE=latin1_general_ci;
INSERT INTO `t1` VALUES (1, 1, 1, 'D', '');
CREATE TABLE `t2` (
  `sessionid` bigint(20) unsigned NOT NULL auto_increment,
  `pid` int(10) unsigned NOT NULL default '0',
  `date` int(10) unsigned NOT NULL default '0',
  `ip` varchar(15) collate latin1_general_ci NOT NULL default '',
  PRIMARY KEY  (`sessionid`)
) DEFAULT CHARSET=latin1 COLLATE=latin1_general_ci;
INSERT INTO `t2` VALUES (1, 1, 1, '10.10.10.1');
SELECT s.ip, count( e.itemid ) FROM `t1` e JOIN t2 s ON s.sessionid = e.sessionid WHERE e.sessionid = ( SELECT sessionid FROM t2 ORDER BY sessionid DESC LIMIT 1 ) GROUP BY s.ip HAVING count( e.itemid ) >0 LIMIT 0 , 30;
drop tables t1,t2;
2157 2158 2159 2160 2161 2162 2163

#
# Correct building of equal fields list (do not include outer
# fields) (BUG#6384)
#
CREATE TABLE t1 (EMPNUM   CHAR(3));
CREATE TABLE t2 (EMPNUM   CHAR(3) );
monty@mysql.com's avatar
monty@mysql.com committed
2164
INSERT INTO t1 VALUES ('E1'),('E2');
2165 2166 2167 2168 2169 2170
INSERT INTO t2 VALUES ('E1');
DELETE FROM t1
WHERE t1.EMPNUM NOT IN
      (SELECT t2.EMPNUM
       FROM t2
       WHERE t1.EMPNUM = t2.EMPNUM);
monty@mysql.com's avatar
monty@mysql.com committed
2171
select * from t1;
2172
DROP TABLE t1,t2;
igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
2173 2174 2175 2176 2177 2178 2179 2180 2181 2182 2183 2184 2185 2186 2187 2188 2189 2190 2191 2192 2193 2194

#
# Test for bug #11487: range access in a subquery
#

CREATE TABLE t1(select_id BIGINT, values_id BIGINT);
INSERT INTO t1 VALUES (1, 1);
CREATE TABLE t2 (select_id BIGINT, values_id BIGINT, 
                 PRIMARY KEY(select_id,values_id));
INSERT INTO t2 VALUES (0, 1), (0, 2), (0, 3), (1, 5);

SELECT values_id FROM t1 
WHERE values_id IN (SELECT values_id FROM t2
                    WHERE select_id IN (1, 0));
SELECT values_id FROM t1 
WHERE values_id IN (SELECT values_id FROM t2
                    WHERE select_id BETWEEN 0 AND 1);
SELECT values_id FROM t1 
WHERE values_id IN (SELECT values_id FROM t2
                    WHERE select_id = 0 OR select_id = 1);

DROP TABLE t1, t2;
2195

2196 2197 2198 2199 2200 2201 2202
# BUG#11821 : Select from subselect using aggregate function on an enum
# segfaults:
create table t1 (fld enum('0','1'));
insert into t1 values ('1');
select * from (select max(fld) from t1) as foo;
drop table t1;

igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
2203 2204 2205 2206 2207 2208 2209 2210 2211 2212 2213 2214 2215 2216 2217 2218 2219 2220 2221 2222 2223 2224 2225 2226 2227 2228 2229 2230 2231 2232 2233 2234 2235 2236 2237 2238 2239 2240 2241 2242 2243 2244 2245 2246 2247 2248 2249 2250 2251 2252 2253 2254 2255 2256 2257 2258 2259 2260 2261 2262 2263 2264 2265 2266 2267 2268 2269 2270 2271 2272 2273 2274 2275 2276 2277 2278 2279 2280 2281 2282 2283 2284 2285
#
# Test for bug #11762: subquery with an aggregate function in HAVING
#

CREATE TABLE t1 (a int, b int);
CREATE TABLE t2 (c int, d int);
CREATE TABLE t3 (e int);

INSERT INTO t1 VALUES 
  (1,10), (2,10), (1,20), (2,20), (3,20), (2,30), (4,40);
INSERT INTO t2 VALUES
  (2,10), (2,20), (4,10), (5,10), (3,20), (2,40);
INSERT INTO t3 VALUES (10), (30), (10), (20) ;

SELECT a, MAX(b), MIN(b) FROM t1 GROUP BY a;
SELECT * FROM t2;
SELECT * FROM t3;

SELECT a FROM t1 GROUP BY a
  HAVING a IN (SELECT c FROM t2 WHERE MAX(b)>20);
SELECT a FROM t1 GROUP BY a
  HAVING a IN (SELECT c FROM t2 WHERE MAX(b)<d);
SELECT a FROM t1 GROUP BY a
  HAVING a IN (SELECT c FROM t2 WHERE MAX(b)>d);
SELECT a FROM t1 GROUP BY a
  HAVING a IN (SELECT c FROM t2
                 WHERE d >= SOME(SELECT e FROM t3 WHERE MAX(b)=e));
SELECT a FROM t1 GROUP BY a
  HAVING a IN (SELECT c FROM t2
                 WHERE  EXISTS(SELECT e FROM t3 WHERE MAX(b)=e AND e <= d));
SELECT a FROM t1 GROUP BY a
  HAVING a IN (SELECT c FROM t2
                 WHERE d > SOME(SELECT e FROM t3 WHERE MAX(b)=e));
SELECT a FROM t1 GROUP BY a
  HAVING a IN (SELECT c FROM t2
                 WHERE  EXISTS(SELECT e FROM t3 WHERE MAX(b)=e AND e < d));
SELECT a FROM t1 GROUP BY a
  HAVING a IN (SELECT c FROM t2
                 WHERE MIN(b) < d AND 
                       EXISTS(SELECT e FROM t3 WHERE MAX(b)=e AND e <= d));

SELECT a, SUM(a) FROM t1 GROUP BY a;

SELECT a FROM t1
   WHERE EXISTS(SELECT c FROM t2 GROUP BY c HAVING SUM(a) = c) GROUP BY a;
SELECT a FROM t1 GROUP BY a
   HAVING EXISTS(SELECT c FROM t2 GROUP BY c HAVING SUM(a) = c);

SELECT a FROM t1
   WHERE a < 3 AND
         EXISTS(SELECT c FROM t2 GROUP BY c HAVING SUM(a) != c) GROUP BY a;
SELECT a FROM t1
   WHERE a < 3 AND
         EXISTS(SELECT c FROM t2 GROUP BY c HAVING SUM(a) != c);

SELECT t1.a FROM t1 GROUP BY t1.a
  HAVING t1.a < ALL(SELECT t2.c FROM t2 GROUP BY t2.c
                       HAVING EXISTS(SELECT t3.e FROM t3 GROUP BY t3.e
                                       HAVING SUM(t1.a+t2.c) < t3.e/4));
SELECT t1.a FROM t1 GROUP BY t1.a
       HAVING t1.a > ALL(SELECT t2.c FROM t2
                           WHERE EXISTS(SELECT t3.e FROM t3 GROUP BY t3.e
                                          HAVING SUM(t1.a+t2.c) < t3.e/4));
-- error 1111
SELECT t1.a FROM t1 GROUP BY t1.a
       HAVING t1.a > ALL(SELECT t2.c FROM t2
                           WHERE EXISTS(SELECT t3.e FROM t3 
                                          WHERE SUM(t1.a+t2.c) < t3.e/4));
-- error 1111 
SELECT t1.a from t1 GROUP BY t1.a HAVING AVG(SUM(t1.b)) > 20;

SELECT t1.a FROM t1 GROUP BY t1.a
  HAVING t1.a IN (SELECT t2.c FROM t2 GROUP BY t2.c
                    HAVING AVG(t2.c+SUM(t1.b)) > 20);
SELECT t1.a FROM t1 GROUP BY t1.a
  HAVING t1.a IN (SELECT t2.c FROM t2 GROUP BY t2.c
                    HAVING AVG(SUM(t1.b)) > 20);

SELECT t1.a, SUM(b) AS sum  FROM t1 GROUP BY t1.a
  HAVING t1.a IN (SELECT t2.c FROM t2 GROUP BY t2.c
                    HAVING t2.c+sum > 20);

DROP TABLE t1,t2,t3;
igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
2286 2287 2288 2289 2290 2291 2292 2293 2294 2295 2296 2297 2298 2299 2300 2301 2302 2303 2304 2305 2306 2307

#
# Test for bug #16603: GROUP BY in a row subquery with a quantifier 
#                      when an index is defined on the grouping field

CREATE TABLE t1 (a varchar(5), b varchar(10));
INSERT INTO t1 VALUES
  ('AAA', 5), ('BBB', 4), ('BBB', 1), ('CCC', 2),
  ('CCC', 7), ('AAA', 2), ('AAA', 4), ('BBB', 3), ('AAA', 8);

SELECT * FROM t1 WHERE (a,b) = ANY (SELECT a, max(b) FROM t1 GROUP BY a);
EXPLAIN
SELECT * FROM t1 WHERE (a,b) = ANY (SELECT a, max(b) FROM t1 GROUP BY a);

ALTER TABLE t1 ADD INDEX(a);

SELECT * FROM t1 WHERE (a,b) = ANY (SELECT a, max(b) FROM t1 GROUP BY a);
EXPLAIN
SELECT * FROM t1 WHERE (a,b) = ANY (SELECT a, max(b) FROM t1 GROUP BY a);

DROP TABLE t1;

2308 2309 2310 2311 2312 2313 2314
#
# Bug#17366: Unchecked Item_int results in server crash
#
create table t1( f1 int,f2 int);
insert into t1 values (1,1),(2,2);
select tt.t from (select 'crash1' as t, f2 from t1) as tt left join t1 on tt.t = 'crash2' and tt.f2 = t1.f2 where tt.t = 'crash1';
drop table t1;
2315 2316 2317 2318 2319 2320 2321 2322 2323 2324 2325

#
# Bug #18306: server crash on delete using subquery.
#

create table t1 (c int, key(c));                              
insert into t1 values (1142477582), (1142455969);
create table t2 (a int, b int);
insert into t2 values (2, 1), (1, 0);
delete from t1 where c <= 1140006215 and (select b from t2 where a = 2) = 1;
drop table t1, t2;
2326 2327 2328 2329 2330 2331 2332 2333 2334 2335 2336 2337 2338 2339 2340

#
# Bug #7549: Missing error message for invalid view selection with subquery
#

CREATE TABLE t1 (a INT);

--error 1054
CREATE VIEW v1 AS SELECT * FROM t1 WHERE no_such_column = ANY (SELECT 1);
--error 1054
CREATE VIEW v2 AS SELECT * FROM t1 WHERE no_such_column = (SELECT 1);
--error 1054
SELECT * FROM t1 WHERE no_such_column = ANY (SELECT 1);

DROP TABLE t1;
2341 2342 2343 2344 2345 2346 2347 2348 2349

#
# Bug#19077: A nested materialized derived table is used before being populated.
#
create table t1 (i int, j bigint);
insert into t1 values (1, 2), (2, 2), (3, 2);
select * from (select min(i) from t1 where j=(select * from (select min(j) from t1) t2)) t3;
drop table t1;

2350 2351 2352 2353
# 
# Bug#19700: subselect returning BIGINT always returned it as SIGNED
#
CREATE TABLE t1 (i BIGINT UNSIGNED);
2354
INSERT INTO t1 VALUES (10000000000000000000); # > MAX SIGNED BIGINT 9323372036854775807
2355 2356 2357
INSERT INTO t1 VALUES (1);

CREATE TABLE t2 (i BIGINT UNSIGNED);
2358
INSERT INTO t2 VALUES (10000000000000000000); # same as first table
2359 2360 2361 2362 2363 2364 2365 2366 2367 2368 2369 2370 2371
INSERT INTO t2 VALUES (1);

/* simple test */
SELECT t1.i FROM t1 JOIN t2 ON t1.i = t2.i;

/* subquery test */
SELECT t1.i FROM t1 WHERE t1.i = (SELECT MAX(i) FROM t2);

/* subquery test with cast*/
SELECT t1.i FROM t1 WHERE t1.i = CAST((SELECT MAX(i) FROM t2) AS UNSIGNED);

DROP TABLE t1;
DROP TABLE t2;
igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
2372 2373

# 
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2374 2375 2376 2377 2378 2379 2380 2381 2382 2383 2384 2385 2386 2387 2388 2389 2390 2391 2392 2393 2394 2395 2396 2397 2398 2399 2400 2401 2402 2403 2404 2405 2406 2407 2408 2409 2410 2411
# Bug#20519: subselect with LIMIT M, N
#

CREATE TABLE t1 (
  id bigint(20) unsigned NOT NULL auto_increment,
  name varchar(255) NOT NULL,
  PRIMARY KEY  (id)
);
INSERT INTO t1 VALUES
  (1, 'Balazs'), (2, 'Joe'), (3, 'Frank');

CREATE TABLE t2 (
  id bigint(20) unsigned NOT NULL auto_increment,
  mid bigint(20) unsigned NOT NULL,
  date date NOT NULL,
  PRIMARY KEY  (id)
);
INSERT INTO t2 VALUES 
  (1, 1, '2006-03-30'), (2, 2, '2006-04-06'), (3, 3, '2006-04-13'),
  (4, 2, '2006-04-20'), (5, 1, '2006-05-01');

SELECT *,
      (SELECT date FROM t2 WHERE mid = t1.id
         ORDER BY date DESC LIMIT 0, 1) AS date_last,
      (SELECT date FROM t2 WHERE mid = t1.id
         ORDER BY date DESC LIMIT 3, 1) AS date_next_to_last
  FROM t1;
SELECT *,
      (SELECT COUNT(*) FROM t2 WHERE mid = t1.id
         ORDER BY date DESC LIMIT 1, 1) AS date_count
  FROM t1;
SELECT *,
      (SELECT date FROM t2 WHERE mid = t1.id
         ORDER BY date DESC LIMIT 0, 1) AS date_last,
      (SELECT date FROM t2 WHERE mid = t1.id
         ORDER BY date DESC LIMIT 1, 1) AS date_next_to_last
  FROM t1;
DROP TABLE t1,t2;
2412 2413

#
igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
2414 2415 2416 2417 2418 2419 2420 2421 2422 2423 2424 2425 2426 2427 2428 2429 2430 2431 2432 2433 2434 2435 2436 2437 2438 2439 2440 2441 2442 2443 2444 2445 2446 2447 2448 2449
# Bug#20869: subselect with range access by DESC
#

CREATE TABLE t1 (
  i1 int(11) NOT NULL default '0',
  i2 int(11) NOT NULL default '0',
  t datetime NOT NULL default '0000-00-00 00:00:00',
  PRIMARY KEY  (i1,i2,t)
);
INSERT INTO t1 VALUES 
(24,1,'2005-03-03 16:31:31'),(24,1,'2005-05-27 12:40:07'),
(24,1,'2005-05-27 12:40:08'),(24,1,'2005-05-27 12:40:10'),
(24,1,'2005-05-27 12:40:25'),(24,1,'2005-05-27 12:40:30'),
(24,2,'2005-03-03 13:43:05'),(24,2,'2005-03-03 16:23:31'),
(24,2,'2005-03-03 16:31:30'),(24,2,'2005-05-27 12:37:02'),
(24,2,'2005-05-27 12:40:06');

CREATE TABLE t2 (
  i1 int(11) NOT NULL default '0',
  i2 int(11) NOT NULL default '0',
  t datetime default NULL,
  PRIMARY KEY  (i1)
);
INSERT INTO t2 VALUES (24,1,'2006-06-20 12:29:40');

EXPLAIN
SELECT * FROM t1,t2
  WHERE t1.t = (SELECT t1.t FROM t1 
                  WHERE t1.t < t2.t  AND t1.i2=1 AND t2.i1=t1.i1
                    ORDER BY t1.t DESC LIMIT 1);
SELECT * FROM t1,t2
  WHERE t1.t = (SELECT t1.t FROM t1 
                  WHERE t1.t < t2.t  AND t1.i2=1 AND t2.i1=t1.i1
                    ORDER BY t1.t DESC LIMIT 1);

DROP TABLE t1, t2;
2450 2451 2452 2453 2454 2455 2456 2457

#
# Bug#14654 : Cannot select from the same table twice within a UNION
# statement 
#
CREATE TABLE t1 (i INT);

(SELECT i FROM t1) UNION (SELECT i FROM t1);
2458 2459
#TODO:not supported
--error ER_PARSE_ERROR
2460 2461 2462 2463 2464 2465
SELECT sql_no_cache * FROM t1 WHERE NOT EXISTS 
  (
   (SELECT i FROM t1) UNION 
   (SELECT i FROM t1)
  );

2466 2467
#TODO:not supported
--error ER_PARSE_ERROR
2468 2469 2470 2471 2472 2473 2474
SELECT * FROM t1 
WHERE NOT EXISTS (((SELECT i FROM t1) UNION (SELECT i FROM t1)));

#TODO:not supported
--error 1064
explain select ((select t11.i from t1 t11) union (select t12.i from t1 t12))
  from t1;
2475 2476 2477

#TODO:not supported
--error ER_PARSE_ERROR
2478 2479 2480 2481
explain select * from t1 where not exists 
  ((select t11.i from t1 t11) union (select t12.i from t1 t12));

DROP TABLE t1;
2482

2483 2484 2485 2486 2487 2488 2489 2490 2491 2492 2493 2494 2495 2496 2497 2498 2499 2500 2501 2502 2503 2504 2505 2506 2507
#
# Bug#21798: memory leak during query execution with subquery in column 
#             list using a function
#
CREATE TABLE t1 (a VARCHAR(250), b INT auto_increment, PRIMARY KEY (b));
insert into t1 (a) values (FLOOR(rand() * 100));
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;
insert into t1 (a) select FLOOR(rand() * 100) from t1;

SELECT a, 
       (SELECT REPEAT(' ',250) FROM t1 i1 
        WHERE i1.b=t1.a ORDER BY RAND() LIMIT 1) AS a 
FROM t1 ORDER BY a LIMIT 5;
DROP TABLE t1;
2508

2509 2510 2511 2512 2513 2514 2515 2516 2517 2518 2519 2520 2521 2522 2523 2524 2525 2526 2527 2528 2529 2530 2531 2532 2533 2534 2535 2536 2537 2538
#
# Bug #21540: Subqueries with no from and aggregate functions return 
#              wrong results
CREATE TABLE t1 (a INT, b INT);
CREATE TABLE t2 (a INT);
INSERT INTO t2 values (1);
INSERT INTO t1 VALUES (1,1),(1,2),(2,3),(3,4);
SELECT (SELECT COUNT(DISTINCT t1.b) from t2) FROM t1 GROUP BY t1.a;
SELECT (SELECT COUNT(DISTINCT t1.b) from t2 union select 1 from t2 where 12 < 3)
  FROM t1 GROUP BY t1.a;
SELECT COUNT(DISTINCT t1.b), (SELECT COUNT(DISTINCT t1.b)) FROM t1 GROUP BY t1.a;
SELECT COUNT(DISTINCT t1.b), 
       (SELECT COUNT(DISTINCT t1.b) union select 1 from DUAL where 12 < 3)
  FROM t1 GROUP BY t1.a;
SELECT (
    SELECT (
      SELECT COUNT(DISTINCT t1.b)
    )
) 
FROM t1 GROUP BY t1.a;
SELECT (
  SELECT (
      SELECT (
        SELECT COUNT(DISTINCT t1.b)
      )
  ) 
  FROM t1 GROUP BY t1.a LIMIT 1) 
FROM t1 t2
GROUP BY t2.a;
DROP TABLE t1,t2;  
igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
2539 2540 2541 2542 2543 2544 2545 2546 2547 2548 2549 2550 2551 2552 2553 2554 2555 2556 2557 2558 2559 2560 2561 2562 2563 2564 2565 2566 2567 2568 2569 2570 2571 2572 2573 2574 2575

#
# Bug #21727: Correlated subquery that requires filesort:
#             slow with big sort_buffer_size 
#

CREATE TABLE t1 (a int, b int auto_increment, PRIMARY KEY (b));
CREATE TABLE t2 (x int auto_increment, y int, z int,
                 PRIMARY KEY (x), FOREIGN KEY (y) REFERENCES t1 (b));

disable_query_log;
let $1=3000;
while ($1)
{
  eval INSERT INTO t1(a) VALUES(RAND()*1000);
  eval SELECT MAX(b) FROM t1 INTO @id;
  let $2=10;
  while ($2)
  {
    eval INSERT INTO t2(y,z) VALUES(@id,RAND()*1000);
    dec $2;
  } 
  dec $1;
}
enable_query_log;

SET SESSION sort_buffer_size = 32 * 1024;
SELECT SQL_NO_CACHE COUNT(*) 
  FROM (SELECT  a, b, (SELECT x FROM t2 WHERE y=b ORDER BY z DESC LIMIT 1) c
          FROM t1) t;

SET SESSION sort_buffer_size = 8 * 1024 * 1024;
SELECT SQL_NO_CACHE COUNT(*) 
  FROM (SELECT  a, b, (SELECT x FROM t2 WHERE y=b ORDER BY z DESC LIMIT 1) c
          FROM t1) t;

DROP TABLE t1,t2;
2576

2577 2578 2579
#
# Bug #25219: EXIST subquery with UNION over a mix of
#             correlated and uncorrelated selects
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2580
#
2581 2582 2583 2584 2585 2586 2587

CREATE TABLE t1 (id char(4) PRIMARY KEY, c int);
CREATE TABLE t2 (c int);

INSERT INTO t1 VALUES ('aa', 1);
INSERT INTO t2 VALUES (1);

malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2588
SELECT * FROM t1
2589
  WHERE EXISTS (SELECT c FROM t2 WHERE c=1
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2590
                UNION
2591 2592 2593 2594
                SELECT c from t2 WHERE c=t1.c);

INSERT INTO t1 VALUES ('bb', 2), ('cc', 3), ('dd',1);

malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2595
SELECT * FROM t1
2596
  WHERE EXISTS (SELECT c FROM t2 WHERE c=1
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2597
                UNION
2598 2599 2600 2601 2602 2603
                SELECT c from t2 WHERE c=t1.c);

INSERT INTO t2 VALUES (2);
CREATE TABLE t3 (c int);
INSERT INTO t3 VALUES (1);

malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2604
SELECT * FROM t1
2605
  WHERE EXISTS (SELECT t2.c FROM t2 JOIN t3 ON t2.c=t3.c WHERE t2.c=1
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2606
                UNION
2607 2608 2609
                SELECT c from t2 WHERE c=t1.c);

DROP TABLE t1,t2,t3;
2610

2611 2612 2613 2614 2615 2616 2617 2618 2619 2620 2621 2622 2623 2624 2625 2626 2627 2628 2629 2630 2631 2632 2633 2634 2635 2636 2637
#                                                                             
# Bug#23800: Outer fields in correlated subqueries is used in a temporary     
#            table created for sorting.                                       
#                                                                             
CREATE TABLE t1(f1 int);
CREATE TABLE t2(f2 int, f21 int, f3 timestamp);
INSERT INTO t1 VALUES (1),(1),(2),(2);
INSERT INTO t2 VALUES (1,1,"2004-02-29 11:11:11"), (2,2,"2004-02-29 11:11:11");
SELECT ((SELECT f2 FROM t2 WHERE f21=f1 LIMIT 1) * COUNT(f1)) AS sq FROM t1 GROUP BY f1;
SELECT (SELECT SUM(1) FROM t2 ttt GROUP BY t2.f3 LIMIT 1) AS tt FROM t2;
PREPARE stmt1 FROM 'SELECT ((SELECT f2 FROM t2 WHERE f21=f1 LIMIT 1) * COUNT(f1)) AS sq FROM t1 GROUP BY f1';
EXECUTE stmt1;
EXECUTE stmt1;
DEALLOCATE PREPARE stmt1;
SELECT f2, AVG(f21), 
      (SELECT t.f3 FROM t2 AS t WHERE t2.f2=t.f2 AND t.f3=MAX(t2.f3)) AS test
  FROM t2 GROUP BY f2;
DROP TABLE t1,t2;                                                             
CREATE TABLE t1 (a int, b INT, c CHAR(10) NOT NULL);                          
INSERT INTO t1 VALUES                                                         
  (1,1,'a'), (1,2,'b'), (1,3,'c'), (1,4,'d'), (1,5,'e'),                      
  (2,1,'f'), (2,2,'g'), (2,3,'h'), (3,4,'i'), (3,3,'j'),                      
  (3,2,'k'), (3,1,'l'), (1,9,'m');                                            
SELECT a, MAX(b),                                                             
      (SELECT t.c FROM t1 AS t WHERE t1.a=t.a AND t.b=MAX(t1.b)) AS test      
  FROM t1 GROUP BY a;                                                         
DROP TABLE t1;      
malff/marcsql@weblab.(none)'s avatar
malff/marcsql@weblab.(none) committed
2638 2639 2640 2641 2642 2643 2644 2645 2646 2647 2648 2649 2650 2651 2652 2653 2654 2655 2656 2657 2658 2659 2660 2661 2662 2663 2664 2665 2666 2667 2668 2669 2670 2671 2672 2673 2674 2675 2676 2677 2678 2679 2680 2681 2682 2683 2684 2685 2686 2687 2688 2689 2690 2691 2692 2693 2694 2695 2696 2697 2698 2699 2700 2701 2702 2703 2704 2705 2706 2707 2708 2709 2710 2711 2712 2713 2714 2715 2716 2717 2718 2719 2720 2721 2722 2723 2724 2725 2726 2727 2728 2729 2730 2731 2732 2733 2734 2735 2736 2737

#
# Bug#21904 (parser problem when using IN with a double "(())")
#

--disable_warnings
DROP TABLE IF EXISTS t1;
DROP TABLE IF EXISTS t2;
DROP TABLE IF EXISTS t1xt2;
--enable_warnings

CREATE TABLE t1 (
  id_1 int(5) NOT NULL,
  t varchar(4) DEFAULT NULL
);

CREATE TABLE t2 (
  id_2 int(5) NOT NULL,
  t varchar(4) DEFAULT NULL
);

CREATE TABLE t1xt2 (
  id_1 int(5) NOT NULL,
  id_2 int(5) NOT NULL
);

INSERT INTO t1 VALUES (1, 'a'), (2, 'b'), (3, 'c'), (4, 'd');

INSERT INTO t2 VALUES (2, 'bb'), (3, 'cc'), (4, 'dd'), (12, 'aa');

INSERT INTO t1xt2 VALUES (2, 2), (3, 3), (4, 4);

# subselect returns 0 rows

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN (SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN ((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1)));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN (((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1))));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN (SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN ((SELECT t1xt2.id_2 FROM t1xt2 where t1.id_1 = t1xt2.id_1)));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN (((SELECT t1xt2.id_2 FROM t1xt2 where t1.id_1 = t1xt2.id_1))));

insert INTO t1xt2 VALUES (1, 12);

# subselect returns 1 row

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN (SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN ((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1)));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN (((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1))));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN (SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN ((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1)));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN (((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1))));

insert INTO t1xt2 VALUES (2, 12);

# subselect returns more than 1 row

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN (SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN ((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1)));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 IN (((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1))));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN (SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN ((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1)));

SELECT DISTINCT t1.id_1 FROM t1 WHERE
(12 NOT IN (((SELECT t1xt2.id_2 FROM t1xt2 WHERE t1.id_1 = t1xt2.id_1))));

DROP TABLE t1;
DROP TABLE t2;
DROP TABLE t1xt2;

2738 2739 2740 2741 2742 2743 2744 2745 2746 2747 2748 2749
#
# Bug #26728: derived table with concatanation of literals in select list
#  

CREATE TABLE t1 (a int);
INSERT INTO t1 VALUES (3), (1), (2);           

SELECT 'this is ' 'a test.' AS col1, a AS col2 FROM t1;
SELECT * FROM (SELECT 'this is ' 'a test.' AS col1, a AS t2 FROM t1) t;

DROP table t1;

2750 2751 2752 2753 2754 2755 2756 2757
#
# Bug #27257: COUNT(*) aggregated in outer query
#  

CREATE TABLE t1 (a int, b int);
CREATE TABLE t2 (m int, n int);
INSERT INTO t1 VALUES (2,2), (2,2), (3,3), (3,3), (3,3), (4,4);
INSERT INTO t2 VALUES (1,11), (2,22), (3,32), (4,44), (4,44);
2758

2759 2760 2761 2762 2763 2764 2765 2766 2767 2768 2769 2770 2771
SELECT COUNT(*), a,
       (SELECT m FROM t2 WHERE m = count(*) LIMIT 1)
  FROM t1 GROUP BY a;

SELECT COUNT(*), a,
       (SELECT MIN(m) FROM t2 WHERE m = count(*))
  FROM t1 GROUP BY a;

SELECT COUNT(*), a       
  FROM t1 GROUP BY a
    HAVING (SELECT MIN(m) FROM t2 WHERE m = count(*)) > 1;

DROP TABLE t1,t2;
2772

2773 2774 2775 2776 2777 2778 2779 2780 2781 2782 2783 2784 2785 2786 2787 2788 2789 2790
#
# Bug #27229: GROUP_CONCAT in subselect with COUNT() as an argument 
#  

CREATE TABLE t1 (a int, b int);
CREATE TABLE t2 (m int, n int);
INSERT INTO t1 VALUES (2,2), (2,2), (3,3), (3,3), (3,3), (4,4);
INSERT INTO t2 VALUES (1,11), (2,22), (3,32), (4,44), (4,44);

SELECT COUNT(*) c, a,
       (SELECT GROUP_CONCAT(COUNT(a)) FROM t2 WHERE m = a)
  FROM t1 GROUP BY a;

SELECT COUNT(*) c, a,
       (SELECT GROUP_CONCAT(COUNT(a)+1) FROM t2 WHERE m = a)
  FROM t1 GROUP BY a;

DROP table t1,t2;
2791

2792 2793 2794 2795 2796 2797 2798 2799 2800 2801 2802 2803 2804 2805 2806 2807 2808 2809 2810 2811 2812 2813 2814 2815 2816 2817 2818 2819 2820 2821 2822 2823 2824 2825 2826
#
# Bug#27321: Wrong subquery result in a grouping select
#
CREATE TABLE t1 (a int, b INT, d INT, c CHAR(10) NOT NULL, PRIMARY KEY (a, b));
INSERT INTO t1 VALUES (1,1,0,'a'), (1,2,0,'b'), (1,3,0,'c'), (1,4,0,'d'),
(1,5,0,'e'), (2,1,0,'f'), (2,2,0,'g'), (2,3,0,'h'), (3,4,0,'i'), (3,3,0,'j'),
(3,2,0,'k'), (3,1,0,'l'), (1,9,0,'m'), (1,0,10,'n'), (2,0,5,'o'), (3,0,7,'p');

SELECT a, MAX(b),
  (SELECT t.c FROM t1 AS t WHERE t1.a=t.a AND t.b=MAX(t1.b + 0)) as test 
  FROM t1 GROUP BY a;
SELECT a x, MAX(b),
  (SELECT t.c FROM t1 AS t WHERE x=t.a AND t.b=MAX(t1.b + 0)) as test
  FROM t1 GROUP BY a;
SELECT a, AVG(b),
  (SELECT t.c FROM t1 AS t WHERE t1.a=t.a AND t.b=AVG(t1.b)) AS test
  FROM t1 WHERE t1.d=0 GROUP BY a;

SELECT tt.a,
 (SELECT (SELECT c FROM t1 as t WHERE t1.a=t.a AND t.d=MAX(t1.b + tt.a)
  LIMIT 1) FROM t1 WHERE t1.a=tt.a GROUP BY a LIMIT 1) as test 
  FROM t1 as tt;

SELECT tt.a,
 (SELECT (SELECT t.c FROM t1 AS t WHERE t1.a=t.a AND t.d=MAX(t1.b + tt.a)
  LIMIT 1)
  FROM t1 WHERE t1.a=tt.a GROUP BY a LIMIT 1) as test 
  FROM t1 as tt GROUP BY tt.a;

SELECT tt.a, MAX(
 (SELECT (SELECT t.c FROM t1 AS t WHERE t1.a=t.a AND t.d=MAX(t1.b + tt.a)
  LIMIT 1)
  FROM t1 WHERE t1.a=tt.a GROUP BY a LIMIT 1)) as test 
  FROM t1 as tt GROUP BY tt.a;

2827
DROP TABLE t1;
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
2828 2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840 2841 2842 2843 2844 2845 2846 2847 2848 2849 2850 2851 2852 2853
#
# Bug #27348: SET FUNCTION used in  a subquery from WHERE condition 
#  

CREATE TABLE t1 (a int, b int);
INSERT INTO t1 VALUES (2,22),(1,11),(2,22);

SELECT a FROM t1 WHERE (SELECT COUNT(b) FROM DUAL) > 0 GROUP BY a;
SELECT a FROM t1 WHERE (SELECT COUNT(b) FROM DUAL) > 1 GROUP BY a;

SELECT a FROM t1 t0
  WHERE (SELECT COUNT(t0.b) FROM t1 t WHERE t.b>20) GROUP BY a;

SET @@sql_mode='ansi';
--error 1111
SELECT a FROM t1 WHERE (SELECT COUNT(b) FROM DUAL) > 0 GROUP BY a;
--error 1111
SELECT a FROM t1 WHERE (SELECT COUNT(b) FROM DUAL) > 1 GROUP BY a;

--error 1111
SELECT a FROM t1 t0
  WHERE (SELECT COUNT(t0.b) FROM t1 t WHERE t.b>20) GROUP BY a;

SET @@sql_mode=default;

DROP TABLE t1;
gkodinov/kgeorge@magare.gmz's avatar
gkodinov/kgeorge@magare.gmz committed
2854 2855 2856 2857 2858 2859 2860 2861 2862 2863 2864 2865 2866 2867 2868 2869 2870 2871 2872 2873 2874 2875 2876 2877 2878 2879 2880 2881 2882

#
# Bug #27363: nested aggregates in outer, subquery / sum(select
# count(outer))
#
CREATE TABLE t1 (a INT); INSERT INTO t1 values (1),(1),(1),(1);
CREATE TABLE t2 (x INT); INSERT INTO t1 values (1000),(1001),(1002);

--error ER_INVALID_GROUP_FUNC_USE
SELECT SUM( (SELECT COUNT(a) FROM t2) ) FROM t1;
--error ER_INVALID_GROUP_FUNC_USE
SELECT SUM( (SELECT SUM(COUNT(a)) FROM t2) ) FROM t1;
SELECT COUNT(1) FROM DUAL;

--error ER_INVALID_GROUP_FUNC_USE
SELECT SUM( (SELECT AVG( (SELECT t1.a FROM t2) ) FROM DUAL) ) FROM t1;

--error ER_INVALID_GROUP_FUNC_USE
SELECT 
  SUM( (SELECT AVG( (SELECT COUNT(*) FROM t1 t HAVING t1.a < 12) ) FROM t2) )
FROM t1;

--error ER_INVALID_GROUP_FUNC_USE
SELECT t1.a as XXA, 
   SUM( (SELECT AVG( (SELECT COUNT(*) FROM t1 t HAVING XXA < 12) ) FROM t2) )
FROM t1;

DROP TABLE t1,t2;

gkodinov/kgeorge@magare.gmz's avatar
gkodinov/kgeorge@magare.gmz committed
2883 2884 2885 2886 2887 2888 2889 2890
#
# Bug #27807: Server crash when executing subquery with EXPLAIN
#  
CREATE TABLE t1 (a int, b int, KEY (a)); 
INSERT INTO t1 VALUES (1,1),(2,1);
EXPLAIN SELECT 1 FROM t1 WHERE a = (SELECT COUNT(*) FROM t1 GROUP BY b);
DROP TABLE t1;

2891 2892 2893 2894 2895 2896 2897 2898 2899 2900 2901 2902 2903 2904 2905 2906 2907 2908 2909 2910 2911 2912 2913 2914
#
# Bug #28377: grouping query with a correlated subquery in WHERE condition
#  

CREATE TABLE t1 (id int NOT NULL, st CHAR(2), INDEX idx(id));
INSERT INTO t1 VALUES
  (3,'FL'), (2,'GA'), (4,'FL'), (1,'GA'), (5,'NY'), (7,'FL'), (6,'NY');
CREATE TABLE t2 (id int NOT NULL, INDEX idx(id));
INSERT INTO t2 VALUES (7), (5), (1), (3);

SELECT id, st FROM t1 
  WHERE st IN ('GA','FL') AND EXISTS(SELECT 1 FROM t2 WHERE t2.id=t1.id);
SELECT id, st FROM t1 
  WHERE st IN ('GA','FL') AND EXISTS(SELECT 1 FROM t2 WHERE t2.id=t1.id)
    GROUP BY id;

SELECT id, st FROM t1 
  WHERE st IN ('GA','FL') AND NOT EXISTS(SELECT 1 FROM t2 WHERE t2.id=t1.id);
SELECT id, st FROM t1 
  WHERE st IN ('GA','FL') AND NOT EXISTS(SELECT 1 FROM t2 WHERE t2.id=t1.id)
    GROUP BY id;

DROP TABLE t1,t2;

2915 2916 2917 2918 2919 2920 2921 2922 2923 2924 2925 2926 2927 2928
#
# Bug #28728: crash with EXPLAIN EXTENDED for a query with a derived table
#             over a grouping subselect
# 

CREATE TABLE t1 (a int);

INSERT INTO t1 VALUES (1), (2);

EXPLAIN EXTENDED
SELECT * FROM (SELECT count(*) FROM t1 GROUP BY a) as res;

DROP TABLE t1;

2929 2930 2931 2932 2933 2934 2935 2936 2937 2938 2939 2940 2941 2942 2943 2944 2945 2946 2947 2948 2949 2950 2951 2952 2953 2954 2955 2956 2957 2958 2959 2960
#
# Bug #28811: crash for query containing subquery with ORDER BY and LIMIT 1 
#
 
CREATE TABLE t1 (
  a varchar(255) default NULL,
  b timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
  INDEX idx(a,b)
);
CREATE TABLE t2 (
  a varchar(255) default NULL
);

INSERT INTO t1 VALUES ('abcdefghijk','2007-05-07 06:00:24');
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO t1 SELECT * FROM t1;
INSERT INTO `t1` VALUES ('asdf','2007-02-08 01:11:26');
INSERT INTO `t2` VALUES ('abcdefghijk');
INSERT INTO `t2` VALUES ('asdf');

SET session sort_buffer_size=8192;

SELECT (SELECT 1 FROM  t1 WHERE t1.a=t2.a ORDER BY t1.b LIMIT 1) AS d1 FROM t2;

DROP TABLE t1,t2;

2961 2962 2963 2964 2965 2966 2967 2968 2969 2970 2971 2972 2973 2974 2975 2976 2977 2978 2979 2980 2981 2982 2983 2984 2985

#
# Bug #27333: subquery grouped for aggregate of outer query / no aggregate
# of subquery
#
CREATE TABLE t1 (a INTEGER, b INTEGER);
CREATE TABLE t2 (x INTEGER);
INSERT INTO t1 VALUES (1,11), (2,22), (2,22);
INSERT INTO t2 VALUES (1), (2);

# wasn't failing, but should
--error ER_SUBQUERY_NO_1_ROW
SELECT a, COUNT(b), (SELECT COUNT(b) FROM t2) FROM t1 GROUP BY a;

# fails as it should
--error ER_SUBQUERY_NO_1_ROW
SELECT a, COUNT(b), (SELECT COUNT(b)+0 FROM t2) FROM t1 GROUP BY a;

SELECT (SELECT SUM(t1.a)/AVG(t2.x) FROM t2) FROM t1;
DROP TABLE t1,t2;

# second test case from 27333
CREATE TABLE t1 (a INT, b INT);
INSERT INTO t1 VALUES (1, 2), (1,3), (1,4), (2,1), (2,2);

istruewing@chilla.local's avatar
istruewing@chilla.local committed
2986
# returns no rows, when it should
2987 2988 2989 2990 2991 2992 2993 2994 2995 2996 2997 2998 2999 3000 3001 3002
SELECT a1.a, COUNT(*) FROM t1 a1 WHERE a1.a = 1
AND EXISTS( SELECT a2.a FROM t1 a2 WHERE a2.a = a1.a)
GROUP BY a1.a;
DROP TABLE t1;

#test cases from 29297
CREATE TABLE t1 (a INT);
CREATE TABLE t2 (a INT);
INSERT INTO t1 VALUES (1),(2);
INSERT INTO t2 VALUES (1),(2);
SELECT (SELECT SUM(t1.a) FROM t2 WHERE a=0) FROM t1;
--error ER_SUBQUERY_NO_1_ROW
SELECT (SELECT SUM(t1.a) FROM t2 WHERE a!=0) FROM t1;
SELECT (SELECT SUM(t1.a) FROM t2 WHERE a=1) FROM t1;
DROP TABLE t1,t2;

3003 3004 3005 3006 3007 3008 3009 3010 3011 3012 3013 3014 3015
#
# Bug31048: Many nested subqueries may cause server crash.
#
create table t1(a int,b int,key(a),key(b));
insert into t1(a,b) values (1,2),(2,1),(2,3),(3,4),(5,4),(5,5),
  (6,7),(7,4),(5,3);
# test for the stack overflow bug
select sum(a),a from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
evgen@moonbone.local's avatar
evgen@moonbone.local committed
3016 3017
  select sum(a) from t1 where a> ( select sum(a) from t1
  )group by b limit 1)group by b limit 1
3018 3019 3020 3021 3022 3023 3024 3025 3026 3027 3028 3029 3030 3031 3032 3033 3034 3035 3036 3037 3038 3039 3040 3041 3042 3043 3044 3045 3046 3047 3048 3049 3050 3051 3052 3053 3054 3055 3056 3057 3058
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1) 
group by a;
--replace_regex /overrun.*$/overrun detected/
--error 1436
select sum(a),a from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1) 
group by a;
# test for the memory consumption & subquery slowness bug
explain select sum(a),a from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
evgen@moonbone.local's avatar
evgen@moonbone.local committed
3059 3060
  select sum(a) from t1 where a> ( select sum(a) from t1 
  )group by b limit 1)group by b limit 1
3061 3062 3063 3064 3065 3066 3067 3068 3069 3070 3071 3072 3073 3074 3075 3076 3077 3078 3079 3080 3081 3082 3083 3084 3085 3086 3087 3088 3089 3090 3091 3092 3093 3094 3095
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1) 
group by a;
--replace_regex /overrun.*$/overrun detected/
--error 1436
explain select sum(a),a from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 where a> ( select sum(a) from t1 where a> (
  select sum(a) from t1 
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1
  )group by b limit 1)group by b limit 1)group by b limit 1) 
group by a;
drop table t1;
3096

3097 3098 3099 3100 3101 3102 3103 3104 3105 3106 3107 3108 3109 3110 3111
#
# Bug #31884: Assertion + crash in subquery in the SELECT clause.
#

CREATE TABLE t1 (a1 INT, a2 INT);
CREATE TABLE t2 (b1 INT, b2 INT);

INSERT INTO t1 VALUES (100, 200);
INSERT INTO t1 VALUES (101, 201);
INSERT INTO t2 VALUES (101, 201);
INSERT INTO t2 VALUES (103, 203);

SELECT ((a1,a2) IN (SELECT * FROM t2 WHERE b2 > 0)) IS NULL FROM t1;
DROP TABLE t1, t2;

3112 3113 3114 3115 3116 3117 3118 3119 3120 3121 3122 3123 3124 3125 3126 3127 3128 3129 3130 3131 3132 3133 3134 3135 3136 3137 3138 3139 3140 3141 3142 3143 3144 3145 3146 3147 3148 3149 3150 3151 3152 3153
#
# Bug #28076: inconsistent binary/varbinary comparison
#

CREATE TABLE t1 (s1 BINARY(5), s2 VARBINARY(5));
INSERT INTO t1 VALUES (0x41,0x41), (0x42,0x42), (0x43,0x43);

SELECT s1, s2 FROM t1 WHERE s2 IN (SELECT s1 FROM t1);
SELECT s1, s2 FROM t1 WHERE (s2, 10) IN (SELECT s1, 10 FROM t1);

CREATE INDEX I1 ON t1 (s1);
CREATE INDEX I2 ON t1 (s2);

SELECT s1, s2 FROM t1 WHERE s2 IN (SELECT s1 FROM t1);
SELECT s1, s2 FROM t1 WHERE (s2, 10) IN (SELECT s1, 10 FROM t1);

TRUNCATE t1;
INSERT INTO t1 VALUES (0x41,0x41);
SELECT * FROM t1 WHERE s1 = (SELECT s2 FROM t1);

DROP TABLE t1;

CREATE TABLE t1 (a1 VARBINARY(2) NOT NULL DEFAULT '0', PRIMARY KEY (a1));
CREATE TABLE t2 (a2 BINARY(2) default '0', INDEX (a2));
CREATE TABLE t3 (a3 BINARY(2) default '0');
INSERT INTO t1 VALUES (1),(2),(3),(4);
INSERT INTO t2 VALUES (1),(2),(3);
INSERT INTO t3 VALUES (1),(2),(3);
SELECT LEFT(t2.a2, 1) FROM t2,t3 WHERE t3.a3=t2.a2;
SELECT t1.a1, t1.a1 in (SELECT t2.a2 FROM t2,t3 WHERE t3.a3=t2.a2) FROM t1;
DROP TABLE t1,t2,t3;

CREATE TABLE t1 (a1 BINARY(3) PRIMARY KEY, b1 VARBINARY(3));
CREATE TABLE t2 (a2 VARBINARY(3) PRIMARY KEY);
CREATE TABLE t3 (a3 VARBINARY(3) PRIMARY KEY);
INSERT INTO t1 VALUES (1,10), (2,20), (3,30), (4,40);
INSERT INTO t2 VALUES (2), (3), (4), (5);
INSERT INTO t3 VALUES (10), (20), (30);
SELECT LEFT(t1.a1,1) FROM t1,t3 WHERE t1.b1=t3.a3;
SELECT a2 FROM t2 WHERE t2.a2 IN (SELECT t1.a1 FROM t1,t3 WHERE t1.b1=t3.a3);
DROP TABLE t1, t2, t3;

3154 3155 3156 3157 3158 3159 3160 3161 3162 3163 3164 3165 3166 3167 3168 3169 3170 3171 3172 3173 3174 3175 3176 3177 3178
#
# Bug #30788: Inconsistent retrieval of char/varchar
#

CREATE TABLE t1 (a CHAR(1), b VARCHAR(10));
INSERT INTO t1 VALUES ('a', 'aa');
INSERT INTO t1 VALUES ('a', 'aaa');
SELECT a,b FROM t1 WHERE b IN (SELECT a FROM t1);
CREATE INDEX I1 ON t1 (a);
CREATE INDEX I2 ON t1 (b);
EXPLAIN SELECT a,b FROM t1 WHERE b IN (SELECT a FROM t1);
SELECT a,b FROM t1 WHERE b IN (SELECT a FROM t1);

CREATE TABLE t2 (a VARCHAR(1), b VARCHAR(10));
INSERT INTO t2 SELECT * FROM t1;
CREATE INDEX I1 ON t2 (a);
CREATE INDEX I2 ON t2 (b);
EXPLAIN SELECT a,b FROM t2 WHERE b IN (SELECT a FROM t2);
SELECT a,b FROM t2 WHERE b IN (SELECT a FROM t2);
EXPLAIN
SELECT a,b FROM t1 WHERE b IN (SELECT a FROM t1 WHERE LENGTH(a)<500);
SELECT a,b FROM t1 WHERE b IN (SELECT a FROM t1 WHERE LENGTH(a)<500);

DROP TABLE t1,t2;

3179 3180 3181 3182 3183 3184 3185 3186 3187 3188 3189 3190 3191 3192 3193 3194 3195 3196 3197 3198 3199 3200 3201 3202 3203 3204 3205 3206 3207 3208 3209
#
# Bug #32400: Complex SELECT query returns correct result only on some
# occasions
#

CREATE TABLE t1(a INT, b INT);
INSERT INTO t1 VALUES (1,1), (1,2), (2,3), (2,4);

--error ER_BAD_FIELD_ERROR
EXPLAIN 
SELECT a AS out_a, MIN(b) FROM t1
WHERE b > (SELECT MIN(b) FROM t1 WHERE a = out_a)
GROUP BY a;

--error ER_BAD_FIELD_ERROR
SELECT a AS out_a, MIN(b) FROM t1
WHERE b > (SELECT MIN(b) FROM t1 WHERE a = out_a)
GROUP BY a;

EXPLAIN 
SELECT a AS out_a, MIN(b) FROM t1 t1_outer
WHERE b > (SELECT MIN(b) FROM t1 WHERE a = t1_outer.a)
GROUP BY a;

SELECT a AS out_a, MIN(b) FROM t1 t1_outer
WHERE b > (SELECT MIN(b) FROM t1 WHERE a = t1_outer.a)
GROUP BY a;

DROP TABLE t1;


3210 3211 3212 3213 3214 3215 3216 3217 3218 3219 3220 3221 3222 3223 3224 3225 3226 3227 3228 3229 3230 3231 3232
#
# Bug #32036: EXISTS within a WHERE clause with a UNION crashes MySQL 5.122
#

CREATE TABLE t1 (a INT);
CREATE TABLE t2 (a INT);

INSERT INTO t1 VALUES (1),(2);
INSERT INTO t2 VALUES (1),(2);

SELECT 2 FROM t1 WHERE EXISTS ((SELECT 1 FROM t2 WHERE t1.a=t2.a));
EXPLAIN EXTENDED
SELECT 2 FROM t1 WHERE EXISTS ((SELECT 1 FROM t2 WHERE t1.a=t2.a));


#TODO:not supported
--error ER_PARSE_ERROR
EXPLAIN EXTENDED
SELECT 2 FROM t1 WHERE EXISTS ((SELECT 1 FROM t2 WHERE t1.a=t2.a) UNION 
                               (SELECT 1 FROM t2 WHERE t1.a = t2.a));

DROP TABLE t1,t2;

3233

gkodinov/kgeorge@magare.gmz's avatar
gkodinov/kgeorge@magare.gmz committed
3234
--echo End of 5.0 tests.
3235

3236
#
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
3237 3238 3239 3240 3241 3242 3243 3244 3245 3246 3247 3248 3249 3250 3251 3252 3253 3254 3255 3256 3257 3258 3259
# Bug #27348: SET FUNCTION used in  a subquery from WHERE condition 
#  

CREATE TABLE t1 (a int, b int);
INSERT INTO t1 VALUES (2,22),(1,11),(2,22);

SELECT a FROM t1 WHERE (SELECT COUNT(b) FROM DUAL) > 0 GROUP BY a;
SELECT a FROM t1 WHERE (SELECT COUNT(b) FROM DUAL) > 1 GROUP BY a;

SELECT a FROM t1 t0
  WHERE (SELECT COUNT(t0.b) FROM t1 t WHERE t.b>20) GROUP BY a;

SET @@sql_mode='ansi';
--error 1111
SELECT a FROM t1 WHERE (SELECT COUNT(b) FROM DUAL) > 0 GROUP BY a;
--error 1111
SELECT a FROM t1 WHERE (SELECT COUNT(b) FROM DUAL) > 1 GROUP BY a;

--error 1111
SELECT a FROM t1 t0
  WHERE (SELECT COUNT(t0.b) FROM t1 t WHERE t.b>20) GROUP BY a;

SET @@sql_mode=default;
3260
DROP TABLE t1;
igor@olga.mysql.com's avatar
igor@olga.mysql.com committed
3261

3262 3263 3264 3265 3266 3267
# Bug#20835 (literal string with =any values)
#
CREATE TABLE t1 (s1 char(1));
INSERT INTO t1 VALUES ('a');
SELECT * FROM t1 WHERE _utf8'a' = ANY (SELECT s1 FROM t1);
DROP TABLE t1;