renametablehistoryto history_bak; renametablehistory_logto history_log_bak; renametablehistory_strto history_str_bak; renametablehistory_textto history_text_bak; renametablehistory_unitto history_unit_bak; renametabletrendsto trends_bak; renametabletrends_unitto trends_unit_bak;
CREATETABLE `history` ( `itemid` bigint(20) unsigned NOT NULL, `clock` int(11) NOT NULL DEFAULT '0', `value` double(16,4) NOT NULL DEFAULT '0.0000', `ns` int(11) NOT NULL DEFAULT '0', KEY `history_1` (`itemid`,`clock`) ) ENGINE=TokudbDEFAULT CHARSET=utf8; CREATETABLE `history_log` ( `id` bigint(20) unsigned NOT NULL, `itemid` bigint(20) unsigned NOT NULL, `clock` int(11) NOT NULL DEFAULT '0', `timestamp` int(11) NOT NULL DEFAULT '0', `source` varchar(64) NOT NULL DEFAULT '', `severity` int(11) NOT NULL DEFAULT '0', `value` textNOT NULL, `logeventid` int(11) NOT NULL DEFAULT '0', `ns` int(11) NOT NULL DEFAULT '0', PRIMARYKEY (`id`), UNIQUEKEY `history_log_2` (`itemid`,`id`), KEY `history_log_1` (`itemid`,`clock`) ) ENGINE=TokudbDEFAULT CHARSET=utf8; CREATETABLE `history_str` ( `itemid` bigint(20) unsigned NOT NULL, `clock` int(11) NOT NULL DEFAULT '0', `value` varchar(255) NOT NULL DEFAULT '', `ns` int(11) NOT NULL DEFAULT '0', KEY `history_str_1` (`itemid`,`clock`) ) ENGINE=TokudbDEFAULT CHARSET=utf8; CREATETABLE `history_text` ( `id` bigint(20) unsigned NOT NULL, `itemid` bigint(20) unsigned NOT NULL, `clock` int(11) NOT NULL DEFAULT '0', `value` textNOT NULL, `ns` int(11) NOT NULL DEFAULT '0', PRIMARYKEY (`id`), UNIQUEKEY `history_text_2` (`itemid`,`id`), KEY `history_text_1` (`itemid`,`clock`) ) ENGINE=TokudbDEFAULT CHARSET=utf8; CREATETABLE `history_uint` ( `itemid` bigint(20) unsigned NOT NULL, `clock` int(11) NOT NULL DEFAULT '0', `value` bigint(20) unsigned NOT NULL DEFAULT '0', `ns` int(11) NOT NULL DEFAULT '0', KEY `history_uint_1` (`itemid`,`clock`) ) ENGINE=TokudbDEFAULT CHARSET=utf8; CREATETABLE `trends` ( `itemid` bigint(20) unsigned NOT NULL, `clock` int(11) NOT NULL DEFAULT '0', `num` int(11) NOT NULL DEFAULT '0', `value_min` double(16,4) NOT NULL DEFAULT '0.0000', `value_avg` double(16,4) NOT NULL DEFAULT '0.0000', `value_max` double(16,4) NOT NULL DEFAULT '0.0000', PRIMARYKEY (`itemid`,`clock`) ) ENGINE=TokudbDEFAULT CHARSET=utf8; CREATETABLE `trends_uint` ( `itemid` bigint(20) unsigned NOT NULL, `clock` int(11) NOT NULL DEFAULT '0', `num` int(11) NOT NULL DEFAULT '0', `value_min` bigint(20) unsigned NOT NULL DEFAULT '0', `value_avg` bigint(20) unsigned NOT NULL DEFAULT '0', `value_max` bigint(20) unsigned NOT NULL DEFAULT '0', PRIMARYKEY (`itemid`,`clock`) ) ENGINE=TokudbDEFAULT CHARSET=utf8;
ALTERTABLEhistory_textDROPPRIMARYKEY, ADDINDEX (id), DROPINDEXhistory_text_2, ADDINDEXhistory_text_2 (itemid, id); ALTERTABLEhistory_logDROPPRIMARYKEY, ADDINDEX (id), DROPINDEXhistory_log_2, ADDINDEXhistory_log_2 (itemid, id);
**************************************partition_create**************************************
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 RETROWSINT;
SELECTCOUNT(1) INTORETROWS
FROMinformation_schema.partitions
WHEREtable_schema = SCHEMANAMEAND table_name = TABLENAMEAND 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.
*/
SELECTCONCAT( "partition_create(", SCHEMANAME, ",", TABLENAME, ",", PARTITIONNAME, ",", CLOCK, ")" ) AS msg;
SET @sql = CONCAT( 'ALTER TABLE ', SCHEMANAME, '.', TABLENAME, ' ADD PARTITION (PARTITION ', PARTITIONNAME, ' VALUES LESS THAN (', CLOCK, '));' );
PREPARESTMTFROM @sql;
EXECUTESTMT;
DEALLOCATEPREPARESTMT;
END IF;
END
**************************************partition_drop**************************************
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 doneINT DEFAULT FALSE;
DECLARE drop_part_nameVARCHAR(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 myCursorCURSORFOR
SELECTpartition_name
FROMinformation_schema.partitions
WHEREtable_schema = SCHEMANAMEAND table_name = TABLENAMEAND CAST(SUBSTRING(partition_nameFROM 2) AS UNSIGNED) < DELETE_BELOW_PARTITION_DATE;
DECLARE CONTINUE HANDLERFOR NOT FOUNDSETdone = 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.
*/
OPENmyCursor;
read_loop: LOOP
FETCHmyCursorINTOdrop_part_name;
IF doneTHEN
LEAVEread_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, ";");
PREPARESTMTFROM @full_sql;
EXECUTESTMT;
DEALLOCATEPREPARESTMT;
SELECTCONCAT(SCHEMANAME, ".", TABLENAME) AS `table`, @drop_partitionsAS `partitions_deleted`;
ELSE
/*
No partitions are being deleted, so print out "N/A" (Not applicable) to indicate
that no changes were made.
*/
SELECTCONCAT(SCHEMANAME, ".", TABLENAME) AS `table`, "N/A" AS `partitions_deleted`;
END IF;
END
**************************************partition_verify**************************************
BEGIN
DECLARE PARTITION_NAMEVARCHAR(16);
DECLARE RETROWSINT(11);
DECLARE FUTURE_TIMESTAMPTIMESTAMP;
/*
* Check if any partitions exist for the given SCHEMANAME.TABLENAME.
*/
SELECTCOUNT(1) INTORETROWS
FROMinformation_schema.partitions
WHEREtable_schema = SCHEMANAMEAND table_name = TABLENAMEAND partition_nameIS 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").
*/
SETFUTURE_TIMESTAMP = TIMESTAMPADD(HOUR, HOURLYINTERVAL, CONCAT(CURDATE(), " ", '00:00:00'));
SETPARTITION_NAME = DATE_FORMAT(CURDATE(), 'p%Y%m%d%H00');
-- Createthepartitioningquery
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), "));");
-- Runthepartitioningquery
PREPARESTMTFROM @__PARTITION_SQL;
EXECUTESTMT;
DEALLOCATEPREPARESTMT;
END IF;
END
**************************************partition_maintenance**************************************
BEGIN
DECLARE OLDER_THAN_PARTITION_DATEVARCHAR(16);
DECLARE PARTITION_NAMEVARCHAR(16);
DECLARE OLD_PARTITION_NAMEVARCHAR(16);
DECLARE LESS_THAN_TIMESTAMPINT;
DECLARE CUR_TIMEINT;
CALLpartition_verify(SCHEMA_NAME, TABLE_NAME, HOURLY_INTERVAL);
SETCUR_TIME = UNIX_TIMESTAMP(DATE_FORMAT(NOW(), '%Y-%m-%d 00:00:00'));
SET @__interval = 1;
create_loop: LOOP
IF @__interval > CREATE_NEXT_INTERVALSTHEN
LEAVEcreate_loop;
END IF;
SETLESS_THAN_TIMESTAMP = CUR_TIME + (HOURLY_INTERVAL * @__interval * 3600);
SETPARTITION_NAME = FROM_UNIXTIME(CUR_TIME + HOURLY_INTERVAL * (@__interval - 1) * 3600, 'p%Y%m%d%H00');
IF(PARTITION_NAME != OLD_PARTITION_NAME) THEN
CALLpartition_create(SCHEMA_NAME, TABLE_NAME, PARTITION_NAME, LESS_THAN_TIMESTAMP);
END IF;
SET @__interval=@__interval+1;
SETOLD_PARTITION_NAME = PARTITION_NAME;
END LOOP;
SETOLDER_THAN_PARTITION_DATE=DATE_FORMAT(DATE_SUB(NOW(), INTERVALKEEP_DATA_DAYSDAY), '%Y%m%d0000');
CALLpartition_drop(SCHEMA_NAME, TABLE_NAME, OLDER_THAN_PARTITION_DATE);
END
**************************************partition_maintenance_all**************************************
BEGIN
CALLpartition_maintenance(SCHEMA_NAME, 'history', 90, 24, 30);
#针对zabbix数据库(调用时传入zabbix数据库的库名)的history表创建分区,数据保留90天,分区时间间隔为24小时,每次创建30个分区
CALLpartition_maintenance(SCHEMA_NAME, 'history_log', 90, 24, 30);
CALLpartition_maintenance(SCHEMA_NAME, 'history_str', 90, 24, 30);
CALLpartition_maintenance(SCHEMA_NAME, 'history_text', 90, 24, 30);
CALLpartition_maintenance(SCHEMA_NAME, 'history_uint', 90, 24, 30);
CALLpartition_maintenance(SCHEMA_NAME, 'trends', 730, 24, 15);
CALLpartition_maintenance(SCHEMA_NAME, 'trends_uint', 730, 24, 30);
END
开启数据库EventScheduler功能
setGLOBAL event_scheduler=ON;
创建事件zbx_partition_maintenance:
DELIMITER $$
CREATEEVENTzbx_partition_maintenanceONSCHEDULEEVERY 1 MONTHSTARTSDATE_ADD(
DATE_ADD(
DATE_SUB(
CURDATE(),
INTERVALDAY (CURDATE()) - 1 DAY
),
INTERVAL 1 MONTH
),
INTERVAL 5 HOUR
) ONCOMPLETIONPRESERVEDO
BEGIN
CALLpartition_maintenance_all ('zabbix') ; END$$
DELIMITER ;