文档首页/ 数据复制服务 DRS/ 常见问题/ 实时同步/ 同步到GaussDB(DWS)的使用建议
更新时间:2024-11-28 GMT+08:00

同步到GaussDB(DWS)的使用建议

增量DDL支持度

MySQL、Oracle等数据库语法与GaussDB(DWS)不同,增量阶段DDL同步存在失败的可能性,部分DDL转换规则可参考表1,建议在方案实施前联系GaussDB(DWS)技术支持评估DDL的支持度。

表1 DDL转换规则

语法转换点

转换结果

示例原语句

转换结果

备注

表名、列名有反引号

替换为双引号

create table `t1`( `c1`  int, `c2`  varchar(10) );
CREATE TABLE "public"."t1"(  "c1" INTEGER,  "c2" VARCHAR(40))  WITH ( ORIENTATION = ROW, COMPRESSION = NO )  NOCOMPRESS  DISTRIBUTE BY HASH ("c1");

-

key 字段名(字段名)

建索引

Create Table mall_order_dc (id bigint NOT NULL AUTO_INCREMENT,order_id varchar(50) NOT NULL,key order_id(id));
CREATE TABLE "public"."mall_order_dc"(
  "id" BIGSERIAL NOT NULL,
  "order_id" VARCHAR(200) NOT NULL)
  WITH ( ORIENTATION = ROW, COMPRESSION = NO )
  NOCOMPRESS
  DISTRIBUTE BY HASH ("id");
CREATE INDEX "order_id" ON "public"."mall_order_dc" USING BTREE ("id");

-

自定义的字段名和系统隐藏字段重名

加_new后缀

Create Table mall_order_dc (
xc_node_id bigint NOT NULL AUTO_INCREMENT,
tableoid varchar(50) NOT NULL,
cmax int,
xmax int,
cmin char,
xmin varchar(10),
ctid smallint,
tid time,
tidd int,
ctidd int
);
CREATE TABLE "public"."mall_order_dc"(
  "xc_node_id_new" BIGSERIAL NOT NULL,
  "tableoid_new" VARCHAR(200) NOT NULL,
  "cmax_new" INTEGER,
  "xmax_new" INTEGER,
  "cmin_new" CHAR(4),
  "xmin_new" VARCHAR(40),
  "ctid_new" SMALLINT,
  "tid_new" TIME WITHOUT TIME ZONE,
  "tidd" INTEGER,
  "ctidd" INTEGER)
  WITH ( ORIENTATION = ROW, COMPRESSION = NO )
  NOCOMPRESS
  DISTRIBUTE BY HASH ("xc_node_id_new");

GaussDB(DWS)有如下系统字段:xc_node_id,tableoid,cmax, xmax, cmin,xmin,ctid,tid,最终会加_new后缀进行重命名。

GaussDB(DWS)关键字做字段名,字段名需要加双引号

加双引号

-

-

所有表名、字段名均会添加双引号,关键字如desc,checksum,operator,size等。

GaussDB(DWS)关键字做表名,表名需要加双引号

加双引号

-

-

所有表名、字段名均会添加双引号,关键字如user。

RENAME TABLE

-

RENAME TABLE department TO newdept;
RENAME TABLE employee TO pepole;
RENAME TABLE newdept TO newdept_02,pepole to pepole_02;
ALTER TABLE "public"."department" RENAME TO "newdept";
ALTER TABLE "public"."employee" RENAME TO "pepole";
ALTER TABLE "public"."newdept" RENAME TO "newdept_02";
ALTER TABLE "public"."pepole" RENAME TO "pepole_02";

并列rename语句会转换成为多个rename语句。

SET DEFAULT

-

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 SET DEFAULT '1';
ALTER TABLE runoob_alter_test ALTER COLUMN dataType2 SET DEFAULT '3';
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" SET DEFAULT '1';
ALTER TABLE "public"."runoob_alter_test" ALTER COLUMN "datatype2" SET DEFAULT '3';

-

CHANGE

-

ALTER TABLE runoob_alter_test CHANGE dataType1 dataType1New VARCHAR(50);
ALTER TABLE runoob_alter_test CHANGE dataType2 dataType2New VARCHAR(50) NOT NULL;
ALTER TABLE runoob_alter_test CHANGE dataType3 dataType3New VARCHAR(100) FIRST;
ALTER TABLE runoob_alter_test CHANGE dataType4 dataType4New VARCHAR(50) AFTER dataType1;
ALTER TABLE "public"."runoob_alter_test" CHANGE COLUMN "datatype1" "datatype1new" VARCHAR(200);
ALTER TABLE "public"."runoob_alter_test" CHANGE COLUMN "datatype2" "datatype2new" VARCHAR(200) NOT NULL;
ALTER TABLE "public"."runoob_alter_test" CHANGE COLUMN "datatype3" "datatype3new" VARCHAR(400);
ALTER TABLE "public"."runoob_alter_test" CHANGE COLUMN "datatype4" "datatype4new" VARCHAR(200);

