use test;
DELIMITER ||
drop procedure if exists 事件名称 ||
create procedure 事件名称 (in databasename varchar(50) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci,in tablename varchar(50) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci, in partition_number int, in partitiontype int, in gaps int)
L_END:
begin
declare max_partition_description varchar(255) default '';
declare p_name varchar(255) default 0;
declare p_description varchar(255) default 0;
declare isexist_partition varchar(255) default 0;
declare i int default 1;
select partition_name into isexist_partition from information_schema.partitions where table_schema = databasename and table_name = tablename limit 1;
if isexist_partition <=> "" then
select "partition table not is exist" as "ERROR";
leave L_END;
end if;
select partition_description into max_partition_description from information_schema.partitions where table_schema = databasename and table_name = tablename order by partition_description desc limit 1;
if max_partition_description <=> "" then
select "partition table is error" as "ERROR";
leave L_END;
end if;
set max_partition_description = REPLACE(max_partition_description-1, '\'', '');
-- 自动创建number个分区
while (i <= partition_number) do
if (partitiontype = 0) then
-- 每个分区按天递增,递增gaps天
set p_description = DATE_ADD(FROM_DAYS(max_partition_description), interval i*gaps day);
elseif (partitiontype = 1) then
-- 每个分区按月递增,递增gaps月
set p_description = DATE_ADD(FROM_DAYS(max_partition_description), interval i*gaps month);
else
-- 每个分区按年递增,递增gaps年
set p_description = DATE_ADD(FROM_DAYS(max_partition_description), interval i*gaps year);
end if;
-- 删除空格
set p_name = REPLACE(p_description, ' ', '');
-- 例如10.20的记录实际是less than 10.21
set p_description = DATE_ADD(p_description, interval 1 day);
-- 如果有横杆替换为空
set p_name = REPLACE(p_name, '-', '');
-- 删除时间冒号
set p_name = REPLACE(p_name, ':', '');
-- alter table tablename add partition ( partition pname values less than ('2019-05-22 23:59:59') );
set @sql=CONCAT('ALTER TABLE ', tablename ,' ADD PARTITION ( PARTITION p', p_name ,' VALUES LESS THAN (TO_DAYS(\'', p_description ,'\')))');
-- set @sql=CONCAT('ALTER TABLE ', tablename ,' ADD PARTITION ( PARTITION p', p_name ,' VALUES LESS THAN (TO_DAYS(\'', p_description ,'\')))');
-- 打印sql变量
-- select @sql;
-- 准备sql语句
PREPARE stmt from @sql;
-- 执行sql语句
EXECUTE stmt;
-- 释放资源
DEALLOCATE PREPARE stmt;
-- 递增变量
set i = (i + 1) ;
end while;
end ||
-- 恢复语句中断符
DELIMITER ;