Skip to content

Commit

Permalink
MDEV-13417 UPDATE produces wrong values if an updated column is later…
Browse files Browse the repository at this point in the history
… used as an update source

Standard compatible behavior for UPDATE: all assignments in SET
are executed "simultaneously", not left-to-right. And `SET a=b,b=a`
will swap the values.
  • Loading branch information
Jerome Brauge authored and vuvova committed Feb 12, 2018
1 parent 355ee68 commit d943d7f
Show file tree
Hide file tree
Showing 29 changed files with 565 additions and 75 deletions.
2 changes: 1 addition & 1 deletion mysql-test/r/information_schema.result
Original file line number Diff line number Diff line change
Expand Up @@ -664,7 +664,7 @@ proc body longblob
proc definer char(141)
proc created timestamp
proc modified timestamp
proc sql_mode set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL')
proc sql_mode set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL','SIMULTANEOUS_ASSIGNMENT')
proc comment text
proc character_set_client char(32)
proc collation_connection char(32)
Expand Down
2 changes: 1 addition & 1 deletion mysql-test/r/mysqld--help.result
Original file line number Diff line number Diff line change
Expand Up @@ -1187,7 +1187,7 @@ The following options may be given as the first argument:
ERROR_FOR_DIVISION_BY_ZERO, TRADITIONAL,
NO_AUTO_CREATE_USER, HIGH_NOT_PRECEDENCE,
NO_ENGINE_SUBSTITUTION, PAD_CHAR_TO_FULL_LENGTH,
EMPTY_STRING_IS_NULL
EMPTY_STRING_IS_NULL, SIMULTANEOUS_ASSIGNMENT
--stack-trace Print a symbolic stack trace on failure
(Defaults to on; use --skip-stack-trace to disable.)
--standard-compliant-cte
Expand Down
222 changes: 222 additions & 0 deletions mysql-test/r/simultaneous_assignment.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,222 @@
SET sql_mode='STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION,SIMULTANEOUS_ASSIGNMENT';
#
# MDEV-13417 UPDATE produces wrong values if an UPDATEd column is later used as an UPDATE source
#
CREATE TABLE t1 (c1 INTEGER, c2 INTEGER, c3 INTEGER) ENGINE=InnoDb;
INSERT INTO t1(c1,c2,c3) VALUES (1,1,1);
CREATE TABLE t2 (c1 INTEGER, c2 INTEGER, c3 INTEGER) ENGINE=InnoDb;
INSERT INTO t2(c1,c2,c3) VALUES (1,1,1);
#
# Check that a column is only updated once.
#
UPDATE t1
SET c1 = 1,
c1 = 2;
ERROR HY000: The column `t1`.`c1` cannot be changed more than once in a single UPDATE statement
UPDATE t1, t2
SET t1.c1 = t1.c1 + 1,
t1.c2 = t1.c1 + 1,
t2.c2 = t1.c2 + 1,
t2.c2 = t1.c2 + 1;
ERROR HY000: The column `t2`.`c2` cannot be changed more than once in a single UPDATE statement
#
# Check standard update
#
UPDATE t1
SET c1 = c1+1,
c2 = c1+1,
c3 = c2+1
WHERE c1=10;
START TRANSACTION;
UPDATE t1
SET c1 = c1+1,
c2 = c1+1,
c3 = c2+1;
SELECT * FROM t1;
c1 c2 c3
2 2 2
ROLLBACK;
#
# Check update through a single view
#
CREATE VIEW v1 (a, b) AS SELECT c1, c2 FROM t1;
UPDATE v1
SET a = 10,
a = b+1;
ERROR HY000: The column `t1`.`c1` cannot be changed more than once in a single UPDATE statement
SELECT * FROM t1;
c1 c2 c3
1 1 1
DROP VIEW v1;
CREATE VIEW v1 (a, b) AS SELECT c2, c2 FROM t1;
UPDATE v1
SET a = 10,
b = 20;
ERROR HY000: The column `t1`.`c2` cannot be changed more than once in a single UPDATE statement
SELECT * FROM t1;
c1 c2 c3
1 1 1
DROP VIEW v1;
#
# Check update through a multi table view
#
CREATE VIEW v1 (a, b) AS SELECT t1.c1, t2.c1 FROM t1, t2 WHERE t1.c1=t2.c1;
UPDATE v1
SET a = 10,
b = 20;
ERROR HY000: Can not modify more than one base table through a join view 'test.v1'
START TRANSACTION;
UPDATE v1
SET a = 10;
ROLLBACK;
UPDATE v1
SET a = 10,
a = a + 1;
ERROR HY000: The column `t1`.`c1` cannot be changed more than once in a single UPDATE statement
DROP VIEW v1;
#
# Check multi update
#
START TRANSACTION;
UPDATE t1, t2
SET t1.c1 = t1.c1 + 1,
t1.c2 = t1.c1 + 1,
t2.c2 = t1.c2 + 1,
t2.c3 = t2.c2 + 1
WHERE t1.c1=t2.c1;
SELECT * FROM t1;
c1 c2 c3
2 2 1
SELECT * FROM t2;
c1 c2 c3
1 2 2
ROLLBACK;
CREATE TRIGGER tr1 BEFORE UPDATE ON t1 FOR EACH ROW
BEGIN
INSERT INTO t2 VALUES(10+old.c1,10+old.c2,10+old.c3);
INSERT INTO t2 VALUES(20+new.c1,10+new.c2,10+new.c3);
END;
/
START TRANSACTION;
UPDATE t1
SET c1 = c1+1,
c2 = c1+1,
c3 = c2+1;
SELECT * FROM t1;
c1 c2 c3
2 2 2
SELECT * FROM t2;
c1 c2 c3
1 1 1
11 11 11
22 12 12
ROLLBACK;
DROP TABLE t1;
DROP TABLE t2;
#
# Check update fired by INSERT ... ON DUPLICATE KEY UPDATE
#
CREATE TABLE t1 (
id INT(11) NOT NULL AUTO_INCREMENT,
name VARCHAR(60) NOT NULL,
nb_visits INT NOT NULL,
nb_visits_prev INT NOT NULL default 0,
PRIMARY KEY (id),
UNIQUE KEY name (name)
) ENGINE=InnoDB AUTO_INCREMENT=1;
INSERT INTO t1(name, nb_visits) VALUES('nico', 1)
ON DUPLICATE KEY UPDATE nb_visits = nb_visits + 1;
SELECT * FROM t1;
id name nb_visits nb_visits_prev
1 nico 1 0
INSERT INTO t1(name, nb_visits) VALUES('nico', 1)
ON DUPLICATE KEY UPDATE nb_visits = nb_visits + 1, nb_visits_prev=nb_visits;
SELECT * FROM t1;
id name nb_visits nb_visits_prev
1 nico 2 1
DROP TABLE t1;
#
# Update table with virtual column
#
CREATE TABLE t1 (c1 INTEGER, c2 INTEGER, c3 INTEGER AS (c1 MOD 10) VIRTUAL, c4 INTEGER AS (c1+c2 MOD 5) PERSISTENT ) ENGINE=InnoDb;
INSERT INTO t1(c1,c2) VALUES (1,1);
SELECT * FROM t1;
c1 c2 c3 c4
1 1 1 2
UPDATE t1 SET c2 = 10, c1 = c2;
SELECT * FROM t1;
c1 c2 c3 c4
1 10 1 1
UPDATE t1 SET c2 = 4, c1 = c2;
SELECT * FROM t1;
c1 c2 c3 c4
10 4 0 14
DROP TABLE t1;
#
# Update dynamic column
#
SET @@local.character_set_connection='latin1';
CREATE TABLE assets (
item_name VARCHAR(32) PRIMARY KEY,
dynamic_col1 BLOB,
dynamic_col2 BLOB
);
INSERT INTO assets VALUES ('Thinkpad Laptop', COLUMN_CREATE('color', 'black', 'price', 500),COLUMN_CREATE('CPU', 'Core I7', 'memory', '8Go'));
INSERT INTO assets VALUES ('Thinkpad Laptop2', COLUMN_CREATE('color', 'yellow', 'price', 700),COLUMN_CREATE('CPU', 'Core I7', 'memory', '16Go'));
SELECT item_name, COLUMN_GET(dynamic_col1, 'color' as char) AS color1,
COLUMN_GET(dynamic_col2, 'color' as char) AS color2
FROM assets;
item_name color1 color2
Thinkpad Laptop black NULL
Thinkpad Laptop2 yellow NULL
UPDATE assets
SET dynamic_col1=COLUMN_ADD(dynamic_col1, 'warranty', '3 years'),
dynamic_col2=dynamic_col1
WHERE item_name LIKE 'Thinkpad Laptop%';
SELECT item_name, COLUMN_GET(dynamic_col1, 'warranty' as char) AS waranty1,
COLUMN_GET(dynamic_col2, 'warranty' as char) AS waranty2,
COLUMN_GET(dynamic_col2, 'color' as char) AS color2
FROM assets;
item_name waranty1 waranty2 color2
Thinkpad Laptop 3 years NULL black
Thinkpad Laptop2 3 years NULL yellow
DROP TABLE assets;
#
# Update TEXT column
#
CREATE TABLE ft2(copy TEXT,copy2 TEXT,FULLTEXT(copy)) ENGINE=MyISAM;
INSERT INTO ft2(copy) VALUES
('MySQL vs MariaDB database'),
('Oracle vs MariaDB database'),
('PostgreSQL vs MariaDB database'),
('MariaDB overview'),
('Foreign keys'),
('Primary keys'),
('Indexes'),
('Transactions'),
('Triggers');
SELECT * FROM ft2;
copy copy2
MySQL vs MariaDB database NULL
Oracle vs MariaDB database NULL
PostgreSQL vs MariaDB database NULL
MariaDB overview NULL
Foreign keys NULL
Primary keys NULL
Indexes NULL
Transactions NULL
Triggers NULL
UPDATE ft2 SET copy = UPPER(copy),
copy2= copy;
SELECT * FROM ft2;
copy copy2
MYSQL VS MARIADB DATABASE MySQL vs MariaDB database
ORACLE VS MARIADB DATABASE Oracle vs MariaDB database
POSTGRESQL VS MARIADB DATABASE PostgreSQL vs MariaDB database
MARIADB OVERVIEW MariaDB overview
FOREIGN KEYS Foreign keys
PRIMARY KEYS Primary keys
INDEXES Indexes
TRANSACTIONS Transactions
TRIGGERS Triggers
DROP TABLE ft2;
6 changes: 3 additions & 3 deletions mysql-test/r/sql_mode.result
Original file line number Diff line number Diff line change
Expand Up @@ -75,7 +75,7 @@ t1 CREATE TABLE `t1` (
set sql_mode="postgresql,oracle,mssql,db2,maxdb";
select @@sql_mode;
@@sql_mode
PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,POSTGRESQL,ORACLE,MSSQL,DB2,MAXDB,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER
PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,POSTGRESQL,ORACLE,MSSQL,DB2,MAXDB,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER,SIMULTANEOUS_ASSIGNMENT
show create table t1;
Table Create Table
t1 CREATE TABLE "t1" (
Expand Down Expand Up @@ -475,8 +475,8 @@ set sql_mode=16384+(65536*4);
select @@sql_mode;
@@sql_mode
REAL_AS_FLOAT,PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,NO_TABLE_OPTIONS,ANSI
set sql_mode=2147483648*2*2;
ERROR 42000: Variable 'sql_mode' can't be set to the value of '8589934592'
set sql_mode=2147483648*2*2*2;
ERROR 42000: Variable 'sql_mode' can't be set to the value of '17179869184'
select @@sql_mode;
@@sql_mode
REAL_AS_FLOAT,PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,NO_TABLE_OPTIONS,ANSI
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/r/system_mysql_db.result
Original file line number Diff line number Diff line change
Expand Up @@ -217,7 +217,7 @@ proc CREATE TABLE `proc` (
`definer` char(141) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`created` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`modified` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL') NOT NULL DEFAULT '',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL','SIMULTANEOUS_ASSIGNMENT') NOT NULL DEFAULT '',
`comment` text CHARACTER SET utf8 COLLATE utf8_bin NOT NULL,
`character_set_client` char(32) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
`collation_connection` char(32) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
Expand All @@ -243,7 +243,7 @@ event CREATE TABLE `event` (
`ends` datetime DEFAULT NULL,
`status` enum('ENABLED','DISABLED','SLAVESIDE_DISABLED') NOT NULL DEFAULT 'ENABLED',
`on_completion` enum('DROP','PRESERVE') NOT NULL DEFAULT 'DROP',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL') NOT NULL DEFAULT '',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL','SIMULTANEOUS_ASSIGNMENT') NOT NULL DEFAULT '',
`comment` char(64) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`originator` int(10) unsigned NOT NULL,
`time_zone` char(64) CHARACTER SET latin1 NOT NULL DEFAULT 'SYSTEM',
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/r/system_mysql_db_fix40123.result
Original file line number Diff line number Diff line change
Expand Up @@ -217,7 +217,7 @@ proc CREATE TABLE `proc` (
`definer` char(141) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`created` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`modified` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL') NOT NULL DEFAULT '',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL','SIMULTANEOUS_ASSIGNMENT') NOT NULL DEFAULT '',
`comment` text CHARACTER SET utf8 COLLATE utf8_bin NOT NULL,
`character_set_client` char(32) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
`collation_connection` char(32) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
Expand All @@ -243,7 +243,7 @@ event CREATE TABLE `event` (
`ends` datetime DEFAULT NULL,
`status` enum('ENABLED','DISABLED','SLAVESIDE_DISABLED') NOT NULL DEFAULT 'ENABLED',
`on_completion` enum('DROP','PRESERVE') NOT NULL DEFAULT 'DROP',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL') NOT NULL DEFAULT '',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL','SIMULTANEOUS_ASSIGNMENT') NOT NULL DEFAULT '',
`comment` char(64) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`originator` int(10) unsigned NOT NULL,
`time_zone` char(64) CHARACTER SET latin1 NOT NULL DEFAULT 'SYSTEM',
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/r/system_mysql_db_fix50030.result
Original file line number Diff line number Diff line change
Expand Up @@ -217,7 +217,7 @@ proc CREATE TABLE `proc` (
`definer` char(141) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`created` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`modified` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL') NOT NULL DEFAULT '',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL','SIMULTANEOUS_ASSIGNMENT') NOT NULL DEFAULT '',
`comment` text CHARACTER SET utf8 COLLATE utf8_bin NOT NULL,
`character_set_client` char(32) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
`collation_connection` char(32) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
Expand All @@ -243,7 +243,7 @@ event CREATE TABLE `event` (
`ends` datetime DEFAULT NULL,
`status` enum('ENABLED','DISABLED','SLAVESIDE_DISABLED') NOT NULL DEFAULT 'ENABLED',
`on_completion` enum('DROP','PRESERVE') NOT NULL DEFAULT 'DROP',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL') NOT NULL DEFAULT '',
`sql_mode` set('REAL_AS_FLOAT','PIPES_AS_CONCAT','ANSI_QUOTES','IGNORE_SPACE','IGNORE_BAD_TABLE_OPTIONS','ONLY_FULL_GROUP_BY','NO_UNSIGNED_SUBTRACTION','NO_DIR_IN_CREATE','POSTGRESQL','ORACLE','MSSQL','DB2','MAXDB','NO_KEY_OPTIONS','NO_TABLE_OPTIONS','NO_FIELD_OPTIONS','MYSQL323','MYSQL40','ANSI','NO_AUTO_VALUE_ON_ZERO','NO_BACKSLASH_ESCAPES','STRICT_TRANS_TABLES','STRICT_ALL_TABLES','NO_ZERO_IN_DATE','NO_ZERO_DATE','INVALID_DATES','ERROR_FOR_DIVISION_BY_ZERO','TRADITIONAL','NO_AUTO_CREATE_USER','HIGH_NOT_PRECEDENCE','NO_ENGINE_SUBSTITUTION','PAD_CHAR_TO_FULL_LENGTH','EMPTY_STRING_IS_NULL','SIMULTANEOUS_ASSIGNMENT') NOT NULL DEFAULT '',
`comment` char(64) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`originator` int(10) unsigned NOT NULL,
`time_zone` char(64) CHARACTER SET latin1 NOT NULL DEFAULT 'SYSTEM',
Expand Down
Loading

0 comments on commit d943d7f

Please sign in to comment.