MySQL :: MySQL 5.7 Reference Manual :: 13.1.18 CREATE TABLE Statement (original) (raw)
13.1.18 CREATE TABLE Statement
CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name
(create_definition,...)
[table_options]
[partition_options]
CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name
[(create_definition,...)]
[table_options]
[partition_options]
[IGNORE | REPLACE]
[AS] query_expression
CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name
{ LIKE old_tbl_name | (LIKE old_tbl_name) }
create_definition: {
col_name column_definition
| {INDEX | KEY} [index_name] [index_type] (key_part,...)
[index_option] ...
| {FULLTEXT | SPATIAL} [INDEX | KEY] [index_name] (key_part,...)
[index_option] ...
| [CONSTRAINT [symbol]] PRIMARY KEY
[index_type] (key_part,...)
[index_option] ...
| [CONSTRAINT [symbol]] UNIQUE [INDEX | KEY]
[index_name] [index_type] (key_part,...)
[index_option] ...
| [CONSTRAINT [symbol]] FOREIGN KEY
[index_name] (col_name,...)
reference_definition
| CHECK (expr)
}
column_definition: {
data_type [NOT NULL | NULL] [DEFAULT default_value]
[AUTO_INCREMENT] [UNIQUE [KEY]] [[PRIMARY] KEY]
[COMMENT 'string']
[COLLATE collation_name]
[COLUMN_FORMAT {FIXED | DYNAMIC | DEFAULT}]
[STORAGE {DISK | MEMORY}]
[reference_definition]
| data_type
[COLLATE collation_name]
[GENERATED ALWAYS] AS (expr)
[VIRTUAL | STORED] [NOT NULL | NULL]
[UNIQUE [KEY]] [[PRIMARY] KEY]
[COMMENT 'string']
[reference_definition]
}
data_type:
(see Chapter 11, Data Types)
key_part:
col_name [(length)] [ASC | DESC]
index_type:
USING {BTREE | HASH}
index_option: {
KEY_BLOCK_SIZE [=] value
| index_type
| WITH PARSER parser_name
| COMMENT 'string'
}
reference_definition:
REFERENCES tbl_name (key_part,...)
[MATCH FULL | MATCH PARTIAL | MATCH SIMPLE]
[ON DELETE reference_option]
[ON UPDATE reference_option]
reference_option:
RESTRICT | CASCADE | SET NULL | NO ACTION | SET DEFAULT
table_options:
table_option [[,] table_option] ...
table_option: {
AUTO_INCREMENT [=] value
| AVG_ROW_LENGTH [=] value
| [DEFAULT] CHARACTER SET [=] charset_name
| CHECKSUM [=] {0 | 1}
| [DEFAULT] COLLATE [=] collation_name
| COMMENT [=] 'string'
| COMPRESSION [=] {'ZLIB' | 'LZ4' | 'NONE'}
| CONNECTION [=] 'connect_string'
| {DATA | INDEX} DIRECTORY [=] 'absolute path to directory'
| DELAY_KEY_WRITE [=] {0 | 1}
| ENCRYPTION [=] {'Y' | 'N'}
| ENGINE [=] engine_name
| INSERT_METHOD [=] { NO | FIRST | LAST }
| KEY_BLOCK_SIZE [=] value
| MAX_ROWS [=] value
| MIN_ROWS [=] value
| PACK_KEYS [=] {0 | 1 | DEFAULT}
| PASSWORD [=] 'string'
| ROW_FORMAT [=] {DEFAULT | DYNAMIC | FIXED | COMPRESSED | REDUNDANT | COMPACT}
| STATS_AUTO_RECALC [=] {DEFAULT | 0 | 1}
| STATS_PERSISTENT [=] {DEFAULT | 0 | 1}
| STATS_SAMPLE_PAGES [=] value
| tablespace_option
| UNION [=] (tbl_name[,tbl_name]...)
}
partition_options:
PARTITION BY
{ [LINEAR] HASH(expr)
| [LINEAR] KEY [ALGORITHM={1 | 2}] (column_list)
| RANGE{(expr) | COLUMNS(column_list)}
| LIST{(expr) | COLUMNS(column_list)} }
[PARTITIONS num]
[SUBPARTITION BY
{ [LINEAR] HASH(expr)
| [LINEAR] KEY [ALGORITHM={1 | 2}] (column_list) }
[SUBPARTITIONS num]
]
[(partition_definition [, partition_definition] ...)]
partition_definition:
PARTITION partition_name
[VALUES
{LESS THAN {(expr | value_list) | MAXVALUE}
|
IN (value_list)}]
[[STORAGE] ENGINE [=] engine_name]
[COMMENT [=] 'string' ]
[DATA DIRECTORY [=] 'data_dir']
[INDEX DIRECTORY [=] 'index_dir']
[MAX_ROWS [=] max_number_of_rows]
[MIN_ROWS [=] min_number_of_rows]
[TABLESPACE [=] tablespace_name]
[(subpartition_definition [, subpartition_definition] ...)]
subpartition_definition:
SUBPARTITION logical_name
[[STORAGE] ENGINE [=] engine_name]
[COMMENT [=] 'string' ]
[DATA DIRECTORY [=] 'data_dir']
[INDEX DIRECTORY [=] 'index_dir']
[MAX_ROWS [=] max_number_of_rows]
[MIN_ROWS [=] min_number_of_rows]
[TABLESPACE [=] tablespace_name]
tablespace_option:
TABLESPACE tablespace_name [STORAGE DISK]
| [TABLESPACE tablespace_name] STORAGE MEMORY
query_expression:
SELECT ... (Some valid select or union statement)CREATE TABLE creates a table with the given name. You must have theCREATE privilege for the table.
By default, tables are created in the default database, using theInnoDB storage engine. An error occurs if the table exists, if there is no default database, or if the database does not exist.
MySQL has no limit on the number of tables. The underlying file system may have a limit on the number of files that represent tables. Individual storage engines may impose engine-specific constraints. InnoDB permits up to 4 billion tables.
For information about the physical representation of a table, seeSection 13.1.18.1, “Files Created by CREATE TABLE”.
There are several aspects to the CREATE TABLE statement, described under the following topics in this section:
- Table Name
- Temporary Tables
- Table Cloning and Copying
- Column Data Types and Attributes
- Indexes and Foreign Keys
- Table Options
- Table Partitioning
Table Name
_`tblname`_
The table name can be specified as_dbname.tblname_ to create the table in a specific database. This works regardless of whether there is a default database, assuming that the database exists. If you use quoted identifiers, quote the database and table names separately. For example, write`mydb`.`mytbl`, not`mydb.mytbl`.
Rules for permissible table names are given inSection 9.2, “Schema Object Names”.IF NOT EXISTS
Prevents an error from occurring if the table exists. However, there is no verification that the existing table has a structure identical to that indicated by theCREATE TABLE statement.
Temporary Tables
You can use the TEMPORARY keyword when creating a table. A TEMPORARY table is visible only within the current session, and is dropped automatically when the session is closed. For more information, seeSection 13.1.18.2, “CREATE TEMPORARY TABLE Statement”.
Table Cloning and Copying
LIKE
UseCREATE TABLE ... LIKEto create an empty table based on the definition of another table, including any column attributes and indexes defined in the original table:
CREATE TABLE new_tbl LIKE orig_tbl; For more information, see Section 13.1.18.3, “CREATE TABLE ... LIKE Statement”.
[AS]_`queryexpression`_
To create one table from another, add aSELECT statement at the end of the CREATE TABLE statement:
CREATE TABLE new_tbl AS SELECT * FROM orig_tbl; For more information, seeSection 13.1.18.4, “CREATE TABLE ... SELECT Statement”.
IGNORE | REPLACE
TheIGNOREandREPLACEoptions indicate how to handle rows that duplicate unique key values when copying a table using aSELECT statement.
For more information, seeSection 13.1.18.4, “CREATE TABLE ... SELECT Statement”.
Column Data Types and Attributes
There is a hard limit of 4096 columns per table, but the effective maximum may be less for a given table and depends on the factors discussed in Section 8.4.7, “Limits on Table Column Count and Row Size”.
_`datatype`_datatyperepresents the data type in a column definition. For a full description of the syntax available for specifying column data types, as well as information about the properties of each type, seeChapter 11, Data Types.- Some attributes do not apply to all data types.
AUTO_INCREMENTapplies only to integer and floating-point types.DEFAULTdoes not apply to the BLOB,TEXT,GEOMETRY, andJSON types. - Character data types (CHAR,VARCHAR, theTEXT types,ENUM,SET, and any synonyms) can include
CHARACTER SETto specify the character set for the column.CHARSETis a synonym forCHARACTER SET. A collation for the character set can be specified with theCOLLATEattribute, along with any other attributes. For details, see Chapter 10, Character Sets, Collations, Unicode. Example:
CREATE TABLE t (c CHAR(20) CHARACTER SET utf8 COLLATE utf8_bin);MySQL 5.7 interprets length specifications in character column definitions in characters. Lengths forBINARY andVARBINARY are in bytes.
- For CHAR,VARCHAR,BINARY, andVARBINARY columns, indexes can be created that use only the leading part of column values, using
_`colname`_(_`length`_)syntax to specify an index prefix length.BLOB andTEXT columns also can be indexed, but a prefix length must be given. Prefix lengths are given in characters for nonbinary string types and in bytes for binary string types. That is, index entries consist of the first_length_ characters of each column value for CHAR,VARCHAR, andTEXT columns, and the first_length_ bytes of each column value for BINARY,VARBINARY, andBLOB columns. Indexing only a prefix of column values like this can make the index file much smaller. For additional information about index prefixes, see Section 13.1.14, “CREATE INDEX Statement”.
Only theInnoDBandMyISAMstorage engines support indexing on BLOB andTEXT columns. For example:
CREATE TABLE test (blob_col BLOB, INDEX(blob_col(10)));As of MySQL 5.7.17, if a specified index prefix exceeds the maximum column data type size,CREATE TABLE handles the index as follows:
* For a nonunique index, either an error occurs (if strict SQL mode is enabled), or the index length is reduced to lie within the maximum column data type size and a warning is produced (if strict SQL mode is not enabled).
* For a unique index, an error occurs regardless of SQL mode because reducing the index length might enable insertion of nonunique entries that do not meet the specified uniqueness requirement.- JSON columns cannot be indexed. You can work around this restriction by creating an index on a generated column that extracts a scalar value from the
JSONcolumn. SeeIndexing a Generated Column to Provide a JSON Column Index, for a detailed example.
- Some attributes do not apply to all data types.
NOT NULL | NULL
If neitherNULLnorNOT NULLis specified, the column is treated as thoughNULLhad been specified.
In MySQL 5.7, only theInnoDB,MyISAM, andMEMORYstorage engines support indexes on columns that can haveNULLvalues. In other cases, you must declare indexed columns asNOT NULLor an error results.DEFAULT
Specifies a default value for a column. For more information about default value handling, including the case that a column definition includes no explicitDEFAULTvalue, see Section 11.6, “Data Type Default Values”.
If the NO_ZERO_DATE orNO_ZERO_IN_DATE SQL mode is enabled and a date-valued default is not correct according to that mode, CREATE TABLE produces a warning if strict SQL mode is not enabled and an error if strict mode is enabled. For example, withNO_ZERO_IN_DATE enabled,c1 DATE DEFAULT '2010-00-00'produces a warning.AUTO_INCREMENT
An integer or floating-point column can have the additional attributeAUTO_INCREMENT. When you insert a value ofNULL(recommended) or0into an indexedAUTO_INCREMENTcolumn, the column is set to the next sequence value. Typically this is_`value`_+1, where_value_ is the largest value for the column currently in the table.AUTO_INCREMENTsequences begin with1.
To retrieve anAUTO_INCREMENTvalue after inserting a row, use theLAST_INSERT_ID() SQL function or the mysql_insert_id() C API function. See Section 12.15, “Information Functions”, andmysql_insert_id().
If the NO_AUTO_VALUE_ON_ZERO SQL mode is enabled, you can store0inAUTO_INCREMENTcolumns as0without generating a new sequence value. See Section 5.1.10, “Server SQL Modes”.
There can be only oneAUTO_INCREMENTcolumn per table, it must be indexed, and it cannot have aDEFAULTvalue. AnAUTO_INCREMENTcolumn works properly only if it contains only positive values. Inserting a negative number is regarded as inserting a very large positive number. This is done to avoid precision problems when numbers“wrap” over from positive to negative and also to ensure that you do not accidentally get anAUTO_INCREMENTcolumn that contains0.
ForMyISAMtables, you can specify anAUTO_INCREMENTsecondary column in a multiple-column key. SeeSection 3.6.9, “Using AUTO_INCREMENT”.
To make MySQL compatible with some ODBC applications, you can find theAUTO_INCREMENTvalue for the last inserted row with the following query:
SELECT * FROM tbl_name WHERE auto_col IS NULL This method requires thatsql_auto_is_null variable is not set to 0. See Section 5.1.7, “Server System Variables”.
For information about InnoDB andAUTO_INCREMENT, seeSection 14.6.1.6, “AUTO_INCREMENT Handling in InnoDB”. For information about AUTO_INCREMENT and MySQL Replication, seeSection 16.4.1.1, “Replication and AUTO_INCREMENT”.
COMMENT
A comment for a column can be specified with theCOMMENToption, up to 1024 characters long. The comment is displayed by the SHOW CREATE TABLE andSHOW FULL COLUMNS statements. It is also shown in theCOLUMN_COMMENTcolumn of the Information Schema COLUMNS table.COLUMN_FORMAT
In NDB Cluster, it is also possible to specify a data storage format for individual columns ofNDB tables usingCOLUMN_FORMAT. Permissible column formats areFIXED,DYNAMIC, andDEFAULT.FIXEDis used to specify fixed-width storage,DYNAMICpermits the column to be variable-width, andDEFAULTcauses the column to use fixed-width or variable-width storage as determined by the column's data type (possibly overridden by aROW_FORMATspecifier).
Beginning with MySQL NDB Cluster 7.5.4, forNDB tables, the default value forCOLUMN_FORMATisFIXED. (The default had been switched toDYNAMICin MySQL NDB Cluster 7.5.1, but this change was reverted to maintain backwards compatibility with existing GA release series.) (Bug #24487363)
In NDB Cluster, the maximum possible offset for a column defined withCOLUMN_FORMAT=FIXEDis 8188 bytes. For more information and possible workarounds, seeSection 21.2.7.5, “Limits Associated with Database Objects in NDB Cluster”.COLUMN_FORMATcurrently has no effect on columns of tables using storage engines other thanNDB. In MySQL 5.7 and later,COLUMN_FORMATis silently ignored.STORAGE
For NDB tables, it is possible to specify whether the column is stored on disk or in memory by using aSTORAGEclause.STORAGE DISKcauses the column to be stored on disk, andSTORAGE MEMORYcauses in-memory storage to be used. The CREATE TABLE statement used must still include aTABLESPACEclause:
mysql> CREATE TABLE t1 (
-> c1 INT STORAGE DISK,
-> c2 INT STORAGE MEMORY
-> ) ENGINE NDB;
ERROR 1005 (HY000): Can't create table 'c.t1' (errno: 140)
mysql> CREATE TABLE t1 (
-> c1 INT STORAGE DISK,
-> c2 INT STORAGE MEMORY
-> ) TABLESPACE ts_1 ENGINE NDB;
Query OK, 0 rows affected (1.06 sec) For NDB tables, STORAGE DEFAULT is equivalent to STORAGE MEMORY.
The STORAGE clause has no effect on tables using storage engines other thanNDB. TheSTORAGE keyword is supported only in the build of mysqld that is supplied with NDB Cluster; it is not recognized in any other version of MySQL, where any attempt to use the STORAGE keyword causes a syntax error.
GENERATED ALWAYS
Used to specify a generated column expression. For information about generated columns, seeSection 13.1.18.7, “CREATE TABLE and Generated Columns”.
Stored generated columns can be indexed.InnoDBsupports secondary indexes onvirtual generated columns. SeeSection 13.1.18.8, “Secondary Indexes and Generated Columns”.
Indexes and Foreign Keys
Several keywords apply to creation of indexes and foreign keys. For general background in addition to the following descriptions, see Section 13.1.14, “CREATE INDEX Statement”, andSection 13.1.18.5, “FOREIGN KEY Constraints”.
CONSTRAINT_`symbol`_
TheCONSTRAINT_`symbol`_clause may be given to name a constraint. If the clause is not given, or a_symbol_ is not included following theCONSTRAINTkeyword, MySQL automatically generates a constraint name, with the exception noted below. Thesymbolvalue, if used, must be unique per schema (database), per constraint type. A duplicate_symbol_ results in an error. See also the discussion about length limits of generated constraint identifiers at Section 9.2.1, “Identifier Length Limits”.
Note
If theCONSTRAINT_`symbol`_clause is not given in a foreign key definition, or a_symbol_ is not included following theCONSTRAINTkeyword,NDB uses the foreign key index name.
The SQL standard specifies that all types of constraints (primary key, unique index, foreign key, check) belong to the same namespace. In MySQL, each constraint type has its own namespace per schema. Consequently, names for each type of constraint must be unique per schema.PRIMARY KEY
A unique index where all key columns must be defined asNOT NULL. If they are not explicitly declared asNOT NULL, MySQL declares them so implicitly (and silently). A table can have only onePRIMARY KEY. The name of aPRIMARY KEYis alwaysPRIMARY, which thus cannot be used as the name for any other kind of index.
If you do not have aPRIMARY KEYand an application asks for thePRIMARY KEYin your tables, MySQL returns the firstUNIQUEindex that has noNULLcolumns as thePRIMARY KEY.
InInnoDBtables, keep thePRIMARY KEYshort to minimize storage overhead for secondary indexes. Each secondary index entry contains a copy of the primary key columns for the corresponding row. (SeeSection 14.6.2.1, “Clustered and Secondary Indexes”.)
In the created table, aPRIMARY KEYis placed first, followed by allUNIQUEindexes, and then the nonunique indexes. This helps the MySQL optimizer to prioritize which index to use and also more quickly to detect duplicatedUNIQUEkeys.
APRIMARY KEYcan be a multiple-column index. However, you cannot create a multiple-column index using thePRIMARY KEYkey attribute in a column specification. Doing so only marks that single column as primary. You must use a separatePRIMARY KEY(_`keypart`_, ...)clause.
If a table has aPRIMARY KEYorUNIQUE NOT NULLindex that consists of a single column that has an integer type, you can use_rowidto refer to the indexed column inSELECT statements, as described in Unique Indexes.
In MySQL, the name of aPRIMARY KEYisPRIMARY. For other indexes, if you do not assign a name, the index is assigned the same name as the first indexed column, with an optional suffix (_2,_3,...) to make it unique. You can see index names for a table usingSHOW INDEX FROM_`tblname`_. SeeSection 13.7.5.22, “SHOW INDEX Statement”.KEY | INDEXKEYis normally a synonym forINDEX. The key attributePRIMARY KEYcan also be specified as justKEYwhen given in a column definition. This was implemented for compatibility with other database systems.UNIQUE
AUNIQUEindex creates a constraint such that all values in the index must be distinct. An error occurs if you try to add a new row with a key value that matches an existing row. For all engines, aUNIQUEindex permits multipleNULLvalues for columns that can containNULL. If you specify a prefix value for a column in aUNIQUEindex, the column values must be unique within the prefix length.
If a table has aPRIMARY KEYorUNIQUE NOT NULLindex that consists of a single column that has an integer type, you can use_rowidto refer to the indexed column inSELECT statements, as described in Unique Indexes.FULLTEXT
AFULLTEXTindex is a special type of index used for full-text searches. Only theInnoDB andMyISAM storage engines supportFULLTEXTindexes. They can be created only from CHAR,VARCHAR, andTEXT columns. Indexing always happens over the entire column; column prefix indexing is not supported and any prefix length is ignored if specified. SeeSection 12.9, “Full-Text Search Functions”, for details of operation. AWITH PARSERclause can be specified as an_indexoption_ value to associate a parser plugin with the index if full-text indexing and searching operations need special handling. This clause is valid only forFULLTEXTindexes. BothInnoDB andMyISAM support full-text parser plugins. See Full-Text Parser Plugins andWriting Full-Text Parser Plugins for more information.SPATIAL
You can createSPATIALindexes on spatial data types. Spatial types are supported only forMyISAMandInnoDBtables, and indexed columns must be declared asNOT NULL. See Section 11.4, “Spatial Data Types”.FOREIGN KEY
MySQL supports foreign keys, which let you cross-reference related data across tables, and foreign key constraints, which help keep this spread-out data consistent. For definition and option information, seereference_definition, andreference_option.
Partitioned tables employing theInnoDB storage engine do not support foreign keys. SeeSection 22.6, “Restrictions and Limitations on Partitioning”, for more information.CHECK
TheCHECKclause is parsed but ignored by all storage engines._`keypart`_- A
keypartspecification can end withASCorDESC. These keywords are permitted for future extensions for specifying ascending or descending index value storage. Currently, they are parsed but ignored; index values are always stored in ascending order. - Prefixes, defined by the
lengthattribute, can be up to 767 bytes long forInnoDBtables or 3072 bytes if theinnodb_large_prefix option is enabled. ForMyISAMtables, the prefix length limit is 1000 bytes.
Prefix limits are measured in bytes. However, prefix lengths for index specifications in CREATE TABLE, ALTER TABLE, and CREATE INDEX statements are interpreted as number of characters for nonbinary string types (CHAR,VARCHAR,TEXT) and number of bytes for binary string types (BINARY,VARBINARY,BLOB). Take this into account when specifying a prefix length for a nonbinary string column that uses a multibyte character set.
- A
_`indextype`_
Some storage engines permit you to specify an index type when creating an index. The syntax for the_indextype_ specifier isUSING _`typename`_.
Example:
CREATE TABLE lookup
(id INT, INDEX USING BTREE (id))
ENGINE = MEMORY; The preferred position for USING is after the index column list. It can be given before the column list, but support for use of the option in that position is deprecated; expect it to be removed in a future MySQL release.
_`indexoption`_indexoptionvalues specify additional options for an index.KEY_BLOCK_SIZE
For MyISAM tables,KEY_BLOCK_SIZEoptionally specifies the size in bytes to use for index key blocks. The value is treated as a hint; a different size could be used if necessary. AKEY_BLOCK_SIZEvalue specified for an individual index definition overrides the table-levelKEY_BLOCK_SIZEvalue.
For information about the table-levelKEY_BLOCK_SIZEattribute, seeTable Options.WITH PARSER
TheWITH PARSERoption can be used only withFULLTEXTindexes. It associates a parser plugin with the index if full-text indexing and searching operations need special handling. BothInnoDB andMyISAM support full-text parser plugins. If you have aMyISAM table with an associated full-text parser plugin, you can convert the table toInnoDBusingALTER TABLE.COMMENT
Index definitions can include an optional comment of up to 1024 characters.
You can set theInnoDBMERGE_THRESHOLDvalue for an individual index using the_`indexoption`_COMMENTclause. SeeSection 14.8.12, “Configuring the Merge Threshold for Index Pages”.
For more information about permissible_indexoption_ values, seeSection 13.1.14, “CREATE INDEX Statement”. For more information about indexes, see Section 8.3.1, “How MySQL Uses Indexes”.
_`referencedefinition`_
Forreferencedefinitionsyntax details and examples, seeSection 13.1.18.5, “FOREIGN KEY Constraints”.
InnoDB andNDB tables support checking of foreign key constraints. The columns of the referenced table must always be explicitly named. BothON DELETEandON UPDATEactions on foreign keys are supported. For more detailed information and examples, see Section 13.1.18.5, “FOREIGN KEY Constraints”.
For other storage engines, MySQL Server parses and ignores theFOREIGN KEYsyntax inCREATE TABLE statements.
Important
For users familiar with the ANSI/ISO SQL Standard, please note that no storage engine, includingInnoDB, recognizes or enforces theMATCHclause used in referential integrity constraint definitions. Use of an explicitMATCHclause does not have the specified effect, and also causesON DELETEandON UPDATEclauses to be ignored. For these reasons, specifyingMATCHshould be avoided.
TheMATCHclause in the SQL standard controls howNULLvalues in a composite (multiple-column) foreign key are handled when comparing to a primary key.InnoDBessentially implements the semantics defined byMATCH SIMPLE, which permit a foreign key to be all or partiallyNULL. In that case, the (child table) row containing such a foreign key is permitted to be inserted, and does not match any row in the referenced (parent) table. It is possible to implement other semantics using triggers.
Additionally, MySQL requires that the referenced columns be indexed for performance. However,InnoDBdoes not enforce any requirement that the referenced columns be declaredUNIQUEorNOT NULL. The handling of foreign key references to nonunique keys or keys that containNULLvalues is not well defined for operations such asUPDATEorDELETE CASCADE. You are advised to use foreign keys that reference only keys that are bothUNIQUE(orPRIMARY) andNOT NULL.
MySQL parses but ignores “inlineREFERENCESspecifications” (as defined in the SQL standard) where the references are defined as part of the column specification. MySQL acceptsREFERENCESclauses only when specified as part of a separateFOREIGN KEYspecification. For more information, seeSection 1.6.2.3, “FOREIGN KEY Constraint Differences”._`referenceoption`_
For information about theRESTRICT,CASCADE,SET NULL,NO ACTION, andSET DEFAULToptions, seeSection 13.1.18.5, “FOREIGN KEY Constraints”.
Table Options
Table options are used to optimize the behavior of the table. In most cases, you do not have to specify any of them. These options apply to all storage engines unless otherwise indicated. Options that do not apply to a given storage engine may be accepted and remembered as part of the table definition. Such options then apply if you later use ALTER TABLE to convert the table to use a different storage engine.
ENGINE
Specifies the storage engine for the table, using one of the names shown in the following table. The engine name can be unquoted or quoted. The quoted name'DEFAULT'is recognized but ignored.Storage Engine Description InnoDB Transaction-safe tables with row locking and foreign keys. The default storage engine for new tables. SeeChapter 14, The InnoDB Storage Engine, and in particular Section 14.1, “Introduction to InnoDB” if you have MySQL experience but are new toInnoDB. MyISAM The binary portable storage engine that is primarily used for read-only or read-mostly workloads. SeeSection 15.2, “The MyISAM Storage Engine”. MEMORY The data for this storage engine is stored only in memory. SeeSection 15.3, “The MEMORY Storage Engine”. CSV Tables that store rows in comma-separated values format. SeeSection 15.4, “The CSV Storage Engine”. ARCHIVE The archiving storage engine. SeeSection 15.5, “The ARCHIVE Storage Engine”. EXAMPLE An example engine. See Section 15.9, “The EXAMPLE Storage Engine”. FEDERATED Storage engine that accesses remote tables. SeeSection 15.8, “The FEDERATED Storage Engine”. HEAP This is a synonym for MEMORY. MERGE A collection of MyISAM tables used as one table. Also known as MRG_MyISAM. SeeSection 15.7, “The MERGE Storage Engine”. NDB Clustered, fault-tolerant, memory-based tables, supporting transactions and foreign keys. Also known asNDBCLUSTER. SeeChapter 21, MySQL NDB Cluster 7.5 and NDB Cluster 7.6. By default, if a storage engine is specified that is not available, the statement fails with an error. You can override this behavior by removingNO_ENGINE_SUBSTITUTION from the server SQL mode (see Section 5.1.10, “Server SQL Modes”) so that MySQL allows substitution of the specified engine with the default storage engine instead. Normally in such cases, this is InnoDB, which is the default value for the default_storage_engine system variable. WhenNO_ENGINE_SUBSTITUTIONis disabled, a warning occurs if the storage engine specification is not honored.AUTO_INCREMENT
The initialAUTO_INCREMENTvalue for the table. In MySQL 5.7, this works forMyISAM,MEMORY,InnoDB, andARCHIVEtables. To set the first auto-increment value for engines that do not support theAUTO_INCREMENTtable option, insert a “dummy” row with a value one less than the desired value after creating the table, and then delete the dummy row.
For engines that support theAUTO_INCREMENTtable option in CREATE TABLE statements, you can also useALTER TABLE_`tblname`_ AUTO_INCREMENT =_`N`_to reset theAUTO_INCREMENTvalue. The value cannot be set lower than the maximum value currently in the column.AVG_ROW_LENGTH
An approximation of the average row length for your table. You need to set this only for large tables with variable-size rows.
When you create aMyISAMtable, MySQL uses the product of theMAX_ROWSandAVG_ROW_LENGTHoptions to decide how big the resulting table is. If you don't specify either option, the maximum size forMyISAMdata and index files is 256TB by default. (If your operating system does not support files that large, table sizes are constrained by the file size limit.) If you want to keep down the pointer sizes to make the index smaller and faster and you don't really need big files, you can decrease the default pointer size by setting themyisam_data_pointer_size system variable. (SeeSection 5.1.7, “Server System Variables”.) If you want all your tables to be able to grow above the default limit and are willing to have your tables slightly slower and larger than necessary, you can increase the default pointer size by setting this variable. Setting the value to 7 permits table sizes up to 65,536TB.[DEFAULT] CHARACTER SET
Specifies a default character set for the table.CHARSETis a synonym forCHARACTER SET. If the character set name isDEFAULT, the database character set is used.CHECKSUM
Set this to 1 if you want MySQL to maintain a live checksum for all rows (that is, a checksum that MySQL updates automatically as the table changes). This makes the table a little slower to update, but also makes it easier to find corrupted tables. The CHECKSUM TABLE statement reports the checksum. (MyISAMonly.)[DEFAULT] COLLATE
Specifies a default collation for the table.COMMENT
A comment for the table, up to 2048 characters long.
You can set theInnoDBMERGE_THRESHOLDvalue for a table using the_`tableoption`_COMMENTclause. SeeSection 14.8.12, “Configuring the Merge Threshold for Index Pages”.
Setting NDB_TABLE options. In MySQL NDB Cluster 7.5.2 and later, the table comment in aCREATE TABLEorALTER TABLE statement can also be used to specify one to four of theNDB_TABLEoptionsNOLOGGING,READ_BACKUP,PARTITION_BALANCE, orFULLY_REPLICATEDas a set of name-value pairs, separated by commas if need be, immediately following the stringNDB_TABLE=that begins the quoted comment text. An example statement using this syntax is shown here (emphasized text):
CREATE TABLE t1 (
c1 INT NOT NULL AUTO_INCREMENT PRIMARY KEY,
c2 VARCHAR(100),
c3 VARCHAR(100) )
ENGINE=NDB
COMMENT="NDB_TABLE=READ_BACKUP=0,PARTITION_BALANCE=FOR_RP_BY_NODE"; Spaces are not permitted within the quoted string. The string is case-insensitive.
The comment is displayed as part of the ouput ofSHOW CREATE TABLE. The text of the comment is also available as the TABLE_COMMENT column of the MySQL Information SchemaTABLES table.
This comment syntax is also supported withALTER TABLE statements forNDB tables. Keep in mind that a table comment used with ALTER TABLE replaces any existing comment which the table might have had perviously.
Setting the MERGE_THRESHOLD option in table comments is not supported for NDB tables (it is ignored).
For complete syntax information and examples, seeSection 13.1.18.9, “Setting NDB Comment Options”.
COMPRESSION
The compression algorithm used for page level compression forInnoDBtables. Supported values includeZlib,LZ4, andNone. TheCOMPRESSIONattribute was introduced with the transparent page compression feature. Page compression is only supported withInnoDBtables that reside infile-per-table tablespaces, and is only available on Linux and Windows platforms that support sparse files and hole punching. For more information, seeSection 14.9.2, “InnoDB Page Compression”.CONNECTION
The connection string for aFEDERATEDtable.
Note
Older versions of MySQL used aCOMMENToption for the connection string.DATA DIRECTORY,INDEX DIRECTORY
ForInnoDB, theDATA DIRECTORY='_`directory`_'clause permits creating a table outside of the data directory. The innodb_file_per_table variable must be enabled to use theDATA DIRECTORYclause. The full directory path must be specified. For more information, seeSection 14.6.1.2, “Creating Tables Externally”.
When creatingMyISAMtables, you can use theDATA DIRECTORY='_`directory`_'clause, theINDEX DIRECTORY='_`directory`_'clause, or both. They specify where to put aMyISAMtable's data file and index file, respectively. UnlikeInnoDBtables, MySQL does not create subdirectories that correspond to the database name when creating aMyISAMtable with aDATA DIRECTORYorINDEX DIRECTORYoption. Files are created in the directory that is specified.
As of MySQL 5.7.17, you must have theFILE privilege to use theDATA DIRECTORYorINDEX DIRECTORYtable option.
Important
Table-levelDATA DIRECTORYandINDEX DIRECTORYoptions are ignored for partitioned tables. (Bug #32091)
These options work only when you are not using the--skip-symbolic-links option. Your operating system must also have a working, thread-saferealpath()call. SeeSection 8.12.3.2, “Using Symbolic Links for MyISAM Tables on Unix”, for more complete information.
If aMyISAMtable is created with noDATA DIRECTORYoption, the.MYDfile is created in the database directory. By default, ifMyISAMfinds an existing.MYDfile in this case, it overwrites it. The same applies to.MYIfiles for tables created with noINDEX DIRECTORYoption. To suppress this behavior, start the server with the--keep_files_on_create option, in which caseMyISAMdoes not overwrite existing files and returns an error instead.
If aMyISAMtable is created with aDATA DIRECTORYorINDEX DIRECTORYoption and an existing.MYDor.MYIfile is found, MyISAM always returns an error. It does not overwrite a file in the specified directory.
Important
You cannot use path names that contain the MySQL data directory withDATA DIRECTORYorINDEX DIRECTORY. This includes partitioned tables and individual table partitions. (See Bug #32167.)DELAY_KEY_WRITE
Set this to 1 if you want to delay key updates for the table until the table is closed. See the description of thedelay_key_write system variable in Section 5.1.7, “Server System Variables”. (MyISAMonly.)ENCRYPTION
Set theENCRYPTIONoption to'Y'to enable page-level data encryption for anInnoDBtable created in afile-per-table tablespace. Option values are not case-sensitive. TheENCRYPTIONoption was introduced with theInnoDBtablespace encryption feature; seeSection 14.14, “InnoDB Data-at-Rest Encryption”. Akeyringplugin must be installed and configured before encryption can be enabled.
TheENCRYPTIONoption is supported only by theInnoDBstorage engine; thus it works only if the default storage engine isInnoDB, or if theCREATE TABLEstatement also specifiesENGINE=InnoDB. Otherwise the statement is rejected withER_CHECK_NOT_IMPLEMENTED.INSERT_METHOD
If you want to insert data into aMERGEtable, you must specify withINSERT_METHODthe table into which the row should be inserted.INSERT_METHODis an option useful forMERGEtables only. Use a value ofFIRSTorLASTto have inserts go to the first or last table, or a value ofNOto prevent inserts. SeeSection 15.7, “The MERGE Storage Engine”.KEY_BLOCK_SIZE
For MyISAM tables,KEY_BLOCK_SIZEoptionally specifies the size in bytes to use for index key blocks. The value is treated as a hint; a different size could be used if necessary. AKEY_BLOCK_SIZEvalue specified for an individual index definition overrides the table-levelKEY_BLOCK_SIZEvalue.
For InnoDB tables,KEY_BLOCK_SIZEspecifies thepage size in kilobytes to use for compressedInnoDBtables. TheKEY_BLOCK_SIZEvalue is treated as a hint; a different size could be used byInnoDBif necessary.KEY_BLOCK_SIZEcan only be less than or equal to theinnodb_page_size value. A value of 0 represents the default compressed page size, which is half of theinnodb_page_size value. Depending oninnodb_page_size, possibleKEY_BLOCK_SIZEvalues include 0, 1, 2, 4, 8, and 16. See Section 14.9.1, “InnoDB Table Compression” for more information.
Oracle recommends enablinginnodb_strict_mode when specifyingKEY_BLOCK_SIZEforInnoDBtables. Wheninnodb_strict_mode is enabled, specifying an invalidKEY_BLOCK_SIZEvalue returns an error. Ifinnodb_strict_mode is disabled, an invalidKEY_BLOCK_SIZEvalue results in a warning, and theKEY_BLOCK_SIZEoption is ignored.
TheCreate_optionscolumn in response toSHOW TABLE STATUS reports the originally specifiedKEY_BLOCK_SIZEoption, as does SHOW CREATE TABLE.InnoDBonly supportsKEY_BLOCK_SIZEat the table level.KEY_BLOCK_SIZEis not supported with 32KB and 64KB innodb_page_size values.InnoDBtable compression does not support these pages sizes.MAX_ROWS
The maximum number of rows you plan to store in the table. This is not a hard limit, but rather a hint to the storage engine that the table must be able to store at least this many rows.
Important
The use ofMAX_ROWSwithNDBtables to control the number of table partitions is deprecated as of NDB Cluster 7.5.4. It remains supported in later versions for backward compatibility, but is subject to removal in a future release. Use PARTITION_BALANCE instead; seeSetting NDB_TABLE options.
The NDB storage engine treats this value as a maximum. If you plan to create very large NDB Cluster tables (containing millions of rows), you should use this option to insure that NDB allocates sufficient number of index slots in the hash table used for storing hashes of the table's primary keys by settingMAX_ROWS = 2 *_`rows`_, where_rows_ is the number of rows that you expect to insert into the table.
The maximumMAX_ROWSvalue is 4294967295; larger values are truncated to this limit.MIN_ROWS
The minimum number of rows you plan to store in the table. TheMEMORY storage engine uses this option as a hint about memory use.PACK_KEYS
Takes effect only withMyISAMtables. Set this option to 1 if you want to have smaller indexes. This usually makes updates slower and reads faster. Setting the option to 0 disables all packing of keys. Setting it toDEFAULTtells the storage engine to pack only long CHAR,VARCHAR,BINARY, orVARBINARY columns.
If you do not usePACK_KEYS, the default is to pack strings, but not numbers. If you usePACK_KEYS=1, numbers are packed as well.
When packing binary number keys, MySQL uses prefix compression:- Every key needs one extra byte to indicate how many bytes of the previous key are the same for the next key.
- The pointer to the row is stored in high-byte-first order directly after the key, to improve compression.
This means that if you have many equal keys on two consecutive rows, all following “same” keys usually only take two bytes (including the pointer to the row). Compare this to the ordinary case where the following keys takesstorage_size_for_key + pointer_size(where the pointer size is usually 4). Conversely, you get a significant benefit from prefix compression only if you have many numbers that are the same. If all keys are totally different, you use one byte more per key, if the key is not a key that can haveNULLvalues. (In this case, the packed key length is stored in the same byte that is used to mark if a key isNULL.)
PASSWORD
This option is unused. If you have a need to scramble your.frmfiles and make them unusable to any other MySQL server, please contact our sales department.ROW_FORMAT
Defines the physical format in which the rows are stored.
When creating a table withstrict mode disabled, the storage engine's default row format is used if the specified row format is not supported. The actual row format of the table is reported in theRow_formatcolumn in response to SHOW TABLE STATUS. TheCreate_optionscolumn shows the row format that was specified in theCREATE TABLE statement, as doesSHOW CREATE TABLE.
Row format choices differ depending on the storage engine used for the table.
ForInnoDBtables:- The default row format is defined byinnodb_default_row_format, which has a default setting of
DYNAMIC. The default row format is used when theROW_FORMAToption is not defined or whenROW_FORMAT=DEFAULTis used.
If theROW_FORMAToption is not defined, or ifROW_FORMAT=DEFAULTis used, operations that rebuild a table also silently change the row format of the table to the default defined byinnodb_default_row_format. For more information, seeDefining the Row Format of a Table. - For more efficient
InnoDBstorage of data types, especially BLOB types, use theDYNAMIC. SeeDYNAMIC Row Format for requirements associated with theDYNAMICrow format. - To enable compression for
InnoDBtables, specifyROW_FORMAT=COMPRESSED. See Section 14.9, “InnoDB Table and Page Compression” for requirements associated with theCOMPRESSEDrow format. - The row format used in older versions of MySQL can still be requested by specifying the
REDUNDANTrow format. - When you specify a non-default
ROW_FORMATclause, consider also enabling theinnodb_strict_mode configuration option. ROW_FORMAT=FIXEDis not supported. IfROW_FORMAT=FIXEDis specified whileinnodb_strict_mode is disabled,InnoDBissues a warning and assumesROW_FORMAT=DYNAMIC. IfROW_FORMAT=FIXEDis specified whileinnodb_strict_mode is enabled, which is the default,InnoDBreturns an error.- For additional information about
InnoDBrow formats, see Section 14.11, “InnoDB Row Formats”.
ForMyISAMtables, the option value can beFIXEDorDYNAMICfor static or variable-length row format.myisampack sets the type toCOMPRESSED. SeeSection 15.2.3, “MyISAM Table Storage Formats”.
For NDB tables, the defaultROW_FORMATin MySQL NDB Cluster 7.5.1 and later isDYNAMIC. (Previously, it wasFIXED.)
- The default row format is defined byinnodb_default_row_format, which has a default setting of
STATS_AUTO_RECALC
Specifies whether to automatically recalculatepersistent statistics for anInnoDBtable. The valueDEFAULTcauses the persistent statistics setting for the table to be determined by theinnodb_stats_auto_recalc configuration option. The value1causes statistics to be recalculated when 10% of the data in the table has changed. The value0prevents automatic recalculation for this table; with this setting, issue an ANALYZE TABLE statement to recalculate the statistics after making substantial changes to the table. For more information about the persistent statistics feature, seeSection 14.8.11.1, “Configuring Persistent Optimizer Statistics Parameters”.STATS_PERSISTENT
Specifies whether to enablepersistent statistics for anInnoDBtable. The valueDEFAULTcauses the persistent statistics setting for the table to be determined by theinnodb_stats_persistent configuration option. The value1enables persistent statistics for the table, while the value0turns off this feature. After enabling persistent statistics through aCREATE TABLEorALTER TABLEstatement, issue an ANALYZE TABLE statement to calculate the statistics, after loading representative data into the table. For more information about the persistent statistics feature, seeSection 14.8.11.1, “Configuring Persistent Optimizer Statistics Parameters”.STATS_SAMPLE_PAGES
The number of index pages to sample when estimating cardinality and other statistics for an indexed column, such as those calculated by ANALYZE TABLE. For more information, seeSection 14.8.11.1, “Configuring Persistent Optimizer Statistics Parameters”.TABLESPACE
TheTABLESPACEclause can be used to create an InnoDB table in an existing general tablespace, a file-per-table tablespace, or the system tablespace.
CREATE TABLE tbl_name ... TABLESPACE [=] tablespace_name The general tablespace that you specify must exist prior to using the TABLESPACE clause. For information about general tablespaces, seeSection 14.6.3.3, “General Tablespaces”.
The_`tablespacename`_ is a case-sensitive identifier. It may be quoted or unquoted. The forward slash character (“/”) is not permitted. Names beginning with “innodb_” are reserved for special use.
To create a table in the system tablespace, specifyinnodb_system as the tablespace name.
CREATE TABLE tbl_name ... TABLESPACE [=] innodb_system Using TABLESPACE [=] innodb_system, you can place a table of any uncompressed row format in the system tablespace regardless of theinnodb_file_per_table setting. For example, you can add a table withROW_FORMAT=DYNAMIC to the system tablespace using TABLESPACE [=] innodb_system.
To create a table in a file-per-table tablespace, specifyinnodb_file_per_table as the tablespace name.
CREATE TABLE tbl_name ... TABLESPACE [=] innodb_file_per_table Note
If innodb_file_per_table is enabled, you need not specifyTABLESPACE=innodb_file_per_table to create an InnoDB file-per-table tablespace. InnoDB tables are created in file-per-table tablespaces by default wheninnodb_file_per_table is enabled.
Note
Support for creating table partitions in sharedInnoDB tablespaces is deprecated in MySQL 5.7.24; expect it to be removed in a future version of MySQL. Shared tablespaces include theInnoDB system tablespace and general tablespaces.
The DATA DIRECTORY clause is permitted withCREATE TABLE ... TABLESPACE=innodb_file_per_table but is otherwise not supported for use in combination with theTABLESPACE option.
Note
Support for TABLESPACE = innodb_file_per_table and TABLESPACE = innodb_temporary clauses withCREATE TEMPORARY TABLE is deprecated as of MySQL 5.7.24; expect it to be removed in a future version of MySQL.
The STORAGE table option is employed only with NDB tables.STORAGE determines the type of storage used, and can be either of DISK orMEMORY.TABLESPACE ... STORAGE DISK assigns a table to an NDB Cluster Disk Data tablespace. STORAGE DISK cannot be used in CREATE TABLE unless preceded byTABLESPACE tablespacename.
For STORAGE MEMORY, the tablespace name is optional, thus, you can use TABLESPACE_`tablespacename`_ STORAGE MEMORY or simply STORAGE MEMORY to specify explicitly that the table is in-memory.
See Section 21.6.11, “NDB Cluster Disk Data Tables”, for more information.
- UNION
Used to access a collection of identicalMyISAMtables as one. This works only withMERGEtables. SeeSection 15.7, “The MERGE Storage Engine”.
You must have SELECT,UPDATE, andDELETE privileges for the tables you map to aMERGEtable.
Note
Formerly, all tables used had to be in the same database as theMERGEtable itself. This restriction no longer applies.
Table Partitioning
partitionoptions can be used to control partitioning of the table created withCREATE TABLE.
Not all options shown in the syntax for_partitionoptions_ at the beginning of this section are available for all partitioning types. Please see the listings for the following individual types for information specific to each type, and see Chapter 22, Partitioning, for more complete information about the workings of and uses for partitioning in MySQL, as well as additional examples of table creation and other statements relating to MySQL partitioning.
Partitions can be modified, merged, added to tables, and dropped from tables. For basic information about the MySQL statements to accomplish these tasks, see Section 13.1.8, “ALTER TABLE Statement”. For more detailed descriptions and examples, seeSection 22.3, “Partition Management”.
PARTITION BY
If used, apartitionoptionsclause begins withPARTITION BY. This clause contains the function that is used to determine the partition; the function returns an integer value ranging from 1 to_num, wherenum_ is the number of partitions. (The maximum number of user-defined partitions which a table may contain is 1024; the number of subpartitions—discussed later in this section—is included in this maximum.)
Note
The expression (expr) used in aPARTITION BYclause cannot refer to any columns not in the table being created; such references are specifically not permitted and cause the statement to fail with an error. (Bug #29444)HASH(_`expr`_)
Hashes one or more columns to create a key for placing and locating rows.expris an expression using one or more table columns. This can be any valid MySQL expression (including MySQL functions) that yields a single integer value. For example, these are both validCREATE TABLE statements usingPARTITION BY HASH:
CREATE TABLE t1 (col1 INT, col2 CHAR(5))
PARTITION BY HASH(col1);
CREATE TABLE t1 (col1 INT, col2 CHAR(5), col3 DATETIME)
PARTITION BY HASH ( YEAR(col3) ); You may not use either VALUES LESS THAN orVALUES IN clauses with PARTITION BY HASH.PARTITION BY HASH uses the remainder of_expr_ divided by the number of partitions (that is, the modulus). For examples and additional information, see Section 22.2.4, “HASH Partitioning”.
The LINEAR keyword entails a somewhat different algorithm. In this case, the number of the partition in which a row is stored is calculated as the result of one or more logical AND operations. For discussion and examples of linear hashing, seeSection 22.2.4.1, “LINEAR HASH Partitioning”.
KEY(_`columnlist`_)
This is similar toHASH, except that MySQL supplies the hashing function so as to guarantee an even data distribution. Thecolumnlistargument is simply a list of 1 or more table columns (maximum: 16). This example shows a simple table partitioned by key, with 4 partitions:
CREATE TABLE tk (col1 INT, col2 CHAR(5), col3 DATE)
PARTITION BY KEY(col3)
PARTITIONS 4; For tables that are partitioned by key, you can employ linear partitioning by using the LINEAR keyword. This has the same effect as with tables that are partitioned by HASH. That is, the partition number is found using the& operator rather than the modulus (seeSection 22.2.4.1, “LINEAR HASH Partitioning”, andSection 22.2.5, “KEY Partitioning”, for details). This example uses linear partitioning by key to distribute data between 5 partitions:
CREATE TABLE tk (col1 INT, col2 CHAR(5), col3 DATE)
PARTITION BY LINEAR KEY(col3)
PARTITIONS 5; The ALGORITHM={1 | 2} option is supported with [SUB]PARTITION BY [LINEAR] KEY.ALGORITHM=1 causes the server to use the same key-hashing functions as MySQL 5.1;ALGORITHM=2 means that the server employs the key-hashing functions used by default for newKEY partitioned tables in MySQL 5.7 and later. Not specifying the option has the same effect as usingALGORITHM=2. This option is intended for use chiefly when upgrading [LINEAR] KEY partitioned tables from MySQL 5.1 to later MySQL versions. For more information, seeSection 13.1.8.1, “ALTER TABLE Partition Operations”.
mysqldump writes this option encased in versioned comments, like this:
CREATE TABLE t1 (a INT)
/*!50100 PARTITION BY KEY */ /*!50611 ALGORITHM = 1 */ /*!50100 ()
PARTITIONS 3 */ This causes MySQL 5.6.10 and earlier servers to ignore the option, which would otherwise cause a syntax error in those versions.ALGORITHM=1 is shown when necessary in the output of SHOW CREATE TABLE using versioned comments in the same manner asmysqldump. ALGORITHM=2 is always omitted from SHOW CREATE TABLE output, even if this option was specified when creating the original table.
You may not use either VALUES LESS THAN orVALUES IN clauses with PARTITION BY KEY.
RANGE(_`expr`_)
In this case,exprshows a range of values using a set ofVALUES LESS THANoperators. When using range partitioning, you must define at least one partition usingVALUES LESS THAN. You cannot useVALUES INwith range partitioning.
Note
For tables partitioned byRANGE,VALUES LESS THANmust be used with either an integer literal value or an expression that evaluates to a single integer value. In MySQL 5.7, you can overcome this limitation in a table that is defined usingPARTITION BY RANGE COLUMNS, as described later in this section.
Suppose that you have a table that you wish to partition on a column containing year values, according to the following scheme.Partition Number: Years Range: 0 1990 and earlier 1 1991 to 1994 2 1995 to 1998 3 1999 to 2002 4 2003 to 2005 5 2006 and later A table implementing such a partitioning scheme can be realized by the CREATE TABLE statement shown here:
CREATE TABLE t1 (
year_col INT,
some_data INT
)
PARTITION BY RANGE (year_col) (
PARTITION p0 VALUES LESS THAN (1991),
PARTITION p1 VALUES LESS THAN (1995),
PARTITION p2 VALUES LESS THAN (1999),
PARTITION p3 VALUES LESS THAN (2002),
PARTITION p4 VALUES LESS THAN (2006),
PARTITION p5 VALUES LESS THAN MAXVALUE
); PARTITION ... VALUES LESS THAN ... statements work in a consecutive fashion. VALUES LESS THAN MAXVALUE works to specify“leftover” values that are greater than the maximum value otherwise specified.VALUES LESS THAN clauses work sequentially in a manner similar to that of the case portions of a switch ... case block (as found in many programming languages such as C, Java, and PHP). That is, the clauses must be arranged in such a way that the upper limit specified in each successive VALUES LESS THAN is greater than that of the previous one, with the one referencing MAXVALUE coming last of all in the list.
RANGE COLUMNS(_`columnlist`_)
This variant onRANGEfacilitates partition pruning for queries using range conditions on multiple columns (that is, having conditions such asWHERE a = 1 AND b < 10orWHERE a = 1 AND b = 10 AND c < 10). It enables you to specify value ranges in multiple columns by using a list of columns in theCOLUMNSclause and a set of column values in eachPARTITION ... VALUES LESS THAN (_`valuelist`_)partition definition clause. (In the simplest case, this set consists of a single column.) The maximum number of columns that can be referenced in thecolumnlistand_valuelist_ is 16.
Thecolumnlistused in theCOLUMNSclause may contain only names of columns; each column in the list must be one of the following MySQL data types: the integer types; the string types; and time or date column types. Columns usingBLOB,TEXT,SET,ENUM,BIT, or spatial data types are not permitted; columns that use floating-point number types are also not permitted. You also may not use functions or arithmetic expressions in theCOLUMNSclause.
TheVALUES LESS THANclause used in a partition definition must specify a literal value for each column that appears in theCOLUMNS()clause; that is, the list of values used for eachVALUES LESS THANclause must contain the same number of values as there are columns listed in theCOLUMNSclause. An attempt to use more or fewer values in aVALUES LESS THANclause than there are in theCOLUMNSclause causes the statement to fail with the error Inconsistency in usage of column lists for partitioning.... You cannot useNULLfor any value appearing inVALUES LESS THAN. It is possible to useMAXVALUEmore than once for a given column other than the first, as shown in this example:
CREATE TABLE rc (
a INT NOT NULL,
b INT NOT NULL
)
PARTITION BY RANGE COLUMNS(a,b) (
PARTITION p0 VALUES LESS THAN (10,5),
PARTITION p1 VALUES LESS THAN (20,10),
PARTITION p2 VALUES LESS THAN (50,MAXVALUE),
PARTITION p3 VALUES LESS THAN (65,MAXVALUE),
PARTITION p4 VALUES LESS THAN (MAXVALUE,MAXVALUE)
); Each value used in a VALUES LESS THAN value list must match the type of the corresponding column exactly; no conversion is made. For example, you cannot use the string'1' for a value that matches a column that uses an integer type (you must use the numeral1 instead), nor can you use the numeral1 for a value that matches a column that uses a string type (in such a case, you must use a quoted string: '1').
For more information, seeSection 22.2.1, “RANGE Partitioning”, andSection 22.4, “Partition Pruning”.
LIST(_`expr`_)
This is useful when assigning partitions based on a table column with a restricted set of possible values, such as a state or country code. In such a case, all rows pertaining to a certain state or country can be assigned to a single partition, or a partition can be reserved for a certain set of states or countries. It is similar toRANGE, except that onlyVALUES INmay be used to specify permissible values for each partition.VALUES INis used with a list of values to be matched. For instance, you could create a partitioning scheme such as the following:
CREATE TABLE client_firms (
id INT,
name VARCHAR(35)
)
PARTITION BY LIST (id) (
PARTITION r0 VALUES IN (1, 5, 9, 13, 17, 21),
PARTITION r1 VALUES IN (2, 6, 10, 14, 18, 22),
PARTITION r2 VALUES IN (3, 7, 11, 15, 19, 23),
PARTITION r3 VALUES IN (4, 8, 12, 16, 20, 24)
); When using list partitioning, you must define at least one partition using VALUES IN. You cannot useVALUES LESS THAN with PARTITION BY LIST.
Note
For tables partitioned by LIST, the value list used with VALUES IN must consist of integer values only. In MySQL 5.7, you can overcome this limitation using partitioning by LIST COLUMNS, which is described later in this section.
LIST COLUMNS(_`columnlist`_)
This variant onLISTfacilitates partition pruning for queries using comparison conditions on multiple columns (that is, having conditions such asWHERE a = 5 AND b = 5orWHERE a = 1 AND b = 10 AND c = 5). It enables you to specify values in multiple columns by using a list of columns in theCOLUMNSclause and a set of column values in eachPARTITION ... VALUES IN (_`valuelist`_)partition definition clause.
The rules governing regarding data types for the column list used inLIST COLUMNS(_`columnlist`_)and the value list used inVALUES IN(_`valuelist`_)are the same as those for the column list used inRANGE COLUMNS(_`columnlist`_)and the value list used inVALUES LESS THAN(_`valuelist`_), respectively, except that in theVALUES INclause,MAXVALUEis not permitted, and you may useNULL.
There is one important difference between the list of values used forVALUES INwithPARTITION BY LIST COLUMNSas opposed to when it is used withPARTITION BY LIST. When used withPARTITION BY LIST COLUMNS, each element in theVALUES INclause must be a_set_ of column values; the number of values in each set must be the same as the number of columns used in theCOLUMNSclause, and the data types of these values must match those of the columns (and occur in the same order). In the simplest case, the set consists of a single column. The maximum number of columns that can be used in thecolumnlistand in the elements making up the_valuelist_ is 16.
The table defined by the followingCREATE TABLEstatement provides an example of a table usingLIST COLUMNSpartitioning:
CREATE TABLE lc (
a INT NULL,
b INT NULL
)
PARTITION BY LIST COLUMNS(a,b) (
PARTITION p0 VALUES IN( (0,0), (NULL,NULL) ),
PARTITION p1 VALUES IN( (0,1), (0,2), (0,3), (1,1), (1,2) ),
PARTITION p2 VALUES IN( (1,0), (2,0), (2,1), (3,0), (3,1) ),
PARTITION p3 VALUES IN( (1,3), (2,2), (2,3), (3,2), (3,3) )
); PARTITIONS _`num`_
The number of partitions may optionally be specified with aPARTITIONS _`num`_clause, wherenumis the number of partitions. If both this clause and anyPARTITIONclauses are used,nummust be equal to the total number of any partitions that are declared usingPARTITIONclauses.
Note
Whether or not you use aPARTITIONSclause in creating a table that is partitioned byRANGEorLIST, you must still include at least onePARTITION VALUESclause in the table definition (see below).SUBPARTITION BY
A partition may optionally be divided into a number of subpartitions. This can be indicated by using the optionalSUBPARTITION BYclause. Subpartitioning may be done byHASHorKEY. Either of these may beLINEAR. These work in the same way as previously described for the equivalent partitioning types. (It is not possible to subpartition byLISTorRANGE.)
The number of subpartitions can be indicated using theSUBPARTITIONSkeyword followed by an integer value.- Rigorous checking of the value used in
PARTITIONSorSUBPARTITIONSclauses is applied and this value must adhere to the following rules:- The value must be a positive, nonzero integer.
- No leading zeros are permitted.
- The value must be an integer literal, and cannot not be an expression. For example,
PARTITIONS 0.2E+01is not permitted, even though0.2E+01evaluates to2. (Bug #15890)
_`partitiondefinition`_
Each partition may be individually defined using a_partitiondefinition_ clause. The individual parts making up this clause are as follows:PARTITION_`partitionname`_
Specifies a logical name for the partition.VALUES
For range partitioning, each partition must include aVALUES LESS THANclause; for list partitioning, you must specify aVALUES INclause for each partition. This is used to determine which rows are to be stored in this partition. See the discussions of partitioning types inChapter 22, Partitioning, for syntax examples.[STORAGE] ENGINE
The partitioning handler accepts a[STORAGE] ENGINEoption for bothPARTITIONandSUBPARTITION. Currently, the only way in which this can be used is to set all partitions or all subpartitions to the same storage engine, and an attempt to set different storage engines for partitions or subpartitions in the same table raises the errorERROR 1469 (HY000): The mix of handlers in the partitions is not permitted in this version of MySQL. We expect to lift this restriction on partitioning in a future MySQL release.COMMENT
An optionalCOMMENTclause may be used to specify a string that describes the partition. Example:
COMMENT = 'Data for the years previous to 1999'The maximum length for a partition comment is 1024 characters.
DATA DIRECTORYandINDEX DIRECTORY
DATA DIRECTORYandINDEX DIRECTORYmay be used to indicate the directory where, respectively, the data and indexes for this partition are to be stored. Both the_`datadir`_and the_`indexdir`_must be absolute system path names.
As of MySQL 5.7.17, you must have theFILE privilege to use theDATA DIRECTORYorINDEX DIRECTORYpartition option.
Example:
CREATE TABLE th (id INT, name VARCHAR(30), adate DATE) PARTITION BY LIST(YEAR(adate)) ( PARTITION p1999 VALUES IN (1995, 1999, 2003) DATA DIRECTORY = '/var/appdata/95/data' INDEX DIRECTORY = '/var/appdata/95/idx', PARTITION p2000 VALUES IN (1996, 2000, 2004) DATA DIRECTORY = '/var/appdata/96/data' INDEX DIRECTORY = '/var/appdata/96/idx', PARTITION p2001 VALUES IN (1997, 2001, 2005) DATA DIRECTORY = '/var/appdata/97/data' INDEX DIRECTORY = '/var/appdata/97/idx', PARTITION p2002 VALUES IN (1998, 2002, 2006) DATA DIRECTORY = '/var/appdata/98/data' INDEX DIRECTORY = '/var/appdata/98/idx' );DATA DIRECTORYandINDEX DIRECTORYbehave in the same way as in theCREATE TABLE statement's_tableoption_ clause as used forMyISAMtables.
One data directory and one index directory may be specified per partition. If left unspecified, the data and indexes are stored by default in the table's database directory.
On Windows, theDATA DIRECTORYandINDEX DIRECTORYoptions are not supported for individual partitions or subpartitions ofMyISAM tables, and theINDEX DIRECTORYoption is not supported for individual partitions or subpartitions ofInnoDB tables. These options are ignored on Windows, except that a warning is generated. (Bug #30459)
Note
TheDATA DIRECTORYandINDEX DIRECTORYoptions are ignored for creating partitioned tables ifNO_DIR_IN_CREATE is in effect. (Bug #24633)MAX_ROWSandMIN_ROWS
May be used to specify, respectively, the maximum and minimum number of rows to be stored in the partition. The values formaxnumberofrowsandminnumberofrowsmust be positive integers. As with the table-level options with the same names, these act only as“suggestions” to the server and are not hard limits.TABLESPACE
May be used to designate a tablespace for the partition. Supported by NDB Cluster. ForInnoDBtables, it may be used to designate a file-per-table tablespace for the partition by specifyingTABLESPACE `innodb_file_per_table`. All partitions must belong to the same storage engine.
Note
Support for placingInnoDBtable partitions in sharedInnoDBtablespaces is deprecated in MySQL 5.7.24; expect it to be removed in a future MySQL version. Shared tablespaces include theInnoDBsystem tablespace and general tablespaces.
_`subpartitiondefinition`_
The partition definition may optionally contain one or more_subpartitiondefinition_ clauses. Each of these consists at a minimum of theSUBPARTITION_`name`_, where_name_ is an identifier for the subpartition. Except for the replacement of thePARTITIONkeyword withSUBPARTITION, the syntax for a subpartition definition is identical to that for a partition definition.
Subpartitioning must be done byHASHorKEY, and can be done only onRANGEorLISTpartitions. See Section 22.2.6, “Subpartitioning”.
Partitioning by Generated Columns
Partitioning by generated columns is permitted. For example:
CREATE TABLE t1 (
s1 INT,
s2 INT AS (EXP(s1)) STORED
)
PARTITION BY LIST (s2) (
PARTITION p1 VALUES IN (1)
); Partitioning sees a generated column as a regular column, which enables workarounds for limitations on functions that are not permitted for partitioning (seeSection 22.6.3, “Partitioning Limitations Relating to Functions”). The preceding example demonstrates this technique:EXP() cannot be used directly in the PARTITION BY clause, but a generated column defined using EXP() is permitted.