CREATE [TEMPORARY] TABLE [IF NOT EXISTS]tbl_name(create_definition,...) [table_options] [partition_options]
Or:
CREATE [TEMPORARY] TABLE [IF NOT EXISTS]tbl_name[(create_definition,...)] [table_options] [partition_options]select_statement
Or:
CREATE [TEMPORARY] TABLE [IF NOT EXISTS]tbl_name{ LIKEold_tbl_name| (LIKEold_tbl_name) }
create_definition:col_namecolumn_definition| [CONSTRAINT [symbol]] PRIMARY KEY [index_type] (index_col_name,...) [index_option] ... | {INDEX|KEY} [index_name] [index_type] (index_col_name,...) [index_option] ... | [CONSTRAINT [symbol]] UNIQUE [INDEX|KEY] [index_name] [index_type] (index_col_name,...) [index_option] ... | {FULLTEXT|SPATIAL} [INDEX|KEY] [index_name] (index_col_name,...) [index_option] ... | [CONSTRAINT [symbol]] FOREIGN KEY [index_name] (index_col_name,...)reference_definition| CHECK (expr)column_definition:data_type[NOT NULL | NULL] [DEFAULTdefault_value] [AUTO_INCREMENT] [UNIQUE [KEY] | [PRIMARY] KEY] [COMMENT 'string'] [COLUMN_FORMAT {FIXED|DYNAMIC|DEFAULT}] [STORAGE {DISK|MEMORY|DEFAULT}] [reference_definition]data_type: BIT[(length)] | TINYINT[(length)] [UNSIGNED] [ZEROFILL] | SMALLINT[(length)] [UNSIGNED] [ZEROFILL] | MEDIUMINT[(length)] [UNSIGNED] [ZEROFILL] | INT[(length)] [UNSIGNED] [ZEROFILL] | INTEGER[(length)] [UNSIGNED] [ZEROFILL] | BIGINT[(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 | TIMESTAMP | DATETIME | YEAR | CHAR[(length)] [CHARACTER SETcharset_name] [COLLATEcollation_name] | VARCHAR(length) [CHARACTER SETcharset_name] [COLLATEcollation_name] | BINARY[(length)] | VARBINARY(length) | TINYBLOB | BLOB | MEDIUMBLOB | LONGBLOB | TINYTEXT [BINARY] [CHARACTER SETcharset_name] [COLLATEcollation_name] | TEXT [BINARY] [CHARACTER SETcharset_name] [COLLATEcollation_name] | MEDIUMTEXT [BINARY] [CHARACTER SETcharset_name] [COLLATEcollation_name] | LONGTEXT [BINARY] [CHARACTER SETcharset_name] [COLLATEcollation_name] | ENUM(value1,value2,value3,...) [CHARACTER SETcharset_name] [COLLATEcollation_name] | SET(value1,value2,value3,...) [CHARACTER SETcharset_name] [COLLATEcollation_name] |spatial_typeindex_col_name:col_name[(length)] [ASC | DESC]index_type: USING {BTREE | HASH | RTREE}index_option: KEY_BLOCK_SIZE [=]value|index_type| WITH PARSERparser_namereference_definition: REFERENCEStbl_name(index_col_name,...) [MATCH FULL | MATCH PARTIAL | MATCH SIMPLE] [ON DELETEreference_option] [ON UPDATEreference_option]reference_option: RESTRICT | CASCADE | SET NULL | NO ACTIONtable_options:table_option[[,]table_option] ...table_option: ENGINE [=]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' | 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} | TABLESPACEtablespace_name[STORAGE {DISK|MEMORY|DEFAULT}] | UNION [=] (tbl_name[,tbl_name]...)partition_options: PARTITION BY { [LINEAR] HASH(expr) | [LINEAR] KEY(column_list) | RANGE(expr) | LIST(expr) } [PARTITIONSnum] [SUBPARTITION BY { [LINEAR] HASH(expr) | [LINEAR] KEY(column_list) } [SUBPARTITIONSnum] ] [(partition_definition[,partition_definition] ...)]partition_definition: PARTITIONpartition_name[VALUES {LESS THAN {(expr) |MAXVALUE} | IN (value_list)}] [[STORAGE] ENGINE [=]engine_name] [COMMENT [=]'comment_text'] [DATA DIRECTORY [=] ''] [INDEX DIRECTORY [=] 'data_dir'] [MAX_ROWS [=]index_dirmax_number_of_rows] [MIN_ROWS [=]min_number_of_rows] [TABLESPACE [=]tablespace_name] [NODEGROUP [=]node_group_id] [(subpartition_definition[,subpartition_definition] ...)]subpartition_definition: SUBPARTITIONlogical_name[[STORAGE] ENGINE [=]engine_name] [COMMENT [=]'comment_text'] [DATA DIRECTORY [=] ''] [INDEX DIRECTORY [=] 'data_dir'] [MAX_ROWS [=]index_dirmax_number_of_rows] [MIN_ROWS [=]min_number_of_rows] [TABLESPACE [=]tablespace_name] [NODEGROUP [=]node_group_id]select_statement:[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 allowable table names are given in Section 8.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`.
    
      You can use the TEMPORARY keyword when creating
      a table. A TEMPORARY table is visible only to
      the current connection, and is dropped automatically when the
      connection is closed. This means that two different connections
      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.
      
      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.
    
      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. In the case
      of MyISAM tables, the storage engine creates
      data and index files. Thus, for each MyISAM
      table tbl_name, there are three disk
      files.
    
| File | Purpose | 
|  | Table format (definition) file | 
|  | Data file | 
|  | Index file | 
Chapter 13, Storage Engines, describes what files each storage engine creates to represent tables. If a table name contains special characters, the names for the table files contain encoded versions of those characters as described in Section 8.2.3, “Mapping of Identifiers to File Names”.
      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 10, Data Types, and
      Section 11.13, “Spatial Extensions”.
    
      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+1value 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 11.11.3, “Information Functions”, and
          Section 21.9.3.37, “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.8, “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 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 * FROMtbl_nameWHEREauto_colIS NULL
          For information about InnoDB and
          AUTO_INCREMENT, see
          Section 13.6.4.3, “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 9.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.1 interprets length specifications in
          character column definitions in characters. (Versions before
          MySQL 4.1 interpreted them in bytes.) 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 10.3.1.1, “TIMESTAMP Properties”.
        
          If a column definition includes no explicit
          DEFAULT value, MySQL determines the default
          value as described in Section 10.1.4, “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'.
        
Native default value handling in MySQL Cluster NDB 7.1 and later. 
            Starting with MySQL Cluster NDB 7.1.0, default values for
            table columns are stored by
            NDBCLUSTER, rather than by the
            MySQL server as was previously the case. Because less data
            must be sent from an SQL node to the data nodes, inserts on
            tables having column value defaults can be performed more
            efficiently than before.
          
          Tables created using previous MySQL Cluster releases can still
          be used in MySQL Cluster 7.1.0 and later, although they do not
          support native default values and continue to use defaults
          supplied by the MySQL server until they are upgraded. This can
          be done by means of an offline ALTER
          TABLE statement.
        
            You cannot set or change a table column's default value
            using an online ALTER TABLE
            operation
          
Tables created in MySQL Cluster NDB 7.1.0 and later cannot be used with earlier versions of MySQL Cluster.
          NDBCLUSTER tables supporting
          native default values are still subject to the restrictions on
          default values imposed by the MySQL server. For more
          information, see Section 10.1.4, “Data Type Default Values”.
        
          
          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.
        
          
          Beginning with MySQL Cluster NDB 6.2.5 and MySQL Cluster NDB
          6.3.2, it is also possible to specify a data storage format
          for individual columns of NDB
          tables using COLUMN_FORMAT. Allowable
          column formats are FIXED,
          DYNAMIC, and DEFAULT.
          FIXED is used to specify
          fixed-width storage, DYNAMIC allows the
          column to be variable-width, and DEFAULT
          causes the column to use fixed-width or variable-width storage
          as determined by the column's data type (possibly overridden
          by a ROW_FORMAT specifier).
        
          For NDB tables, the default value
          for COLUMN_FORMAT is
          DEFAULT.
        
          COLUMN_FORMAT currently has no effect on
          columns of tables using storage engines other than
          NDB.
        
          
          For NDB tables, beginning with
          MySQL Cluster NDB 6.2.5 and MySQL Cluster NDB 6.3.2, it is
          also possible to specify whether the column is stored on disk
          or in memory by using a STORAGE clause.
          STORAGE DISK causes the column to be stored
          on disk, and STORAGE MEMORY causes
          in-memory storage to be used. The CREATE
          TABLE statement used must still include a
          TABLESPACE clause:
        
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 than
          NDB.
        
          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. For all engines, a UNIQUE
          index allows 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. 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 13.6.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(
          clause.
        index_col_name, ...)
          
          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
          . See
          Section 12.4.5.23, “tbl_nameSHOW INDEX Syntax”.
        
          Some storage engines allow you to specify an index type when
          creating an index. The syntax for the
          index_type specifier is
          USING .
        type_name
Example:
CREATE TABLE lookup (id INT, INDEX USING BTREE (id)) ENGINE = MEMORY;
          Before MySQL 5.1.10, USING can be given
          only before the index column list. As of 5.1.10, the preferred
          position is after the column list. Use of the option before
          the column list will no longer be recognized in a future MySQL
          release.
        
          index_option values specify
          additional options for an index. USING is
          one such option. For details about allowable
          index_option values, see
          Section 12.1.13, “CREATE INDEX Syntax”.
        
For more information about indexes, see Section 7.4.4, “How MySQL Uses Indexes”.
          
          
          In MySQL 5.1, only the MyISAM,
          InnoDB, 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)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 7.4.2, “Column Indexes”.
        
          Only the MyISAM 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
          multi-byte character set.
        
          An index_col_name specification can
          end with ASC or DESC.
          These keywords are allowed 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 TEXT or
          BLOB column in a
          SELECT, the server sorts values
          using only the initial number of bytes indicated by the
          max_sort_length system
          variable. See Section 10.4.3, “The BLOB and
        TEXT Types”.
        
          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 11.8, “Full-Text Search Functions”, for details of operation. A
          WITH PARSER clause can be specified as an
          index_option value to associate a
          parser plugin with the index if full-text indexing and
          searching operations need special handling. This clause is
          legal only for FULLTEXT indexes. See
          Section 22.2, “The MySQL Plugin API”, for details on creating plugins.
        
          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.13, “Spatial Extensions”.
        
          InnoDB tables support checking of foreign
          key constraints. See Section 13.6, “The InnoDB Storage Engine”. Note that the
          FOREIGN KEY syntax in
          InnoDB is more restrictive than the syntax
          presented for the CREATE TABLE
          statement at the beginning of this section: The columns of the
          referenced table must always be explicitly named.
          InnoDB supports both ON
          DELETE and ON UPDATE actions on
          foreign keys. For the precise syntax, see
          Section 13.6.4.4, “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 1.8.5.4, “Foreign Keys”.
        
            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 allow a foreign key to be all or
            partially NULL. In that case, the (child
            table) row containing such a foreign key is allowed 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 and InnoDB require
            that the referenced columns be indexed for performance.
            However, the system does not enforce a requirement that the
            referenced columns be UNIQUE or be
            declared 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 UNIQUE
            and NOT NULL keys.
          
            Furthermore, InnoDB does not recognize or
            support “inline REFERENCES
            specifications” (as defined in the SQL standard)
            where the references are defined as part of the column
            specification. InnoDB accepts
            REFERENCES clauses only when specified as
            part of a separate FOREIGN KEY
            specification. For other storage engines, MySQL Server
            parses and ignores foreign key specifications.
          
