Shantanu's Blog

Database Consultant

April 26, 2012

 

Partition Guide

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;


Comments: Post a Comment

<< Home

Archives

June 2001   July 2001   January 2003   May 2003   September 2003   October 2003   December 2003   January 2004   February 2004   March 2004   April 2004   May 2004   June 2004   July 2004   August 2004   September 2004   October 2004   November 2004   December 2004   January 2005   February 2005   March 2005   April 2005   May 2005   June 2005   July 2005   August 2005   September 2005   October 2005   November 2005   December 2005   January 2006   February 2006   March 2006   April 2006   May 2006   June 2006   July 2006   August 2006   September 2006   October 2006   November 2006   December 2006   January 2007   February 2007   March 2007   April 2007   June 2007   July 2007   August 2007   September 2007   October 2007   November 2007   December 2007   January 2008   February 2008   March 2008   April 2008   July 2008   August 2008   September 2008   October 2008   November 2008   December 2008   January 2009   February 2009   March 2009   April 2009   May 2009   June 2009   July 2009   August 2009   September 2009   October 2009   November 2009   December 2009   January 2010   February 2010   March 2010   April 2010   May 2010   June 2010   July 2010   August 2010   September 2010   October 2010   November 2010   December 2010   January 2011   February 2011   March 2011   April 2011   May 2011   June 2011   July 2011   August 2011   September 2011   October 2011   November 2011   December 2011   January 2012   February 2012   March 2012   April 2012   May 2012   June 2012   July 2012   August 2012   October 2012   November 2012   December 2012   January 2013   February 2013   March 2013   April 2013   May 2013   June 2013   July 2013   September 2013   October 2013   January 2014   March 2014   April 2014   May 2014   July 2014   August 2014   September 2014   October 2014   November 2014   December 2014   January 2015   February 2015   March 2015   April 2015   May 2015   June 2015   July 2015   August 2015   September 2015   January 2016   February 2016   March 2016   April 2016   May 2016   June 2016   July 2016   August 2016   September 2016   October 2016   November 2016   December 2016   January 2017   February 2017   April 2017   May 2017   June 2017   July 2017   August 2017   September 2017   October 2017   November 2017   December 2017   February 2018   March 2018   April 2018   May 2018   June 2018   July 2018   August 2018   September 2018   October 2018   November 2018   December 2018   January 2019   February 2019   March 2019   April 2019   May 2019   July 2019   August 2019   September 2019   October 2019   November 2019   December 2019   January 2020   February 2020   March 2020   April 2020   May 2020   July 2020   August 2020   September 2020   October 2020   December 2020   January 2021   April 2021   May 2021   July 2021   September 2021   March 2022   October 2022   November 2022   March 2023   April 2023   July 2023   September 2023   October 2023   November 2023  

This page is powered by Blogger. Isn't yours?