zabbix進(jìn)行數(shù)據(jù)庫備份以及表分區(qū)的方法
由于測試環(huán)境上面使用的zabbix服務(wù)器配置比較低,經(jīng)常會遇到性能瓶頸(主要是數(shù)據(jù)庫和磁盤I/O等),于是倒逼我使用了一些方式來緩解這些問題。
主要是以前使用的那個(gè)備份數(shù)據(jù)庫的腳本是對zabbix數(shù)據(jù)庫進(jìn)行全備的,使用的又是mysql自帶的工具mysqldump,當(dāng)數(shù)據(jù)量大了之后進(jìn)行全備所花的時(shí)間比較長,這樣將會造成數(shù)據(jù)庫的鎖讀。。。從而使zabbix服務(wù)以為mysql死掉了,產(chǎn)生一大堆的報(bào)警。
后來發(fā)現(xiàn)原來造成數(shù)據(jù)庫數(shù)據(jù)量大量增加的是zabbix數(shù)據(jù)庫中的一些存儲數(shù)據(jù)的大表導(dǎo)致的。于是備份數(shù)據(jù)庫的時(shí)候可以選擇跳過這些表進(jìn)行備份,這樣,將大大減少數(shù)據(jù)庫備份所花的時(shí)間(PS:之前備份數(shù)據(jù)庫所花時(shí)間在十分鐘左右,現(xiàn)在跳過大表備份,所花時(shí)間在1S左右就能備份完,大大縮短了備份數(shù)據(jù)庫時(shí)間)。
下面就貼出某位大神寫的專門為zabbix數(shù)據(jù)庫做備份以及恢復(fù)的腳本:
#!/bin/bash #author: itnihao red='\e[0;31m' # 紅色 RED='\e[1;31m' green='\e[0;32m' # 綠色 GREEN='\e[1;32m' blue='\e[0;34m' # 藍(lán)色 BLUE='\e[1;34m' purple='\e[0;35m' # 紫色 PURPLE='\e[1;35m' NC='\e[0m' # 沒有顏色 source /etc/bashrc source /etc/profile MySQL_USER=zabbix MySQL_PASSWORD=zabbix MySQL_HOST=localhost MySQL_PORT=3306 MySQL_DUMP_PATH=/opt/backup MYSQL_BIN_PATH=/opt/software/mysql/bin/mysql MYSQL_DUMP_BIN_PATH=/opt/software/mysql/bin/mysqldump MySQL_DATABASE_NAME=zabbix DATE=$(date '+%Y%m%d') MySQLDUMP () { [ -d ${MySQL_DUMP_PATH} ] || mkdir ${MySQL_DUMP_PATH} cd ${MySQL_DUMP_PATH} [ -d logs ] || mkdir logs [ -d ${DATE} ] || mkdir ${DATE} cd ${DATE} #TABLE_NAME_ALL=$(${MYSQL_BIN_PATH} -u${MySQL_USER} -p${MySQL_PASSWORD} -h${MySQL_HOST} ${MySQL_DATABASE_NAME} -e "show tables"|egrep -v "(Tables_in_zabbix)") TABLE_NAME_ALL=$(${MYSQL_BIN_PATH} -u${MySQL_USER} -p${MySQL_PASSWORD} -h${MySQL_HOST} ${MySQL_DATABASE_NAME} -e "show tables"|egrep -v "(Tables_in_zabbix|history*|trends*|acknowledges|alerts|auditlog|events|service_alarms)") for TABLE_NAME in ${TABLE_NAME_ALL} do ${MYSQL_DUMP_BIN_PATH} --opt -u${MySQL_USER} -p${MySQL_PASSWORD} -P${MySQL_PORT} -h${MySQL_HOST} ${MySQL_DATABASE_NAME} ${TABLE_NAME} >${TABLE_NAME}.sql sleep 0.01 done [ "$?" == 0 ] && echo "${DATE}: Backup zabbix succeed" >> ${MySQL_DUMP_PATH}/logs/ZabbixMysqlDump.log [ "$?" != 0 ] && echo "${DATE}: Backup zabbix not succeed" >> ${MySQL_DUMP_PATH}/logs/ZabbixMysqlDump.log cd ${MySQL_DUMP_PATH}/ rm -rf $(date +%Y%m%d --date='5 days ago') exit 0 } MySQLImport () { cd ${MySQL_DUMP_PATH} DATE=$(ls ${MySQL_DUMP_PATH} |egrep "\b^[0-9]+$\b") echo -e "${green}${DATE}" echo -e "${blue}what DATE do you want to import,please input date:${NC}" read SELECT_DATE if [ -d "${SELECT_DATE}" ];then echo -e "you select is ${green}${SELECT_DATE}${NC}, do you want to contine,if,input ${red}(yes|y|Y)${NC},else then exit" read Input [[ 'yes|y|Y' =~ "${Input}" ]] status="$?" if [ "${status}" == "0" ];then echo "now import SQL....... Please wait......." else exit 1 fi cd ${SELECT_DATE} for PER_TABEL_SQL in $(ls *.sql) do ${MYSQL_BIN_PATH} -u${MySQL_USER} -p${MySQL_PASSWORD} -h${MySQL_HOST} ${MySQL_DATABASE_NAME} < ${PER_TABEL_SQL} echo -e "import ${PER_TABEL_SQL} ${PURPLE}........................${NC}" done echo "Finish import SQL,Please check Zabbix database" else echo "Don't exist ${SELECT_DATE} DIR" fi } case "$1" in MySQLDUMP|mysqldump) MySQLDUMP ;; MySQLImport|mysqlimport) MySQLImport ;; *) echo "Usage: $0 {(MySQLDUMP|mysqldump) (MySQLImport|mysqlimport)}" ;; esac
該腳本源出處在這https://github.com/itnihao/zabbix-book/blob/master/03-chapter/Zabbix_MySQLdump_per_table_v2.sh
我這是在大神的腳本上做了修改之后形成的適合我自己備份的腳本,各位也可以自行修改成適合自己的備份腳本。這個(gè)腳本實(shí)現(xiàn)的效果上面已經(jīng)說了,之前做全備的時(shí)候差不多有4G左右的數(shù)據(jù)量,現(xiàn)在只備份配置文件數(shù)據(jù)量只有不到10M,果斷大大節(jié)省時(shí)間以及空間呀。
不過這樣的話將無法保證數(shù)據(jù)的備份,我目前考慮使用xtradbbackup對數(shù)據(jù)進(jìn)行增量備份,目前還未實(shí)現(xiàn),留待過兩天做吧。
好了,關(guān)于數(shù)據(jù)庫備份的事情搞了,然后還需要對大數(shù)據(jù)量的表進(jìn)行表分區(qū),參考了zabbix官網(wǎng)的一篇文章https://www.zabbix.org/wiki/Docs/howto/mysql_partition 各位有興趣的話可以去看看,我這里將其總結(jié)在了一起,更加方便一點(diǎn)。
表分區(qū)可以對大數(shù)據(jù)量的表進(jìn)行物理上的拆分成多個(gè)文件,但是邏輯上來看,還是一張表,對應(yīng)用程序是透明的。另外,將這一張大表拆分成很多小表的話將使得數(shù)據(jù)查詢速度能夠更快。還可以隨時(shí)刪除舊的數(shù)據(jù)分區(qū),刪除過期數(shù)據(jù)。這種方式適用于大數(shù)據(jù)量的表,但是查詢量比較少的應(yīng)用場景。如果是大數(shù)據(jù)量的表,又有大量查詢的話建議還是進(jìn)行分庫分表操作。
好了,不多扯了,開始作業(yè)了。
首先,登錄數(shù)據(jù)庫(PS:這個(gè)就不演示了)
然后登陸到zabbix庫中修改兩張表的結(jié)構(gòu):
use zabbix; Alter table history_text drop primary key, add index (id), drop index history_text_2, add index history_text_2 (itemid, id); Alter table history_log drop primary key, add index (id), drop index history_log_2, add index history_log_2 (itemid, id);
修改完之后再按照官網(wǎng)上的過程創(chuàng)建四個(gè)存儲過程:
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("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 ;
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 ;
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 ;
上面四個(gè)存儲過程執(zhí)行后將可以使用
CALL partition_maintenance('<zabbix_db_name>', '<table_name>', <days_to_keep_data>, <hourly_interval>, <num_future_intervals_to_create>)
命令對想要分區(qū)的表進(jìn)行表分區(qū)了。其中的參數(shù)我這里解釋一下。
這是舉例:
CALL partition_maintenance(zabbix, 'history_uint', 31, 24, 14);
zabbix_db_name:庫名
table_name:表名
days_to_keep_data:保存多少天的數(shù)據(jù)
hourly_interval:每隔多久生成一個(gè)分區(qū)
num_future_intervals_to_create:本次一共生成多少個(gè)分區(qū)
這個(gè)例子就是history_uint表最多保存31天的數(shù)據(jù),每隔24小時(shí)生成一個(gè)分區(qū),這次一共生成14個(gè)分區(qū)
這里可以將上面四個(gè)存儲過程保存為一個(gè)文件,導(dǎo)入到數(shù)據(jù)庫中,文件我稍后將會放在附件中,這里使用的命令是:mysql -uzabbix -pzabbix zabbix<partition_call.sql
然后可以將CALL統(tǒng)一調(diào)用也做成一個(gè)文件,統(tǒng)一調(diào)用的內(nèi)容如下:
DELIMITER $$ CREATE PROCEDURE `partition_maintenance_all`(SCHEMA_NAME VARCHAR(32)) BEGIN CALL partition_maintenance(SCHEMA_NAME, 'history', 31, 24, 14); CALL partition_maintenance(SCHEMA_NAME, 'history_log', 31, 24, 14); CALL partition_maintenance(SCHEMA_NAME, 'history_str', 31, 24, 14); CALL partition_maintenance(SCHEMA_NAME, 'history_text', 31, 24, 14); CALL partition_maintenance(SCHEMA_NAME, 'history_uint', 31, 24, 14); CALL partition_maintenance(SCHEMA_NAME, 'trends', 180, 24, 14); CALL partition_maintenance(SCHEMA_NAME, 'trends_uint', 180, 24, 14); END$$ DELIMITER ;
也將該文件導(dǎo)入到數(shù)據(jù)庫中,使用命令:mysql -uzabbix -pzabbix zabbix<partition_all.sql
好了,到了這里之后就可以使用如下命令執(zhí)行表分區(qū)了:
mysql -uzabbix -pzabbix zabbix -e "CALL partition_maintenance_all('zabbix');" +----------------+--------------------+ | table | partitions_deleted | +----------------+--------------------+ | zabbix.history | N/A | +----------------+--------------------+ +--------------------+--------------------+ | table | partitions_deleted | +--------------------+--------------------+ | zabbix.history_log | N/A | +--------------------+--------------------+ +--------------------+--------------------+ | table | partitions_deleted | +--------------------+--------------------+ | zabbix.history_str | N/A | +--------------------+--------------------+ +---------------------+--------------------+ | table | partitions_deleted | +---------------------+--------------------+ | zabbix.history_text | N/A | +---------------------+--------------------+ +---------------------+--------------------+ | table | partitions_deleted | +---------------------+--------------------+ | zabbix.history_uint | N/A | +---------------------+--------------------+ +---------------+--------------------+ | table | partitions_deleted | +---------------+--------------------+ | zabbix.trends | N/A | +---------------+--------------------+ +--------------------+--------------------+ | table | partitions_deleted | +--------------------+--------------------+ | zabbix.trends_uint | N/A | +--------------------+--------------------+
看到如下結(jié)果證明所有7張表都進(jìn)行了表分區(qū),也可以在Mysql的數(shù)data目錄下看到新生成的表分區(qū)文件。(PS:注意,最好是清空history_uint表的數(shù)據(jù)之后再執(zhí)行上面這條命令,否則因?yàn)檫@張表數(shù)據(jù)量太大,轉(zhuǎn)換時(shí)間將會好長,清空表中數(shù)據(jù)的命令為: truncate table history_uint;)
好了,這樣可以進(jìn)行表分區(qū)了。
將上面這條命令寫入到計(jì)劃任務(wù)中如下:
crontab -l|tail -1 01 01 * * * /opt/software/mysql/bin/mysql -uzabbix -pzabbix zabbix -e "CALL partition_maintenance_all('zabbix');"
每天晚上的1點(diǎn)01執(zhí)行一次。還有之前寫的備份數(shù)據(jù)庫的腳本也需要執(zhí)行計(jì)劃任務(wù)每天的凌晨0點(diǎn)01執(zhí)行備份:
crontab -l|tail -2|head -1 01 00 * * * /usr/local/scripts/Zabbix_MySQLdump_per_table_v2.sh mysqldump
這樣就大功告成了,之后再體驗(yàn)一下zabbix的web頁面看是不是感覺比以前快了?
相關(guān)文章
Linux 僵尸進(jìn)程產(chǎn)生原因及解決方法
這篇文章主要介紹了Linux 僵尸進(jìn)程產(chǎn)生原因及解決方法,小編覺得挺不錯(cuò)的,現(xiàn)在分享給大家,也給大家做個(gè)參考。一起跟隨小編過來看看吧2018-02-02centos安裝jdk1.8時(shí)出現(xiàn)沒有/lib/ld-linux.so.2:這個(gè)文件的原因分析
這篇文章主要介紹了centos安裝jdk1.8時(shí)出現(xiàn)沒有/lib/ld-linux.so.2:這個(gè)文件的原因分析,通過使用一個(gè)簡單的命令可以幫助我們解決,需要的朋友跟隨腳本之家小編一起看看吧2018-08-08免費(fèi)常用Linux VPS管理面板/一鍵包介紹和安裝方法
這篇文章主要介紹了常用免費(fèi)Linux VPS管理面板/一鍵包介紹和安裝方法,需要的朋友可以參考下2017-02-02