mirror of
				https://github.com/MariaDB/server.git
				synced 2025-10-31 19:06:14 +01:00 
			
		
		
		
	 9e1fb104a3
			
		
	
	
	9e1fb104a3
	
	
	
		
			
			-----BEGIN PGP SIGNATURE----- iQIzBAABCgAdFiEEF39AEP5WyjM2MAMF8WVvJMdM0dgFAmck77AACgkQ8WVvJMdM 0dgccQ/+Lls8fWt4D+gMPP7x+drJSO/IE/gZFt3ugbWF+/p3B2xXAs5AAE83wxEh QSbp4DCkb/9PnuakhLmzg0lFbxMUlh4rsJ1YyiuLB2J+YgKbAc36eQQf+rtYSipd DT5uRk36c9wOcOXo/mMv4APEvpPXBIBdIL4VvpKFbIOE7xT24Sp767zWXdXqrB1f JgOQdM2ct+bvSPC55oZ5p1kqyxwvd6K6+3RB3CIpwW9zrVSLg7enT3maLjj/761s jvlRae+Cv+r+Hit9XpmEH6n2FYVgIJ3o3WhdAHwN0kxKabXYTg7OCB7QxDZiUHI9 C/5goKmKaPB1PCQyuTQyLSyyK9a8nPfgn6tqw/p/ZKDQhKT9sWJv/5bSWecrVndx LLYifSTrFC/eXLzgPvCnNv/U8SjsZaAdMIKS681+qDJ0P5abghUIlGnMYTjYXuX1 1B6Vrr0bdrQ3V1CLB3tpkRjpUvicrsabtuAUAP65QnEG2G9UJXklOer+DE291Gsl f1I0o6C1zVGAOkUUD3QEYaHD8w7hlvyfKme5oXKUm3DOjaAar5UUKLdr6prxRZL4 ebhmGEy42Mf8fBYoeohIxmxgvv6h2Xd9xCukgPp8hFpqJGw8abg7JNZTTKH4h2IY J51RpD10h4eoi6WRn3opEcjexTGvZ+xNR7yYO5WxWw6VIre9IUA= =s+WW -----END PGP SIGNATURE----- Merge tag '11.4' into 11.6 MariaDB 11.4.4 release
		
			
				
	
	
		
			2186 lines
		
	
	
	
		
			72 KiB
		
	
	
	
		
			Text
		
	
	
	
	
	
			
		
		
	
	
			2186 lines
		
	
	
	
		
			72 KiB
		
	
	
	
		
			Text
		
	
	
	
	
	
| --source include/have_sequence.inc
 | |
| 
 | |
| # Initialise
 | |
| --disable_warnings
 | |
| drop table if exists t1,t2,t3;
 | |
| --enable_warnings
 | |
| 
 | |
| #
 | |
| # Simple test without tables
 | |
| 
 | |
| -- error 1111
 | |
| SELECT 1 FROM (SELECT 1) as a  GROUP BY SUM(1);
 | |
| 
 | |
| #
 | |
| # Test of group (Failed for Lars Hoss <lh@pbm.de>)
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   spID int(10) unsigned,
 | |
|   userID int(10) unsigned,
 | |
|   score smallint(5) unsigned,
 | |
|   lsg char(40),
 | |
|   date date
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,1,1,'','0000-00-00');
 | |
| INSERT INTO t1 VALUES (2,2,2,'','0000-00-00');
 | |
| INSERT INTO t1 VALUES (2,1,1,'','0000-00-00');
 | |
| INSERT INTO t1 VALUES (3,3,3,'','0000-00-00');
 | |
| 
 | |
| CREATE TABLE t2 (
 | |
|   userID int(10) unsigned NOT NULL auto_increment,
 | |
|   niName char(15),
 | |
|   passwd char(8),
 | |
|   mail char(50),
 | |
|   isAukt enum('N','Y') DEFAULT 'N',
 | |
|   vName char(30),
 | |
|   nName char(40),
 | |
|   adr char(60),
 | |
|   plz char(5),
 | |
|   ort char(35),
 | |
|   land char(20),
 | |
|   PRIMARY KEY (userID)
 | |
| );
 | |
| 
 | |
| INSERT INTO t2 VALUES (1,'name','pass','mail','Y','v','n','adr','1','1','1');
 | |
| INSERT INTO t2 VALUES (2,'name','pass','mail','Y','v','n','adr','1','1','1');
 | |
| INSERT INTO t2 VALUES (3,'name','pass','mail','Y','v','n','adr','1','1','1');
 | |
| INSERT INTO t2 VALUES (4,'name','pass','mail','Y','v','n','adr','1','1','1');
 | |
| INSERT INTO t2 VALUES (5,'name','pass','mail','Y','v','n','adr','1','1','1');
 | |
| 
 | |
| SELECT t2.userid, MIN(t1.score) FROM t1, t2 WHERE t1.userID=t2.userID GROUP BY t2.userid;
 | |
| SELECT t2.userid, MIN(t1.score) FROM t1, t2 WHERE t1.userID=t2.userID GROUP BY t2.userid ORDER BY NULL;
 | |
| SELECT t2.userid, MIN(t1.score) FROM t1, t2 WHERE t1.userID=t2.userID AND t1.spID=2  GROUP BY t2.userid;
 | |
| SELECT t2.userid, MIN(t1.score+0.0) FROM t1, t2 WHERE t1.userID=t2.userID AND t1.spID=2  GROUP BY t2.userid;
 | |
| SELECT t2.userid, MIN(t1.score+0.0) FROM t1, t2 WHERE t1.userID=t2.userID AND t1.spID=2  GROUP BY t2.userid ORDER BY NULL;
 | |
| EXPLAIN SELECT t2.userid, MIN(t1.score+0.0) FROM t1, t2 WHERE t1.userID=t2.userID AND t1.spID=2  GROUP BY t2.userid ORDER BY NULL;
 | |
| drop table t1,t2;
 | |
| 
 | |
| #
 | |
| # Bug in GROUP BY, by Nikki Chumakov <nikki@saddam.cityline.ru>
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   PID int(10) unsigned NOT NULL auto_increment,
 | |
|   payDate date DEFAULT '0000-00-00' NOT NULL,
 | |
|   recDate datetime DEFAULT '0000-00-00 00:00:00' NOT NULL,
 | |
|   URID int(10) unsigned DEFAULT '0' NOT NULL,
 | |
|   CRID int(10) unsigned DEFAULT '0' NOT NULL,
 | |
|   amount int(10) unsigned DEFAULT '0' NOT NULL,
 | |
|   operator int(10) unsigned,
 | |
|   method enum('unknown','cash','dealer','check','card','lazy','delayed','test') DEFAULT 'unknown' NOT NULL,
 | |
|   DIID int(10) unsigned,
 | |
|   reason char(1) binary DEFAULT '' NOT NULL,
 | |
|   code_id int(10) unsigned,
 | |
|   qty mediumint(8) unsigned DEFAULT '0' NOT NULL,
 | |
|   PRIMARY KEY (PID),
 | |
|   KEY URID (URID),
 | |
|   KEY reason (reason),
 | |
|   KEY method (method),
 | |
|   KEY payDate (payDate)
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,'1970-01-01','1997-10-17 00:00:00',2529,1,21000,11886,'check',0,'F',16200,6);
 | |
| 
 | |
| --error 1056
 | |
| SELECT COUNT(P.URID),SUM(P.amount),P.method, MIN(PP.recdate+0) > 19980501000000   AS IsNew FROM t1 AS P JOIN t1 as PP WHERE P.URID = PP.URID GROUP BY method,IsNew;
 | |
| 
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # Problem with GROUP BY + ORDER BY when no match
 | |
| # Tested with locking
 | |
| #
 | |
| --disable_service_connection
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   cid mediumint(9) NOT NULL auto_increment,
 | |
|   firstname varchar(32) DEFAULT '' NOT NULL,
 | |
|   surname varchar(32) DEFAULT '' NOT NULL,
 | |
|   PRIMARY KEY (cid)
 | |
| );
 | |
| INSERT INTO t1 VALUES (1,'That','Guy');
 | |
| INSERT INTO t1 VALUES (2,'Another','Gent');
 | |
| 
 | |
| CREATE TABLE t2 (
 | |
|   call_id mediumint(8) NOT NULL auto_increment,
 | |
|   contact_id mediumint(8) DEFAULT '0' NOT NULL,
 | |
|   PRIMARY KEY (call_id),
 | |
|   KEY contact_id (contact_id)
 | |
| );
 | |
| 
 | |
| lock tables t1 read,t2 write;
 | |
| 
 | |
| INSERT INTO t2 VALUES (10,2);
 | |
| INSERT INTO t2 VALUES (18,2);
 | |
| INSERT INTO t2 VALUES (62,2);
 | |
| INSERT INTO t2 VALUES (91,2);
 | |
| INSERT INTO t2 VALUES (92,2);
 | |
| 
 | |
| SELECT cid, CONCAT(firstname, ' ', surname), COUNT(call_id) FROM t1 LEFT JOIN t2 ON cid=contact_id WHERE firstname like '%foo%' GROUP BY cid;
 | |
| SELECT cid, CONCAT(firstname, ' ', surname), COUNT(call_id) FROM t1 LEFT JOIN t2 ON cid=contact_id WHERE firstname like '%foo%' GROUP BY cid ORDER BY NULL;
 | |
| SELECT HIGH_PRIORITY cid, CONCAT(firstname, ' ', surname), COUNT(call_id) FROM t1 LEFT JOIN t2 ON cid=contact_id WHERE firstname like '%foo%' GROUP BY cid ORDER BY surname, firstname;
 | |
| 
 | |
| drop table t2;
 | |
| unlock tables;
 | |
| drop table t1;
 | |
| 
 | |
| --enable_service_connection
 | |
| #
 | |
| # Test of group by bug in bugzilla
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   bug_id mediumint(9) NOT NULL auto_increment,
 | |
|   groupset bigint(20) DEFAULT '0' NOT NULL,
 | |
|   assigned_to mediumint(9) DEFAULT '0' NOT NULL,
 | |
|   bug_file_loc text,
 | |
|   bug_severity enum('blocker','critical','major','normal','minor','trivial','enhancement') DEFAULT 'blocker' NOT NULL,
 | |
|   bug_status enum('','NEW','ASSIGNED','REOPENED','RESOLVED','VERIFIED','CLOSED') DEFAULT 'NEW' NOT NULL,
 | |
|   creation_ts datetime DEFAULT '0000-00-00 00:00:00' NOT NULL,
 | |
|   delta_ts timestamp,
 | |
|   short_desc mediumtext,
 | |
|   long_desc mediumtext,
 | |
|   op_sys enum('All','Windows 3.1','Windows 95','Windows 98','Windows NT','Windows 2000','Linux','other') DEFAULT 'All' NOT NULL,
 | |
|   priority enum('P1','P2','P3','P4','P5') DEFAULT 'P1' NOT NULL,
 | |
|   product varchar(64) DEFAULT '' NOT NULL,
 | |
|   rep_platform enum('All','PC','VTD-8','Other'),
 | |
|   reporter mediumint(9) DEFAULT '0' NOT NULL,
 | |
|   version varchar(16) DEFAULT '' NOT NULL,
 | |
|   component varchar(50) DEFAULT '' NOT NULL,
 | |
|   resolution enum('','FIXED','INVALID','WONTFIX','LATER','REMIND','DUPLICATE','WORKSFORME') DEFAULT '' NOT NULL,
 | |
|   target_milestone varchar(20) DEFAULT '' NOT NULL,
 | |
|   qa_contact mediumint(9) DEFAULT '0' NOT NULL,
 | |
|   status_whiteboard mediumtext NOT NULL,
 | |
|   votes mediumint(9) DEFAULT '0' NOT NULL,
 | |
|   PRIMARY KEY (bug_id),
 | |
|   KEY assigned_to (assigned_to),
 | |
|   KEY creation_ts (creation_ts),
 | |
|   KEY delta_ts (delta_ts),
 | |
|   KEY bug_severity (bug_severity),
 | |
|   KEY bug_status (bug_status),
 | |
|   KEY op_sys (op_sys),
 | |
|   KEY priority (priority),
 | |
|   KEY product (product),
 | |
|   KEY reporter (reporter),
 | |
|   KEY version (version),
 | |
|   KEY component (component),
 | |
|   KEY resolution (resolution),
 | |
|   KEY target_milestone (target_milestone),
 | |
|   KEY qa_contact (qa_contact),
 | |
|   KEY votes (votes)
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,0,0,'','normal','','2000-02-10 09:25:12',20000321114747,'','','Linux','P1','TestProduct','PC',3,'other','TestComponent','','M1',0,'',0);
 | |
