表(操作)
本节主要介绍表(操作)的迁移语法。迁移语法决定了关键字/功能的迁移方式。
本节包括以下节点内容:
LIKE 表克隆
MySQL数据库中,可以使用 CREATE TABLE .. LIKE ..方式克隆旧表结构创建新表。GaussDB(DWS)也支持这种建表方式。DSC工具迁移时会添加额外的表属性信息。
输入示例
CREATE TABLE IF NOT EXISTS `public`.`runoob_tbl_old`( `dataType_1` YEAR, `dataType_2` YEAR(4), `dataType_3` YEAR DEFAULT '2018', `dataType_4` TIME DEFAULT NULL ); CREATE TABLE `runoob_tbl` (like `runoob_tbl_old`);
输出示例
CREATE TABLE "public"."runoob_tbl_old" ( "datatype_1" VARCHAR(4), "datatype_2" VARCHAR(4), "datatype_3" VARCHAR(4) DEFAULT '2018', "datatype_4" TIME WITHOUT TIME ZONE DEFAULT NULL ) WITH ( ORIENTATION = ROW, COMPRESSION = NO ) NOCOMPRESS DISTRIBUTE BY HASH ("datatype_1"); CREATE TABLE "public"."runoob_tbl"( LIKE "public"."runoob_tbl_old" INCLUDING COMMENTS INCLUDING CONSTRAINTS INCLUDING DEFAULTS INCLUDING INDEXES INCLUDING STORAGE);
添加与删除列
MySQL添加、删除列语句与GaussDB(DWS)存在差异。DSC工具迁移时会根据GaussDB的特性进行相应适配。
GaussDB不支持表定义中列序数的变更,工具暂不支持FRIST,AFTER特性的完整迁移。基于当前的临时方案,工具仅仅移除该关键字。
输入示例
CREATE TABLE IF NOT EXISTS `runoob_alter_test`( `dataType1` int NOT NULL AUTO_INCREMENT, `dataType2` FLOAT(10,2), `dataType3` DOUBLE(20,8), `dataType4` TEXT NOT NULL, `dataType5` YEAR NOT NULL DEFAULT '2018', `dataType6` DATETIME NOT NULL DEFAULT '2018-10-12 15:27:33.999999', `dataType7` CHAR NOT NULL DEFAULT '', `dataType8` VARCHAR(50), `dataType9` VARCHAR(50) NOT NULL DEFAULT '', `dataType10` TIME NOT NULL DEFAULT '10:20:59', PRIMARY KEY(`dataType1`) )ENGINE=InnoDB DEFAULT CHARSET=utf8; ## A. ALTER TABLE runoob_alter_test ADD dataType1_1 INT NOT NULL AFTER dataType1; ALTER TABLE runoob_alter_test DROP dataType1_1; ## B. ALTER TABLE runoob_alter_test ADD dataType1_1 INT NOT NULL FIRST; ALTER TABLE runoob_alter_test DROP dataType1_1; ## C. ALTER TABLE runoob_alter_test ADD COLUMN dataType1_1 INT NOT NULL AFTER dataType2; ALTER TABLE runoob_alter_test DROP COLUMN dataType1_1; ## D. ALTER TABLE runoob_alter_test ADD COLUMN dataType1_1 INT NOT NULL FIRST; ALTER TABLE runoob_alter_test DROP COLUMN dataType1_1; ## E. ALTER TABLE runoob_alter_test ADD COLUMN(dataType1_1 INT NOT NULL, dataType1_2 VARCHAR(200) NOT NULL); ALTER TABLE runoob_alter_test DROP COLUMN dataType1_1, DROP COLUMN dataType1_2;
输出示例
CREATE TABLE "public"."runoob_alter_test" ( "datatype1" SERIAL NOT NULL, "datatype2" FLOAT(10), "datatype3" FLOAT(20), "datatype4" TEXT NOT NULL, "datatype5" VARCHAR(4) NOT NULL DEFAULT '2018', "datatype6" TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT '2018-10-12 15:27:33.999999', "datatype7" CHAR NOT NULL DEFAULT '', "datatype8" VARCHAR(50), "datatype9" VARCHAR(50) NOT NULL DEFAULT '', "datatype10" TIME WITHOUT TIME ZONE NOT NULL DEFAULT '10:20:59', PRIMARY KEY ("datatype1") ) WITH ( ORIENTATION = ROW, COMPRESSION = NO ) NOCOMPRESS DISTRIBUTE BY HASH ("datatype1"); -- A. ALTER TABLE "public"."runoob_alter_test" ADD COLUMN "datatype1_1" INTEGER NOT NULL; ALTER TABLE "public"."runoob_alter_test" DROP COLUMN "datatype1_1" RESTRICT; -- B. ALTER TABLE "public"."runoob_alter_test" ADD COLUMN "datatype1_1" INTEGER NOT NULL; ALTER TABLE "public"."runoob_alter_test" DROP COLUMN "datatype1_1" RESTRICT; -- C. ALTER TABLE "public"."runoob_alter_test" ADD COLUMN "datatype1_1" INTEGER NOT NULL; ALTER TABLE "public"."runoob_alter_test" DROP COLUMN "datatype1_1" RESTRICT; -- D. ALTER TABLE "public"."runoob_alter_test" ADD COLUMN "datatype1_1" INTEGER NOT NULL; ALTER TABLE "public"."runoob_alter_test" DROP COLUMN "datatype1_1" RESTRICT; -- E. ALTER TABLE "public"."runoob_alter_test" ADD COLUMN "datatype1_1" VARCHAR(200) NOT NULL, ADD COLUMN "datatype1_2" VARCHAR(200) NOT NULL; ALTER TABLE "public"."runoob_alter_test" DROP COLUMN "datatype1_1" RESTRICT, DROP COLUMN "datatype1_2" RESTRICT;
MODIFY修改列
MySQL使用 MODIFY关键字修改列数据类型、设置非空约束。DSC工具迁移时会根据GaussDB的特性进行相应适配。
输入示例
CREATE TABLE IF NOT EXISTS `runoob_alter_test`( `dataType0` varchar(100), `dataType1` bigint, `dataType2` bigint, `dataType3` bigint )ENGINE=InnoDB DEFAULT CHARSET=utf8; ## A. ALTER TABLE runoob_alter_test MODIFY dataType1 smallint; ## B. ALTER TABLE runoob_alter_test MODIFY dataType1 smallint NOT NULL; ## C. ALTER TABLE runoob_alter_test MODIFY dataType1 smallint NOT NULL FIRST; ## D. ALTER TABLE runoob_alter_test MODIFY dataType1 smallint NOT NULL AFTER dataType3;
输出示例
CREATE TABLE "public"."runoob_alter_test" ( "datatype0" VARCHAR(100), "datatype1" BIGINT, "datatype2" BIGINT, "datatype3" BIGINT ) WITH ( ORIENTATION = ROW, COMPRESSION = NO ) NOCOMPRESS DISTRIBUTE BY HASH ("datatype0"); -- A. ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype1" SET DATA TYPE SMALLINT; -- B. ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype1" SET DATA TYPE SMALLINT, ALTER COLUMN "datatype1" SET NOT NULL; -- C. ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype1" SET DATA TYPE SMALLINT, ALTER COLUMN "datatype1" SET NOT NULL; -- D. ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype1" SET DATA TYPE SMALLINT, ALTER COLUMN "datatype1" SET NOT NULL;
CHANGE修改列
MySQL使用CHANGE关键字同时修改列名、列数据类型、设置非空约束。DSC工具迁移时会根据GaussDB的特性进行相应适配。
输入示例
CREATE TABLE IF NOT EXISTS `runoob_alter_test`( `dataType0` varchar(128), `dataType1` bigint, `dataType2` bigint, `dataType3` bigint, `dataType4` bigint )ENGINE=InnoDB DEFAULT CHARSET=utf8; ## A. ALTER TABLE runoob_alter_test CHANGE dataType1 dataType1New VARCHAR(50); ## B. ALTER TABLE runoob_alter_test CHANGE dataType2 dataType2New VARCHAR(50) NOT NULL; ## C. ALTER TABLE runoob_alter_test CHANGE dataType3 dataType3New VARCHAR(100) FIRST; ## D. ALTER TABLE runoob_alter_test CHANGE dataType4 dataType4New VARCHAR(50) AFTER dataType1;
输出示例
CREATE TABLE "public"."runoob_alter_test" ( "datatype0" VARCHAR(128), "datatype1" BIGINT, "datatype2" BIGINT, "datatype3" BIGINT, "datatype4" BIGINT ) WITH ( ORIENTATION = ROW, COMPRESSION = NO ) NOCOMPRESS DISTRIBUTE BY HASH ("datatype0"); -- A. ALTER TABLE "public"."runoob_alter_test" RENAME COLUMN "datatype1" TO "datatype1new"; ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype1new" SET DATA TYPE VARCHAR(50); -- B. ALTER TABLE "public"."runoob_alter_test" RENAME COLUMN "datatype2" TO "datatype2new"; ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype2new" SET DATA TYPE VARCHAR(50), ALTER COLUMN "datatype2new" SET NOT NULL; -- C. ALTER TABLE "public"."runoob_alter_test" RENAME COLUMN "datatype3" TO "datatype3new"; ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype3new" SET DATA TYPE VARCHAR(100); -- D. ALTER TABLE "public"."runoob_alter_test" RENAME COLUMN "datatype4" TO "datatype4new"; ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype4new" SET DATA TYPE VARCHAR(50);
设置与清除列默认值
MySQL使用ALTER语句设置列默认值时可省略"COLUMN"关键字。DSC工具迁移时会根据GaussDB的特性进行相应适配。
输入示例
CREATE TABLE IF NOT EXISTS `runoob_alter_test`( `dataType1` int NOT NULL AUTO_INCREMENT, `dataType2` FLOAT(10,2), `dataType3` DOUBLE(20,8), `dataType4` TEXT NOT NULL, `dataType5` YEAR NOT NULL DEFAULT '2018', `dataType6` DATETIME NOT NULL DEFAULT '2018-10-12 15:27:33.999999', `dataType7` CHAR NOT NULL DEFAULT '', `dataType8` VARCHAR(50), `dataType9` VARCHAR(50) NOT NULL DEFAULT '', `dataType10` TIME NOT NULL DEFAULT '10:20:59', PRIMARY KEY(`dataType1`) )ENGINE=InnoDB DEFAULT CHARSET=utf8; ALTER TABLE runoob_alter_test ALTER dataType2 SET DEFAULT 1; ALTER TABLE runoob_alter_test ALTER COLUMN dataType2 SET DEFAULT 3; ALTER TABLE runoob_alter_test ALTER dataType2 DROP DEFAULT; ALTER TABLE runoob_alter_test ALTER COLUMN dataType2 DROP DEFAULT;
输出示例
CREATE TABLE "public"."runoob_alter_test" ( "datatype1" SERIAL NOT NULL, "datatype2" FLOAT(10), "datatype3" FLOAT(20), "datatype4" TEXT NOT NULL, "datatype5" VARCHAR(4) NOT NULL DEFAULT '2018', "datatype6" TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT '2018-10-12 15:27:33.999999', "datatype7" CHAR NOT NULL DEFAULT '', "datatype8" VARCHAR(50), "datatype9" VARCHAR(50) NOT NULL DEFAULT '', "datatype10" TIME WITHOUT TIME ZONE NOT NULL DEFAULT '10:20:59', PRIMARY KEY ("datatype1") ) WITH ( ORIENTATION = ROW, COMPRESSION = NO ) NOCOMPRESS DISTRIBUTE BY HASH ("datatype1"); ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype2" SET DEFAULT 1; ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype2" SET DEFAULT 3; ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype2" DROP DEFAULT; ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype2" DROP DEFAULT;
DROP删除表
GaussDB(DWS)与MySQL都支持使用DROP语句删除表,但GaussDB(DWS)不支持在DROP语句中使用 RESTRICT | CASCADE 关键字。DSC工具迁移时会将上述关键字移除。
输入示例
CREATE TABLE IF NOT EXISTS `public`.`express_elb_server`( `runoob_id` VARCHAR(10), `runoob_title` VARCHAR(100) NOT NULL, `runoob_author` VARCHAR(40) NOT NULL, `submission_date` VARCHAR(10) )ENGINE=InnoDB DEFAULT CHARSET=utf8; DROP TABLE `public`.`express_elb_server` RESTRICT;
输出示例
CREATE TABLE "public"."express_elb_server" ( "runoob_id" VARCHAR(10), "runoob_title" VARCHAR(100) NOT NULL, "runoob_author" VARCHAR(40) NOT NULL, "submission_date" VARCHAR(10) ) WITH ( ORIENTATION = ROW, COMPRESSION = NO ) NOCOMPRESS DISTRIBUTE BY HASH ("runoob_id"); DROP TABLE "public"."express_elb_server";
TRUNCATE 删除表
MySQL在使用TRUNCATE语句删除表数据时可以省略 "TABLE"关键字,GaussDB 不支持这种用法。此外,DSC工具在做迁移TRUNCATE语句时会添加 "CONTINUE IDENTITY RESTRICT"关键字。
输入示例
TRUNCATE TABLE `public`.`test_create_table01`; TRUNCATE TEST_CREATE_TABLE01;
输出示例
TRUNCATE TABLE "public"."test_create_table01" CONTINUE IDENTITY RESTRICT; TRUNCATE TABLE "public"."test_create_table01" CONTINUE IDENTITY RESTRICT;
LOCK
GaussDB(DWS)不支持MySQL中的"ALTER TABLE tbName LOCK"语句,DSC工具迁移时会将其删除。
输入示例
CREATE TABLE IF NOT EXISTS `runoob_alter_test`( `dataType1` int NOT NULL AUTO_INCREMENT, `dataType2` FLOAT(10), `dataType4` TEXT NOT NULL, `dataType5` YEAR NOT NULL DEFAULT '2018', `dataType6` DATETIME NOT NULL, `dataType7` CHAR NOT NULL DEFAULT '', `dataType8` VARCHAR(50), `dataType9` VARCHAR(50) NOT NULL DEFAULT '', `dataType10` TIME NOT NULL DEFAULT '10:20:59', PRIMARY KEY(`dataType1`) )ENGINE=InnoDB DEFAULT CHARSET=utf8; ## A. ALTER TABLE runoob_alter_test LOCK DEFAULT; ## B. ALTER TABLE runoob_alter_test LOCK=DEFAULT; ## C. ALTER TABLE runoob_alter_test LOCK EXCLUSIVE; ## D. ALTER TABLE runoob_alter_test LOCK=EXCLUSIVE;
输出示例
CREATE TABLE "public"."runoob_alter_test" ( "datatype1" SERIAL NOT NULL, "datatype2" FLOAT(10), "datatype4" TEXT NOT NULL, "datatype5" VARCHAR(4) NOT NULL DEFAULT '2018', "datatype6" TIMESTAMP WITHOUT TIME ZONE NOT NULL, "datatype7" CHAR NOT NULL DEFAULT '', "datatype8" VARCHAR(50), "datatype9" VARCHAR(50) NOT NULL DEFAULT '', "datatype10" TIME WITHOUT TIME ZONE NOT NULL DEFAULT '10:20:59', PRIMARY KEY ("datatype1") ) WITH ( ORIENTATION = ROW, COMPRESSION = NO ) NOCOMPRESS DISTRIBUTE BY HASH ("datatype1"); -- A. -- B. -- C. -- D.
RENAME 重命名表名
MySQL重命名表名的语句与GaussDB(DWS)有一些差异。DSC工具迁移时会根据GaussDB的特性进行相应适配。
工具暂不支持原表名附有DATABASE(SCHEMA)的场景。
- MySQL通过RENAME TABLE语句修改表名
# 单表重命名 RENAME TABLE DEPARTMENT TO NEWDEPT; # 多表重命名 RENAME TABLE NEWDEPT TO NEWDEPT_02,PEOPLE TO PEOPLE_02;
输出示例
--单表重命名 ALTER TABLE "public"."department" RENAME TO "newdept"; --多表重命名 ALTER TABLE "public"."newdept" RENAME TO "newdept_02"; ALTER TABLE "public"."people" RENAME TO "people_02";
- MySQL通过ALTER TABLE RENAME 语句修改表名,DSC工具迁移该语句时会将 "AS" 关键字迁移为 "TO"。
## A. ALTER TABLE runoob_alter_test RENAME TO runoob_alter_testnew; ## B. ALTER TABLE runoob_alter_testnew RENAME AS runoob_alter_testnewnew;
输出示例
-- A. ALTER TABLE "public"."runoob_alter_test" RENAME TO "runoob_alter_testnew"; -- B. ALTER TABLE "public"."runoob_alter_testnew" RENAME TO "runoob_alter_testnewnew";