-

MODIFY

-

ALTER TABLE runoob_alter_test modify datatype1 char default 1;
ALTER TABLE runoob_alter_test modify datatype1 char default '1';
ALTER TABLE runoob_alter_test modify datatype1 char default "1";
ALTER TABLE "public"."runoob_alter_test" MODIFY "datatype1" CHAR(4) DEFAULT '1';
ALTER TABLE "public"."runoob_alter_test" MODIFY "datatype1" CHAR(4) DEFAULT '1';
ALTER TABLE "public"."runoob_alter_test" MODIFY "datatype1" CHAR(4) DEFAULT '1';

-

ADD PRIMARY KEY

-

ALTER TABLE runoob_alter_test ADD PRIMARY KEY (dataType1);
ALTER TABLE "public"."runoob_alter_test" ADD PRIMARY KEY("datatype1");

-

DROP PRIMARY KEY

-

ALTER TABLE runoob_alter_test DROP PRIMARY KEY;
ALTER TABLE "public"."runoob_alter_test" DROP CONSTRAINT IF EXISTS runoob_alter_test_pkey;

-

ADD COLUMN

-

ALTER TABLE runoob_alter_test ADD dataType1_1 INT NOT NULL AFTER dataType1;
ALTER TABLE "public"."runoob_alter_test" ADD COLUMN "datatype1_1" INTEGER NOT NULL;

-

ADD INDEX

-

ALTER TABLE runoob_tbl ADD INDEX idex_runoob_id(runoob_id) USING BTREE;
CREATE INDEX "idex_runoob_id" ON "public"."runoob_tbl" ("runoob_id");

-

ADD UNIQUE INDEX

unique key生成普通索引

ALTER TABLE runoob_tbl ADD UNIQUE KEY IDEX_runoob_id USING BTREE (runoob_id);
CREATE INDEX "idex_runoob_id" ON "public"."runoob_tbl" ("runoob_id");

-

DROP INDEX

-

ALTER TABLE runoob_tbl DROP KEY IDEX_runoob_id;
DROP INDEX "public"."idex_runoob_id" RESTRICT;

-

ALGORITHM

删除

ALTER TABLE runoob_alter_test ALGORITHM=DEFAULT;
ALTER TABLE runoob_alter_test ALGORITHM=INPLACE;
ALTER TABLE runoob_alter_test ALGORITHM=COPY;

-

-

DEFAULT CHARACTER SET

删除

ALTER TABLE runoob_alter_test CHARACTER SET=utf8;
ALTER TABLE runoob_alter_test DEFAULT CHARACTER SET=utf8;

-

-

COLLATE

删除

-

-

COLLATE表示默认的数据库排序规则。

DELAY_KEY_WRITE

删除

CREATE TABLE `public`.`runoob_tbl_test`(
 `runoob_id` VARCHAR(30),
 `runoob_title` VARCHAR(100) NOT NULL,
 `runoob_author` VARCHAR(40) NOT NULL,
 `submission_date` VARCHAR(30)
) ENGINE=MyISAM, DELAY_KEY_WRITE=0;
ALTER TABLE `public`.`runoob_tbl_test6` DELAY_KEY_WRITE=1;
CREATE TABLE "PUBLIC"."RUNOOB_TBL_TEST"(
 "RUNOOB_ID" VARCHAR(30),
 "RUNOOB_TITLE" VARCHAR(100) NOT NULL,
 "RUNOOB_AUTHOR" VARCHAR(40) NOT NULL,
 "SUBMISSION_DATE" VARCHAR(30)
) WITH ( ORIENTATION = ROW, COMPRESSION = NO )
 NOCOMPRESS
 DISTRIBUTE BY HASH ("RUNOOB_ID");

DELAY_KEY_WRITE只对MyISAM引擎表有作用,根据DELAY_KEY_WRITE的值来延迟更新直至表关闭。

DIRECTORY

删除

CREATE TABLE `public`.`runoob_tbl_test1` (
`dataType1` int NOT NULL AUTO_INCREMENT,
`dataType2` DOUBLE(20,8), 
PRIMARY KEY(`dataType1`)
) ENGINE=MYISAM DATA DIRECTORY = 'D:\\input' INDEX DIRECTORY= 'D:\\input';
CREATE TABLE `public`.`runoob_tbl_test2` (
`dataType1` int NOT NULL AUTO_INCREMENT, 
`dataType2` DOUBLE(20,8), 
PRIMARY KEY(`dataType1`)
) ENGINE=INNODB DATA DIRECTORY = 'D:\\input'
CREATE TABLE "public"."runoob_tbl_test1"(
 "datatype1" SERIAL NOT NULL,
 "datatype2" FLOAT(20),
 PRIMARY KEY ("datatype1")
) WITH ( ORIENTATION = ROW, COMPRESSION = NO )
 NOCOMPRESS
 DISTRIBUTE BY HASH ("datatype1");
