23rfe 发表于 2015-12-21 09:50:03

zabbix分区表

由于housekeeper功能对性能有较大影响,建议关闭此功能,使用分区表来维护历史数据
从2.2版本开始,不再使用配置文件参数关闭,改为WEB页面Administration--->General--->housekeeping里关闭

查看是否支持分区表

1
mysql> show plugins      #查看partition项




修改表结构,删除主键,修改索引

1
2
3
mysql> use zabbix;
mysql> Alter table history_text drop primary key, add index (id), drop index history_text_2, add index history_text_2 (itemid, id);
mysql> Alter table history_log drop primary key, add index (id), drop index history_log_2, add index history_log_2 (itemid, id);




创建存储过程,共4个

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
DELIMITER $$
CREATE PROCEDURE `partition_create`(SCHEMANAME VARCHAR(64), TABLENAME VARCHAR(64), PARTITIONNAME VARCHAR(64), CLOCK INT)
BEGIN
      /*
         SCHEMANAME = The DB schema in which to make changes
         TABLENAME = The table with partitions to potentially delete
         PARTITIONNAME = The name of the partition to create
      */
      /*
         Verify that the partition does not already exist
      */
   
      DECLARE RETROWS INT;
      SELECT COUNT(1) INTO RETROWS
      FROM information_schema.partitions
      WHERE table_schema = SCHEMANAME AND TABLE_NAME = TABLENAME AND partition_description >= CLOCK;
   
      IF RETROWS = 0 THEN
                /*
                   1. Print a message indicating that a partition was created.
                   2. Create the SQL to create the partition.
                   3. Execute the SQL from #2.
                */
                SELECT CONCAT( "partition_create(", SCHEMANAME, ",", TABLENAME, ",", PARTITIONNAME, ",", CLOCK, ")" ) AS msg;
                SET @SQL = CONCAT( 'ALTER TABLE ', SCHEMANAME, '.', TABLENAME, ' ADD PARTITION (PARTITION ', PARTITIONNAME, ' VALUES LESS THAN (', CLOCK, '));' );
                PREPARE STMT FROM @SQL;
                EXECUTE STMT;
                DEALLOCATE PREPARE STMT;
      END IF;
END$$
DELIMITER ;





1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
DELIMITER $$
CREATE PROCEDURE `partition_drop`(SCHEMANAME VARCHAR(64), TABLENAME VARCHAR(64), DELETE_BELOW_PARTITION_DATE BIGINT)
BEGIN
      /*
         SCHEMANAME = The DB schema in which to make changes
         TABLENAME = The table with partitions to potentially delete
         DELETE_BELOW_PARTITION_DATE = Delete any partitions with names that are dates older than this one (yyyy-mm-dd)
      */
      DECLARE done INT DEFAULT FALSE;
      DECLARE drop_part_name VARCHAR(16);
   
      /*
         Get a list of all the partitions that are older than the date
         in DELETE_BELOW_PARTITION_DATE.All partitions are prefixed with
         a "p", so use SUBSTRING TO get rid of that character.
      */
      DECLARE myCursor CURSOR FOR
                SELECT partition_name
                FROM information_schema.partitions
                WHERE table_schema = SCHEMANAME AND TABLE_NAME = TABLENAME AND CAST(SUBSTRING(partition_name FROM 2) AS UNSIGNED) < DELETE_BELOW_PARTITION_DATE;
      DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
   
      /*
         Create the basics for when we need to drop the partition.Also, create
         @drop_partitions to hold a comma-delimited list of all partitions that
         should be deleted.
      */
      SET @alter_header = CONCAT("ALTER TABLE ", SCHEMANAME, ".", TABLENAME, " DROP PARTITION ");
      SET @drop_partitions = "";
   
      /*
         Start looping through all the partitions that are too old.
      */
      OPEN myCursor;
      read_loop: LOOP
                FETCH myCursor INTO drop_part_name;
                IF done THEN
                        LEAVE read_loop;
                END IF;
                SET @drop_partitions = IF(@drop_partitions = "", drop_part_name, CONCAT(@drop_partitions, ",", drop_part_name));
      END LOOP;
      IF @drop_partitions != "" THEN
                /*
                   1. Build the SQL to drop all the necessary partitions.
                   2. Run the SQL to drop the partitions.
                   3. Print out the table partitions that were deleted.
                */
                SET @full_sql = CONCAT(@alter_header, @drop_partitions, ";");
                PREPARE STMT FROM @full_sql;
                EXECUTE STMT;
                DEALLOCATE PREPARE STMT;
   
                SELECT CONCAT(SCHEMANAME, ".", TABLENAME) AS `table`, @drop_partitions AS `partitions_deleted`;
      ELSE
                /*
                   No partitions are being deleted, so print out "N/A" (Not applicable) to indicate
                   that no changes were made.
                */
                SELECT CONCAT(SCHEMANAME, ".", TABLENAME) AS `table`, "N/A" AS `partitions_deleted`;
      END IF;
END$$
DELIMITER ;





