cencenhai 发表于 2019-1-17 12:38:46

Zabbix优化:数据库表分区

  参考:https://www.zabbix.org/wiki/Docs/howto/mysql_partition(官网)
  

  当zabbix监控的服务器数量越来越多,就会报“Zabbix housekeeper processes more than 75% busy”这个错误
http://blog.运维网.com/static/js/ueditor1.4.3/themes/default/images/spacer.gifhttp://s1.运维网.com/images/20171228/1514428144267776.png
  机器数量多的时候,mysql里面的history表就会越来越大,虽然zabbix本身有删除功能(就是那个housekeeper的功能),但这东西太影响性能,所以网上的做法都是关闭这个东西,用mysql的表分区功能来实现清理历史数据还可以提升mysql的性能
  修改表索引
http://s1.运维网.com/images/20171228/1514428171353109.png
   zabbix3.2以上版本跳过此步骤
mysql> Alter table history_text drop primary key, add index (id), drop index history_text_2, add index history_text_2 (itemid, id);
Query OK, 0 rows affected (0.49 sec)
Records: 0Duplicates: 0Warnings: 0
mysql> Alter table history_log drop primary key, add index (id), drop index history_log_2, add index history_log_2 (itemid, id);
Query OK, 0 rows affected (2.71 sec)
Records: 0Duplicates: 0Warnings: 0
mysql>  

  创建存储过程
     增加分区的存储过程:
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 ;      删除分区的存储过程
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(&quot;ALTER TABLE &quot;, SCHEMANAME, &quot;.&quot;, TABLENAME, &quot; DROP PARTITION &quot;);
      SET @drop_partitions = &quot;&quot;;
      /*
         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 = &quot;&quot;, drop_part_name, CONCAT(@drop_partitions, &quot;,&quot;, drop_part_name));
      END LOOP;
      IF @drop_partitions != &quot;&quot; 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, &quot;;&quot;);
                PREPARE STMT FROM @full_sql;
                EXECUTE STMT;
                DEALLOCATE PREPARE STMT;
                SELECT CONCAT(SCHEMANAME, &quot;.&quot;, TABLENAME) AS `table`, @drop_partitions AS `partitions_deleted`;
      ELSE
                /*
                   No partitions are being deleted, so print out &quot;N/A&quot; (Not applicable) to indicate
                   that no changes were made.
                */
                SELECT CONCAT(SCHEMANAME, &quot;.&quot;, TABLENAME) AS `table`, &quot;N/A&quot; AS `partitions_deleted`;
      END IF;
END$$
DELIMITER ;     维护分区的存储过程
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 OLD_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');
                IF(PARTITION_NAME != OLD_PARTITION_NAME) THEN
                        CALL partition_create(SCHEMA_NAME, TABLE_NAME, PARTITION_NAME, LESS_THAN_TIMESTAMP);
                END IF;
                SET @__interval=@__interval+1;
                SET OLD_PARTITION_NAME = PARTITION_NAME;
      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 ;     检查分区、创建第一个分区的存储过程
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 &quot;p201403270600&quot; when all other partitions will be like &quot;p201403280000&quot;).
               */
                SET FUTURE_TIMESTAMP = TIMESTAMPADD(HOUR, HOURLYINTERVAL, CONCAT(CURDATE(), &quot; &quot;, '00:00:00'));
                SET PARTITION_NAME = DATE_FORMAT(CURDATE(), 'p%Y%m%d%H00');
                -- Create the partitioning query
                SET @__PARTITION_SQL = CONCAT(&quot;ALTER TABLE &quot;, SCHEMANAME, &quot;.&quot;, TABLENAME, &quot; PARTITION BY RANGE(`clock`)&quot;);
                SET @__PARTITION_SQL = CONCAT(@__PARTITION_SQL, &quot;(PARTITION &quot;, PARTITION_NAME, &quot; VALUES LESS THAN (&quot;, UNIX_TIMESTAMP(FUTURE_TIMESTAMP), &quot;));&quot;);
                -- Run the partitioning query
                PREPARE STMT FROM @__PARTITION_SQL;
                EXECUTE STMT;
                DEALLOCATE PREPARE STMT;
      END IF;
END$$
DELIMITER ;  将上面4个存储过程语句写到一个sql文件里,partition_call.sql
  执行:mysql-uzabbix -p'zabbix' zabbix < partition_call.sql
  使用存储过程
  语法:
mysql> CALL partition_maintenance('', '', , , )  zabbix_db_name:库名
  table_name:表名
  days_to_keep_data:保存多少天的数据
  hourly_interval:每隔多久生成一个分区
  num_future_intervals_to_create:本次一共生成多少个分区
  例如:
  mysql> CALL partition_maintenance('zabbix', 'history', 7, 24, 7);

  这个例子就是history表最多保存7天的数据,每隔24小时生成一个分区,这次一共生成7个分区
  统一调用存储过程:
DELIMITER $$
CREATE PROCEDURE `partition_maintenance_all`(SCHEMA_NAME VARCHAR(32))
BEGIN
                CALL partition_maintenance(SCHEMA_NAME, 'history', 28, 24, 14);
                CALL partition_maintenance(SCHEMA_NAME, 'history_log', 28, 24, 14);
                CALL partition_maintenance(SCHEMA_NAME, 'history_str', 28, 24, 14);
                CALL partition_maintenance(SCHEMA_NAME, 'history_text', 28, 24, 14);
                CALL partition_maintenance(SCHEMA_NAME, 'history_uint', 28, 24, 14);
                CALL partition_maintenance(SCHEMA_NAME, 'trends', 730, 24, 14);
                CALL partition_maintenance(SCHEMA_NAME, 'trends_uint', 730, 24, 14);
END$$
DELIMITER ;  将这条语句保存成sql文件 partition_all.sql,再次导入存储过程
  mysql-uzabbix -p'zabbix' zabbix < partition_all.sql

  

  计划任务每天调用一次:
  注意:
  若数据量比较大,首次执行的时间较长,请使用nohup执行(我当时执行了15个小时左右,这期间zabbix是无法正常工作的,获取的agent数据不展示,但数据不会丢失)
  nohup time mysql -uzabbix -pzabbix zabbix -e &quot;CALL partition_maintenance_all('zabbix');&quot; &> /tmp/file.txt &
  后面只需要调用这个存储过程就可以了,每天执行一次:

  mysql -uzabbix -pzabbix zabbix -e &quot;CALL partition_maintenance_all('zabbix');&quot;
# crontab -e
0 1 * * * /data/tools/mysql/bin/mysql -uzabbix -pzabbix zabbix -e &quot;CALL partition_maintenance_all('zabbix');&quot;  关闭Housekeeper自维护功能
http://s1.运维网.com/images/20171228/1514428423429344.png
http://s1.运维网.com/images/20171228/1514428433693879.png



页: [1]
查看完整版本: Zabbix优化:数据库表分区