From 1e5c179bef054b9bdc2a145f602d75864a9ccecc Mon Sep 17 00:00:00 2001 From: Lynn Date: Mon, 11 Mar 2024 11:24:38 +0800 Subject: [PATCH] ddl, tests: add expression default values feature relevant tests for some DDLs and fix a related bug (#51571) close pingcap/tidb#51554, close pingcap/tidb#51570 --- pkg/ddl/db_integration_test.go | 17 +- pkg/ddl/ddl_api.go | 2 +- .../r/ddl/default_as_expression.result | 308 ++++++++++++++++-- .../t/ddl/default_as_expression.test | 124 ++++++- 4 files changed, 412 insertions(+), 39 deletions(-) diff --git a/pkg/ddl/db_integration_test.go b/pkg/ddl/db_integration_test.go index c4b6b25c20259..f41de8b89b207 100644 --- a/pkg/ddl/db_integration_test.go +++ b/pkg/ddl/db_integration_test.go @@ -1614,7 +1614,7 @@ func TestDefaultValueAsExpressions(t *testing.T) { store := testkit.CreateMockStoreWithSchemaLease(t, testLease) tk := testkit.NewTestKit(t, store) tk.MustExec("use test") - tk.MustExec("drop table if exists t, t1") + tk.MustExec("drop table if exists t, t1, t2") // date_format tk.MustExec("create table t6 (c int(10), c1 int default (date_format(now(),'%Y-%m-%d %H:%i:%s')))") @@ -1630,6 +1630,16 @@ func TestDefaultValueAsExpressions(t *testing.T) { tk.Session().GetSessionVars().User = &auth.UserIdentity{Username: "xyz", Hostname: "localhost"} tk.MustExec("insert into t(c) values (4),(5),(6)") tk.MustExec("insert into t values (7, default)") + rows := tk.MustQuery("SELECT c1 from t order by c").Rows() + for i, row := range rows { + d, ok := row[0].(string) + require.True(t, ok) + if i < 3 { + require.Equal(t, "ROOT", d) + } else { + require.Equal(t, "XYZ", d) + } + } // replace tk.MustExec("create table t1 (c int(10), c1 int default (REPLACE(UPPER(UUID()), '-', '')))") @@ -1642,6 +1652,11 @@ func TestDefaultValueAsExpressions(t *testing.T) { if int(sqlErr.Code) != errno.ErrTruncatedWrongValue { require.Equal(t, errno.ErrDataOutOfRange, int(sqlErr.Code)) } + // test modify column + // The error message has UUID, so put this test here. + tk.MustExec("create table t2(c int(10), c1 varchar(256) default (REPLACE(UPPER(UUID()), '-', '')), index idx(c1));") + tk.MustExec("insert into t2(c) values (1),(2),(3);") + tk.MustGetErrCode("alter table t2 modify column c1 varchar(30) default 'xx';", errno.WarnDataTruncated) } func TestChangingDBCharset(t *testing.T) { diff --git a/pkg/ddl/ddl_api.go b/pkg/ddl/ddl_api.go index 2d01c4670b1ce..118dcd9170796 100644 --- a/pkg/ddl/ddl_api.go +++ b/pkg/ddl/ddl_api.go @@ -6280,8 +6280,8 @@ func (d *ddl) AlterColumn(ctx sessionctx.Context, ident ast.Ident, spec *ast.Alt // Clean the NoDefaultValueFlag value. col.DelFlag(mysql.NoDefaultValueFlag) + col.DefaultIsExpr = false if len(specNewColumn.Options) == 0 { - col.DefaultIsExpr = false err = col.SetDefaultValue(nil) if err != nil { return errors.Trace(err) diff --git a/tests/integrationtest/r/ddl/default_as_expression.result b/tests/integrationtest/r/ddl/default_as_expression.result index 4ae2932c99154..e5779aa89a3f6 100644 --- a/tests/integrationtest/r/ddl/default_as_expression.result +++ b/tests/integrationtest/r/ddl/default_as_expression.result @@ -19,7 +19,7 @@ SELECT * FROM t0 WHERE c = date_format(@x,'%Y-%m') OR c = date_format(DATE_ADD(@ c c1 insert into t1(c) values (1); insert into t1 values (2, default); -SELECT * FROM t1 WHERE c = date_format(@x,'%Y-%m-%d') OR c = date_format(DATE_ADD(@x, INTERVAL 1 SECOND), '%Y-%m-%d'); +SELECT * FROM t1 WHERE c = date_format(@x,'%Y-%m-%d'); c c1 insert into t2(c) values (1); insert into t2 values (2, default); @@ -56,29 +56,71 @@ t2 CREATE TABLE `t2` ( `c` int(10) DEFAULT NULL, `c1` varchar(256) DEFAULT date_format(now(), _utf8mb4'%Y-%m-%d %H.%i.%s') ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +alter table t0 add index idx(c1); +alter table t1 add index idx(c1); +insert into t0 values (3, default); +insert into t1 values (3, default); +show create table t0; +Table Create Table +t0 CREATE TABLE `t0` ( + `c` int(10) DEFAULT NULL, + `c1` varchar(256) DEFAULT date_format(now(), _utf8mb4'%Y-%m'), + KEY `idx` (`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(10) DEFAULT NULL, + `c1` datetime DEFAULT date_format(now(), _utf8mb4'%Y-%m-%d'), + KEY `idx` (`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin alter table t0 modify column c1 varchar(30) default 'xx'; alter table t1 modify column c1 varchar(30) default 'xx'; +insert into t0 values (4, default); +insert into t1 values (4, default); show create table t0; Table Create Table t0 CREATE TABLE `t0` ( `c` int(10) DEFAULT NULL, - `c1` varchar(30) DEFAULT 'xx' + `c1` varchar(30) DEFAULT 'xx', + KEY `idx` (`c1`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin show create table t1; Table Create Table t1 CREATE TABLE `t1` ( `c` int(10) DEFAULT NULL, - `c1` varchar(30) DEFAULT 'xx' + `c1` varchar(30) DEFAULT 'xx', + KEY `idx` (`c1`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin alter table t0 modify column c1 datetime DEFAULT (date_format(now(), '%Y-%m-%d')); Error 1292 (22007): Incorrect datetime value: '2024-03' +alter table t0 alter column c1 SET DEFAULT (date_format(now(), '%Y-%m-%d')); +insert into t0 values (5, default); alter table t1 modify column c1 datetime DEFAULT (date_format(now(), '%Y-%m-%d')); +Error 1292 (22007): Incorrect datetime value: 'xx' +delete from t1 where c = 4; +alter table t1 modify column c1 datetime DEFAULT (date_format(now(), '%Y-%m-%d')); +insert into t1 values (5, default); +alter table t0 drop index idx; +alter table t1 drop index idx; +show create table t0; +Table Create Table +t0 CREATE TABLE `t0` ( + `c` int(10) DEFAULT NULL, + `c1` varchar(30) DEFAULT date_format(now(), _utf8mb4'%Y-%m-%d') +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin show create table t1; Table Create Table t1 CREATE TABLE `t1` ( `c` int(10) DEFAULT NULL, `c1` datetime DEFAULT date_format(now(), _utf8mb4'%Y-%m-%d') ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +SELECT count(1) FROM t0 WHERE c1 = date_format(@x,'%Y-%m') OR c1 = date_format(@x,'%Y-%m-%d') OR c1 = "xx"; +count(1) +5 +SELECT count(1) FROM t1 WHERE c1 = date_format(@x,'%Y-%m-%d'); +count(1) +4 SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; column_default extra date_format(now(), _utf8mb4'%Y-%m-%d') DEFAULT_GENERATED @@ -86,9 +128,9 @@ show columns from test.t1 where field='c1'; Field Type Null Key Default Extra c1 datetime YES date_format(now(), _utf8mb4'%Y-%m-%d') DEFAULT_GENERATED drop table if exists t, t1, t2; -create table t (c int(10), c1 varchar(256) default (REPLACE(UPPER(UUID()), '-', ''))); -create table t1 (c int(10), c1 int default (REPLACE(UPPER(UUID()), '-', ''))); -create table t2 (c int(10), c1 varchar(256) default (REPLACE(CONVERT(UPPER(UUID()) USING UTF8MB4), '-', ''))); +create table t (c int(10), c1 varchar(256) default (REPLACE(UPPER(UUID()), '-', '')), index idx(c1)); +create table t1 (c int(10), c1 int default (REPLACE(UPPER(UUID()), '-', '')), index idx(c1)); +create table t2 (c int(10), c1 varchar(256) default (REPLACE(CONVERT(UPPER(UUID()) USING UTF8MB4), '-', '')), index idx(c1)); create table t1 (c int(10), c1 varchar(256) default (REPLACE('xdfj-jfj', '-', ''))); Error 3770 (HY000): Default value expression of column 'c1' contains a disallowed function: `REPLACE`. create table t1 (c int(10), c1 varchar(256) default (UPPER(UUID()))); @@ -102,7 +144,7 @@ Error 1674 (HY000): Statement is unsafe because it uses a system function that m alter table t add column c4 int default (REPLACE(UPPER('dfdkj-kjkl-d'), '-', '')); Error 1674 (HY000): Statement is unsafe because it uses a system function that may return a different value on the slave insert into t(c) values (1),(2),(3); -insert into t values (4, default) +insert into t values (4, default); SELECT count(1) FROM t WHERE c1 REGEXP '^[A-Z0-9]+$'; count(1) 4 @@ -110,40 +152,65 @@ show create table t; Table Create Table t CREATE TABLE `t` ( `c` int(10) DEFAULT NULL, - `c1` varchar(256) DEFAULT replace(upper(uuid()), _utf8mb4'-', _utf8mb4'') + `c1` varchar(256) DEFAULT replace(upper(uuid()), _utf8mb4'-', _utf8mb4''), + KEY `idx` (`c1`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin show create table t1; Table Create Table t1 CREATE TABLE `t1` ( `c` int(10) DEFAULT NULL, - `c1` int(11) DEFAULT replace(upper(uuid()), _utf8mb4'-', _utf8mb4'') + `c1` int(11) DEFAULT replace(upper(uuid()), _utf8mb4'-', _utf8mb4''), + KEY `idx` (`c1`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin show create table t2; Table Create Table t2 CREATE TABLE `t2` ( `c` int(10) DEFAULT NULL, - `c1` varchar(256) DEFAULT replace(convert(upper(uuid()) using 'utf8mb4'), _utf8mb4'-', _utf8mb4'') + `c1` varchar(256) DEFAULT replace(convert(upper(uuid()) using 'utf8mb4'), _utf8mb4'-', _utf8mb4''), + KEY `idx` (`c1`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin -alter table t1 modify column c1 varchar(30) default 'xx'; -show create table t1; +alter table t alter column c1 set default 'xx'; +alter table t drop index idx; +show create table t; Table Create Table -t1 CREATE TABLE `t1` ( +t CREATE TABLE `t` ( `c` int(10) DEFAULT NULL, - `c1` varchar(30) DEFAULT 'xx' + `c1` varchar(256) DEFAULT 'xx' ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin -alter table t1 modify column c1 varchar(32) default (REPLACE(UPPER(UUID()), '-', '')); -show create table t1; +insert into t values (5, default); +show create table t; Table Create Table -t1 CREATE TABLE `t1` ( +t CREATE TABLE `t` ( `c` int(10) DEFAULT NULL, - `c1` varchar(32) DEFAULT replace(upper(uuid()), _utf8mb4'-', _utf8mb4'') + `c1` varchar(256) DEFAULT 'xx' ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin -SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; +alter table t add unique index idx(c, c1); +alter table t modify column c1 varchar(32) default (REPLACE(UPPER(UUID()), '-', '')); +insert into t values (6, default); +SELECT count(1) FROM t WHERE c1 REGEXP '^[A-Z0-9]+$'; +count(1) +5 +show create table t; +Table Create Table +t CREATE TABLE `t` ( + `c` int(10) DEFAULT NULL, + `c1` varchar(32) DEFAULT replace(upper(uuid()), _utf8mb4'-', _utf8mb4''), + UNIQUE KEY `idx` (`c`,`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t' AND COLUMN_NAME='c1'; column_default extra replace(upper(uuid()), _utf8mb4'-', _utf8mb4'') DEFAULT_GENERATED +alter table t alter column c1 set default null; +insert into t(c) values (7); +alter table t alter column c1 drop default; +insert into t(c) values (8); +Error 1364 (HY000): Field 'c1' doesn't have a default value +SELECT count(1) FROM t WHERE c1 REGEXP '^[A-Z0-9]+$'; +count(1) +5 drop table if exists t0, t1, t2, t3, t4, t5; -create table t0 (c int(10), c1 varchar(32) default (str_to_date('1980-01-01','%Y-%m-%d')), c2 date default (str_to_date('9999-01-01','%Y-%m-%d'))); -create table t1 (c int(10), c1 int default (str_to_date('1980-01-01','%Y-%m-%d')), c2 int default (str_to_date('9999-01-01','%Y-%m-%d'))); +create table t0 (c int(10), c1 varchar(32) default (str_to_date('1980-01-01','%Y-%m-%d')), c2 date default (str_to_date('9999-01-01','%Y-%m-%d')), index idx(c, c1)); +create table t1 (c int(10), c1 int default (str_to_date('1980-01-01','%Y-%m-%d')), c2 int default (str_to_date('9999-01-01','%Y-%m-%d')), unique key idx(c, c1)); create table t3 (c int(10), c1 varchar(32) default (str_to_date('1980-01-01','%m-%d'))); create table t4 (c int(10), c1 varchar(32) default (str_to_date('01-01','%Y-%m-%d'))); set @sqlMode := @@session.sql_mode; @@ -174,11 +241,126 @@ insert into t2 values (4, default, default); set session sql_mode=@sqlMode; insert into t2(c) values (5); Error 1292 (22007): Incorrect datetime value: '0000-00-00 00:00:00' +select * from t0; +c c1 c2 +1 1980-01-01 9999-01-01 +2 1980-01-01 9999-01-01 +3 1980-01-01 9999-01-01 +4 1980-01-01 9999-01-01 +select * from t1; +c c1 c2 +1 19800101 99990101 +2 19800101 99990101 +3 19800101 99990101 +4 19800101 99990101 +select * from t2; +c c1 c2 +1 1980-01-01 NULL +2 1980-01-01 NULL +3 1980-01-01 NULL +4 1980-01-01 NULL +show create table t0; +Table Create Table +t0 CREATE TABLE `t0` ( + `c` int(10) DEFAULT NULL, + `c1` varchar(32) DEFAULT str_to_date(_utf8mb4'1980-01-01', _utf8mb4'%Y-%m-%d'), + `c2` date DEFAULT str_to_date(_utf8mb4'9999-01-01', _utf8mb4'%Y-%m-%d'), + KEY `idx` (`c`,`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(10) DEFAULT NULL, + `c1` int(11) DEFAULT str_to_date(_utf8mb4'1980-01-01', _utf8mb4'%Y-%m-%d'), + `c2` int(11) DEFAULT str_to_date(_utf8mb4'9999-01-01', _utf8mb4'%Y-%m-%d'), + UNIQUE KEY `idx` (`c`,`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t2; +Table Create Table +t2 CREATE TABLE `t2` ( + `c` int(10) DEFAULT NULL, + `c1` blob DEFAULT str_to_date(_utf8mb4'1980-01-01', _utf8mb4'%Y-%m-%d'), + `c2` blob DEFAULT str_to_date(_utf8mb4'9999-01-01', _utf8mb4'%m-%d') +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +alter table t0 add index idx1(c1); +alter table t1 add unique index idx1(c, c1); +insert into t0 values (5, default, default); +insert into t1 values (5, default, default); +show create table t0; +Table Create Table +t0 CREATE TABLE `t0` ( + `c` int(10) DEFAULT NULL, + `c1` varchar(32) DEFAULT str_to_date(_utf8mb4'1980-01-01', _utf8mb4'%Y-%m-%d'), + `c2` date DEFAULT str_to_date(_utf8mb4'9999-01-01', _utf8mb4'%Y-%m-%d'), + KEY `idx` (`c`,`c1`), + KEY `idx1` (`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(10) DEFAULT NULL, + `c1` int(11) DEFAULT str_to_date(_utf8mb4'1980-01-01', _utf8mb4'%Y-%m-%d'), + `c2` int(11) DEFAULT str_to_date(_utf8mb4'9999-01-01', _utf8mb4'%Y-%m-%d'), + UNIQUE KEY `idx` (`c`,`c1`), + UNIQUE KEY `idx1` (`c`,`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +alter table t0 alter column c2 set default (current_date()); +alter table t1 modify column c1 varchar(30) default 'xx'; +insert into t0 values (6, default, default); +insert into t1 values (6, default, default); +show create table t0; +Table Create Table +t0 CREATE TABLE `t0` ( + `c` int(10) DEFAULT NULL, + `c1` varchar(32) DEFAULT str_to_date(_utf8mb4'1980-01-01', _utf8mb4'%Y-%m-%d'), + `c2` date DEFAULT CURRENT_DATE, + KEY `idx` (`c`,`c1`), + KEY `idx1` (`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(10) DEFAULT NULL, + `c1` varchar(30) DEFAULT 'xx', + `c2` int(11) DEFAULT str_to_date(_utf8mb4'9999-01-01', _utf8mb4'%Y-%m-%d'), + UNIQUE KEY `idx` (`c`,`c1`), + UNIQUE KEY `idx1` (`c`,`c1`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +alter table t0 alter column c1 drop default; +alter table t1 modify column c1 varchar(32) default (str_to_date('1980-01-01','%Y-%m-%d')); +insert into t0 values (7, default, default); +Error 1364 (HY000): Field 'c1' doesn't have a default value +insert into t1 values (7, default, default); +select * from t0 where c < 6; +c c1 c2 +1 1980-01-01 9999-01-01 +2 1980-01-01 9999-01-01 +3 1980-01-01 9999-01-01 +4 1980-01-01 9999-01-01 +5 1980-01-01 9999-01-01 +select c, c1 from t0 where c = 6 and c2 = date_format(now(),'%Y-%m-%d');; +c c1 +6 1980-01-01 +select * from t1; +c c1 c2 +1 19800101 99990101 +2 19800101 99990101 +3 19800101 99990101 +4 19800101 99990101 +5 19800101 99990101 +6 xx 99990101 +7 1980-01-01 99990101 +select * from t2; +c c1 c2 +1 1980-01-01 NULL +2 1980-01-01 NULL +3 1980-01-01 NULL +4 1980-01-01 NULL SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; column_default extra str_to_date(_utf8mb4'1980-01-01', _utf8mb4'%Y-%m-%d') DEFAULT_GENERATED drop table if exists t, t1, t2; -create table t (c int(10), c1 varchar(256) default (upper(substring_index(user(),'@',1)))); +create table t (c int(10), c1 varchar(256) default (upper(substring_index(user(),'@',1))), unique index idx(c, c1)); create table t1 (c int(10), c1 int default (upper(substring_index(user(),_utf8mb4'@',1)))); create table t2 (c int(10), c1 varchar(256) default (substring_index(user(),'@',1))); Error 3770 (HY000): Default value expression of column 'c1' contains a disallowed function: `substring_index`. @@ -196,7 +378,8 @@ show create table t; Table Create Table t CREATE TABLE `t` ( `c` int(10) DEFAULT NULL, - `c1` varchar(256) DEFAULT upper(substring_index(user(), _utf8mb4'@', 1)) + `c1` varchar(256) DEFAULT upper(substring_index(user(), _utf8mb4'@', 1)), + UNIQUE KEY `idx` (`c`,`c1`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin show create table t1; Table Create Table @@ -212,11 +395,13 @@ t1 CREATE TABLE `t1` ( `c1` varchar(30) DEFAULT 'xx' ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin alter table t1 modify column c1 varchar(32) default (upper(substring_index(user(),'@',1))); +alter table t1 add index idx1(c1); show create table t1; Table Create Table t1 CREATE TABLE `t1` ( `c` int(10) DEFAULT NULL, - `c1` varchar(32) DEFAULT upper(substring_index(user(), _utf8mb4'@', 1)) + `c1` varchar(32) DEFAULT upper(substring_index(user(), _utf8mb4'@', 1)), + KEY `idx1` (`c1`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; column_default extra @@ -285,6 +470,81 @@ date_format(now(), _utf8mb4'%Y-%m-%d') DEFAULT_GENERATED SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t3' AND COLUMN_NAME='c1'; column_default extra date_format(now(), _utf8mb4'%Y-%m-%d') DEFAULT_GENERATED +alter table t0 alter column c1 set default "xx"; +Error 1101 (42000): BLOB/TEXT/JSON column 'c1' can't have a default value +alter table t1 alter column c1 set default "xx"; +Error 1101 (42000): BLOB/TEXT/JSON column 'c1' can't have a default value +alter table t2 alter column c1 set default 'y'; +alter table t3 alter column c1 set default 'n'; +INSERT INTO t0 values (2, DEFAULT); +INSERT INTO t2 values (2, DEFAULT); +INSERT INTO t3 values (2, DEFAULT); +alter table t0 modify column c1 BLOB default (date_format(now(),'%Y-%m-%d')); +alter table t1 modify column c1 JSON default (date_format(now(),'%Y-%m-%d')); +alter table t2 modify column c1 ENUM('y','n') default (date_format(now(),'%Y-%m-%d')); +alter table t3 modify column c1 SET('y','n') default (date_format(now(),'%Y-%m-%d')); +INSERT INTO t0 values (3, DEFAULT); +show create table t0; +Table Create Table +t0 CREATE TABLE `t0` ( + `c` int(10) DEFAULT NULL, + `c1` blob DEFAULT date_format(now(), _utf8mb4'%Y-%m-%d') +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(10) DEFAULT NULL, + `c1` json DEFAULT date_format(now(), _utf8mb4'%Y-%m-%d') +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t2; +Table Create Table +t2 CREATE TABLE `t2` ( + `c` int(10) DEFAULT NULL, + `c1` enum('y','n') DEFAULT date_format(now(), _utf8mb4'%Y-%m-%d') +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t3; +Table Create Table +t3 CREATE TABLE `t3` ( + `c` int(10) DEFAULT NULL, + `c1` set('y','n') DEFAULT date_format(now(), _utf8mb4'%Y-%m-%d') +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +alter table t0 alter column c1 drop default; +alter table t1 alter column c1 drop default; +alter table t2 alter column c1 drop default; +alter table t3 alter column c1 drop default; +show create table t0; +Table Create Table +t0 CREATE TABLE `t0` ( + `c` int(10) DEFAULT NULL, + `c1` blob +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t1; +Table Create Table +t1 CREATE TABLE `t1` ( + `c` int(10) DEFAULT NULL, + `c1` json +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t2; +Table Create Table +t2 CREATE TABLE `t2` ( + `c` int(10) DEFAULT NULL, + `c1` enum('y','n') +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +show create table t3; +Table Create Table +t3 CREATE TABLE `t3` ( + `c` int(10) DEFAULT NULL, + `c1` set('y','n') +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +select count(1) from t0 where c1 = date_format(now(), '%Y-%m-%d'); +count(1) +4 +select * from t2; +c c1 +2 y +select * from t3; +c c1 +2 n drop table t0, t1, t2, t3; create table t0 (c int(10), c1 BLOB default (REPLACE(UPPER(UUID()), '-', ''))); create table t1 (c int(10), c1 JSON default (REPLACE(UPPER(UUID()), '-', ''))); diff --git a/tests/integrationtest/t/ddl/default_as_expression.test b/tests/integrationtest/t/ddl/default_as_expression.test index db2a0e3293f33..09d81e1cf0e55 100644 --- a/tests/integrationtest/t/ddl/default_as_expression.test +++ b/tests/integrationtest/t/ddl/default_as_expression.test @@ -21,7 +21,7 @@ insert into t0 values (2, default); SELECT * FROM t0 WHERE c = date_format(@x,'%Y-%m') OR c = date_format(DATE_ADD(@x, INTERVAL 1 SECOND), '%Y-%m'); insert into t1(c) values (1); insert into t1 values (2, default); -SELECT * FROM t1 WHERE c = date_format(@x,'%Y-%m-%d') OR c = date_format(DATE_ADD(@x, INTERVAL 1 SECOND), '%Y-%m-%d'); +SELECT * FROM t1 WHERE c = date_format(@x,'%Y-%m-%d'); insert into t2(c) values (1); insert into t2 values (2, default); SELECT * FROM t2 WHERE c = date_format(@x,'%Y-%m-%d %H.%i.%s') OR c = date_format(DATE_ADD(@x, INTERVAL 1 SECOND), '%Y-%m-%d %H.%i.%s'); @@ -35,26 +35,48 @@ SELECT * FROM t4 WHERE c = date_format(@x,'%Y-%m-%d %H:%i:%s') OR c = date_forma insert into t5(c) values (1); insert into t5 values (2, default); SELECT * FROM t5 WHERE c = date_format(@x,'%Y-%m-%d %H:%i:%s') OR c = date_format(DATE_ADD(@x, INTERVAL 1 SECOND), '%Y-%m-%d %H:%i:%s'); + show create table t0; show create table t1; show create table t2; + +# test modify column, set default value, add index +alter table t0 add index idx(c1); +alter table t1 add index idx(c1); +insert into t0 values (3, default); +insert into t1 values (3, default); +show create table t0; +show create table t1; alter table t0 modify column c1 varchar(30) default 'xx'; alter table t1 modify column c1 varchar(30) default 'xx'; +insert into t0 values (4, default); +insert into t1 values (4, default); show create table t0; show create table t1; -- error 1292 alter table t0 modify column c1 datetime DEFAULT (date_format(now(), '%Y-%m-%d')); +alter table t0 alter column c1 SET DEFAULT (date_format(now(), '%Y-%m-%d')); +insert into t0 values (5, default); +-- error 1292 alter table t1 modify column c1 datetime DEFAULT (date_format(now(), '%Y-%m-%d')); +delete from t1 where c = 4; +alter table t1 modify column c1 datetime DEFAULT (date_format(now(), '%Y-%m-%d')); +insert into t1 values (5, default); +alter table t0 drop index idx; +alter table t1 drop index idx; +show create table t0; show create table t1; +SELECT count(1) FROM t0 WHERE c1 = date_format(@x,'%Y-%m') OR c1 = date_format(@x,'%Y-%m-%d') OR c1 = "xx"; +SELECT count(1) FROM t1 WHERE c1 = date_format(@x,'%Y-%m-%d'); SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; show columns from test.t1 where field='c1'; # TestDefaultColumnWithReplace # replace drop table if exists t, t1, t2; -create table t (c int(10), c1 varchar(256) default (REPLACE(UPPER(UUID()), '-', ''))); -create table t1 (c int(10), c1 int default (REPLACE(UPPER(UUID()), '-', ''))); -create table t2 (c int(10), c1 varchar(256) default (REPLACE(CONVERT(UPPER(UUID()) USING UTF8MB4), '-', ''))); +create table t (c int(10), c1 varchar(256) default (REPLACE(UPPER(UUID()), '-', '')), index idx(c1)); +create table t1 (c int(10), c1 int default (REPLACE(UPPER(UUID()), '-', '')), index idx(c1)); +create table t2 (c int(10), c1 varchar(256) default (REPLACE(CONVERT(UPPER(UUID()) USING UTF8MB4), '-', '')), index idx(c1)); -- error 3770 create table t1 (c int(10), c1 varchar(256) default (REPLACE('xdfj-jfj', '-', ''))); -- error 3770 @@ -73,7 +95,7 @@ alter table t add column c4 int default (REPLACE(UPPER('dfdkj-kjkl-d'), '-', '') # insert records insert into t(c) values (1),(2),(3); -insert into t values (4, default) +insert into t values (4, default); # It consists of uppercase letters or numbers. SELECT count(1) FROM t WHERE c1 REGEXP '^[A-Z0-9]+$'; @@ -82,18 +104,32 @@ SELECT count(1) FROM t WHERE c1 REGEXP '^[A-Z0-9]+$'; show create table t; show create table t1; show create table t2; -alter table t1 modify column c1 varchar(30) default 'xx'; -show create table t1; -alter table t1 modify column c1 varchar(32) default (REPLACE(UPPER(UUID()), '-', '')); -show create table t1; -SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; + +# test modify column, set default value, add index +alter table t alter column c1 set default 'xx'; +alter table t drop index idx; +show create table t; +insert into t values (5, default); +show create table t; +alter table t add unique index idx(c, c1); +alter table t modify column c1 varchar(32) default (REPLACE(UPPER(UUID()), '-', '')); +insert into t values (6, default); +SELECT count(1) FROM t WHERE c1 REGEXP '^[A-Z0-9]+$'; +show create table t; +SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t' AND COLUMN_NAME='c1'; +alter table t alter column c1 set default null; +insert into t(c) values (7); +alter table t alter column c1 drop default; +-- error 1364 +insert into t(c) values (8); +SELECT count(1) FROM t WHERE c1 REGEXP '^[A-Z0-9]+$'; # TestDefaultColumnWithStrToDate # str_to_date drop table if exists t0, t1, t2, t3, t4, t5; # create table -create table t0 (c int(10), c1 varchar(32) default (str_to_date('1980-01-01','%Y-%m-%d')), c2 date default (str_to_date('9999-01-01','%Y-%m-%d'))); -create table t1 (c int(10), c1 int default (str_to_date('1980-01-01','%Y-%m-%d')), c2 int default (str_to_date('9999-01-01','%Y-%m-%d'))); +create table t0 (c int(10), c1 varchar(32) default (str_to_date('1980-01-01','%Y-%m-%d')), c2 date default (str_to_date('9999-01-01','%Y-%m-%d')), index idx(c, c1)); +create table t1 (c int(10), c1 int default (str_to_date('1980-01-01','%Y-%m-%d')), c2 int default (str_to_date('9999-01-01','%Y-%m-%d')), unique key idx(c, c1)); create table t3 (c int(10), c1 varchar(32) default (str_to_date('1980-01-01','%m-%d'))); create table t4 (c int(10), c1 varchar(32) default (str_to_date('01-01','%Y-%m-%d'))); set @sqlMode := @@session.sql_mode; @@ -128,13 +164,43 @@ insert into t2 values (4, default, default); set session sql_mode=@sqlMode; -- error 1292 insert into t2(c) values (5); +select * from t0; +select * from t1; +select * from t2; + +show create table t0; +show create table t1; +show create table t2; + +# test modify column, set default value, add index +alter table t0 add index idx1(c1); +alter table t1 add unique index idx1(c, c1); +insert into t0 values (5, default, default); +insert into t1 values (5, default, default); +show create table t0; +show create table t1; +alter table t0 alter column c2 set default (current_date()); +alter table t1 modify column c1 varchar(30) default 'xx'; +insert into t0 values (6, default, default); +insert into t1 values (6, default, default); +show create table t0; +show create table t1; +alter table t0 alter column c1 drop default; +alter table t1 modify column c1 varchar(32) default (str_to_date('1980-01-01','%Y-%m-%d')); +-- error 1364 +insert into t0 values (7, default, default); +insert into t1 values (7, default, default); +select * from t0 where c < 6; +select c, c1 from t0 where c = 6 and c2 = date_format(now(),'%Y-%m-%d');; +select * from t1; +select * from t2; SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; # TestDefaultColumnWithUpper # upper drop table if exists t, t1, t2; # create table -create table t (c int(10), c1 varchar(256) default (upper(substring_index(user(),'@',1)))); +create table t (c int(10), c1 varchar(256) default (upper(substring_index(user(),'@',1))), unique index idx(c, c1)); create table t1 (c int(10), c1 int default (upper(substring_index(user(),_utf8mb4'@',1)))); -- error 3770 create table t2 (c int(10), c1 varchar(256) default (substring_index(user(),'@',1))); @@ -150,9 +216,12 @@ alter table t add column c3 int default (upper(substring_index('fjks@jkkl','@',1 insert into t1(c) values (1); show create table t; show create table t1; + +# test modify column, set default value, add index alter table t1 modify column c1 varchar(30) default 'xx'; show create table t1; alter table t1 modify column c1 varchar(32) default (upper(substring_index(user(),'@',1))); +alter table t1 add index idx1(c1); show create table t1; SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; @@ -189,6 +258,35 @@ SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema= SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t1' AND COLUMN_NAME='c1'; SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t2' AND COLUMN_NAME='c1'; SELECT column_default, extra FROM INFORMATION_SCHEMA.COLUMNS WHERE table_schema='test' AND TABLE_NAME='t3' AND COLUMN_NAME='c1'; +-- error 1101 +alter table t0 alter column c1 set default "xx"; +-- error 1101 +alter table t1 alter column c1 set default "xx"; +alter table t2 alter column c1 set default 'y'; +alter table t3 alter column c1 set default 'n'; +INSERT INTO t0 values (2, DEFAULT); +INSERT INTO t2 values (2, DEFAULT); +INSERT INTO t3 values (2, DEFAULT); +alter table t0 modify column c1 BLOB default (date_format(now(),'%Y-%m-%d')); +alter table t1 modify column c1 JSON default (date_format(now(),'%Y-%m-%d')); +alter table t2 modify column c1 ENUM('y','n') default (date_format(now(),'%Y-%m-%d')); +alter table t3 modify column c1 SET('y','n') default (date_format(now(),'%Y-%m-%d')); +INSERT INTO t0 values (3, DEFAULT); +show create table t0; +show create table t1; +show create table t2; +show create table t3; +alter table t0 alter column c1 drop default; +alter table t1 alter column c1 drop default; +alter table t2 alter column c1 drop default; +alter table t3 alter column c1 drop default; +show create table t0; +show create table t1; +show create table t2; +show create table t3; +select count(1) from t0 where c1 = date_format(now(), '%Y-%m-%d'); +select * from t2; +select * from t3; drop table t0, t1, t2, t3; # Different data types for replace. create table t0 (c int(10), c1 BLOB default (REPLACE(UPPER(UUID()), '-', '')));