MariaDB ColumnStore Partition Management
While a user does not need to create partitions on a table, MariaDB ColumnStore automatically creates logical partition across every columns. MariaDB ColumnStore allows to view partition information as well as disable or drop partitions. Caution should be used when disabling or dropping partitions as these commands as they are destructive. There are 2 ways to manage the partitions:
- Column Value
- Partition Number
Partition Management by Column Value
Contents
Display Partition Information by Column Value
A pre-built stored function calShowPartitionsbyValue is provided with MariaDB ColumnStore to display the partition information for a particular column
The syntax for the function is
select calShowPartitionsByValue('tbl_name','col_name', 'start_value', 'end_value');
Only casual partition column types (INTEGER, DECIMAL, DATE, DATETIME, CHAR up to 8 bytes and VARCHAR up to 7 bytes) are supported for this function.
The function returns list of partitions whose minimum and maximum values for the column 'col_name' fall completely within the range of 'start_value' and 'end_value'
Example: select calShowPartitionsByValue('orders','orderdate', '1992-01-01', '2010-07-24'); +----------------------------------------------------------------+ |calShowPartitionsbyvalue('orders','orderdate', '1992-01-02', '2010-07-24')| +----------------------------------------------------------------+ | Part# Min Max Status 0.0.1 1992-01-01 1998-08-02 Enabled 0.1.2 1998-08-03 2004-05-15 Enabled 0.2.3 2004-05-16 2010-07-24 Enabled | +----------------------------------------------------------------+ 1 row in set (0.05 sec)
Disable Partition by Column Value
A pre-built stored function calDisablePartitionsbyValue is provided with MariaDB ColumnStore to disable specific partitions based on the value of a particular column. After analysis of the partition information from calShowPartitionsbyValue, if a decision is made to disable the partition instead of dropping it, the calDisablePartitionsbyValue function would be used.
The syntax for the function is
select calDisablePartitionsByValue('tbl_name','col_name', 'start_value', 'end_value');
Only casual partition column types (INTEGER, DECIMAL, DATE, DATETIME, CHAR up to 8 bytes and VARCHAR up to 7 bytes) are supported for this function.
The function disables all the partitions whose minimum and maximum values for the column 'col_name' fall completely within the range of 'start_value' and 'end_value'. A disabled partition still exists on the file system but will not participate in any query, DML or import activity.
Example: select calDisablePartitionsByValue('orders','orderdate', '1992-01-01', '1998-08-02'); +---------------------------------------------------------------------------+ | caldisablepartitionsbyvalue ('orders', 'o_orderdate','1992-01-01','1998-08-02') | +---------------------------------------------------------------------------+ | Partitions are disabled successfully | +---------------------------------------------------------------------------+ 1 row in set (0.28 sec) The result showing the first partition has been disabled: MariaDB[test]> select calShowPartitionsByValue('orders','orderdate', '1992-01-01', '2010-07-24'); +----------------------------------------------------------------+ |calShowPartitionsbyvalue('orders','orderdate', '1992-01-02','2010-07-24’ )| +----------------------------------------------------------------+ | Part# Min Max Status 0.0.1 1992-01-01 1998-08-02 Disabled 0.1.2 1998-08-03 2004-05-15 Enabled 0.2.3 2004-05-16 2010-07-24 Enabled | +----------------------------------------------------------------+ 1 row in set (0.05 sec)
Enabling Partition by Column Value
A pre-built stored function calEnablePartitionsbyValue is provided with MariaDB ColumnStore to enables specific partitions based on the value of a particular column.
The syntax for the function is
select calEnablePartitionsByValue('tbl_name','col_name', 'start_value', 'end_value');
The following execution of calEnablePartitionsbyValue enables the first partition:
select calEnablePartitionsByValue('orders','orderdate', '1992-01-01', '1998-08-02'); +---------------------------------------------------------------------------+ | calenablepartitionsbyvalue ('orders', 'o_orderdate','1992-01-01','1998-08-02')| +---------------------------------------------------------------------------+ | Partitions are enabled successfully | +---------------------------------------------------------------------------+ 1 row in set (0.28 sec)
The result showing the first partition has been enabled:
select calShowPartitionsByValue('orders','orderdate', '1992-01-01', '2010-07- 24'); +----------------------------------------------------------------+ |calShowPartitionsbyvalue('orders','orderdate', '1992-01-02','2010-07-24' )| +----------------------------------------------------------------+ | Part# Min Max Status 0.0.1 1992-01-01 1998-08-02 Enabled 0.1.2 1998-08-03 2004-05-15 Enabled 0.2.3 2004-05-16 2010-07-24 Enabled | +----------------------------------------------------------------+ 2 rows in set (0.05 sec)
Drop Partition by Column Value
A pre-built stored function calDisablePartitionsbyValue is provided with MariaDB ColumnStore to disable specific partitions based on the value of a particular column. After analysis of the partition information from calShowPartitionsbyValue, if a decision is made to drop the partition, the calDropPartitionsbyValue function can be used.
The syntax for the function is
select calDropPartitionsByValue('tbl_name','col_name', 'start_value', 'end_value');
Only casual partition column types (INTEGER, DECIMAL, DATE, DATETIME, CHAR up to 8 bytes and VARCHAR up to 7 bytes) are supported for this function.
A partition may be dropped from both an Enabled or Disabled state.
The function drops all the partitions whose minimum and maximum values for the column 'col_name' fall completely within the range of 'start_value' and 'end_value'. A dropped partition is removed from file system permanently.
The following execution of calDropPartitionsbyValue drops the first partition:
select calDropPartitionsByValue('orders','orderdate', '1992-01-01', '1998-08-02'); +---------------------------------------------------------------------------+ | caldroppartitionsbyvalue ('orders', 'o_orderdate','1992-01-01','1998-08-02') | +---------------------------------------------------------------------------+ | Partitions are enabled successfully | +---------------------------------------------------------------------------+ 1 row in set (0.28 sec)
The result showing the first partition has been dropped:
select calShowPartitionsByValue('orders','orderdate', '1992-01-01', '2010-07-24'); +----------------------------------------------------------------+ |calShowPartitionsbyvalue('orders','orderdate', '1992-01-02','2010-07-24' )| +----------------------------------------------------------------+ | Part# Min Max Status 0.1.2 1998-08-03 2004-05-15 Enabled 0.2.3 2004-05-16 2010-07-24 Enabled | +----------------------------------------------------------------+ 1 row in set (0.05 sec)