这篇文章将详细介绍一组存储过程,用于管理 MySQL 数据库中的分区。
这些存储过程包括
partition_create、
partition_drop、
partition_maintenance、
partition_maintenance_all
partition_verify。
这些过程的功能、逻辑关系和使用方法如下所述。
1. partition_create
此存储过程用于创建新的分区。如果指定的分区不存在且其描述符合条件(即分区描述的时间戳大于等于给定的时间戳),它将创建该分区。
CREATE DEFINER=`root`@`localhost` PROCEDURE `partition_create`(
SCHEMANAME varchar(64),
TABLENAME varchar(64),
PARTITIONNAME varchar(64),
CLOCK int
)
BEGIN
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
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
2. partition_drop
此存储过程用于删除指定日期之前的分区。它通过游标遍历满足条件的分区名称,并将这些分区删除。
CREATE DEFINER=`root`@`localhost` PROCEDURE `partition_drop`(
SCHEMANAME VARCHAR(64),
TABLENAME VARCHAR(64),
DELETE_BELOW_PARTITION_DATE BIGINT
)
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE drop_part_name VARCHAR(16);
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;
SET @alter_header = CONCAT("ALTER TABLE ", SCHEMANAME, ".", TABLENAME, " DROP PARTITION ");
SET @drop_partitions = "";
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
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
SELECT CONCAT(SCHEMANAME, ".", TABLENAME) AS `table`, "N/A" AS `partitions_deleted`;
END IF;
END
3. partition_maintenance
此存储过程用于定期创建和删除分区。它会根据给定的参数,创建未来的分区并删除过期的分区。
CREATE DEFINER=`root`@`localhost` 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
4. partition_maintenance_all
此存储过程调用 partition_maintenance,对多个特定的表执行分区维护操作。
CREATE DEFINER=`root`@`localhost` PROCEDURE `partition_maintenance_all`(
SCHEMA_NAME VARCHAR(32)
)
BEGIN
CALL partition_maintenance(SCHEMA_NAME, 'history', 90, 24, 14);
CALL partition_maintenance(SCHEMA_NAME, 'history_log', 90, 24, 14);
CALL partition_maintenance(SCHEMA_NAME, 'history_str', 90, 24, 14);
CALL partition_maintenance(SCHEMA_NAME, 'history_text', 90, 24, 14);
CALL partition_maintenance(SCHEMA_NAME, 'history_uint', 90, 24, 14);
CALL partition_maintenance(SCHEMA_NAME, 'trends', 730, 24, 14);
CALL partition_maintenance(SCHEMA_NAME, 'trends_uint', 730, 24, 14);
END
5. partition_verify
此存储过程用于验证表是否已经分区。如果表尚未分区,它将对表进行分区。
CREATE DEFINER=`root`@`localhost` 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;
SELECT COUNT(1) INTO RETROWS
FROM information_schema.partitions
WHERE table_schema = SCHEMANAME AND table_name = TABLENAME AND partition_name IS NULL;
IF RETROWS = 1 THEN
SET FUTURE_TIMESTAMP = TIMESTAMPADD(HOUR, HOURLYINTERVAL, CONCAT(CURDATE(), " ", '00:00:00'));
SET PARTITION_NAME = DATE_FORMAT(CURDATE(), 'p%Y%m%d%H00');
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), "));");
PREPARE STMT FROM @__PARTITION_SQL;
EXECUTE STMT;
DEALLOCATE PREPARE STMT;
END IF;
END
使用示例
假设您有一个数据库 mydb,其中包含多个需要分区维护的表。以下是如何使用这些存储过程的示例。
创建分区
创建分区时,您可以直接调用 partition_create 存储过程。例如:
CALL partition_create('mydb', 'mytable', 'p2023061500', UNIX_TIMESTAMP('2024-06-15 00:00:00'));
删除分区
删除过期的分区时,您可以调用 partition_drop 存储过程。例如:
CALL partition_drop('mydb', 'mytable', 20230601);
维护分区
定期创建和删除分区时,您可以调用 partition_maintenance 存储过程。例如:
CALL partition_maintenance('mydb', 'mytable', 90, 24, 14);
全局维护分区
对多个表执行分区维护操作时,您可以调用 partition_maintenance_all 存储过程。例如:
CALL partition_maintenance_all('mydb');
验证分区
在对表进行分区前,您可以先调用 partition_verify 存储过程。例如:
CALL partition_verify('mydb', 'mytable', 24);
如果是对zabbix 的历史表进行分区,可以直接调用分区,在系统中添加计划任务即可。
crontab -l
0 1 * * * mysql -uzabbix -pzabbix zabbix -e"CALL partition_maintenance_all('zabbix')"
⚠️注: partition_maintenance_all 这个存储过程中接收的参数就是数据库名称。这样就仅对 zabbix 数据库里面的历史表自动每天分区,并删除 90 天以前的历史分区。进行自动管理分区的目地。
如果您在开发 Python/Shell 脚本或 Zabbix 模板过程中遇到问题,或者有开发模板或脚本的需求,欢迎随时添加 QQ:1030202304,与我一起沟通交流。
错误信息