Partitioned tables do not support foreign keys. See Section 18.5, “Restrictions and Limitations on Partitioning”, for more information.
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 D.7.2, “The Maximum Number of Columns Per Table”.
      The TABLESPACE and STORAGE
      table options were both introduced in MySQL 5.1.6. In MySQL 5.1,
      they are employed only with
      NDBCLUSTER tables. The tablespace
      named tablespace_name must already have
      been created using CREATE TABLESPACE.
      STORAGE determines the type of storage used
      (disk or memory), and can be one of DISK,
      MEMORY, or DEFAULT.
    
      TABLESPACE ... STORAGE DISK assigns a table to
      a MySQL Cluster Disk Data tablespace. See
      Section 17.5.10, “MySQL Cluster Disk Data Tables”, for more information.
    
        A STORAGE clause cannot be used in a
        CREATE TABLE statement without a
        TABLESPACE clause.
      
      The ENGINE table option specifies the storage
      engine for the table.
    
      The ENGINE table option takes the storage
      engine names shown in the following table.
    
| Storage Engine | Description | 
| ARCHIVE | The archiving storage engine. See
              Section 13.12, “The ARCHIVEStorage Engine”. | 
| CSV | Tables that store rows in comma-separated values format. See
              Section 13.13, “The CSVStorage Engine”. | 
