13.1.10 CREATE TABLE Syntax



    { LIKE old_tbl_name | (LIKE old_tbl_name) }

    col_name column_definition
  | [CONSTRAINT [symbol]] PRIMARY KEY [index_type] (index_col_name,...)
  | {INDEX|KEY} [index_name] [index_type] (index_col_name,...)
        [index_name] [index_type] (index_col_name,...)
  | {FULLTEXT|SPATIAL} [INDEX|KEY] [index_name] (index_col_name,...)
        [index_name] (index_col_name,...) reference_definition
  | CHECK (expr)

    data_type [NOT NULL | NULL] [DEFAULT default_value]
      [COMMENT 'string'] [reference_definition]

  | INT[(length)] [UNSIGNED] [ZEROFILL]
  | REAL[(length,decimals)] [UNSIGNED] [ZEROFILL]
  | DOUBLE[(length,decimals)] [UNSIGNED] [ZEROFILL]
  | FLOAT[(length,decimals)] [UNSIGNED] [ZEROFILL]
  | DECIMAL[(length[,decimals])] [UNSIGNED] [ZEROFILL]
  | NUMERIC[(length[,decimals])] [UNSIGNED] [ZEROFILL]
  | DATE
  | TIME
  | YEAR
  | CHAR[(length)] [BINARY]
      [CHARACTER SET charset_name] [COLLATE collation_name]
  | VARCHAR(length) [BINARY]
      [CHARACTER SET charset_name] [COLLATE collation_name]
  | BINARY[(length)]
  | VARBINARY(length)
  | BLOB
      [CHARACTER SET charset_name] [COLLATE collation_name]
      [CHARACTER SET charset_name] [COLLATE collation_name]
      [CHARACTER SET charset_name] [COLLATE collation_name]
      [CHARACTER SET charset_name] [COLLATE collation_name]
  | ENUM(value1,value2,value3,...)
      [CHARACTER SET charset_name] [COLLATE collation_name]
  | SET(value1,value2,value3,...)
      [CHARACTER SET charset_name] [COLLATE collation_name]
  | spatial_type

    col_name [(length)] [ASC | DESC]


    REFERENCES tbl_name (index_col_name,...)
      [ON DELETE reference_option]
      [ON UPDATE reference_option]


    table_option [[,] table_option] ...

    {ENGINE|TYPE} [=] engine_name
  | AUTO_INCREMENT [=] value
  | AVG_ROW_LENGTH [=] value
  | [DEFAULT] CHARACTER SET [=] charset_name
  | CHECKSUM [=] {0 | 1}
  | [DEFAULT] COLLATE [=] collation_name
  | COMMENT [=] 'string'
  | CONNECTION [=] 'connect_string'
  | DATA DIRECTORY [=] 'absolute path to directory'
  | DELAY_KEY_WRITE [=] {0 | 1}
  | INDEX DIRECTORY [=] 'absolute path to directory'
  | MAX_ROWS [=] value
  | MIN_ROWS [=] value
  | PACK_KEYS [=] {0 | 1 | DEFAULT}
  | PASSWORD [=] 'string'
  | UNION [=] (tbl_name[,tbl_name]...)

    [IGNORE | REPLACE] [AS] SELECT ...   (Some legal select statement)

CREATE TABLE creates a table with the given name. You must have the CREATE privilege for the table.

Rules for permissible table names are given in Section 9.2, “Schema Object Names”. By default, the table is created in the default database. An error occurs if the table exists, if there is no default database, or if the database does not exist.

