CREATE TABLE `jk_data` ( `id` int(11) NOT NULL AUTO_INCREMENT COMMENT '数据ID主键', `jk_date` datetime NOT NULL COMMENT '时间日期格式', `jk_time` int(11) DEFAULT NULL COMMENT 'Unit格式的时间', `jk_sn` varchar(20) DEFAULT NULL COMMENT '设备序列号SN', `jk_counter` int(11) DEFAULT '0' COMMENT '设备计数器', `jk_ip` varchar(50) DEFAULT NULL COMMENT '设备在网络中的ip地址', `jk_isphysical` tinyint(2) DEFAULT '0' COMMENT '是否匹配了物理公式', `jk_eid` tinyint(4) DEFAULT '0' COMMENT 'ID号', `jk_wid` tinyint(2) DEFAULT '0' COMMENT '通道', `jk_wave` int(11) DEFAULT '0' COMMENT '波长', `jk_phyvalue` decimal(10,6) DEFAULT '0.000000' COMMENT '物理量', `jk_serialnum` varchar(20) DEFAULT NULL COMMENT '序列号', `jk_error` tinyint(2) DEFAULT '0' COMMENT '错误代码', `jk_warning` tinyint(2) DEFAULT '0' COMMENT '警告代码', PRIMARY KEY (`id`,`jk_date`) USING BTREE ) ENGINE=InnoDB AUTO_INCREMENT=304894 DEFAULT CHARSET=utf8 /*!50100 PARTITION BY RANGE (TO_DAYS(jk_date)-1) (PARTITION jk_data20201109 VALUES LESS THAN (738103) ENGINE = InnoDB, PARTITION jk_data20201110 VALUES LESS THAN (738104) ENGINE = InnoDB, PARTITION jk_data20201111 VALUES LESS THAN (738105) ENGINE = InnoDB, PARTITION jk_data20201112 VALUES LESS THAN (738106) ENGINE = InnoDB, PARTITION jk_data20201113 VALUES LESS THAN (738107) ENGINE = InnoDB, PARTITION jk_data20201114 VALUES LESS THAN (738108) ENGINE = InnoDB, PARTITION jk_data20201115 VALUES LESS THAN (738109) ENGINE = InnoDB, PARTITION jk_data20201116 VALUES LESS THAN (738110) ENGINE = InnoDB, PARTITION jk_data20201117 VALUES LESS THAN (738111) ENGINE = InnoDB, PARTITION jk_data20201118 VALUES LESS THAN (738112) ENGINE = InnoDB) */
创建存储过程
DROP PROCEDURE IF EXISTS topv.create_partition_jkdata; CREATE DEFINER=`topv`@`%` PROCEDURE `create_partition_jkdata`() BEGIN /* 事务回滚,其实放这里没什么作用,ALTER TABLE是隐式提交,回滚不了的。*/ DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK; START TRANSACTION; /* 到系统表查出这个表的最大分区,得到最大分区的日期。在创建分区的时候,名称就以日期格式存放,方便后面维护 */ SELECT REPLACE(partition_name,'jk_data','') INTO @P12_Name FROM INFORMATION_SCHEMA.PARTITIONS WHERE table_name='jk_data' ORDER BY partition_ordinal_position DESC LIMIT 1; SET @Max_date= DATE(DATE_ADD(@P12_Name+0, INTERVAL 1 DAY))+0; /* 修改表,在最大分区的后面增加一个分区,时间范围加1天 */ SET @s1=CONCAT('ALTER TABLE jk_data ADD PARTITION (PARTITION jk_data',@Max_date,' VALUES LESS THAN (TO_DAYS (''',DATE(@Max_date),''')))'); /* 输出查看增加分区语句*/ SELECT @s1; PREPARE stmt2 FROM @s1; EXECUTE stmt2; DEALLOCATE PREPARE stmt2; /* 取出最小的分区的名称,并删除掉 。 注意:删除分区会同时删除分区内的数据,慎重 */ /*select partition_name into @P0_Name from INFORMATION_SCHEMA.PARTITIONS where table_name='jk_data' order by partition_ordinal_position limit 1; SET @s=concat('ALTER TABLE jk_data DROP PARTITION ',@P0_Name); PREPARE stmt1 FROM @s; EXECUTE stmt1; DEALLOCATE PREPARE stmt1; */ /* 提交 */ COMMIT ; END;
Done!