| EXAMPLE | An example engine. See Section 13.10, “The EXAMPLEStorage Engine”. | 
| FEDERATED | Storage engine that accesses remote tables. See
              Section 13.11, “The FEDERATEDStorage Engine”. | 
| HEAP | This is a synonym for MEMORY. | 
| ISAM(OBSOLETE) | Not available in MySQL 5.1. If you are upgrading to MySQL
              5.1 from a previous version, you should
              convert any existing ISAMtables toMyISAMbefore
              performing the upgrade. | 
| InnoDB | Transaction-safe tables with row locking and foreign keys. See
              Section 13.6, “The InnoDBStorage Engine”. | 
| MEMORY | The data for this storage engine is stored only in memory. See
              Section 13.9, “The MEMORY(HEAP) Storage Engine”. | 
| MERGE | A collection of MyISAMtables used as one table. Also
              known asMRG_MyISAM. See
              Section 13.8, “TheMERGEStorage Engine”. | 
| MyISAM | The binary portable storage engine that is the default storage engine
              used by MySQL. See
              Section 13.5, “The MyISAMStorage Engine”. | 
| NDBCLUSTER | Clustered, fault-tolerant, memory-based tables. Also known as NDB. See
              Chapter 17, MySQL Cluster NDB 6.X/7.X. | 
      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=INNODB option but the MySQL
      server does not support INNODB 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.1, 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.8, “Server SQL Modes”.
    
        The older TYPE option was synonymous with
        ENGINE. TYPE has been
        deprecated since MySQL 4.0 but is still supported for backward
        compatibility in MySQL 5.1 (excepting MySQL 5.1.7). Since MySQL
        5.1.8, it produces a warning. It is removed in MySQL 5.5.
        You should not use TYPE in any new
        applications, and you should immediately begin conversion of
        existing applications to use ENGINE
        instead. (See Section C.1.44, “Changes in MySQL 5.1.8 (Not released)”.)
      
      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.
    
          AUTO_INCREMENT
        
          The initial AUTO_INCREMENT value for the
          table. In MySQL 5.1, this works for
          MyISAM, MEMORY, and
          InnoDB tables. It also works for
          ARCHIVE tables as of MySQL 5.1.6. 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
           to reset the
          tbl_name AUTO_INCREMENT =
          NAUTO_INCREMENT value. 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 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
          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 the
          myisam_data_pointer_size
          system variable. (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 allows table
          sizes up to 65,536TB.
        
          [DEFAULT] CHARACTER SET
        
          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.
        
          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.
          (MyISAM only.)
        
          [DEFAULT] COLLATE
        
Specify a default collation for the table.
          COMMENT
        
A comment for the table, up to 60 characters long.
          CONNECTION
        
          The connection string for a FEDERATED
          table.
        
            Older versions of MySQL used a COMMENT
            option for the connection string.
          
          DATA DIRECTORY, INDEX
          DIRECTORY
        
          By using DATA
          DIRECTORY=' or
          directory'INDEX
          DIRECTORY=' you
          can specify where the directory'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.
        
            Beginning with MySQL 5.1.23, table-level DATA
            DIRECTORY and INDEX DIRECTORY
            options 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-safe realpath() call. See
          Section 7.6.1.2, “Using Symbolic Links for 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.1.23, 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.1.24, you cannot use path names that
            contain the MySQL data directory with DATA
            DIRECTORY or INDEX 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 the
          delay_key_write system
          variable in Section 5.1.4, “Server System Variables”.
          (MyISAM only.)
        
          INSERT_METHOD
        
          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 13.8, “The MERGE Storage Engine”.
        
          KEY_BLOCK_SIZE
        
          This option provides a hint to the storage engine about the
          size in bytes to use for index key blocks. The engine is
          allowed to change the value if necessary. A value of 0
          indicates that the default value should be used. Individual
          index definitions can specify a
          KEY_BLOCK_SIZE value of their own to
          override the table value. KEY_BLOCK_SIZE
          was added in MySQL 5.1.10.
        
          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.
          MIN_ROWS
        
          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
        
          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.)
        
          PASSWORD
        
          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.
        
          RAID_TYPE
        
          RAID support has been removed as of MySQL
          5.0. For information on RAID, see
          CREATE TABLE Syntax.
        
          ROW_FORMAT
        
          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 13.5.3, “MyISAM Table Storage Formats”.
        
          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.
          
          UNION is used when you want to
          access a collection of identical MyISAM
          tables as one. This works only with MERGE
          tables. See Section 13.8, “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.
          
      partition_options can be used to
      control partitioning of the table created with
      CREATE TABLE.
    
        Not all options shown in the syntax for
        partition_options 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 18, 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.
      
      If used, a partition_options clause
      begins with PARTITION BY. This clause contains
      the function that is used to determine the partition; the function
      returns an integer value ranging from 1 to
      num, where
      num 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.) The
      choices that are available for this function in MySQL
      5.1 are shown in the following list:
    
          HASH(:
          Hashes one or more columns to create a key for placing and
          locating rows. expr)expr is an
          expression using one or more table columns. This can be any
          legal MySQL expression (including MySQL functions) that yields
          a single integer value. For example, these are all valid
          CREATE TABLE statements using
          PARTITION BY HASH:
        
