- MySQL 5.1 Reference Manual :: 18 Partitioning :: 18.3 Partition Management :: 18.3.4 Obtaining Information About Partitions
-
- MySQL 5.1 Reference Manual
- Preface, Notes, Licenses
- 1 General Information
- 2 Installing and Upgrading MySQL
- 3 Tutorial
- 4 MySQL Programs
- 5 MySQL Server Administration
- 6 Backup and Recovery
- 7 Optimization
- 8 Language Structure
- 9 Internationalization and Localization
- 10 Data Types
- 11 Functions and Operators
- 12 SQL Statement Syntax
- 13 Storage Engines
- 14 High Availability and Scalability
- 15 MySQL Enterprise Monitor
- 16 Replication
- 17 MySQL Cluster NDB 6.X/7.X
- 18 Partitioning
- 19 Stored Programs and Views
- 20 INFORMATION_SCHEMA Tables
- 21 Connectors and APIs
- 22 Extending MySQL
- A MySQL 5.1 Frequently Asked Questions
- B Errors, Error Codes, and Common Problems
- C MySQL Change History
- D Restrictions and Limits
- Index
- Standard Index
- C Function Index
- Command Index
- Function Index
- INFORMATION_SCHEMA Index
- Transaction Isolation Level Index
- JOIN Types Index
- Operator Index
- Option Index
- Privileges Index
- SQL Modes Index
- Status Variable Index
- Statement/Syntax Index
- System Variable Index
This section discusses obtaining information about existing partitions, which can be done in a number of ways. These include:
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 PARTITIONS SELECT
to see which partitions are used by a givenSELECT
.
As discussed elsewhere in this chapter,
SHOW CREATE TABLE
includes in its output thePARTITION 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=MyISAM DEFAULT CHARSET=latin1 PARTITION BY RANGE (YEAR(purchased)) ( PARTITION p0 VALUES LESS THAN (1990) ENGINE = MyISAM, PARTITION p1 VALUES LESS THAN (1995) ENGINE = MyISAM, PARTITION p2 VALUES LESS THAN (2000) ENGINE = MyISAM, PARTITION p3 VALUES LESS THAN (2005) ENGINE = MyISAM ) 1 row in set (0.00 sec)Note
In early MySQL 5.1 releases, the
PARTITIONS
clause was not shown for tables partitioned byHASH
orKEY
. This issue was fixed in MySQL 5.1.6.SHOW TABLE STATUS
works with partitioned tables. Beginning with MySQL 5.1.9, its output is the same as that for nonpartitioned tables, except that theCreate_options
column contains the stringpartitioned
. In MySQL 5.1.8 and earlier, theEngine
column always contained the valuePARTITION
; beginning with MySQL 5.1.9, this column contains the name of the storage engine used by all partitions of the table. (See Section 12.4.5.38, “SHOW TABLE STATUS
Syntax”, for more information about this statement.)You can also obtain information about partitions from
INFORMATION_SCHEMA
, which contains aPARTITIONS
table. See Section 20.19, “TheINFORMATION_SCHEMA PARTITIONS
Table”.Beginning with MySQL 5.1.5, it is possible to determine which partitions of a partitioned table are involved in a given
SELECT
query usingEXPLAIN PARTITIONS
. ThePARTITIONS
keyword adds apartitions
column to the output ofEXPLAIN
listing the partitions from which records would be matched by the query.Suppose that you have a table
trb1
defined 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 PARTITIONS 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 filesortIn 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 PARTITIONS 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 whereEXPLAIN PARTITIONS
provides information about keys used and possible keys, just as with the standardEXPLAIN SELECT
statement:mysql>
ALTER TABLE trb1 ADD PRIMARY KEY (id);
Query OK, 10 rows affected (0.03 sec) Records: 10 Duplicates: 0 Warnings: 0 mysql>EXPLAIN PARTITIONS 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 whereYou should take note of the following restrictions and limitations on
EXPLAIN PARTITIONS
:You cannot use the
PARTITIONS
andEXTENDED
keywords together in the sameEXPLAIN ... SELECT
statement. Attempting to do so produces a syntax error.If
EXPLAIN PARTITIONS
is used to examine a query against a nonpartitioned table, no error is produced, but the value of thepartitions
column is alwaysNULL
.
As of MySQL 5.1.28, the
rows
column ofEXPLAIN PARTITIONS
output always displays the total number of records in the table. Previously, this was the number of matching rows. (Bug#35745)See also Section 12.8.2, “
EXPLAIN
Syntax”.