Zabbix需要做分区的大表
history
history_log
history_str
history_text
history_uint
trends
trends_uint
分表前提 按时间范围分表(字段clock,字段无索引) MySQL分区表要求范围字段是唯一索引或主键索引,或者是其中一部分,需要修改前核实clock是否在索引中 创建4个存储过程 存储过程1
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 ;
存储过程2
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 ;
存储过程3
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 ;
存储过程4
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 ;
存储过程中有四个功能: partition_create - 这将在给定模式中的给定表上创建一个分区。
partition_drop - 这将删除给定模式中给定表上给定时间戳的分区。
partition_maintenance - 此功能是用户调用的。它负责解析给定的参数,然后根据需要创建/删除分区。
partition_verify - 检查给定模式中给定表上是否启用了分区。如果没有启用,它将创建一个单独的分区。
partition_create
程序定义:partition_create(SCHEMANAME varchar(64),TABLENAME varchar(64),PARTITIONNAME varchar(64),CLOCK int)
示例:CALL partition_create(“zabbix”,“history”,“p20131216”,1387267200);
SCHEMANAME =要在其中进行更改的DB模式
TABLENAME =要在其上创建PARTITIONNAME的表
PARTITIONNAME =要创建的分区的名称
将创建CLOCK = PARTITIONNAME以保存“clock”列值小于此值的值
partition_drop
过程定义:partition_drop(SCHEMANAME VARCHAR(64),TABLENAME VARCHAR(64),DELETE_BELOW_PARTITION_DATE VARCHAR(64))
示例:CALL partition_drop(“zabbix”,“history”,“20131216”);
SCHEMANAME =要在其中进行更改的DB模式
TABLENAME =要删除PARTITIONNAME的表
DELETE_BELOW_PARTITION_DATE =允许的最旧分区日期。所有旧版本的分区将被删除。格式为yyyymmdd。
partition_maintenance
过程定义:partition_maintenance(SCHEMA_NAME VARCHAR(32),TABLE_NAME VARCHAR(32),KEEP_DATA_DAYS INT,HOURLY_INTERVAL INT,CREATE_NEXT_INTERVALS INT)
示例:CALL partition_maintenance('zabbix','history',28,24,14 );
SCHEMA_NAME =要在其中进行更改的DB模式
TABLE_NAME =要进行更改的表
KEEP_DATA_DAYS =要保留的分区的最大天数。所有超过此天数的分区将被删除。
HOURLY_INTERVAL =分区之间的小时间隔。例如,每日分区的值为24,小时分区的值为1。
CREATE_NEXT_INTERVALS =提前创建的值的分区数。
partition_verify
过程定义:partition_verify(SCHEMANAME VARCHAR(64),TABLENAME VARCHAR(64),HOURLYINTERVAL INT(11))
示例:CALL partition_verify(“zabbix”,“history”);
SCHEMANAME =要在其中进行更改的DB模式
TABLENAME =要检查分区的表
HOURLY_INTERVAL =分区之间的小时间隔。例如,每日分区的值为24,小时分区的值为1。
分区表需求:
每月一个分区(24小时*31约等于720小时)
历史保存1年数据(12个月)
趋势保存2年数据(24个月)
未来周期12个(未来12个月)
单独语句:
CALL partition_maintenance('zabbix', 'history', 24, 720, 12);
CALL partition_maintenance(zabbix, 'trends', 48, 720, 12);
查看分区
select PARTITION_NAME as "分区",TABLE_ROWS as "行数" from information_schema.partitions where table_schema="mysql_test" and table_name="test_11";
解释:创建24个分区,其中未来月份12个,每个周期存储720小时数据
添加以下存储过程,用来增加新的分区和删除旧的分区
DELIMITER $$
CREATE PROCEDURE `partition_maintenance_all`(SCHEMA_NAME VARCHAR(32))
BEGIN
CALL partition_maintenance(SCHEMA_NAME, 'history', 24, 720, 12);
CALL partition_maintenance(SCHEMA_NAME, 'history_log', 24, 720, 12);
CALL partition_maintenance(SCHEMA_NAME, 'history_str', 24, 720, 12);
CALL partition_maintenance(SCHEMA_NAME, 'history_text', 24, 720, 12);
CALL partition_maintenance(SCHEMA_NAME, 'history_uint', 24, 720, 12);
CALL partition_maintenance(SCHEMA_NAME, 'trends', 48, 720, 12);
CALL partition_maintenance(SCHEMA_NAME, 'trends_uint', 48, 720, 12);
END$$
DELIMITER ;
执行后,观察分区表状态是否建立 定时调用此存储过程 用来增加新的分区和删除旧的分区,注意定时调用的间隔不能小于每次创建的未来的分区周期,如上情况,最少12个月调用一次
vim /root/shell/create_partition.sh 加入以下:
/opt/tokudb/mysql/bin/mysql -uzabbix -pzabbix zabbix -e "call partition_maintenance_all('zabbix');"
crontab -e 加入以下:
0 3 * */11 * sh /root/shell/create_partition.sh
关闭housekeeper 管理-》一般-》管家
换句话说,实际就是执行了以下语句
ALTER TABLE `history_str` PARTITION BY RANGE ( clock)(
PARTITION p20171 VALUES LESS THAN (UNIX_TIMESTAMP("2017-01-01 00:00:00")),
PARTITION p20172 VALUES LESS THAN (UNIX_TIMESTAMP("2017-02-01 00:00:00")),
PARTITION p20173 VALUES LESS THAN (UNIX_TIMESTAMP("2017-03-01 00:00:00")),
PARTITION p20174 VALUES LESS THAN (UNIX_TIMESTAMP("2017-04-01 00:00:00")),
PARTITION p20175 VALUES LESS THAN (UNIX_TIMESTAMP("2017-05-01 00:00:00")),
PARTITION p20176 VALUES LESS THAN (UNIX_TIMESTAMP("2017-06-01 00:00:00")),
PARTITION p20177 VALUES LESS THAN (UNIX_TIMESTAMP("2017-07-01 00:00:00")),
PARTITION p20178 VALUES LESS THAN (UNIX_TIMESTAMP("2017-08-01 00:00:00")),
PARTITION p20179 VALUES LESS THAN (UNIX_TIMESTAMP("2017-09-01 00:00:00")),
PARTITION p201710 VALUES LESS THAN (UNIX_TIMESTAMP("2017-10-01 00:00:00")),
PARTITION p201711 VALUES LESS THAN (UNIX_TIMESTAMP("2017-11-01 00:00:00")),
PARTITION p201712 VALUES LESS THAN (UNIX_TIMESTAMP("2017-12-01 00:00:00")),
PARTITION p20181 VALUES LESS THAN (UNIX_TIMESTAMP("2018-01-01 00:00:00")),
PARTITION p20182 VALUES LESS THAN (UNIX_TIMESTAMP("2018-02-01 00:00:00")),
PARTITION p20183 VALUES LESS THAN (UNIX_TIMESTAMP("2018-03-01 00:00:00")),
PARTITION p20184 VALUES LESS THAN (UNIX_TIMESTAMP("2018-04-01 00:00:00")),
PARTITION p20185 VALUES LESS THAN (UNIX_TIMESTAMP("2018-05-01 00:00:00")),
PARTITION p20186 VALUES LESS THAN (UNIX_TIMESTAMP("2018-06-01 00:00:00")),
PARTITION p20187 VALUES LESS THAN (UNIX_TIMESTAMP("2018-07-01 00:00:00")),
PARTITION p20188 VALUES LESS THAN (UNIX_TIMESTAMP("2018-08-01 00:00:00")),
PARTITION p20189 VALUES LESS THAN (UNIX_TIMESTAMP("2018-09-01 00:00:00")),
PARTITION p201810 VALUES LESS THAN (UNIX_TIMESTAMP("2018-10-01 00:00:00")),
PARTITION p201811 VALUES LESS THAN (UNIX_TIMESTAMP("2018-11-01 00:00:00")),
PARTITION p201812 VALUES LESS THAN (UNIX_TIMESTAMP("2018-12-01 00:00:00")),
PARTITION p20191 VALUES LESS THAN (UNIX_TIMESTAMP("2019-01-01 00:00:00")),
PARTITION p20192 VALUES LESS THAN (UNIX_TIMESTAMP("2019-02-01 00:00:00")),
PARTITION p20193 VALUES LESS THAN (UNIX_TIMESTAMP("2019-03-01 00:00:00")),
PARTITION p20194 VALUES LESS THAN (UNIX_TIMESTAMP("2019-04-01 00:00:00")),
PARTITION p20195 VALUES LESS THAN (UNIX_TIMESTAMP("2019-05-01 00:00:00")),
PARTITION p20196 VALUES LESS THAN (UNIX_TIMESTAMP("2019-06-01 00:00:00")),
PARTITION p20197 VALUES LESS THAN (UNIX_TIMESTAMP("2019-07-01 00:00:00")),
PARTITION p20198 VALUES LESS THAN (UNIX_TIMESTAMP("2019-08-01 00:00:00")),
PARTITION p20199 VALUES LESS THAN (UNIX_TIMESTAMP("2019-09-01 00:00:00")),
PARTITION p201910 VALUES LESS THAN (UNIX_TIMESTAMP("2019-10-01 00:00:00")),
PARTITION p201911 VALUES LESS THAN (UNIX_TIMESTAMP("2019-11-01 00:00:00")),
PARTITION p201912 VALUES LESS THAN (UNIX_TIMESTAMP("2019-12-01 00:00:00")),
PARTITION p20201 VALUES LESS THAN (UNIX_TIMESTAMP("2020-01-01 00:00:00")),
PARTITION p20202 VALUES LESS THAN (UNIX_TIMESTAMP("2020-02-01 00:00:00")),
PARTITION p20203 VALUES LESS THAN (UNIX_TIMESTAMP("2020-03-01 00:00:00")),
PARTITION p20204 VALUES LESS THAN (UNIX_TIMESTAMP("2020-04-01 00:00:00")),
PARTITION p20205 VALUES LESS THAN (UNIX_TIMESTAMP("2020-05-01 00:00:00")),
PARTITION p20206 VALUES LESS THAN (UNIX_TIMESTAMP("2020-06-01 00:00:00")),
PARTITION p20207 VALUES LESS THAN (UNIX_TIMESTAMP("2020-07-01 00:00:00")),
PARTITION p20208 VALUES LESS THAN (UNIX_TIMESTAMP("2020-08-01 00:00:00")),
PARTITION p20209 VALUES LESS THAN (UNIX_TIMESTAMP("2020-09-01 00:00:00")),
PARTITION p202010 VALUES LESS THAN (UNIX_TIMESTAMP("2020-10-01 00:00:00")),
PARTITION p202011 VALUES LESS THAN (UNIX_TIMESTAMP("2020-11-01 00:00:00")),
PARTITION p202012 VALUES LESS THAN (UNIX_TIMESTAMP("2020-12-01 00:00:00")),
PARTITION p20211 VALUES LESS THAN (UNIX_TIMESTAMP("2021-01-01 00:00:00")),
PARTITION p20212 VALUES LESS THAN (UNIX_TIMESTAMP("2021-02-01 00:00:00")),
PARTITION p20213 VALUES LESS THAN (UNIX_TIMESTAMP("2021-03-01 00:00:00")),
PARTITION p20214 VALUES LESS THAN (UNIX_TIMESTAMP("2021-04-01 00:00:00")),
PARTITION p20215 VALUES LESS THAN (UNIX_TIMESTAMP("2021-05-01 00:00:00")),
PARTITION p20216 VALUES LESS THAN (UNIX_TIMESTAMP("2021-06-01 00:00:00")),
PARTITION p20217 VALUES LESS THAN (UNIX_TIMESTAMP("2021-07-01 00:00:00")),
PARTITION p20218 VALUES LESS THAN (UNIX_TIMESTAMP("2021-08-01 00:00:00")),
PARTITION p20219 VALUES LESS THAN (UNIX_TIMESTAMP("2021-09-01 00:00:00")),
PARTITION p202110 VALUES LESS THAN (UNIX_TIMESTAMP("2021-10-01 00:00:00")),
PARTITION p202111 VALUES LESS THAN (UNIX_TIMESTAMP("2021-11-01 00:00:00")),
PARTITION p202112 VALUES LESS THAN (UNIX_TIMESTAMP("2021-12-01 00:00:00")),
PARTITION p9999 VALUES LESS VALUES LESS THAN MAXVALUE);
评论列表,共 0 条评论
暂无评论