美文网首页
mysql 自动分区实现,包含天,小时、分钟三种分区

mysql 自动分区实现,包含天,小时、分钟三种分区

作者: JackSpeed | 来源:发表于2019-10-12 16:53 被阅读0次

    当前版本:mysql8.0


    一共分为三步

     1.建库、建表
     2.新建自动创建分区的存储过程和新建定时调用分区存储过程的事件
     3.测试:新建自动插入数据的存储过程和事件
    

    需要关注的.

    1.一定要在建表的之后创建分区,如果不这个时候创建,后期存储过程中创建会失败,mysql会有提示!
    2.DATE_FORMAT(TARGET_DATE, 'p%Y%m%d%h%m')得到的数字不是年月日小时分,而是年月日小时月,应该使用 DATE_FORMAT(TARGET_DATE, 'p%Y%m%d%h%m%i')
    3.执行顺序要按三步顺序执行


    一、建库、建表

    create database if not exists test;
    use test;
    
    drop table if exists t_auto_insert_day;
    create table if not exists test.t_auto_insert_day
    (
        id        int auto_increment not null,
        column_2  varchar(20)        null,
        dc_time   datetime           null,
        data_time bigint             not null comment '数据时间,数据分区字段yyyymmdd',
        primary key (id, data_time)
    ) partition by range ( data_time ) (
        partition p20190912 values less than (20190912)
        );
    
    drop table if exists t_auto_insert_hour;
    create table if not exists test.t_auto_insert_hour
    (
        id        int auto_increment not null,
        column_2  varchar(20)        null,
        column_3  varchar(20)        null,
        dc_time   datetime           null,
        data_time bigint             not null comment '数据时间,数据分区字段yyyymmddHH',
        primary key (id, data_time)
    ) partition by range ( data_time ) (
        partition p2019091215 values less than (2019091215)
        );
    
    drop table if exists t_auto_insert_minute;
    create table if not exists test.t_auto_insert_minute
    (
        id        int auto_increment not null,
        column_2  varchar(20)        null,
        dc_time   datetime           null,
        data_time bigint             not null comment '数据时间,数据分区字段yyyymmddHHmm',
        primary key (id, data_time)
    ) partition by range ( data_time ) (
        partition p201909121525 values less than (201909121525)
        );
    
    

    新建分区存储过程和对应的事件

     drop procedure if exists auto_create_partition_by_day;
    #每天创建区分存储过程
    create procedure auto_create_partition_by_day(IN IN_SCHEMANAME varchar(64), IN IN_TABLENAME varchar(64))
    BEGIN
        #当前日期存在的分区的个数
        DECLARE ROWS_CNT INT UNSIGNED;
        #目前日期,为当前日期的后一天
        DECLARE TARGET_DATE TIMESTAMP;
        #分区的名称,格式为p20180620
        DECLARE PARTITIONNAME VARCHAR(9);
        #当前分区名称的分区值上限,即为 PARTITIONNAME + 1
        DECLARE PARTITION_ADD_DAY VARCHAR(9);
        SET TARGET_DATE = NOW() + INTERVAL 1 DAY;
        #格式化时间得到新增分区名称
        SET PARTITIONNAME = DATE_FORMAT(TARGET_DATE, 'p%Y%m%d');
        SET TARGET_DATE = TARGET_DATE + INTERVAL 1 DAY;
        #格式化时间得到新增分区范围
        SET PARTITION_ADD_DAY = DATE_FORMAT(TARGET_DATE, '%Y%m%d');
        SELECT COUNT(*)
        INTO ROWS_CNT
        FROM information_schema.partitions
        WHERE table_schema = IN_SCHEMANAME
          AND table_name = IN_TABLENAME
          AND partition_name = PARTITIONNAME;
        IF ROWS_CNT = 0 THEN
            SET @SQL = CONCAT('ALTER TABLE `', IN_SCHEMANAME, '`.`', IN_TABLENAME, '`',
                              ' ADD PARTITION (PARTITION ', PARTITIONNAME, ' VALUES LESS THAN (',
                              PARTITION_ADD_DAY, ') ENGINE = InnoDB);');
            PREPARE STMT FROM @SQL;
            EXECUTE STMT;
            deallocate PREPARE STMT;
        ELSE
            SELECT CONCAT('partition `', PARTITIONNAME, '` for table `', IN_SCHEMANAME, '.', IN_TABLENAME, '` already exists') AS result;
        END IF;
    END;
    
    drop event if exists event_every_day_call_create_partition;
    #每天晚上十二点,执行事件,调用每天分区存储过程
    create event event_every_day_call_create_partition on schedule
        every '1' day
            #从现在开始,也可以从制定时间开始2019-09-11 23:59:59
            starts now()
        on completion preserve
        enable
        do
        #调用分区存储过程
        call auto_create_partition_by_day('test', 't_auto_insert_day');
    
    
    
    drop procedure if exists auto_create_partition_by_hour;
    #每小时创建区分存储过程
    create procedure auto_create_partition_by_hour(IN IN_SCHEMANAME varchar(64), IN IN_TABLENAME varchar(64))
    BEGIN
        #当前日期存在的分区的个数
        DECLARE ROWS_CNT INT UNSIGNED;
        #目前日期,为当前日期的后一天
        DECLARE TARGET_DATE TIMESTAMP;
        #分区的名称,格式为p2019091214
        DECLARE PARTITIONNAME VARCHAR(11);
        #当前分区名称的分区值上限,即为 PARTITIONNAME + 1
        DECLARE PARTITION_ADD_HOUR VARCHAR(11);
        SET TARGET_DATE = NOW() + INTERVAL 1 hour;
        SET PARTITIONNAME = DATE_FORMAT(TARGET_DATE, 'p%Y%m%d%H');
        SET TARGET_DATE = TARGET_DATE + INTERVAL 1 hour;
        SET PARTITION_ADD_HOUR = DATE_FORMAT(TARGET_DATE, '%Y%m%d%H');
        SELECT COUNT(*)
        INTO ROWS_CNT
        FROM information_schema.partitions
        WHERE table_schema = IN_SCHEMANAME
          AND table_name = IN_TABLENAME
          AND partition_name = PARTITIONNAME;
        IF ROWS_CNT = 0 THEN
            SET @SQL = CONCAT('ALTER TABLE `', IN_SCHEMANAME, '`.`', IN_TABLENAME, '`',
                              ' ADD PARTITION (PARTITION ', PARTITIONNAME, ' VALUES LESS THAN (',
                              PARTITION_ADD_HOUR, ') ENGINE = InnoDB);');
            PREPARE STMT FROM @SQL;
            EXECUTE STMT;
            deallocate PREPARE STMT;
        ELSE
            SELECT CONCAT('partition `', PARTITIONNAME, '` for table `', IN_SCHEMANAME, '.', IN_TABLENAME, '` already exists') AS result;
        END IF;
    END;
    
    drop event if exists event_every_hour_call_create_partition;
    #每小时,执行事件,调用每天分区存储过程
    create event event_every_hour_call_create_partition on schedule
        every '1' hour
            #从现在开始,也可以从制定时间开始2019-09-11 10:00:00
            starts now()
        on completion preserve
        enable
        do
        #调用分区存储过程
        call auto_create_partition_by_hour('test', 't_auto_insert_hour');
    
    
    
    drop procedure if exists auto_create_partition_by_five_minute;
    #每五分钟分区一次的存储过程
    create procedure auto_create_partition_by_five_minute(IN IN_SCHEMANAME varchar(64), IN IN_TABLENAME varchar(64))
    BEGIN
        #当前日期存在的分区的个数
        DECLARE ROWS_CNT INT UNSIGNED;
        #当前日期,为当前日期的后一天
        DECLARE TARGET_DATE TIMESTAMP;
        #分区的名称,格式为p201909121009
        DECLARE PARTITIONNAME VARCHAR(15);
        #当前分区名称的分区值上限,即为 PARTITIONNAME + 1
        DECLARE PARTITION_ADD_MINUTE VARCHAR(15);
        SET TARGET_DATE = NOW() + INTERVAL 5 minute;
        SET PARTITIONNAME = DATE_FORMAT(TARGET_DATE, 'p%Y%m%d%H%i');
        SET TARGET_DATE = TARGET_DATE + INTERVAL 5 minute;
        SET PARTITION_ADD_MINUTE = DATE_FORMAT(TARGET_DATE, '%Y%m%d%H%i');
        SELECT COUNT(*)
        INTO ROWS_CNT
        FROM information_schema.partitions
        WHERE table_schema = IN_SCHEMANAME
          AND table_name = IN_TABLENAME
          AND partition_name = PARTITIONNAME;
        IF ROWS_CNT = 0 THEN
            SET @SQL = CONCAT('ALTER TABLE `', IN_SCHEMANAME, '`.`', IN_TABLENAME, '`',
                              ' ADD PARTITION (PARTITION ', PARTITIONNAME, ' VALUES LESS THAN (',
                              PARTITION_ADD_MINUTE, ') ENGINE = InnoDB);');
            PREPARE STMT FROM @SQL;
            EXECUTE STMT;
            deallocate PREPARE STMT;
        ELSE
            SELECT CONCAT('partition `', PARTITIONNAME, '` for table `', IN_SCHEMANAME, '.', IN_TABLENAME, '` already exists') AS result;
        END IF;
    END;
    
    drop event if exists event_every_five_minute_call_create_partition;
    #每五分钟,执行事件,调用分区存储过程
    create event event_every_five_minute_call_create_partition on schedule
        every '5' minute
            #从现在开始,也可以从制定时间开始2019-09-11 10:00:00
            starts now() #'2019-09-11 10:00:00'
        on completion preserve
        enable
        do
        #调用分区存储过程
        call auto_create_partition_by_five_minute('test', 't_auto_insert_minute');
    
    

    新建插入数据的存储过程和对应的事件

    #清空表,且重置主键
    truncate table t_auto_insert_day;
    truncate table t_auto_insert_hour;
    truncate table t_auto_insert_minute;
    
    
    drop procedure if exists procedure_auto_insert_day;
    #创建存储过程,每天插入5数据
    create procedure procedure_auto_insert_day()
    BEGIN
        declare i int default 0;
        while (i < 5)
            do
                insert into t_auto_insert_day
                values (0, concat('auto_insert_day', i), now(), date_format(now(), '%Y%m%d'));
                set i = i + 1;
            end while;
    END;
    
    
    #创建事件,每天调用存储过程,插入5条数据
    drop event if exists event_every_day_call_insert;
    create event event_every_day_call_insert on schedule
        every '1' day
            #从2019-09-11 10:00:00 开始执行
            starts now()
        on completion preserve
        enable
        do
        call procedure_auto_insert_day();
    
    
    
    drop procedure if exists procedure_auto_insert_hour;
    #创建存储过程,每小时插入5条数据
    create
        procedure procedure_auto_insert_hour()
    BEGIN
        declare i int default 0;
        while (i < 5)
            do
                insert into t_auto_insert_hour
                values (0, concat('auto_insert_hour', i), concat('auto_insert_hour', i), now(), date_format(now(), '%Y%m%d%H'));
                set i = i + 1;
            end while;
    END;
    
    drop event if exists event_every_hour_call_insert;
    #创建事件,每小时调用存储过程插入5条数据
    create event event_every_hour_call_insert on schedule
        every '1' hour
            #从现在开始执行
            starts now()
        on completion preserve
        enable
        do
        call procedure_auto_insert_hour();
    
    
    drop procedure if exists procedure_auto_insert_minute;
    #存储过程-每分钟插入数据
    create
        procedure procedure_auto_insert_minute()
    BEGIN
        declare i int default 0;
        while (i < 5)
            do
                insert into t_auto_insert_minute
                values (0, concat('procene', i), now(), concat(date_format(now(), '%Y%m%d%H'), minute(now())));
                set i = i + 1;
            end while;
    
    END;
    
    
    drop event if exists event_every_minute_call_insert;
    #每分钟一次调用存储过程
    create event event_every_minute_call_insert on schedule
        every 1 minute
            starts now()
        on completion preserve
        enable
        do
        call procedure_auto_insert_minute();
    

    查询分区结果:

    select partition_name        part,
           partition_expression  expr,
           partition_description descr,
           table_rows
    from information_schema.partitions
    where table_schema = 'test'
      and table_name = 't_auto_insert_minute';
    

    返回结果

    part expr descr table_rows
    p201909121525 data_time 201909121525 0
    p201909121728 data_time 201909121733 45
    p201909121733 data_time 201909121738 24
    p201909121738 data_time 201909121743 24
    p201909121743 data_time 201909121748 24
    p201909121748 data_time 201909121753 25
    p201909121753 data_time 201909121758 25

    p201909121525这个分区是初始化表的时候创建的。

    手动新增分区

    ALTER TABLE t_auto_insert_minute add PARTITION (PARTITION p201909121509 values less than (201909121509));
    

    删除分区,删除时不能全部删除,最少需要留一个

    ALTER TABLE t_auto_insert_minute    DROP PARTITION 201909121509;
    

    相关文章

      网友评论

          本文标题:mysql 自动分区实现,包含天,小时、分钟三种分区

          本文链接:https://www.haomeiwen.com/subject/fnbgyctx.html