This section discusses obtaining information about existing partitions, which can be done in a number of ways. Methods of obtaining such information include the following:
Using the
SHOW CREATE TABLE
statement to view the partitioning clauses used in creating a partitioned table.Using the
SHOW TABLE STATUS
statement to determine whether a table is partitioned.Querying the Information Schema
PARTITIONS
table.Using the statement
EXPLAIN SELECT
to see which partitions are used by a givenSELECT
.
From MySQL 8.0.16, when insertions, deletions, or updates are
made to partitioned tables, the binary log records information
about the partition and (if any) the subpartition in which the
row event took place. A new row event is created for a
modification that takes place in a different partition or
subpartition, even if the table involved is the same. So if a
transaction involves three partitions or subpartitions, three
row events are generated. For an update event, the partition
information is recorded for both the “before” image
and the “after” image. The partition information is
displayed if you specify the -v
or
--verbose
option when viewing the binary log
using mysqlbinlog. Partition information is
only recorded when row-based logging is in use
(binlog_format=ROW
).
As discussed elsewhere in this chapter,
SHOW CREATE TABLE
includes in its
output the PARTITION BY
clause used to create
a partitioned table. For example:
mysql> SHOW CREATE TABLE trb3\G
*************************** 1. row ***************************
Table: trb3
Create Table: CREATE TABLE `trb3` (
`id` int(11) DEFAULT NULL,
`name` varchar(50) DEFAULT NULL,
`purchased` date DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4
/*!50100 PARTITION BY RANGE (YEAR(purchased))
(PARTITION p0 VALUES LESS THAN (1990) ENGINE = InnoDB,
PARTITION p1 VALUES LESS THAN (1995) ENGINE = InnoDB,
PARTITION p2 VALUES LESS THAN (2000) ENGINE = InnoDB,
PARTITION p3 VALUES LESS THAN (2005) ENGINE = InnoDB) */
0 row in set (0.00 sec)
The output from SHOW TABLE STATUS
for partitioned tables is the same as that for nonpartitioned
tables, except that the Create_options
column
contains the string partitioned
. The
Engine
column contains the name of the
storage engine used by all partitions of the table. (See
SHOW TABLE STATUS Statement, for more information about
this statement.)
You can also obtain information about partitions from
INFORMATION_SCHEMA
, which contains a
PARTITIONS
table. See
The INFORMATION_SCHEMA PARTITIONS Table.
It is possible to determine which partitions of a partitioned
table are involved in a given
SELECT
query using
EXPLAIN
. The
partitions
column in the
EXPLAIN
output lists the
partitions from which records would be matched by the query.
Suppose that a table trb1
is created and
populated as follows:
CREATE TABLE trb1 (id INT, name VARCHAR(50), purchased DATE)
PARTITION BY RANGE(id)
(
PARTITION p0 VALUES LESS THAN (3),
PARTITION p1 VALUES LESS THAN (7),
PARTITION p2 VALUES LESS THAN (9),
PARTITION p3 VALUES LESS THAN (11)
);
INSERT INTO trb1 VALUES
(1, 'desk organiser', '2003-10-15'),
(2, 'CD player', '1993-11-05'),
(3, 'TV set', '1996-03-10'),
(4, 'bookcase', '1982-01-10'),
(5, 'exercise bike', '2004-05-09'),
(6, 'sofa', '1987-06-05'),
(7, 'popcorn maker', '2001-11-22'),
(8, 'aquarium', '1992-08-04'),
(9, 'study desk', '1984-09-16'),
(10, 'lava lamp', '1998-12-25');
You can see which partitions are used in a query such as
SELECT * FROM trb1;
, as shown here:
mysql> EXPLAIN SELECT * FROM trb1\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: trb1
partitions: p0,p1,p2,p3
type: ALL
possible_keys: NULL
key: NULL
key_len: NULL
ref: NULL
rows: 10
Extra: Using filesort
In this case, all four partitions are searched. However, when a limiting condition making use of the partitioning key is added to the query, you can see that only those partitions containing matching values are scanned, as shown here:
mysql> EXPLAIN SELECT * FROM trb1 WHERE id < 5\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: trb1
partitions: p0,p1
type: ALL
possible_keys: NULL
key: NULL
key_len: NULL
ref: NULL
rows: 10
Extra: Using where
EXPLAIN
also provides
information about keys used and possible keys:
mysql> ALTER TABLE trb1 ADD PRIMARY KEY (id);
Query OK, 10 rows affected (0.03 sec)
Records: 10 Duplicates: 0 Warnings: 0
mysql> EXPLAIN SELECT * FROM trb1 WHERE id < 5\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: trb1
partitions: p0,p1
type: range
possible_keys: PRIMARY
key: PRIMARY
key_len: 4
ref: NULL
rows: 7
Extra: Using where
If EXPLAIN
is used to examine a
query against a nonpartitioned table, no error is produced, but
the value of the partitions
column is always
NULL
.
The rows
column of
EXPLAIN
output displays the total
number of rows in the table.
See also EXPLAIN Statement.