CREATE TABLE "public"."runoob_tbl_test2"(
 "datatype1" SERIAL NOT NULL,
 "datatype2" FLOAT(20),
 PRIMARY KEY ("datatype1")
) WITH ( ORIENTATION = ROW, COMPRESSION = NO )
 NOCOMPRESS
 DISTRIBUTE BY HASH ("datatype1");

-

INSERT_METHOD

删除

CREATE TABLE `public`.`runoob_alter_test`(
 `dataType1` int NOT NULL AUTO_INCREMENT,
 `dataType2` DOUBLE(20,8),
 `dataType3` TEXT NOT NULL,
 PRIMARY KEY(`dataType1`)
) INSERT_METHOD=LAST;
ALTER TABLE runoob_alter_test INSERT_METHOD NO;
ALTER TABLE runoob_alter_test INSERT_METHOD=NO;
ALTER TABLE runoob_alter_test INSERT_METHOD FIRST;
ALTER TABLE runoob_alter_test INSERT_METHOD=FIRST;
ALTER TABLE runoob_alter_test INSERT_METHOD LAST;
ALTER TABLE runoob_alter_test INSERT_METHOD=LAST;
CREATE TABLE "public"."runoob_alter_test"(
 "datatype1" SERIAL NOT NULL,
 "datatype2" FLOAT(20),
 "datatype3" TEXT NOT NULL,
 PRIMARY KEY ("datatype1")
) WITH ( ORIENTATION = ROW, COMPRESSION = NO )
 NOCOMPRESS
 DISTRIBUTE BY HASH ("datatype1");

-

KEY_BLOCK_SIZE

删除

CREATE TABLE `public`.`runoob_tbl_test`(
 `runoob_id` VARCHAR(30),
 `runoob_title` VARCHAR(100) NOT NULL,
 `runoob_author` VARCHAR(40) NOT NULL,
 `submission_date` VARCHAR(30)
) ENGINE=MyISAM KEY_BLOCK_SIZE=8;
ALTER TABLE runoob_tbl_test ENGINE=InnoDB;
ALTER TABLE runoob_tbl_test KEY_BLOCK_SIZE=0;
CREATE TABLE "public"."runoob_tbl_test"(
 "runoob_id" VARCHAR(30),
 "runoob_title" VARCHAR(100) NOT NULL,
 "runoob_author" VARCHAR(40) NOT NULL,
 "submission_date" VARCHAR(30)
) WITH ( ORIENTATION = ROW, COMPRESSION = NO )
 NOCOMPRESS
 DISTRIBUTE BY HASH ("runoob_id");

-

MAX_ROWS

删除

CREATE TABLE `public`.`runoob_alter_test`(
 `dataType1` int NOT NULL AUTO_INCREMENT,
 `dataType2` DOUBLE(20,8),
 `dataType3` TEXT NOT NULL,
 PRIMARY KEY(`dataType1`)
);
ALTER TABLE runoob_alter_test MAX_ROWS 100000;
ALTER TABLE runoob_alter_test MAX_ROWS=100000;
CREATE TABLE "public"."runoob_alter_test"(
"datatype1" SERIAL NOT NULL,
"datatype2" FLOAT(20),
"datatype3" TEXT NOT NULL,
PRIMARY KEY ("datatype1")
) WITH ( ORIENTATION = ROW, COMPRESSION = NO )
NOCOMPRESS
DISTRIBUTE BY HASH ("datatype1");

-

MIN_ROWS

删除

CREATE TABLE `public`.`runoob_alter_test`(
`dataType1` int NOT NULL AUTO_INCREMENT,
`dataType2` DOUBLE(20,8),
`dataType3` TEXT NOT NULL,
PRIMARY KEY(`dataType1`)
);
ALTER TABLE runoob_alter_test MIN_ROWS 10000;
ALTER TABLE runoob_alter_test MIN_ROWS=10000;
CREATE TABLE "public"."runoob_alter_test"(
"datatype1" SERIAL NOT NULL,
"datatype2" FLOAT(20),
"datatype3" TEXT NOT NULL,
PRIMARY KEY ("datatype1")
)WITH ( ORIENTATION = ROW, COMPRESSION = NO )
NOCOMPRESS
DISTRIBUTE BY HASH ("datatype1");

-

PACK_KEYS

删除

