Updated on 2024-12-30 GMT+08:00

Partition-level MDL

In MySQL Community Edition, you cannot perform both data manipulation language (DML) operations for accessing data of partitioned tables and data definition language (DDL) operations for maintaining partitions at the same time. This means that DDL operations can only be done during off-peak hours. However, the frequent creation and deletion of partitions greatly limits the use of partitioned tables.

To resolve such an issue, TaurusDB introduces partition-level metadata lock (MDL) to refine the lock granularity of a partitioned table from the table level to the partition level. After partition-level MDL is enabled, DML operations and specific DDL operations (such as adding and deleting partitions) on different partitions can be both performed, greatly improving concurrency between partitions.

Constraints

  • Partition-level MDL is only available for ADD PARTITION operations for RANGE and LIST partitioning and DROP PARTITION operations.
  • ADD PARTITION and DROP PARTITION operations only support the INPLACE algorithm.
  • The isolation level can be set to the session level. If transaction_isolation is set to REPEATABLE-READ or a higher isolation level, the following error may be reported when DDL operations are performed concurrently:
    ERROR HY000: Table definition has changed, please retry transaction.

    This is normal because a transaction accesses the new partition created by DDL. To resolve this issue, you can simply re-execute the transaction.

Prerequisites

  • The kernel version of your TaurusDB instance must be 2.0.57.240900 or later.
  • The global isolation level of transaction_isolation must be set to READ-COMMITTED.

Enabling Partition-level MDL

You can set the rds_partition_level_mdl_enabled parameter to configure partition-level MDL.

Table 1 Parameter description

Parameter

Level

Description

rds_partition_level_mdl_enabled

Global

Controls whether to enable partition-level MDL.

ON: Partition-level MDL is enabled.

OFF (default value): Partition-level MDL is disabled.

NOTE:

A reboot is required to apply the parameter modification.

Examples

Partition-level MDL ensures that DDL and DML operations do not affect each other. You can maintain partitions more flexibly without affecting the traffic of a partitioned table.