1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
DELIMITER $$
CREATE PROCEDURE `partition_maintenance`(SCHEMA_NAME VARCHAR(32), TABLE_NAME VARCHAR(32), KEEP_DATA_DAYS INT, HOURLY_INTERVAL INT, CREATE_NEXT_INTERVALS INT)
BEGIN
      DECLARE OLDER_THAN_PARTITION_DATE VARCHAR(16);
      DECLARE PARTITION_NAME VARCHAR(16);
      DECLARE LESS_THAN_TIMESTAMP INT;
      DECLARE CUR_TIME INT;
   
      CALL partition_verify(SCHEMA_NAME, TABLE_NAME, HOURLY_INTERVAL);
      SET CUR_TIME = UNIX_TIMESTAMP(DATE_FORMAT(NOW(), '%Y-%m-%d 00:00:00'));
   
      SET @__interval = 1;
      create_loop: LOOP
                IF @__interval > CREATE_NEXT_INTERVALS THEN
                        LEAVE create_loop;
                END IF;
   
                SET LESS_THAN_TIMESTAMP = CUR_TIME + (HOURLY_INTERVAL * @__interval * 3600);
                SET PARTITION_NAME = FROM_UNIXTIME(CUR_TIME + HOURLY_INTERVAL * (@__interval - 1) * 3600, 'p%Y%m%d%H00');
                CALL partition_create(SCHEMA_NAME, TABLE_NAME, PARTITION_NAME, LESS_THAN_TIMESTAMP);
                SET @__interval=@__interval+1;
      END LOOP;
   
      SET OLDER_THAN_PARTITION_DATE=DATE_FORMAT(DATE_SUB(NOW(), INTERVAL KEEP_DATA_DAYS DAY), '%Y%m%d0000');
      CALL partition_drop(SCHEMA_NAME, TABLE_NAME, OLDER_THAN_PARTITION_DATE);
   
END$$
DELIMITER ;





1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
DELIMITER $$
CREATE PROCEDURE `partition_verify`(SCHEMANAME VARCHAR(64), TABLENAME VARCHAR(64), HOURLYINTERVAL INT(11))
BEGIN
      DECLARE PARTITION_NAME VARCHAR(16);
      DECLARE RETROWS INT(11);
      DECLARE FUTURE_TIMESTAMP TIMESTAMP;
   
      /*
         * Check if any partitions exist for the given SCHEMANAME.TABLENAME.
         */
      SELECT COUNT(1) INTO RETROWS
      FROM information_schema.partitions
      WHERE table_schema = SCHEMANAME AND TABLE_NAME = TABLENAME AND partition_name IS NULL;
   
      /*
         * If partitions do not exist, go ahead and partition the table
         */
      IF RETROWS = 1 THEN
                /*
               * Take the current date at 00:00:00 and add HOURLYINTERVAL to it.This is the timestamp below which we will store values.
               * We begin partitioning based on the beginning of a day.This is because we don't want to generate a random partition
               * that won't necessarily fall in line with the desired partition naming (ie: if the hour interval is 24 hours, we could
               * end up creating a partition now named "p201403270600" when all other partitions will be like "p201403280000").
               */
                SET FUTURE_TIMESTAMP = TIMESTAMPADD(HOUR, HOURLYINTERVAL, CONCAT(CURDATE(), " ", '00:00:00'));
                SET PARTITION_NAME = DATE_FORMAT(CURDATE(), 'p%Y%m%d%H00');
   
                -- Create the partitioning query
                SET @__PARTITION_SQL = CONCAT("ALTER TABLE ", SCHEMANAME, ".", TABLENAME, " PARTITION BY RANGE(`clock`)");
                SET @__PARTITION_SQL = CONCAT(@__PARTITION_SQL, "(PARTITION ", PARTITION_NAME, " VALUES LESS THAN (", UNIX_TIMESTAMP(FUTURE_TIMESTAMP), "));");
   
                -- Run the partitioning query
                PREPARE STMT FROM @__PARTITION_SQL;
                EXECUTE STMT;
                DEALLOCATE PREPARE STMT;
      END IF;
END$$
DELIMITER ;




调用方法

1
2
3
CALL partition_maintenance('<zabbix_db_name>', '<table_name>', <days_to_keep_data>, <hourly_interval>, <num_future_intervals_to_create>)
例如:history表数据保留30天,每24小时一个分区,一次创建10个分区
CALL partition_maintenance(zabbix, 'history', 30, 24, 10);




将创建过程综合到一起

1
2
3
4
5
6
7
8
9
10
11
12
DELIMITER $$
CREATE PROCEDURE `partition_maintenance_all`(SCHEMA_NAME VARCHAR(32))
BEGIN
       CALL partition_maintenance(SCHEMA_NAME, 'history', 30, 24, 10);
       CALL partition_maintenance(SCHEMA_NAME, 'history_log', 30, 24, 10);
       CALL partition_maintenance(SCHEMA_NAME, 'history_str', 30, 24, 10);
       CALL partition_maintenance(SCHEMA_NAME, 'history_text', 30, 24, 10);
       CALL partition_maintenance(SCHEMA_NAME, 'history_uint', 30, 24, 10);
       CALL partition_maintenance(SCHEMA_NAME, 'trends', 120, 24, 10);
       CALL partition_maintenance(SCHEMA_NAME, 'trends_uint', 120, 24, 10);
END$$
DELIMITER ;




当要新建分区时使用CALL partition_maintenance_all('zabbix');即可

参考地址:https://github.com/itnihao/zabbix-book

页: [1]
查看完整版本: zabbix分区表