Browse Source

优化迁移sql:
1.生成site、channel、viewInfo、tableInfo、template五个特殊的偏移量记录表
2.sp_data_migration_buildOffset迁移前生成当次偏移量记录数据

xxy 6 years ago
parent
commit
c9fe10634b

+ 4 - 2
TRS.WCM.Developer/贵州项目/0_delete_redundance_data.sql

@@ -1,5 +1,5 @@
-#迁移前先清除冗余数据
-#需求场景:按站点迁移一个节点,须保留的站点id人工整理
+-- 迁移前先清除冗余数据
+-- 需求场景:按站点迁移一个节点,须保留的站点id人工整理
 
 DELETE from wcmwebsite where siteid not in (124,120,66,108,35,52,101,91,76,88,184,195,188,177,194,193,187,190,183,186,191,189,175,176,180,179,174,169,130,166,165,164,199,198,197,173,182,155,171,196);
 -- 删除多余栏目
@@ -44,6 +44,8 @@ DELETE from xwcmdbfieldinfo where TABLEID not in (SELECT TABLEINFOID from xwcmta
 -- --------数据记录
 -- chnldoc记录
 DELETE from wcmchnldoc where CHNLID not in (SELECT CHANNELID from wcmchannel);
+-- 时间: 609.133s
 -- document
 DELETE from wcmdocument where docchannel not in (SELECT CHANNELID from wcmchannel);
+-- 时间: 1295.934s
 -- metatable如何清理?

+ 48 - 1
TRS.WCM.Developer/贵州项目/1_data_migration_offset.sql

@@ -1,3 +1,48 @@
+use trs_data_migration;
+-- 对于在其他表有外键的记录,
+-- 建立offset表,记录迁移的次数、上次迁移的id、偏移量用于增量时能够获取到每次偏移量的变化
+CREATE  TABLE `site_offset`(
+  `times` SMALLINT NOT NULL comment '迁移次数',
+  `previous_id` INT(11) NOT NULL comment '上次迁移的最大id',
+  `offset` INT(11) NOT NULL comment '偏移量',
+  PRIMARY KEY (`times`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+CREATE  TABLE `channel_offset`(
+  `times` SMALLINT NOT NULL comment '迁移次数',
+  `previous_id` INT(11) NOT NULL comment '上次迁移的最大id',
+  `offset` INT(11) NOT NULL comment '偏移量',
+  PRIMARY KEY (`times`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+CREATE  TABLE `template_offset`(
+  `times` SMALLINT NOT NULL comment '迁移次数',
+  `previous_id` INT(11) NOT NULL comment '上次迁移的最大id',
+  `offset` INT(11) NOT NULL comment '偏移量',
+  PRIMARY KEY (`times`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+CREATE  TABLE `document_offset`(
+  `times` SMALLINT NOT NULL comment '迁移次数',
+  `previous_id` INT(11) NOT NULL comment '上次迁移的最大id',
+  `offset` INT(11) NOT NULL comment '偏移量',
+  PRIMARY KEY (`times`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+CREATE  TABLE `viewInfo_offset`(
+  `times` SMALLINT NOT NULL comment '迁移次数',
+  `previous_id` INT(11) NOT NULL comment '上次迁移的最大id',
+  `offset` INT(11) NOT NULL comment '偏移量',
+  PRIMARY KEY (`times`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+CREATE  TABLE `tableInfo_offset`(
+  `times` SMALLINT NOT NULL comment '迁移次数',
+  `previous_id` INT(11) NOT NULL comment '上次迁移的最大id',
+  `offset` INT(11) NOT NULL comment '偏移量',
+  PRIMARY KEY (`times`)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
 CREATE TABLE `data_migration_offset` (
   `tableName` varchar(50) NOT NULL DEFAULT '',
   `offset` int(11) DEFAULT NULL,
@@ -12,4 +57,6 @@ BEGIN
 	IF @x = 0 THEN
     INSERT into data_migration_offset values(t_name ,_offset);
 	END IF;
-END $$
+END $$
+
+

+ 52 - 0
TRS.WCM.Developer/贵州项目/2.sp_data_migration_buildOffset.sql

@@ -0,0 +1,52 @@
+use trs_data_migration;
+-- 迁移前执行call sp_data_migration_buildOffset(n);
+-- 为偏移量记录表插入数据。
+DROP PROCEDURE IF EXISTS sp_data_migration_buildOffset;
+DELIMITER $$
+CREATE PROCEDURE sp_data_migration_buildOffset(IN n SMALLINT(2))
+  BEGIN
+-- 文档表
+    set @offset = IFNULL((select `offset` from document_offset where `times` = n),0);
+    IF @docOffset = 0 THEN
+			SET @previous_id = IFNULL((select MAX(docId) from wcmdocument),0);
+			SET @offset = IFNULL((select MAX(docid) from trs_hycloud_iip.wcmdocument),0);
+			INSERT INTO document_offset values(n,@previous_id,@offset);
+		END IF;
+-- 站点表
+    set @offset = IFNULL((select `offset` from site_offset where `times` = n),0);
+    IF @offset = 0 THEN
+			SET @previous_id = IFNULL((select MAX(siteId) from wcmwebsite),0);
+			SET @offset = IFNULL((select MAX(siteId) from trs_hycloud_iip.wcmwebsite),0);
+			INSERT INTO site_offset values(n,@previous_id,@offset);
+		END IF;
+
+-- 栏目表
+    set @offset = IFNULL((select `offset` from channel_offset where `times` = n),0);
+    IF @offset = 0 THEN
+			SET @previous_id = IFNULL((select MAX(channelId) from wcmchannel),0);
+			SET @offset = IFNULL((select MAX(channelId) from trs_hycloud_iip.wcmchannel),0);
+			INSERT INTO channel_offset values(n,@previous_id,@offset);
+		END IF;
+-- template表
+    set @offset = IFNULL((select `offset` from template_offset where `times` = n),0);
+    IF @offset = 0 THEN
+			SET @previous_id = IFNULL((select MAX(tempId) from wcmtemplate),0);
+			SET @offset = IFNULL((select MAX(tempId) from trs_hycloud_iip.wcmtemplate),0);
+			INSERT INTO template_offset values(n,@previous_id,@offset);
+		END IF;
+-- viewInfo表
+    set @offset = IFNULL((select `offset` from viewInfo_offset where `times` = n),0);
+    IF @offset = 0 THEN
+			SET @previous_id = IFNULL((select MAX(viewInfoId) from xwcmviewinfo),0);
+			SET @offset = IFNULL((select MAX(viewInfoId) from trs_hycloud_iip.xwcmviewinfo),0);
+			INSERT INTO viewInfo_offset values(n,@previous_id,@offset);
+		END IF;
+-- tableInfo表
+    set @offset = IFNULL((select `offset` from tableInfo_offset where `times` = n),0);
+    IF @offset = 0 THEN
+			SET @previous_id = IFNULL((select MAX(tableInfoId) from xwcmtableinfo),0);
+			SET @offset = IFNULL((select MAX(tableInfoId) from trs_hycloud_iip.xwcmtableinfo),0);
+			INSERT INTO tableInfo_offset values(n,@previous_id,@offset);
+		END IF;
+  END $$
+DELIMITER ;