CREATE TABLE t1 (col1 INT, col2 CHAR(5))
    PARTITION BY HASH(col1);
CREATE TABLE t1 (col1 INT, col2 CHAR(5))
    PARTITION BY HASH( ORD(col2) );
CREATE TABLE t1 (col1 INT, col2 CHAR(5), col3 DATETIME)
    PARTITION BY HASH ( YEAR(col3) );
          You may not use either VALUES LESS THAN or
          VALUES 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 18.2.3, “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, see
          Section 18.2.3.1, “LINEAR HASH Partitioning”.
        
          KEY(:
          This is similar to column_list)HASH, except that MySQL
          supplies the hashing function so as to guarantee an even data
          distribution. The column_list
          argument is simply a list of table columns. 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 (see
          Section 18.2.3.1, “LINEAR HASH Partitioning”, and
          Section 18.2.4, “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;
          You may not use either VALUES LESS THAN or
          VALUES IN clauses with PARTITION
          BY KEY.
        
          RANGE: In this case,
          expr shows a range of values using
          a set of VALUES LESS THAN operators. When
          using range partitioning, you must define at least one
          partition using VALUES LESS THAN. You
          cannot use VALUES IN with range
          partitioning.
        
          VALUES LESS THAN can be used with either a
          literal value or an expression that evaluates to a single
          value.
        
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 – 1994 | 
| 2 | 1995 – 1998 | 
| 3 | 1999 – 2002 | 
| 4 | 2003 – 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.
        
          Note that 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.
        
          LIST(: 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 to expr)RANGE, except
          that only VALUES IN may be used to specify
          allowable values for each partition.
        
          VALUES IN is 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 use
          VALUES LESS THAN with PARTITION BY
          LIST.
        
            Currently, the value list used with VALUES
            IN must consist of integer values only.
          
          The number of partitions may optionally be specified with a
          PARTITIONS 
          clause, where numnum is the number of
          partitions. If both this clause and any
          PARTITION clauses are used,
          num must be equal to the total
          number of any partitions that are declared using
          PARTITION clauses.
        
            Whether or not you use a PARTITIONS
            clause in creating a table that is partitioned by
            RANGE or LIST, you
            must still include at least one PARTITION
            VALUES clause in the table definition (see below).
          
          A partition may optionally be divided into a number of
          subpartitions. This can be indicated by using the optional
          SUBPARTITION BY clause. Subpartitioning may
          be done by HASH or KEY.
          Either of these may be LINEAR. These work
          in the same way as previously described for the equivalent
          partitioning types. (It is not possible to subpartition by
          LIST or RANGE.)
        
          The number of subpartitions can be indicated using the
          SUBPARTITIONS keyword followed by an
          integer value.
        
          MySQL 5.1.12 introduces rigorous checking of the value used in
          a PARTITIONS or
          SUBPARTITIONS clause. Beginning with this
          version, this value must adhere to the following rules:
        
The value must be a positive, nonzero integer.
No leading zeroes are permitted.
              The value must be an integer literal, and cannot not be an
              expression. For example, PARTITIONS
              0.2E+01 is not allowed, even though
              0.2E+01 evaluates to
              2. (Bug#15890)
            
        The expression (expr) used in a
        PARTITION BY clause cannot refer to any
        columns not in the table being created; beginning with MySQL
        5.1.23, such references are specifically disallowed and cause
        the statement to fail with an error. (Bug#29444)
      
      Each partition may be individually defined using a
      partition_definition clause. The
      individual parts making up this clause are as follows:
    
          PARTITION
          : This
          specifies a logical name for the partition.
        partition_name
          A VALUES clause: For range partitioning,
          each partition must include a VALUES LESS
          THAN clause; for list partitioning, you must specify
          a VALUES IN clause for each partition. This
          is used to determine which rows are to be stored in this
          partition. See the discussions of partitioning types in
          Chapter 18, Partitioning, for syntax examples.
        
          An optional COMMENT clause may be used to
          specify a string that describes the partition. Example:
        
COMMENT = 'Data for the years previous to 1999'
          DATA DIRECTORY and INDEX
          DIRECTORY may be used to indicate the directory
          where, respectively, the data and indexes for this partition
          are to be stored. Both the
          data_dirindex_dir
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 p2000 VALUES IN (1998, 2002, 2006)
    DATA DIRECTORY = '/var/appdata/98/data'
    INDEX DIRECTORY = '/var/appdata/98/idx'
);
          DATA DIRECTORY and INDEX
          DIRECTORY behave in the same way as in the
          CREATE TABLE statement's
          table_option clause as used for
          MyISAM tables.
        
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, the DATA DIRECTORY and
          INDEX DIRECTORY options are not supported
          for individual partitions or subpartitions. Beginning with
          MySQL 5.1.24, these options are ignored on Windows, except
          that a warning is generated. (Bug#30459)
        
            Prior to MySQL 5.1.18, DATA DIRECTORY and
            INDEX DIRECTORY were allowed even if the
            NO_DIR_IN_CREATE server
            SQL mode was in effect at the time that a partitioned table
            was created. Beginning with MySQL 5.1.18, these options are
            ignored for creating partitioned tables if
            NO_DIR_IN_CREATE is in
            effect. (Bug#24633)
          
          MAX_ROWS and MIN_ROWS
          may be used to specify, respectively, the maximum and minimum
          number of rows to be stored in the partition. The values for
          max_number_of_rows and
          min_number_of_rows must 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.
        
          The optional TABLESPACE clause may be used
          to designate a tablespace for the partition. Used for MySQL
          Cluster only.
        
          The partitioning handler accepts a [STORAGE]
          ENGINE option for both PARTITION
          and SUBPARTITION. 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 will give rise to the error ERROR
          1469 (HY000): The mix of handlers in the partitions is not
          allowed in this version of MySQL. We expect to
          lift this restriction on partitioning in a future MySQL
          release.
        
          The NODEGROUP option can be used to make
          this partition act as part of the node group identified by
          node_group_id. This option is
          applicable only to MySQL Cluster.
        
          The partition definition may optionally contain one or more
          subpartition_definition clauses.
          Each of these consists at a minimum of the
          SUBPARTITION
          , where
          namename is an identifier for the
          subpartition. Except for the replacement of the
          PARTITION keyword with
          SUBPARTITION, the syntax for a subpartition
          definition is identical to that for a partition definition.
        
          Subpartitioning must be done by HASH or
          KEY, and can be done only on
          RANGE or LIST
          partitions. See Section 18.2.5, “Subpartitioning”.
        
      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 12.1.7, “ALTER TABLE Syntax”. For
      more detailed descriptions and examples, see
      Section 18.3, “Partition Management”.
    
        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 allows 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.
      
      You can create one table from another by adding a
      SELECT statement at the end of the
      CREATE TABLE statement:
    
CREATE TABLEnew_tblSELECT * FROMorig_tbl;
      MySQL creates new columns for all elements in the
      SELECT. For example:
    
mysql>CREATE TABLE test (a INT NOT NULL AUTO_INCREMENT,->PRIMARY KEY (a), KEY(b))->ENGINE=MyISAM SELECT b,c FROM test2;
      This creates a MyISAM table with three columns,
      a, b, and
      c. Notice that the columns from the
      SELECT statement are appended to
      the right side of the table, not overlapped onto it. Take the
      following example:
    
mysql>SELECT * FROM foo;+---+ | n | +---+ | 1 | +---+ mysql>CREATE TABLE bar (m INT) SELECT n FROM foo;Query OK, 1 row affected (0.02 sec) Records: 1 Duplicates: 0 Warnings: 0 mysql>SELECT * FROM bar;+------+---+ | m | n | +------+---+ | NULL | 1 | +------+---+ 1 row in set (0.00 sec)
      For each row in table foo, a row is inserted in
      bar with the values from foo
      and default values for the new columns.
    
      In a table resulting from
      CREATE TABLE ...
      SELECT, columns named only in the
      CREATE TABLE part come first.
      Columns named in both parts or only in the
      SELECT part come after that. The
      data type of SELECT columns can be
      overridden by also specifying the column in the
      CREATE TABLE part.
    
If any errors occur while copying the data to the table, it is automatically dropped and not created.
      CREATE TABLE ...
      SELECT does not automatically create any indexes for
      you. This is done intentionally to make the statement as flexible
      as possible. If you want to have indexes in the created table, you
      should specify these before the
      SELECT statement:
    
mysql> CREATE TABLE bar (UNIQUE (n)) SELECT n FROM foo;
      Some conversion of data types might occur. For example, the
      AUTO_INCREMENT attribute is not preserved, and
      VARCHAR columns can become
      CHAR columns. Retrained attributes
      are NULL (or NOT NULL) and,
      for those columns that have them, CHARACTER
      SET, COLLATION,
      COMMENT, and the DEFAULT
      clause.
    
      When creating a table with CREATE ... SELECT,
      make sure to alias any function calls or expressions in the query.
      If you do not, the CREATE statement might fail
      or result in undesirable column names.
    
CREATE TABLE artists_and_works SELECT artist.name, COUNT(work.artist_id) AS number_of_works FROM artist LEFT JOIN work ON artist.id = work.artist_id GROUP BY artist.id;
You can also explicitly specify the data type for a generated column:
CREATE TABLE foo (a TINYINT NOT NULL) SELECT b+1 AS a FROM bar;
      For CREATE TABLE ...
      SELECT, if IF NOT EXISTS is given and
      the table already exists, MySQL handles the statement as follows:
    
          The table definition given in the CREATE
          TABLE part is ignored. No error occurs, even if the
          definition does not match that of the existing table.
        
          If there is a mismatch between the number of columns in the
          table and the number of columns produced by the
          SELECT part, the selected
          values are assigned to the rightmost columns. For example, if
          the table contains n columns and
          the SELECT produces
          m columns, where
          m <
          n, the selected values are assigned
          to the m rightmost columns in the
          table. Each of the initial n
          – m columns is assigned its
          default value, either that specified explicitly in the column
          definition or the implicit column data type default if the
          definition contains no default. If the
          SELECT part produces too many
          columns (m >
          n), an error occurs.
        
If strict SQL mode is enabled and any of these initial columns do not have an explicit default value, the statement fails with an error.
      The following example illustrates IF NOT EXISTS
      handling:
    
mysql>CREATE TABLE t1 (i1 INT DEFAULT 0, i2 INT, i3 INT, i4 INT);Query OK, 0 rows affected (0.05 sec) mysql>CREATE TABLE IF NOT EXISTS t1 (c1 CHAR(10)) SELECT 1, 2;Query OK, 1 row affected, 1 warning (0.01 sec) Records: 1 Duplicates: 0 Warnings: 0 mysql>SELECT * FROM t1;+------+------+------+------+ | i1 | i2 | i3 | i4 | +------+------+------+------+ | 0 | NULL | 1 | 2 | +------+------+------+------+ 1 row in set (0.00 sec)
      Use 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 TABLEnew_tblLIKEorig_tbl;
      The copy is created using the same version of the table storage
      format as the original table. The
      SELECT privilege is required on the
      original table.
    
      LIKE works only for base tables, not for views.
    
      CREATE TABLE ... LIKE does not preserve any
      DATA DIRECTORY or INDEX
      DIRECTORY table options that were specified for the
      original table, or any foreign key definitions.
    
      If the original table is a TEMPORARY table,
      CREATE TABLE ... LIKE does not preserve
      TEMPORARY. To create a
      TEMPORARY destination table, use
      CREATE TEMPORARY TABLE ... LIKE.
    
      You can precede the SELECT by
      IGNORE or
      REPLACE to indicate how to handle
      rows that duplicate unique key values. With
      IGNORE, new rows that duplicate an existing row
      on a unique key value are discarded. With
      REPLACE, new rows replace rows that
      have the same unique key value. If neither
      IGNORE nor
      REPLACE is specified, duplicate
      unique key values result in an error.
    
      To ensure that the binary log can be used to re-create the
      original tables, MySQL does not allow concurrent inserts during
      CREATE TABLE ...
      SELECT.
    


User Comments
For 3.23.58 using InnoDB, I discovered that if you have a unique index key with multiple optional columns, then it does not apply a unique constraint at all if ANY of your data values for the columns are null. Thus, it will duplicate any data that has any nulls in any of the key columns.
If none of your column values are null, then it applies the unique constraint.
This was unexpected, because I remember Oracle applying the unique constraint on the remaining non-null values. It would be nice if MySQL could do this as well so we can guarantee that a unique key will not permit duplicates.
just found a possibility to wotrk around the limitations of not reopening temp tables (works in 4.1.10 , but wouldnt bet on its future);
create temporary table tmp1 (...);
create temporary table tmp2 (...) enginme merge union (tmp1);
# this will only work is the merge table is temporary itself
add as many mrg tables as you need, use the merge tables instead of reopening the tmp (its still the same table :-) )
they are all temporary, so no clean up
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.
I just found a work around 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
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`)
ON DELETE NO ACTION
ON UPDATE NO ACTION)
ENGINE = InnoDB
DEFAULT CHARACTER SET = utf8
COLLATE = utf8_bin
Add your own comment.