The table name can be specified as db_name.tbl_name 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`.

Cloning or Copying a Table

Use CREATE TABLE ... LIKE to 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, “CREATE TABLE ... LIKE Syntax”.

To create one table from another, add a SELECT statement at the end of the CREATE TABLE statement:

CREATE TABLE new_tbl SELECT * FROM orig_tbl;

For more information, see Section, “CREATE TABLE ... SELECT Syntax”.

Temporary Tables

You can use the TEMPORARY keyword when creating a table. A TEMPORARY table is visible only to the current session, and is dropped automatically when the session is closed. This means that two different sessions can use the same temporary table name without conflicting with each other or with an existing non-TEMPORARY table of the same name. (The existing table is hidden until the temporary table is dropped.) To create temporary tables, you must have the CREATE TEMPORARY TABLES privilege.


CREATE TABLE does not automatically commit the current active transaction if you use the TEMPORARY keyword.


TEMPORARY tables have a very loose relationship with databases (schemas). Dropping a database does not automatically drop any TEMPORARY tables created within that database. Also, you can create a TEMPORARY table in a nonexistent database if you qualify the table name with the database name in the CREATE TABLE statement. In this case, all subsequent references to the table must be qualified with the database name.

Existing Table with Same Name

The keywords IF NOT EXISTS prevent 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 the CREATE TABLE statement.

Physical Representation

MySQL represents each table by an .frm table format (definition) file in the database directory. The storage engine for the table might create other files as well.

For InnoDB tables, the file storage is controlled by the innodb_file_per_table configuration option. When this option is turned off, all InnoDB tables and indexes are stored in the system tablespace, represented by one or more ibdata* files. For each InnoDB table created when this option is turned on, the table data and all associated indexes are stored in a .ibd file located inside the database directory.

For MyISAM tables, the storage engine creates data and index files. Thus, for each MyISAM table tbl_name, there are three disk files.

tbl_name.frmTable format (definition) file
tbl_name.MYDData file
tbl_name.MYIIndex file

Chapter 14, Storage Engines, describes what files each storage engine creates to represent tables.

Data Types and Attributes for Columns

data_type represents the data type in a column definition. spatial_type represents a spatial data type. The data type syntax shown is representative only. For a full description of the syntax available for specifying column data types, as well as information about the properties of each type, see Chapter 11, Data Types, and Section 11.5, “Extensions for Spatial Data”.

Some attributes do not apply to all data types. AUTO_INCREMENT applies only to integer and floating-point types. DEFAULT does not apply to the BLOB or TEXT types.

  • If neither NULL nor NOT NULL is specified, the column is treated as though NULL had been specified.

  • An integer or floating-point column can have the additional attribute AUTO_INCREMENT. When you insert a value of NULL (recommended) or 0 into an indexed AUTO_INCREMENT column, 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_INCREMENT sequences begin with 1.

    To retrieve an AUTO_INCREMENT value after inserting a row, use the LAST_INSERT_ID() SQL function or the mysql_insert_id() C API function. See Section 12.13, “Information Functions”, and Section, “mysql_insert_id()”.

    If the NO_AUTO_VALUE_ON_ZERO SQL mode is enabled, you can store 0 in AUTO_INCREMENT columns as 0 without generating a new sequence value. See Section 5.1.7, “Server SQL Modes”.


    There can be only one AUTO_INCREMENT column per table, it must be indexed, and it cannot have a DEFAULT value. An AUTO_INCREMENT column 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 an AUTO_INCREMENT column that contains 0.

    For MyISAM and BDB tables, you can specify an AUTO_INCREMENT secondary column in a multiple-column key. See Section 3.6.9, “Using AUTO_INCREMENT”.

    To make MySQL compatible with some ODBC applications, you can find the AUTO_INCREMENT value for the last inserted row with the following query:

    SELECT * FROM tbl_name WHERE auto_col IS NULL

    For information about InnoDB and AUTO_INCREMENT, see Section, “AUTO_INCREMENT Handling in InnoDB”.

  • Character data types (CHAR, VARCHAR, TEXT) can include CHARACTER SET and COLLATE attributes to specify the character set and collation for the column. For details, see Section 10.1, “Character Set Support”. CHARSET is a synonym for CHARACTER SET. Example:

    CREATE TABLE t (c CHAR(20) CHARACTER SET utf8 COLLATE utf8_bin);

    MySQL 5.0 interprets length specifications in character column definitions in characters. Lengths for BINARY and VARBINARY are in bytes.

  • The DEFAULT clause specifies a default value for a column. With one exception, the default value must be a constant; it cannot be a function or an expression. This means, for example, that you cannot set the default for a date column to be the value of a function such as NOW() or CURRENT_DATE. The exception is that you can specify CURRENT_TIMESTAMP as the default for a TIMESTAMP column. See Section 11.3.5, “Automatic Initialization and Updating for TIMESTAMP”.

    If a column definition includes no explicit DEFAULT value, MySQL determines the default value as described in Section 11.6, “Data Type Default Values”.

    BLOB and TEXT columns cannot be assigned a default value.

    CREATE TABLE fails if a date-valued default is not correct according to the NO_ZERO_IN_DATE SQL mode, even if strict SQL mode is not enabled. For example, c1 DATE DEFAULT '2010-00-00' causes CREATE TABLE to fail with Invalid default value for 'c1'.

  • A comment for a column can be specified with the COMMENT option, up to 255 characters long. The comment is displayed by the SHOW CREATE TABLE and SHOW FULL COLUMNS statements.

  • KEY is normally a synonym for INDEX. The key attribute PRIMARY KEY can also be specified as just KEY when given in a column definition. This was implemented for compatibility with other database systems.

  • A UNIQUE index 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. This constraint does not apply to NULL values except for the BDB storage engine. For other engines, a UNIQUE index permits multiple NULL values for columns that can contain NULL.

  • A PRIMARY KEY is a unique index where all key columns must be defined as NOT NULL. If they are not explicitly declared as NOT NULL, MySQL declares them so implicitly (and silently). A table can have only one PRIMARY KEY. The name of a PRIMARY KEY is always PRIMARY, which thus cannot be used as the name for any other kind of index.

    If you do not have a PRIMARY KEY and an application asks for the PRIMARY KEY in your tables, MySQL returns the first UNIQUE index that has no NULL columns as the PRIMARY KEY.

    In InnoDB tables, having a long PRIMARY KEY wastes a lot of space. (See Section 14.2.10, “InnoDB Table and Index Structures”.)

  • In the created table, a PRIMARY KEY is placed first, followed by all UNIQUE indexes, and then the nonunique indexes. This helps the MySQL optimizer to prioritize which index to use and also more quickly to detect duplicated UNIQUE keys.

  • A PRIMARY KEY can be a multiple-column index. However, you cannot create a multiple-column index using the PRIMARY KEY key attribute in a column specification. Doing so only marks that single column as primary. You must use a separate PRIMARY KEY(index_col_name, ...) clause.

  • If a PRIMARY KEY or UNIQUE index consists of only one column that has an integer type, you can also refer to the column as _rowid in SELECT statements.

  • In MySQL, the name of a PRIMARY KEY is PRIMARY. 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 using SHOW INDEX FROM tbl_name. See Section, “SHOW INDEX Syntax”.

  • Some storage engines permit you to specify an index type when creating an index. The syntax for the index_type specifier is USING type_name.


    CREATE TABLE lookup
      (id INT, INDEX USING BTREE (id))

    Before MySQL 5.0.60, USING can be given only before the index column list. As of 5.0.60, the preferred position is after the column list. Support for use of the option before the column list will be removed in a future MySQL release.

    index_option values specify additional options for an index. USING is one such option. For details about permissible index_option values, see Section 13.1.8, “CREATE INDEX Syntax”.

    For more information about indexes, see Section 8.3.1, “How MySQL Uses Indexes”.

  • In MySQL 5.0, only the MyISAM, InnoDB, BDB, and MEMORY storage engines support indexes on columns that can have NULL values. In other cases, you must declare indexed columns as NOT NULL or an error results.

  • For CHAR, VARCHAR, BINARY, and VARBINARY columns, indexes can be created that use only the leading part of column values, using col_name(length) syntax to specify an index prefix length. BLOB and TEXT 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, and TEXT columns, and the first length bytes of each column value for BINARY, VARBINARY, and BLOB columns. Indexing only a prefix of column values like this can make the index file much smaller. See Section 8.3.4, “Column Indexes”.

    Only the MyISAM, BDB, and InnoDB storage engines support indexing on BLOB and TEXT columns. For example:

    CREATE TABLE test (blob_col BLOB, INDEX(blob_col(10)));

    Prefixes can be up to 1000 bytes long (767 bytes for InnoDB tables). Note that prefix limits are measured in bytes, whereas the prefix length in CREATE TABLE statements is interpreted as number of characters for nonbinary data types (CHAR, VARCHAR, TEXT). Take this into account when specifying a prefix length for a column that uses a multibyte character set.

  • An index_col_name specification can end with ASC or DESC. 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.

  • When you use ORDER BY or GROUP BY on a column in a SELECT, the server sorts values using only the initial number of bytes indicated by the max_sort_length system variable.

  • You can create special FULLTEXT indexes, which are used for full-text searches. Only the MyISAM storage engine supports FULLTEXT indexes. They can be created only from CHAR, VARCHAR, and TEXT columns. Indexing always happens over the entire column; column prefix indexing is not supported and any prefix length is ignored if specified. See Section 12.9, “Full-Text Search Functions”, for details of operation.

  • You can create SPATIAL indexes on spatial data types. Spatial types are supported only for MyISAM tables and indexed columns must be declared as NOT NULL. See Section 11.5, “Extensions for Spatial Data”.

  • InnoDB tables support checking of foreign key constraints. The columns of the referenced table must always be explicitly named. Both ON DELETE and ON UPDATE actions on foreign keys. For more detailed information and examples, see Section, “Using FOREIGN KEY Constraints”. For information specific to foreign keys in InnoDB, see Section, “InnoDB and FOREIGN KEY Constraints”.

    For other storage engines, MySQL Server parses and ignores the FOREIGN KEY and REFERENCES syntax in CREATE TABLE statements. The CHECK clause is parsed but ignored by all storage engines. See Section, “Foreign Key Differences”.


    For users familiar with the ANSI/ISO SQL Standard, please note that no storage engine, including InnoDB, recognizes or enforces the MATCH clause used in referential integrity constraint definitions. Use of an explicit MATCH clause will not have the specified effect, and also causes ON DELETE and ON UPDATE clauses to be ignored. For these reasons, specifying MATCH should be avoided.

    The MATCH clause in the SQL standard controls how NULL values in a composite (multiple-column) foreign key are handled when comparing to a primary key. InnoDB essentially implements the semantics defined by MATCH SIMPLE, which permit a foreign key to be all or partially NULL. 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, InnoDB does not enforce any requirement that the referenced columns be declared UNIQUE or NOT NULL. The handling of foreign key references to nonunique keys or keys that contain NULL values is not well defined for operations such as UPDATE or DELETE CASCADE. You are advised to use foreign keys that reference only keys that are both UNIQUE (or PRIMARY) and NOT NULL.

    MySQL parses but ignores inline REFERENCES specifications (as defined in the SQL standard) where the references are defined as part of the column specification. MySQL accepts REFERENCES clauses only when specified as part of a separate FOREIGN KEY specification.

  • 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 C.7.4, “Limits on Table Column Count and Row Size”.

Storage Engines

The ENGINE table option specifies the storage engine for the table. TYPE is a synonym, but ENGINE is the preferred option name.

The ENGINE table option 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 equivalent to specifying the default storage engine name.

Storage EngineDescription
ARCHIVEThe archiving storage engine. See Section 14.8, “The ARCHIVE Storage Engine”.
BDBTransaction-safe tables with page locking. Also known as BerkeleyDB. See Section 14.5, “The BDB (BerkeleyDB) Storage Engine”.
CSVTables that store rows in comma-separated values format. See Section 14.9, “The CSV Storage Engine”.
EXAMPLEAn example engine. See Section 14.6, “The EXAMPLE Storage Engine”.
FEDERATEDStorage engine that accesses remote tables. See Section 14.7, “The FEDERATED Storage Engine”.
HEAPThis is a synonym for MEMORY.
ISAM (OBSOLETE)Not available in MySQL 5.0. If you are upgrading to MySQL 5.0 from a previous version, you should convert any existing ISAM tables to MyISAM before performing the upgrade.
InnoDBTransaction-safe tables with row locking and foreign keys. See Section 14.2, “The InnoDB Storage Engine”.
MEMORYThe data for this storage engine is stored only in memory. See Section 14.4, “The MEMORY (HEAP) Storage Engine”.
MERGEA collection of MyISAM tables used as one table. Also known as MRG_MyISAM. See Section 14.3, “The MERGE Storage Engine”.
MyISAMThe binary portable storage engine that is the default storage engine used by MySQL. See Section 14.1, “The MyISAM Storage Engine”.
NDBCLUSTERClustered, fault-tolerant, memory-based tables. Also known as NDB. See Chapter 17, MySQL Cluster.

If a storage engine is specified that is not available, MySQL uses the default engine instead. Normally, this is MyISAM. For example, if a table definition includes the ENGINE=BDB option but the MySQL server does not support BDB tables, the table is created as a MyISAM table. This makes it possible to have a replication setup where you have transactional tables on the master but tables created on the slave are nontransactional (to get more speed). In MySQL 5.0, a warning occurs if the storage engine specification is not honored.

Engine substitution can be controlled by the setting of the NO_ENGINE_SUBSTITUTION SQL mode, as described in Section 5.1.7, “Server SQL Modes”.

Optimizing Performance

The other 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.


    The initial AUTO_INCREMENT value for the table. In MySQL 5.0, this works for MyISAM and MEMORY tables. It is also supported for InnoDB as of MySQL 5.0.3. To set the first auto-increment value for engines that do not support the AUTO_INCREMENT table 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 the AUTO_INCREMENT table option in CREATE TABLE statements, you can also use ALTER TABLE tbl_name AUTO_INCREMENT = N to reset the AUTO_INCREMENT value. The value cannot be set lower than the maximum value currently in the column.


    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 a MyISAM table, MySQL uses the product of the MAX_ROWS and AVG_ROW_LENGTH options to decide how big the resulting table is. If you don't specify either option, the maximum size for MyISAM data and index table files is 256TB of data by default (4GB before MySQL 5.0.6). (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 the myisam_data_pointer_size system variable, which was added in MySQL 4.1.2. (See Section 5.1.4, “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.


    Specify a default character set for the table. CHARSET is a synonym for CHARACTER SET. If the character set name is DEFAULT, the database character set is used.


    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. (MyISAM only.)


    Specify a default collation for the table.


    A comment for the table, up to 60 characters long.


    The connection string for a FEDERATED table. This option is available as of MySQL 5.0.13; before that, use a COMMENT option for the connection string.


    By using DATA DIRECTORY='directory' or INDEX DIRECTORY='directory' you can specify where the MyISAM storage engine should put a table's data file and index file. The directory must be the full path name to the directory, not a relative path.

    These options work only when you are not using the --skip-symbolic-links option. Your operating system must also have a working, thread-safe realpath() call. See Section, “Using Symbolic Links for MyISAM Tables on Unix”, for more complete information.

    If a MyISAM table is created with no DATA DIRECTORY option, the .MYD file is created in the database directory. By default, if MyISAM finds an existing .MYD file in this case, it overwrites it. The same applies to .MYI files for tables created with no INDEX DIRECTORY option. As of MySQL 5.0.48, to suppress this behavior, start the server with the --keep_files_on_create option, in which case MyISAM will not overwrite existing files and returns an error instead.

    If a MyISAM table is created with a DATA DIRECTORY or INDEX DIRECTORY option and an existing .MYD or .MYI file is found, MyISAM always returns an error. It will not overwrite a file in the specified directory.


    Beginning with MySQL 5.0.60, you cannot use path names that contain the MySQL data directory with DATA DIRECTORY or INDEX DIRECTORY. (See Bug #32167.)


    Set this to 1 if you want to delay key updates for the table until the table is closed. See the description of the delay_key_write system variable in Section 5.1.4, “Server System Variables”. (MyISAM only.)


    If you want to insert data into a MERGE table, you must specify with INSERT_METHOD the table into which the row should be inserted. INSERT_METHOD is an option useful for MERGE tables only. Use a value of FIRST or LAST to have inserts go to the first or last table, or a value of NO to prevent inserts. See Section 14.3, “The MERGE Storage Engine”.


    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.

    The NDB storage engine treats this value as a maximum. If you plan to create very large MySQL 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 setting MAX_ROWS = 2 * rows, where rows is the number of rows that you expect to insert into the table.

    The maximum MAX_ROWS value is 4294967295; larger values are truncated to this limit.


    The minimum number of rows you plan to store in the table. The MEMORY storage engine uses this option as a hint about memory use.


    PACK_KEYS takes effect only with MyISAM tables. 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 to DEFAULT tells the storage engine to pack only long CHAR, VARCHAR, BINARY, or VARBINARY columns.

    If you do not use PACK_KEYS, the default is to pack strings, but not numbers. If you use PACK_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 takes storage_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 have NULL values. (In this case, the packed key length is stored in the same byte that is used to mark if a key is NULL.)


    This option is unused. If you have a need to scramble your .frm files and make them unusable to any other MySQL server, please contact our sales department.


    Defines how the rows should be stored. For MyISAM tables, the option value can be FIXED or DYNAMIC for static or variable-length row format. myisampack sets the type to COMPRESSED. See Section 14.1.3, “MyISAM Table Storage Formats”.

    Starting with MySQL 5.0.3, for InnoDB tables, rows are stored in compact format (ROW_FORMAT=COMPACT) by default. The noncompact format used in older versions of MySQL can still be requested by specifying ROW_FORMAT=REDUNDANT.


    When executing a CREATE TABLE statement, if you specify a row format which is not supported by the storage engine that is used for the table, the table is created using that storage engine's default row format. The information reported in this column in response to SHOW TABLE STATUS is the actual row format used. This may differ from the value in the Create_options column because the original CREATE TABLE definition is retained during creation.


    RAID support has been removed as of MySQL 5.0.


    UNION is used when you want to access a collection of identical MyISAM tables as one. This works only with MERGE tables. See Section 14.3, “The MERGE Storage Engine”.

    You must have SELECT, UPDATE, and DELETE privileges for the tables you map to a MERGE table.


    Formerly, all tables used had to be in the same database as the MERGE table itself. This restriction no longer applies.


The original CREATE TABLE statement, including all specifications and table options are stored by MySQL when the table is created. The information is retained so that if you change storage engines, collations or other settings using an ALTER TABLE statement, the original table options specified are retained. This enables you to change between InnoDB and MyISAM table types even though the row formats supported by the two engines are different.

Because the text of the original statement is retained, but due to the way that certain values and options may be silently reconfigured (such as the ROW_FORMAT), the active table definition (accessible through DESCRIBE or with SHOW TABLE STATUS) and the table creation string (accessible through SHOW CREATE TABLE) will report different values.

Download this Manual
User Comments
  Posted by Martin Friebe on February 22, 2005
I just found a workaround for the limitation of not reopening temp tables (works in 4.1.10 , but wouldn't bet on it in the future);

create temporary table tmp1 (...);

create temporary table tmp2 (...) engine merge union (tmp1);

this will only work if the merge table is temporary itself

add as many merge tables as you need, use the merge tables instead of reopening the tmp (it's still the same table :-) )

they are all temporary, so no clean up necessary.
  Posted by Jeff Donner on August 11, 2005
If you want to the flexibility to drop or modify a foreign key (and, to change properties, you must drop & re-add the new version), you must create the foreign key with an otherwise optional 'symbol' name. You can verify this at the 'alter table syntax' page.
  Posted by Samba Pedapalli on January 2, 2010
Create table with constraints. If you happen to run into "can't create table errno 121" with Error Code 1005, most likely your foreign key name is used by another table's foreign key.

CREATE TABLE IF NOT EXISTS `schema`.`Employee` (
`idEmployee` VARCHAR(45) NOT NULL ,
`Name` VARCHAR(255) NULL ,
`idAddresses` VARCHAR(45) NULL ,
PRIMARY KEY (`idEmployee`) ,
CONSTRAINT `fkEmployee_Addresses`
FOREIGN KEY `fkEmployee_Addresses` (`idAddresses`)
REFERENCES `schema`.`Addresses` (`idAddresses`)
COLLATE = utf8_bin
  Posted by Winfred Qin on August 1, 2010
FOREIGN KEY Constraint Allow Multi-NULL Values -- Not Mentioned by MySQL 5.0 Reference Manual

Compare to UNIQUE KEY Constraint ( the manual says: "For other engines (all but BDB), a UNIQUE index allows multiple NULL values for columns that can contain NULL." ), whether 'allow FOREIGN KEY Constraint to have multi-NULL values' is not mentioned.

By tested on MySQL 5.0 / Ubuntu 8.04, the system says YES, the multi-NULLs are allowed.

I think this should be added to the manual explicitly.
  Posted by Chris Broome on June 9, 2011
As a suggestion, if you're looking to implement some form of alpha-numeric, auto incrementing, primary key you can achieve the same functionality with a regular int-type key. The trick is convert the integer value into a suitable alpha numeric version, ideally through stored functions.

That way when a user requests the alpha numeric value, say '5xzz2', a stored function would translate this into a raw int which would match the id in your table. This approach has the advantage of avoiding maintaining a separate (keyed) varchar column in your tables.

The process to convert a decimal key to an alphanumeric string is essentially the same as converting to a hexadecimal, here's a basic breakdown of a JavaScript version: http://en.wikipedia.org/wiki/Hexadecimal#Division-remainder_in_source_base

You'd just be expanding this algorithm to include as many characters as needed. Here's another example with mysql stored functions for converting a decimal value to a base 36 number (which uses all ten digits and twenty six lower case characters): http://www.ditherandbicker.com/programming/spoof_alpha_numeric_keys_in_mysql/
  Posted by josé ambriz meza on December 27, 2012
Video en español sobre esta acción de MySQL

Sign Up Login You must be logged in to post a comment.