From e25e2a871aee8388ddb49ecda9988dad1bab10b6 Mon Sep 17 00:00:00 2001 From: Halbe Bruno Date: Mon, 10 Feb 2025 17:34:58 -0300 Subject: [PATCH] Adicionar sql/zbx_db_partitiong.sql --- sql/zbx_db_partitiong.sql | 175 ++++++++++++++++++++++++++++++++++++++ 1 file changed, 175 insertions(+) create mode 100644 sql/zbx_db_partitiong.sql diff --git a/sql/zbx_db_partitiong.sql b/sql/zbx_db_partitiong.sql new file mode 100644 index 0000000..f4e905f --- /dev/null +++ b/sql/zbx_db_partitiong.sql @@ -0,0 +1,175 @@ +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 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 "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 ; +DELIMITER $$ +CREATE PROCEDURE `partition_maintenance_all`(SCHEMA_NAME VARCHAR(32)) +BEGIN + CALL partition_maintenance(SCHEMA_NAME, 'history', 7, 24, 3); + CALL partition_maintenance(SCHEMA_NAME, 'history_log', 7, 24, 3); + CALL partition_maintenance(SCHEMA_NAME, 'history_str', 7, 24, 3); + CALL partition_maintenance(SCHEMA_NAME, 'history_text', 7, 24, 3); + CALL partition_maintenance(SCHEMA_NAME, 'history_uint', 7, 24, 3); + CALL partition_maintenance(SCHEMA_NAME, 'trends', 365, 24, 3); + CALL partition_maintenance(SCHEMA_NAME, 'trends_uint', 365, 24, 3); +END$$ +DELIMITER ; \ No newline at end of file