Here are useful commands one can use while working with partitions.
CREATE TABLE `data_summary` (
`data_summary_ad_hourly_id` bigint(20) NOT NULL AUTO_INCREMENT,
`date_time` datetime NOT NULL,
`ad_id` int(10) unsigned NOT NULL,
...
some more columns
...
) ENGINE=MyISAM DEFAULT CHARSET=latin1 ;
This is the table without any partitions. We need to use alter table statement to divide it.
ALTER TABLE `data_summary`
PARTITION BY RANGE (TO_SECONDS(`date_time` )) (
PARTITION 20120315parti VALUES less than (to_seconds('2012-03-15 00:00:00')),
PARTITION 20120316parti VALUES less than (to_seconds('2012-03-16 00:00:00')),
PARTITION 20120317parti VALUES less than (to_seconds('2012-03-17 00:00:00')),
PARTITION 20120318parti VALUES less than (to_seconds('2012-03-18 00:00:00')),
PARTITION 20120319parti VALUES less than (to_seconds('2012-03-19 00:00:00')),
PARTITION 20120320parti VALUES less than (to_seconds('2012-03-20 00:00:00')),
PARTITION 20120321parti VALUES less than (to_seconds('2012-03-21 00:00:00')),
PARTITION 20120322parti VALUES less than (to_seconds('2012-03-22 00:00:00')),
PARTITION 20120323parti VALUES less than (to_seconds('2012-03-23 00:00:00')),
PARTITION 20120324parti VALUES less than (to_seconds('2012-03-24 00:00:00')),
PARTITION 20120325parti VALUES less than (to_seconds('2012-03-25 00:00:00')),
PARTITION 20120326parti VALUES less than (to_seconds('2012-03-26 00:00:00')),
PARTITION 20120327parti VALUES less than (to_seconds('2012-03-27 00:00:00')),
PARTITION 20120328parti VALUES less than (to_seconds('2012-03-28 00:00:00')),
PARTITION 20120329parti VALUES less than (to_seconds('2012-03-29 00:00:00')),
PARTITION 20120330parti VALUES less than (to_seconds('2012-03-30 00:00:00')),
PARTITION 20120331parti VALUES less than (to_seconds('2012-03-31 00:00:00')),
PARTITION 20120401parti VALUES less than (to_seconds('2012-04-01 00:00:00')),
PARTITION 20120402parti VALUES less than (to_seconds('2012-04-02 00:00:00')),
PARTITION 20120403parti VALUES less than (to_seconds('2012-04-03 00:00:00')),
PARTITION 20120404parti VALUES less than (to_seconds('2012-04-04 00:00:00')),
PARTITION 20120405parti VALUES less than (to_seconds('2012-04-05 00:00:00')),
PARTITION 20120406parti VALUES less than (to_seconds('2012-04-06 00:00:00')),
PARTITION 20120407parti VALUES less than (to_seconds('2012-04-07 00:00:00')),
PARTITION 20120408parti VALUES less than (to_seconds('2012-04-08 00:00:00')),
PARTITION 20120409parti VALUES less than (to_seconds('2012-04-09 00:00:00')),
PARTITION 20120410parti VALUES less than (to_seconds('2012-04-10 00:00:00')),
PARTITION 20120411parti VALUES less than (to_seconds('2012-04-11 00:00:00')),
PARTITION 20120412parti VALUES less than (to_seconds('2012-04-12 00:00:00')),
PARTITION 20120413parti VALUES less than (to_seconds('2012-04-13 00:00:00')),
PARTITION 20120414parti VALUES less than (to_seconds('2012-04-14 00:00:00')),
PARTITION 20120415parti VALUES less than (to_seconds('2012-04-15 00:00:00')),
PARTITION maxParti VALUES LESS THAN (MAXVALUE)
);
We can not add partitions to the earlier date range. For e.g. when I try to add a partition at lower end, March 13 and March 14 it does not work.
ALTER TABLE `data_summary`
REORGANIZE PARTITION 20120315parti INTO (
PARTITION 20120313parti VALUES less than (to_seconds('2012-03-13 00:00:00')),
PARTITION 20120314parti VALUES less than (to_seconds('2012-03-14 00:00:00'))
);
ERROR 1520 (HY000): Reorganize of range partitions cannot change total ranges except for last partition where it can extend the range
If you really need to create partitions for older days, it is still possible to drop and recreate all partitions as explained below.
_____
But we can add partitions at the higher end.
ALTER TABLE `data_summary`
REORGANIZE PARTITION maxParti INTO (
PARTITION 20120416parti VALUES less than (to_seconds('2012-04-16 00:00:00')),
PARTITION maxParti VALUES LESS THAN (MAXVALUE)
);
So we are taking data from the "maxParti" partition and splitting it up in April 16 partition and rest again in "maxParti" partition.
_____
We can merge the data of March 15, 16 and 17 into a single partition called "20120315TO17parti"
ALTER TABLE `data_summary`
REORGANIZE PARTITION 20120315parti, 20120316parti, 20120317parti INTO (
PARTITION 20120315TO17parti VALUES less than (to_seconds('2012-03-17 00:00:00'))
);
_____
We can totally change the way the data is divided by merging and splitting records all over again.
ALTER TABLE `data_summary`
REORGANIZE PARTITION
20120315TO17parti, 20120318parti, 20120319parti, 20120320parti, 20120321parti, 20120322parti, 20120323parti, 20120324parti, 20120325parti, 20120326parti, 20120327parti, 20120328parti, 20120329parti, 20120330parti, 20120331parti, 20120401parti, 20120402parti, 20120403parti, 20120404parti, 20120405parti, 20120406parti, 20120407parti, 20120408parti, 20120409parti, 20120410parti, 20120411parti, 20120412parti, 20120413parti, 20120414parti, 20120415parti, 20120416parti, maxParti
INTO (
PARTITION 20120313parti VALUES less than (to_seconds('2012-03-13 00:00:00')),
PARTITION 20120314parti VALUES less than (to_seconds('2012-03-14 00:00:00')),
PARTITION 20120315parti VALUES less than (to_seconds('2012-03-15 00:00:00')),
PARTITION 20120316parti VALUES less than (to_seconds('2012-03-16 00:00:00')),
PARTITION maxParti VALUES LESS THAN (MAXVALUE)
);
So the newly organized table will look like this...
mysql> SHOW CREATE TABLE `data_summary` \G
*************************** 1. row ***************************
Table: data_summary
Create Table: CREATE TABLE `data_summary` (
`data_summary_ad_hourly_id` bigint(20) NOT NULL AUTO_INCREMENT,
`date_time` datetime NOT NULL,
`ad_id` int(10) unsigned NOT NULL,
...
some more columns
...
) ENGINE=MyISAM DEFAULT CHARSET=latin1
/*!50500 PARTITION BY RANGE (TO_SECONDS(`date_time` ))
(PARTITION 20120313parti VALUES LESS THAN (63498816000) ENGINE = MyISAM,
PARTITION 20120314parti VALUES LESS THAN (63498902400) ENGINE = MyISAM,
PARTITION 20120315parti VALUES LESS THAN (63498988800) ENGINE = MyISAM,
PARTITION 20120316parti VALUES LESS THAN (63499075200) ENGINE = MyISAM,
PARTITION maxParti VALUES LESS THAN MAXVALUE ENGINE = MyISAM) */
1 row in set (0.00 sec)
_____
We can complete drop the partition along with the data by altering the table.
ALTER TABLE data_summary DROP PARTITION 20120313parti;
We can also truncate the data within a single or multiple partitions.
ALTER TABLE data_summary TRUNCATE PARTITION 20120314parti, 20120315parti;