diff options
author | unknown <holyfoot/hf@mysql.com/hfmain.(none)> | 2007-07-31 10:46:04 +0500 |
---|---|---|
committer | unknown <holyfoot/hf@mysql.com/hfmain.(none)> | 2007-07-31 10:46:04 +0500 |
commit | 791584ae0d57ce1f31b4652c1dd9cb4edee8526e (patch) | |
tree | 7f93a63d138c3bb1107b87f1d770f853b438e461 | |
parent | 1a2d2117ffcd9641ed472039f29c8996023e7b60 (diff) | |
download | mariadb-git-791584ae0d57ce1f31b4652c1dd9cb4edee8526e.tar.gz |
Bug #29717 INSERT INTO SELECT inserts values even if
SELECT statement itself returns empty.
As a result of this bug 'SELECT AGGREGATE_FUNCTION(fld) ... GROUP BY'
can return one row instead of an empty result set.
When GROUP BY only has fields of constant tables
(with a single row), the optimizer deletes the group_list.
After that we lose the information about whether we had an
GROUP BY statement. Though it's important
as SELECT min(x) from empty_table; and
SELECT min(x) from empty_table GROUP BY y; have to return
different results - the first query should return one row,
second - an empty result set.
So here we add the 'group_optimized_away' flag to remember this case
when GROUP BY exists in the query and is removed
by the optimizer, and check this flag in end_send_group()
mysql-test/r/group_by.result:
Bug #29717 INSERT INTO SELECT inserts values even if
SELECT statement itself returns empty.
test result
mysql-test/r/insert_select.result:
Bug #29717 INSERT INTO SELECT inserts values even if
SELECT statement itself returns empty.
test result
mysql-test/t/group_by.test:
Bug #29717 INSERT INTO SELECT inserts values even if
SELECT statement itself returns empty.
This is additional testcase that is more basic than the
original bug's testcase and has the same reason.
mysql-test/t/insert_select.test:
Bug #29717 INSERT INTO SELECT inserts values even if
SELECT statement itself returns empty.
test case
sql/sql_select.cc:
Bug #29717 INSERT INTO SELECT inserts values even if
SELECT statement itself returns empty.
Remember the 'GROUP BY was optimized away' case in the JOIN::group_optimized
and check this in the end_send_group()
sql/sql_select.h:
Bug #29717 INSERT INTO SELECT inserts values even if
SELECT statement itself returns empty.
JOIN::group_optimized member added to remember the 'GROUP BY optimied away'
case
-rw-r--r-- | mysql-test/r/group_by.result | 17 | ||||
-rw-r--r-- | mysql-test/r/insert_select.result | 26 | ||||
-rw-r--r-- | mysql-test/t/group_by.test | 23 | ||||
-rw-r--r-- | mysql-test/t/insert_select.test | 28 | ||||
-rw-r--r-- | sql/sql_select.cc | 4 | ||||
-rw-r--r-- | sql/sql_select.h | 9 |
6 files changed, 106 insertions, 1 deletions
diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result index 61b73dc7005..f717c16742f 100644 --- a/mysql-test/r/group_by.result +++ b/mysql-test/r/group_by.result @@ -818,3 +818,20 @@ a 2 1 DROP TABLE t1; +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; +avg(t2.f1) +SELECT avg(t2.f1) FROM t1, t2 where t2.f2 = 'SIR' GROUP BY t1.f1; +avg(t2.f1) +DROP TABLE t1, t2; diff --git a/mysql-test/r/insert_select.result b/mysql-test/r/insert_select.result index 1d7aef256e1..601eb2aa0bc 100644 --- a/mysql-test/r/insert_select.result +++ b/mysql-test/r/insert_select.result @@ -690,3 +690,29 @@ CREATE TABLE t1 (a int PRIMARY KEY); INSERT INTO t1 values (1), (2); INSERT INTO t1 SELECT a + 2 FROM t1 LIMIT 1; DROP TABLE t1; +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 COUNT(*) FROM t1; +COUNT(*) +1 +SELECT min(t2.f1) FROM t1, t2 where t2.f2 = 'SIR' GROUP BY t1.f1; +min(t2.f1) +INSERT INTO t1 (f2) +SELECT min(t2.f1) FROM t1, t2 where t2.f2 = 'SIR' GROUP BY t1.f1; +SELECT COUNT(*) FROM t1; +COUNT(*) +1 +SELECT * FROM t1; +f1 f2 +1 +DROP TABLE t1, t2; diff --git a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test index 064d46aa0c0..180299f7f4a 100644 --- a/mysql-test/t/group_by.test +++ b/mysql-test/t/group_by.test @@ -633,4 +633,27 @@ 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 diff --git a/mysql-test/t/insert_select.test b/mysql-test/t/insert_select.test index fcea489fcff..dfb313706dd 100644 --- a/mysql-test/t/insert_select.test +++ b/mysql-test/t/insert_select.test @@ -239,4 +239,32 @@ INSERT INTO t1 SELECT a + 2 FROM t1 LIMIT 1; 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 COUNT(*) FROM t1; + +SELECT min(t2.f1) FROM t1, t2 where t2.f2 = 'SIR' GROUP BY t1.f1; + +INSERT INTO t1 (f2) + SELECT min(t2.f1) FROM t1, t2 where t2.f2 = 'SIR' GROUP BY t1.f1; + +SELECT COUNT(*) FROM t1; +SELECT * FROM t1; +DROP TABLE t1, t2; + # End of 4.1 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 8b5664a7f96..8f0ad359f43 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -777,6 +777,7 @@ JOIN::optimize() order=0; // The output has only one row simple_order=1; select_distinct= 0; // No need in distinct for 1 row + group_optimized_away= 1; } calc_group_buffer(this, group_list); @@ -6896,7 +6897,8 @@ end_send_group(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)), if (!join->first_record || end_of_records || (idx=test_if_group_changed(join->group_fields)) >= 0) { - if (join->first_record || (end_of_records && !join->group)) + if (join->first_record || + (end_of_records && !join->group && !join->group_optimized_away)) { if (join->procedure) join->procedure->end_group(); diff --git a/sql/sql_select.h b/sql/sql_select.h index c61ef4fb92b..6227d6d2cc5 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -180,6 +180,14 @@ class JOIN :public Sql_alloc ROLLUP rollup; // Used with rollup bool select_distinct; // Set if SELECT DISTINCT + /* + If we have the GROUP BY statement in the query, + but the group_list was emptied by optimizer, this + flag is TRUE. + It happens when fields in the GROUP BY are from + constant table + */ + bool group_optimized_away; /* simple_xxxxx is set if ORDER/GROUP BY doesn't include any references @@ -276,6 +284,7 @@ class JOIN :public Sql_alloc ref_pointer_array_size= 0; zero_result_cause= 0; optimized= 0; + group_optimized_away= 0; fields_list= fields_arg; bzero((char*) &keyuse,sizeof(keyuse)); |