| INSERT INTO t1 VALUES (9,0,0,'','enhancement','','2000-03-10 11:49:36',20000321114747,'','','All','P5','AAAAA','PC',3,'2.00 CD - Pre','BBBBBBBBBBBBB - conversion','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (10,0,0,'','enhancement','','2000-03-10 18:10:16',20000321114747,'','','All','P4','AAAAA','PC',3,'2.00 CD - Pre','BBBBBBBBBBBBB - conversion','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (7,0,0,'','critical','','2000-03-09 10:50:21',20000321114747,'','','All','P1','AAAAA','PC',3,'2.00 CD - Pre','BBBBBBBBBBBBB - generic','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (6,0,0,'','normal','','2000-03-09 10:42:44',20000321114747,'','','All','P2','AAAAA','PC',3,'2.00 CD - Pre','kkkkkkkkkkk lllllllllll','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (8,0,0,'','major','','2000-03-09 11:32:14',20000321114747,'','','All','P3','AAAAA','PC',3,'2.00 CD - Pre','kkkkkkkkkkk lllllllllll','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (5,0,0,'','enhancement','','2000-03-09 10:38:59',20000321114747,'','','All','P5','CCC/CCCCCC','PC',5,'7.00','Administration','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (4,0,0,'','normal','','2000-03-08 18:32:14',20000321114747,'','','other','P2','TestProduct','Other',3,'other','TestComponent2','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (3,0,0,'','normal','','2000-03-08 18:30:52',20000321114747,'','','other','P2','TestProduct','Other',3,'other','TestComponent','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (2,0,0,'','enhancement','','2000-03-08 18:24:51',20000321114747,'','','All','P2','TestProduct','Other',4,'other','TestComponent2','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (11,0,0,'','blocker','','2000-03-13 09:43:41',20000321114747,'','','All','P2','CCC/CCCCCC','PC',5,'7.00','DDDDDDDDD','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (12,0,0,'','normal','','2000-03-13 16:14:31',20000321114747,'','','All','P2','AAAAA','PC',3,'2.00 CD - Pre','kkkkkkkkkkk lllllllllll','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (13,0,0,'','normal','','2000-03-15 16:20:44',20000321114747,'','','other','P2','TestProduct','Other',3,'other','TestComponent','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (14,0,0,'','blocker','','2000-03-15 18:13:47',20000321114747,'','','All','P1','AAAAA','PC',3,'2.00 CD - Pre','BBBBBBBBBBBBB - generic','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (15,0,0,'','minor','','2000-03-16 18:03:28',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','DDDDDDDDD','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (16,0,0,'','normal','','2000-03-16 18:33:41',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','Administration','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (17,0,0,'','normal','','2000-03-16 18:34:18',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','Administration','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (18,0,0,'','normal','','2000-03-16 18:34:56',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','Administration','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (19,0,0,'','enhancement','','2000-03-16 18:35:34',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','Administration','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (20,0,0,'','enhancement','','2000-03-16 18:36:23',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','Administration','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (21,0,0,'','enhancement','','2000-03-16 18:37:23',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','Administration','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (22,0,0,'','enhancement','','2000-03-16 18:38:16',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','Administration','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (23,0,0,'','normal','','2000-03-16 18:58:12',20000321114747,'','','All','P2','CCC/CCCCCC','Other',5,'7.00','DDDDDDDDD','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (24,0,0,'','normal','','2000-03-17 11:08:10',20000321114747,'','','All','P2','AAAAAAAA-AAA','PC',3,'2.8','Web Interface','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (25,0,0,'','normal','','2000-03-17 11:10:45',20000321114747,'','','All','P2','AAAAAAAA-AAA','PC',3,'2.8','Web Interface','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (26,0,0,'','normal','','2000-03-17 11:15:47',20000321114747,'','','All','P2','AAAAAAAA-AAA','PC',3,'2.8','Web Interface','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (27,0,0,'','normal','','2000-03-17 17:45:41',20000321114747,'','','All','P2','CCC/CCCCCC','PC',5,'7.00','DDDDDDDDD','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (28,0,0,'','normal','','2000-03-20 09:51:45',20000321114747,'','','Windows NT','P2','TestProduct','PC',8,'other','TestComponent','','',0,'',0);
 | |
| INSERT INTO t1 VALUES (29,0,0,'','normal','','2000-03-20 11:15:09',20000321114747,'','','All','P5','AAAAAAAA-AAA','PC',3,'2.8','Web Interface','','',0,'',0);
 | |
| CREATE TABLE t2 (
 | |
|   value tinytext,
 | |
|   program varchar(64),
 | |
|   initialowner tinytext NOT NULL,
 | |
|   initialqacontact tinytext NOT NULL,
 | |
|   description mediumtext NOT NULL
 | |
| );
 | |
| 
 | |
| INSERT INTO t2 VALUES ('TestComponent','TestProduct','id0001','','');
 | |
| INSERT INTO t2 VALUES ('BBBBBBBBBBBBB - conversion','AAAAA','id0001','','');
 | |
| INSERT INTO t2 VALUES ('BBBBBBBBBBBBB - generic','AAAAA','id0001','','');
 | |
| INSERT INTO t2 VALUES ('TestComponent2','TestProduct','id0001','','');
 | |
| INSERT INTO t2 VALUES ('BBBBBBBBBBBBB - eeeeeeeee','AAAAA','id0001','','');
 | |
| INSERT INTO t2 VALUES ('kkkkkkkkkkk lllllllllll','AAAAA','id0001','','');
 | |
| INSERT INTO t2 VALUES ('Test Procedures','AAAAA','id0001','','');
 | |
| INSERT INTO t2 VALUES ('Documentation','AAAAA','id0003','','');
 | |
| INSERT INTO t2 VALUES ('DDDDDDDDD','CCC/CCCCCC','id0002','','');
 | |
| INSERT INTO t2 VALUES ('Eeeeeeee Lite','CCC/CCCCCC','id0002','','');
 | |
| INSERT INTO t2 VALUES ('Eeeeeeee Full','CCC/CCCCCC','id0002','','');
 | |
| INSERT INTO t2 VALUES ('Administration','CCC/CCCCCC','id0002','','');
 | |
| INSERT INTO t2 VALUES ('Distribution','CCC/CCCCCC','id0002','','');
 | |
| INSERT INTO t2 VALUES ('Setup','CCC/CCCCCC','id0002','','');
 | |
| INSERT INTO t2 VALUES ('Unspecified','CCC/CCCCCC','id0002','','');
 | |
| INSERT INTO t2 VALUES ('Web Interface','AAAAAAAA-AAA','id0001','','');
 | |
| INSERT INTO t2 VALUES ('Host communication','AAAAA','id0001','','');
 | |
| select value,description,bug_id from t2 left join t1 on t2.program=t1.product and t2.value=t1.component where program="AAAAA";
 | |
| select value,description,COUNT(bug_id) from t2 left join t1 on t2.program=t1.product and t2.value=t1.component where program="AAAAA" group by value;
 | |
| select value,description,COUNT(bug_id) from t2 left join t1 on t2.program=t1.product and t2.value=t1.component where program="AAAAA" group by value having COUNT(bug_id) IN (0,2);
 | |
| 
 | |
| drop table t1,t2;
 | |
| 
 | |
| #
 | |
| # Problem with functions and group functions when no matching rows
 | |
| #
 | |
| 
 | |
| create table t1 (foo int);
 | |
| insert into t1 values (1);
 | |
| select 1+1, "a",count(*) from t1 where foo in (2);
 | |
| insert into t1 values (1);
 | |
| select 1+1,"a",count(*) from t1 where foo in (2);
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # Test GROUP BY DESC
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   spID int(10) unsigned,
 | |
|   userID int(10) unsigned,
 | |
|   score smallint(5) unsigned,
 | |
|   key (spid),
 | |
|   key (score)
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,1,1),(2,2,2),(2,1,1),(3,3,3),(4,3,3),(5,3,3),(6,3,3),(7,3,3);
 | |
| explain select userid,count(*) from t1 group by userid desc;
 | |
| explain select userid,count(*) from t1 group by userid desc order by null;
 | |
| select userid,count(*) from t1 group by userid desc;
 | |
| select userid,count(*) from t1 group by userid desc having (count(*)+1) IN (4,3);
 | |
| select userid,count(*) from t1 group by userid desc having 3  IN (1,COUNT(*));
 | |
| explain select spid,count(*) from t1 where spid between 1 and 2 group by spid desc;
 | |
| explain select spid,count(*) from t1 where spid between 1 and 2 group by spid;
 | |
| explain select spid,count(*) from t1 where spid between 1 and 2 group by spid order by null;
 | |
| select spid,count(*) from t1 where spid between 1 and 2 group by spid;
 | |
| select spid,count(*) from t1 where spid between 1 and 2 group by spid desc;
 | |
| explain extended select sql_big_result spid,sum(userid) from t1 group by spid desc;
 | |
| explain select sql_big_result spid,sum(userid) from t1 group by spid desc order by null;
 | |
| select sql_big_result spid,sum(userid) from t1 group by spid desc;
 | |
| explain select sql_big_result score,count(*) from t1 group by score desc;
 | |
| explain select sql_big_result score,count(*) from t1 group by score desc order by null;
 | |
| select sql_big_result score,count(*) from t1 group by score desc;
 | |
| drop table t1;
 | |
| 
 | |
| # not purely group_by bug, but group_by is involved...
 | |
| 
 | |
| create table t1 (a date default null, b date default null);
 | |
| insert t1 values ('1999-10-01','2000-01-10'), ('1997-01-01','1998-10-01');
 | |
| select a,min(b) c,count(distinct rand()) from t1 group by a having c<a + interval 1 day;
 | |
| drop table t1;
 | |
| 
 | |
| # Compare with hash keys
 | |
| 
 | |
| --disable_view_protocol
 | |
| CREATE TABLE t1 (a char(1));
 | |
| INSERT INTO t1 VALUES ('A'),('B'),('A'),('B'),('A'),('B'),(NULL),('a'),('b'),(NULL),('A'),('B'),(NULL);
 | |
| flush status;
 | |
| --disable_cursor_protocol
 | |
| --disable_ps2_protocol
 | |
| SELECT a FROM t1 GROUP BY a;
 | |
| SELECT a,count(*) FROM t1 GROUP BY a;
 | |
| SELECT a FROM t1 GROUP BY binary a;
 | |
| SELECT a,count(*) FROM t1 GROUP BY binary a;
 | |
| SELECT binary a FROM t1 GROUP BY 1;
 | |
| SELECT binary a,count(*) FROM t1 GROUP BY 1;
 | |
| --enable_ps2_protocol
 | |
| --enable_cursor_protocol
 | |
| --disable_ps_protocol
 | |
| show status like 'Created%tables';
 | |
| --enable_ps_protocol
 | |
| # Do the same tests with on-disk temporary tables
 | |
| set tmp_memory_table_size=0;
 | |
| --disable_cursor_protocol
 | |
| --disable_ps2_protocol
 | |
| SELECT a FROM t1 GROUP BY a;
 | |
| SELECT a,count(*) FROM t1 GROUP BY a;
 | |
| SELECT a FROM t1 GROUP BY binary a;
 | |
| SELECT a,count(*) FROM t1 GROUP BY binary a;
 | |
| SELECT binary a FROM t1 GROUP BY 1;
 | |
| SELECT binary a,count(*) FROM t1 GROUP BY 1;
 | |
| --enable_ps2_protocol
 | |
| --enable_cursor_protocol
 | |
| --disable_ps_protocol
 | |
| show status like 'Created%tables';
 | |
| --enable_ps_protocol
 | |
| set tmp_memory_table_size=default;
 | |
| drop table t1;
 | |
| --enable_view_protocol
 | |
| 
 | |
| #
 | |
| # Test of key >= 256 bytes
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   `a` char(193) default NULL,
 | |
|   `b` char(63) default NULL
 | |
| );
 | |
| INSERT INTO t1 VALUES ('abc','def'),('hij','klm');
 | |
| SELECT CONCAT(a, b) FROM t1 GROUP BY 1;
 | |
| SELECT CONCAT(a, b),count(*) FROM t1 GROUP BY 1;
 | |
| SELECT CONCAT(a, b),count(distinct a) FROM t1 GROUP BY 1;
 | |
| SELECT 1 FROM t1 GROUP BY CONCAT(a, b);
 | |
| INSERT INTO t1 values ('hij','klm');
 | |
| SELECT CONCAT(a, b),count(*) FROM t1 GROUP BY 1;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #
 | |
| # Test problem with ORDER BY on a SUM() column
 | |
| #
 | |
| 
 | |
| create table t1 (One int unsigned, Two int unsigned, Three int unsigned, Four int unsigned);
 | |
| insert into t1 values (1,2,1,4),(1,2,2,4),(1,2,3,4),(1,2,4,4),(1,1,1,4),(1,1,2,4),(1,1,3,4),(1,1,4,4),(1,3,1,4),(1,3,2,4),(1,3,3,4),(1,3,4,4);
 | |
| select One, Two, sum(Four) from t1 group by One,Two;
 | |
| drop table t1;
 | |
| 
 | |
| create table t1 (id integer primary key not null auto_increment, gender char(1));
 | |
| insert into t1 values (NULL, 'M'), (NULL, 'F'),(NULL, 'F'),(NULL, 'F'),(NULL, 'M');
 | |
| create table t2 (user_id integer not null, date date);
 | |
| insert into t2 values (1, '2002-06-09'),(2, '2002-06-09'),(1, '2002-06-09'),(3, '2002-06-09'),(4, '2002-06-09'),(4, '2002-06-09');
 | |
| select u.gender as gender, count(distinct  u.id) as dist_count, (count(distinct u.id)/5*100) as percentage from t1 u, t2 l where l.user_id = u.id group by u.gender;
 | |
| select u.gender as  gender, count(distinct  u.id) as dist_count, (count(distinct u.id)/5*100) as percentage from t1 u, t2 l where l.user_id = u.id group by u.gender  order by percentage;
 | |
| drop table t1,t2;
 | |
| 
 | |
| #
 | |
| # The GROUP BY returned rows in wrong order in 3.23.51
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (ID1 int, ID2 int, ID int NOT NULL AUTO_INCREMENT,PRIMARY KEY(ID
 | |
| ));
 | |
| insert into t1 values (1,244,NULL),(2,243,NULL),(134,223,NULL),(185,186,NULL);
 | |
| SET @save_optimizer_switch=@@optimizer_switch;
 | |
| SET optimizer_switch='outer_join_with_cache=off';
 | |
| select S.ID as xID, S.ID1 as xID1 from t1 as S left join t1 as yS  on S.ID1 between yS.ID1 and yS.ID2;
 | |
| select S.ID as xID, S.ID1 as xID1, repeat('*',count(distinct yS.ID)) as Level from t1 as S left join t1 as yS  on S.ID1 between yS.ID1 and yS.ID2 group by xID order by xID1;
 | |
| SET optimizer_switch=@save_optimizer_switch;
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # Problem with MAX and LEFT JOIN
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   pid int(11) unsigned NOT NULL default '0',
 | |
|   c1id int(11) unsigned default NULL,
 | |
|   c2id int(11) unsigned default NULL,
 | |
|   value int(11) unsigned NOT NULL default '0',
 | |
|   UNIQUE KEY pid2 (pid,c1id,c2id),
 | |
|   UNIQUE KEY pid (pid,value)
 | |
| ) ENGINE=MyISAM;
 | |
| 
 | |
| INSERT INTO t1 VALUES (1, 1, NULL, 1),(1, 2, NULL, 2),(1, NULL, 3, 3),(1, 4, NULL, 4),(1, 5, NULL, 5);
 | |
| 
 | |
| CREATE TABLE t2 (
 | |
|   id int(11) unsigned NOT NULL default '0',
 | |
|   active enum('Yes','No') NOT NULL default 'Yes',
 | |
|   PRIMARY KEY  (id)
 | |
| ) ENGINE=MyISAM;
 | |
| 
 | |
| INSERT INTO t2 VALUES (1, 'Yes'),(2, 'No'),(4, 'Yes'),(5, 'No');
 | |
| 
 | |
| CREATE TABLE t3 (
 | |
|   id int(11) unsigned NOT NULL default '0',
 | |
|   active enum('Yes','No') NOT NULL default 'Yes',
 | |
|   PRIMARY KEY  (id)
 | |
| );
 | |
| INSERT INTO t3 VALUES (3, 'Yes');
 | |
| 
 | |
| select * from t1 AS m LEFT JOIN t2 AS c1 ON m.c1id = 
 | |
| c1.id AND c1.active = 'Yes' LEFT JOIN t3 AS c2 ON m.c2id = c2.id AND 
 | |
| c2.active = 'Yes' WHERE m.pid=1  AND (c1.id IS NOT NULL OR c2.id IS NOT NULL);
 | |
| select max(value) from t1 AS m LEFT JOIN t2 AS c1 ON 
 | |
| m.c1id = c1.id AND c1.active = 'Yes' LEFT JOIN t3 AS c2 ON m.c2id = 
 | |
| c2.id AND c2.active = 'Yes' WHERE m.pid=1  AND (c1.id IS NOT NULL OR c2.id IS 
 | |
| NOT NULL);
 | |
| drop table t1,t2,t3;
 | |
| 
 | |
| #
 | |
| # Test bug in GROUP BY on BLOB that is NULL or empty
 | |
| #
 | |
| 
 | |
| create table t1 (a blob null);
 | |
| insert into t1 values (NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(NULL),(""),(""),(""),("b");
 | |
| select a,count(*) from t1 group by a;
 | |
| set tmp_memory_table_size=0;
 | |
| select a,count(*) from t1 group by a;
 | |
| drop table t1;
 | |
| set tmp_memory_table_size=default;
 | |
| 
 | |
| #
 | |
| # Test of GROUP BY ... ORDER BY NULL optimization
 | |
| #
 | |
| 
 | |
| SET @save_optimizer_use_condition_selectivity=@@optimizer_use_condition_selectivity,@save_optimizer_switch=@@optimizer_switch;
 | |
| SET optimizer_switch='outer_join_with_cache=off',@@optimizer_use_condition_selectivity=4;
 | |
| create table t1 (a int not null, b int not null);
 | |
| insert into t1 values (1,1),(1,2),(3,1),(3,2),(2,2),(2,1);
 | |
| create table t2 (a int not null, b int not null, key(a));
 | |
| insert into t2 values (1,3),(3,1),(2,2),(1,1);
 | |
| select t1.a,t2.b from t1,t2 where t1.a=t2.a group by t1.a,t2.b;
 | |
| --sorted_result
 | |
| select t1.a,t2.b from t1,t2 where t1.a=t2.a group by t1.a,t2.b ORDER BY NULL;
 | |
| explain select t1.a,t2.b from t1,t2 where t1.a=t2.a group by t1.a,t2.b;
 | |
| explain select t1.a,t2.b from t1,t2 where t1.a=t2.a group by t1.a,t2.b ORDER BY NULL;
 | |
| drop table t1,t2;
 | |
| SET @@optimizer_use_condition_selectivity=@save_optimizer_use_condition_selectivity,@@optimizer_switch=@save_optimizer_switch;
 | |
| 
 | |
| 
 | |
| #
 | |
| # group function arguments in some functions
 | |
| #
 | |
| 
 | |
| create table t1 (a int, b int);
 | |
| insert into t1 values (1, 4),(10, 40),(1, 4),(10, 43),(1, 4),(10, 41),(1, 4),(10, 43),(1, 4);
 | |
| select a, MAX(b), INTERVAL (MAX(b), 1,3,10,30,39,40,50,60,100,1000) from t1 group by a;
 | |
| select a, MAX(b), CASE MAX(b) when 4 then 4 when 43 then 43 else 0 end from t1 group by a;
 | |
| select a, MAX(b), FIELD(MAX(b), '43', '4', '5') from t1 group by a;
 | |
| select a, MAX(b), CONCAT_WS(MAX(b), '43', '4', '5') from t1 group by a;
 | |
| select a, MAX(b), ELT(MAX(b), 'a', 'b', 'c', 'd', 'e', 'f') from t1 group by a;
 | |
| select a, MAX(b), MAKE_SET(MAX(b), 'a', 'b', 'c', 'd', 'e', 'f', 'g', 'h') from t1 group by a;
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # Problem with group by and alias
 | |
| #
 | |
| 
 | |
| create table t1 (id int not null, qty int not null);
 | |
| insert into t1 values (1,2),(1,3),(2,4),(2,5);
 | |
| select id, sum(qty) as sqty, count(qty) as cqty from t1 group by id having sum(qty)>2 and cqty>1;
 | |
| select id, sum(qty) as sqty from t1 group by id having sqty>2 and count(qty)>1;
 | |
| select id, sum(qty) as sqty, count(qty) as cqty from t1 group by id having sqty>2 and cqty>1;
 | |
| select id, sum(qty) as sqty, count(qty) as cqty from t1 group by id having sum(qty)>2 and count(qty)>1;
 | |
| select count(*), case interval(qty,2,3,4,5,6,7,8) when -1 then NULL when 0 then "zero" when 1 then "one" when 2 then "two" end as category from t1 group by category;
 | |
| select count(*), interval(qty,2,3,4,5,6,7,8) as category from t1 group by category;
 | |
| drop table t1;
 | |
| #
 | |
| # Tests for bug #1355: 'Using filesort' is missing in EXPLAIN when ORDER BY
 | |
| # NULL is used.
 | |
| #
 | |
| CREATE TABLE t1 (
 | |
|   userid int(10) unsigned,
 | |
|   score smallint(5) unsigned,
 | |
|   key (score)
 | |
| );
 | |
| INSERT INTO t1 VALUES (1,1),(2,2),(1,1),(3,3),(3,3),(3,3),(3,3),(3,3);
 | |
| # Here we select unordered GROUP BY into a temporary talbe, 
 | |
| # and then sort it with filesort (GROUP BY in MySQL 
 | |
| # implies sorted order of results)
 | |
| SELECT userid,count(*) FROM t1 GROUP BY userid DESC;
 | |
| EXPLAIN SELECT userid,count(*) FROM t1 GROUP BY userid DESC;
 | |
| DROP TABLE t1;
 | |
| CREATE TABLE t1 (
 | |
|   i int(11) default NULL,
 | |
|   j int(11) default NULL
 | |
| );
 | |
| INSERT INTO t1 VALUES (1,2),(2,3),(4,5),(3,5),(1,5),(23,5);
 | |
| SELECT i, COUNT(DISTINCT(i)) FROM t1 GROUP BY j ORDER BY NULL;
 | |
| explain SELECT i, COUNT(DISTINCT(i)) FROM t1 GROUP BY j ORDER BY NULL;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #Test for BUG#6976: Aggregate functions have incorrect NULL-ness
 | |
| create table t1 (a int);
 | |
| insert into t1 values(null);
 | |
| select min(a) is null from t1;
 | |
| select min(a) is null or null from t1;
 | |
| select 1 and min(a) is null from t1;
 | |
| drop table t1;
 | |
| 
 | |
| # Test for BUG#5400: GROUP_CONCAT returns everything twice.
 | |
| create table t1 ( col1 int, col2 int );
 | |
| insert into t1 values (1,1),(1,2),(1,3),(2,1),(2,2);
 | |
| select group_concat( distinct col1 ) as alias from t1
 | |
|   group by col2 having alias like '%';
 | |
| 
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # Test BUG#8216 when referring in HAVING to n alias which is rand() function
 | |
| #
 | |
| 
 | |
| create table t1 (a integer, b integer, c integer);
 | |
| insert into t1 (a,b) values (1,2),(1,3),(2,5);
 | |
| select a, 0.1*0+1 r2, sum(1) r1 from t1 where a = 1 group  by a having r1>1 and r2=1;
 | |
| # rand(100)*10 will be < 2 only for the first row (of 6)
 | |
| select a, round(rand(100)*10) r2, sum(1) r1 from t1 where a = 1 group by a having r1>1 and r2<=2;
 | |
| select a, round(rand(100)*10) r2, sum(1) r1 from t1  group by a having r1>1 and r2<=2;
 | |
| select a,sum(b) from t1 where a=1 group by c;
 | |
| select a*sum(b) from t1 where a=1 group by c;
 | |
| select a*sum(b) as f1 from t1 where a=1 group by c having f1 <= 10;
 | |
| select a,a*sum(b) as f1 from t1 where a=1 group by c having a*sum(b)+0 <= 10;
 | |
| select sum(a)*sum(b) from t1 where a=1 group by c;
 | |
| select a,sum(b) from t1 where a=1 group by c having a=1;
 | |
| select a as d,sum(b) from t1 where a=1 group by c having d=1;
 | |
| select sum(a)*sum(b) as d from t1 where a=1 group by c having d > 0;
 | |
| drop table t1;
 | |
| 
 | |
| # Test for BUG#9213 GROUP BY query on utf-8 key returns wrong results
 | |
| create table t1(a int);
 | |
| insert into t1 values (0),(1),(2),(3),(4),(5),(6),(8),(9);
 | |
| create table t2 (
 | |
|   a int,
 | |
|   b varchar(200) NOT NULL,
 | |
|   c varchar(50) NOT NULL,
 | |
|   d varchar(100) NOT NULL,
 | |
|   primary key (a,b(132),c,d),
 | |
|   key a (a,b)
 | |
| ) charset=utf8;
 | |
| 
 | |
| insert into t2 select 
 | |
|    x3.a,  -- 3
 | |
|    concat('val-', x3.a + 3*x4.a), -- 12
 | |
|    concat('val-', @a:=x3.a + 3*x4.a + 12*C.a), -- 120
 | |
|    concat('val-', @a + 120*D.a)
 | |
| from t1 x3, t1 x4, t1 C, t1 D where x3.a < 3 and x4.a < 4 and D.a < 4;
 | |
| 
 | |
| delete from t2  where a = 2 and b = 'val-2' order by a,b,c,d limit 30;
 | |
| 
 | |
| explain select c from t2 where a = 2 and b = 'val-2' group by c;
 | |
| select c from t2 where a = 2 and b = 'val-2' group by c;
 | |
| drop table t1,t2;
 | |
| 
 | |
| # Test for BUG#9298 "Wrong handling of int4 unsigned columns in GROUP functions"
 | |
| # (the actual problem was with protocol code, not GROUP BY)
 | |
| create table t1 (b int4 unsigned not null);
 | |
| insert into t1 values(3000000000);
 | |
| select * from t1;
 | |
| select min(b) from t1;
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # Test for bug #11088: GROUP BY a BLOB column with COUNT(DISTINCT column1) 
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (id int PRIMARY KEY, user_id int, hostname longtext);
 | |
| 
 | |
| INSERT INTO t1 VALUES
 | |
|   (1, 7, 'cache-dtc-af05.proxy.aol.com'),
 | |
|   (2, 3, 'what.ever.com'),
 | |
|   (3, 7, 'cache-dtc-af05.proxy.aol.com'),
 | |
|   (4, 7, 'cache-dtc-af05.proxy.aol.com');
 | |
| 
 | |
| SELECT hostname, COUNT(DISTINCT user_id) as no FROM t1
 | |
|   WHERE hostname LIKE '%aol%'
 | |
|     GROUP BY hostname;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #
 | |
| # Test for bug #8614: GROUP BY 'const' with DISTINCT  
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (a  int, b int);
 | |
| INSERT INTO t1 VALUES (1,2), (1,3);
 | |
| SELECT a, b FROM t1 GROUP BY 'const';
 | |
| SELECT DISTINCT a, b FROM t1 GROUP BY 'const';
 | |
| 
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #
 | |
| # Test for bug #11385: GROUP BY for datetime converted to decimals  
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (id INT, dt DATETIME);
 | |
| INSERT INTO t1 VALUES ( 1, '2005-05-01 12:30:00' );
 | |
| INSERT INTO t1 VALUES ( 1, '2005-05-01 12:30:00' );
 | |
| INSERT INTO t1 VALUES ( 1, '2005-05-01 12:30:00' );
 | |
| INSERT INTO t1 VALUES ( 1, '2005-05-01 12:30:00' );
 | |
| SELECT dt DIV 1 AS f, id FROM t1 GROUP BY f;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #
 | |
| # Test for bug #11295: GROUP BY a BLOB column with COUNT(DISTINCT column1) 
 | |
| #                      when the BLOB column takes NULL values
 | |
| # 
 | |
| 
 | |
| CREATE TABLE t1 (id varchar(20) NOT NULL);
 | |
| INSERT INTO t1 VALUES ('trans1'), ('trans2');
 | |
| CREATE TABLE t2 (id varchar(20) NOT NULL, err_comment blob NOT NULL);
 | |
| INSERT INTO t2 VALUES ('trans1', 'a problem');
 | |
| SELECT COUNT(DISTINCT(t1.id)), LEFT(err_comment, 256) AS comment
 | |
|   FROM t1 LEFT JOIN t2 ON t1.id=t2.id GROUP BY comment;
 | |
| 
 | |
| DROP TABLE t1, t2;
 | |
| 
 | |
| #
 | |
| # Bug #12266 GROUP BY expression on DATE column produces result with
 | |
| #            reduced length
 | |
| #
 | |
| create table t1 (f1 date);
 | |
| insert into t1 values('2005-06-06');
 | |
| insert into t1 values('2005-06-06'); 
 | |
| select date(left(f1+0,8)) from t1 group by 1;
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # Test for bug #11414: crash on Windows for a simple GROUP BY query 
 | |
| #  
 | |
|                     
 | |
| CREATE TABLE t1 (n int);
 | |
| INSERT INTO t1 VALUES (1);
 | |
| SELECT n+1 AS n FROM t1 GROUP BY n;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #
 | |
| # BUG#12695: Item_func_isnull::update_used_tables
 | |
| # did not update const_item_cache
 | |
| #
 | |
| create table t1(f1 varchar(5) key);
 | |
| insert into t1 values (1),(2);
 | |
| select sql_buffer_result max(f1) is null from t1;
 | |
| select sql_buffer_result max(f1)+1 from t1;
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # BUG#14019-4.1-opt
 | |
| #
 | |
| CREATE TABLE t1(a INT); INSERT INTO t1 VALUES (1),(2);
 | |
| 
 | |
| SELECT a FROM t1 GROUP BY 'a';
 | |
| SELECT a FROM t1 GROUP BY "a";
 | |
| SELECT a FROM t1 GROUP BY `a`;
 | |
| 
 | |
| --disable_service_connection
 | |
| 
 | |
| set sql_mode=ANSI_QUOTES;
 | |
| SELECT a FROM t1 GROUP BY "a";
 | |
| SELECT a FROM t1 GROUP BY 'a';
 | |
| SELECT a FROM t1 GROUP BY `a`;
 | |
| set sql_mode='';
 | |
| 
 | |
| --enable_service_connection
 | |
| 
 | |
| SELECT a FROM t1 HAVING 'a' > 1;
 | |
| SELECT a FROM t1 HAVING "a" > 1;
 | |
| SELECT a FROM t1 HAVING `a` > 1;
 | |
| 
 | |
| SELECT a FROM t1 ORDER BY 'a' DESC;
 | |
| SELECT a FROM t1 ORDER BY "a" DESC;
 | |
| SELECT a FROM t1 ORDER BY `a` DESC;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #
 | |
| # Bug #29717 INSERT INTO SELECT inserts values even if SELECT statement itself
 | |
| # returns empty
 | |
| # 
 | |
| CREATE TABLE t1 (
 | |
|     f1 int(10) unsigned NOT NULL auto_increment primary key,
 | |
|     f2 varchar(100) NOT NULL default ''
 | |
| );
 | |
| CREATE TABLE t2 (
 | |
|     f1 varchar(10) NOT NULL default '',
 | |
|     f2 char(3) NOT NULL default '',
 | |
|     PRIMARY KEY  (`f1`),
 | |
|     KEY `k1` (`f2`,`f1`)
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 values(NULL, '');
 | |
| INSERT INTO `t2` VALUES ('486878','WDT'),('486910','WDT');
 | |
| SELECT SQL_BUFFER_RESULT avg(t2.f1) FROM t1, t2 where t2.f2 = 'SIR' GROUP BY t1.f1;
 | |
| SELECT avg(t2.f1) FROM t1, t2 where t2.f2 = 'SIR' GROUP BY t1.f1;
 | |
| DROP TABLE t1, t2;
 | |
| 
 | |
| 
 | |
| # End of 4.1 tests
 | |
| 
 | |
| #
 | |
| # Bug#11211: Ambiguous column reference in GROUP BY.
 | |
| #
 | |
| 
 | |
| #disable --view-prototcol because warnings are dropped
 | |
| --disable_view_protocol
 | |
| 
 | |
| create table t1 (c1 char(3), c2 char(3));
 | |
| create table t2 (c3 char(3), c4 char(3));
 | |
| insert into t1 values ('aaa', 'bb1'), ('aaa', 'bb2');
 | |
| insert into t2 values ('aaa', 'bb1'), ('aaa', 'bb2');
 | |
| 
 | |
| # query with ambiguous column reference 'c2'
 | |
| select t1.c1 as c2 from t1, t2 where t1.c2 = t2.c4
 | |
| group by c2;
 | |
| show warnings;
 | |
| 
 | |
| # this query has no ambiguity
 | |
| select t1.c1 as c2 from t1, t2 where t1.c2 = t2.c4
 | |
| group by t1.c1;
 | |
| 
 | |
| show warnings;
 | |
| drop table t1, t2;
 | |
| 
 | |
| --enable_view_protocol
 | |
| 
 | |
| #
 | |
| # Bug #20466: a view is mixing data when there's a trigger on the table
 | |
| #
 | |
| CREATE TABLE t1 (a tinyint(3), b varchar(255), PRIMARY KEY  (a));
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,'-----'), (6,'Allemagne'), (17,'Autriche'), 
 | |
|     (25,'Belgique'), (54,'Danemark'), (62,'Espagne'), (68,'France'),
 | |
|     (100,"No land"), (101,"No land");
 | |
| 
 | |
| CREATE TABLE t2 (a tinyint(3), b tinyint(3), PRIMARY KEY  (a), KEY b (b));
 | |
| 
 | |
| INSERT INTO t2 VALUES (1,1), (2,1), (6,6), (18,17), (15,25), (16,25),
 | |
|  (17,25), (10,54), (5,62),(3,68);
 | |
| 
 | |
| CREATE VIEW v1 AS select t1.a, concat(t1.b,'') AS b, t1.b as real_b from t1;
 | |
| 
 | |
| explain 
 | |
| SELECT straight_join sql_no_cache v1.a, v1.b, v1.real_b from t2, v1
 | |
| where t2.b=v1.a GROUP BY t2.b;
 | |
| SELECT straight_join sql_no_cache v1.a, v1.b, v1.real_b from t2, v1
 | |
| where t2.b=v1.a GROUP BY t2.b;
 | |
| 
 | |
| DROP VIEW v1;
 | |
| DROP TABLE t1,t2;
 | |
| 
 | |
| #
 | |
| # Bug#22781: SQL_BIG_RESULT fails to influence sort plan
 | |
| #
 | |
| CREATE TABLE t1 (a INT PRIMARY KEY, b INT, key (b));
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,      1);
 | |
| INSERT INTO t1 SELECT  a + 1 , MOD(a + 1 , 20) FROM t1;
 | |
| INSERT INTO t1 SELECT  a + 2 , MOD(a + 2 , 20) FROM t1;
 | |
| INSERT INTO t1 SELECT  a + 4 , MOD(a + 4 , 20) FROM t1;
 | |
| INSERT INTO t1 SELECT  a + 8 , MOD(a + 8 , 20) FROM t1;
 | |
| INSERT INTO t1 SELECT  a + 16, MOD(a + 16, 20) FROM t1;
 | |
| INSERT INTO t1 SELECT  a + 32, MOD(a + 32, 20) FROM t1;
 | |
| INSERT INTO t1 SELECT  a + 64, MOD(a + 64, 20) FROM t1;
 | |
| 
 | |
| SELECT MIN(b), MAX(b) from t1;
 | |
| 
 | |
| EXPLAIN SELECT b, sum(1) FROM t1 GROUP BY b;
 | |
| EXPLAIN SELECT SQL_BIG_RESULT b, sum(1) FROM t1 GROUP BY b;
 | |
| SELECT b, sum(1) FROM t1 GROUP BY b;
 | |
| SELECT SQL_BIG_RESULT b, sum(1) FROM t1 GROUP BY b;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #
 | |
| # Bug #23417: Too strict checks against GROUP BY in the ONLY_FULL_GROUP_BY mode
 | |
| #
 | |
| CREATE TABLE t1 (a INT PRIMARY KEY, b INT);
 | |
| INSERT INTO t1 VALUES (1,1),(2,1),(3,2),(4,2),(5,3),(6,3);
 | |
| 
 | |
| SET SQL_MODE = 'ONLY_FULL_GROUP_BY';
 | |
| SELECT MAX(a)-MIN(a) FROM t1 GROUP BY b;
 | |
| SELECT CEILING(MIN(a)) FROM t1 GROUP BY b;
 | |
| SELECT CASE WHEN AVG(a)>=0 THEN 'Positive' ELSE 'Negative' END FROM t1 
 | |
|  GROUP BY b;
 | |
| SELECT a + 1 FROM t1 GROUP BY a;
 | |
| --error ER_WRONG_FIELD_WITH_GROUP 
 | |
| SELECT a + b FROM t1 GROUP BY b;
 | |
| SELECT (SELECT t1_outer.a FROM t1 AS t1_inner GROUP BY b LIMIT 1) 
 | |
|   FROM t1 AS t1_outer;
 | |
| SELECT 1 FROM t1 as t1_outer GROUP BY a 
 | |
|   HAVING (SELECT t1_outer.a FROM t1 AS t1_inner GROUP BY b LIMIT 1);
 | |
| --error ER_WRONG_FIELD_WITH_GROUP 
 | |
| SELECT (SELECT t1_outer.a FROM t1 AS t1_inner LIMIT 1) 
 | |
|   FROM t1 AS t1_outer GROUP BY t1_outer.b;
 | |
| --error ER_BAD_FIELD_ERROR 
 | |
| SELECT 1 FROM t1 as t1_outer GROUP BY a 
 | |
|   HAVING (SELECT t1_outer.b FROM t1 AS t1_inner LIMIT 1);
 | |
| SELECT (SELECT SUM(t1_inner.a) FROM t1 AS t1_inner LIMIT 1) 
 | |
|   FROM t1 AS t1_outer GROUP BY t1_outer.b;
 | |
| 
 | |
| SELECT (SELECT SUM(t1_inner.a) FROM t1 AS t1_inner GROUP BY t1_inner.b LIMIT 1)
 | |
| AS m
 | |
|   FROM t1 AS t1_outer;
 | |
| 
 | |
| --error ER_WRONG_FIELD_WITH_GROUP 
 | |
| SELECT (SELECT SUM(t1_outer.a) FROM t1 AS t1_inner LIMIT 1) 
 | |
|   FROM t1 AS t1_outer GROUP BY t1_outer.b;
 | |
| 
 | |
| SELECT 1 FROM t1 as t1_outer 
 | |
|   WHERE (SELECT t1_outer.b FROM t1 AS t1_inner GROUP BY t1_inner.b LIMIT 1);
 | |
| 
 | |
| SELECT b FROM t1 GROUP BY b HAVING CEILING(b) > 0;
 | |
| 
 | |
| SELECT 1 FROM t1 GROUP BY b HAVING b = 2 OR b = 3 OR SUM(a) > 12;
 | |
| SELECT 1 FROM t1 GROUP BY b HAVING ROW (b,b) = ROW (1,1);
 | |
| 
 | |
| --error ER_BAD_FIELD_ERROR
 | |
| SELECT 1 FROM t1 GROUP BY b HAVING a = 2;
 | |
| --error ER_INVALID_GROUP_FUNC_USE
 | |
| SELECT 1 FROM t1 GROUP BY SUM(b);
 | |
| --error ER_WRONG_FIELD_WITH_GROUP 
 | |
| SELECT b FROM t1 AS t1_outer GROUP BY a HAVING t1_outer.a IN 
 | |
|   (SELECT SUM(t1_inner.b)+t1_outer.b FROM t1 AS t1_inner GROUP BY t1_inner.a
 | |
|    HAVING SUM(t1_inner.b)+t1_outer.b > 5);
 | |
| DROP TABLE t1;
 | |
| SET SQL_MODE = '';
 | |
| #
 | |
| # Bug#27874: Non-grouped columns are allowed by * in ONLY_FULL_GROUP_BY mode.
 | |
| #
 | |
| SET SQL_MODE = 'ONLY_FULL_GROUP_BY';
 | |
| create table t1(f1 int, f2 int);
 | |
| --error 1055
 | |
| select * from t1 group by f1;
 | |
| --error 1055
 | |
| select * from t1 group by f2;
 | |
| select * from t1 group by f1, f2;
 | |
| --error 1055
 | |
| select t1.f1,t.* from t1, t1 t group by 1;
 | |
| drop table t1;
 | |
| SET SQL_MODE = '';
 | |
| 
 | |
| #
 | |
| # Bug #32202: ORDER BY not working with GROUP BY
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1(
 | |
|   id INT AUTO_INCREMENT PRIMARY KEY, 
 | |
|   c1 INT NOT NULL, 
 | |
|   c2 INT NOT NULL,
 | |
|   UNIQUE KEY (c2,c1));
 | |
| 
 | |
| INSERT INTO t1(c1,c2) VALUES (5,1), (4,1), (3,5), (2,3), (1,3);
 | |
| 
 | |
| # Show that the test cases from the bug report pass
 | |
| SELECT * FROM t1 ORDER BY c1;
 | |
| SELECT * FROM t1 GROUP BY id ORDER BY c1;
 | |
| 
 | |
| # Show that DESC is handled correctly
 | |
| SELECT * FROM t1 GROUP BY id ORDER BY id DESC;
 | |
| 
 | |
| # Show that results are correctly ordered when ORDER BY fields
 | |
| # are a subset of GROUP BY ones
 | |
| SELECT * FROM t1 GROUP BY c2 ,c1, id ORDER BY c2, c1;
 | |
| SELECT * FROM t1 GROUP BY c2, c1, id ORDER BY c2 DESC, c1;
 | |
| SELECT * FROM t1 GROUP BY c2, c1, id ORDER BY c2 DESC, c1 DESC;
 | |
| 
 | |
| # Show that results are correctly ordered when GROUP BY fields
 | |
| # are a subset of ORDER BY ones
 | |
| SELECT * FROM t1 GROUP BY c2  ORDER BY c2, c1;
 | |
| SELECT * FROM t1 GROUP BY c2  ORDER BY c2 DESC, c1;
 | |
| SELECT * FROM t1 GROUP BY c2  ORDER BY c2 DESC, c1 DESC;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| 
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug#27219: Aggregate functions in ORDER BY.  
 | |
| --echo #
 | |
| 
 | |
| SET @save_sql_mode=@@sql_mode;
 | |
| SET @@sql_mode='ONLY_FULL_GROUP_BY';
 | |
| 
 | |
| CREATE TABLE t1 (a INT, b INT, c INT DEFAULT 0);
 | |
| INSERT INTO t1 (a, b) VALUES (3,3), (2,2), (3,3), (2,2), (3,3), (4,4);
 | |
| CREATE TABLE t2 SELECT * FROM t1;
 | |
| 
 | |
| SELECT 1 FROM t1 ORDER BY COUNT(*);
 | |
| SELECT 1 FROM t1 ORDER BY COUNT(*) + 1;
 | |
| --error 1140
 | |
| SELECT 1 FROM t1 ORDER BY COUNT(*) + a;
 | |
| SELECT 1 FROM t1 ORDER BY COUNT(*), 1;
 | |
| --error 1140
 | |
| SELECT 1 FROM t1 ORDER BY COUNT(*), a;
 | |
| 
 | |
| SELECT 1 FROM t1 ORDER BY SUM(a);
 | |
| SELECT 1 FROM t1 ORDER BY SUM(a + 1);
 | |
| SELECT 1 FROM t1 ORDER BY SUM(a) + 1;
 | |
| --error 1140
 | |
| SELECT 1 FROM t1 ORDER BY SUM(a), b;
 | |
| 
 | |
| --disable_service_connection
 | |
| 
 | |
| --error 1140
 | |
| SELECT a FROM t1 ORDER BY COUNT(b);
 | |
| 
 | |
| SELECT t1.a FROM t1 ORDER BY (SELECT SUM(t2.a) FROM t2);
 | |
| 
 | |
| --error 1140
 | |
| SELECT t1.a FROM t1 ORDER BY (SELECT SUM(t2.a), t2.a FROM t2);
 | |
| --error 1140
 | |
| SELECT t1.a FROM t1 ORDER BY (SELECT SUM(t2.a) FROM t2 ORDER BY t2.a);
 | |
| --error 1140
 | |
| SELECT t1.a FROM t1 ORDER BY (SELECT t2.a FROM t2 ORDER BY SUM(t2.b) LIMIT 1);
 | |
| 
 | |
| --error 1140
 | |
| SELECT t1.a FROM t1
 | |
|   WHERE t1.a = (SELECT t2.a FROM t2 ORDER BY SUM(t2.b) LIMIT 1);
 | |
| --error 1140
 | |
| SELECT t1.a FROM t1 GROUP BY t1.a
 | |
|   HAVING t1.a = (SELECT t2.a FROM t2 ORDER BY SUM(t2.a) LIMIT 1);
 | |
| 
 | |
| SELECT t1.a FROM t1 GROUP BY t1.a
 | |
|   HAVING t1.a IN (SELECT t2.a FROM t2 ORDER BY SUM(t1.b));
 | |
| --error 1140
 | |
| SELECT t1.a FROM t1 GROUP BY t1.a
 | |
|   HAVING t1.a IN (SELECT t2.a FROM t2 ORDER BY t2.a, SUM(t2.b));
 | |
| --error 1140
 | |
| SELECT t1.a FROM t1 GROUP BY t1.a
 | |
|   HAVING t1.a > ANY (SELECT t2.a FROM t2 ORDER BY t2.a, SUM(t2.b));
 | |
| 
 | |
| --error 1140
 | |
| SELECT t1.a FROM t1
 | |
|   WHERE t1.a = (SELECT t2.a FROM t2 ORDER BY SUM(t1.b));
 | |
| 
 | |
| SELECT 1 FROM t1 GROUP BY t1.a
 | |
|   HAVING (SELECT AVG(SUM(t1.b) + 1) FROM t2 ORDER BY SUM(t2.a) LIMIT 1);
 | |
| SELECT 1 FROM t1 GROUP BY t1.a
 | |
|   HAVING (SELECT AVG(SUM(t1.b) + t2.b) FROM t2 ORDER BY SUM(t2.a) LIMIT 1);
 | |
| SELECT 1 FROM t1 GROUP BY t1.a
 | |
|   HAVING (SELECT AVG(t1.b + t2.b) FROM t2 ORDER BY SUM(t2.a) LIMIT 1);
 | |
| 
 | |
| --error 1140
 | |
| SELECT 1 FROM t1 GROUP BY t1.a
 | |
|   HAVING (SELECT AVG(SUM(t1.b) + 1) FROM t2 ORDER BY t2.a LIMIT 1);
 | |
| --error 1140
 | |
| SELECT 1 FROM t1 GROUP BY t1.a
 | |
|   HAVING (SELECT AVG(SUM(t1.b) + t2.b) FROM t2 ORDER BY t2.a LIMIT 1);
 | |
| --error 1140
 | |
| SELECT 1 FROM t1 GROUP BY t1.a
 | |
|   HAVING (SELECT AVG(t1.b + t2.b) FROM t2 ORDER BY t2.a LIMIT 1);
 | |
| 
 | |
| --enable_service_connection
 | |
| 
 | |
| # Both SUMs are aggregated in the subquery, no mixture:
 | |
| SELECT t1.a FROM t1 
 | |
|   WHERE t1.a = (SELECT t2.a FROM t2 GROUP BY t2.a
 | |
|                   ORDER BY SUM(t2.b), SUM(t1.b) LIMIT 1);
 | |
| 
 | |
| # SUM(t1.b) is aggregated in the subquery, no mixture:
 | |
| SELECT t1.a, SUM(t1.b) FROM t1 
 | |
|   WHERE t1.a = (SELECT SUM(t2.b) FROM t2 GROUP BY t2.a
 | |
|                   ORDER BY SUM(t2.b), SUM(t1.b) LIMIT 1)
 | |
|   GROUP BY t1.a;
 | |
| 
 | |
| # 2nd SUM(t1.b) is aggregated in the subquery, no mixture:
 | |
| SELECT t1.a, SUM(t1.b) FROM t1 
 | |
|   WHERE t1.a = (SELECT SUM(t2.b) FROM t2
 | |
|                   ORDER BY SUM(t2.b) + SUM(t1.b) LIMIT 1)
 | |
|   GROUP BY t1.a;
 | |
| 
 | |
| # SUM(t2.b + t1.a) is aggregated in the subquery, no mixture:
 | |
| SELECT t1.a, SUM(t1.b) FROM t1 
 | |
|   WHERE t1.a = (SELECT SUM(t2.b) FROM t2
 | |
|                   ORDER BY SUM(t2.b + t1.a) LIMIT 1)
 | |
|   GROUP BY t1.a;
 | |
| 
 | |
| SELECT t1.a FROM t1 GROUP BY t1.a
 | |
|     HAVING (1, 1) = (SELECT SUM(t1.a), t1.a FROM t2 LIMIT 1);
 | |
| 
 | |
| select avg (
 | |
|   (select
 | |
|     (select sum(outr.a + innr.a) from t1 as innr limit 1) as tt
 | |
|    from t1 as outr order by outr.a limit 1)) as m
 | |
| from t1 as most_outer;
 | |
| 
 | |
| --disable_service_connection
 | |
| 
 | |
| --error 1140
 | |
| select avg (
 | |
|   (select (
 | |
|     (select sum(outr.a + innr.a) from t1 as innr limit 1)) as tt
 | |
|    from t1 as outr order by count(outr.a) limit 1)) as tt
 | |
| from t1 as most_outer;
 | |
| 
 | |
| --enable_service_connection
 | |
| 
 | |
| select (select sum(outr.a + t1.a) from t1 limit 1) as tt from t1 as outr order by outr.a;
 | |
| 
 | |
| SET sql_mode=@save_sql_mode;
 | |
| DROP TABLE t1, t2;
 | |
| 
 | |
| --echo # 
 | |
| --echo # BUG#38072: Wrong result: HAVING not observed in a query with aggregate
 | |
| --echo # 
 | |
| CREATE TABLE t1 (
 | |
|   pk int(11) NOT NULL AUTO_INCREMENT,
 | |
|   int_nokey int(11) NOT NULL,
 | |
|   int_key int(11) NOT NULL,
 | |
|   varchar_key varchar(1) NOT NULL,
 | |
|   varchar_nokey varchar(1) NOT NULL,
 | |
|   PRIMARY KEY (pk),
 | |
|   KEY int_key (int_key),
 | |
|   KEY varchar_key (varchar_key)
 | |
| );
 | |
| INSERT INTO t1 VALUES 
 | |
| (1,5,5, 'h','h'),
 | |
| (2,1,1, '{','{'),
 | |
| (3,1,1, 'z','z'),
 | |
| (4,8,8, 'x','x'),
 | |
| (5,7,7, 'o','o'),
 | |
| (6,3,3, 'p','p'),
 | |
| (7,9,9, 'c','c'),
 | |
| (8,0,0, 'k','k'),
 | |
| (9,6,6, 't','t'),
 | |
| (10,0,0,'c','c');
 | |
| 
 | |
| explain SELECT COUNT(varchar_key) AS X FROM t1 WHERE pk = 8 having 'foo'='bar';
 | |
| SELECT COUNT(varchar_key) AS X FROM t1 WHERE pk = 8 having 'foo'='bar';
 | |
| drop table t1;
 | |
|   
 | |
| --echo End of 5.0 tests
 | |
| # Bug #21174: Index degrades sort performance and 
 | |
| #             optimizer does not honor IGNORE INDEX.
 | |
| #             a.k.a WL3527.
 | |
| #
 | |
| CREATE TABLE t1 (a INT, b INT,
 | |
|                  PRIMARY KEY (a),
 | |
|                  KEY i2(a,b));
 | |
| INSERT INTO t1 VALUES (1,1),(2,2),(3,3),(4,4),(5,5),(6,6),(7,7),(8,8);
 | |
| INSERT INTO t1 SELECT a + 8,b FROM t1;
 | |
| INSERT INTO t1 SELECT a + 16,b FROM t1;
 | |
| INSERT INTO t1 SELECT a + 32,b FROM t1;
 | |
| INSERT INTO t1 SELECT a + 64,b FROM t1;
 | |
| INSERT INTO t1 SELECT a + 128,b FROM t1 limit 16;
 | |
| ANALYZE TABLE t1;
 | |
| EXPLAIN SELECT a FROM t1 WHERE a < 2;
 | |
| EXPLAIN SELECT a FROM t1 WHERE a < 2 ORDER BY a;
 | |
| EXPLAIN SELECT a FROM t1 WHERE a < 2 GROUP BY a;
 | |
| EXPLAIN SELECT a FROM t1 IGNORE INDEX (PRIMARY,i2);
 | |
| EXPLAIN SELECT a FROM t1 IGNORE INDEX FOR JOIN (PRIMARY,i2);
 | |
| 
 | |
| --echo #
 | |
| --echo #  For this explain, the query plan is weird: if we are using 
 | |
| --echo #  the primary key for reasons other than doing grouping, can't
 | |
| --echo #  GROUP BY code take advantage of this?  Well, currently it doesnt:
 | |
| EXPLAIN SELECT a FROM t1 IGNORE INDEX FOR GROUP BY (PRIMARY,i2) GROUP BY a;
 | |
| --echo #  Here's a proof it is really doing sorting:
 | |
| flush status;
 | |
| --disable_ps2_protocol
 | |
| --disable_result_log
 | |
| SELECT a FROM t1 IGNORE INDEX FOR GROUP BY (PRIMARY,i2) GROUP BY a;
 | |
| --enable_result_log
 | |
| --enable_ps2_protocol
 | |
| show status like 'Sort_%';
 | |
| --echo # Proof ends.
 | |
| --echo # 
 | |
| 
 | |
| --echo #  For this explain, the query plan is weird: if we are using 
 | |
| --echo #  the primary key for reasons other than doing sorting, can't
 | |
| --echo #  ORDER BY code take advantage of this?  Well, currently it doesnt:
 | |
| EXPLAIN SELECT a FROM t1 IGNORE INDEX FOR ORDER BY (PRIMARY,i2) ORDER BY a;
 | |
| --echo #  Here's a proof it is really doing sorting:
 | |
| flush status;
 | |
| --disable_ps2_protocol
 | |
| --disable_result_log
 | |
| SELECT a FROM t1 IGNORE INDEX FOR ORDER BY (PRIMARY,i2) ORDER BY a;
 | |
| --enable_result_log
 | |
| --enable_ps2_protocol
 | |
| show status like 'Sort_%';
 | |
| --echo # Proof ends.
 | |
| --echo # 
 | |
| SELECT a FROM t1 IGNORE INDEX FOR ORDER BY (PRIMARY,i2) ORDER BY a;
 | |
| EXPLAIN SELECT a FROM t1 IGNORE INDEX FOR ORDER BY (PRIMARY)
 | |
|   IGNORE INDEX FOR GROUP BY (i2) GROUP BY a;
 | |
| EXPLAIN SELECT a FROM t1 IGNORE INDEX (PRIMARY) IGNORE INDEX FOR ORDER BY (i2);
 | |
| EXPLAIN SELECT a FROM t1 FORCE INDEX (i2);
 | |
| EXPLAIN SELECT a FROM t1 USE INDEX ();
 | |
| EXPLAIN SELECT a FROM t1 USE INDEX () USE INDEX (i2);
 | |
| --error ER_WRONG_USAGE
 | |
| EXPLAIN SELECT a FROM t1 
 | |
|   FORCE INDEX (PRIMARY) 
 | |
|   IGNORE INDEX FOR GROUP BY (i2)
 | |
|   IGNORE INDEX FOR ORDER BY (i2)
 | |
|   USE INDEX (i2);
 | |
| EXPLAIN SELECT a FROM t1 USE INDEX (i2) USE INDEX ();
 | |
| --error ER_PARSE_ERROR
 | |
| EXPLAIN SELECT a FROM t1 FORCE INDEX ();
 | |
| --error ER_PARSE_ERROR
 | |
| EXPLAIN SELECT a FROM t1 IGNORE INDEX ();
 | |
| # disable the columns irrelevant to this test here. On some systems 
 | |
| # without support for large files the rowid is shorter and its size affects 
 | |
| # the cost calculations. This causes the optimizer to choose loose index
 | |
| # scan over normal index access.
 | |
| --replace_column 4 # 7 # 9 # 10 #
 | |
| EXPLAIN SELECT a FROM t1 USE INDEX FOR JOIN (i2) 
 | |
|   USE INDEX FOR GROUP BY (i2) GROUP BY a;
 | |
| EXPLAIN SELECT a FROM t1 FORCE INDEX FOR JOIN (i2) 
 | |
|   FORCE INDEX FOR GROUP BY (i2) GROUP BY a;
 | |
| EXPLAIN SELECT a FROM t1 USE INDEX () IGNORE INDEX (i2);
 | |
| EXPLAIN SELECT a FROM t1 IGNORE INDEX (i2) USE INDEX ();
 | |
| 
 | |
| EXPLAIN SELECT a FROM t1 
 | |
|   USE INDEX FOR GROUP BY (i2) 
 | |
|   USE INDEX FOR ORDER BY (i2)
 | |
|   USE INDEX FOR JOIN (i2);
 | |
| 
 | |
| EXPLAIN SELECT a FROM t1 
 | |
|   USE INDEX FOR JOIN (i2) 
 | |
|   USE INDEX FOR JOIN (i2) 
 | |
|   USE INDEX FOR JOIN (i2,i2);
 | |
| 
 | |
| SET @save_optimizer_switch=@@optimizer_switch;
 | |
| SET optimizer_switch='semijoin_with_cache=off';
 | |
| EXPLAIN SELECT 1 FROM t1 WHERE a IN
 | |
|   (SELECT a FROM t1 USE INDEX (i2) IGNORE INDEX (i2));
 | |
| SET optimizer_switch=@save_optimizer_switch;
 | |
| 
 | |
| CREATE TABLE t2 (a INT, b INT, KEY(a));
 | |
| INSERT INTO t2 VALUES (1, 1), (2, 2), (3,3), (4,4);
 | |
| EXPLAIN SELECT a, SUM(b) FROM t2 GROUP BY a LIMIT 2; 
 | |
| EXPLAIN SELECT a, SUM(b) FROM t2 IGNORE INDEX (a) GROUP BY a LIMIT 2;
 | |
| 
 | |
| SET @save_optimizer_switch=@@optimizer_switch;
 | |
| SET optimizer_switch='semijoin_with_cache=off';
 | |
| EXPLAIN SELECT 1 FROM t2 WHERE a IN
 | |
|   (SELECT a FROM t1 USE INDEX (i2) IGNORE INDEX (i2));
 | |
| SET optimizer_switch=@save_optimizer_switch;
 | |
| 
 | |
| DROP TABLE t1, t2;
 | |
| 
 | |
| #
 | |
| # Bug#30596: GROUP BY optimization gives wrong result order
 | |
| #
 | |
| CREATE TABLE t1(
 | |
|   a INT, 
 | |
|   b INT NOT NULL, 
 | |
|   c INT NOT NULL, 
 | |
|   d INT, 
 | |
|   UNIQUE KEY (c,b)
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
 | |
| 
 | |
| CREATE TABLE t2(
 | |
|   a INT,
 | |
|   b INT,
 | |
|   UNIQUE KEY(a,b)
 | |
| );
 | |
| 
 | |
| INSERT INTO t2 VALUES (NULL, NULL), (NULL, NULL), (NULL, 1), (1, NULL), (1, 1), (1,2);
 | |
| 
 | |
| EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
 | |
| SELECT c,b,d FROM t1 GROUP BY c,b,d;
 | |
| EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
 | |
| SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
 | |
| EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
 | |
| SELECT c,b,d FROM t1 ORDER BY c,b,d;
 | |
| 
 | |
| EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
 | |
| SELECT c,b,d FROM t1 GROUP BY c,b;
 | |
| EXPLAIN SELECT c,b   FROM t1 GROUP BY c,b;
 | |
| SELECT c,b   FROM t1 GROUP BY c,b;
 | |
| 
 | |
| EXPLAIN SELECT a,b from t2 ORDER BY a,b;
 | |
| SELECT a,b from t2 ORDER BY a,b;
 | |
| EXPLAIN SELECT a,b from t2 GROUP BY a,b;
 | |
| SELECT a,b from t2 GROUP BY a,b;
 | |
| EXPLAIN SELECT a from t2 GROUP BY a;
 | |
| SELECT a from t2 GROUP BY a;
 | |
| EXPLAIN SELECT b from t2 GROUP BY b;
 | |
| SELECT b from t2 GROUP BY b;
 | |
| 
 | |
| # Show that we are using 'range' when there is more NULL rows in the table
 | |
| insert into t2 SELECT NULL, NULL from seq_1_to_10;
 | |
| EXPLAIN SELECT b from t2 GROUP BY a;
 | |
| --echo # Expect: Using index for group-by
 | |
| analyze table t2;
 | |
| EXPLAIN SELECT b from t2 GROUP BY a;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| DROP TABLE t2;
 | |
| 
 | |
| #
 | |
| # Bug #31797: error while parsing subqueries -- WHERE is parsed as HAVING
 | |
| #
 | |
| CREATE TABLE t1 ( a INT, b INT );
 | |
| 
 | |
| SELECT b c, (SELECT a FROM t1 WHERE b = c)
 | |
| FROM t1;
 | |
| 
 | |
| SELECT b c, (SELECT a FROM t1 WHERE b = c)
 | |
| FROM t1 
 | |
| HAVING b = 10;
 | |
| 
 | |
| --error ER_ILLEGAL_REFERENCE
 | |
| SELECT MAX(b) c, (SELECT a FROM t1 WHERE b = c)
 | |
| FROM t1 
 | |
| HAVING b = 10;
 | |
| 
 | |
| SET @old_sql_mode = @@sql_mode;
 | |
| SET @@sql_mode='ONLY_FULL_GROUP_BY';
 | |
| 
 | |
| SELECT b c, (SELECT a FROM t1 WHERE b = c)
 | |
| FROM t1;
 | |
| 
 | |
| --error ER_NON_GROUPING_FIELD_USED
 | |
| SELECT b c, (SELECT a FROM t1 WHERE b = c)
 | |
| FROM t1 
 | |
| HAVING b = 10;
 | |
| 
 | |
| --error ER_ILLEGAL_REFERENCE
 | |
| SELECT MAX(b) c, (SELECT a FROM t1 WHERE b = c)
 | |
| FROM t1 
 | |
| HAVING b = 10;
 | |
| 
 | |
| INSERT INTO t1 VALUES (1, 1);
 | |
| SELECT b c, (SELECT a FROM t1 WHERE b = c)
 | |
| FROM t1;
 | |
| 
 | |
| INSERT INTO t1 VALUES (2, 1);
 | |
| --error ER_SUBQUERY_NO_1_ROW
 | |
| SELECT b c, (SELECT a FROM t1 WHERE b = c)
 | |
| FROM t1;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| SET @@sql_mode = @old_sql_mode;
 | |
| 
 | |
| 
 | |
| #
 | |
| # Bug#42567 Invalid GROUP BY error
 | |
| #
 | |
| 
 | |
| # Setup of the subtest
 | |
| SET @old_sql_mode = @@sql_mode;
 | |
| SET @@sql_mode='ONLY_FULL_GROUP_BY';
 | |
| 
 | |
| CREATE TABLE t1(i INT);
 | |
| INSERT INTO t1 VALUES (1), (10);
 | |
| 
 | |
| # The actual test
 | |
| SELECT COUNT(i) FROM t1;
 | |
| SELECT COUNT(i) FROM t1 WHERE i > 1;
 | |
| 
 | |
| # Cleanup of subtest
 | |
| DROP TABLE t1;
 | |
| SET @@sql_mode = @old_sql_mode;
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug #45640: optimizer bug produces wrong results
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (a INT, b INT);
 | |
| INSERT INTO t1 VALUES (4, 40), (1, 10), (2, 20), (2, 20), (3, 30);
 | |
| 
 | |
| --echo # should return 4 ordered records:
 | |
| SELECT (SELECT t1.a) aa, COUNT(DISTINCT b) FROM t1 GROUP BY aa;
 | |
| 
 | |
| SELECT (SELECT (SELECT t1.a)) aa, COUNT(DISTINCT b) FROM t1 GROUP BY aa;
 | |
| 
 | |
| SELECT (SELECT t1.a) aa, COUNT(DISTINCT b) FROM t1 GROUP BY aa+0;
 | |
| 
 | |
| --echo # should return the same result in a reverse order:
 | |
| SELECT (SELECT t1.a) aa, COUNT(DISTINCT b) FROM t1 GROUP BY -aa;
 | |
| 
 | |
| --echo # execution plan should not use temporary table:
 | |
| EXPLAIN EXTENDED
 | |
| SELECT (SELECT t1.a) aa, COUNT(DISTINCT b) FROM t1 GROUP BY aa+0;
 | |
| 
 | |
| EXPLAIN EXTENDED
 | |
| SELECT (SELECT t1.a) aa, COUNT(DISTINCT b) FROM t1 GROUP BY -aa;
 | |
| 
 | |
| --echo # should return only one record
 | |
| SELECT (SELECT tt.a FROM t1 tt LIMIT 1) aa, COUNT(DISTINCT b) FROM t1
 | |
|   GROUP BY aa;
 | |
| 
 | |
| CREATE TABLE t2 SELECT DISTINCT a FROM t1;
 | |
| 
 | |
| --echo # originally reported queries (1st two columns of next two query
 | |
| --echo # results should be same):
 | |
| 
 | |
| SELECT (SELECT t2.a FROM t2 WHERE t2.a = t1.a) aa, b, COUNT(DISTINCT b)
 | |
|   FROM t1 GROUP BY aa, b;
 | |
| SELECT (SELECT t2.a FROM t2 WHERE t2.a = t1.a) aa, b, COUNT(         b)
 | |
|   FROM t1 GROUP BY aa, b;
 | |
| 
 | |
| --echo # ORDER BY for sure:
 | |
| 
 | |
| SELECT (SELECT t2.a FROM t2 WHERE t2.a = t1.a) aa, b, COUNT(DISTINCT b)
 | |
|   FROM t1 GROUP BY aa, b ORDER BY -aa, -b;
 | |
| SELECT (SELECT t2.a FROM t2 WHERE t2.a = t1.a) aa, b, COUNT(         b)
 | |
|   FROM t1 GROUP BY aa, b ORDER BY -aa, -b;
 | |
| 
 | |
| DROP TABLE t1, t2;
 | |
| 
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug#52051: Aggregate functions incorrectly returns NULL from outer
 | |
| --echo # join query
 | |
| --echo #
 | |
| CREATE TABLE t1 (a INT PRIMARY KEY);
 | |
| CREATE TABLE t2 (a INT PRIMARY KEY);
 | |
| INSERT INTO t2 VALUES (1), (2);
 | |
| EXPLAIN SELECT MIN(t2.a) FROM t2 LEFT JOIN t1 ON t2.a = t1.a;
 | |
| SELECT MIN(t2.a) FROM t2 LEFT JOIN t1 ON t2.a = t1.a;
 | |
| EXPLAIN SELECT MAX(t2.a) FROM t2 LEFT JOIN t1 ON t2.a = t1.a;
 | |
| SELECT MAX(t2.a) FROM t2 LEFT JOIN t1 ON t2.a = t1.a;
 | |
| DROP TABLE t1, t2;
 | |
| 
 | |
| #
 | |
| # min() returns wrong value when used in expression when there is no matching
 | |
| # rows
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 (a int(11) NOT NULL);
 | |
| INSERT INTO t1 VALUES (1),(2);
 | |
| CREATE TABLE t2 (
 | |
|  key_col int(11) NOT NULL,
 | |
|  KEY (key_col)
 | |
| );
 | |
| INSERT INTO t2 VALUES (1),(2);
 | |
| 
 | |
| select min(t2.key_col) from t1,t2 where t1.a=1;
 | |
| select min(t2.key_col) from t1,t2 where t1.a > 1000;
 | |
| select min(t2.key_col)+1 from t1,t2 where t1.a> 1000;
 | |
| drop table t1,t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug#55188: GROUP BY, GROUP_CONCAT and TEXT - inconsistent results
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (a text, b varchar(10));
 | |
| INSERT INTO t1 VALUES (repeat('1', 1300),'one'), (repeat('1', 1300),'two');
 | |
| 
 | |
| query_vertical EXPLAIN 
 | |
| SELECT SUBSTRING(a,1,10), LENGTH(a), GROUP_CONCAT(b) FROM t1 GROUP BY a;
 | |
| SELECT SUBSTRING(a,1,10), LENGTH(a), GROUP_CONCAT(b) FROM t1 GROUP BY a;
 | |
| query_vertical EXPLAIN 
 | |
| SELECT SUBSTRING(a,1,10), LENGTH(a) FROM t1 GROUP BY a;
 | |
| SELECT SUBSTRING(a,1,10), LENGTH(a) FROM t1 GROUP BY a;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug#57688 Assertion `!table || (!table->write_set || bitmap_is_set(table->write_set, field
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1(f1 INT NOT NULL);
 | |
| INSERT INTO t1 VALUES (16777214),(0);
 | |
| 
 | |
| SELECT COUNT(*) FROM t1 LEFT JOIN t1 t2
 | |
| ON 1 WHERE t2.f1 > 1 GROUP BY t2.f1;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug#59839: Aggregation followed by subquery yields wrong result
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   a INT,
 | |
|   b INT,
 | |
|   c INT,
 | |
|   KEY (a, b)
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 VALUES
 | |
|   ( 1, 1,  1 ),
 | |
|   ( 1, 2,  2 ),
 | |
|   ( 1, 3,  3 ),
 | |
|   ( 1, 4,  6 ),
 | |
|   ( 1, 5,  5 ),
 | |
|   ( 1, 9, 13 ),
 | |
| 
 | |
|   ( 2, 1,  6 ),
 | |
|   ( 2, 2,  7 ),
 | |
|   ( 2, 3,  8 );
 | |
| 
 | |
| EXPLAIN
 | |
| SELECT a, AVG(t1.b),
 | |
| (SELECT t11.c FROM t1 t11 WHERE t11.a = t1.a AND t11.b = AVG(t1.b)) AS t11c,
 | |
| (SELECT t12.c FROM t1 t12 WHERE t12.a = t1.a AND t12.b = AVG(t1.b)) AS t12c
 | |
| FROM t1 GROUP BY a;
 | |
| 
 | |
| SELECT a, AVG(t1.b),
 | |
| (SELECT t11.c FROM t1 t11 WHERE t11.a = t1.a AND t11.b = AVG(t1.b)) AS t11c,
 | |
| (SELECT t12.c FROM t1 t12 WHERE t12.a = t1.a AND t12.b = AVG(t1.b)) AS t12c
 | |
| FROM t1 GROUP BY a;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug#11765254 (58200): Assertion failed: param.sort_length when grouping
 | |
| --echo # by functions
 | |
| --echo #
 | |
| #creating view adds one new warning
 | |
| --disable_view_protocol
 | |
| 
 | |
| set tmp_memory_table_size=0;
 | |
| CREATE TABLE t1(a INT);
 | |
| INSERT INTO t1 VALUES (0),(0);
 | |
| SELECT 1 FROM t1 GROUP BY IF(`a`,'','');
 | |
| SELECT 1 FROM t1 GROUP BY TRIM(LEADING RAND() FROM '');
 | |
| SELECT 1 FROM t1 GROUP BY SUBSTRING('',SLEEP(0),'');
 | |
| SELECT 1 FROM t1 GROUP BY SUBSTRING(SYSDATE() FROM 'K' FOR 'jxW<');
 | |
| DROP TABLE t1;
 | |
| set tmp_memory_table_size=default;
 | |
| 
 | |
| --enable_view_protocol
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-641 LP:1002108 - Wrong result (or crash) from a query with duplicated field in the group list and a limit clause
 | |
| --echo # Bug#11761078: 53534: INCORRECT 'SELECT SQL_BIG_RESULT...' 
 | |
| --echo #               WITH GROUP BY ON DUPLICATED FIELDS
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1(
 | |
|  col1 int, 
 | |
|  UNIQUE INDEX idx (col1));
 | |
| 
 | |
| INSERT INTO t1 VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),
 | |
|    (11),(12),(13),(14),(15),(16),(17),(18),(19),(20);
 | |
| 
 | |
| let $query0=SELECT col1 AS field1, col1 AS field2
 | |
|             FROM t1 GROUP BY field1, field2;
 | |
| 
 | |
| # Needs to be range to exercise bug
 | |
| --eval EXPLAIN $query0;
 | |
| FLUSH STATUS;
 | |
| --disable_ps2_protocol
 | |
| --eval $query0;
 | |
| --enable_ps2_protocol
 | |
| SHOW SESSION STATUS LIKE 'Sort_scan%';
 | |
| 
 | |
| let $query=SELECT SQL_BIG_RESULT col1 AS field1, col1 AS field2
 | |
|            FROM t1 GROUP BY field1, field2;
 | |
| 
 | |
| # Needs to be range to exercise bug
 | |
| --eval EXPLAIN $query
 | |
| FLUSH STATUS;
 | |
| --disable_ps2_protocol
 | |
| --eval $query
 | |
| --enable_ps2_protocol
 | |
| SHOW SESSION STATUS LIKE 'Sort_scan%';
 | |
| 
 | |
| CREATE VIEW v1 AS SELECT * FROM t1;
 | |
| 
 | |
| SELECT SQL_BIG_RESULT col1 AS field1, col1 AS field2
 | |
| FROM v1 
 | |
| GROUP BY field1, field2; 
 | |
| 
 | |
| SELECT SQL_BIG_RESULT tbl1.col1 AS field1, tbl2.col1 AS field2
 | |
| FROM t1 as tbl1, t1 as tbl2 
 | |
| GROUP BY field1, field2 
 | |
| LIMIT 3;
 | |
| 
 | |
| explain
 | |
| select col1 f1, col1 f2 from t1 order by f2, f1;
 | |
| explain
 | |
| select col1 f1, col1 f2 from t1 order by f2, f1+0;
 | |
| select col1 f1, col1 f2 from t1 order by f2, f1+0;
 | |
| 
 | |
| explain
 | |
| select col1 f1, col1 f2 from t1 group by f1;
 | |
| select col1 f1, col1 f2 from t1 group by f1;
 | |
| 
 | |
| explain
 | |
| select col1 f1, col1 f2 from t1 group by f1, f2;
 | |
| select col1 f1, col1 f2 from t1 group by f1, f2;
 | |
| 
 | |
| explain
 | |
| select col1 f1, col1 f2 from t1 group by f2 order by f2, f1;
 | |
| select col1 f1, col1 f2 from t1 group by f2 order by f2, f1;
 | |
| 
 | |
| explain
 | |
| select col1 f1, col1 f2 from t1 group by f1, f2 order by f2, f1;
 | |
| select col1 f1, col1 f2 from t1 group by f1, f2 order by f2, f1;
 | |
| 
 | |
| 
 | |
| CREATE TABLE t2(
 | |
|  col1 int, 
 | |
|  col2 int, 
 | |
|  UNIQUE INDEX idx (col1, col2));
 | |
| 
 | |
| INSERT INTO t2(col1, col2) VALUES
 | |
|    (1,20),(2,19),(3,18),(4,17),(5,16),(6,15),(7,14),(8,13),(9,12),(10,11),
 | |
|    (11,10),(12,9),(13,8),(14,7),(15,6),(16,5),(17,4),(18,3),(19,2),(20,1);
 | |
| 
 | |
| explain
 | |
| select col1 f1, col2 f2, col1 f3 from t2 group by f1;
 | |
| explain
 | |
| select SQL_BIG_RESULT col1 f1, col2 f2, col1 f3 from t2 group by f1;
 | |
| explain
 | |
| select col1 f1, col2 f2, col1 f3 from t2 group by f1, f2;
 | |
| explain
 | |
| select col1 f1, col1 f2 from t2 group by f1, 1+1;
 | |
| 
 | |
| explain
 | |
| select col1 f1, col2 f2, col1 f3 from t2 group by f1, f2, f3+0;
 | |
| select col1 f1, col2 f2, col1 f3 from t2 group by f1, f2, f3+0;
 | |
| 
 | |
| explain
 | |
| select col1 f1, col2 f2, col1 f3 from t2 order by f1,f2;
 | |
| explain
 | |
| select col1 f1, col2 f2, col1 f3 from t2 order by f1, f2, f3+0;
 | |
| select col1 f1, col2 f2, col1 f3 from t2 order by f1, f2, f3+0;
 | |
| 
 | |
| DROP VIEW v1;
 | |
| DROP TABLE t1, t2;
 | |
| 
 | |
| --echo # End of 5.1 tests
 | |
| 
 | |
| --echo #
 | |
| --echo # LP bug#694450 Wrong result with non-standard GROUP BY + ORDER BY
 | |
| --echo #
 | |
| SET SESSION SQL_MODE='ONLY_FULL_GROUP_BY';
 | |
| CREATE TABLE t1 (
 | |
| f1 int(11), f2 int(11), f3 datetime, f4 varchar(1), PRIMARY KEY (f1)) ;
 | |
| INSERT IGNORE INTO t1 VALUES ('1','9','2004-10-11 18:13','x'),('2','5','2004-03-07 14:02','g'),('3','1','2004-04-09 09:38','o'),('4','0','1900-01-01 00:00','g'),('5','1','2009-02-19 02:05','v');
 | |
| 
 | |
| # This must return an error, but instead returns 1 row
 | |
| SELECT alias2.f3 AS field1 , alias2.f1 AS field2 FROM t1 AS alias1 JOIN t1 AS alias2 ON alias2.f1 = alias1.f2 AND alias2.f1 != alias1.f4 GROUP BY field1 , field2 ORDER BY alias1.f2 , field2;
 | |
| 
 | |
| # This returns several rows
 | |
| SELECT alias2.f3 AS field1 , alias2.f1 AS field2 FROM t1 AS alias1 JOIN t1 AS alias2 ON alias2.f1 = alias1.f2 AND alias2.f1 != alias1.f4 GROUP BY field1 , field2 ;
 | |
| SET SESSION SQL_MODE=default;
 | |
| drop table t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # LP bug#967242 Wrong result (extra rows, not grouped) with JOIN, AND in ON condition, multi-part key, GROUP BY, OR in WHERE
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 ( a VARCHAR(1) ) ENGINE=MyISAM;
 | |
| INSERT INTO t1 VALUES ('x');
 | |
| CREATE TABLE t2 ( b INT, c VARCHAR(1), KEY (c, b) ) ENGINE=MyISAM;
 | |
| INSERT INTO t2 VALUES
 | |
| (4, 'd'),(8, 'g'),(3, 'x'),(3, 'f'),
 | |
| (0, 'p'),(3, 'j'),(8, 'c');
 | |
| 
 | |
| SELECT t2_1.b as zzz
 | |
| FROM t1 JOIN t2 AS t2_1 JOIN t2 AS t2_2
 | |
| ON (t2_2.b = t2_1.b ) AND (t2_2.c = t2_1.c )
 | |
| WHERE
 | |
| rand() + 1 > 0 OR
 | |
| a = t2_1.c
 | |
| GROUP BY zzz;
 | |
| 
 | |
| SELECT t2_1.b as zzz
 | |
| FROM t1 JOIN t2 AS t2_1 JOIN t2 AS t2_2
 | |
| ON (t2_2.b = t2_1.b ) AND (t2_2.c = t2_1.c )
 | |
| WHERE
 | |
| 1 > 0 OR
 | |
| a = t2_1.c
 | |
| GROUP BY zzz;
 | |
| 
 | |
| SELECT t2_1.b as zzz
 | |
| FROM t1 JOIN t2 AS t2_1 JOIN t2 AS t2_2
 | |
| ON (t2_2.b = t2_1.b ) AND (t2_2.c = t2_1.c )
 | |
| WHERE
 | |
| t2_1.b + 1 > 0 OR
 | |
| a = t2_1.c
 | |
| GROUP BY zzz;
 | |
| 
 | |
| SET @save_optimizer_switch967242=@@optimizer_switch;
 | |
| SET optimizer_switch = 'in_to_exists=on';
 | |
| 
 | |
| SELECT t2_1.b
 | |
| FROM t1 JOIN t2 AS t2_1 JOIN t2 AS t2_2
 | |
|     ON (t2_2.b = t2_1.b ) AND (t2_2.c = t2_1.c )
 | |
| WHERE
 | |
|   ( SELECT COUNT(*) FROM t2 ) IS NOT NULL
 | |
|   OR a = t2_1.c
 | |
| GROUP BY t2_1.b;
 | |
| SET optimizer_switch=@save_optimizer_switch967242;
 | |
| 
 | |
| drop table t1, t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug#12578908: SELECT SQL_BUFFER_RESULT OUTPUTS TOO MANY 
 | |
| --echo #               ROWS WHEN GROUP IS OPTIMIZED AWAY
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (col1 int, col2 int) ;
 | |
| INSERT INTO t1 VALUES (10,1),(11,7);
 | |
| 
 | |
| CREATE TABLE t2 (col1 int, col2 int) ;
 | |
| INSERT INTO t2 VALUES (10,8);
 | |
| 
 | |
| let $q_body=t2.col2 FROM t2 JOIN t1 ON t1.col1 GROUP BY t2.col2;
 | |
| 
 | |
| --echo
 | |
| --eval EXPLAIN SELECT SQL_BUFFER_RESULT $q_body
 | |
| --eval SELECT SQL_BUFFER_RESULT $q_body
 | |
| --echo
 | |
| --eval EXPLAIN SELECT $q_body
 | |
| --eval SELECT $q_body
 | |
| 
 | |
| --echo
 | |
| DROP TABLE t1,t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # BUG#12640437: USING SQL_BUFFER_RESULT RESULTS IN A
 | |
| --echo #               DIFFERENT QUERY OUTPUT
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   a int,
 | |
|   b varchar(1),
 | |
|   KEY (b,a)
 | |
| ) CHARSET=latin1;
 | |
| INSERT INTO t1 VALUES
 | |
|   (1,NULL),(0,'a'),(1,NULL),(0,'a'), (1,'a'),(0,'a'),(2,'a'),(1,'a');
 | |
| ANALYZE TABLE t1;
 | |
| 
 | |
| let $query=
 | |
|   SELECT SQL_BUFFER_RESULT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
 | |
| 
 | |
| --echo
 | |
| --eval EXPLAIN $query
 | |
| --echo
 | |
| --eval $query
 | |
| 
 | |
| let $query= SELECT MIN(a), b FROM t1 WHERE t1.b = 'a' GROUP BY b;
 | |
| --echo
 | |
| --eval EXPLAIN $query
 | |
| --echo
 | |
| --eval $query
 | |
| 
 | |
| --echo
 | |
| DROP TABLE t1;
 | |
| 
 | |
| 
 | |
| #
 | |
| # Bug#19880368 : GROUP_CONCAT CRASHES AFTER DUMP_LEAF_KEY
 | |
| #
 | |
| create table t1 (a int, b int);
 | |
| insert into t1 values (1,11), (1,12), (2,22),(2,23), (4,44),(4,45);
 | |
| create table t2 (c int, d int);
 | |
| insert into t2 values (1,11), (2,22), (4,44);
 | |
| select distinct a,sum(b), (select d from t2 where c=a order by max(b) limit 1) from t1 group by a order by max(b);
 | |
| drop table t1, t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # LP bug#993726 Wrong result from a query with ALL subquery predicate in WHERE
 | |
| --echo #
 | |
| CREATE TABLE t1(a INT);
 | |
| INSERT INTO t1 VALUES (0);
 | |
| SELECT 1 FROM t1 WHERE 1 > ALL(SELECT 1 FROM t1 WHERE a!=0);
 | |
| SELECT max(1) FROM t1 WHERE a!=0;
 | |
| drop table t1;
 | |
| 
 | |
| --echo # End of 5.2 tests
 | |
| 
 | |
| --echo #
 | |
| --echo # lp:872702: Crash in add_ref_to_table_cond() when grouping by a PK
 | |
| --echo #
 | |
| CREATE TABLE t1 (a int, PRIMARY KEY (a)) ;
 | |
| INSERT INTO t1 VALUES (14),(15),(16),(17),(18),(19),(20);
 | |
| 
 | |
| CREATE TABLE t2 (a int) ;
 | |
| 
 | |
| SELECT a
 | |
| FROM t1
 | |
| WHERE a = (
 | |
|         SELECT t2.a
 | |
|         FROM t2
 | |
| ) OR t1.a = 73
 | |
| GROUP BY 1;
 | |
| DROP TABLE t1, t2;
 | |
| 
 | |
| #
 | |
| # MDEV-736 LP:1004615 - Unexpected warnings "Encountered illegal value '' when converting to DECIMAL" on a query with aggregate functions and GROUP BY
 | |
| #
 | |
| 
 | |
| #the view protocol creates 
 | |
| # an additional util connection and other statistics data
 | |
| --disable_ps2_protocol
 | |
| --disable_view_protocol
 | |
| --disable_cursor_protocol
 | |
| FLUSH STATUS; # this test case *must* use Aria temp tables
 | |
| 
 | |
| CREATE TABLE t1 (f1 INT, f2 decimal(20,1), f3 blob);
 | |
| INSERT INTO t1 values(11,NULL,'blob'),(11,NULL,'blob');
 | |
| SELECT f3, MIN(f2) FROM t1 GROUP BY f1 LIMIT 1;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| --echo the value below *must* be 1
 | |
| show status like 'Created_tmp_disk_tables';
 | |
| --enable_cursor_protocol
 | |
| --enable_view_protocol
 | |
| --enable_ps2_protocol
 | |
| 
 | |
| --echo #
 | |
| --echo #  Bug #1002146: Unneeded filesort if usage of join buffer is not allowed
 | |
| --echo #  (bug mdev-645)
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (pk int PRIMARY KEY, a int, INDEX idx(a));
 | |
| INSERT INTO t1 VALUES (3,2), (2,3), (5,3), (6,4);
 | |
| 
 | |
| CREATE TABLE t2 (pk int PRIMARY KEY, a int, INDEX idx(a));
 | |
| INSERT INTO t2 VALUES (9,0), (10,3), (6,4), (1,6), (3,100), (5,200);
 | |
| 
 | |
| set join_cache_level=0;
 | |
| 
 | |
| EXPLAIN
 | |
| SELECT t2.a FROM t2 STRAIGHT_JOIN t1 ON t2.a <> 0 WHERE t2.a <> 6
 | |
|   GROUP BY t2.a;
 | |
| SELECT t2.a FROM t2 STRAIGHT_JOIN t1 ON t2.a <> 0 WHERE t2.a <> 6
 | |
|   GROUP BY t2.a;
 | |
| 
 | |
| set join_cache_level=default;
 | |
| 
 | |
| set @save_optimizer_switch=@@optimizer_switch;
 | |
| set optimizer_switch='outer_join_with_cache=off';
 | |
| 
 | |
| EXPLAIN
 | |
| SELECT t2.a FROM t2 LEFT JOIN t1 ON t2.a <> 0 WHERE t2.a <> 6
 | |
|   GROUP BY t2.a;
 | |
| SELECT t2.a FROM t2 LEFT JOIN t1 ON t2.a <> 0 WHERE t2.a <> 6
 | |
|   GROUP BY t2.a;
 | |
| 
 | |
| set optimizer_switch=@save_optimizer_switch;
 | |
| 
 | |
| 
 | |
| DROP TABLE t1,t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-5104 crash in Item_field::used_tables with broken order by
 | |
| --echo #
 | |
| 
 | |
| --error ER_BAD_FIELD_ERROR
 | |
| (select 1 order by x(y)) order by 1;
 | |
| 
 | |
| --echo # End of 5.3 tests
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug#49771: Incorrect MIN (date) when minimum value is 0000-00-00
 | |
| --echo #
 | |
| CREATE TABLE t1 (f1 int, f2 DATE);
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,'2004-04-19'), (1,'0000-00-00'), (1,'2004-04-18'),
 | |
| (2,'2004-05-19'), (2,'0001-01-01'), (3,'2004-04-10');
 | |
| 
 | |
| SELECT MIN(f2),MAX(f2) FROM t1;
 | |
| SELECT f1,MIN(f2),MAX(f2) FROM t1 GROUP BY 1;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| 
 | |
| CREATE TABLE t1 ( f1 int, f2 time);
 | |
| INSERT INTO t1 VALUES (1,'01:27:35'), (1,'06:11:01'), (2,'19:53:05'),
 | |
| (2,'21:44:25'), (3,'10:55:12'), (3,'05:45:11'), (4,'00:25:00');
 | |
| 
 | |
| SELECT MIN(f2),MAX(f2) FROM t1;
 | |
| SELECT f1,MIN(f2),MAX(f2) FROM t1 GROUP BY 1;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| --echo #End of test#49771
 | |
| 
 | |
| --echo #
 | |
| --echo # Test of bug in GROUP_CONCAT with ROLLUP
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 ( b VARCHAR(8) NOT NULL, a INT NOT NULL ) ENGINE=MyISAM;
 | |
| INSERT INTO t1 (a,b) VALUES (1,'c'),(2,'v');
 | |
| 
 | |
| CREATE TABLE t2 ( c VARCHAR(8), d INT, KEY (c, d) ) ENGINE=MyISAM;
 | |
| INSERT INTO t2 VALUES ('v',6),('c',4),('v',3);
 | |
| 
 | |
| SELECT b, GROUP_CONCAT( a, b ORDER BY a, b )
 | |
| FROM t1 JOIN t2 ON c = b GROUP BY b;
 | |
| 
 | |
| SELECT b, GROUP_CONCAT( a, b ORDER BY a, b )
 | |
| FROM t1 JOIN t2 ON c = b GROUP BY b WITH ROLLUP;
 | |
| 
 | |
| DROP TABLE t1,t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-24855 ER_CRASHED_ON_USAGE or Assertion `length <= column->length'
 | |
| --echo # failed in ma_blockrec.c
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (a BIT(5), c BINARY(179));
 | |
| INSERT INTO t1 VALUES (b'1100','foo'),(b'0','bar');
 | |
| --disable_result_log
 | |
| SELECT c, GROUP_CONCAT(CASE NULL WHEN 0 THEN a END, CASE 'foo' WHEN c THEN 1 END) AS f FROM t1 GROUP BY ExtractValue('<a></a>', '/a'), UUID();
 | |
| --enable_result_log
 | |
| DROP TABLE t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-6129: Server crashes during UNION with ORDER BY field IS NULL
 | |
| --echo #
 | |
| 
 | |
| SET sql_mode='ONLY_FULL_GROUP_BY';
 | |
| SELECT 1 AS test UNION SELECT 2 AS test ORDER BY test IS NULL ASC;
 | |
| SET sql_mode='';
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-6484: Assertion `tab->ref.use_count' failed on query with joins, constant table, multi-part key
 | |
| --echo #
 | |
| CREATE TABLE t1 (i1 INT, c1 VARCHAR(1)) ENGINE=MyISAM;
 | |
| INSERT INTO t1 VALUES (6,'b');
 | |
| 
 | |
| CREATE TABLE t2 (pk2 INT, i2 INT, c2 VARCHAR(1), PRIMARY KEY(pk2), KEY(pk2,i2)) ENGINE=MyISAM;
 | |
| INSERT INTO t2 VALUES (1,2,'s'),(2,4,'r'),(3,8,'m'),(4,4,'b'),(5,4,'x'),(6,7,'g'),(7,4,'p');
 | |
| 
 | |
| SELECT i2 FROM t1 AS t1a STRAIGHT_JOIN ( t2 INNER JOIN t1 AS t1b ON (t1b.c1 = c2) ) ON (t1b.i1 = pk2 ) 
 | |
| WHERE t1a.c1 = c2 GROUP BY i2;
 | |
| 
 | |
| DROP TABLE t1,t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-6855
 | |
| --echo # MIN(*) with subqueries with IS NOT NULL in WHERE clause crashed.
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (i INT, c VARCHAR(3), KEY(c,i)) ENGINE=MyISAM;
 | |
| INSERT INTO t1 VALUES (7,'foo'),(0,'bar');
 | |
| 
 | |
| CREATE TABLE t2 (j INT) ENGINE=MyISAM;
 | |
| INSERT INTO t2 VALUES (0),(8),(1),(8),(9);
 | |
| 
 | |
| SELECT MAX(i), c FROM t1 
 | |
| WHERE c != 'qux' AND ( SELECT SUM(j) FROM t1, t2 ) IS NOT NULL GROUP BY c;
 | |
| drop table t1,t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # ONLY_FULL_GROUP_BY references
 | |
| --echo #
 | |
| 
 | |
| set @save_sql_mode = @@sql_mode;
 | |
| set sql_mode='ONLY_FULL_GROUP_BY';
 | |
| create table t1 (a int, b int);
 | |
| select a+b as x from t1 group by x having x > 1;
 | |
| select a as x from t1 group by x having x > 1;
 | |
| select a from t1 group by a having a > 1;
 | |
| drop table t1;
 | |
| set sql_mode= @save_sql_mode;
 | |
| 
 | |
| #
 | |
| # MDEV-7826 Server crashes in Item_subselect::enumerate_field_refs_processor
 | |
| #
 | |
| create table t1 (f1 int);
 | |
| insert into t1 values (5),(9);
 | |
| create table t2 (f2 int);
 | |
| insert into t2 values (0),(6);
 | |
| create table t3 (f3 int);
 | |
| insert into t3 values (6),(3);
 | |
| create table t4 (f4 int);
 | |
| insert into t4 values (1),(0);
 | |
| --error ER_ILLEGAL_REFERENCE
 | |
| select
 | |
| (select min(f1) from t1 where f1 in (select min(f4) from t2)) as field7,
 | |
| (select count(*) from t3 where f3 in (select max(f4) from t2 group by field7))
 | |
| from t4;
 | |
| drop table t1, t2, t3, t4;
 | |
| 
 | |
| #
 | |
| # MDEV-13180 Unused left join causes server crash
 | |
| #
 | |
| create table t1 (i1 int);
 | |
| insert into t1 values (1);
 | |
| create table t2 (i int);
 | |
| insert into t2 values (2);
 | |
| select 1 from t1 left join t2 b on b.i = (select max(b.i) from t2);
 | |
| drop table t1, t2;
 | |
| 
 | |
| 
 | |
| #
 | |
| # MDEV-12489 The select stmt may fail due to "having clause is ambiguous" unexpected
 | |
| #
 | |
| create table t1 (c1 int, c2 int);
 | |
| create table t2 (c1 int, c2 int);
 | |
| select t1.c1 as c1, t2.c2 as c1 from t1, t2 where t1.c1 < 20 and t2.c2 > 5 group by t1.c1, t2.c2 having t1.c1 < 3;
 | |
| drop table t1, t2;
 | |
| 
 | |
| #
 | |
| # MDEV-12350: Heap corruption, overrun buffer, ASAN errors, server crash in my_fill_8bit / filesort
 | |
| #
 | |
| 
 | |
| SET @old_sort_buff_size = @@sort_buffer_size;
 | |
| SET @@sort_buffer_size=256*1024;
 | |
| CREATE TABLE t1 (c INT) ENGINE=MyISAM;
 | |
| INSERT INTO t1 VALUES
 | |
|   (2011),(1977),(1982),(2027),(2023),(NULL),(NULL),(2004),(1974),(2032),
 | |
|   (1993),(NULL),(1995),(2034),(NULL),(2009),(1900),(NULL),(2025),(1900),
 | |
|   (2033),(1900),(2012),(NULL),(2009),(1992),(1974),(1974),(2012),(2028),
 | |
|   (2007),(2012),(1900),(1983),(1900),(2010),(1987),(1994),(1981),(2032),
 | |
|   (2010),(1989),(2014),(1900),(1900),(1976),(1978),(2007),(2030),(NULL),
 | |
|   (2002),(1997),(1900),(NULL),(2000),(2027),(1975),(2026),(1975),(2026),
 | |
|   (2029),(1977),(1900),(1900),(2031),(1993),(1986),(2012),(1979),(2013),
 | |
|   (1994),(2014),(2025),(2006),(1971),(1974),(2021),(2011),(NULL),(1991),
 | |
|   (2001),(1977),(2023),(2012),(1900),(1978),(1998),(NULL),(1988),(1999),
 | |
|   (2017),(2008),(1976),(1900),(2005),(2030),(2023),(1900),(1978),(1990),
 | |
|   (1978),(1987),(2030),(1900),(2034),(2006),(2015),(2001),(2019),(2024),
 | |
|   (2030),(1989),(1997),(2007),(2023),(1994),(1971),(2011),(2011),(2015),
 | |
|   (1984),(1978),(1979),(1989),(2008),(2030);
 | |
|   
 | |
| SELECT ExtractValue('<a></a>','/a') AS f1, SPACE(c) AS f2 FROM t1 GROUP BY f1, f2 WITH ROLLUP;
 | |
| SET @@sort_buffer_size = @old_sort_buff_size;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| #
 | |
| # End of MariaDB 5.5 tests
 | |
| #
 | |
| 
 | |
| --echo #
 | |
| --echo # Bug #58782
 | |
| --echo # Missing rows with SELECT .. WHERE .. IN subquery 
 | |
| --echo # with full GROUP BY and no aggr
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (
 | |
|   pk INT NOT NULL,
 | |
|   col_int_nokey INT,
 | |
|   PRIMARY KEY (pk)
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 VALUES (10,7);
 | |
| INSERT INTO t1 VALUES (11,1);
 | |
| INSERT INTO t1 VALUES (12,5);
 | |
| INSERT INTO t1 VALUES (13,3);
 | |
| 
 | |
| ## original query:
 | |
| 
 | |
| SELECT pk AS field1, col_int_nokey AS field2 
 | |
| FROM t1 
 | |
| WHERE col_int_nokey > 0
 | |
| GROUP BY field1, field2;
 | |
| 
 | |
| ## store query results in a new table:
 | |
| 
 | |
| CREATE TABLE where_subselect
 | |
|   SELECT pk AS field1, col_int_nokey AS field2
 | |
|   FROM t1
 | |
|   WHERE col_int_nokey > 0
 | |
|   GROUP BY field1, field2
 | |
| ;
 | |
| 
 | |
| ## query the new table and compare to original using WHERE ... IN():
 | |
| 
 | |
| SELECT * 
 | |
| FROM where_subselect
 | |
| WHERE (field1, field2) IN (
 | |
|   SELECT pk AS field1, col_int_nokey AS field2
 | |
|   FROM t1
 | |
|   WHERE col_int_nokey > 0
 | |
|   GROUP BY field1, field2
 | |
| );
 | |
| 
 | |
| DROP TABLE t1;
 | |
| DROP TABLE where_subselect;
 | |
| 
 | |
| --echo # End of Bug #58782
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-8988: Apparently valid SQL query gives wrong result (nested WHERE)
 | |
| --echo #
 | |
| create table t0(a int);
 | |
| insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
 | |
| 
 | |
| create table t1 (a int, b int, c int);
 | |
| insert into t1 select A.a + 10*B.a, A.a, A.a + 10*B.a from t0 A, t0 B;
 | |
| insert into t1 values (NULL, NULL, NULL);
 | |
| 
 | |
| create table t2 (c int, col1 int, key(c));
 | |
| insert into t2 select t1.a, 100000 from t1;
 | |
| analyze table t2;
 | |
| 
 | |
| explain 
 | |
| select 
 | |
|   max(a)+ (select col1 from t2 where t2.c=t1.c)
 | |
| from t1 
 | |
| group by t1.b;
 | |
| 
 | |
| select 
 | |
|   max(a) + (select col1 from t2 where t2.c=t1.c)
 | |
| from t1 
 | |
| group by t1.b;
 | |
| 
 | |
| drop table t0,t1,t2;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-9602 crash in st_key::actual_rec_per_key when group by constant
 | |
| --echo #
 | |
| 
 | |
| create table t1 (a date not null,unique (a)) engine=innodb;
 | |
| select distinct a from t1 group by 'a';
 | |
| insert into t1 values("2001-02-02"),("2001-02-03");
 | |
| select distinct a from t1 group by 'a';
 | |
| drop table t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-10324: Server crash in get_sel_arg_for_keypart or Assertion `n < size()' failed in Mem_root_array
 | |
| --echo #
 | |
| CREATE TABLE t1 (
 | |
|   job_id int(10) unsigned NOT NULL AUTO_INCREMENT,
 | |
|   job_cmd varbinary(60) NOT NULL DEFAULT '',
 | |
|   job_namespace int(11) NOT NULL,
 | |
|   job_title varbinary(255) NOT NULL,
 | |
|   job_params blob NOT NULL,
 | |
|   job_timestamp varbinary(14) DEFAULT NULL,
 | |
|   job_random int(10) unsigned NOT NULL DEFAULT '0',
 | |
|   job_token varbinary(32) NOT NULL DEFAULT '',
 | |
|   job_token_timestamp varbinary(14) DEFAULT NULL,
 | |
|   job_sha1 varbinary(32) NOT NULL DEFAULT '',
 | |
|   job_attempts int(10) unsigned NOT NULL DEFAULT '0',
 | |
|   PRIMARY KEY (job_id),
 | |
|   KEY job_cmd (job_cmd,job_namespace,job_title,job_params(128)),
 | |
|   KEY job_timestamp (job_timestamp),
 | |
|   KEY job_sha1 (job_sha1),
 | |
|   KEY job_cmd_token (job_cmd,job_token,job_random),
 | |
|   KEY job_cmd_token_id (job_cmd,job_token,job_id)
 | |
| );
 | |
|  
 | |
| INSERT INTO t1 VALUES 
 | |
|     (NULL, 'foo', 1, 'foo', 'foo', 'foo', 1, 'foo', 'foo', 'foo', 1),
 | |
|     (NULL, 'bar', 2, 'bar', 'bar', 'bar', 2, 'bar', 'bar', 'bar', 2);
 | |
|     
 | |
| SELECT DISTINCT job_cmd  FROM t1 WHERE job_cmd IN ('foobar','null');
 | |
| drop table t1;
 | |
| 
 | |
| CREATE TABLE t1 (f1 INT NOT NULL, f2 VARCHAR(3) NOT NULL, KEY(f1), KEY(f2, f1));
 | |
| INSERT INTO t1 VALUES (0,'foo'),(1,'bar');
 | |
| SELECT 1 IN ( SELECT COUNT( DISTINCT f2 ) FROM t1 WHERE f1 <= 4 );
 | |
| drop table t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-20922: Adding an order by changes the query results
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1(a int, b int);
 | |
| INSERT INTO t1 values (1, 100), (2, 200), (3, 100), (4, 200), (5, 200);
 | |
| 
 | |
| create view v1 as select a, b+1 as x from t1;
 | |
| 
 | |
| SELECT x, COUNT(DISTINCT a) AS y FROM v1 GROUP BY x ORDER BY y;
 | |
| SELECT b+1 AS x, COUNT(DISTINCT a) AS y FROM t1 GROUP BY x ORDER BY y;
 | |
| 
 | |
| drop view v1;
 | |
| drop table t1;
 | |
| --echo #
 | |
| --echo # MDEV-10694 - SIGFPE and/or huge memory allocation in maria_create with distinct/group by/ rollup
 | |
| --echo #
 | |
| create table t1 (a int,b int) ;
 | |
| insert into t1 values(-126,7),(1,1),(0,0),(-1,1),(351,65534);
 | |
| select distinct 1 from t1 group by a,b with rollup limit 1;
 | |
| drop table t1;
 | |
| 
 | |
| #
 | |
| # MDEV-12575: Server crash in AGGR_OP::put_record or in JOIN_CACHE::free
 | |
| # or Invalid write in JOIN::make_aggr_tables_info
 | |
| #
 | |
| 
 | |
| CREATE TABLE t1 ( pk int, i1 int, v1 varchar(1));
 | |
| explain
 | |
| SELECT 1 FROM t1
 | |
| GROUP BY REPEAT((BINARY pk), v1), AES_DECRYPT((@A := i1), 20852) WITH ROLLUP HAVING LOAD_FILE('a') ;
 | |
| SELECT 1 FROM t1
 | |
| GROUP BY REPEAT((BINARY pk), v1), AES_DECRYPT((@A := i1), 20852) WITH ROLLUP HAVING LOAD_FILE('a') ;
 | |
| drop table t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-22019: Sig 11 in next_breadth_first_tab | max_sort_length setting + double
 | |
| --echo # GROUP BY leads to crash
 | |
| --echo #
 | |
| 
 | |
| CALL mtr.add_suppression("Out of sort memory");
 | |
| CALL mtr.add_suppression("Sort aborted");
 | |
| SET @save_max_sort_length= @@max_sort_length;
 | |
| SET max_sort_length=2000000;
 | |
| --error ER_OUT_OF_SORTMEMORY
 | |
| SELECT * FROM information_schema.tables t JOIN information_schema.columns c
 | |
| ON t.table_schema=c.table_schema
 | |
| WHERE c.table_schema=(SELECT COUNT(*) FROM INFORMATION_SCHEMA.columns GROUP BY column_type)
 | |
| GROUP BY t.table_name;
 | |
| SET max_sort_length= @save_max_sort_length;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-23826: ORDER BY in view definition leads to wrong result with GROUP BY on query using view
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1
 | |
| (
 | |
|   id INT PRIMARY KEY AUTO_INCREMENT,
 | |
|   dt datetime,
 | |
|   INDEX(dt),
 | |
|   foo int
 | |
| );
 | |
| 
 | |
| INSERT INTO t1 VALUES (1,'2020-09-26 12:00:00',1);
 | |
| INSERT INTO t1 VALUES (2,'2020-09-26 13:00:00',1);
 | |
| INSERT INTO t1 VALUES (3,'2020-09-27 13:00:00',1);
 | |
| INSERT INTO t1 VALUES (4,'2020-09-27 12:00:00',1);
 | |
| INSERT INTO t1 VALUES (5,'2020-09-28 12:00:00',1);
 | |
| INSERT INTO t1 VALUES (6,'2020-09-28 13:00:00',1);
 | |
| INSERT INTO t1 VALUES (7,'2020-09-25 12:00:00',1);
 | |
| INSERT INTO t1 VALUES (8,'2020-09-25 13:00:00',1);
 | |
| INSERT INTO t1 VALUES (9,'2020-09-26 13:00:00',1);
 | |
| 
 | |
| CREATE VIEW v1 AS SELECT * FROM t1;
 | |
| CREATE VIEW v2 AS SELECT * FROM t1 ORDER BY dt;
 | |
| SELECT dt, sum(foo) AS foo FROM v1 WHERE dt>DATE_SUB('2020-09-27 00:00:00', INTERVAL 3 DAY) GROUP BY dt;
 | |
| SELECT dt, sum(foo) AS foo FROM v2 WHERE dt>DATE_SUB('2020-09-27 00:00:00', INTERVAL 3 DAY) GROUP BY dt;
 | |
| 
 | |
| DROP TABLE t1;
 | |
| DROP VIEW v1,v2;
 | |
| 
 | |
| --echo #
 | |
| --echo # End of 10.2 tests
 | |
| --echo #
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-16170
 | |
| --echo # Server crashes in Item_null_result::type_handler on SELECT with ROLLUP
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (d DATE);
 | |
| INSERT INTO t1 VALUES ('2032-10-08');
 | |
| SELECT d != '2023-03-04' AS f, COUNT(*) FROM t1 GROUP BY d WITH ROLLUP;
 | |
| DROP TABLE t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-24710 Uninitialized value upon CREATE .. SELECT ... VALUE
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (a VARCHAR(8) NOT NULL DEFAULT '');
 | |
| INSERT INTO t1 (a) VALUES ('foo');
 | |
| CREATE TABLE t2 AS SELECT MAX(a) AS f1, a AS f2 FROM t1 WHERE VALUE(a) IS NOT NULL;
 | |
| SELECT * from t2;
 | |
| SELECT MAX(a) AS f1, a AS f2 FROM t1 WHERE VALUE(a) IS NOT NULL;
 | |
| SELECT MAX(a) AS f1, a AS f2 FROM t1 WHERE 1=0;
 | |
| drop table t1,t2;
 | |
| 
 | |
| --echo # Extra test by to check the fix for MDEV-24710
 | |
| 
 | |
| create table t20 (pk int primary key, a int);
 | |
| insert into t20 values (1,1);create table t21 (pk int primary key, b int not null);
 | |
| insert into t21 values (1,1);
 | |
| create table t22 (a int);
 | |
| insert into t22 values (1),(2);
 | |
| select a, (select max(t21.b) from t20 left join t21 on t21.pk=t20.a+10
 | |
|            where t20.pk=1 and rand(123) < 0.5) as SUBQ from t22;
 | |
| drop table t20, t21, t22;
 | |
| 
 | |
| --echo #
 | |
| --echo # End of 10.3 tests
 | |
| --echo #
 | |
| 
 | |
| --echo #
 | |
| --echo # MDEV-29351 SIGSEGV when doing forward reference of item in select list
 | |
| --echo #
 | |
| 
 | |
| CREATE TABLE t1 (a INT);
 | |
| --error ER_BAD_FIELD_ERROR
 | |
| UPDATE t1 SET c=1 ORDER BY (SELECT c);
 | |
| --error ER_BAD_FIELD_ERROR
 | |
| UPDATE t1 SET c=1 ORDER BY (SELECT c);
 | |
| DROP TABLE t1;
 | |
| 
 | |
| --echo #
 | |
| --echo # End of 10.5 tests
 | |
| --echo #
 | |
| 
 | |
| --echo #
 | |
| --echo # Test new group_min_max optimization
 | |
| --echo #
 | |
| 
 | |
| create table t1 (a int, b int, c int, key(a,b,c));
 | |
| insert into t1 select mod(seq,23),mod(seq,13), mod(seq,5) from seq_1_to_10000;
 | |
| 
 | |
| explain select a from t1 where a in (1,2,3) group by a;
 | |
| explain select a from t1 where a in (1,2,3) or a = 22 group by a;
 | |
| explain select a from t1 where a in (1,2,3) and a < 3 group by a;
 | |
| explain select a,b from t1 where (a) in (1,2,3) and b in (5,6,7) group by a,b;
 | |
| explain select a,b from t1 where (a,b) in ((1,1),(2,2),(3,3)) group by a,b;
 | |
| explain select a,b,c from t1 where (a,b) in ((1,1),(2,2),(3,3)) and c=3 group by a,b,c;
 | |
| 
 | |
| --echo # Will not use index for group-by
 | |
| explain select a from t1 where a in (1,2,3) and b>1 group by a;
 | |
| explain select a from t1 where a in (1,2,3) and c=1 group by a;
 | |
| drop table t1;
 |