zabbix mysql 数据库调优
zabbix 默认使用的是mysql数据库,当时zabbxi历史数据大的时候,会出现 cpu iowait的报警。
可以使用 mysql的分区表来解决,使用方法如下;
|
|
use zabbix
#关闭housekeeper
ALTER TABLE housekeeper ENGINE = BLACKHOLE;
#删除主键
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: 0 Duplicates: 0 Warnings: 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: 0 Duplicates: 0 Warnings: 0
mysql>
使用分区表
- 创建存储过程123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165DELIMITER $$CREATE PROCEDURE `partition_create`(SCHEMANAME varchar(64), TABLENAME varchar(64), PARTITIONNAME varchar(64), CLOCK int)BEGIN/*SCHEMANAME = The DB schema in which to make changesTABLENAME = The table with partitions to potentially deletePARTITIONNAME = The name of the partition to create*//*Verify that the partition does not already exist*/DECLARE RETROWS INT;SELECT COUNT(1) INTO RETROWSFROM information_schema.partitionsWHERE 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 changesTABLENAME = The table with partitions to potentially deleteDELETE_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 datein DELETE_BELOW_PARTITION_DATE. All partitions are prefixed witha "p", so use SUBSTRING TO get rid of that character.*/DECLARE myCursor CURSOR FORSELECT partition_nameFROM information_schema.partitionsWHERE 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 thatshould 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: LOOPFETCH myCursor INTO drop_part_name;IF done THENLEAVE 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 indicatethat no changes were made.*/SELECT CONCAT(SCHEMANAME, ".", TABLENAME) AS `table`, "N/A" 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)BEGINDECLARE 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: LOOPIF @__interval > CREATE_NEXT_INTERVALS THENLEAVE 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) THENCALL 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))BEGINDECLARE 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 RETROWSFROM information_schema.partitionsWHERE 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 querySET @__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 queryPREPARE STMT FROM @__PARTITION_SQL;EXECUTE STMT;DEALLOCATE PREPARE STMT;END IF;END$$DELIMITER ;
##
设置上面后 存储过程调用方法是
CALL partition_maintenance(‘zabbix’, ‘history’, 28, 24, 14);
CALL partition_maintenance(‘zabbix’, ‘history_log’, 28, 24, 14);
等
优化存储过程调用
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 ;
##使用上面这个存储过程之后
mysql> CALL partition_maintenance_all(‘zabbix’);
+—————-+——————–+
| table | partitions_deleted |
+—————-+——————–+
| zabbix.history | N/A |
+—————-+——————–+
1 row in set (0.01 sec)
….
….
….
+——————–+——————–+
| table | partitions_deleted |
+——————–+——————–+
| zabbix.trends_uint | N/A |
+——————–+——————–+
1 row in set (22.85 sec)
Query OK, 0 rows affected, 1 warning (22.85 sec)
mysql>
创建计划任务 每天定时 生成新的分区表
zabbix tunning 分区表
30 04 * mysql zabbix -e “CALL partition_maintenance_all(‘zabbix’);”
end zabbix
在zabbix server上关闭 Housekeeper
登录zabbix server的web管理
在上面菜单栏 –>管理–>一般 右边选管家
历史记录
开启内部管家 去除勾选
覆盖监控项历史期间 勾选
数据存储时间(天)28
趋势
开启内部管家 去除勾选
覆盖监控项趋势期间 勾选
数据存储时间(天) 730
注释:
mysql> CALL partition_maintenance(‘zabbix’, ‘history’, 28, 24, 14);
表明:历史数据保留28天,24小时,14代表一次创建14个表