CREATE TABLE `public`.`runoob_alter_test`(
`dataType1` int NOT NULL AUTO_INCREMENT,
`dataType2` DOUBLE(20,8),
`dataType3` TEXT NOT NULL,
PRIMARY KEY(`dataType1`)
) ENGINE=MyISAM PACK_KEYS=1;
##A
ALTER TABLE runoob_alter_test PACK_KEYS 0;
ALTER TABLE runoob_alter_test PACK_KEYS=0;
##B
ALTER TABLE runoob_alter_test PACK_KEYS 1;
ALTER TABLE runoob_alter_test PACK_KEYS=1;
##C
ALTER TABLE runoob_alter_test PACK_KEYS DEFAULT;
ALTER TABLE runoob_alter_test PACK_KEYS=DEFAULT;
CREATE TABLE "public"."runoob_alter_test"(
"datatype1" SERIAL NOT NULL,
"datatype2" FLOAT(10),
"datatype3" FLOAT(20),
"datatype4" TEXT NOT NULL,
PRIMARY KEY ("datatype1")
)WITH ( ORIENTATION = ROW, COMPRESSION = NO )
NOCOMPRESS
DISTRIBUTE BY HASH ("datatype1");
--A
--B
--C

-

PASSWORD

删除

CREATE TABLE `public`.`runoob_alter_test`(

`dataType1` int NOT NULL AUTO_INCREMENT,

`dataType2` DOUBLE(20,8),

`dataType3` TEXT NOT NULL,

PRIMARY KEY(`dataType1`)

);

ALTER TABLE runoob_alter_test PASSWORD 'HELLO';

CREATE TABLE "public"."runoob_alter_test"

