Partitioning Overview
Learn the fundamentals of table partitioning in MariaDB, including its benefits for performance, maintenance, and managing large datasets.
In MariaDB, a table can be split in smaller subsets. Both data and indexes are partitioned.
Uses for Partitioning
There can be several reasons to use this feature:
If you often need to delete a large set of rows, such as all rows for a given year, using partitions can help, as dropping a partition with many rows is very fast, while deleting a lot of rows can be very slow.
Very large tables and indexes can be slow even with optimized queries. But if the target table is partitioned, queries that read a small number of partitions can be much faster. However, this means that the queries have to be written carefully in order to only access a given set of partitions.
Partitioning allows one to distribute files over multiple storage devices. For example, we can have historical data on slower, larger disks (historical data are not supposed to be frequently read); and current data can be on faster disks, or SSD devices.
In case we separate historical data from recent data, we will probably need to take regular backups of one partition, not the whole table.
Partitioning Types
When partitioning a table, the use should decide:
a partitioning type;
a partitioning expression.
A partitioning type is the method used by MariaDB to decide how rows are distributed over existing partitions. Choosing the proper partitioning type is important to distribute rows over partitions in an efficient way.
With some partitioning types, a partitioning expression is also required. A partitioning function is an SQL expression returning an integer or temporal value, used to determine which partition will contain a given row. The partitioning expression is used for all reads and writes on involving the partitioned table, thus it should be fast.
MariaDB supports the following partitioning types:
Enabling Partitioning
By default, MariaDB permits partitioning. You can determine this by using the SHOW PLUGINS statement, for example:
If partition is listed as DISABLED:
MariaDB has either been built without partitioning support, or has been started with the --skip-partition option, or one of its variants:
and you will not be able to create partitions.
Using Partitions
It is possible to create a new partitioned table using CREATE TABLE.
ALTER TABLE allows one to:
Partition an existing table;
Remove partitions from a partitioned table (with all data in the partition);
Add/remove partitions, or reorganize them, as long as the partitioning function allows these operations (see below);
Exchange a partition with a table;
Perform administrative operations on some or all partitions (analyze, optimize, check, repair).
Adding Partitions
[ALTER TABLE](../../reference/sql-statements-and-structure/sql-statements/data-definition/alter/alter-table.md) ... ADD PARTITION can be used to add partitions to an existing table:
With RANGE partitions, it is only possible to add a partition to the high end of the range, not the low end. For example, the following results in an error:
You can work around this by using REORGANIZE PARTITION to split the partition instead. See Splitting Partitions.
Coalescing Partitions
ALTER TABLE is used to reduce the number of HASH or KEY partitions by the specified number. For example, given the following table with 5 partitions:
The following statement reduces the number of partitions by 2, leaving the table with 3 partitions:
Converting Partitions to/from Tables
ALTER TABLE can be used to convert partitions in an existing table to a standalone table:
CONVERT TABLE does the reverse, converting a table into a partition:
CONVERT TABLE ... WITH / WITHOUT VALIDATION
When converting tables to a partition, validation is performed on each row to ensure it meets the partition requirements. This can be very slow in the case of larger tables. It is possible to disable this validation by specifying the WITHOUT VALIDATION option.
WITH VALIDATION will result in the validation being performed, and is the default behaviour.
An alternative to convert partitions to tables is to use ALTER TABLE EXCHANGE PARTITION. This requires having to manually do the following steps:
Create an empty table with the same structure as the partition.
Exchange the table with the partition.
Drop the empty partition.
For example:
Similarly, to do the reverse and convert a table into a partition [ALTER TABLE](../../reference/sql-statements-and-structure/sql-statements/data-definition/alter/alter-table.md) ... EXCHANGE PARTITION can also be used, with the following manual steps required:
create the partition
exchange the partition with the table
drop the old table:
For example:
Dropping Partitions
ALTER TABLE DROP PARTITION can be used to drop specific partitions (and discard all data within the specified partitions) for RANGE and LIST partitions. It cannot be used on HASH or KEY partitions. To rather remove all partitioning, while leaving the data unaffected, see Removing Partitioning.
Exchanging Partitions
ALTER TABLE t1 EXCHANGE PARTITION p1 WITH TABLE t2 allows to exchange a partition or subpartition with another table.
The following requirements must be met:
Table t1 must be partitioned, and table t2 cannot be partitioned.
Table t2 cannot be a temporary table.
Table t1 and t2 must otherwise be identical.
Any existing row in t2 must match the conditions for storage in the exchanged partition p1 unless, from MariaDB 11.4, the
WITHOUT VALIDATIONoption is specified.
By default, MariaDB performs the validation to see that each row meets the partition requirements, and the statement fails if a row does not fit.
This attempted exchange fails, as the value is already in t2, and 2015-05-05 is outside of the partition conditions:
WITH / WITHOUT VALIDATION
This validation is performed for each row, and can be very slow in the case of larger tables. It is possible to disable this validation by specifying the WITHOUT VALIDATION option:
WITH VALIDATION results in the validation being performed, and is the default behavior.
Removing Partitioning
ALTER TABLE REMOVE PARTITIONING removes all partitioning from the table, while leaving the data unaffected. To rather drop a particular partition (and discard all of its data), see Dropping Partitions.
Reorganizing Partitions
Reorganizing partitions allows one to adjust existing partitions, without losing data. Specifically, the statement can be used for:
Splitting an existing partition into multiple partitions.
Merging a number of existing partitions into a new, single, partition.
Changing the ranges for a subset of existing partitions defined using
VALUES LESS THAN.Changing the value lists for a subset of partitions defined using
VALUES I.Renaming partitions.
Splitting Partitions
An existing partition can be split into multiple partitions. This can also be used to add a new partition at the low end of a RANGE partition (which is not possible by Adding Partitions).
Similarly, if MAXVALUE binds the high end:
Merging Partitions
A number of existing partitions can be merged into a new partition, for example:
Changing Ranges
Renaming Partitions
The ALTER TABLE REORGANIZE PARTITION statement can also be used for renaming partitions. Note that this creates a copy of the partition:
Truncating Partitions
[ALTER TABLE](../../reference/sql-statements-and-structure/sql-statements/data-definition/alter/alter-table.md) ... TRUNCATE PARTITION
ALTER TABLE TRUNCATE PARTITION removes all data from the specified partition/s, leaving the table and partition structure unchanged. Partitions don't need to be contiguous:
Analyzing Partitions
Similar to ANALYZE TABLE, key distributions for specific partitions can also be analyzed and stored, for example:
Checking Partitions
Similar to CHECK TABLE, specific partitions can be checked for errors, for example:
The ALL keyword can be used in place of the list of partition names, and the check operation are performed on all partitions.
Repairing Partitions
Similar to REPAIR TABLE, specific partitions can be repaired:
As with REPAIR TABLE, the QUICK and EXTENDED options are available. However, the USE_FRM option cannot be used with this statement on a partitioned table.
REPAIR PARTITION fails if there are duplicate key errors. ALTER IGNORE TABLE ... REPAIR PARTITION can be used in this case.
The ALL keyword can be used in place of the list of partition names, and the repair operation are performed on all partitions.
Optimizing Partitions
Similar to OPTIMIZE TABLE, specific partitions can be checked for errors:
OPTIMIZE PARTITION does not support per-partition optimization on InnoDB tables, and will issue a warning and cause the entire table to rebuilt and analyzed. ALTER TABLE ... REBUILD PARTITION and ALTER TABLE ... ANALYZE PARTITION can be used instead.
The ALL keyword can be used in place of the list of partition names, and the optimize operation are performed on all partitions.
Partitioning for Specific Storage Engines
Some MariaDB storage engines allow more interesting uses for partitioning.
The MERGE storage engine allows one to:
Treat a set of identical defined MyISAM tables as one.
A MyISAM table can be in many different
MERGEsets and also used separately.
SPIDER allows one to:
Move partitions of the same table on different servers. In this way, the workload can be distributed on more physical or virtual machines (data sharding).
All partitions of a
SPIDERtable can also live on the same machine. In this case there are a small overhead (SPIDERuses connections to localhost), but queries that read multiple partitions will use parallel threads.
CONNECT allows one to:
Build a table whose partitions are tables using different storage engines (like InnoDB, MyISAM, or even engines that do not support partitioning).
Build an indexable, writeable table on several data files. These files can be in different formats.
See also: Using CONNECT - Partitioning and Sharding
See Also
INFORMATION_SCHEMA.PARTITIONS contains information about existing partitions.
Partition Maintenance for suggestions on using partitions
This page is licensed: CC BY-SA / Gnu FDL
Last updated
Was this helpful?

