From 761a88ee0d5ada601e14509c4095794d9c4d0ae0 Mon Sep 17 00:00:00 2001 From: "iggy@rolltop.ignatz42.dyndns.org" <> Date: Tue, 28 Nov 2006 17:21:39 -0500 Subject: [PATCH 1/4] Bug#20836 Selecting into variables results in wrong results being returned This error is displayed anytime the SELECT statement needs a temp table to return correct results because the object (select_dumpvar) that represents variables named in the INTO clause stored the results before the temp table was considered. The problem was fixed by creating the necessary Item_func_set_user_var objects once the correct data is ready. --- mysql-test/r/distinct.result | 59 ++++++++++++++++++++++++++++++++ mysql-test/t/distinct.test | 65 ++++++++++++++++++++++++++++++++++++ sql/sql_class.cc | 48 ++++++++++++-------------- sql/sql_class.h | 3 +- 4 files changed, 147 insertions(+), 28 deletions(-) diff --git a/mysql-test/r/distinct.result b/mysql-test/r/distinct.result index 6cdf4063291..7334c9b2da4 100644 --- a/mysql-test/r/distinct.result +++ b/mysql-test/r/distinct.result @@ -566,3 +566,62 @@ a b 3 2 2 3 DROP TABLE t1; +DROP TABLE IF EXISTS t1; +CREATE TABLE t1 (id INT NOT NULL, fruit_id INT NOT NULL, fruit_name varchar(20) +default NULL); +INSERT INTO t1 VALUES (1,1,'ORANGE'); +INSERT INTO t1 VALUES (2,2,'APPLE'); +INSERT INTO t1 VALUES (3,2,'APPLE'); +INSERT INTO t1 VALUES (4,3,'PEAR'); +SELECT DISTINCT fruit_id, fruit_name INTO @v1, @v2 FROM t1 WHERE fruit_name = +'APPLE'; +SELECT @v1, @v2; +@v1 @v2 +2 APPLE +SELECT DISTINCT fruit_id, fruit_name INTO @v3, @v4 FROM t1 GROUP BY fruit_id, +fruit_name HAVING fruit_name = 'APPLE'; +SELECT @v3, @v4; +@v3 @v4 +2 APPLE +SELECT DISTINCT @v5:= fruit_id, @v6:= fruit_name INTO @v7, @v8 FROM t1 WHERE +fruit_name = 'APPLE'; +SELECT @v5, @v6, @v7, @v8; +@v5 @v6 @v7 @v8 +2 APPLE 2 APPLE +SELECT DISTINCT @v5 + fruit_id, CONCAT(@v6, fruit_name) INTO @v9, @v10 FROM t1 +WHERE fruit_name = 'APPLE'; +SELECT @v5, @v6, @v7, @v8, @v9, @v10; +@v5 @v6 @v7 @v8 @v9 @v10 +2 APPLE 2 APPLE 4 APPLEAPPLE +SELECT DISTINCT @v11:= @v5 + fruit_id, @v12:= CONCAT(@v6, fruit_name) INTO +@v13, @v14 FROM t1 WHERE fruit_name = 'APPLE'; +SELECT @v11, @v12, @v13, @v14; +@v11 @v12 @v13 @v14 +4 APPLEAPPLE 4 APPLEAPPLE +SELECT DISTINCT @v13, @v14 INTO @v15, @v16 FROM t1 WHERE fruit_name = 'APPLE'; +SELECT @v15, @v16; +@v15 @v16 +4 APPLEAPPLE +SELECT DISTINCT 2 + 2, 'Bob' INTO @v17, @v18 FROM t1 WHERE fruit_name = +'APPLE'; +SELECT @v17, @v18; +@v17 @v18 +4 Bob +DROP TABLE IF EXISTS t2; +CREATE TABLE t2 (fruit_id INT NOT NULL, fruit_name varchar(20) +default NULL); +SELECT DISTINCT fruit_id, fruit_name INTO OUTFILE +'../tmp/data1.tmp' FROM t1 WHERE fruit_name = 'APPLE'; +LOAD DATA INFILE '../tmp/data1.tmp' INTO TABLE t2; +SELECT DISTINCT @v19:= fruit_id, @v20:= fruit_name INTO OUTFILE +'../tmp/data2.tmp' FROM t1 WHERE fruit_name = 'APPLE'; +LOAD DATA INFILE '../tmp/data2.tmp' INTO TABLE t2; +SELECT @v19, @v20; +@v19 @v20 +2 APPLE +SELECT * FROM t2; +fruit_id fruit_name +2 APPLE +2 APPLE +DROP TABLE t1; +DROP TABLE t2; diff --git a/mysql-test/t/distinct.test b/mysql-test/t/distinct.test index 2a87427a2b6..a057eee8e37 100644 --- a/mysql-test/t/distinct.test +++ b/mysql-test/t/distinct.test @@ -389,4 +389,69 @@ explain SELECT DISTINCT a, b FROM t1 ORDER BY b; SELECT DISTINCT a, b FROM t1 ORDER BY b; DROP TABLE t1; +# +#Bug #20836: Selecting into variables results in wrong results being returned +# +--disable_warnings +DROP TABLE IF EXISTS t1; +--enable_warnings + +CREATE TABLE t1 (id INT NOT NULL, fruit_id INT NOT NULL, fruit_name varchar(20) +default NULL); + +INSERT INTO t1 VALUES (1,1,'ORANGE'); +INSERT INTO t1 VALUES (2,2,'APPLE'); +INSERT INTO t1 VALUES (3,2,'APPLE'); +INSERT INTO t1 VALUES (4,3,'PEAR'); + +SELECT DISTINCT fruit_id, fruit_name INTO @v1, @v2 FROM t1 WHERE fruit_name = +'APPLE'; +SELECT @v1, @v2; + +SELECT DISTINCT fruit_id, fruit_name INTO @v3, @v4 FROM t1 GROUP BY fruit_id, +fruit_name HAVING fruit_name = 'APPLE'; +SELECT @v3, @v4; + +SELECT DISTINCT @v5:= fruit_id, @v6:= fruit_name INTO @v7, @v8 FROM t1 WHERE +fruit_name = 'APPLE'; +SELECT @v5, @v6, @v7, @v8; + +SELECT DISTINCT @v5 + fruit_id, CONCAT(@v6, fruit_name) INTO @v9, @v10 FROM t1 +WHERE fruit_name = 'APPLE'; +SELECT @v5, @v6, @v7, @v8, @v9, @v10; + +SELECT DISTINCT @v11:= @v5 + fruit_id, @v12:= CONCAT(@v6, fruit_name) INTO +@v13, @v14 FROM t1 WHERE fruit_name = 'APPLE'; +SELECT @v11, @v12, @v13, @v14; + +SELECT DISTINCT @v13, @v14 INTO @v15, @v16 FROM t1 WHERE fruit_name = 'APPLE'; +SELECT @v15, @v16; + +SELECT DISTINCT 2 + 2, 'Bob' INTO @v17, @v18 FROM t1 WHERE fruit_name = +'APPLE'; +SELECT @v17, @v18; + +--disable_warnings +DROP TABLE IF EXISTS t2; +--enable_warnings + +CREATE TABLE t2 (fruit_id INT NOT NULL, fruit_name varchar(20) +default NULL); + +SELECT DISTINCT fruit_id, fruit_name INTO OUTFILE +'../tmp/data1.tmp' FROM t1 WHERE fruit_name = 'APPLE'; +LOAD DATA INFILE '../tmp/data1.tmp' INTO TABLE t2; +--exec rm $MYSQL_TEST_DIR/var/tmp/data1.tmp + +SELECT DISTINCT @v19:= fruit_id, @v20:= fruit_name INTO OUTFILE +'../tmp/data2.tmp' FROM t1 WHERE fruit_name = 'APPLE'; +LOAD DATA INFILE '../tmp/data2.tmp' INTO TABLE t2; +--exec rm $MYSQL_TEST_DIR/var/tmp/data2.tmp + +SELECT @v19, @v20; +SELECT * FROM t2; + +DROP TABLE t1; +DROP TABLE t2; + # End of 4.1 tests diff --git a/sql/sql_class.cc b/sql/sql_class.cc index fc9597cba87..cbab172a478 100644 --- a/sql/sql_class.cc +++ b/sql/sql_class.cc @@ -1372,37 +1372,20 @@ bool select_exists_subselect::send_data(List &items) int select_dumpvar::prepare(List &list, SELECT_LEX_UNIT *u) { - List_iterator_fast li(list); - List_iterator_fast gl(var_list); - Item *item; - LEX_STRING *ls; + unit= u; + if (var_list.elements != list.elements) { my_error(ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT, MYF(0)); return 1; } - unit=u; - while ((item=li++)) - { - ls= gl++; - Item_func_set_user_var *xx = new Item_func_set_user_var(*ls,item); - /* - Item_func_set_user_var can't substitute something else on its place => - 0 can be passed as last argument (reference on item) - */ - xx->fix_fields(thd,(TABLE_LIST*) thd->lex->select_lex.table_list.first, - 0); - xx->fix_length_and_dec(); - vars.push_back(xx); - } return 0; } void select_dumpvar::cleanup() { - vars.empty(); - row_count=0; + row_count= 0; } @@ -1744,12 +1727,14 @@ Statement_map::~Statement_map() bool select_dumpvar::send_data(List &items) { - List_iterator_fast li(vars); - Item_func_set_user_var *xx; + List_iterator_fast var_li(var_list); + List_iterator it(items); + Item *item; + LEX_STRING *ls; DBUG_ENTER("send_data"); if (unit->offset_limit_cnt) - { // Using limit offset,count + { // using limit offset,count unit->offset_limit_cnt--; DBUG_RETURN(0); } @@ -1758,10 +1743,21 @@ bool select_dumpvar::send_data(List &items) my_error(ER_TOO_MANY_ROWS, MYF(0)); DBUG_RETURN(1); } - while ((xx=li++)) + while ((ls= var_li++) && (item= it++)) { - xx->check(); - xx->update(); + Item_func_set_user_var *suv= new Item_func_set_user_var(*ls, item); + + /* + Item_func_set_user_var can't substitute something else on its + place => NULL may be passed as last argument (reference on + item) Item_func_set_user_var can't be fixed after creation, so + we do not check var->fixed + */ + + suv->fix_fields(thd, (TABLE_LIST *) thd->lex->select_lex.table_list.first, + 0); + suv->check(); + suv->update(); } DBUG_RETURN(0); } diff --git a/sql/sql_class.h b/sql/sql_class.h index 7cf0b474ed7..b61403e4b0a 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -1573,8 +1573,7 @@ class select_dumpvar :public select_result_interceptor { ha_rows row_count; public: List var_list; - List vars; - select_dumpvar(void) { var_list.empty(); vars.empty(); row_count=0;} + select_dumpvar() { var_list.empty(); row_count= 0;} ~select_dumpvar() {} int prepare(List &list, SELECT_LEX_UNIT *u); bool send_data(List &items); From 3add79dd1113b8623a1caa04f0376023898d8b00 Mon Sep 17 00:00:00 2001 From: "iggy@rolltop.ignatz42.dyndns.org" <> Date: Thu, 30 Nov 2006 13:09:48 -0500 Subject: [PATCH 2/4] Bug#20836 Selecting into variables results in wrong results being returned - Post-merge cleanup. - Disabled this bug's test for 5.x until 16861 is resolved. --- mysql-test/r/distinct.result | 59 ----------------- mysql-test/t/distinct.test | 124 ++++++++++++++++++----------------- sql/sql_class.cc | 12 ++-- 3 files changed, 68 insertions(+), 127 deletions(-) diff --git a/mysql-test/r/distinct.result b/mysql-test/r/distinct.result index 2c1e2bf0c15..86ab2141e2d 100644 --- a/mysql-test/r/distinct.result +++ b/mysql-test/r/distinct.result @@ -607,62 +607,3 @@ id select_type table type possible_keys key key_len ref rows Extra SELECT DISTINCT a,a FROM t1 WHERE b < 12 ORDER BY a; a a DROP TABLE t1; -DROP TABLE IF EXISTS t1; -CREATE TABLE t1 (id INT NOT NULL, fruit_id INT NOT NULL, fruit_name varchar(20) -default NULL); -INSERT INTO t1 VALUES (1,1,'ORANGE'); -INSERT INTO t1 VALUES (2,2,'APPLE'); -INSERT INTO t1 VALUES (3,2,'APPLE'); -INSERT INTO t1 VALUES (4,3,'PEAR'); -SELECT DISTINCT fruit_id, fruit_name INTO @v1, @v2 FROM t1 WHERE fruit_name = -'APPLE'; -SELECT @v1, @v2; -@v1 @v2 -2 APPLE -SELECT DISTINCT fruit_id, fruit_name INTO @v3, @v4 FROM t1 GROUP BY fruit_id, -fruit_name HAVING fruit_name = 'APPLE'; -SELECT @v3, @v4; -@v3 @v4 -2 APPLE -SELECT DISTINCT @v5:= fruit_id, @v6:= fruit_name INTO @v7, @v8 FROM t1 WHERE -fruit_name = 'APPLE'; -SELECT @v5, @v6, @v7, @v8; -@v5 @v6 @v7 @v8 -2 APPLE 2 APPLE -SELECT DISTINCT @v5 + fruit_id, CONCAT(@v6, fruit_name) INTO @v9, @v10 FROM t1 -WHERE fruit_name = 'APPLE'; -SELECT @v5, @v6, @v7, @v8, @v9, @v10; -@v5 @v6 @v7 @v8 @v9 @v10 -2 APPLE 2 APPLE 4 APPLEAPPLE -SELECT DISTINCT @v11:= @v5 + fruit_id, @v12:= CONCAT(@v6, fruit_name) INTO -@v13, @v14 FROM t1 WHERE fruit_name = 'APPLE'; -SELECT @v11, @v12, @v13, @v14; -@v11 @v12 @v13 @v14 -4 APPLEAPPLE 4 APPLEAPPLE -SELECT DISTINCT @v13, @v14 INTO @v15, @v16 FROM t1 WHERE fruit_name = 'APPLE'; -SELECT @v15, @v16; -@v15 @v16 -4 APPLEAPPLE -SELECT DISTINCT 2 + 2, 'Bob' INTO @v17, @v18 FROM t1 WHERE fruit_name = -'APPLE'; -SELECT @v17, @v18; -@v17 @v18 -4 Bob -DROP TABLE IF EXISTS t2; -CREATE TABLE t2 (fruit_id INT NOT NULL, fruit_name varchar(20) -default NULL); -SELECT DISTINCT fruit_id, fruit_name INTO OUTFILE -'../tmp/data1.tmp' FROM t1 WHERE fruit_name = 'APPLE'; -LOAD DATA INFILE '../tmp/data1.tmp' INTO TABLE t2; -SELECT DISTINCT @v19:= fruit_id, @v20:= fruit_name INTO OUTFILE -'../tmp/data2.tmp' FROM t1 WHERE fruit_name = 'APPLE'; -LOAD DATA INFILE '../tmp/data2.tmp' INTO TABLE t2; -SELECT @v19, @v20; -@v19 @v20 -2 APPLE -SELECT * FROM t2; -fruit_id fruit_name -2 APPLE -2 APPLE -DROP TABLE t1; -DROP TABLE t2; diff --git a/mysql-test/t/distinct.test b/mysql-test/t/distinct.test index b671d7b06cd..b2cc42cc0ff 100644 --- a/mysql-test/t/distinct.test +++ b/mysql-test/t/distinct.test @@ -437,68 +437,70 @@ EXPLAIN SELECT DISTINCT a,a FROM t1 WHERE b < 12 ORDER BY a; SELECT DISTINCT a,a FROM t1 WHERE b < 12 ORDER BY a; DROP TABLE t1; +# The test case for bug#20836 should be re-enabled when bug#16861 is resolved +# The results for the test should be the same as in 4.1. # #Bug #20836: Selecting into variables results in wrong results being returned # ---disable_warnings -DROP TABLE IF EXISTS t1; ---enable_warnings - -CREATE TABLE t1 (id INT NOT NULL, fruit_id INT NOT NULL, fruit_name varchar(20) -default NULL); - -INSERT INTO t1 VALUES (1,1,'ORANGE'); -INSERT INTO t1 VALUES (2,2,'APPLE'); -INSERT INTO t1 VALUES (3,2,'APPLE'); -INSERT INTO t1 VALUES (4,3,'PEAR'); - -SELECT DISTINCT fruit_id, fruit_name INTO @v1, @v2 FROM t1 WHERE fruit_name = -'APPLE'; -SELECT @v1, @v2; - -SELECT DISTINCT fruit_id, fruit_name INTO @v3, @v4 FROM t1 GROUP BY fruit_id, -fruit_name HAVING fruit_name = 'APPLE'; -SELECT @v3, @v4; - -SELECT DISTINCT @v5:= fruit_id, @v6:= fruit_name INTO @v7, @v8 FROM t1 WHERE -fruit_name = 'APPLE'; -SELECT @v5, @v6, @v7, @v8; - -SELECT DISTINCT @v5 + fruit_id, CONCAT(@v6, fruit_name) INTO @v9, @v10 FROM t1 -WHERE fruit_name = 'APPLE'; -SELECT @v5, @v6, @v7, @v8, @v9, @v10; - -SELECT DISTINCT @v11:= @v5 + fruit_id, @v12:= CONCAT(@v6, fruit_name) INTO -@v13, @v14 FROM t1 WHERE fruit_name = 'APPLE'; -SELECT @v11, @v12, @v13, @v14; - -SELECT DISTINCT @v13, @v14 INTO @v15, @v16 FROM t1 WHERE fruit_name = 'APPLE'; -SELECT @v15, @v16; - -SELECT DISTINCT 2 + 2, 'Bob' INTO @v17, @v18 FROM t1 WHERE fruit_name = -'APPLE'; -SELECT @v17, @v18; - ---disable_warnings -DROP TABLE IF EXISTS t2; ---enable_warnings - -CREATE TABLE t2 (fruit_id INT NOT NULL, fruit_name varchar(20) -default NULL); - -SELECT DISTINCT fruit_id, fruit_name INTO OUTFILE -'../tmp/data1.tmp' FROM t1 WHERE fruit_name = 'APPLE'; -LOAD DATA INFILE '../tmp/data1.tmp' INTO TABLE t2; ---exec rm $MYSQL_TEST_DIR/var/tmp/data1.tmp - -SELECT DISTINCT @v19:= fruit_id, @v20:= fruit_name INTO OUTFILE -'../tmp/data2.tmp' FROM t1 WHERE fruit_name = 'APPLE'; -LOAD DATA INFILE '../tmp/data2.tmp' INTO TABLE t2; ---exec rm $MYSQL_TEST_DIR/var/tmp/data2.tmp - -SELECT @v19, @v20; -SELECT * FROM t2; - -DROP TABLE t1; -DROP TABLE t2; +#--disable_warnings +#DROP TABLE IF EXISTS t1; +#--enable_warnings +# +#CREATE TABLE t1 (id INT NOT NULL, fruit_id INT NOT NULL, fruit_name varchar(20) +#default NULL); +# +#INSERT INTO t1 VALUES (1,1,'ORANGE'); +#INSERT INTO t1 VALUES (2,2,'APPLE'); +#INSERT INTO t1 VALUES (3,2,'APPLE'); +#INSERT INTO t1 VALUES (4,3,'PEAR'); +# +#SELECT DISTINCT fruit_id, fruit_name INTO @v1, @v2 FROM t1 WHERE fruit_name = +#'APPLE'; +#SELECT @v1, @v2; +# +#SELECT DISTINCT fruit_id, fruit_name INTO @v3, @v4 FROM t1 GROUP BY fruit_id, +#fruit_name HAVING fruit_name = 'APPLE'; +#SELECT @v3, @v4; +# +#SELECT DISTINCT @v5:= fruit_id, @v6:= fruit_name INTO @v7, @v8 FROM t1 WHERE +#fruit_name = 'APPLE'; +#SELECT @v5, @v6, @v7, @v8; +# +#SELECT DISTINCT @v5 + fruit_id, CONCAT(@v6, fruit_name) INTO @v9, @v10 FROM t1 +#WHERE fruit_name = 'APPLE'; +#SELECT @v5, @v6, @v7, @v8, @v9, @v10; +# +#SELECT DISTINCT @v11:= @v5 + fruit_id, @v12:= CONCAT(@v6, fruit_name) INTO +#@v13, @v14 FROM t1 WHERE fruit_name = 'APPLE'; +#SELECT @v11, @v12, @v13, @v14; +# +#SELECT DISTINCT @v13, @v14 INTO @v15, @v16 FROM t1 WHERE fruit_name = 'APPLE'; +#SELECT @v15, @v16; +# +#SELECT DISTINCT 2 + 2, 'Bob' INTO @v17, @v18 FROM t1 WHERE fruit_name = +#'APPLE'; +#SELECT @v17, @v18; +# +#--disable_warnings +#DROP TABLE IF EXISTS t2; +#--enable_warnings +# +#CREATE TABLE t2 (fruit_id INT NOT NULL, fruit_name varchar(20) +#default NULL); +# +#SELECT DISTINCT fruit_id, fruit_name INTO OUTFILE +#'../tmp/data1.tmp' FROM t1 WHERE fruit_name = 'APPLE'; +#LOAD DATA INFILE '../tmp/data1.tmp' INTO TABLE t2; +#--exec rm $MYSQL_TEST_DIR/var/tmp/data1.tmp +# +#SELECT DISTINCT @v19:= fruit_id, @v20:= fruit_name INTO OUTFILE +#'../tmp/data2.tmp' FROM t1 WHERE fruit_name = 'APPLE'; +#LOAD DATA INFILE '../tmp/data2.tmp' INTO TABLE t2; +#--exec rm $MYSQL_TEST_DIR/var/tmp/data2.tmp +# +#SELECT @v19, @v20; +#SELECT * FROM t2; +# +#DROP TABLE t1; +#DROP TABLE t2; diff --git a/sql/sql_class.cc b/sql/sql_class.cc index a1ad76f84e4..f3c450d28f5 100644 --- a/sql/sql_class.cc +++ b/sql/sql_class.cc @@ -1853,13 +1853,12 @@ bool select_dumpvar::send_data(List &items) { if (mv->local) { - if (thd->spcont->set_variable(current_thd, yy->get_var_idx(), - it.ref())) - DBUG_RETURN(1); + if (thd->spcont->set_variable(thd, mv->offset, &item)) + DBUG_RETURN(1); } else { - Item_func_set_user_var *suv= new Item_func_set_user_var(*ls, item); + Item_func_set_user_var *suv= new Item_func_set_user_var(mv->s, item); /* Item_func_set_user_var can't substitute something else on its @@ -1868,9 +1867,8 @@ bool select_dumpvar::send_data(List &items) we do not check var->fixed */ - suv->fix_fields(thd, (TABLE_LIST *) thd->lex->select_lex.table_list.first, - 0); - suv->check(); + suv->fix_fields(thd, 0); + suv->check(0); suv->update(); } } From e6a47277790f4a07ab37abd55772cddfc403438a Mon Sep 17 00:00:00 2001 From: "andrey@example.com" <> Date: Mon, 4 Dec 2006 18:22:38 +0100 Subject: [PATCH 3/4] Fix for bug#22369: Alter table rename combined with other alterations causes lost tables Using RENAME clause combined with other clauses of ALTER TABLE led to data loss (the data was there but not accessible). This could happen if the changes do not change the table much. Adding and droppping of fields and indices was safe. Renaming a column with MODIFY or CHANGE was unsafe operation, if the actual column didn't change (changing from int to int, which is a noop) Depending on the storage engine (SE) the behavior is different: 1)MyISAM/MEMORY - the ALTER TABLE statement completes without any error but next SELECT against the new table fails. 2)InnoDB (and every other transactional table) - The ALTER TABLE statement fails. There are the the following files in the db dir - `new_table_name.frm` and a temporary table's frm. If the SE is file based, then the data and index files will be present but with the old names. What happens is that for InnoDB the table is not renamed in the internal DDIC. Fixed by adding additional call to mysql_rename_table() method, which should not include FRM file rename, because it has been already done during file names juggling. --- mysql-test/r/alter_table.result | 42 +++++++++++++++ mysql-test/r/grant.result | 65 ++++++++++++++++++++++ mysql-test/t/alter_table.test | 53 ++++++++++++++---- mysql-test/t/grant.test | 76 ++++++++++++++++++++++++++ sql/mysql_priv.h | 1 + sql/sql_parse.cc | 7 ++- sql/sql_table.cc | 95 +++++++++++++++++++++++++++------ 7 files changed, 313 insertions(+), 26 deletions(-) diff --git a/mysql-test/r/alter_table.result b/mysql-test/r/alter_table.result index f3c94ea5af9..7b8479e6e72 100644 --- a/mysql-test/r/alter_table.result +++ b/mysql-test/r/alter_table.result @@ -733,3 +733,45 @@ Table Create Table `c1` int(11) DEFAULT NULL ) ENGINE=MyISAM DEFAULT CHARSET=latin1 DROP TABLE `#sql2`, `@0023sql1`; +DROP TABLE IF EXISTS t1; +DROP TABLE IF EXISTS t2; +CREATE TABLE t1 ( +int_field INTEGER UNSIGNED NOT NULL, +char_field CHAR(10), +INDEX(`int_field`) +); +DESCRIBE t1; +Field Type Null Key Default Extra +int_field int(10) unsigned NO MUL +char_field char(10) YES NULL +SHOW INDEXES FROM t1; +Table Non_unique Key_name Seq_in_index Column_name Collation Cardinality Sub_part Packed Null Index_type Comment +t1 1 int_field 1 int_field A NULL NULL NULL BTREE +INSERT INTO t1 VALUES (1, "edno"), (1, "edno"), (2, "dve"), (3, "tri"), (5, "pet"); +"Non-copy data change - new frm, but old data and index files" +ALTER TABLE t1 +CHANGE int_field unsigned_int_field INTEGER UNSIGNED NOT NULL, +RENAME t2; +SELECT * FROM t1 ORDER BY int_field; +ERROR 42S02: Table 'test.t1' doesn't exist +SELECT * FROM t2 ORDER BY unsigned_int_field; +unsigned_int_field char_field +1 edno +1 edno +2 dve +3 tri +5 pet +DESCRIBE t2; +Field Type Null Key Default Extra +unsigned_int_field int(10) unsigned NO MUL +char_field char(10) YES NULL +DESCRIBE t2; +Field Type Null Key Default Extra +unsigned_int_field int(10) unsigned NO MUL +char_field char(10) YES NULL +ALTER TABLE t2 MODIFY unsigned_int_field BIGINT UNSIGNED NOT NULL; +DESCRIBE t2; +Field Type Null Key Default Extra +unsigned_int_field bigint(20) unsigned NO MUL +char_field char(10) YES NULL +DROP TABLE t2; diff --git a/mysql-test/r/grant.result b/mysql-test/r/grant.result index 5dbbfbd9ab8..13f9950a337 100644 --- a/mysql-test/r/grant.result +++ b/mysql-test/r/grant.result @@ -948,6 +948,71 @@ DROP USER 'mysqltest_1'@'localhost'; use test; create user mysqltest1_thisisreallytoolong; ERROR HY000: String 'mysqltest1_thisisreallytoolong' is too long for user name (should be no longer than 16) +CREATE DATABASE mysqltest1; +CREATE TABLE mysqltest1.t1 ( +int_field INTEGER UNSIGNED NOT NULL, +char_field CHAR(10), +INDEX(`int_field`) +); +CREATE TABLE mysqltest1.t2 (int_field INT); +"Now check that we require equivalent grants for " +"RENAME TABLE and ALTER TABLE" +CREATE USER mysqltest_1@localhost; +GRANT SELECT ON mysqltest1.t1 TO mysqltest_1@localhost; +SELECT USER(); +USER() +mysqltest_1@localhost +SHOW GRANTS; +Grants for mysqltest_1@localhost +GRANT USAGE ON *.* TO 'mysqltest_1'@'localhost' +GRANT SELECT ON `mysqltest1`.`t1` TO 'mysqltest_1'@'localhost' +RENAME TABLE t1 TO t2; +ERROR 42000: ALTER command denied to user 'mysqltest_1'@'localhost' for table 't1' +ALTER TABLE t1 RENAME TO t2; +ERROR 42000: DROP,ALTER command denied to user 'mysqltest_1'@'localhost' for table 't1' +GRANT DROP ON mysqltest1.t1 TO mysqltest_1@localhost; +RENAME TABLE t1 TO t2; +ERROR 42000: ALTER command denied to user 'mysqltest_1'@'localhost' for table 't1' +ALTER TABLE t1 RENAME TO t2; +ERROR 42000: ALTER command denied to user 'mysqltest_1'@'localhost' for table 't1' +GRANT ALTER ON mysqltest1.t1 TO mysqltest_1@localhost; +SHOW GRANTS; +Grants for mysqltest_1@localhost +GRANT USAGE ON *.* TO 'mysqltest_1'@'localhost' +GRANT SELECT, DROP, ALTER ON `mysqltest1`.`t1` TO 'mysqltest_1'@'localhost' +RENAME TABLE t1 TO t2; +ERROR 42000: INSERT,CREATE command denied to user 'mysqltest_1'@'localhost' for table 't2' +ALTER TABLE t1 RENAME TO t2; +ERROR 42000: INSERT,CREATE command denied to user 'mysqltest_1'@'localhost' for table 't2' +GRANT INSERT, CREATE ON mysqltest1.t1 TO mysqltest_1@localhost; +SHOW GRANTS; +Grants for mysqltest_1@localhost +GRANT USAGE ON *.* TO 'mysqltest_1'@'localhost' +GRANT SELECT, INSERT, CREATE, DROP, ALTER ON `mysqltest1`.`t1` TO 'mysqltest_1'@'localhost' +GRANT INSERT, SELECT, CREATE, ALTER, DROP ON mysqltest1.t2 TO mysqltest_1@localhost; +DROP TABLE mysqltest1.t2; +SHOW GRANTS; +Grants for mysqltest_1@localhost +GRANT USAGE ON *.* TO 'mysqltest_1'@'localhost' +GRANT SELECT, INSERT, CREATE, DROP, ALTER ON `mysqltest1`.`t2` TO 'mysqltest_1'@'localhost' +GRANT SELECT, INSERT, CREATE, DROP, ALTER ON `mysqltest1`.`t1` TO 'mysqltest_1'@'localhost' +RENAME TABLE t1 TO t2; +RENAME TABLE t2 TO t1; +ALTER TABLE t1 RENAME TO t2; +ALTER TABLE t2 RENAME TO t1; +REVOKE DROP, INSERT ON mysqltest1.t1 FROM mysqltest_1@localhost; +REVOKE DROP, INSERT ON mysqltest1.t2 FROM mysqltest_1@localhost; +SHOW GRANTS; +Grants for mysqltest_1@localhost +GRANT USAGE ON *.* TO 'mysqltest_1'@'localhost' +GRANT SELECT, CREATE, ALTER ON `mysqltest1`.`t2` TO 'mysqltest_1'@'localhost' +GRANT SELECT, CREATE, ALTER ON `mysqltest1`.`t1` TO 'mysqltest_1'@'localhost' +RENAME TABLE t1 TO t2; +ERROR 42000: INSERT command denied to user 'mysqltest_1'@'localhost' for table 't2' +ALTER TABLE t1 RENAME TO t2; +ERROR 42000: DROP command denied to user 'mysqltest_1'@'localhost' for table 't1' +DROP USER mysqltest_1@localhost; +DROP DATABASE mysqltest1; GRANT CREATE ON mysqltest.* TO 1234567890abcdefGHIKL@localhost; ERROR HY000: String '1234567890abcdefGHIKL' is too long for user name (should be no longer than 16) GRANT CREATE ON mysqltest.* TO some_user_name@1234567890abcdefghij1234567890abcdefghij1234567890abcdefghijQWERTY; diff --git a/mysql-test/t/alter_table.test b/mysql-test/t/alter_table.test index aa2133db9c5..d4db81f08fa 100644 --- a/mysql-test/t/alter_table.test +++ b/mysql-test/t/alter_table.test @@ -101,7 +101,7 @@ create table mysqltest.t1 (name char(15)); insert into mysqltest.t1 (name) values ("mysqltest"); select * from t1; select * from mysqltest.t1; ---error 1050 +--error ER_TABLE_EXISTS_ERROR alter table t1 rename mysqltest.t1; select * from t1; select * from mysqltest.t1; @@ -231,9 +231,9 @@ DROP TABLE t1; # BUG#4717 - check for valid table names # create table t1 (a int); ---error 1103 +--error ER_WRONG_TABLE_NAME alter table t1 rename to ``; ---error 1103 +--error ER_WRONG_TABLE_NAME rename table t1 to ``; drop table t1; @@ -325,14 +325,14 @@ drop table t1; CREATE TABLE t1 (a int PRIMARY KEY, b INT UNIQUE); ALTER TABLE t1 DROP PRIMARY KEY; SHOW CREATE TABLE t1; ---error 1091 +--error ER_CANT_DROP_FIELD_OR_KEY ALTER TABLE t1 DROP PRIMARY KEY; DROP TABLE t1; # BUG#3899 create table t1 (a int, b int, key(a)); insert into t1 values (1,1), (2,2); ---error 1091 +--error ER_CANT_DROP_FIELD_OR_KEY alter table t1 drop key no_such_key; alter table t1 drop key a; drop table t1; @@ -343,7 +343,7 @@ drop table t1; # Some platforms (Mac OS X, Windows) will send the error message using small letters. CREATE TABLE T12207(a int) ENGINE=MYISAM; --replace_result t12207 T12207 ---error 1031 +--error ER_ILLEGAL_HA ALTER TABLE T12207 DISCARD TABLESPACE; DROP TABLE T12207; @@ -367,7 +367,7 @@ drop table t1; # shorter than packed field length. # create table t1 ( a timestamp ); ---error 1089 +--error ER_WRONG_SUB_KEY alter table t1 add unique ( a(1) ); drop table t1; @@ -380,7 +380,7 @@ create table t1 (c1 int); # Move table to other database. alter table t1 rename mysqltest.t1; # Assure that it has moved. ---error 1051 +--error ER_BAD_TABLE_ERROR drop table t1; # Move table back. alter table mysqltest.t1 rename t1; @@ -394,7 +394,7 @@ use mysqltest; # Drop the current db. This de-selects any db. drop database mysqltest; # Now test for correct message. ---error 1046 +--error ER_NO_DB_ERROR alter table test.t1 rename t1; # Check that explicit qualifying works even with no selected db. alter table test.t1 rename test.t1; @@ -554,3 +554,38 @@ SHOW CREATE TABLE `#sql2`; SHOW CREATE TABLE `@0023sql1`; DROP TABLE `#sql2`, `@0023sql1`; +# +# Bug #22369: Alter table rename combined with other alterations causes lost tables +# +# This problem happens if the data change is compatible. +# Changing to the same type is compatible for example. +# +--disable_warnings +DROP TABLE IF EXISTS t1; +DROP TABLE IF EXISTS t2; +--enable_warnings +CREATE TABLE t1 ( + int_field INTEGER UNSIGNED NOT NULL, + char_field CHAR(10), + INDEX(`int_field`) +); + +DESCRIBE t1; + +SHOW INDEXES FROM t1; + +INSERT INTO t1 VALUES (1, "edno"), (1, "edno"), (2, "dve"), (3, "tri"), (5, "pet"); +--echo "Non-copy data change - new frm, but old data and index files" +ALTER TABLE t1 + CHANGE int_field unsigned_int_field INTEGER UNSIGNED NOT NULL, + RENAME t2; + +--error ER_NO_SUCH_TABLE +SELECT * FROM t1 ORDER BY int_field; +SELECT * FROM t2 ORDER BY unsigned_int_field; +DESCRIBE t2; +DESCRIBE t2; +ALTER TABLE t2 MODIFY unsigned_int_field BIGINT UNSIGNED NOT NULL; +DESCRIBE t2; + +DROP TABLE t2; diff --git a/mysql-test/t/grant.test b/mysql-test/t/grant.test index d3781d58780..10203a4a221 100644 --- a/mysql-test/t/grant.test +++ b/mysql-test/t/grant.test @@ -822,6 +822,82 @@ create user mysqltest1_thisisreallytoolong; # statements. # +# +# Bug #22369: Alter table rename combined with other alterations causes lost tables +# +CREATE DATABASE mysqltest1; +CREATE TABLE mysqltest1.t1 ( + int_field INTEGER UNSIGNED NOT NULL, + char_field CHAR(10), + INDEX(`int_field`) +); +CREATE TABLE mysqltest1.t2 (int_field INT); + +--echo "Now check that we require equivalent grants for " +--echo "RENAME TABLE and ALTER TABLE" +CREATE USER mysqltest_1@localhost; +GRANT SELECT ON mysqltest1.t1 TO mysqltest_1@localhost; + +--connect (conn42,localhost,mysqltest_1,,mysqltest1); +SELECT USER(); +SHOW GRANTS; +--error ER_TABLEACCESS_DENIED_ERROR +RENAME TABLE t1 TO t2; +--error ER_TABLEACCESS_DENIED_ERROR +ALTER TABLE t1 RENAME TO t2; +--disconnect conn42 +--connection default +GRANT DROP ON mysqltest1.t1 TO mysqltest_1@localhost; + +--connect (conn42,localhost,mysqltest_1,,mysqltest1); +--error ER_TABLEACCESS_DENIED_ERROR +RENAME TABLE t1 TO t2; +--error ER_TABLEACCESS_DENIED_ERROR +ALTER TABLE t1 RENAME TO t2; +--disconnect conn42 +--connection default +GRANT ALTER ON mysqltest1.t1 TO mysqltest_1@localhost; + +--connect (conn42,localhost,mysqltest_1,,mysqltest1); +SHOW GRANTS; +--error ER_TABLEACCESS_DENIED_ERROR +RENAME TABLE t1 TO t2; +--error ER_TABLEACCESS_DENIED_ERROR +ALTER TABLE t1 RENAME TO t2; +--disconnect conn42 +--connection default +GRANT INSERT, CREATE ON mysqltest1.t1 TO mysqltest_1@localhost; +--connect (conn42,localhost,mysqltest_1,,mysqltest1); +SHOW GRANTS; +--error ER_TABLEACCESS_DENIED_ERROR +--disconnect conn42 +--connection default +GRANT INSERT, SELECT, CREATE, ALTER, DROP ON mysqltest1.t2 TO mysqltest_1@localhost; +DROP TABLE mysqltest1.t2; + +--connect (conn42,localhost,mysqltest_1,,mysqltest1); +SHOW GRANTS; +RENAME TABLE t1 TO t2; +RENAME TABLE t2 TO t1; +ALTER TABLE t1 RENAME TO t2; +ALTER TABLE t2 RENAME TO t1; +--disconnect conn42 +--connection default +REVOKE DROP, INSERT ON mysqltest1.t1 FROM mysqltest_1@localhost; +REVOKE DROP, INSERT ON mysqltest1.t2 FROM mysqltest_1@localhost; + +--connect (conn42,localhost,mysqltest_1,,mysqltest1); +SHOW GRANTS; +--error ER_TABLEACCESS_DENIED_ERROR +RENAME TABLE t1 TO t2; +--error ER_TABLEACCESS_DENIED_ERROR +ALTER TABLE t1 RENAME TO t2; +--disconnect conn42 +--connection default + +DROP USER mysqltest_1@localhost; +DROP DATABASE mysqltest1; + # Working with database-level privileges. --error ER_WRONG_STRING_LENGTH diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index 3dfb6aed9b0..ebae63b68d5 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -1843,6 +1843,7 @@ uint build_table_filename(char *buff, size_t bufflen, const char *db, #define FN_FROM_IS_TMP (1 << 0) #define FN_TO_IS_TMP (1 << 1) #define FN_IS_TMP (FN_FROM_IS_TMP | FN_TO_IS_TMP) +#define NO_FRM_RENAME (1 << 2) /* from hostname.cc */ struct in_addr; diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index 9233ccd747e..68e7d7e1790 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -3098,8 +3098,11 @@ end_with_restore_list: { ulong priv=0; ulong priv_needed= ALTER_ACL; - /* We also require DROP priv for ALTER TABLE ... DROP PARTITION */ - if (lex->alter_info.flags & ALTER_DROP_PARTITION) + /* + We also require DROP priv for ALTER TABLE ... DROP PARTITION, as well + as for RENAME TO, as being done by SQLCOM_RENAME_TABLE + */ + if (lex->alter_info.flags & (ALTER_DROP_PARTITION | ALTER_RENAME)) priv_needed|= DROP_ACL; if (lex->name && (!lex->name[0] || strlen(lex->name) > NAME_LEN)) diff --git a/sql/sql_table.cc b/sql/sql_table.cc index 1d7768d8b93..f886aae3d5a 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -3652,10 +3652,12 @@ make_unique_key_name(const char *field_name,KEY *start,KEY *end) flags flags for build_table_filename(). FN_FROM_IS_TMP old_name is temporary. FN_TO_IS_TMP new_name is temporary. + NO_FRM_RENAME Don't rename the FRM file + but only the table in the storage engine. RETURN - 0 OK - != 0 Error + FALSE OK + TRUE Error */ bool @@ -3704,7 +3706,7 @@ mysql_rename_table(handlerton *base, const char *old_db, if (!file || !(error=file->rename_table(from_base, to_base))) { - if (rename_file_ext(from,to,reg_ext)) + if (!(flags & NO_FRM_RENAME) && rename_file_ext(from,to,reg_ext)) { error=my_errno; /* Restore old file name */ @@ -5197,6 +5199,51 @@ static uint compare_tables(TABLE *table, List *create_list, /* Alter table + + SYNOPSIS + mysql_alter_table() + thd Thread handle + new_db If there is a RENAME clause + new_name If there is a RENAME clause + lex_create_info Information from the parsing phase. Since some + clauses are common to CREATE and ALTER TABLE, the + data is stored in lex->create_info. The non-common + is stored in lex->alter_info. + table_list The table to change. + fields lex->create_list - List of fields to be changed, + added or dropped. + keys lex->key_list - List of keys to be changed, added or + dropped. + order_num How many ORDER BY fields has been specified. + order List of fields to ORDER BY. + ignore Whether we have ALTER IGNORE TABLE + alter_info Information from the parsing phase specific to ALTER + TABLE and not shared with CREATE TABLE. + do_send_ok Whether to call send_ok() on success. + + DESCRIPTION + This is a veery long function and is everything but the kitchen sink :) + It is used to alter a table and not only by ALTER TABLE but also + CREATE|DROP INDEX are mapped on this function. + + When the ALTER TABLE statement just does a RENAME or ENABLE|DISABLE KEYS, + or both, then this function short cuts its operation by renaming + the table and/or enabling/disabling the keys. In this case, the FRM is + not changed, directly by mysql_alter_table. However, if there is a + RENAME + change of a field, or an index, the short cut is not used. + See how `fields` is used to generate the new FRM regarding the structure + of the fields. The same is done for the indices of the table. + + Important is the fact, that this function tries to do as little work as + possible, by finding out whether a intermediate table is needed to copy + data into and when finishing the altering to use it as the original table. + For this reason the function compare_tables() is called, which decides + based on all kind of data how similar are the new and the original + tables. + + RETURN VALUES + FALSE OK + TRUE Error */ bool mysql_alter_table(THD *thd,char *new_db, char *new_name, @@ -5215,7 +5262,7 @@ bool mysql_alter_table(THD *thd,char *new_db, char *new_name, char reg_path[FN_REFLEN+1]; ha_rows copied,deleted; uint db_create_options, used_fields; - handlerton *old_db_type, *new_db_type; + handlerton *old_db_type, *new_db_type, *save_old_db_type; legacy_db_type table_type; HA_CREATE_INFO *create_info; frm_type_enum frm_type; @@ -5519,7 +5566,7 @@ view_err: DBUG_RETURN(error); } - /* Full alter table */ + /* We have to do full alter table */ /* Let new create options override the old ones */ if (!(used_fields & HA_CREATE_USED_MIN_ROWS)) @@ -6038,8 +6085,8 @@ view_err: old data and index files. Create also symlinks to point at the new tables. Copy data. - At end, rename temporary tables and symlinks to temporary table - to final table name. + At end, rename intermediate tables, and symlinks to intermediate + table, to final table name. Remove old table and old symlinks If rename is made to another database: @@ -6100,6 +6147,7 @@ view_err: /* table is a normal table: Create temporary table in same directory */ build_table_filename(path, sizeof(path), new_db, tmp_name, "", FN_IS_TMP); + /* Open our intermediate table */ new_table=open_temporary_table(thd, path, new_db, tmp_name,0); } if (!new_table) @@ -6305,7 +6353,7 @@ view_err: if (new_table) { - /* close temporary table that will be the new table */ + /* Close the intermediate table that will be the new table */ intern_close_table(new_table); my_free((gptr) new_table,MYF(0)); } @@ -6319,7 +6367,7 @@ view_err: /* Data is copied. Now we rename the old table to a temp name, - rename the new one to the old name, remove all entries from the old table + rename the new one to the old name, remove all entries about the old table from the cache, free all locks, close the old table and remove it. */ @@ -6346,7 +6394,7 @@ view_err: { /* Win32 and InnoDB can't drop a table that is in use, so we must - close the original table at before doing the rename + close the original table before doing the rename */ table->s->version= 0; // Force removal of table def close_cached_table(thd, table); @@ -6360,6 +6408,21 @@ view_err: error=0; + save_old_db_type= old_db_type; + + /* + This leads to the storage engine (SE) not being notified for renames in + mysql_rename_table(), because we just juggle with the FRM and nothing + more. If we have an intermediate table, then we notify the SE that + it should become the actual table. Later, we will recycle the old table. + However, in case of ALTER TABLE RENAME there might be no intermediate + table. This is when the old and new tables are compatible, according to + compare_table(). Then, we need one additional call to + mysql_rename_table() with flag NO_FRM_RENAME, which does nothing else but + actual rename in the SE and the FRM is not touched. Note that, if the + table is renamed and the SE is also changed, then an intermediate table + is created and the additional call will not take place. + */ if (!need_copy_table) new_db_type=old_db_type= NULL; // this type cannot happen in regular ALTER if (mysql_rename_table(old_db_type, db, table_name, db, old_name, @@ -6369,8 +6432,11 @@ view_err: VOID(quick_rm_table(new_db_type, new_db, tmp_name, FN_IS_TMP)); } else if (mysql_rename_table(new_db_type,new_db,tmp_name,new_db, - new_alias, FN_FROM_IS_TMP) || + new_alias, FN_FROM_IS_TMP) || (new_name != table_name || new_db != db) && // we also do rename + (need_copy_table || + mysql_rename_table(save_old_db_type, db, table_name, new_db, + new_alias, NO_FRM_RENAME)) && Table_triggers_list::change_table_name(thd, db, table_name, new_db, new_alias)) { @@ -6381,6 +6447,7 @@ view_err: VOID(mysql_rename_table(old_db_type, db, old_name, db, alias, FN_FROM_IS_TMP)); } + if (error) { /* @@ -6412,6 +6479,7 @@ view_err: goto err; } } + if (thd->lock || new_name != table_name || no_table_reopen) // True if WIN32 { /* @@ -6478,10 +6546,7 @@ view_err: DBUG_ASSERT(!(mysql_bin_log.is_open() && thd->current_stmt_binlog_row_based && (create_info->options & HA_LEX_CREATE_TMP_TABLE))); write_bin_log(thd, TRUE, thd->query, thd->query_length); - /* - TODO RONM: This problem needs to handled for Berkeley DB partitions - as well - */ + if (ha_check_storage_engine_flag(old_db_type,HTON_FLUSH_AFTER_RENAME)) { /* From 6c4c315210af3bd4fbd3da3decab1a70c37840d2 Mon Sep 17 00:00:00 2001 From: "Kristofer.Pettersson@naruto." <> Date: Mon, 4 Dec 2006 22:51:52 +0100 Subject: [PATCH 4/4] Disabled testcase flush2 until pushbild framework can handle test which disables binlog. --- mysql-test/t/disabled.def | 3 +++ 1 file changed, 3 insertions(+) diff --git a/mysql-test/t/disabled.def b/mysql-test/t/disabled.def index b541b6d8d33..c36ac1bd168 100644 --- a/mysql-test/t/disabled.def +++ b/mysql-test/t/disabled.def @@ -35,3 +35,6 @@ synchronization : Bug#24529 Test 'synchronization' fails on Mac pushb #ndb_binlog_ddl_multi : BUG#18976 2006-04-10 kent CRBR: multiple binlog, second binlog may miss schema log events ndb_binlog_discover : bug#21806 2006-08-24 ndb_autodiscover3 : bug#21806 + +flush2 : Bug#24805 Pushbuild can't handle test with --disable-log-bin +