(

"datatype1" SERIAL NOT NULL,

"datatype2" FLOAT(20),

"datatype3" TEXT NOT NULL,

PRIMARY KEY ("datatype1")

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("datatype1");

-

STATS_AUTO_RECALC

删除

CREATE TABLE `public`.`runoob_alter_test`(

`runoob_id` VARCHAR(30),

`runoob_title` VARCHAR(100) NOT NULL,

`runoob_author` VARCHAR(40) NOT NULL,

`submission_date` VARCHAR(30)

) ENGINE=InnoDB, STATS_AUTO_RECALC=DEFAULT;

## A.

ALTER TABLE runoob_alter_test STATS_AUTO_RECALC DEFAULT;

ALTER TABLE runoob_alter_test STATS_AUTO_RECALC=DEFAULT;

## B.

ALTER TABLE runoob_alter_test STATS_AUTO_RECALC 0;

ALTER TABLE runoob_alter_test STATS_AUTO_RECALC=0;

## C.

ALTER TABLE runoob_alter_test STATS_AUTO_RECALC 1;

ALTER TABLE runoob_alter_test STATS_AUTO_RECALC=1;

CREATE TABLE "public"."runoob_alter_test"

(

"runoob_id" VARCHAR(30),

"runoob_title" VARCHAR(100) NOT NULL,

"runoob_author" VARCHAR(40) NOT NULL,

"submission_date" VARCHAR(30)

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("runoob_id");

-- A.

-- B.

-- C

-

STATS_PERSISTENT

删除

CREATE TABLE `public`.`runoob_alter_test`(

`dataType1` int NOT NULL AUTO_INCREMENT,

`dataType2` DOUBLE(20,8),

`dataType3` TEXT NOT NULL,

PRIMARY KEY(`dataType1`)

) ENGINE=InnoDB, STATS_PERSISTENT=0;

## A.

ALTER TABLE runoob_alter_test STATS_PERSISTENT DEFAULT;

ALTER TABLE runoob_alter_test STATS_PERSISTENT=DEFAULT;

## B.

ALTER TABLE runoob_alter_test STATS_PERSISTENT 0;

ALTER TABLE runoob_alter_test STATS_PERSISTENT=0;

## C.

ALTER TABLE runoob_alter_test STATS_PERSISTENT 1;

ALTER TABLE runoob_alter_test STATS_PERSISTENT=1

CREATE TABLE "public"."runoob_alter_test"

(

"datatype1" SERIAL NOT NULL,

"datatype2" FLOAT(20),

"datatype3" TEXT NOT NULL,

PRIMARY KEY ("datatype1")

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("datatype1");

-- A.

-- B.

-- C.

-

STATS_SAMPLE_PAGES

删除

CREATE TABLE `public`.`runoob_alter_test`(

`dataType1` int NOT NULL AUTO_INCREMENT,

`dataType2` DOUBLE(20,8),

`dataType3` TEXT NOT NULL,

PRIMARY KEY(`dataType1`)

) ENGINE=InnoDB,STATS_SAMPLE_PAGES=25;

ALTER TABLE runoob_alter_test STATS_SAMPLE_PAGES 100;

ALTER TABLE runoob_alter_test STATS_SAMPLE_PAGES=100;

CREATE TABLE "public"."runoob_alter_test"

(

"datatype1" SERIAL NOT NULL,

"datatype2" FLOAT(20),

"datatype3" TEXT NOT NULL,

PRIMARY KEY ("datatype1")

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("datatype1");

-

创建表指定引擎类型

删除

CREATE TABLE `public`.`runoob_alter_test`(

`dataType1` int NOT NULL,

`dataType2` DOUBLE(20,8),

PRIMARY KEY(`dataType1`)

)ENGINE=MYISAM;

## A.

ALTER TABLE runoob_alter_test ENGINE INNODB;

ALTER TABLE runoob_alter_test ENGINE=INNODB;

## B.

ALTER TABLE runoob_alter_test ENGINE MYISAM;

ALTER TABLE runoob_alter_test ENGINE=MYISAM;

## C.

ALTER TABLE runoob_alter_test ENGINE MEMORY;

ALTER TABLE runoob_alter_test ENGINE=MEMORY

CREATE TABLE "public"."runoob_alter_test"

(

"datatype1" INTEGER NOT NULL,

"datatype2" FLOAT(20),

PRIMARY KEY ("datatype1")

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("datatype1");

-- A.

-- B.

-- C.

在MySQL中,ENGINE指定表的存储引擎。当存储引擎为ARCHIVE、BLACKHOLE、CSV、FEDERATED、INNODB、MYISAM、MEMORY、MRG_MYISAM、NDB、NDBCLUSTER和PERFOMANCE_SCHEMA时,支持该属性迁移,迁移过程中会将该属性删除。

CHECKSUM

删除

CREATE TABLE `public`.`runoob_alter_test`(

`dataType1` int NOT NULL AUTO_INCREMENT,

`dataType2` FLOAT(10,2),

`dataType3` DOUBLE(20,8),

PRIMARY KEY(`dataType1`)

) CHECKSUM=1;

ALTER TABLE runoob_alter_test CHECKSUM 0;

ALTER TABLE runoob_alter_test CHECKSUM=0;

ALTER TABLE runoob_alter_test CHECKSUM 1;

ALTER TABLE runoob_alter_test CHECKSUM=1

CREATE TABLE "public"."runoob_alter_test"

(

"datatype1" SERIAL NOT NULL,

"datatype2" REAL,

"datatype3" DOUBLE PRECISION,

PRIMARY KEY ("datatype1")

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("datatype1");

-

ON UPDATE CURRENT_TIMESTAMP

删除

drop table if exists unsupport_parse_test;

create table `unsupport_parse_test` (

`username` int,

`update` timestamp not null default current_timestamp on update current_timestamp

);

DROP TABLE IF EXISTS "public"."unsupport_parse_test";

CREATE TABLE "public"."unsupport_parse_test"

(

"username" INTEGER,

"update" TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("username");

-

SET FOREIGN_KEY_CHECKS=0或1

删除

-

-

-

PRIMARY KEY (`id`) USING BTREE

删除

Create Table mall_order_dc (

id int,

name varchar(10),

primary key(`id`) using btree

);

CREATE TABLE "public"."mall_order_dc"

(

"id" INTEGER,

"name" VARCHAR(40),

PRIMARY KEY ("id")

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("id");

默认btree,不需要此关键字

行列存转换

默认行存

-

-

-

create table if not exists

支持if not exists关键字

-

-

-

charset

迁移时会将该关键字删除。

-

-

CHARSET指定表的默认字符集。

分区表

支持RANGE分区

drop table if exists `runoob_tbl_part_test`;

CREATE TABLE IF NOT EXISTS `runoob_tbl_part_test`(

`runoob_id` INT NOT NULL,

`runoob_title` VARCHAR(100) NOT NULL,

`runoob_author` VARCHAR(40) NOT NULL,

`submission_date` INT

)ENGINE=InnoDB DEFAULT CHARSET=utf8

PARTITION BY RANGE COLUMNS(runoob_id, submission_date)(

PARTITION p0 VALUES LESS THAN(123, MAXVALUE),

PARTITION p1 VALUES LESS THAN(200, MAXVALUE),

PARTITION p2 VALUES LESS THAN(300, MAXVALUE),

PARTITION p3 VALUES LESS THAN(400, MAXVALUE),

PARTITION p4 VALUES LESS THAN(500, MAXVALUE),

PARTITION p5 VALUES LESS THAN(MAXVALUE, MAXVALUE)

);

CREATE TABLE IF NOT EXISTS "public"."runoob_tbl_part_test"

(

"runoob_id" INTEGER NOT NULL,

"runoob_title" VARCHAR(400) NOT NULL,

"runoob_author" VARCHAR(160) NOT NULL,

"submission_date" INTEGER

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("runoob_id")

PARTITION BY RANGE ("runoob_id", "submission_date")

(

PARTITION p0 VALUES LESS THAN (123, MAXVALUE),

PARTITION p1 VALUES LESS THAN (200, MAXVALUE),

PARTITION p2 VALUES LESS THAN (300, MAXVALUE),

PARTITION p3 VALUES LESS THAN (400, MAXVALUE),

PARTITION p4 VALUES LESS THAN (500, MAXVALUE),

PARTITION p5 VALUES LESS THAN (MAXVALUE, MAXVALUE)

);

-

字段指定字符编码

删除

CREATE TABLE `FCT_TRADE_***_RT` (

`KID` INT(11) NOT NULL AUTO_INCREMENT,

`YM` VARCHAR(7) CHARSET UTF8MB4 COLLATE UTF8MB4_BIN NOT NULL COMMENT '年月,例如2019-04'

);

CREATE TABLE "public"."fct_trade_***_rt"

(

"kid" SERIAL NOT NULL,

"ym" VARCHAR(28) NOT NULL COMMENT '年月,例如2019-04'

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("kid");

-

带数据宽度的整型

删除宽度

CREATE TABLE `FCT_TRADE_***_RT` (

`KID` INT(11) NOT NULL AUTO_INCREMENT,

`YM` SMALLINT(15),

`c3` BIGINT(50)

);

CREATE TABLE "public"."fct_trade_***_rt"

(

"kid" SERIAL NOT NULL,

"ym" SMALLINT,

"c3" BIGINT

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("kid");

数字类型int、smallint、bigint不支持带宽度,统一删除。

unsigned zerofill

删除

CREATE TABLE IF NOT EXISTS `runoob_dataType_test`(

`dataType_1` DEC,

`dataType_2` DEC(10),

`dataType_3` DEC(10, 2) UNSIGNED ZEROFILL,

`dataType_4` DEC(10, 2) ZEROFILL

)ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci;

CREATE TABLE IF NOT EXISTS "public"."runoob_datatype_test"

(

"datatype_1" DECIMAL,

"datatype_2" DECIMAL(10),

"datatype_3" DECIMAL(10,2),

"datatype_4" DECIMAL(10,2)

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("datatype_1");

-

auto_increment

不支持该参数,迁移时会将设置该属性的字段迁移为SERIAL类型,并删除该关键字。

CREATE TABLE `public`.`job_instance` (

`job_sche_id` int(11) NOT NULL AUTO_INCREMENT,

`task_name` varchar(100) NOT NULL DEFAULT '',

PRIMARY KEY (`job_sche_id`)

) ENGINE=InnoDB AUTO_INCREMENT=219 DEFAULT CHARSET=utf8

CREATE TABLE "public"."job_instance"

(

"job_sche_id" SERIAL NOT NULL,

"task_name" VARCHAR(100) NOT NULL DEFAULT '',

PRIMARY KEY ("job_sche_id")

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("job_sche_id");

-

AVG_ROW_LENGTH

不支持此属性,该属性将迁移到SERIAL,并在迁移过程中被删除。

CREATE TABLE `public`.`runoob_tbl_test`(

`runoob_id` VARCHAR(30),

`runoob_title` VARCHAR(100) NOT NULL,

`runoob_author` VARCHAR(40) NOT NULL,

`submission_date` VARCHAR(30)

)AVG_ROW_LENGTH=10000;

CREATE TABLE "public"."runoob_tbl_test"

(

"runoob_id" VARCHAR(30),

"runoob_title" VARCHAR(100) NOT NULL,

"runoob_author" VARCHAR(40) NOT NULL,

"submission_date" VARCHAR(30)

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("runoob_id")

-

UNION

迁移时会将该特性转为GaussDB视图创建语句。

CREATE TABLE t1 (

a INT NOT NULL AUTO_INCREMENT PRIMARY KEY,

message CHAR(20)

) ENGINE=MyISAM;

CREATE TABLE t2 (

a INT NOT NULL AUTO_INCREMENT PRIMARY KEY,

message CHAR(20)

) ENGINE=MyISAM;

CREATE TABLE total (

a INT NOT NULL AUTO_INCREMENT,

message CHAR(20))

ENGINE=MERGE UNION=(t1,t2) INSERT_METHOD=LAST;

CREATE TABLE t1 (

a SERIAL NOT NULL PRIMARY KEY,

message CHAR(20)

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("a");

CREATE TABLE t2 (

a SERIAL NOT NULL PRIMARY KEY,

message CHAR(20)

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("a");

CREATE VIEW total(a, message) AS

SELECT * FROM t1

UNION ALL

SELECT * FROM t2;

UNION 是 MERGE 引擎的建表参数。通过该关键字建表类似于创建普通视图。新创建的表将在逻辑上合并UNION关键字限定的多个表的数据。

LIKE 表克隆

迁移时会添加额外的表属性信息。

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);

-

drop表

默认schema为public

DROP TABLE `test_create_table01`;

DROP TABLE "public"."test_create_table01";

-

TRUNCATE 删除表

-

TRUNCATE TABLE `test_create_table01`;

TRUNCATE TABLE "public"."test_create_table01" CONTINUE IDENTITY RESTRICT;

-

HASH索引

迁移时会根据GaussDB的特性将其迁移为普通索引。

CREATE TABLE `public`.`test_create_table03` (

`DEMAND_ID` INT(11) NOT NULL AUTO_INCREMENT,

`DEMAND_NAME` CHAR(100) NOT NULL,

`THEME` VARCHAR(200) NULL DEFAULT NULL,

`SEND_ID` INT(11) NULL DEFAULT NULL,

`SEND_NAME` CHAR(20) NULL DEFAULT NULL,

`SEND_TIME` DATETIME NULL DEFAULT NULL,

`DEMAND_CONTENT` TEXT NOT NULL,

PRIMARY KEY(`DEMAND_ID`),

INDEX CON_INDEX(DEMAND_CONTENT(100)) USING HASH ,

INDEX SEND_INFO_INDEX USING HASH (SEND_ID,SEND_NAME(10),SEND_TIME)

);

ALTER TABLE runoob_alter_test ADD KEY alterTable_addKey_indexType(dataType1) USING HASH;

CREATE TABLE "public"."test_create_table03"

(

"demand_id" SERIAL NOT NULL,

"demand_name" CHAR(100) NOT NULL,

"theme" VARCHAR(200) DEFAULT NULL,

"send_id" INTEGER(11) DEFAULT NULL,

"send_name" CHAR(20) DEFAULT NULL,

"send_time" TIMESTAMP WITHOUT TIME ZONE DEFAULT NULL,

"demand_content" TEXT NOT NULL,

PRIMARY KEY ("demand_id")

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("demand_id");

CREATE INDEX "con_index" ON "public"."test_create_table03" ("demand_content");

CREATE INDEX "send_info_index" ON "public"."test_create_table03"

("send_id","send_name","send_time");

CREATE INDEX "altertable_addkey_indextype" ON "public"."runoob_alter_test" ("datatype1");

-

BTREE索引

迁移时会根据GaussDB的特性进行相应适配。

ALTER TABLE runoob_alter_test ADD KEY alterTable_addKey_indexType (dataType1) USING BTREE;

CREATE INDEX "altertable_addkey_indextype" ON "public"."runoob_alter_test" ("datatype1");

-

SPATIAL 空间索引

迁移时会根据GaussDB的特性进行相应适配。

CREATE TABLE `public`.`test_create_table04` (

`ID` INT(11) NOT NULL AUTO_INCREMENT PRIMARY KEY,

`A` POINT NOT NULL,

`B` POLYGON NOT NULL,

`C` GEOMETRYCOLLECTION NOT NULL,

`D` LINESTRING NOT NULL,

`E` MULTILINESTRING NOT NULL,

`F` MULTIPOINT NOT NULL,

`G` MULTIPOLYGON NOT NULL,

SPATIAL INDEX A_INDEX(A),

SPATIAL INDEX B_INDEX(B),

SPATIAL INDEX C_INDEX(C),

SPATIAL KEY D_INDEX(D),

SPATIAL KEY E_INDEX(E),

SPATIAL KEY F_INDEX(F),

SPATIAL INDEX G_INDEX(G)

);

CREATE TABLE "public"."test_create_table04"

(

"id" SERIAL NOT NULL PRIMARY KEY,

"a" POINT NOT NULL,

"b" POLYGON NOT NULL,

"c" CIRCLE NOT NULL,

"d" POLYGON NOT NULL,

"e" BOX NOT NULL,

"f" BOX NOT NULL,

"g" POLYGON NOT NULL

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("id");

CREATE INDEX "a_index" ON "public"."test_create_table04" USING GIST ("a");

CREATE INDEX "b_index" ON "public"."test_create_table04" USING GIST ("b");

CREATE INDEX "c_index" ON "public"."test_create_table04" USING GIST ("c");

CREATE INDEX "d_index" ON "public"."test_create_table04" USING GIST ("d");

CREATE INDEX "e_index" ON "public"."test_create_table04" USING GIST ("e");

CREATE INDEX "f_index" ON "public"."test_create_table04" USING GIST ("f");

CREATE INDEX "g_index" ON "public"."test_create_table04" USING GIST ("g")

-

FULLTEXT 全文索引

迁移时会根据GaussDB的特性进行相应适配。

CREATE TABLE `public`.`test_create_table02` (

`ID` INT(11) NOT NULL PRIMARY KEY,

`TITLE` CHAR(255) NOT NULL,

`CONTENT` TEXT NULL,

`CREATE_TIME` DATETIME NULL DEFAULT NULL,

FULLTEXT (`CONTENT`)

);

CREATE TABLE IF NOT EXISTS `public`.`runoob_dataType_test`

(

`id` INT PRIMARY KEY AUTO_INCREMENT,

`name` VARCHAR(128) NOT NULL,

FULLTEXT INDEX (name)

);

CREATE TABLE IF NOT EXISTS `public`.`runoob_dataType_test`

(

`id` INT PRIMARY KEY AUTO_INCREMENT,

`name` VARCHAR(128) NOT NULL,

FULLTEXT INDEX (name ASC)

);

CREATE TABLE "public"."test_create_table02"

(

"id" INTEGER(11) NOT NULL PRIMARY KEY,

"title" CHAR(255) NOT NULL,

"content" TEXT,

"create_time" TIMESTAMP WITHOUT TIME ZONE DEFAULT NULL

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("id");

CREATE INDEX "idx_test_create_table02_content" ON "public"."test_create_table02" USING

GIN(to_tsvector(coalesce("content",'')));

CREATE TABLE "public"."runoob_datatype_test"

(

"id" SERIAL PRIMARY KEY,

"name" VARCHAR(128) NOT NULL

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("id");

CREATE INDEX "idx_runoob_datatype_test_name" ON "public"."runoob_datatype_test" USING

GIN(to_tsvector(coalesce("name",'')));

CREATE TABLE "public"."runoob_datatype_test"

(

"id" SERIAL PRIMARY KEY,

"name" VARCHAR(128) NOT NULL

)

WITH ( ORIENTATION = ROW, COMPRESSION = NO )

NOCOMPRESS

DISTRIBUTE BY HASH ("id");

CREATE INDEX "idx_runoob_datatype_test_name" ON "public"."runoob_datatype_test" USING

GIN(to_tsvector(coalesce("name",'')));

-

CHECK约束

迁移时会根据GaussDB的特性进行相应适配。

drop table if exists `t1`;

create table if not exists t1 (

id int(25) not null primary key check (id > 1 and id < 100),

city varchar(255) not null unique check (city='CityA' or city='CityB' or city='CityC'),

population int(25) not null ,

constraint t1_1 check (population>0 and population<10000)

) ;

DROP TABLE IF EXISTS "public"."t1";

CREATE TABLE IF NOT EXISTS "public"."t1" (

"id" INTEGER NOT NULL PRIMARY KEY CHECK (

id > 1

and id < 100

),

"city" VARCHAR(1020) NOT NULL CHECK (

city = 'CityA'

or city = 'CityB'

or city = 'CityC'

),

"population" INTEGER NOT NULL,

CONSTRAINT t1_1 CHECK (

population > 0

and population < 10000

)

) WITH (ORIENTATION = ROW, COMPRESSION = NO) NOCOMPRESS DISTRIBUTE BY HASH ("id

-

GENERATED ALWAYS AS

删除

create table `createTable_others11` (

id INT PRIMARY KEY,

price DECIMAL(10, 2),

discount DECIMAL(4, 2),

discounted_price DECIMAL(10, 2) GENERATED ALWAYS AS (price - price * discount) STORED

);

-

-

多表归一场景注意事项

DRS支持多表对一的数据聚合场景,最佳实践是推荐只选择同步加列DDL,其他大部分DDL同步都可能会因目标表修改而导致其他任务失败或数据不一致的情况发生,常见情况有:同步truncate导致目标数据全部被清空;同步创建索引导致目标表被锁定;同步rename导致其他任务找不到目标表而失败;同步改列导致其他任务因数据类型不兼容而失败。

  • 多表归一高风险操作:
    • DROP、TRUNCATE、RENAME等高危DDL未过滤,导致目标表DROP、TRUNCATE、RENAME。
    • 随意执行DDL,导致同步任务中断未提前识别业务数据冲突,出现同步后数据不一致。
    • 多对一的表不支持Online DDL工具。Online DDL通常会使用临时表和执行rename操作,多对一任务如果未过滤rename会导致目标数据丢失。
  • 多表归一DDL操作技巧:
    • 增加列ADD COLUMN:

      配置DRS任务时过滤ADD COLUMN:先在目标库目标表增加列,再在每个多对一任务的源库源表分别增加列。同步任务会自动兼容源表列少于目标表的场景,因此任务不受影响。顺序相反则会导致任务中断。

      配置DRS任务时未过滤ADD COLUMN:DRS会自动识别只执行一次DDL,不会导致任务失败。

    • 修改列MODIFY COLUMN:

      配置DRS任务时过滤MODIFY COLUMN:需要确保所有源表已经完成同步无时延并且无业务写入,先在目标库目标表修改列,再在每个多对一任务的源库源表分别修改列。

      配置DRS任务时未过滤MODIFY COLUMN:DRS会自动识别只执行一次DDL,不会导致任务失败。

    • 删除列DROP COLUMN:

      配置DRS任务时过滤DROP COLUMN:先在每个源库源表删除列,多对一任务的所有源表删除列后,再在目标库表删除列。同步任务会自动兼容源表列少于目标表的场景,因此任务不受影响。顺序相反则会导致任务中断。

      配置DRS任务时未过滤DROP COLUMN:DRS会自动识别只执行一次DDL,不会导致任务失败。

    • DROP、TRUNCATE类操作:

      高危操作建议配置DRS任务时过滤掉,手工执行。如果未选择过滤,多对一任务一张源表的DROP、TRUNCATE操作会同步到目标表执行DROP、TRUNCATE操作,比如多对一任务DROP掉其中一个表,在目标库就把多对一的表DROP掉了,DROP索引、DROP约束是类似的。