The following is an example:

  1. Prepare data.
    mysql>
    mysql>  CREATE TABLE t1 ( c1 INTEGER NOT NULL PRIMARY KEY, c2 CHAR(10)) PARTITION BY RANGE (c1) (
        ->     PARTITION p0 VALUES LESS THAN (100),
        ->     PARTITION p1 VALUES LESS THAN (200),
        ->     PARTITION p2 VALUES LESS THAN (300),
        ->     PARTITION p3 VALUES LESS THAN (400),
        ->     PARTITION p4 VALUES LESS THAN (500));
    Query OK, 0 rows affected (0.22 sec)
     
    mysql>  INSERT INTO t1 VALUES(0,'abc'),(100,'abc'),(200,'abc'),(300,'abc'),(400,'abc');
    Query OK, 5 rows affected (0.02 sec)
    Records: 5  Duplicates: 0  Warnings: 0
     
  2. Start a transaction on client 1.
    mysql> BEGIN;
    Query OK, 0 rows affected (0.00 sec)
     
    mysql> SELECT * FROM t1 WHERE c1 >= 300;
    +-----+------+
    | c1  | c2   |
    +-----+------+
    | 300 | abc  |
    | 400 | abc  |
    +-----+------+
    2 rows in set (0.00 sec)
  3. Add a new partition on client 2.
    mysql> ALTER TABLE t1 ADD PARTITION (PARTITION p5 VALUES LESS THAN (600));
    Query OK, 0 rows affected (0.21 sec)
    Records: 0  Duplicates: 0  Warnings: 0
     
    mysql> INSERT INTO t1 VALUES(500,'abc');
    Query OK, 1 row affected (0.00 sec)
  4. On client 1, check that the new partition data is available in the transaction.
    mysql> SELECT * FROM t1 WHERE c1 >= 300;
    +-----+------+
    | c1  | c2   |
    +-----+------+
    | 300 | abc  |
    | 400 | abc  |
    | 500 | abc  |
    +-----+------+
    3 rows in set (0.00 sec)
  5. Drop an old partition on client 2.
    mysql> ALTER TABLE t1 DROP PARTITION p0;
    Query OK, 0 rows affected (0.13 sec)
    Records: 0  Duplicates: 0  Warnings: 0
  6. On client 1, check that the old partition no longer exists and the new partition exists.
    mysql> SHOW CREATE TABLE t1\G
    *************************** 1. row ***************************
           Table: t1
    Create Table: CREATE TABLE `t1` (
      `c1` int NOT NULL,
      `c2` char(10) DEFAULT NULL,
      PRIMARY KEY (`c1`)
    ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
    /*!50100 PARTITION BY RANGE (`c1`)
    (PARTITION p1 VALUES LESS THAN (200) ENGINE = InnoDB,
     PARTITION p2 VALUES LESS THAN (300) ENGINE = InnoDB,
     PARTITION p3 VALUES LESS THAN (400) ENGINE = InnoDB,
     PARTITION p4 VALUES LESS THAN (500) ENGINE = InnoDB,
     PARTITION p5 VALUES LESS THAN (600) ENGINE = InnoDB) */
    1 row in set (0.00 sec)
  7. Commit the transaction on client 1.
    mysql> COMMIT;
    Query OK, 0 rows affected (0.01 sec) 

Partition-level MDL reduces the granularity of locks acquired during DML and DDL operations to improve concurrency. During partition maintenance, you can check the acquisition of partition-level MDL locks through the performance_schema.metadata_locks table. The following is an example:

  1. Start a transaction on client 1.
    mysql> BEGIN;
    Query OK, 0 rows affected (0.00 sec)
     
    mysql> SELECT * FROM t1 WHERE c1 >= 500;
    +-----+------+
    | c1  | c2   |
    +-----+------+
    | 500 | abc  |
    +-----+------+
    1 rows in set (0.00 sec)
  2. On client 1, check the acquisition of MDL locks.
    mysql> SELECT * FROM performance_schema.metadata_locks;
    +-------------------+--------------------+----------------+-----------------------+-----------------------+---------------------+---------------+-------------+-------------------+-----------------+----------------+
    | OBJECT_TYPE       | OBJECT_SCHEMA      | OBJECT_NAME    | COLUMN_NAME           | OBJECT_INSTANCE_BEGIN | LOCK_TYPE           | LOCK_DURATION | LOCK_STATUS | SOURCE            | OWNER_THREAD_ID | OWNER_EVENT_ID |
    +-------------------+--------------------+----------------+-----------------------+-----------------------+---------------------+---------------+-------------+-------------------+-----------------+----------------+
    | TABLE             | test               | t1             | NULL                  |       140082560509056 | SHARED_READ         | TRANSACTION   | GRANTED     | sql_parse.cc:8006 |              69 |             23 |
    | PARTITION         | test               | t1             | p5                    |       140082560508384 | SHARED_READ         | TRANSACTION   | GRANTED     | sql_lex.cc:5434   |              69 |             23 |
    | TABLE             | performance_schema | metadata_locks | NULL                  |       140082560511936 | SHARED_READ         | TRANSACTION   | GRANTED     | sql_parse.cc:8006 |              69 |             24 |
    +-------------------+--------------------+----------------+-----------------------+-----------------------+---------------------+---------------+-------------+-------------------+-----------------+----------------+
    4 rows in set (0.01 sec)

    The transaction of client 1 acquires a SHARED_READ lock of table t1 and a SHARED_READ lock of partition p5. Partition p5 is the partition that needs to be accessed and is obtained through partition pruning.

  3. Drop partition p5 on client 2.
    mysql> ALTER TABLE t1 DROP PARTITION p5;

    Client 1 is accessing partition p5 and has acquired a SHARED_READ lock of partition p5. In this case, the DROP operation is blocked and enters the waiting state.

  4. Check that the DROP operation is blocked and enters the waiting state.
    mysql> SHOW PROCESSLIST;
    +----+-----------------+-----------------+------+---------+-------+-------------------------------------------+----------------------------------+
    | Id | User            | Host            | db   | Command | Time  | State                                     | Info                             |
    +----+-----------------+-----------------+------+---------+-------+-------------------------------------------+----------------------------------+
    |  5 | event_scheduler | localhost       | NULL | Daemon  | 33127 | Waiting on empty queue                    | NULL                             |
    | 13 | root            | localhost:42926 | test | Query   |     0 | init                                      | SHOW PROCESSLIST                 |
    | 14 | root            | localhost:42936 | test | Query   |   180 | Waiting for table partition metadata lock | ALTER TABLE t1 DROP PARTITION p5 |
    | 15 | root            | localhost:42938 | test | Sleep   |  1542 |                                           | NULL                             |
    +----+-----------------+-----------------+------+---------+-------+-------------------------------------------+----------------------------------+
    4 rows in set (0.00 sec)
     
  5. After the transaction is committed on client 1, check that partition p5 is dropped on client 2.

    Client 1:

    mysql> COMMIT;
    Query OK, 0 rows affected (0.01 sec)

    Client 2:

    mysql> ALTER TABLE t1 DROP PARTITION p5;
    Query OK, 0 rows affected (1 min 2.48 sec)
    Records: 0  Duplicates: 0  Warnings: 0