Table of Contents
This chapter describes the syntax for the SQL statements supported by MySQL.
ALTER {DATABASE | SCHEMA} [db_name]
    alter_specification ...
ALTER {DATABASE | SCHEMA} db_name
    UPGRADE DATA DIRECTORY NAME
alter_specification:
    [DEFAULT] CHARACTER SET [=] charset_name
  | [DEFAULT] COLLATE [=] collation_name
      ALTER DATABASE enables you to
      change the overall characteristics of a database. These
      characteristics are stored in the db.opt file
      in the database directory. To use ALTER
      DATABASE, you need the
      ALTER privilege on the database.
      ALTER
      SCHEMA is a synonym for ALTER
      DATABASE.
    
The database name can be omitted from the first syntax, in which case the statement applies to the default database.
      The CHARACTER SET clause changes the default
      database character set. The COLLATE clause
      changes the default database collation. Section 10.1, “Character Set Support”,
      discusses character set and collation names.
    
      You can see what character sets and collations are available
      using, respectively, the SHOW CHARACTER
      SET and SHOW COLLATION
      statements. See Section 13.7.5.4, “SHOW CHARACTER SET Syntax”, and
      Section 13.7.5.5, “SHOW COLLATION Syntax”, for more information.
    
If you change the default character set or collation for a database, stored routines that use the database defaults must be dropped and recreated so that they use the new defaults. (In a stored routine, variables with character data types use the database defaults if the character set or collation are not specified explicitly. See Section 13.1.15, “CREATE PROCEDURE and CREATE FUNCTION Syntax”.)
      The syntax that includes the UPGRADE DATA DIRECTORY
      NAME clause updates the name of the directory associated
      with the database to use the encoding implemented in MySQL 5.1 for
      mapping database names to database directory names (see
      Section 9.2.3, “Mapping of Identifiers to File Names”). This clause is for use
      under these conditions:
It is intended when upgrading MySQL to 5.1 or later from older versions.
It is intended to update a database directory name to the current encoding format if the name contains special characters that need encoding.
The statement is used by mysqlcheck (as invoked by mysql_upgrade).
      For example, if a database in MySQL 5.0 has the name
      a-b-c, the name contains instances of the
      - (dash) character. In MySQL 5.0, the database
      directory is also named a-b-c, which is not
      necessarily safe for all file systems. In MySQL 5.1 and later, the
      same database name is encoded as a@002db@002dc
      to produce a file system-neutral directory name.
    
      When a MySQL installation is upgraded to MySQL 5.1 or later from
      an older version,the server displays a name such as
      a-b-c (which is in the old format) as
      #mysql50#a-b-c, and you must refer to the name
      using the #mysql50# prefix. Use
      UPGRADE DATA DIRECTORY NAME in this case to
      explicitly tell the server to re-encode the database directory
      name to the current encoding format:
    
ALTER DATABASE `#mysql50#a-b-c` UPGRADE DATA DIRECTORY NAME;
      After executing this statement, you can refer to the database as
      a-b-c without the special
      #mysql50# prefix.
ALTER
    [DEFINER = { user | CURRENT_USER }]
    EVENT event_name
    [ON SCHEDULE schedule]
    [ON COMPLETION [NOT] PRESERVE]
    [RENAME TO new_event_name]
    [ENABLE | DISABLE | DISABLE ON SLAVE]
    [COMMENT 'comment']
    [DO event_body]
      The ALTER EVENT statement changes
      one or more of the characteristics of an existing event without
      the need to drop and recreate it. The syntax for each of the
      DEFINER, ON SCHEDULE,
      ON COMPLETION, COMMENT,
      ENABLE / DISABLE, and
      DO clauses is exactly the same as
      when used with CREATE EVENT. (See
      Section 13.1.11, “CREATE EVENT Syntax”.)
    
      Any user can alter an event defined on a database for which that
      user has the EVENT privilege. When
      a user executes a successful ALTER
      EVENT statement, that user becomes the definer for the
      affected event.
    
      ALTER EVENT works only with an
      existing event:
    
mysql>ALTER EVENT no_such_event>ON SCHEDULE>EVERY '2:3' DAY_HOUR;ERROR 1517 (HY000): Unknown event 'no_such_event'
      In each of the following examples, assume that the event named
      myevent is defined as shown here:
    
CREATE EVENT myevent
    ON SCHEDULE
      EVERY 6 HOUR
    COMMENT 'A sample comment.'
    DO
      UPDATE myschema.mytable SET mycol = mycol + 1;
      The following statement changes the schedule for
      myevent from once every six hours starting
      immediately to once every twelve hours, starting four hours from
      the time the statement is run:
    
ALTER EVENT myevent
    ON SCHEDULE
      EVERY 12 HOUR
    STARTS CURRENT_TIMESTAMP + INTERVAL 4 HOUR;
      It is possible to change multiple characteristics of an event in a
      single statement. This example changes the SQL statement executed
      by myevent to one that deletes all records from
      mytable; it also changes the schedule for the
      event such that it executes once, one day after this
      ALTER EVENT statement is run.
    
ALTER EVENT myevent
    ON SCHEDULE
      AT CURRENT_TIMESTAMP + INTERVAL 1 DAY
    DO
      TRUNCATE TABLE myschema.mytable;
      Specify the options in an ALTER
      EVENT statement only for those characteristics that you
      want to change; omitted options keep their existing values. This
      includes any default values for CREATE
      EVENT such as ENABLE.
    
      To disable myevent, use this
      ALTER EVENT statement:
    
ALTER EVENT myevent
    DISABLE;
      The ON SCHEDULE clause may use expressions
      involving built-in MySQL functions and user variables to obtain
      any of the timestamp or
      interval values which it contains. You
      cannot use stored routines or user-defined functions in such
      expressions, and you cannot use any table references; however, you
      can use SELECT FROM DUAL. This is true for both
      ALTER EVENT and
      CREATE EVENT statements. References
      to stored routines, user-defined functions, and tables in such
      cases are specifically not permitted, and fail with an error (see
      Bug #22830).
    
      Although an ALTER EVENT statement
      that contains another ALTER EVENT
      statement in its DO clause appears
      to succeed, when the server attempts to execute the resulting
      scheduled event, the execution fails with an error.
    
      To rename an event, use the ALTER
      EVENT statement's RENAME TO clause.
      This statement renames the event myevent to
      yourevent:
    
ALTER EVENT myevent
    RENAME TO yourevent;
      You can also move an event to a different database using
      ALTER EVENT ... RENAME TO ... and
      db_name.event_name
ALTER EVENT olddb.myevent
    RENAME TO newdb.myevent;
      To execute the previous statement, the user executing it must have
      the EVENT privilege on both the
      olddb and newdb databases.
        There is no RENAME EVENT statement.
      The value DISABLE ON SLAVE is used on a
      replication slave instead of ENABLE or
      DISABLE to indicate an event that was created
      on the master and replicated to the slave, but that is not
      executed on the slave. Normally, DISABLE ON
      SLAVE is set automatically as required; however, there
      are some circumstances under which you may want or need to change
      it manually. See Section 17.4.1.11, “Replication of Invoked Features”,
      for more information.
ALTER LOGFILE GROUPlogfile_groupADD UNDOFILE 'file_name' [INITIAL_SIZE [=]size] [WAIT] ENGINE [=]engine_name
      This statement adds an UNDO file named
      'file_name' to an existing log file
      group logfile_group. An
      ALTER LOGFILE GROUP statement has
      one and only one ADD UNDOFILE clause. No
      DROP UNDOFILE clause is currently supported.
All MySQL Cluster Disk Data objects share the same namespace. This means that each Disk Data object must be uniquely named (and not merely each Disk Data object of a given type). For example, you cannot have a tablespace and an undo log file with the same name, or an undo log file and a data file with the same name.
      The optional INITIAL_SIZE parameter sets the
      UNDO file's initial size in bytes; if not
      specified, the initial size defaults to 134217728 (128 MB). Prior
      to MySQL Cluster NDB 7.3.2, this value was required to be
      specified using digits; in MySQL Cluster NDB 7.3.2 and later, you
      may optionally follow size with a
      one-letter abbreviation for an order of magnitude, similar to
      those used in my.cnf. Generally, this is one
      of the letters M (megabytes) or
      G (gigabytes). (Bug #13116514, Bug #16104705,
      Bug #62858)
    
      On 32-bit systems, the maximum supported value for
      INITIAL_SIZE is 4294967296 (4 GB). (Bug #29186)
    
      The minimum allowed value for INITIAL_SIZE is
      1048576 (1 MB). (Bug #29574)
        WAIT is parsed but otherwise ignored. This
        keyword currently has no effect, and is intended for future
        expansion.
      The ENGINE parameter (required) determines the
      storage engine which is used by this log file group, with
      engine_name being the name of the
      storage engine. Currently, the only accepted values for
      engine_name are
      “NDBCLUSTER” and
      “NDB”. The two values
      are equivalent.
    
      Here is an example, which assumes that the log file group
      lg_3 has already been created using
      CREATE LOGFILE GROUP (see
      Section 13.1.14, “CREATE LOGFILE GROUP Syntax”):
    
ALTER LOGFILE GROUP lg_3
    ADD UNDOFILE 'undo_10.dat'
    INITIAL_SIZE=32M
    ENGINE=NDBCLUSTER;
      When ALTER LOGFILE GROUP is used
      with ENGINE = NDBCLUSTER (alternatively,
      ENGINE = NDB), an UNDO log
      file is created on each MySQL Cluster data node. You can verify
      that the UNDO files were created and obtain
      information about them by querying the
      INFORMATION_SCHEMA.FILES table. For
      example:
    
mysql>SELECT FILE_NAME, LOGFILE_GROUP_NUMBER, EXTRA->FROM INFORMATION_SCHEMA.FILES->WHERE LOGFILE_GROUP_NAME = 'lg_3';+-------------+----------------------+----------------+ | FILE_NAME | LOGFILE_GROUP_NUMBER | EXTRA | +-------------+----------------------+----------------+ | newdata.dat | 0 | CLUSTER_NODE=3 | | newdata.dat | 0 | CLUSTER_NODE=4 | | undo_10.dat | 11 | CLUSTER_NODE=3 | | undo_10.dat | 11 | CLUSTER_NODE=4 | +-------------+----------------------+----------------+ 4 rows in set (0.01 sec)
(See Section 21.30.1, “The INFORMATION_SCHEMA FILES Table”.)
      Memory used for UNDO_BUFFER_SIZE comes from the
      global pool whose size is determined by the value of the
      SharedGlobalMemory data
      node configuration parameter. This includes any default value
      implied for this option by the setting of the
      InitialLogFileGroup data
      node configuration parameter.
    
      ALTER LOGFILE GROUP is useful only
      with Disk Data storage for MySQL Cluster. For more information,
      see Section 18.5.12, “MySQL Cluster Disk Data Tables”.
ALTER FUNCTIONfunc_name[characteristic...]characteristic: COMMENT 'string' | LANGUAGE SQL | { CONTAINS SQL | NO SQL | READS SQL DATA | MODIFIES SQL DATA } | SQL SECURITY { DEFINER | INVOKER }
      This statement can be used to change the characteristics of a
      stored function. More than one change may be specified in an
      ALTER FUNCTION statement. However,
      you cannot change the parameters or body of a stored function
      using this statement; to make such changes, you must drop and
      re-create the function using DROP
      FUNCTION and CREATE
      FUNCTION.
    
      You must have the ALTER ROUTINE
      privilege for the function. (That privilege is granted
      automatically to the function creator.) If binary logging is
      enabled, the ALTER FUNCTION
      statement might also require the
      SUPER privilege, as described in
      Section 20.7, “Binary Logging of Stored Programs”.
ALTER PROCEDUREproc_name[characteristic...]characteristic: COMMENT 'string' | LANGUAGE SQL | { CONTAINS SQL | NO SQL | READS SQL DATA | MODIFIES SQL DATA } | SQL SECURITY { DEFINER | INVOKER }
      This statement can be used to change the characteristics of a
      stored procedure. More than one change may be specified in an
      ALTER PROCEDURE statement. However,
      you cannot change the parameters or body of a stored procedure
      using this statement; to make such changes, you must drop and
      re-create the procedure using DROP
      PROCEDURE and CREATE
      PROCEDURE.
    
      You must have the ALTER ROUTINE
      privilege for the procedure. By default, that privilege is granted
      automatically to the procedure creator. This behavior can be
      changed by disabling the
      automatic_sp_privileges system
      variable. See Section 20.2.2, “Stored Routines and MySQL Privileges”.
ALTER SERVERserver_nameOPTIONS (option[,option] ...)
      Alters the server information for
      server_nameCREATE SERVER statement. The
      corresponding fields in the mysql.servers table
      are updated accordingly. This statement requires the
      SUPER privilege.
    
      For example, to update the USER option:
    
ALTER SERVER s OPTIONS (USER 'sally');
      ALTER SERVER does not cause an automatic
      commit.
    
      In MySQL 5.6, ALTER SERVER is not
      written to the binary log, regardless of the logging format that
      is in use.
    
      In MySQL 5.6.11 only, gtid_next
      must be set to AUTOMATIC before issuing this
      statement. (Bug #16062608, Bug #16715809, Bug #69045)
ALTER [ONLINE|OFFLINE] [IGNORE] TABLEtbl_name[alter_specification[,alter_specification] ...] [partition_options]alter_specification:table_options| ADD [COLUMN]col_namecolumn_definition[FIRST | AFTERcol_name] | ADD [COLUMN] (col_namecolumn_definition,...) | ADD {INDEX|KEY} [index_name] [index_type] (index_col_name,...) [index_option] ... | ADD [CONSTRAINT [symbol]] PRIMARY KEY [index_type] (index_col_name,...) [index_option] ... | ADD [CONSTRAINT [symbol]] UNIQUE [INDEX|KEY] [index_name] [index_type] (index_col_name,...) [index_option] ... | ADD FULLTEXT [INDEX|KEY] [index_name] (index_col_name,...) [index_option] ... | ADD SPATIAL [INDEX|KEY] [index_name] (index_col_name,...) [index_option] ... | ADD [CONSTRAINT [symbol]] FOREIGN KEY [index_name] (index_col_name,...)reference_definition| ALGORITHM [=] {DEFAULT|INPLACE|COPY} | ALTER [COLUMN]col_name{SET DEFAULTliteral| DROP DEFAULT} | CHANGE [COLUMN]old_col_namenew_col_namecolumn_definition[FIRST|AFTERcol_name] | LOCK [=] {DEFAULT|NONE|SHARED|EXCLUSIVE} | MODIFY [COLUMN]col_namecolumn_definition[FIRST | AFTERcol_name] | DROP [COLUMN]col_name| DROP PRIMARY KEY | DROP {INDEX|KEY}index_name| DROP FOREIGN KEYfk_symbol| DISABLE KEYS | ENABLE KEYS | RENAME [TO|AS]new_tbl_name| ORDER BYcol_name[,col_name] ... | CONVERT TO CHARACTER SETcharset_name[COLLATEcollation_name] | [DEFAULT] CHARACTER SET [=]charset_name[COLLATE [=]collation_name] | DISCARD TABLESPACE | IMPORT TABLESPACE | FORCE | ADD PARTITION (partition_definition) | DROP PARTITIONpartition_names| TRUNCATE PARTITION {partition_names| ALL} | COALESCE PARTITIONnumber| REORGANIZE PARTITIONpartition_namesINTO (partition_definitions) | EXCHANGE PARTITIONpartition_nameWITH TABLEtbl_name| ANALYZE PARTITION {partition_names| ALL} | CHECK PARTITION {partition_names| ALL} | OPTIMIZE PARTITION {partition_names| ALL} | REBUILD PARTITION {partition_names| ALL} | REPAIR PARTITION {partition_names| ALL} | REMOVE PARTITIONINGindex_col_name:col_name[(length)] [ASC | DESC]index_type: USING {BTREE | HASH}index_option: KEY_BLOCK_SIZE [=]value|index_type| WITH PARSERparser_name| COMMENT 'string'table_options:table_option[[,]table_option] ... (seeCREATE TABLEoptions)partition_options: (seeCREATE TABLEoptions)
      ALTER TABLE changes the structure
      of a table. For example, you can add or delete columns, create or
      destroy indexes, change the type of existing columns, or rename
      columns or the table itself. You can also change characteristics
      such as the storage engine used for the table or the table
      comment.
    
      Following the table name, specify the alterations to be made. If
      none are given, ALTER TABLE does
      nothing.
    
      The syntax for many of the permissible alterations is similar to
      clauses of the CREATE TABLE
      statement. See Section 13.1.17, “CREATE TABLE Syntax”, for more
      information.
    
      table_options signifies table options
      of the kind that can be used in the CREATE
      TABLE statement, such as ENGINE,
      AUTO_INCREMENT,
      AVG_ROW_LENGTH, MAX_ROWS, or
      ROW_FORMAT. For a list of all table options and
      a description of each, see Section 13.1.17, “CREATE TABLE Syntax”.
      However, ALTER TABLE ignores the
      DATA DIRECTORY and INDEX
      DIRECTORY table options.
    
      partition_options signifies options
      that can be used with partitioned tables for repartitioning, for
      adding, dropping, merging, and splitting partitions, and for
      performing partitioning maintenance. It is possible for an
      ALTER TABLE statement to contain a
      PARTITION BY or REMOVE
      PARTITIONING clause in an addition to other alter
      specifications, but the PARTITION BY or
      REMOVE PARTITIONING clause must be specified
      last after any other specifications. The ADD
      PARTITION, DROP PARTITION,
      COALESCE PARTITION, REORGANIZE
      PARTITION, EXCHANGE PARTITION,
      ANALYZE PARTITION, CHECK
      PARTITION, and REPAIR PARTITION
      options cannot be combined with other alter specifications in a
      single ALTER TABLE, since the options just
      listed act on individual partitions. For more information about
      partition options, see Section 13.1.17, “CREATE TABLE Syntax”, and
      Section 13.1.7.1, “ALTER TABLE Partition Operations”. For
      information about and examples of ALTER TABLE ...
      EXCHANGE PARTITION statements, see
      Section 19.3.1, “Management of RANGE and LIST Partitions”.
    
      Some operations may result in warnings if attempted on a table for
      which the storage engine does not support the operation. These
      warnings can be displayed with SHOW
      WARNINGS. See Section 13.7.5.41, “SHOW WARNINGS Syntax”.
    
      For information on troubleshooting ALTER
      TABLE, see Section B.5.7.1, “Problems with ALTER TABLE”.
      In most cases, ALTER TABLE makes a
      temporary copy of the original table. MySQL waits for other
      operations that are modifying the table, then proceeds. It
      incorporates the alteration into the copy, deletes the original
      table, and renames the new one. While ALTER
      TABLE is executing, the original table is readable by
      other sessions (with the exception noted shortly). Updates and
      writes to the table that begin after the
      ALTER TABLE operation begins are
      stalled until the new table is ready, then are automatically
      redirected to the new table without any failed updates. The
      temporary copy of the original table is created in the database
      directory of the new table. This can differ from the database
      directory of the original table for ALTER
      TABLE operations that rename the table to a different
      database.
    
      The exception referred to earlier is that
      ALTER TABLE blocks reads (not just
      writes) at the point where it is ready to install a new version of
      the table .frm file, discard the old file,
      and clear outdated table structures from the table and table
      definition caches. At this point, it must acquire an exclusive
      lock. To do so, it waits for current readers to finish, and blocks
      new reads (and writes).
    
      For MyISAM tables, you can speed up index
      re-creation (the slowest part of the alteration process) by
      setting the
      myisam_sort_buffer_size system
      variable to a high value.
    
      For some operations, an in-place ALTER
      TABLE is possible that does not require a temporary
      table:
          For ALTER TABLE 
          without any other options, MySQL simply renames any files that
          correspond to the table tbl_name
          RENAME TO new_tbl_nametbl_name
          without making a copy. (You can also use the
          RENAME TABLE statement to
          rename tables. See Section 13.1.32, “RENAME TABLE Syntax”.) Any
          privileges granted specifically for the renamed table are not
          migrated to the new name. They must be changed manually.
        
          Alterations that modify only table metadata and not table data
          are immediate because the server only needs to alter the table
          .frm file, not touch table contents. The
          following changes are fast alterations that can be made this
          way:
              Renaming a column, except for the
              InnoDB storage engine before
              MySQL 5.6.6.
            
              Changing the default value of a column (except for
              NDB tables; see
              Limitations
              of MySQL Cluster online operations).
            
              Changing the definition of an
              ENUM or
              SET column by adding new
              enumeration or set members to the end
              of the list of valid member values, as long as the storage
              size of the data type does not change. For example, adding
              a member to a SET column
              that has 8 members changes the required storage per value
              from 1 byte to 2 bytes; this will require a table copy.
              Adding members in the middle of the list causes
              renumbering of existing members, which requires a table
              copy.
          ALTER TABLE with ADD
          PARTITION, DROP PARTITION,
          COALESCE PARTITION, REBUILD
          PARTITION, or REORGANIZE
          PARTITION does not create any temporary tables
          (except when used with NDB
          tables); however, these operations can and do create temporary
          partition files.
        
          ADD or DROP operations
          for RANGE or LIST
          partitions are immediate operations or nearly so.
          ADD or COALESCE
          operations for HASH or
          KEY partitions copy data between all
          partitions, unless LINEAR HASH or
          LINEAR KEY was used; this is effectively
          the same as creating a new table, although the
          ADD or COALESCE
          operation is performed partition by partition.
          REORGANIZE operations copy only changed
          partitions and do not touch unchanged ones.
        
          Renaming an index, except for
          InnoDB.
        
      You can force an ALTER TABLE operation that
      would otherwise not require a table copy to use the temporary
      table method (as supported in MySQL 5.0) by setting the
      old_alter_table system variable
      to ON, or specifying
      ALGORITHM=COPY as one of the
      alter_specification clauses. If there
      is a conflict between the old_alter_table
      setting and an ALGORITHM clause with a value
      other than DEFAULT, the
      ALGORITHM clause takes precedence.
      (ALGORITHM = DEFAULT is the same a specifying
      no ALGORITHM clause at all.)
    
      Specifying ALGORITHM=INPLACE makes the
      operation use the in-place technique for clauses and storage
      engines that support it, and fail with an error otherwise, thus
      avoiding a lengthy table copy if you try altering a table that
      uses a different storage engine than you expect. See
      Section 14.10, “InnoDB and Online DDL” for information about online
      DDL for InnoDB tables.
    
      As of MySQL 5.6.16, ALTER TABLE
      upgrades old temporal columns to 5.6 format for ADD
      COLUMN, CHANGE COLUMN,
      MODIFY COLUMN, ADD INDEX,
      and FORCE operations. This conversion cannot be
      done using the INPLACE algorithm because the
      table must be rebuilt, so specifying
      ALGORITHM=INPLACE in these cases results in an
      error. Specify ALGORITHM=COPY if necessary.
    
      Starting with MySQL 5.6.22, an ALTER TABLE
      operation on a multicolumn index used to partition a table by
      KEY cannot be performed online when the
      operation would change the order of the columns. In such cases,
      you must use a copying ALTER TABLE instead.
      (Bug #17896265)
    
      MySQL Cluster also supports online ALTER TABLE
      operations using the ALGORITHM=INPLACE syntax
      in MySQL Cluster NDB 7.3 and later. MySQL Cluster also supports an
      older syntax specific to NDB that uses the
      ONLINE and OFFLINE keywords.
      These keywords are deprecated beginning with MySQL Cluster NDB
      7.3; they continue to be supported in MySQL Cluster NDB 7.4, but
      are subject to removal in a future version of MySQL Cluster. See
      Section 13.1.7.2, “ALTER TABLE Online Operations in MySQL Cluster”, for the exact
      syntax and other particulars.
    
      You can control the level of concurrent reading and writing of the
      table while it is being altered, using the LOCK
      clause. Specifying a non-default value for this clause lets you
      require a certain amount of concurrent access or exclusivity
      during the alter operation, and halts the operation if the
      requested degree of locking is not available. The parameters for
      the LOCK clause are:
LOCK = DEFAULT
          Maximum level of concurrency for the given
          ALGORITHM clause (if any) and
          ALTER TABLE operation: Permit concurrent
          reads and writes if supported. If not, permit concurrent reads
          if supported. If not, enforce exclusive access.
        
LOCK = NONE
If supported, permit concurrent reads and writes. Otherwise, return an error message.
LOCK = SHARED
          If supported, permit concurrent reads but block writes. Note
          that writes will be blocked even if concurrent writes are
          supported by the storage engine for the given
          ALGORITHM clause (if any) and
          ALTER TABLE operation. If concurrent reads
          are not supported, return an error message.
        
LOCK = EXCLUSIVE
          Enforce exclusive access. This will be done even if concurrent
          reads/writes are supported by the storage engine for the given
          ALGORITHM clause (if any) and
          ALTER TABLE operation.
      As of MySQL 5.6.3, you can also use
      ALTER TABLE
       to perform a
      “null” alter operation that rebuilds the table.
      Previously the tbl_name FORCEFORCE option was recognized but
      ignored. As of MySQL 5.6.17,
      online DDL support is
      provided for the FORCE option. For more
      information, see Section 14.10.1, “Overview of Online DDL”.
    
      For NDB tables, operations that add
      and drop indexes on variable-width columns occur online, without
      any table copying and without blocking concurrent DML actions for
      most of their duration. See
      Section 13.1.7.2, “ALTER TABLE Online Operations in MySQL Cluster”.
          To use ALTER TABLE, you need
          ALTER,
          CREATE, and
          INSERT privileges for the
          table. Renaming a table requires
          ALTER and
          DROP on the old table,
          ALTER,
          CREATE, and
          INSERT on the new table.
        
          IGNORE is a MySQL extension to standard
          SQL. It controls how ALTER
          TABLE works if there are duplicates on unique keys
          in the new table or if warnings occur when strict mode is
          enabled. If IGNORE is not specified, the
          copy is aborted and rolled back if duplicate-key errors occur.
          If IGNORE is specified, only one row is
          used of rows with duplicates on a unique key. The other
          conflicting rows are deleted. Incorrect values are truncated
          to the closest matching acceptable value.
        
          As of MySQL 5.6.17, the IGNORE clause is
          deprecated and its use generates a warning.
          IGNORE is removed in MySQL 5.7.
        
          Pending INSERT DELAYED
          statements are lost if a table is write locked and
          ALTER TABLE is used to modify
          the table structure.
        
          table_option signifies a table
          option of the kind that can be used in the
          CREATE TABLE statement, such as
          ENGINE, AUTO_INCREMENT,
          AVG_ROW_LENGTH,
          MAX_ROWS, or ROW_FORMAT.
          For a list of all table options and a description of each, see
          Section 13.1.17, “CREATE TABLE Syntax”. However,
          ALTER TABLE ignores the
          DATA DIRECTORY and INDEX
          DIRECTORY table options.
        
          For example, to convert a table to be an
          InnoDB table, use this statement:
        
ALTER TABLE t1 ENGINE = InnoDB;
          See Section 14.5.4, “Converting Tables from MyISAM to InnoDB” for
          considerations when switching tables to the
          InnoDB storage engine.
        
          When you specify an ENGINE clause,
          ALTER TABLE rebuilds the table.
          This is true even if the table already has the specified
          storage engine.
        
          Running ALTER
          TABLE  on an existing
          tbl_name
          ENGINE=INNODBInnoDB table performs a “null”
          ALTER TABLE operation, which
          can be used to defragment an InnoDB table,
          as described in Section 14.9.4, “Defragmenting a Table”.
          Running ALTER
          TABLE  on
          an tbl_name FORCEInnoDB table performs the same function.
        
          As of MySQL 5.6.17, both
          ALTER TABLE
          
          and tbl_name ENGINE=INNODBALTER TABLE
           use
          online DDL
          (tbl_name FORCEALGORITHM=COPY). For more information, see
          Section 14.10.1, “Overview of Online DDL”.
        
          The outcome of attempting to change a table's storage engine
          is affected by whether the desired storage engine is available
          and the setting of the
          NO_ENGINE_SUBSTITUTION SQL
          mode, as described in Section 5.1.7, “Server SQL Modes”.
        
          To prevent inadvertent loss of data,
          ALTER TABLE cannot be used to
          change the storage engine of a table to
          MERGE or BLACKHOLE.
        
          To change the value of the AUTO_INCREMENT
          counter to be used for new rows, do this:
        
ALTER TABLE t2 AUTO_INCREMENT = value;
          You cannot reset the counter to a value less than or equal to
          the value that is currently in use. For both
          InnoDB and MyISAM, if
          the value is less than or equal to the maximum value currently
          in the AUTO_INCREMENT column, the value is
          reset to the current maximum AUTO_INCREMENT
          column value plus one.
        
          You can issue multiple ADD,
          ALTER, DROP, and
          CHANGE clauses in a single
          ALTER TABLE statement,
          separated by commas. This is a MySQL extension to standard
          SQL, which permits only one of each clause per
          ALTER TABLE statement. For
          example, to drop multiple columns in a single statement, do
          this:
        
ALTER TABLE t2 DROP COLUMN c, DROP COLUMN d;
          CHANGE ,
          col_nameDROP ,
          and col_nameDROP INDEX are MySQL extensions to
          standard SQL.
        
          The word COLUMN is optional and can be
          omitted.
        
          column_definition clauses use the
          same syntax for ADD and
          CHANGE as for CREATE
          TABLE. See Section 13.1.17, “CREATE TABLE Syntax”.
        
          You can rename a column using a CHANGE
           clause.
          To do so, specify the old and new column names and the
          definition that the column currently has. For example, to
          rename an old_col_name
          new_col_name
          column_definitionINTEGER column from
          a to b, you can do this:
        
ALTER TABLE t1 CHANGE a b INTEGER;
          To change a column's type but not the name,
          CHANGE syntax still requires an old and new
          column name, even if they are the same. For example:
        
ALTER TABLE t1 CHANGE b b BIGINT NOT NULL;
          You can also use MODIFY to change a
          column's type without renaming it:
        
ALTER TABLE t1 MODIFY b BIGINT NOT NULL;
          MODIFY is an extension to
          ALTER TABLE for Oracle
          compatibility.
        
          When you use CHANGE or
          MODIFY,
          column_definition must include the
          data type and all attributes that should apply to the new
          column, other than index attributes such as PRIMARY
          KEY or UNIQUE. Attributes present
          in the original definition but not specified for the new
          definition are not carried forward. Suppose that a column
          col1 is defined as INT UNSIGNED
          DEFAULT 1 COMMENT 'my column' and you modify the
          column as follows:
        
ALTER TABLE t1 MODIFY col1 BIGINT;
          The resulting column will be defined as
          BIGINT, but will not include the attributes
          UNSIGNED DEFAULT 1 COMMENT 'my column'. To
          retain them, the statement should be:
        
ALTER TABLE t1 MODIFY col1 BIGINT UNSIGNED DEFAULT 1 COMMENT 'my column';
          When you change a data type using CHANGE or
          MODIFY, MySQL tries to convert existing
          column values to the new type as well as possible.
            This conversion may result in alteration of data. For
            example, if you shorten a string column, values may be
            truncated. To prevent the operation from succeeding if
            conversions to the new data type would result in loss of
            data, enable strict SQL mode before using
            ALTER TABLE (see
            Section 5.1.7, “Server SQL Modes”).
          To add a column at a specific position within a table row, use
          FIRST or AFTER
          . The default is
          to add the column last. You can also use
          col_nameFIRST and AFTER in
          CHANGE or MODIFY
          operations to reorder columns within a table.
        
          
          
          
          
          
          ALTER ... SET DEFAULT or ALTER ...
          DROP DEFAULT specify a new default value for a
          column or remove the old default value, respectively. If the
          old default is removed and the column can be
          NULL, the new default is
          NULL. If the column cannot be
          NULL, MySQL assigns a default value as
          described in Section 11.6, “Data Type Default Values”.
        
          
          
          
          DROP INDEX removes an index.
          This is a MySQL extension to standard SQL. See
          Section 13.1.24, “DROP INDEX Syntax”. If you are unsure of the index
          name, use SHOW INDEX FROM
          .
        tbl_name
          If columns are dropped from a table, the columns are also
          removed from any index of which they are a part. If all
          columns that make up an index are dropped, the index is
          dropped as well. If you use CHANGE or
          MODIFY to shorten a column for which an
          index exists on the column, and the resulting column length is
          less than the index length, MySQL shortens the index
          automatically.
        
          If a table contains only one column, the column cannot be
          dropped. If what you intend is to remove the table, use
          DROP TABLE instead.
        
          
          
          
          DROP PRIMARY KEY drops the
          primary key. If there
          is no primary key, an error occurs. For information about the
          performance characteristics of primary keys, especially for
          InnoDB tables, see
          Section 8.3.2, “Using Primary Keys”.
        
          If you add a UNIQUE INDEX or
          PRIMARY KEY to a table, MySQL stores it
          before any nonunique index to permit detection of duplicate
          keys as early as possible.
        
          Some storage engines permit you to specify an index type when
          creating an index. The syntax for the
          index_type specifier is
          USING .
          For details about type_nameUSING, see
          Section 13.1.13, “CREATE INDEX Syntax”. 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.13, “CREATE INDEX Syntax”.
        
          After an ALTER TABLE statement,
          it may be necessary to run ANALYZE
          TABLE to update index cardinality information. See
          Section 13.7.5.23, “SHOW INDEX Syntax”.
        
          
          ORDER BY enables you to create the new
          table with the rows in a specific order. This option is useful
          primarily when you know that you are mostly to query the rows
          in a certain order most of the time. By using this option
          after major changes to the table, you might be able to get
          higher performance. In some cases, it might make sorting
          easier for MySQL if the table is in order by the column that
          you want to order it by later.
The table does not remain in the specified order after inserts and deletes.
          ORDER BY syntax permits one or more column
          names to be specified for sorting, each of which optionally
          can be followed by ASC or
          DESC to indicate ascending or descending
          sort order, respectively. The default is ascending order. Only
          column names are permitted as sort criteria; arbitrary
          expressions are not permitted. This clause should be given
          last after any other clauses.
        
          ORDER BY does not make sense for
          InnoDB tables because
          InnoDB always orders table rows according
          to the clustered
          index.
            When used on a partitioned table, ALTER TABLE ...
            ORDER BY orders rows within each partition only.
          
          
          
          If you use ALTER TABLE on a
          MyISAM table, all nonunique indexes are
          created in a separate batch (as for
          REPAIR TABLE). This should make
          ALTER TABLE much faster when
          you have many indexes.
        
          For MyISAM tables, key updating can be
          controlled explicitly. Use ALTER TABLE ... DISABLE
          KEYS to tell MySQL to stop updating nonunique
          indexes. Then use ALTER TABLE ... ENABLE
          KEYS to re-create missing indexes.
          MyISAM does this with a special algorithm
          that is much faster than inserting keys one by one, so
          disabling keys before performing bulk insert operations should
          give a considerable speedup. Using ALTER TABLE ...
          DISABLE KEYS requires the
          INDEX privilege in addition to
          the privileges mentioned earlier.
        
          While the nonunique indexes are disabled, they are ignored for
          statements such as SELECT and
          EXPLAIN that otherwise would
          use them.
        
          Before MySQL 5.6.7, using ALTER
          TABLE to change the definition of a foreign key
          column could cause a loss of referential integrity. For
          example, changing a foreign key column that contained
          NULL values to be NOT
          NULL caused the NULL values to be
          the empty string. Similarly, an
          ALTER TABLE
          IGNORE that removed rows in a parent table could
          break referential integrity.
        
          As of 5.6.7, the server prohibits changes to foreign key
          columns that have the potential to cause loss of referential
          integrity. It also prohibits changes to the data type of such
          columns that may be unsafe. For example, changing
          VARCHAR(20) to
          VARCHAR(30) is permitted, but
          changing it to VARCHAR(1024) is
          not because that alters the number of length bytes required to
          store individual values. A workaround is to use
          ALTER TABLE ...
          DROP FOREIGN KEY before changing the column
          definition and
          ALTER TABLE ...
          ADD FOREIGN KEY afterward.
        
          
          
          The FOREIGN KEY and
          REFERENCES clauses are supported by the
          InnoDB and NDB storage
          engines, which implement ADD [CONSTRAINT
          [. See
          Section 14.5.6, “InnoDB and FOREIGN KEY Constraints”. For other
          storage engines, the clauses are parsed but ignored. The
          symbol]] FOREIGN KEY
          [index_name] (...) REFERENCES ...
          (...)CHECK clause is parsed but ignored by all
          storage engines. See Section 13.1.17, “CREATE TABLE Syntax”. The
          reason for accepting but ignoring syntax clauses is for
          compatibility, to make it easier to port code from other SQL
          servers, and to run applications that create tables with
          references. See Section 1.8.2, “MySQL Differences from Standard SQL”.
        
          For ALTER TABLE, unlike
          CREATE TABLE, ADD
          FOREIGN KEY ignores
          index_name if given and uses an
          automatically generated foreign key name. As a workaround,
          include the CONSTRAINT clause to specify
          the foreign key name:
        
ADD CONSTRAINT name FOREIGN KEY (....) ...
            The inline REFERENCES specifications
            where the references are defined as part of the column
            specification are silently ignored. MySQL only accepts
            REFERENCES clauses defined as part of a
            separate FOREIGN KEY specification.
            Partitioned InnoDB tables do not support
            foreign keys. This restriction does not apply to
            NDB tables, including those explicitly
            partitioned by [LINEAR] KEY. See
            Section 19.6.2, “Partitioning Limitations Relating to Storage Engines”,
            for more information.
          
          
          
          The InnoDB and
          NDB storage engines support the
          use of ALTER TABLE to drop
          foreign keys:
        
ALTER TABLEtbl_nameDROP FOREIGN KEYfk_symbol;
For more information, see Section 14.5.6, “InnoDB and FOREIGN KEY Constraints”.
          Prior to MySQL 5.6.6, adding and dropping a foreign key in the
          same ALTER TABLE statement may
          be problematic in some cases and is therefore unsupported.
          Separate statements should be used for each operation. As of
          MySQL 5.6.6, adding and dropping a foreign key in the same
          ALTER TABLE statement is
          supported for
          ALTER TABLE ...
          ALGORITHM=INPLACE but remains unsupported for
          ALTER TABLE ...
          ALGORITHM=COPY.
        
          
          
          For an InnoDB table that is created with
          its own tablespace in an .ibd file, that
          file can be discarded and imported. To discard the
          .ibd file, use this statement:
        
ALTER TABLE tbl_name DISCARD TABLESPACE;
          This deletes the current .ibd file, so be
          sure that you have a backup first. Attempting to modify the
          table contents while the tablespace file is discarded results
          in an error. You can perform the DDL operations listed in
          Section 14.10, “InnoDB and Online DDL” while the tablespace file
          is discarded.
        
          To import the backup .ibd file back into
          the table, copy it into the database directory, and then issue
          this statement:
        
ALTER TABLE tbl_name IMPORT TABLESPACE;
The tablespace file need not necessarily have been created on the server into which it is imported later. In MySQL 5.6, importing a tablespace file from another server works if the both servers have GA (General Availablility) status and their versions are within the same series. Otherwise, the file must have been created on the server into which it is imported.
            The ALTER TABLE
            ... IMPORT TABLESPACE feature does not enforce
            foreign key constraints on imported data.
          
          To change the table default character set and all character
          columns (CHAR,
          VARCHAR,
          TEXT) to a new character set,
          use a statement like this:
        
ALTER TABLEtbl_nameCONVERT TO CHARACTER SETcharset_name[COLLATEcollation_name];
          The statement also changes the collation of all character
          columns. If you specify no COLLATE clause
          to indicate which collation to use, the statement uses default
          collation for the character set. If this collation is
          inappropriate for the intended table use (for example, if it
          would change from a case-sensitive collation to a
          case-insensitive collation), specify a collation explicitly.
        
          For a column that has a data type of
          VARCHAR or one of the
          TEXT types, CONVERT TO
          CHARACTER SET will change the data type as necessary
          to ensure that the new column is long enough to store as many
          characters as the original column. For example, a
          TEXT column has two length
          bytes, which store the byte-length of values in the column, up
          to a maximum of 65,535. For a latin1
          TEXT column, each character
          requires a single byte, so the column can store up to 65,535
          characters. If the column is converted to
          utf8, each character might require up to
          three bytes, for a maximum possible length of 3 × 65,535
          = 196,605 bytes. That length will not fit in a
          TEXT column's length bytes, so
          MySQL will convert the data type to
          MEDIUMTEXT, which is the
          smallest string type for which the length bytes can record a
          value of 196,605. Similarly, a
          VARCHAR column might be
          converted to MEDIUMTEXT.
        
          To avoid data type changes of the type just described, do not
          use CONVERT TO CHARACTER SET. Instead, use
          MODIFY to change individual columns. For
          example:
        
ALTER TABLE t MODIFY latin1_text_col TEXT CHARACTER SET utf8;
ALTER TABLE t MODIFY latin1_varchar_col VARCHAR(M) CHARACTER SET utf8;
          If you specify CONVERT TO CHARACTER SET
          binary, the CHAR,
          VARCHAR, and
          TEXT columns are converted to
          their corresponding binary string types
          (BINARY,
          VARBINARY,
          BLOB). This means that the
          columns no longer will have a character set and a subsequent
          CONVERT TO operation will not apply to
          them.
        
          If charset_name is
          DEFAULT, the database character set is
          used.
            The CONVERT TO operation converts column
            values between the character sets. This is
            not what you want if you have a column
            in one character set (like latin1) but
            the stored values actually use some other, incompatible
            character set (like utf8). In this case,
            you have to do the following for each such column:
          
ALTER TABLE t1 CHANGE c1 c1 BLOB; ALTER TABLE t1 CHANGE c1 c1 TEXT CHARACTER SET utf8;
            The reason this works is that there is no conversion when
            you convert to or from BLOB
            columns.
To change only the default character set for a table, use this statement:
ALTER TABLEtbl_nameDEFAULT CHARACTER SETcharset_name;
          The word DEFAULT is optional. The default
          character set is the character set that is used if you do not
          specify the character set for columns that you add to a table
          later (for example, with ALTER TABLE ... ADD
          column).
      With the mysql_info() C API
      function, you can find out how many rows were copied by
      ALTER TABLE, and (when
      IGNORE is used) how many rows were deleted due
      to duplication of unique key values. See
      Section 23.8.7.35, “mysql_info()”.
        Partitioning-related clauses for ALTER
        TABLE can be used with partitioned tables for
        repartitioning, for adding, dropping, merging, and splitting
        partitions, and for performing partitioning maintenance.
            Simply using a partition_options
            clause with ALTER TABLE on a
            partitioned table repartitions the table according to the
            partitioning scheme defined by the
            partition_options. This clause
            always begins with PARTITION BY, and
            follows the same syntax and other rules as apply to the
            partition_options clause for
            CREATE TABLE (see
            Section 13.1.17, “CREATE TABLE Syntax”, for more detailed
            information), and can also be used to partition an existing
            table that is not already partitioned. For example, consider
            a (nonpartitioned) table defined as shown here:
          
CREATE TABLE t1 (
    id INT,
    year_col INT
);
            This table can be partitioned by HASH,
            using the id column as the partitioning
            key, into 8 partitions by means of this statement:
          
ALTER TABLE t1
    PARTITION BY HASH(id)
    PARTITIONS 8;
            MySQL 5.6.11 and later supports an
            ALGORITHM option with
            [SUB]PARTITION BY [LINEAR] KEY.
            ALGORITHM=1 causes the server to use the
            same key-hashing functions as MySQL 5.1 when computing the
            placement of rows in partitions;
            ALGORITHM=2 means that the server employs
            the key-hashing functions implemented and used by default
            for new KEY partitioned tables in MySQL
            5.5 and later. (Partitioned tables created with the
            key-hashing functions employed in MySQL 5.5 and later cannot
            be used by a MySQL 5.1 server.) Not specifying the option
            has the same effect as using ALGORITHM=2.
            This option is intended for use chiefly when upgrading or
            downgrading [LINEAR] KEY partitioned
            tables between MySQL 5.1 and later MySQL versions, or for
            creating tables partitioned by KEY or
            LINEAR KEY on a MySQL 5.5 or later server
            which can be used on a MySQL 5.1 server.
          
            To upgrade a KEY partitioned table that
            was created in MySQL 5.1, first execute
            SHOW CREATE TABLE and note
            the exact columns and number of partitions shown. Now
            execute an ALTER TABLE statement using
            exactly the same column list and number of partitions as in
            the CREATE TABLE statement, while adding
            ALGORITHM=2 immediately following the
            PARTITION BY keywords. (You should also
            include the LINEAR keyword if it was used
            for the original table definition.) An example from a
            session in the mysql client is shown
            here:
          
mysql>SHOW CREATE TABLE p\G*************************** 1. row *************************** Table: p Create Table: CREATE TABLE `p` ( `id` int(11) NOT NULL AUTO_INCREMENT, `cd` datetime NOT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1 /*!50100 PARTITION BY LINEAR KEY (id) PARTITIONS 32 */ 1 row in set (0.00 sec) mysql>ALTER TABLE pPARTITION BY LINEAR KEY ALGORITHM=2 (id) PARTITIONS 32;Query OK, 0 rows affected (5.34 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql>SHOW CREATE TABLE p\G*************************** 1. row *************************** Table: p Create Table: CREATE TABLE `p` ( `id` int(11) NOT NULL AUTO_INCREMENT, `cd` datetime NOT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=latin1 /*!50100 PARTITION BY LINEAR KEY (id) PARTITIONS 32 */ 1 row in set (0.00 sec)
            Downgrading a table created using the default key-hashing
            used in MySQL 5.5 and later to enable its use by a MySQL 5.1
            server is similar, except in this case you should use
            ALGORITHM=1 to force the table's
            partitions to be rebuilt using the MySQL 5.1 key-hashing
            functions. It is recommended that you not do this except
            when necessary for compatibility with a MySQL 5.1 server, as
            the improved KEY hashing functions used
            by default in MySQL 5.5 and later provide fixes for a number
            of issues found in the older implementation.
              A table upgraded by means of ALTER TABLE ...
              PARTITION BY ALGORITHM=2 [LINEAR] KEY ... can no
              longer be used by a MySQL 5.1 server. (Such a table would
              need to be downgraded with ALTER TABLE ...
              PARTITION BY ALGORITHM=1 [LINEAR] KEY ... before
              it could be used again by a MySQL 5.1 server.)
            The table that results from using an ALTER TABLE
            ... PARTITION BY statement must follow the same
            rules as one created using CREATE TABLE ...
            PARTITION BY. This includes the rules governing
            the relationship between any unique keys (including any
            primary key) that the table might have, and the column or
            columns used in the partitioning expression, as discussed in
            Section 19.6.1, “Partitioning Keys, Primary Keys, and Unique Keys”.
            The CREATE TABLE ... PARTITION BY rules
            for specifying the number of partitions also apply to
            ALTER TABLE ... PARTITION BY.
          
            The partition_definition clause
            for ALTER TABLE ADD PARTITION supports
            the same options as the clause of the same name for the
            CREATE TABLE statement. (See
            Section 13.1.17, “CREATE TABLE Syntax”, for the syntax and
            description.) Suppose that you have the partitioned table
            created as shown here:
          
CREATE TABLE t1 (
    id INT,
    year_col INT
)
PARTITION BY RANGE (year_col) (
    PARTITION p0 VALUES LESS THAN (1991),
    PARTITION p1 VALUES LESS THAN (1995),
    PARTITION p2 VALUES LESS THAN (1999)
);
            You can add a new partition p3 to this
            table for storing values less than 2002
            as follows:
          
ALTER TABLE t1 ADD PARTITION (PARTITION p3 VALUES LESS THAN (2002));
            DROP PARTITION can be used to drop one or
            more RANGE or LIST
            partitions. This statement cannot be used with
            HASH or KEY
            partitions; instead, use COALESCE
            PARTITION (see below). Any data that was stored in
            the dropped partitions named in the
            partition_names list is
            discarded. For example, given the table
            t1 defined previously, you can drop the
            partitions named p0 and
            p1 as shown here:
          
ALTER TABLE t1 DROP PARTITION p0, p1;
              DROP PARTITION does not work with
              tables that use the NDB
              storage engine. See
              Section 19.3.1, “Management of RANGE and LIST Partitions”, and
              Section 18.1.6, “Known Limitations of MySQL Cluster”.
            ADD PARTITION and DROP
            PARTITION do not currently support IF
            [NOT] EXISTS.
          
            Renames of partitioned table are supported. You can rename
            individual partitions indirectly using ALTER TABLE
            ... REORGANIZE PARTITION; however, this operation
            makes a copy of the partition's data..
          
            In MySQL 5.6, it is possible to delete rows
            from selected partitions using the TRUNCATE
            PARTITION option. This option takes a
            comma-separated list of one or more partition names. For
            example, consider the table t1 as defined
            here:
          
CREATE TABLE t1 (
    id INT,
    year_col 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 (2003),
    PARTITION p4 VALUES LESS THAN (2007)
);
            To delete all rows from partition p0, you
            can use the following statement:
          
ALTER TABLE t1 TRUNCATE PARTITION p0;
            The statement just shown has the same effect as the
            following DELETE statement:
          
DELETE FROM t1 WHERE year_col < 1991;
            When truncating multiple partitions, the partitions do not
            have to be contiguous: This can greatly simplify delete
            operations on partitioned tables that would otherwise
            require very complex WHERE conditions if
            done with DELETE statements.
            For example, this statement deletes all rows from partitions
            p1 and p3:
          
ALTER TABLE t1 TRUNCATE PARTITION p1, p3;
            An equivalent DELETE
            statement is shown here:
          
DELETE FROM t1 WHERE 
    (year_col >= 1991 AND year_col < 1995)
    OR
    (year_col >= 2003 AND year_col < 2007);
            You can also use the ALL keyword in place
            of the list of partition names; in this case, the statement
            acts on all partitions in the table.
          
            TRUNCATE PARTITION merely deletes rows;
            it does not alter the definition of the table itself, or of
            any of its partitions.
              TRUNCATE PARTITION does not work with
              subpartitions.
            You can verify that the rows were dropped by checking the
            INFORMATION_SCHEMA.PARTITIONS table,
            using a query such as this one:
          
SELECT PARTITION_NAME, TABLE_ROWS 
    FROM INFORMATION_SCHEMA.PARTITIONS 
    WHERE TABLE_NAME = 't1';
            TRUNCATE PARTITION is supported only for
            partitioned tables that use the
            MyISAM,
            InnoDB, or
            MEMORY storage engine. It also
            works on BLACKHOLE tables (but
            has no effect). It is not supported for
            ARCHIVE tables.
          
            COALESCE PARTITION can be used with a
            table that is partitioned by HASH or
            KEY to reduce the number of partitions by
            number. Suppose that you have
            created table t2 using the following
            definition:
          
CREATE TABLE t2 (
    name VARCHAR (30),
    started DATE
)
PARTITION BY HASH( YEAR(started) )
PARTITIONS 6;
            You can reduce the number of partitions used by
            t2 from 6 to 4 using the following
            statement:
          
ALTER TABLE t2 COALESCE PARTITION 2;
            The data contained in the last
            number partitions will be merged
            into the remaining partitions. In this case, partitions 4
            and 5 will be merged into the first 4 partitions (the
            partitions numbered 0, 1, 2, and 3).
          
            To change some but not all the partitions used by a
            partitioned table, you can use REORGANIZE
            PARTITION. This statement can be used in several
            ways:
                To merge a set of partitions into a single partition.
                This can be done by naming several partitions in the
                partition_names list and
                supplying a single definition for
                partition_definition.
              
                To split an existing partition into several partitions.
                You can accomplish this by naming a single partition for
                partition_names and providing
                multiple
                partition_definitions.
              
                To change the ranges for a subset of partitions defined
                using VALUES LESS THAN or the value
                lists for a subset of partitions defined using
                VALUES IN.
              
                This statement may also be used without the
                partition_names INTO
                (partition_definitions)HASH partitioning to force
                redistribution of data. (Currently, only
                NDB tables are
                automatically partitioned in this way.) This is useful
                in MySQL Cluster where, after you have added new MySQL
                Cluster data nodes online to an existing MySQL Cluster,
                you wish to redistribute existing MySQL Cluster table
                data to the new data nodes. In such cases, you should
                invoke the statement with the ONLINE
                option; in other words, as shown here:
              
ALTER ONLINE TABLE table REORGANIZE PARTITION;
                You cannot perform other DDL concurrently with online
                table reorganization—that is, no other DDL
                statements can be issued while an ALTER ONLINE
                TABLE ... REORGANIZE PARTITION statement is
                executing. For more information about adding MySQL
                Cluster data nodes online, see
                Section 18.5.13, “Adding MySQL Cluster Data Nodes Online”.
              
                ALTER ONLINE TABLE ... REORGANIZE
                PARTITION does not work with tables which were
                created using the MAX_ROWS option,
                because it uses the constant MAX_ROWS
                value specified in the original
                CREATE TABLE statement to
                determine the number of partitions required, so no new
                partitions are created. You can use ALTER
                ONLINE TABLE ...
                MAX_ROWS= to
                increase the maximum number of rows for the table; after
                this, rowsALTER ONLINE TABLE ... REORGANIZE
                PARTITION can use this new, larger value to
                increase the number of partitions. The value of
                rows must be greater than the
                value specified for MAX_ROWS in the
                original CREATE TABLE statement for
                this to work.
              
                Attempting to use REORGANIZE
                PARTITION without the
                partition_names INTO
                (partition_definitions)
              For partitions that have not been explicitly named, MySQL
              automatically provides the default names
              p0, p1,
              p2, and so on. The same is true with
              regard to subpartitions.
            For more detailed information about and examples of
            ALTER TABLE ... REORGANIZE PARTITION
            statements, see
            Section 19.3.1, “Management of RANGE and LIST Partitions”.
          
            In MySQL 5.6, it is possible to exchange a
            table partition or subpartition with a table using the
            ALTER TABLE ...
            EXCHANGE PARTITION statement—that is, to
            move any existing rows in the partition or subpartition to
            the nonpartitioned table, and any existing rows in the
            nonpartitioned table to the table partition or subpartition.
          
For usage information and examples, see Section 19.3.3, “Exchanging Partitions and Subpartitions with Tables”.
            Several additional options provide partition maintenance and
            repair functionality analogous to that implemented for
            nonpartitioned tables by statements such as
            CHECK TABLE and
            REPAIR TABLE (which are also
            supported for partitioned tables; see
            Section 13.7.2, “Table Maintenance Statements” for more
            information). These include ANALYZE
            PARTITION, CHECK PARTITION,
            OPTIMIZE PARTITION, REBUILD
            PARTITION, and REPAIR
            PARTITION. Each of these options takes a
            partition_names clause consisting
            of one or more names of partitions, separated by commas. The
            partitions must already exist in the table to be altered.
            You can also use the ALL keyword in place
            of partition_names, in which case
            the statement acts on all partitions in the table. For more
            information and examples, see
            Section 19.3.4, “Maintenance of Partitions”.
          
            Some MySQL storage engines, such as
            InnoDB, do not support
            per-partition optimization. For a partitioned table using
            such a storage engine, ALTER TABLE ... OPTIMIZE
            PARTITION rebuilds the entire table. This is a
            known issue. Beginning with MySQL 5.6.9, running this
            statement on such a table causes the entire table to rebuilt
            and analyzed, and an appropriate warning to be issued. (Bug
            #11751825, Bug #42822)
          
            To work around this problem, use the statements
            ALTER TABLE ... REBUILD PARTITION and
            ALTER TABLE ... ANALYZE PARTITION
            instead.
          
            The ANALYZE PARTITION, CHECK
            PARTITION, OPTIMIZE PARTITION,
            and REPAIR PARTITION options are not
            permitted for tables which are not partitioned.
          
            REMOVE PARTITIONING enables you to remove
            a table's partitioning without otherwise affecting the table
            or its data. This option can be combined with other
            ALTER TABLE options such as
            those used to add, drop, or rename columns or indexes.
          
            Using the ENGINE option with
            ALTER TABLE changes the
            storage engine used by the table without affecting the
            partitioning.
        Prior to MySQL 5.6.6, when ALTER TABLE ... EXCHANGE
        PARTITION or ALTER TABLE ... TRUNCATE
        PARTITION was run against a partitioned table that
        used MyISAM (or another storage
        engine that makes use of table-level locking), the entire
        partitioned table was locked; in MySQL 5.6.6 and later, in such
        cases, only those partitions that are actually read from are
        locked. This did not (and does not) affect partitioned tables
        using a storage engine—such as
        InnoDB—that employs row-level
        locking. See Section 19.6.4, “Partitioning and Locking”.
      
        It is possible for an ALTER TABLE
        statement to contain a PARTITION BY or
        REMOVE PARTITIONING clause in an addition to
        other alter specifications, but the PARTITION
        BY or REMOVE PARTITIONING clause
        must be specified last after any other specifications.
      
        The ADD PARTITION, DROP
        PARTITION, COALESCE PARTITION,
        REORGANIZE PARTITION, ANALYZE
        PARTITION, CHECK PARTITION, and
        REPAIR PARTITION options cannot be combined
        with other alter specifications in a single ALTER
        TABLE, since the options just listed act on individual
        partitions. For more information, see
        Section 13.1.7.1, “ALTER TABLE Partition Operations”.
      
        Only a single instance of any one of the following options can
        be used in a given ALTER TABLE
        statement: PARTITION BY, ADD
        PARTITION, DROP PARTITION,
        TRUNCATE PARTITION, EXCHANGE
        PARTITION, REORGANIZE PARTITION, or
        COALESCE PARTITION, ANALYZE
        PARTITION, CHECK PARTITION,
        OPTIMIZE PARTITION, REBUILD
        PARTITION, REMOVE PARTITIONING.
      
For example, the following two statements are invalid:
ALTER TABLE t1 ANALYZE PARTITION p1, ANALYZE PARTITION p2; ALTER TABLE t1 ANALYZE PARTITION p1, CHECK PARTITION p2;
        In the first case, you can analyze partitions
        p1 and p2 of table
        t1 concurrently using a single statement with
        a single ANALYZE PARTITION option that lists
        both of the partitions to be analyzed, like this:
      
ALTER TABLE t1 ANALYZE PARTITION p1, p2;
        In the second case, it is not possible to perform
        ANALYZE and CHECK
        operations on different partitions of the same table
        concurrently. Instead, you must issue two separate statements,
        like this:
      
ALTER TABLE t1 ANALYZE PARTITION p1; ALTER TABLE t1 CHECK PARTITION p2;
        ANALYZE, CHECK,
        OPTIMIZE, REBUILD,
        REPAIR, and TRUNCATE
        operations are not supported for subpartitions.
        This section discusses online table schema changes as
        implemented in MySQL Cluster 5.1, using a syntax specific to
        NDB that is now deprecated and
        subject to removal in a future version of MySQL Cluster. This
        syntax is not supported by any other storage engine, including
        InnoDB. MySQL Cluster NDB 7.3 and
        later support the standard ALTER
        TABLE syntax employed by the MySQL Server
        (ALGORITHM=DEFAULT|INPLACE|COPY), and
        described elsewhere in this section.
      
        Operations that add and drop indexes on variable-width columns
        of NDB tables occur online. Online
        operations are noncopying; that is, they do not require that
        indexes be re-created. They do not lock the table being altered
        from access by other API nodes in a MySQL Cluster (but see
        Limitations later in this section). Such
        operations do not require single user mode for
        NDB table alterations made in a
        cluster with multiple API nodes; transactions can continue
        uninterrupted during online DDL operations.
      
        The ONLINE keyword can be used to perform
        online ADD COLUMN, ADD
        INDEX (including CREATE INDEX
        statements), and DROP INDEX operations on
        NDB tables. Online renaming of
        NDB tables is also supported.
          The ONLINE and OFFLINE
          keywords are supported only in MySQL Cluster. In standard
          MySQL Server 5.6 releases, attempting to use the
          ONLINE or OFFLINE
          keyword in an ALTER TABLE,
          CREATE INDEX, or
          DROP INDEX statement results in
          an error.
        
          The ONLINE and OFFLINE
          keywords are deprecated beginning with MySQL Cluster NDB 7.3.
          They continue to be supported in MySQL Cluster NDB 7.4, but
          are subject to removal in a future version of MySQL Cluster.
        Currently you cannot add disk-based columns to
        NDB tables online. This means that,
        if you wish to add an in-memory column to an
        NDB table that uses a table-level
        STORAGE DISK option, you must declare the new
        column as using memory-based storage explicitly. For
        example—assuming that you have already created tablespace
        ts1—suppose that you create table
        t1 as follows:
      
mysql>CREATE TABLE t1 (>c1 INT NOT NULL PRIMARY KEY,>c2 VARCHAR(30)>)>TABLESPACE ts1 STORAGE DISK>ENGINE NDB;Query OK, 0 rows affected (1.73 sec) Records: 0 Duplicates: 0 Warnings: 0
You can add a new in-memory column to this table online as shown here:
mysql> ALTER ONLINE TABLE t1 ADD COLUMN c3 INT COLUMN_FORMAT DYNAMIC STORAGE MEMORY;
Query OK, 0 rows affected (1.25 sec)
Records: 0  Duplicates: 0  Warnings: 0
        This statement fails if the STORAGE MEMORY
        option is omitted:
      
mysql> ALTER ONLINE TABLE t1 ADD COLUMN c3 INT COLUMN_FORMAT DYNAMIC;
ERROR 1235 (42000): This version of MySQL doesn't yet support
'ALTER ONLINE TABLE t1 ADD COLUMN c3 INT COLUMN_FORMAT DYNAMIC'
        If you omit the COLUMN_FORMAT DYNAMIC option,
        the dynamic column format is employed automatically, but a
        warning is issued, as shown here:
      
mysql>ALTER ONLINE TABLE t1 ADD COLUMN c3 INT STORAGE MEMORY;Query OK, 0 rows affected, 1 warning (1.17 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql>SHOW WARNINGS;+---------+------+---------------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------------+ | Warning | 1478 | Converted FIXED field to DYNAMIC to enable on-line ADD COLUMN | +---------+------+---------------------------------------------------------------+ 1 row in set (0.00 sec) mysql>SHOW CREATE TABLE t1\G*************************** 1. row *************************** Table: t1 Create Table: CREATE TABLE `t1` ( `c1` int(11) NOT NULL, `c2` varchar(30) DEFAULT NULL, `c3` int(11) /*!50120 STORAGE MEMORY */ /*!50120 COLUMN_FORMAT DYNAMIC */ DEFAULT NULL, `t4` int(11) /*!50120 STORAGE MEMORY */ DEFAULT NULL, PRIMARY KEY (`c1`) ) /*!50100 TABLESPACE ts_1 STORAGE DISK */ ENGINE=ndbcluster DEFAULT CHARSET=latin1 1 row in set (0.03 sec)
          The STORAGE and
          COLUMN_FORMAT keywords are supported only
          in MySQL Cluster; in any other version of MySQL, attempting to
          use either of these keywords in a CREATE
          TABLE or ALTER TABLE
          statement results in an error.
        It is also possible to use the statement ALTER ONLINE
        TABLE ... REORGANIZE PARTITION with no
        partition_names INTO
        (partition_definitions)NDB tables. This can be
        used to redistribute MySQL Cluster data among new data nodes
        that have been added to the cluster online. For more information
        about this statement, see
        Section 13.1.7.1, “ALTER TABLE Partition Operations” For more
        information about adding data nodes online to a MySQL Cluster,
        see Section 18.5.13, “Adding MySQL Cluster Data Nodes Online”.
        Online DROP COLUMN operations are not
        supported.
      
        Online ALTER TABLE,
        CREATE INDEX, or
        DROP INDEX statements that add
        columns or add or drop indexes are subject to the following
        limitations:
            A given online ALTER TABLE
            can use only one of ADD COLUMN,
            ADD INDEX, or DROP
            INDEX. One or more columns can be added online in
            a single statement; only one index may be created or dropped
            online in a single statement.
          
            The table being altered is not locked with respect to API
            nodes other than the one on which an online
            ALTER TABLE ADD
            COLUMN, ADD INDEX, or
            DROP INDEX operation (or
            CREATE INDEX or
            DROP INDEX statement) is run.
            However, the table is locked against any other operations
            originating on the same API node while
            the online operation is being executed.
          
            The table to be altered must have an explicit primary key;
            the hidden primary key created by the
            NDB storage engine is not
            sufficient for this purpose.
          
The storage engine used by the table cannot be changed online.
            When used with MySQL Cluster Disk Data tables, it is not
            possible to change the storage type (DISK
            or MEMORY) of a column online. This
            means, that when you add or drop an index in such a way that
            the operation would be performed online, and you want the
            storage type of the column or columns to be changed, you
            must use the OFFLINE keyword in the
            statement that adds or drops the index.
        Columns to be added online cannot use the
        BLOB or
        TEXT type, and must meet the
        following criteria:
            The columns must be dynamic; that is, it must be possible to
            create them using COLUMN_FORMAT DYNAMIC.
            If you omit the COLUMN_FORMAT DYNAMIC
            option, the dynamic column format is employed automatically.
          
            The columns must permit NULL values and
            not have any explicit default value other than
            NULL. Columns added online are
            automatically created as DEFAULT NULL, as
            can be seen here:
          
mysql>CREATE TABLE t1 (>c1 INT NOT NULL AUTO_INCREMENT PRIMARY KEY>) ENGINE=NDB;Query OK, 0 rows affected (1.44 sec) mysql>ALTER ONLINE TABLE t1>ADD COLUMN c2 INT,>ADD COLUMN c3 INT;Query OK, 0 rows affected, 2 warnings (0.93 sec) mysql>SHOW CREATE TABLE t1\G*************************** 1. row *************************** Table: t1 Create Table: CREATE TABLE `t1` ( `c1` int(11) NOT NULL AUTO_INCREMENT, `c2` int(11) DEFAULT NULL, `c3` int(11) DEFAULT NULL, PRIMARY KEY (`c1`) ) ENGINE=ndbcluster DEFAULT CHARSET=latin1 1 row in set (0.00 sec)
            The columns must be added following any existing columns. If
            you attempt to add a column online before any existing
            columns or using the FIRST keyword, the
            statement fails with an error.
          
Existing table columns cannot be reordered online.
        For online ALTER TABLE operations
        on NDB tables, fixed-format columns
        are converted to dynamic when they are added online, or when
        indexes are created or dropped online, as shown here:
      
mysql>CREATE TABLE t1 (>c1 INT NOT NULL AUTO_INCREMENT PRIMARY KEY>) ENGINE=NDB;Query OK, 0 rows affected (1.44 sec) mysql>ALTER ONLINE TABLE t1 ADD COLUMN c2 INT, ADD COLUMN c3 INT;Query OK, 0 rows affected, 2 warnings (0.93 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql>SHOW WARNINGS;+---------+------+---------------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------------+ | Warning | 1475 | Converted FIXED field to DYNAMIC to enable on-line ADD COLUMN | | Warning | 1475 | Converted FIXED field to DYNAMIC to enable on-line ADD COLUMN | +---------+------+---------------------------------------------------------------+ 2 rows in set (0.00 sec)
Existing columns, including the table's primary key, need not be dynamic; only the column or columns to be added online must be dynamic.
mysql>CREATE TABLE t2 (>c1 INT NOT NULL AUTO_INCREMENT PRIMARY KEY COLUMN_FORMAT FIXED>) ENGINE=NDB;Query OK, 0 rows affected (2.10 sec) mysql>ALTER ONLINE TABLE t2 ADD COLUMN c2 INT;Query OK, 0 rows affected, 1 warning (0.78 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql>SHOW WARNINGS;+---------+------+---------------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------------+ | Warning | 1475 | Converted FIXED field to DYNAMIC to enable on-line ADD COLUMN | +---------+------+---------------------------------------------------------------+ 1 row in set (0.00 sec)
        Columns are not converted from FIXED to
        DYNAMIC column format by renaming operations.
        For more information about COLUMN_FORMAT, see
        Section 13.1.17, “CREATE TABLE Syntax”.
      
        The KEY, CONSTRAINT, and
        IGNORE keywords are supported in
        ALTER TABLE statements using the
        ONLINE keyword.
        Begin with a table t1 that is created as
        shown here:
      
CREATE TABLE t1 (a INTEGER,b CHAR(10));
        To rename the table from t1 to
        t2:
      
ALTER TABLE t1 RENAME t2;
        To change column a from
        INTEGER to TINYINT NOT
        NULL (leaving the name the same), and to change column
        b from CHAR(10) to
        CHAR(20) as well as renaming it from
        b to c:
      
ALTER TABLE t2 MODIFY a TINYINT NOT NULL, CHANGE b c CHAR(20);
        To add a new TIMESTAMP column
        named d:
      
ALTER TABLE t2 ADD d TIMESTAMP;
        To add an index on column d and a
        UNIQUE index on column a:
      
ALTER TABLE t2 ADD INDEX (d), ADD UNIQUE (a);
        To remove column c:
      
ALTER TABLE t2 DROP COLUMN c;
        To add a new AUTO_INCREMENT integer column
        named c:
      
ALTER TABLE t2 ADD c INT UNSIGNED NOT NULL AUTO_INCREMENT, ADD PRIMARY KEY (c);
        We indexed c (as a PRIMARY
        KEY) because AUTO_INCREMENT columns
        must be indexed, and we declare c as
        NOT NULL because primary key columns cannot
        be NULL.
      
        For NDB tables, it is also possible
        to change the storage type used for a table or column. For
        example, consider an NDB table
        created as shown here:
      
mysql> CREATE TABLE t1 (c1 INT) TABLESPACE ts_1 ENGINE NDB;
Query OK, 0 rows affected (1.27 sec)
        To convert this table to disk-based storage, you can use the
        following ALTER TABLE statement:
      
mysql>ALTER TABLE t1 TABLESPACE ts_1 STORAGE DISK;Query OK, 0 rows affected (2.99 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql>SHOW CREATE TABLE t1\G*************************** 1. row *************************** Table: t1 Create Table: CREATE TABLE `t1` ( `c1` int(11) DEFAULT NULL ) /*!50100 TABLESPACE ts_1 STORAGE DISK */ ENGINE=ndbcluster DEFAULT CHARSET=latin1 1 row in set (0.01 sec)
        It is not necessary that the tablespace was referenced when the
        table was originally created; however, the tablespace must be
        referenced by the ALTER TABLE:
      
mysql>CREATE TABLE t2 (c1 INT) ts_1 ENGINE NDB;Query OK, 0 rows affected (1.00 sec) mysql>ALTER TABLE t2 STORAGE DISK;ERROR 1005 (HY000): Can't create table 'c.#sql-1750_3' (errno: 140) mysql>ALTER TABLE t2 TABLESPACE ts_1 STORAGE DISK;Query OK, 0 rows affected (3.42 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql>SHOW CREATE TABLE t2\G*************************** 1. row *************************** Table: t1 Create Table: CREATE TABLE `t2` ( `c1` int(11) DEFAULT NULL ) /*!50100 TABLESPACE ts_1 STORAGE DISK */ ENGINE=ndbcluster DEFAULT CHARSET=latin1 1 row in set (0.01 sec)
        To change the storage type of an individual column, you can use
        ALTER TABLE ... MODIFY [COLUMN]. For example,
        suppose you create a MySQL Cluster Disk Data table with two
        columns, using this CREATE TABLE
        statement:
      
mysql>CREATE TABLE t3 (c1 INT, c2 INT)->TABLESPACE ts_1 STORAGE DISK ENGINE NDB;Query OK, 0 rows affected (1.34 sec)
        To change column c2 from disk-based to
        in-memory storage, include a STORAGE MEMORY clause in the column
        definition used by the ALTER TABLE statement, as shown here:
      
mysql> ALTER TABLE t3 MODIFY c2 INT STORAGE MEMORY;
Query OK, 0 rows affected (3.14 sec)
Records: 0  Duplicates: 0  Warnings: 0
        You can make an in-memory column into a disk-based column by
        using STORAGE DISK in a similar fashion.
      
        Column c1 uses disk-based storage, since this
        is the default for the table (determined by the table-level
        STORAGE DISK clause in the
        CREATE TABLE statement). However,
        column c2 uses in-memory storage, as can be
        seen here in the output of SHOW CREATE
        TABLE:
      
mysql> SHOW CREATE TABLE t3\G
*************************** 1. row ***************************
       Table: t3
Create Table: CREATE TABLE `t3` (
  `c1` int(11) DEFAULT NULL,
  `c2` int(11) /*!50120 STORAGE MEMORY */ DEFAULT NULL
) /*!50100 TABLESPACE ts_1 STORAGE DISK */ ENGINE=ndbcluster DEFAULT CHARSET=latin1
1 row in set (0.02 sec)
        When you add an AUTO_INCREMENT column, column
        values are filled in with sequence numbers automatically. For
        MyISAM tables, you can set the first sequence
        number by executing SET
        INSERT_ID= before
        valueALTER TABLE or by using the
        AUTO_INCREMENT=
        table option. See Section 5.1.4, “Server System Variables”.
      value
        With MyISAM tables, if you do not change the
        AUTO_INCREMENT column, the sequence number is
        not affected. If you drop an AUTO_INCREMENT
        column and then add another AUTO_INCREMENT
        column, the numbers are resequenced beginning with 1.
      
        When replication is used, adding an
        AUTO_INCREMENT column to a table might not
        produce the same ordering of the rows on the slave and the
        master. This occurs because the order in which the rows are
        numbered depends on the specific storage engine used for the
        table and the order in which the rows were inserted. If it is
        important to have the same order on the master and slave, the
        rows must be ordered before assigning an
        AUTO_INCREMENT number. Assuming that you want
        to add an AUTO_INCREMENT column to the table
        t1, the following statements produce a new
        table t2 identical to t1
        but with an AUTO_INCREMENT column:
      
CREATE TABLE t2 (id INT AUTO_INCREMENT PRIMARY KEY) SELECT * FROM t1 ORDER BY col1, col2;
        This assumes that the table t1 has columns
        col1 and col2.
      
        This set of statements will also produce a new table
        t2 identical to t1, with
        the addition of an AUTO_INCREMENT column:
      
CREATE TABLE t2 LIKE t1; ALTER TABLE t2 ADD id INT AUTO_INCREMENT PRIMARY KEY; INSERT INTO t2 SELECT * FROM t1 ORDER BY col1, col2;
          To guarantee the same ordering on both master and slave,
          all columns of t1 must
          be referenced in the ORDER BY clause.
        Regardless of the method used to create and populate the copy
        having the AUTO_INCREMENT column, the final
        step is to drop the original table and then rename the copy:
      
DROP TABLE t1; ALTER TABLE t2 RENAME t1;
ALTER TABLESPACEtablespace_name{ADD|DROP} DATAFILE 'file_name' [INITIAL_SIZE [=]size] [WAIT] ENGINE [=]engine_name
This statement can be used either to add a new data file, or to drop a data file from a tablespace.
      The ADD DATAFILE variant enables you to specify
      an initial size using an INITIAL_SIZE clause,
      where size is measured in bytes; the
      default value is 134217728 (128 MB). Prior to MySQL Cluster NDB
      7.3.2, this value was required to be specified using digits (Bug
      #13116514, Bug #16104705, Bug #62858); in MySQL Cluster NDB 7.3.2
      and later, you may optionally follow
      size with a one-letter abbreviation for
      an order of magnitude, similar to those used in
      my.cnf. Generally, this is one of the letters
      M (megabytes) or G
      (gigabytes).
All MySQL Cluster Disk Data objects share the same namespace. This means that each Disk Data object must be uniquely named (and not merely each Disk Data object of a given type). For example, you cannot have a tablespace and an data file with the same name, or an undo log file and a tablespace with the same name.
      On 32-bit systems, the maximum supported value for
      INITIAL_SIZE is 4294967296 (4 GB). (Bug #29186)
    
      INITIAL_SIZE is rounded, explicitly, as for
      CREATE TABLESPACE.
    
      Once a data file has been created, its size cannot be changed;
      however, you can add more data files to the tablespace using
      additional ALTER TABLESPACE ... ADD DATAFILE
      statements.
    
      Using DROP DATAFILE with
      ALTER TABLESPACE drops the data
      file 'file_name' from the tablespace.
      You cannot drop a data file from a tablespace which is in use by
      any table; in other words, the data file must be empty (no extents
      used). See Section 18.5.12.1, “MySQL Cluster Disk Data Objects”. In
      addition, any data file to be dropped must previously have been
      added to the tablespace with CREATE
      TABLESPACE or ALTER
      TABLESPACE.
    
      Both ALTER TABLESPACE ... ADD DATAFILE and
      ALTER TABLESPACE ... DROP DATAFILE require an
      ENGINE clause which specifies the storage
      engine used by the tablespace. Currently, the only accepted values
      for engine_name are
      NDB and
      NDBCLUSTER.
    
      WAIT is parsed but otherwise ignored, and so
      has no effect in MySQL 5.6. It is intended for future
      expansion.
    
      When ALTER TABLESPACE ... ADD DATAFILE is used
      with ENGINE = NDB, a data file is created on
      each Cluster data node. You can verify that the data files were
      created and obtain information about them by querying the
      INFORMATION_SCHEMA.FILES table. For
      example, the following query shows all data files belonging to the
      tablespace named newts:
    
mysql>SELECT LOGFILE_GROUP_NAME, FILE_NAME, EXTRA->FROM INFORMATION_SCHEMA.FILES->WHERE TABLESPACE_NAME = 'newts' AND FILE_TYPE = 'DATAFILE';+--------------------+--------------+----------------+ | LOGFILE_GROUP_NAME | FILE_NAME | EXTRA | +--------------------+--------------+----------------+ | lg_3 | newdata.dat | CLUSTER_NODE=3 | | lg_3 | newdata.dat | CLUSTER_NODE=4 | | lg_3 | newdata2.dat | CLUSTER_NODE=3 | | lg_3 | newdata2.dat | CLUSTER_NODE=4 | +--------------------+--------------+----------------+ 2 rows in set (0.03 sec)
See Section 21.30.1, “The INFORMATION_SCHEMA FILES Table”.
      ALTER TABLESPACE is useful only
      with Disk Data storage for MySQL Cluster. See
      Section 18.5.12, “MySQL Cluster Disk Data Tables”.
ALTER
    [ALGORITHM = {UNDEFINED | MERGE | TEMPTABLE}]
    [DEFINER = { user | CURRENT_USER }]
    [SQL SECURITY { DEFINER | INVOKER }]
    VIEW view_name [(column_list)]
    AS select_statement
    [WITH [CASCADED | LOCAL] CHECK OPTION]
      This statement changes the definition of a view, which must exist.
      The syntax is similar to that for CREATE
      VIEW and the effect is the same as for
      CREATE OR REPLACE
      VIEW. See Section 13.1.20, “CREATE VIEW Syntax”. This statement
      requires the CREATE VIEW and
      DROP privileges for the view, and
      some privilege for each column referred to in the
      SELECT statement.
      ALTER VIEW is permitted only to the
      definer or users with the SUPER
      privilege.
CREATE {DATABASE | SCHEMA} [IF NOT EXISTS] db_name
    [create_specification] ...
create_specification:
    [DEFAULT] CHARACTER SET [=] charset_name
  | [DEFAULT] COLLATE [=] collation_name
      CREATE DATABASE creates a database
      with the given name. To use this statement, you need the
      CREATE privilege for the database.
      CREATE
      SCHEMA is a synonym for CREATE
      DATABASE.
    
      An error occurs if the database exists and you did not specify
      IF NOT EXISTS.
    
      In MySQL 5.6, CREATE
      DATABASE is not permitted within a session that has an
      active LOCK TABLES statement.
    
      create_specification options specify
      database characteristics. Database characteristics are stored in
      the db.opt file in the database directory.
      The CHARACTER SET clause specifies the default
      database character set. The COLLATE clause
      specifies the default database collation.
      Section 10.1, “Character Set Support”, discusses character set and collation
      names.
    
      A database in MySQL is implemented as a directory containing files
      that correspond to tables in the database. Because there are no
      tables in a database when it is initially created, the
      CREATE DATABASE statement creates
      only a directory under the MySQL data directory and the
      db.opt file. Rules for permissible database
      names are given in Section 9.2, “Schema Object Names”. If a database
      name contains special characters, the name for the database
      directory contains encoded versions of those characters as
      described in Section 9.2.3, “Mapping of Identifiers to File Names”.
    
      If you manually create a directory under the data directory (for
      example, with mkdir), the server considers it a
      database directory and it shows up in the output of
      SHOW DATABASES.
    
You can also use the mysqladmin program to create databases. See Section 4.5.2, “mysqladmin — Client for Administering a MySQL Server”.
CREATE
    [DEFINER = { user | CURRENT_USER }]
    EVENT
    [IF NOT EXISTS]
    event_name
    ON SCHEDULE schedule
    [ON COMPLETION [NOT] PRESERVE]
    [ENABLE | DISABLE | DISABLE ON SLAVE]
    [COMMENT 'comment']
    DO event_body;
schedule:
    AT timestamp [+ INTERVAL interval] ...
  | EVERY interval
    [STARTS timestamp [+ INTERVAL interval] ...]
    [ENDS timestamp [+ INTERVAL interval] ...]
interval:
    quantity {YEAR | QUARTER | MONTH | DAY | HOUR | MINUTE |
              WEEK | SECOND | YEAR_MONTH | DAY_HOUR | DAY_MINUTE |
              DAY_SECOND | HOUR_MINUTE | HOUR_SECOND | MINUTE_SECOND}
This statement creates and schedules a new event. The event will not run unless the Event Scheduler is enabled. For information about checking Event Scheduler status and enabling it if necessary, see Section 20.4.2, “Event Scheduler Configuration”.
      CREATE EVENT requires the
      EVENT privilege for the schema in
      which the event is to be created. It might also require the
      SUPER privilege, depending on the
      DEFINER value, as described later in this
      section.
    
      The minimum requirements for a valid CREATE
      EVENT statement are as follows:
          The keywords CREATE EVENT plus
          an event name, which uniquely identifies the event in a
          database schema.
        
          An ON SCHEDULE clause, which determines
          when and how often the event executes.
        
          A DO clause, which contains the
          SQL statement to be executed by an event.
      This is an example of a minimal CREATE
      EVENT statement:
    
CREATE EVENT myevent
    ON SCHEDULE AT CURRENT_TIMESTAMP + INTERVAL 1 HOUR
    DO
      UPDATE myschema.mytable SET mycol = mycol + 1;
      The previous statement creates an event named
      myevent. This event executes once—one
      hour following its creation—by running an SQL statement that
      increments the value of the myschema.mytable
      table's mycol column by 1.
    
      The event_name must be a valid MySQL
      identifier with a maximum length of 64 characters. Event names are
      not case sensitive, so you cannot have two events named
      myevent and MyEvent in the
      same schema. In general, the rules governing event names are the
      same as those for names of stored routines. See
      Section 9.2, “Schema Object Names”.
    
      An event is associated with a schema. If no schema is indicated as
      part of event_name, the default
      (current) schema is assumed. To create an event in a specific
      schema, qualify the event name with a schema using
      schema_name.event_name
      The DEFINER clause specifies the MySQL account
      to be used when checking access privileges at event execution
      time. If a user value is given, it
      should be a MySQL account specified as
      '
      (the same format used in the user_name'@'host_name'GRANT
      statement), CURRENT_USER, or
      CURRENT_USER(). The default
      DEFINER value is the user who executes the
      CREATE EVENT statement. This is the
      same as specifying DEFINER = CURRENT_USER
      explicitly.
    
      If you specify the DEFINER clause, these rules
      determine the valid DEFINER user values:
          If you do not have the SUPER
          privilege, the only permitted user
          value is your own account, either specified literally or by
          using CURRENT_USER. You cannot
          set the definer to some other account.
        
          If you have the SUPER
          privilege, you can specify any syntactically valid account
          name. If the account does not exist, a warning is generated.
        
          Although it is possible to create an event with a nonexistent
          DEFINER account, an error occurs at event
          execution time if the account does not exist.
For more information about event security, see Section 20.6, “Access Control for Stored Programs and Views”.
      Within an event, the CURRENT_USER()
      function returns the account used to check privileges at event
      execution time, which is the DEFINER user. For
      information about user auditing within events, see
      Section 6.3.14, “SQL-Based MySQL Account Activity Auditing”.
    
      IF NOT EXISTS has the same meaning for
      CREATE EVENT as for
      CREATE TABLE: If an event named
      event_name already exists in the same
      schema, no action is taken, and no error results. (However, a
      warning is generated in such cases.)
    
      The ON SCHEDULE clause determines when, how
      often, and for how long the event_body
      defined for the event repeats. This clause takes one of two forms:
          AT  is
          used for a one-time event. It specifies that the event
          executes one time only at the date and time given by
          timestamptimestamp, which must include both
          the date and time, or must be an expression that resolves to a
          datetime value. You may use a value of either the
          DATETIME or
          TIMESTAMP type for this
          purpose. If the date is in the past, a warning occurs, as
          shown here:
        
mysql>SELECT NOW();+---------------------+ | NOW() | +---------------------+ | 2006-02-10 23:59:01 | +---------------------+ 1 row in set (0.04 sec) mysql>CREATE EVENT e_totals->ON SCHEDULE AT '2006-02-10 23:59:00'->DO INSERT INTO test.totals VALUES (NOW());Query OK, 0 rows affected, 1 warning (0.00 sec) mysql>SHOW WARNINGS\G*************************** 1. row *************************** Level: Note Code: 1588 Message: Event execution time is in the past and ON COMPLETION NOT PRESERVE is set. The event was dropped immediately after creation.
          CREATE EVENT statements which
          are themselves invalid—for whatever reason—fail
          with an error.
        
          You may use CURRENT_TIMESTAMP
          to specify the current date and time. In such a case, the
          event acts as soon as it is created.
        
          To create an event which occurs at some point in the future
          relative to the current date and time—such as that
          expressed by the phrase “three weeks from
          now”—you can use the optional clause +
          INTERVAL . The
          intervalinterval portion consists of two
          parts, a quantity and a unit of time, and follows the same
          syntax rules that govern intervals used in the
          DATE_ADD() function (see
          Section 12.7, “Date and Time Functions”. The units keywords
          are also the same, except that you cannot use any units
          involving microseconds when defining an event. With some
          interval types, complex time units may be used. For example,
          “two minutes and ten seconds” can be expressed as
          + INTERVAL '2:10' MINUTE_SECOND.
        
          You can also combine intervals. For example, AT
          CURRENT_TIMESTAMP + INTERVAL 3 WEEK + INTERVAL 2 DAY
          is equivalent to “three weeks and two days from
          now”. Each portion of such a clause must begin with
          + INTERVAL.
        
          To repeat actions at a regular interval, use an
          EVERY clause. The EVERY
          keyword is followed by an interval
          as described in the previous discussion of the
          AT keyword. (+ INTERVAL
          is not used with
          EVERY.) For example, EVERY 6
          WEEK means “every six weeks”.
        
          Although + INTERVAL clauses are not
          permitted in an EVERY clause, you can use
          the same complex time units permitted in a +
          INTERVAL.
        
          An EVERY clause may contain an optional
          STARTS clause. STARTS is
          followed by a timestamp value that
          indicates when the action should begin repeating, and may also
          use + INTERVAL
           to specify an
          amount of time “from now”. For example,
          intervalEVERY 3 MONTH STARTS CURRENT_TIMESTAMP + INTERVAL 1
          WEEK means “every three months, beginning one
          week from now”. Similarly, you can express “every
          two weeks, beginning six hours and fifteen minutes from
          now” as EVERY 2 WEEK STARTS CURRENT_TIMESTAMP
          + INTERVAL '6:15' HOUR_MINUTE. Not specifying
          STARTS is the same as using STARTS
          CURRENT_TIMESTAMP—that is, the action
          specified for the event begins repeating immediately upon
          creation of the event.
        
          An EVERY clause may contain an optional
          ENDS clause. The ENDS
          keyword is followed by a timestamp
          value that tells MySQL when the event should stop repeating.
          You may also use + INTERVAL
           with
          intervalENDS; for instance, EVERY 12 HOUR
          STARTS CURRENT_TIMESTAMP + INTERVAL 30 MINUTE ENDS
          CURRENT_TIMESTAMP + INTERVAL 4 WEEK is equivalent to
          “every twelve hours, beginning thirty minutes from now,
          and ending four weeks from now”. Not using
          ENDS means that the event continues
          executing indefinitely.
        
          ENDS supports the same syntax for complex
          time units as STARTS does.
        
          You may use STARTS,
          ENDS, both, or neither in an
          EVERY clause.
        
          If a repeating event does not terminate within its scheduling
          interval, the result may be multiple instances of the event
          executing simultaneously. If this is undesirable, you should
          institute a mechanism to prevent simultaneous instances. For
          example, you could use the
          GET_LOCK() function, or row or
          table locking.
      The ON SCHEDULE clause may use expressions
      involving built-in MySQL functions and user variables to obtain
      any of the timestamp or
      interval values which it contains. You
      may not use stored functions or user-defined functions in such
      expressions, nor may you use any table references; however, you
      may use SELECT FROM DUAL. This is true for both
      CREATE EVENT and
      ALTER EVENT statements. References
      to stored functions, user-defined functions, and tables in such
      cases are specifically not permitted, and fail with an error (see
      Bug #22830).
    
      Times in the ON SCHEDULE clause are interpreted
      using the current session
      time_zone value. This becomes the
      event time zone; that is, the time zone that is used for event
      scheduling and is in effect within the event as it executes. These
      times are converted to UTC and stored along with the event time
      zone in the mysql.event table. This enables
      event execution to proceed as defined regardless of any subsequent
      changes to the server time zone or daylight saving time effects.
      For additional information about representation of event times,
      see Section 20.4.4, “Event Metadata”. See also
      Section 13.7.5.19, “SHOW EVENTS Syntax”, and Section 21.7, “The INFORMATION_SCHEMA EVENTS Table”.
    
      Normally, once an event has expired, it is immediately dropped.
      You can override this behavior by specifying ON
      COMPLETION PRESERVE. Using ON COMPLETION NOT
      PRESERVE merely makes the default nonpersistent behavior
      explicit.
    
      You can create an event but prevent it from being active using the
      DISABLE keyword. Alternatively, you can use
      ENABLE to make explicit the default status,
      which is active. This is most useful in conjunction with
      ALTER EVENT (see
      Section 13.1.2, “ALTER EVENT Syntax”).
    
      A third value may also appear in place of
      ENABLE or DISABLE;
      DISABLE ON SLAVE is set for the status of an
      event on a replication slave to indicate that the event was
      created on the master and replicated to the slave, but is not
      executed on the slave. See
      Section 17.4.1.11, “Replication of Invoked Features”.
    
      You may supply a comment for an event using a
      COMMENT clause.
      comment may be any string of up to 64
      characters that you wish to use for describing the event. The
      comment text, being a string literal, must be surrounded by
      quotation marks.
    
      The DO clause specifies an action
      carried by the event, and consists of an SQL statement. Nearly any
      valid MySQL statement that can be used in a stored routine can
      also be used as the action statement for a scheduled event. (See
      Section D.1, “Restrictions on Stored Programs”.) For example, the
      following event e_hourly deletes all rows from
      the sessions table once per hour, where this
      table is part of the site_activity schema:
    
CREATE EVENT e_hourly
    ON SCHEDULE
      EVERY 1 HOUR
    COMMENT 'Clears out sessions table each hour.'
    DO
      DELETE FROM site_activity.sessions;
      MySQL stores the sql_mode system
      variable setting in effect when an event is created or altered,
      and always executes the event with this setting in force,
      regardless of the current server SQL mode when the event
      begins executing.
    
      A CREATE EVENT statement that
      contains an ALTER EVENT statement
      in its DO clause appears to
      succeed; however, when the server attempts to execute the
      resulting scheduled event, the execution fails with an error.
        Statements such as SELECT or
        SHOW that merely return a result
        set have no effect when used in an event; the output from these
        is not sent to the MySQL Monitor, nor is it stored anywhere.
        However, you can use statements such as
        SELECT ...
        INTO and
        INSERT INTO ...
        SELECT that store a result. (See the next example in
        this section for an instance of the latter.)
      The schema to which an event belongs is the default schema for
      table references in the DO clause.
      Any references to tables in other schemas must be qualified with
      the proper schema name.
    
      As with stored routines, you can use compound-statement syntax in
      the DO clause by using the
      BEGIN and END keywords, as
      shown here:
    
delimiter |
CREATE EVENT e_daily
    ON SCHEDULE
      EVERY 1 DAY
    COMMENT 'Saves total number of sessions then clears the table each day'
    DO
      BEGIN
        INSERT INTO site_activity.totals (time, total)
          SELECT CURRENT_TIMESTAMP, COUNT(*)
            FROM site_activity.sessions;
        DELETE FROM site_activity.sessions;
      END |
delimiter ;
      This example uses the delimiter command to
      change the statement delimiter. See
      Section 20.1, “Defining Stored Programs”.
    
More complex compound statements, such as those used in stored routines, are possible in an event. This example uses local variables, an error handler, and a flow control construct:
delimiter |
CREATE EVENT e
    ON SCHEDULE
      EVERY 5 SECOND
    DO
      BEGIN
        DECLARE v INTEGER;
        DECLARE CONTINUE HANDLER FOR SQLEXCEPTION BEGIN END;
        SET v = 0;
        WHILE v < 5 DO
          INSERT INTO t1 VALUES (0);
          UPDATE t2 SET s1 = s1 + 1;
          SET v = v + 1;
        END WHILE;
    END |
delimiter ;
There is no way to pass parameters directly to or from events; however, it is possible to invoke a stored routine with parameters within an event:
CREATE EVENT e_call_myproc
    ON SCHEDULE
      AT CURRENT_TIMESTAMP + INTERVAL 1 DAY
    DO CALL myproc(5, 27);
      If an event's definer has the SUPER
      privilege, the event can read and write global variables. As
      granting this privilege entails a potential for abuse, extreme
      care must be taken in doing so.
    
Generally, any statements that are valid in stored routines may be used for action statements executed by events. For more information about statements permitted within stored routines, see Section 20.2.1, “Stored Routine Syntax”. You can create an event as part of a stored routine, but an event cannot be created by another event.
      The CREATE FUNCTION statement is
      used to create stored functions and user-defined functions (UDFs):
For information about creating stored functions, see Section 13.1.15, “CREATE PROCEDURE and CREATE FUNCTION Syntax”.
For information about creating user-defined functions, see Section 13.7.3.1, “CREATE FUNCTION Syntax for User-Defined Functions”.
CREATE [ONLINE|OFFLINE] [UNIQUE|FULLTEXT|SPATIAL] INDEXindex_name[index_type] ONtbl_name(index_col_name,...) [index_option] [algorithm_option|lock_option] ...index_col_name:col_name[(length)] [ASC | DESC]index_type: USING {BTREE | HASH}index_option: KEY_BLOCK_SIZE [=]value|index_type| WITH PARSERparser_name| COMMENT 'string'algorithm_option: ALGORITHM [=] {DEFAULT|INPLACE|COPY}lock_option: LOCK [=] {DEFAULT|NONE|SHARED|EXCLUSIVE}
      CREATE INDEX is mapped to an
      ALTER TABLE statement to create
      indexes. See Section 13.1.7, “ALTER TABLE Syntax”.
      CREATE INDEX cannot be used to
      create a PRIMARY KEY; use
      ALTER TABLE instead. For more
      information about indexes, see Section 8.3.1, “How MySQL Uses Indexes”.
    
      Normally, you create all indexes on a table at the time the table
      itself is created with CREATE
      TABLE. See Section 13.1.17, “CREATE TABLE Syntax”. This
      guideline is especially important for InnoDB
      tables, where the primary key determines the physical layout of
      rows in the data file. CREATE INDEX
      enables you to add indexes to existing tables.
    
      A column list of the form (col1,col2,...)
      creates a multiple-column index. Index key values are formed by
      concatenating the values of the given columns.
    
      Indexes can be created that use only the leading part of column
      values, using
      col_name(length)
          Prefixes can be specified for
          CHAR,
          VARCHAR,
          BINARY, and
          VARBINARY columns.
        
          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.
        
For spatial columns, prefix values cannot be given, as described later in this section.
      The statement shown here creates an index using the first 10
      characters of the name column:
    
CREATE INDEX part_of_name ON customer (name(10));
      If names in the column usually differ in the first 10 characters,
      this index should not be much slower than an index created from
      the entire name column. Also, using column
      prefixes for indexes can make the index file much smaller, which
      could save a lot of disk space and might also speed up
      INSERT operations.
    
      Prefix support and lengths of prefixes (where supported) are
      storage engine dependent. For example, a prefix can be up to 767
      bytes long for InnoDB tables or 3072 bytes if
      the innodb_large_prefix option is
      enabled. For MyISAM tables, the prefix limit is 1000 bytes.
        Prefix limits are measured in bytes, whereas the prefix length
        in CREATE INDEX 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.
      Indexes on variable-width columns of
      NDBCLUSTER tables are created online;
      that is, without any table copying. The table is not locked
      against access from other MySQL Cluster API nodes, although it is
      locked against other operations on the same
      API node for the duration of the operation. This is done
      automatically by the server whenever it determines that it is
      possible to do so; you do not have to use any special SQL syntax
      or server options to cause it to happen.
    
      In standard MySQL 5.6 releases, it is not possible to
      override the server when it determines that an index is to be
      created without table copying. In MySQL Cluster, you can create
      indexes offline (which causes the table to be locked to all API
      nodes in the cluster) using the OFFLINE
      keyword. The rules and limitations governing CREATE
      OFFLINE INDEX and CREATE ONLINE INDEX
      are the same as for ALTER OFFLINE TABLE ... ADD
      INDEX and ALTER ONLINE TABLE ... ADD
      INDEX. You cannot cause the noncopying creation of an
      index that would normally be created offline by using the
      ONLINE keyword: If it is not possible to
      perform the CREATE INDEX operation
      without table copying, the server ignores the
      ONLINE keyword. For more information, see
      Section 13.1.7.2, “ALTER TABLE Online Operations in MySQL Cluster”.
    
      The ONLINE and OFFLINE
      keywords are available only in MySQL Cluster; attempting to use
      these keywords in standard MySQL Server 5.6 releases
      results in a syntax error. The ONLINE and
      OFFLINE keywords are deprecated in MySQL
      Cluster NDB 7.3; they continue to be supported in MySQL Cluster
      NDB 7.4, but they are subject to removal in a future MySQL Cluster
      release.
    
      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 permits
      multiple NULL values for columns that can
      contain NULL. If you specify a prefix value for
      a column in a UNIQUE index, the column values
      must be unique within the prefix.
    
      FULLTEXT indexes are supported only for
      InnoDB and
      MyISAM tables and can include only
      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.
    
      The MyISAM, InnoDB,
      NDB, and ARCHIVE
      storage engines support spatial columns such as
      (POINT and GEOMETRY.
      (Section 11.5, “Extensions for Spatial Data”, describes the spatial data
      types.) However, support for spatial column indexing varies among
      engines. Spatial and nonspatial indexes are available according to
      the following rules.
    
      Spatial indexes (created using SPATIAL INDEX)
      have these characteristics:
          Available only for MyISAM tables.
          Specifying SPATIAL INDEX for other storage
          engines results in an error.
        
          Indexed columns must be NOT NULL.
        
In MySQL 5.6, column prefix lengths are prohibited. The full width of each column is indexed.
      Characteristics of nonspatial indexes (created with
      INDEX, UNIQUE, or
      PRIMARY KEY):
          Permitted for any storage engine that supports spatial columns
          except ARCHIVE.
        
          Columns can be NULL unless the index is a
          primary key.
        
          For each spatial column in a non-SPATIAL
          index except POINT columns, a column prefix
          length must be specified. (This is the same requirement as for
          indexed BLOB columns.) The
          prefix length is given in bytes.
        
          The index type for a non-SPATIAL index
          depends on the storage engine. Currently, B-tree is used.
In MySQL 5.6:
          You can add an index on a column that can have
          NULL values only if you are using the
          InnoDB,
          MyISAM, or
          MEMORY storage engine.
        
          You can add an index on a BLOB
          or TEXT column only if you are
          using the InnoDB or
          MyISAM storage engine.
        
          When the
          innodb_stats_persistent
          setting is enabled, run the ANALYZE
          TABLE statement for an InnoDB
          table after creating an index on that table.
      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.
    
      Following the index column list, index options can be given. An
      index_option value can be any of the
      following:
          KEY_BLOCK_SIZE [=]
          
        value
Optionally specifies the size in bytes to use for index key blocks. The value is treated as a hint; a different size could be used if necessary.
            KEY_BLOCK_SIZE is only supported at the
            table level for InnoDB. See
            Section 13.1.17, “CREATE TABLE Syntax”.
          index_type
        
Some storage engines permit you to specify an index type when creating an index. The permissible index type values supported by different storage engines are shown in the following table. Where multiple index types are listed, the first one is the default when no index type specifier is given.
| Storage Engine | Permissible Index Types | 
|---|---|
| InnoDB | BTREE | 
| MyISAM | BTREE | 
| MEMORY/HEAP | HASH,BTREE | 
| NDB | HASH,BTREE(see note in text) | 
Example:
CREATE TABLE lookup (id INT) ENGINE = MEMORY; CREATE INDEX id_index ON lookup (id) USING BTREE;
          BTREE indexes are implemented by the
          NDBCLUSTER storage engine as
          T-tree indexes.
            For indexes on NDB table
            columns, the USING option can be
            specified only for a unique index or primary key.
            USING HASH prevents the creation of an
            implicit ordered index; otherwise, creating a unique index
            or primary key on an NDB table
            automatically results in the creation of both an ordered
            index and a hash index, each of which indexes the same set
            of columns.
          
            This means that a query using a unique index or primary key
            on a NULL column is always handled by
            NDB with a full scan of the
            table. In particular, if you plan to use an IS
            NULL or IS NOT NULL condition
            involving a unique index or primary key column of an
            NDB table, you should create
            any such index without USING HASH.
          The index_type clause cannot be
          used together with SPATIAL INDEX.
        
          If you specify an index type that is not valid for a given
          storage engine, but there is another index type available that
          the engine can use without affecting query results, the engine
          uses the available type. The parser recognizes
          RTREE as a type name, but currently this
          cannot be specified for any storage engine.
        
          Use of this option before the ON
           clause is
          deprecated; support for use of the option in this position
          will be removed in a future MySQL release. If an
          tbl_nameindex_type option is given in both
          the earlier and later positions, the final option applies.
        
          TYPE 
          is recognized as a synonym for type_nameUSING
          . However,
          type_nameUSING is the preferred form.
        
          WITH PARSER
          
        parser_name
          This option can be used only with FULLTEXT
          indexes. It associates a parser plugin with the index if
          full-text indexing and searching operations need special
          handling. See Section 24.2, “The MySQL Plugin API”, for details on
          creating plugins.
        
          COMMENT '
        string'
Index definitions can include an optional comment of up to 1024 characters.
      As of MySQL 5.6.6, the ALGORITHM and
      LOCK clauses may be given. These influence the
      table copying method and level of concurrency for reading and
      writing the table while its indexes are being modified. They have
      the same meaning as for the ALTER
      TABLE statement. For more information, see
      Section 13.1.7, “ALTER TABLE Syntax”
CREATE LOGFILE GROUPlogfile_groupADD UNDOFILE 'undo_file' [INITIAL_SIZE [=]initial_size] [UNDO_BUFFER_SIZE [=]undo_buffer_size] [REDO_BUFFER_SIZE [=]redo_buffer_size] [NODEGROUP [=]nodegroup_id] [WAIT] [COMMENT [=]comment_text] ENGINE [=]engine_name
      This statement creates a new log file group named
      logfile_group having a single
      UNDO file named
      'undo_file'. A
      CREATE LOGFILE GROUP statement has
      one and only one ADD UNDOFILE clause. For rules
      covering the naming of log file groups, see
      Section 9.2, “Schema Object Names”.
All MySQL Cluster Disk Data objects share the same namespace. This means that each Disk Data object must be uniquely named (and not merely each Disk Data object of a given type). For example, you cannot have a tablespace and a log file group with the same name, or a tablespace and a data file with the same name.
In MySQL Cluster NDB 7.3 and later, you can have only one log file group per Cluster at any given time. (See Bug #16386)
      The optional INITIAL_SIZE parameter sets the
      UNDO file's initial size; if not specified, it
      defaults to 128M (128 megabytes). The optional
      UNDO_BUFFER_SIZE parameter sets the size used
      by the UNDO buffer for the log file group; The
      default value for UNDO_BUFFER_SIZE is
      8M (eight megabytes); this value cannot exceed
      the amount of system memory available. Both of these parameters
      are specified in bytes. In MySQL Cluster NDB 7.3.2 and later, you
      may optionally follow either or both of these with a one-letter
      abbreviation for an order of magnitude, similar to those used in
      my.cnf. Generally, this is one of the
      letters M (for megabytes) or
      G (for gigabytes). Prior to MySQL Cluster NDB
      7.3.2, the values for these options could only be specified using
      digits. (Bug #13116514, Bug #16104705, Bug #62858)
    
      Memory used for UNDO_BUFFER_SIZE comes from the
      global pool whose size is determined by the value of the
      SharedGlobalMemory data
      node configuration parameter. This includes any default value
      implied for this option by the setting of the
      InitialLogFileGroup data
      node configuration parameter.
    
      The maximum permitted for UNDO_BUFFER_SIZE is
      629145600 (600 MB).
    
      On 32-bit systems, the maximum supported value for
      INITIAL_SIZE is 4294967296 (4 GB). (Bug #29186)
    
      The minimum allowed value for INITIAL_SIZE is
      1048576 (1 MB).
    
      The ENGINE option determines the storage engine
      to be used by this log file group, with
      engine_name being the name of the
      storage engine. In MySQL 5.6, this must be
      NDB (or
      NDBCLUSTER). If
      ENGINE is not set, MySQL tries to use the
      engine specified by the
      default_storage_engine server
      system variable (formerly
      storage_engine). In any case, if
      the engine is not specified as NDB or
      NDBCLUSTER, the CREATE
      LOGFILE GROUP statement appears to succeed but actually
      fails to create the log file group, as shown here:
    
mysql>CREATE LOGFILE GROUP lg1->ADD UNDOFILE 'undo.dat' INITIAL_SIZE = 10M;Query OK, 0 rows affected, 1 warning (0.00 sec) mysql>SHOW WARNINGS;+-------+------+------------------------------------------------------------------------------------------------+ | Level | Code | Message | +-------+------+------------------------------------------------------------------------------------------------+ | Error | 1478 | Table storage engine 'InnoDB' does not support the create option 'TABLESPACE or LOGFILE GROUP' | +-------+------+------------------------------------------------------------------------------------------------+ 1 row in set (0.00 sec) mysql>DROP LOGFILE GROUP lg1 ENGINE = NDB;ERROR 1529 (HY000): Failed to drop LOGFILE GROUP mysql>CREATE LOGFILE GROUP lg1->ADD UNDOFILE 'undo.dat' INITIAL_SIZE = 10M->ENGINE = NDB;Query OK, 0 rows affected (2.97 sec)
      The fact that the CREATE LOGFILE GROUP
      statement does not actually return an error when a
      non-NDB storage engine is named, but rather
      appears to succeed, is a known issue which we hope to address in a
      future release of MySQL Cluster.
    
      REDO_BUFFER_SIZE,
      NODEGROUP, WAIT, and
      COMMENT are parsed but ignored, and so have no
      effect in MySQL 5.6. These options are intended for
      future expansion.
    
      When used with ENGINE [=] NDB, a log file group
      and associated UNDO log file are created on
      each Cluster data node. You can verify that the
      UNDO files were created and obtain information
      about them by querying the
      INFORMATION_SCHEMA.FILES table. For
      example:
    
mysql>SELECT LOGFILE_GROUP_NAME, LOGFILE_GROUP_NUMBER, EXTRA->FROM INFORMATION_SCHEMA.FILES->WHERE FILE_NAME = 'undo_10.dat';+--------------------+----------------------+----------------+ | LOGFILE_GROUP_NAME | LOGFILE_GROUP_NUMBER | EXTRA | +--------------------+----------------------+----------------+ | lg_3 | 11 | CLUSTER_NODE=3 | | lg_3 | 11 | CLUSTER_NODE=4 | +--------------------+----------------------+----------------+ 2 rows in set (0.06 sec)
      CREATE LOGFILE GROUP is useful only
      with Disk Data storage for MySQL Cluster. See
      Section 18.5.12, “MySQL Cluster Disk Data Tables”.
CREATE
    [DEFINER = { user | CURRENT_USER }]
    PROCEDURE sp_name ([proc_parameter[,...]])
    [characteristic ...] routine_body
CREATE
    [DEFINER = { user | CURRENT_USER }]
    FUNCTION sp_name ([func_parameter[,...]])
    RETURNS type
    [characteristic ...] routine_body
proc_parameter:
    [ IN | OUT | INOUT ] param_name type
func_parameter:
    param_name type
type:
    Any valid MySQL data type
characteristic:
    COMMENT 'string'
  | LANGUAGE SQL
  | [NOT] DETERMINISTIC
  | { CONTAINS SQL | NO SQL | READS SQL DATA | MODIFIES SQL DATA }
  | SQL SECURITY { DEFINER | INVOKER }
routine_body:
    Valid SQL routine statement
      These statements create stored routines. By default, a routine is
      associated with the default database. To associate the routine
      explicitly with a given database, specify the name as
      db_name.sp_name when you create it.
    
      The CREATE FUNCTION statement is
      also used in MySQL to support UDFs (user-defined functions). See
      Section 24.3, “Adding New Functions to MySQL”. A UDF can be regarded as an
      external stored function. Stored functions share their namespace
      with UDFs. See Section 9.2.4, “Function Name Parsing and Resolution”, for the
      rules describing how the server interprets references to different
      kinds of functions.
    
      To invoke a stored procedure, use the
      CALL statement (see
      Section 13.2.1, “CALL Syntax”). To invoke a stored function, refer to it
      in an expression. The function returns a value during expression
      evaluation.
    
      CREATE PROCEDURE and
      CREATE FUNCTION require the
      CREATE ROUTINE privilege. They
      might also require the SUPER
      privilege, depending on the DEFINER value, as
      described later in this section. If binary logging is enabled,
      CREATE FUNCTION might require the
      SUPER privilege, as described in
      Section 20.7, “Binary Logging of Stored Programs”.
    
      By default, MySQL automatically grants the
      ALTER ROUTINE and
      EXECUTE privileges to the routine
      creator. This behavior can be changed by disabling the
      automatic_sp_privileges system
      variable. See Section 20.2.2, “Stored Routines and MySQL Privileges”.
    
      The DEFINER and SQL SECURITY
      clauses specify the security context to be used when checking
      access privileges at routine execution time, as described later in
      this section.
    
If the routine name is the same as the name of a built-in SQL function, a syntax error occurs unless you use a space between the name and the following parenthesis when defining the routine or invoking it later. For this reason, avoid using the names of existing SQL functions for your own stored routines.
      The IGNORE_SPACE SQL mode
      applies to built-in functions, not to stored routines. It is
      always permissible to have spaces after a stored routine name,
      regardless of whether
      IGNORE_SPACE is enabled.
    
      The parameter list enclosed within parentheses must always be
      present. If there are no parameters, an empty parameter list of
      () should be used. Parameter names are not case
      sensitive.
    
      Each parameter is an IN parameter by default.
      To specify otherwise for a parameter, use the keyword
      OUT or INOUT before the
      parameter name.
        Specifying a parameter as IN,
        OUT, or INOUT is valid
        only for a PROCEDURE. For a
        FUNCTION, parameters are always regarded as
        IN parameters.
      An IN parameter passes a value into a
      procedure. The procedure might modify the value, but the
      modification is not visible to the caller when the procedure
      returns. An OUT parameter passes a value from
      the procedure back to the caller. Its initial value is
      NULL within the procedure, and its value is
      visible to the caller when the procedure returns. An
      INOUT parameter is initialized by the caller,
      can be modified by the procedure, and any change made by the
      procedure is visible to the caller when the procedure returns.
    
      For each OUT or INOUT
      parameter, pass a user-defined variable in the
      CALL statement that invokes the
      procedure so that you can obtain its value when the procedure
      returns. If you are calling the procedure from within another
      stored procedure or function, you can also pass a routine
      parameter or local routine variable as an IN or
      INOUT parameter.
    
Routine parameters cannot be referenced in statements prepared within the routine; see Section D.1, “Restrictions on Stored Programs”.
      The following example shows a simple stored procedure that uses an
      OUT parameter:
    
mysql>delimiter //mysql>CREATE PROCEDURE simpleproc (OUT param1 INT)->BEGIN->SELECT COUNT(*) INTO param1 FROM t;->END//Query OK, 0 rows affected (0.00 sec) mysql>delimiter ;mysql>CALL simpleproc(@a);Query OK, 0 rows affected (0.00 sec) mysql>SELECT @a;+------+ | @a | +------+ | 3 | +------+ 1 row in set (0.00 sec)
      The example uses the mysql client
      delimiter command to change the statement
      delimiter from ; to // while
      the procedure is being defined. This enables the
      ; delimiter used in the procedure body to be
      passed through to the server rather than being interpreted by
      mysql itself. See
      Section 20.1, “Defining Stored Programs”.
    
      The RETURNS clause may be specified only for a
      FUNCTION, for which it is mandatory. It
      indicates the return type of the function, and the function body
      must contain a RETURN
       statement. If the
      valueRETURN statement returns a value of
      a different type, the value is coerced to the proper type. For
      example, if a function specifies an
      ENUM or
      SET value in the
      RETURNS clause, but the
      RETURN statement returns an
      integer, the value returned from the function is the string for
      the corresponding ENUM member of
      set of SET members.
    
      The following example function takes a parameter, performs an
      operation using an SQL function, and returns the result. In this
      case, it is unnecessary to use delimiter
      because the function definition contains no internal
      ; statement delimiters:
    
mysql>CREATE FUNCTION hello (s CHAR(20))mysql>RETURNS CHAR(50) DETERMINISTIC->RETURN CONCAT('Hello, ',s,'!');Query OK, 0 rows affected (0.00 sec) mysql>SELECT hello('world');+----------------+ | hello('world') | +----------------+ | Hello, world! | +----------------+ 1 row in set (0.00 sec)
      Parameter types and function return types can be declared to use
      any valid data type. The COLLATE attribute can
      be used if preceded by the CHARACTER SET
      attribute.
    
      The routine_body consists of a valid
      SQL routine statement. This can be a simple statement such as
      SELECT or
      INSERT, or a compound statement
      written using BEGIN and END.
      Compound statements can contain declarations, loops, and other
      control structure statements. The syntax for these statements is
      described in Section 13.6, “MySQL Compound-Statement Syntax”.
    
      MySQL permits routines to contain DDL statements, such as
      CREATE and DROP. MySQL also
      permits stored procedures (but not stored functions) to contain
      SQL transaction statements such as
      COMMIT. Stored functions may not
      contain statements that perform explicit or implicit commit or
      rollback. Support for these statements is not required by the SQL
      standard, which states that each DBMS vendor may decide whether to
      permit them.
    
      Statements that return a result set can be used within a stored
      procedure but not within a stored function. This prohibition
      includes SELECT statements that do
      not have an INTO
       clause and other
      statements such as var_listSHOW,
      EXPLAIN, and
      CHECK TABLE. For statements that
      can be determined at function definition time to return a result
      set, a Not allowed to return a result set from a
      function error occurs
      (ER_SP_NO_RETSET). For statements
      that can be determined only at runtime to return a result set, a
      PROCEDURE %s can't return a result set in the given
      context error occurs
      (ER_SP_BADSELECT).
    
      USE statements within stored
      routines are not permitted. When a routine is invoked, an implicit
      USE  is
      performed (and undone when the routine terminates). The causes the
      routine to have the given default database while it executes.
      References to objects in databases other than the routine default
      database should be qualified with the appropriate database name.
    db_name
For additional information about statements that are not permitted in stored routines, see Section D.1, “Restrictions on Stored Programs”.
For information about invoking stored procedures from within programs written in a language that has a MySQL interface, see Section 13.2.1, “CALL Syntax”.
      MySQL stores the sql_mode system
      variable setting in effect when a routine is created or altered,
      and always executes the routine with this setting in force,
      regardless of the current server SQL mode when the
      routine begins executing.
    
The switch from the SQL mode of the invoker to that of the routine occurs after evaluation of arguments and assignment of the resulting values to routine parameters. If you define a routine in strict SQL mode but invoke it in nonstrict mode, assignment of arguments to routine parameters does not take place in strict mode. If you require that expressions passed to a routine be assigned in strict SQL mode, you should invoke the routine with strict mode in effect.
      The COMMENT characteristic is a MySQL
      extension, and may be used to describe the stored routine. This
      information is displayed by the SHOW CREATE
      PROCEDURE and SHOW CREATE
      FUNCTION statements.
    
      The LANGUAGE characteristic indicates the
      language in which the routine is written. The server ignores this
      characteristic; only SQL routines are supported.
    
      A routine is considered “deterministic” if it always
      produces the same result for the same input parameters, and
      “not deterministic” otherwise. If neither
      DETERMINISTIC nor NOT
      DETERMINISTIC is given in the routine definition, the
      default is NOT DETERMINISTIC. To declare that a
      function is deterministic, you must specify
      DETERMINISTIC explicitly.
    
      Assessment of the nature of a routine is based on the
      “honesty” of the creator: MySQL does not check that a
      routine declared DETERMINISTIC is free of
      statements that produce nondeterministic results. However,
      misdeclaring a routine might affect results or affect performance.
      Declaring a nondeterministic routine as
      DETERMINISTIC might lead to unexpected results
      by causing the optimizer to make incorrect execution plan choices.
      Declaring a deterministic routine as
      NONDETERMINISTIC might diminish performance by
      causing available optimizations not to be used.
    
      If binary logging is enabled, the DETERMINISTIC
      characteristic affects which routine definitions MySQL accepts.
      See Section 20.7, “Binary Logging of Stored Programs”.
    
      A routine that contains the NOW()
      function (or its synonyms) or
      RAND() is nondeterministic, but it
      might still be replication-safe. For
      NOW(), the binary log includes the
      timestamp and replicates correctly.
      RAND() also replicates correctly as
      long as it is called only a single time during the execution of a
      routine. (You can consider the routine execution timestamp and
      random number seed as implicit inputs that are identical on the
      master and slave.)
    
Several characteristics provide information about the nature of data use by the routine. In MySQL, these characteristics are advisory only. The server does not use them to constrain what kinds of statements a routine will be permitted to execute.
          CONTAINS SQL indicates that the routine
          does not contain statements that read or write data. This is
          the default if none of these characteristics is given
          explicitly. Examples of such statements are SET @x =
          1 or DO RELEASE_LOCK('abc'),
          which execute but neither read nor write data.
        
          NO SQL indicates that the routine contains
          no SQL statements.
        
          READS SQL DATA indicates that the routine
          contains statements that read data (for example,
          SELECT), but not statements
          that write data.
        
          MODIFIES SQL DATA indicates that the
          routine contains statements that may write data (for example,
          INSERT or
          DELETE).
      The SQL SECURITY characteristic can be
      DEFINER or INVOKER to
      specify the security context; that is, whether the routine
      executes using the privileges of the account named in the routine
      DEFINER clause or the user who invokes it. This
      account must have permission to access the database with which the
      routine is associated. The default value is
      DEFINER. The user who invokes the routine must
      have the EXECUTE privilege for it,
      as must the DEFINER account if the routine
      executes in definer security context.
    
      The DEFINER clause specifies the MySQL account
      to be used when checking access privileges at routine execution
      time for routines that have the SQL SECURITY
      DEFINER characteristic.
    
      If a user value is given for the
      DEFINER clause, it should be a MySQL account
      specified as
      '
      (the same format used in the user_name'@'host_name'GRANT
      statement), CURRENT_USER, or
      CURRENT_USER(). The default
      DEFINER value is the user who executes the
      CREATE PROCEDURE or
      CREATE FUNCTION or statement. This
      is the same as specifying DEFINER =
      CURRENT_USER explicitly.
    
      If you specify the DEFINER clause, these rules
      determine the valid DEFINER user values:
          If you do not have the SUPER
          privilege, the only permitted user
          value is your own account, either specified literally or by
          using CURRENT_USER. You cannot
          set the definer to some other account.
        
          If you have the SUPER
          privilege, you can specify any syntactically valid account
          name. If the account does not exist, a warning is generated.
        
          Although it is possible to create a routine with a nonexistent
          DEFINER account, an error occurs at routine
          execution time if the SQL SECURITY value is
          DEFINER but the definer account does not
          exist.
For more information about stored routine security, see Section 20.6, “Access Control for Stored Programs and Views”.
      Within a stored routine that is defined with the SQL
      SECURITY DEFINER characteristic,
      CURRENT_USER returns the routine's
      DEFINER value. For information about user
      auditing within stored routines, see
      Section 6.3.14, “SQL-Based MySQL Account Activity Auditing”.
    
      Consider the following procedure, which displays a count of the
      number of MySQL accounts listed in the
      mysql.user table:
    
CREATE DEFINER = 'admin'@'localhost' PROCEDURE account_count() BEGIN SELECT 'Number of accounts:', COUNT(*) FROM mysql.user; END;
      The procedure is assigned a DEFINER account of
      'admin'@'localhost' no matter which user
      defines it. It executes with the privileges of that account no
      matter which user invokes it (because the default security
      characteristic is DEFINER). The procedure
      succeeds or fails depending on whether invoker has the
      EXECUTE privilege for it and
      'admin'@'localhost' has the
      SELECT privilege for the
      mysql.user table.
    
      Now suppose that the procedure is defined with the SQL
      SECURITY INVOKER characteristic:
    
CREATE DEFINER = 'admin'@'localhost' PROCEDURE account_count() SQL SECURITY INVOKER BEGIN SELECT 'Number of accounts:', COUNT(*) FROM mysql.user; END;
      The procedure still has a DEFINER of
      'admin'@'localhost', but in this case, it
      executes with the privileges of the invoking user. Thus, the
      procedure succeeds or fails depending on whether the invoker has
      the EXECUTE privilege for it and
      the SELECT privilege for the
      mysql.user table.
    
      The server handles the data type of a routine parameter, local
      routine variable created with
      DECLARE, or function return value
      as follows:
Assignments are checked for data type mismatches and overflow. Conversion and overflow problems result in warnings, or errors in strict SQL mode.
          Only scalar values can be assigned. For example, a statement
          such as SET x = (SELECT 1, 2) is invalid.
        
          For character data types, if there is a CHARACTER
          SET attribute in the declaration, the specified
          character set and its default collation is used. If the
          COLLATE attribute is also present, that
          collation is used rather than the default collation.
        
          If CHARACTER SET and
          COLLATE attributes are not present, the
          database character set and collation in effect at routine
          creation time are used. To avoid having the server use the
          database character set and collation, provide explicit
          CHARACTER SET and
          COLLATE attributes for character data
          parameters.
        
If you change the database default character set or collation, stored routines that use the database defaults must be dropped and recreated so that they use the new defaults.
          The database character set and collation are given by the
          value of the
          character_set_database and
          collation_database system
          variables. For more information, see
          Section 10.1.3.2, “Database Character Set and Collation”.
CREATE SERVERserver_nameFOREIGN DATA WRAPPERwrapper_nameOPTIONS (option[,option] ...)option: { HOSTcharacter-literal| DATABASEcharacter-literal| USERcharacter-literal| PASSWORDcharacter-literal| SOCKETcharacter-literal| OWNERcharacter-literal| PORTnumeric-literal}
      This statement creates the definition of a server for use with the
      FEDERATED storage engine. The CREATE
      SERVER statement creates a new row in the
      servers table in the mysql
      database. This statement requires the
      SUPER privilege.
    
      The server_nameserver_name
      The wrapper_namemysql, and may be quoted with single
      quotation marks. Other values for
      wrapper_name
      For each option
        The OWNER option is currently not applied,
        and has no effect on the ownership or operation of the server
        connection that is created.
      The CREATE SERVER statement creates an entry in
      the mysql.servers table that can later be used
      with the CREATE TABLE statement
      when creating a FEDERATED table. The options
      that you specify will be used to populate the columns in the
      mysql.servers table. The table columns are
      Server_name, Host,
      Db, Username,
      Password, Port and
      Socket.
    
For example:
CREATE SERVER s FOREIGN DATA WRAPPER mysql OPTIONS (USER 'Remote', HOST '192.168.1.106', DATABASE 'test');
Be sure to specify all options necessary to establish a connection to the server. The user name, host name, and database name are mandatory. Other options might be required as well, such as password.
      The data stored in the table can be used when creating a
      connection to a FEDERATED table:
    
CREATE TABLE t (s1 INT) ENGINE=FEDERATED CONNECTION='s';
For more information, see Section 15.8, “The FEDERATED Storage Engine”.
      CREATE SERVER causes an automatic commit.
    
      In MySQL 5.6, CREATE SERVER is not
      written to the binary log, regardless of the logging format that
      is in use.
    
      In MySQL 5.6.11 only, gtid_next
      must be set to AUTOMATIC before issuing this
      statement. (Bug #16062608, Bug #16715809, Bug #69045)
CREATE [TEMPORARY] TABLE [IF NOT EXISTS]tbl_name(create_definition,...) [table_options] [partition_options] CREATE [TEMPORARY] TABLE [IF NOT EXISTS]tbl_name[(create_definition,...)] [table_options] [partition_options]select_statementCREATE [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[(fsp)] | TIMESTAMP[(fsp)] | DATETIME[(fsp)] | YEAR | CHAR[(length)] [BINARY] [CHARACTER SETcharset_name] [COLLATEcollation_name] | VARCHAR(length) [BINARY] [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}index_option: KEY_BLOCK_SIZE [=]value|index_type| WITH PARSERparser_name| COMMENT 'string'reference_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} | STATS_AUTO_RECALC [=] {DEFAULT|0|1} | STATS_PERSISTENT [=] {DEFAULT|0|1} | STATS_SAMPLE_PAGES [=]value| TABLESPACEtablespace_name[STORAGE {DISK|MEMORY|DEFAULT}] | UNION [=] (tbl_name[,tbl_name]...)partition_options: PARTITION BY { [LINEAR] HASH(expr) | [LINEAR] KEY [ALGORITHM={1|2}] (column_list) | RANGE{(expr) | COLUMNS(column_list)} | LIST{(expr) | COLUMNS(column_list)} } [PARTITIONSnum] [SUBPARTITION BY { [LINEAR] HASH(expr) | [LINEAR] KEY [ALGORITHM={1|2}] (column_list) } [SUBPARTITIONSnum] ] [(partition_definition[,partition_definition] ...)]partition_definition: PARTITIONpartition_name[VALUES {LESS THAN {(expr|value_list) |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 valid 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, using the
      InnoDB storage engine. 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`.
      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 TABLEnew_tblLIKEorig_tbl;
For more information, see Section 13.1.17.1, “CREATE TABLE ... LIKE Syntax”.
      To create one table from another, add a
      SELECT statement at the end of the
      CREATE TABLE statement:
    
CREATE TABLEnew_tblSELECT * FROMorig_tbl;
For more information, see Section 13.1.17.2, “CREATE TABLE ... SELECT Syntax”.
      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.
      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.
    
      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 .ibd
      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.
| File | Purpose | 
|---|---|
|  | Table format (definition) file | 
|  | Data file | 
|  | Index file | 
Chapter 15, Alternative 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 9.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 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+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 12.14, “Information Functions”, and
          Section 23.8.7.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.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 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 14.5.5, “AUTO_INCREMENT Handling in InnoDB”. For
          information about AUTO_INCREMENT and MySQL
          Replication, see
          Section 17.4.1.1, “Replication and AUTO_INCREMENT”.
        
          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.6 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 or (as
          of MySQL 5.6.5) DATETIME
          column. See Section 11.3.5, “Automatic Initialization and Updating for TIMESTAMP and DATETIME”.
        
          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.
        
          If the NO_ZERO_DATE or
          NO_ZERO_IN_DATE SQL mode is
          enabled and a date-valued default is not correct according to
          that mode, CREATE TABLE
          produces a warning if strict SQL mode is not enabled and an
          error if strict mode is enabled. For example, with
          NO_ZERO_IN_DATE enabled,
          c1 DATE DEFAULT '2010-00-00' produces a
          warning. (Before MySQL 5.6.6, the statement produces an error
          even if strict mode is not enabled.)
        
          
          A comment for a column can be specified with the
          COMMENT option, up to 1024 characters long.
          The comment is displayed by the SHOW
          CREATE TABLE and
          SHOW FULL
          COLUMNS statements.
        
          
          In MySQL Cluster, it is also possible to specify a data
          storage format for individual columns of
          NDB tables using
          COLUMN_FORMAT. Permissible column formats
          are FIXED, DYNAMIC, and
          DEFAULT. FIXED is used
          to specify fixed-width storage, DYNAMIC
          permits 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. In MySQL 5.6
          and later, COLUMN_FORMAT is silently
          ignored.
        
          
          For NDB tables, 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. The
          STORAGE keyword is supported only in the
          build of mysqld that is supplied with MySQL
          Cluster; it is not recognized in any other version of MySQL,
          where any attempt to use the STORAGE
          keyword causes a syntax error.
        
          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 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, keep the PRIMARY
          KEY short to minimize storage overhead for secondary
          indexes. Each secondary index entry contains a copy of the
          primary key columns for the corresponding row. (See
          Section 14.2.6, “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 13.7.5.23, “SHOW INDEX Syntax”.
        tbl_name
          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
Example:
CREATE TABLE lookup (id INT, INDEX USING BTREE (id)) ENGINE = MEMORY;
          The preferred position for USING is after
          the index column list. It can be given before the column list,
          but support for use of the option in that position is
          deprecated and 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.13, “CREATE INDEX Syntax”.
        
For more information about indexes, see Section 8.3.1, “How MySQL Uses Indexes”.
          
          
          In MySQL 5.6, only the InnoDB,
          MyISAM, 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 8.3.4, “Column Indexes”.
        
          Only the InnoDB and
          MyISAM 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 767 bytes long for
          InnoDB tables or 3072 bytes if the
          innodb_large_prefix option is
          enabled.
            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
          InnoDB and
          MyISAM storage engines support
          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. 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
          valid only for FULLTEXT indexes. See
          Section 24.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.5, “Extensions for Spatial Data”.
        
In MySQL 5.6, index definitions can include an optional comment of up to 1024 characters.
          InnoDB and
          NDB 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 are supported. For more detailed information and
          examples, see Section 13.1.17.3, “Using FOREIGN KEY Constraints”. For
          information specific to foreign keys in
          InnoDB, see
          Section 14.5.6, “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 1.8.2.3, “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, it 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.
            Partitioned tables employing the
            InnoDB storage engine do not
            support foreign keys. NDB
            tables that are partitioned by KEY or
            LINEAR KEY are not affected by this
            restriction. See Section 19.6, “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.10.4, “Limits on Table Column Count and Row Size”.
      The TABLESPACE and STORAGE
      table options are employed only with
      NDB 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 18.5.12, “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, using one of the names shown in the
      following table. The engine name can be unquoted or quoted. The
      quoted name 'DEFAULT' is recognized but
      ignored.
| Storage Engine | Description | 
|---|---|
| InnoDB | Transaction-safe tables with row locking and foreign keys. The default
              storage engine for new tables. See
              Chapter 14, The InnoDB Storage Engine, and in particular
              Section 14.1.1, “InnoDB as the Default MySQL Storage Engine” if you have MySQL
              experience but are new to InnoDB. | 
| MyISAM | The binary portable storage engine that is primarily used for read-only or read-mostly workloads. See Section 15.2, “The MyISAM Storage Engine”. | 
| MEMORY | The data for this storage engine is stored only in memory. See Section 15.3, “The MEMORY Storage Engine”. | 
| CSV | Tables that store rows in comma-separated values format. See Section 15.4, “The CSV Storage Engine”. | 
| ARCHIVE | The archiving storage engine. See Section 15.5, “The ARCHIVE Storage Engine”. | 
| EXAMPLE | An example engine. See Section 15.9, “The EXAMPLE Storage Engine”. | 
| FEDERATED | Storage engine that accesses remote tables. See Section 15.8, “The FEDERATED Storage Engine”. | 
| HEAP | This is a synonym for MEMORY. | 
| MERGE | A collection of MyISAMtables used as one table. Also
              known asMRG_MyISAM. See
              Section 15.7, “The MERGE Storage Engine”. | 
| NDB | Clustered, fault-tolerant, memory-based tables, supporting transactions
              and foreign keys. Also known as NDBCLUSTER. See
Chapter 18, MySQL Cluster NDB 7.3 and MySQL Cluster NDB 7.4. | 
      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.6, 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”.
        The older TYPE option that was synonymous
        with ENGINE was removed in MySQL 5.5.
        When upgrading to MySQL 5.5 or later, you must convert
        existing applications that rely on TYPE to
        use ENGINE instead.
      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.6, this works for
          MyISAM, MEMORY,
          InnoDB, and ARCHIVE
          tables. 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 permits 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 2048 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
        
          For InnoDB, the DATA
          DIRECTORY='
          option allows you to create directory'InnoDB
          file-per-table tablespaces outside the MySQL data directory.
          Within the directory that you specify, MySQL creates a
          subdirectory corresponding to the database name, and within
          that a .ibd file for the table. The
          innodb_file_per_table
          configuration option must be enabled to use the DATA
          DIRECTORY option with InnoDB. The
          full directory path must be specified. See
          Section 14.4.5, “Creating a File-Per-Table Tablespace Outside the Data Directory” for more information.
        
          When creating MyISAM tables, you can use
          the DATA
          DIRECTORY='
          clause, the directory'INDEX
          DIRECTORY='
          clause, or both. They specify where to put a
          directory'MyISAM table's data file and index file,
          respectively. Unlike InnoDB tables, MySQL
          does not create subdirectories that correspond to the database
          name when creating a MyISAM table with a
          DATA DIRECTORY or INDEX
          DIRECTORY option. Files are created in the directory
          that is specified.
            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 8.12.4.2, “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. 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.
            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 15.7, “The MERGE Storage Engine”.
        
          KEY_BLOCK_SIZE
        
          For compressed
          InnoDB tables, optionally specifies the
          size in kilobytes to use for
          pages. Possible
          KEY_BLOCK_SIZE values include 0, 1, 2, 4,
          8, and 16. The KEY_BLOCK_SIZE value is
          treated as a hint; a different size could be used by
          InnoDB if necessary. A value of 0
          represents the default compressed page size, which is half of
          the innodb_page_size value.
          The KEY_BLOCK_SIZE can only be less than or
          equal to the innodb_page_size
          value. If you specify a value greater than the
          innodb_page_size value, the
          value is ignored, a warning is issued, and
          KEY_BLOCK_SIZE is set to half of the
          innodb_page_size value. If
          innodb_strict_mode=ON,
          specifying an invalid KEY_BLOCK_SIZE value
          returns an error. See Section 14.6, “InnoDB Table Compression” for
          usage details.
        
          Individual index definitions can specify a
          KEY_BLOCK_SIZE value of their own to
          override the table value.
            Oracle recommends enabling
            innodb_strict_mode when
            using the KEY_BLOCK_SIZE clause for
            InnoDB tables.
          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.
          
          
          
          
          
          
          
          
          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
          * , where
          rowsrows 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.
        
          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.
        
          ROW_FORMAT
        
Defines the physical format in which the rows are stored. The choices differ depending on the storage engine used for the table.
          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.
            
              To enable compression for InnoDB
              tables, specify ROW_FORMAT=COMPRESSED
              and follow the procedures in
              Section 14.6, “InnoDB Table Compression”.
            
              For more efficient InnoDB storage of
              data types, especially BLOB
              types, specify ROW_FORMAT=DYNAMIC and
              follow the procedures in
              Section 14.8.3, “DYNAMIC and COMPRESSED Row Formats”. Both the
              COMPRESSED and
              DYNAMIC row formats require creating
              the table with the configuration settings
              innodb_file_per_table=1
              and
              innodb_file_format=barracuda.
            
              When you specify a non-default
              ROW_FORMAT clause, consider also
              enabling the
              innodb_strict_mode
              configuration option.
            
              For additional information about InnoDB
              row formats, see Section 14.8, “InnoDB Row Storage and Row Formats”.
          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 15.2.3, “MyISAM Table Storage Formats”.
            When executing a CREATE TABLE
            statement, if you specify a row format that 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.
          STATS_AUTO_RECALC
        
          Specifies whether to automatically recalculate
          persistent
          statistics for an InnoDB table. The
          value DEFAULT causes the persistent
          statistics setting for the table to be determined by the
          innodb_stats_auto_recalc
          configuration option. The value 1 causes
          statistics to be recalculated when 10% of the data in the
          table has changed. The value 0 prevents
          automatic recalculation for this table; with this setting,
          issue an ANALYZE TABLE
          statement to recalculate the statistics after making
          substantial changes to the table. For more information about
          the persistent statistics feature, see
          Section 14.3.11.1, “Configuring Persistent Optimizer Statistics Parameters”.
        
          STATS_PERSISTENT
        
          Specifies whether to enable
          persistent
          statistics for an InnoDB table. The
          value DEFAULT causes the persistent
          statistics setting for the table to be determined by the
          innodb_stats_persistent
          configuration option. The value 1 enables
          persistent statistics for the table, while the value
          0 turns off this feature. After enabling
          persistent statistics through a CREATE
          TABLE or ALTER TABLE statement,
          issue an ANALYZE TABLE
          statement to calculate the statistics, after loading
          representative data into the table. For more information about
          the persistent statistics feature, see
          Section 14.3.11.1, “Configuring Persistent Optimizer Statistics Parameters”.
        
          STATS_SAMPLE_PAGES
        
          The number of index pages to sample when estimating
          cardinality and other statistics for an indexed column, such
          as those calculated by ANALYZE
          TABLE. For more information, see
          Section 14.3.11.1, “Configuring Persistent Optimizer Statistics Parameters”.
        
          UNION is used when you want to
          access a collection of identical MyISAM
          tables as one. This works only with MERGE
          tables. See Section 15.7, “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 19, 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.6 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
          valid MySQL expression (including MySQL functions) that yields
          a single integer value. For example, these are both 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), 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 19.2.4, “HASH Partitioning”.
        
          The LINEAR keyword entails a somewhat
          different algorithm. In this case, the number of the partition
          in which a row is stored is calculated as the result of one or
          more logical AND operations. For
          discussion and examples of linear hashing, see
          Section 19.2.4.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 1 or more table columns (maximum:
          16). This example shows a simple table partitioned by key,
          with 4 partitions:
        
CREATE TABLE tk (col1 INT, col2 CHAR(5), col3 DATE)
    PARTITION BY KEY(col3)
    PARTITIONS 4;
          For tables that are partitioned by key, you can employ linear
          partitioning by using the LINEAR keyword.
          This has the same effect as with tables that are partitioned
          by HASH. That is, the partition number is
          found using the
          &
          operator rather than the modulus (see
          Section 19.2.4.1, “LINEAR HASH Partitioning”, and
          Section 19.2.5, “KEY Partitioning”, for details). This example
          uses linear partitioning by key to distribute data between 5
          partitions:
        
CREATE TABLE tk (col1 INT, col2 CHAR(5), col3 DATE)
    PARTITION BY LINEAR KEY(col3)
    PARTITIONS 5;
          The ALGORITHM={1|2} option is supported
          with [SUB]PARTITION BY [LINEAR] KEY
          beginning with MySQL 5.6.11. ALGORITHM=1
          causes the server to use the same key-hashing functions as
          MySQL 5.1; ALGORITHM=2 means that the
          server employs the key-hashing functions implemented and used
          by default for new KEY partitioned tables
          in MySQL 5.5 and later. (Partitioned tables created with the
          key-hashing functions employed in MySQL 5.5 and later cannot
          be used by a MySQL 5.1 server.) Not specifying the option has
          the same effect as using ALGORITHM=2. This
          option is intended for use chiefly when upgrading or
          downgrading [LINEAR] KEY partitioned tables
          between MySQL 5.1 and later MySQL versions, or for creating
          tables partitioned by KEY or
          LINEAR KEY on a MySQL 5.5 or later server
          which can be used on a MySQL 5.1 server. For more information,
          see Section 13.1.7.1, “ALTER TABLE Partition Operations”.
        
mysqldump in MySQL 5.6.11 and later writes this option encased in versioned comments, like this:
CREATE TABLE t1 (a INT)
/*!50100 PARTITION BY KEY */ /*!50611 ALGORITHM = 1 */ /*!50100 ()
      PARTITIONS 3 */
          This causes MySQL 5.6.10 and earlier servers to ignore the
          option, which would otherwise cause a syntax error in those
          versions. If you plan to load a dump made on a MySQL 5.5.31 or
          later MySQL 5.5 server where you use tables that are
          partitioned or subpartitioned by KEY into a
          MySQL 5.6 server previous to version 5.6.11, be sure to
          consult Section 2.11.1.3, “Upgrading from MySQL 5.5 to 5.6”,
          before proceeding. (The information found there also applies
          if you are loading a dump containing KEY
          partitioned or subpartitioned tables made from a MySQL 5.6.11
          or later server into a MySQL 5.5.30 or earlier server.)
        
          Also in MySQL 5.6.11 and later, ALGORITHM=1
          is shown when necessary in the output of
          SHOW CREATE TABLE using
          versioned comments in the same manner as
          mysqldump. ALGORITHM=2
          is always omitted from SHOW CREATE TABLE
          output, even if this option was specified when creating the
          original table.
        
          You may not use either VALUES LESS THAN or
          VALUES IN clauses with PARTITION
          BY KEY.
        
          RANGE(: In
          this case, expr)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.
            For tables partitioned by RANGE,
            VALUES LESS THAN must be used with either
            an integer literal value or an expression that evaluates to
            a single integer value. In MySQL 5.6, you can
            overcome this limitation in a table that is defined using
            PARTITION BY RANGE COLUMNS, as described
            later in this section.
Suppose that you have a table that you wish to partition on a column containing year values, according to the following scheme.
| Partition Number: | Years Range: | 
|---|---|
| 0 | 1990 and earlier | 
| 1 | 1991 to 1994 | 
| 2 | 1995 to 1998 | 
| 3 | 1999 to 2002 | 
| 4 | 2003 to 2005 | 
| 5 | 2006 and later | 
          A table implementing such a partitioning scheme can be
          realized by the CREATE TABLE
          statement shown here:
        
CREATE TABLE t1 (
    year_col  INT,
    some_data INT
)
PARTITION BY RANGE (year_col) (
    PARTITION p0 VALUES LESS THAN (1991),
    PARTITION p1 VALUES LESS THAN (1995),
    PARTITION p2 VALUES LESS THAN (1999),
    PARTITION p3 VALUES LESS THAN (2002),
    PARTITION p4 VALUES LESS THAN (2006),
    PARTITION p5 VALUES LESS THAN MAXVALUE
);
          PARTITION ... VALUES LESS THAN ...
          statements work in a consecutive fashion. VALUES LESS
          THAN MAXVALUE works to specify
          “leftover” values that are greater than the
          maximum value otherwise specified.
        
          VALUES LESS THAN clauses work sequentially
          in a manner similar to that of the case
          portions of a switch ... case block (as
          found in many programming languages such as C, Java, and PHP).
          That is, the clauses must be arranged in such a way that the
          upper limit specified in each successive VALUES LESS
          THAN is greater than that of the previous one, with
          the one referencing MAXVALUE coming last of
          all in the list.
        
          RANGE
          COLUMNS(:
          This variant on column_list)RANGE facilitates partition
          pruning for queries using range conditions on multiple columns
          (that is, having conditions such as WHERE a = 1 AND b
          < 10 or WHERE a = 1 AND b = 10 AND c
          < 10). It enables you to specify value ranges in
          multiple columns by using a list of columns in the
          COLUMNS clause and a set of column values
          in each PARTITION ... VALUES LESS THAN
          ( partition
          definition clause. (In the simplest case, this set consists of
          a single column.) The maximum number of columns that can be
          referenced in the value_list)column_list and
          value_list is 16.
        
          The column_list used in the
          COLUMNS clause may contain only names of
          columns; each column in the list must be one of the following
          MySQL data types: the integer types; the string types; and
          time or date column types. Columns using
          BLOB, TEXT,
          SET, ENUM,
          BIT, or spatial data types are not
          permitted; columns that use floating-point number types are
          also not permitted. You also may not use functions or
          arithmetic expressions in the COLUMNS
          clause.
        
          The VALUES LESS THAN clause used in a
          partition definition must specify a literal value for each
          column that appears in the COLUMNS()
          clause; that is, the list of values used for each
          VALUES LESS THAN clause must contain the
          same number of values as there are columns listed in the
          COLUMNS clause. An attempt to use more or
          fewer values in a VALUES LESS THAN clause
          than there are in the COLUMNS clause causes
          the statement to fail with the error Inconsistency
          in usage of column lists for partitioning.... You
          cannot use NULL for any value appearing in
          VALUES LESS THAN. It is possible to use
          MAXVALUE more than once for a given column
          other than the first, as shown in this example:
        
CREATE TABLE rc (
    a INT NOT NULL, 
    b INT NOT NULL
)
PARTITION BY RANGE COLUMNS(a,b) (
    PARTITION p0 VALUES LESS THAN (10,5),
    PARTITION p1 VALUES LESS THAN (20,10),
    PARTITION p2 VALUES LESS THAN (MAXVALUE,15),
    PARTITION p3 VALUES LESS THAN (MAXVALUE,MAXVALUE)
);
          Each value used in a VALUES LESS THAN value
          list must match the type of the corresponding column exactly;
          no conversion is made. For example, you cannot use the string
          '1' for a value that matches a column that
          uses an integer type (you must use the numeral
          1 instead), nor can you use the numeral
          1 for a value that matches a column that
          uses a string type (in such a case, you must use a quoted
          string: '1').
        
For more information, see Section 19.2.1, “RANGE Partitioning”, and Section 19.4, “Partition Pruning”.
          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
          permissible 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.
            For tables partitioned by LIST, the value
            list used with VALUES IN must consist of
            integer values only. In MySQL 5.6, you can
            overcome this limitation using partitioning by LIST
            COLUMNS, which is described later in this section.
          LIST
          COLUMNS(:
          This variant on column_list)LIST facilitates partition
          pruning for queries using comparison conditions on multiple
          columns (that is, having conditions such as WHERE a =
          5 AND b = 5 or WHERE a = 1 AND b = 10 AND c
          = 5). It enables you to specify values in multiple
          columns by using a list of columns in the
          COLUMNS clause and a set of column values
          in each PARTITION ... VALUES IN
          ( partition
          definition clause.
        value_list)
          The rules governing regarding data types for the column list
          used in LIST
          COLUMNS( and
          the value list used in column_list)VALUES
          IN( are the
          same as those for the column list used in value_list)RANGE
          COLUMNS( and
          the value list used in column_list)VALUES LESS
          THAN(,
          respectively, except that in the value_list)VALUES IN
          clause, MAXVALUE is not permitted, and you
          may use NULL.
        
          There is one important difference between the list of values
          used for VALUES IN with PARTITION
          BY LIST COLUMNS as opposed to when it is used with
          PARTITION BY LIST. When used with
          PARTITION BY LIST COLUMNS, each element in
          the VALUES IN clause must be a
          set of column values; the number of
          values in each set must be the same as the number of columns
          used in the COLUMNS clause, and the data
          types of these values must match those of the columns (and
          occur in the same order). In the simplest case, the set
          consists of a single column. The maximum number of columns
          that can be used in the column_list
          and in the elements making up the
          value_list is 16.
        
          The table defined by the following CREATE
          TABLE statement provides an example of a table using
          LIST COLUMNS partitioning:
        
CREATE TABLE lc (
    a INT NULL, 
    b INT NULL
)
PARTITION BY LIST COLUMNS(a,b) (
    PARTITION p0 VALUES IN( (0,0), (NULL,NULL) ),
    PARTITION p1 VALUES IN( (0,1), (0,2), (0,3), (1,1), (1,2) ),
    PARTITION p2 VALUES IN( (1,0), (2,0), (2,1), (3,0), (3,1) ),
    PARTITION p3 VALUES IN( (1,3), (2,2), (2,3), (3,2), (3,3) )
);
          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.
        
          Rigorous checking of the value used in
          PARTITIONS or
          SUBPARTITIONS clauses is applied and this
          value must adhere to the following rules:
The value must be a positive, nonzero integer.
No leading zeros are permitted.
              The value must be an integer literal, and cannot not be an
              expression. For example, PARTITIONS
              0.2E+01 is not permitted, 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; such references are
        specifically not permitted 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 19, 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'
Beginning with MySQL 5.6.6, the maximum length for a partition comment is 1024 characters. (Previously, this limit was not explicitly defined.)
          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 p2002 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 of
          MyISAM tables, and the
          INDEX DIRECTORY option is not supported for
          individual partitions or subpartitions of
          InnoDB tables. These options are
          ignored on Windows, except that a warning is generated. (Bug
          #30459)
            The DATA DIRECTORY and INDEX
            DIRECTORY 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
          permitted in this version of MySQL. We expect to
          lift this restriction on partitioning in a future MySQL
          release.
        
          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 19.2.6, “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 13.1.7, “ALTER TABLE Syntax”. For more detailed descriptions and examples, see Section 19.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 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.
        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 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.
          Beginning with MySQL 5.6.1, you cannot execute CREATE
          TABLE or CREATE TABLE ... LIKE
          while a LOCK TABLES statement
          is in effect.
        
          Also as of MySQL 5.6.1,
          CREATE TABLE ...
          LIKE makes the same checks as
          CREATE TABLE and does not just
          copy the .frm file. This means that if
          the current SQL mode is different from the mode in effect when
          the original table was created, the table definition might be
          considered invalid for the new mode and the statement will
          fail.
        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 create one table from another by adding a
        SELECT statement at the end of
        the CREATE TABLE statement:
      
CREATE TABLEnew_tbl[AS] SELECT * 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. The ENGINE option is
        part of the CREATE TABLE
        statement, and should not be used following the
        SELECT; this would result in a
        syntax error. The same is true for other
        CREATE TABLE options such as
        CHARSET.
      
        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.
        You can precede the SELECT by
        IGNORE or
        REPLACE to indicate how to handle
        rows that duplicate unique key values. With
        IGNORE, 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.
      
        Because the ordering of the rows in the underlying
        SELECT statements cannot always
        be determined, CREATE TABLE ... IGNORE SELECT
        and CREATE TABLE ... REPLACE SELECT
        statements in MySQL 5.6.4 and later are flagged as unsafe for
        statement-based replication. With this change, such statements
        produce a warning in the log when using statement-based mode and
        are logged using the row-based format when using
        MIXED mode. See also
        Section 17.1.2.1, “Advantages and Disadvantages of Statement-Based and Row-Based
        Replication”.
      
        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
        TABLE ... 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 column in the created table:
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 destination table already exists, the result is
        version dependent. Before MySQL 5.5.6, 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. MySQL attempts to insert the rows
            from the SELECT part anyway.
          
            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)
        As of MySQL 5.5.6, handling of
        CREATE
        TABLE IF NOT EXISTS ... SELECT statements was changed
        for the case that the destination table already exists. This
        change also involves a change in MySQL 5.1 beginning with
        5.1.51.
            Previously, for
            CREATE
            TABLE IF NOT EXISTS ... SELECT, MySQL produced a
            warning that the table exists, but inserted the rows and
            wrote the statement to the binary log anyway. By contrast,
            CREATE
            TABLE ... SELECT (without IF NOT
            EXISTS) failed with an error, but MySQL inserted
            no rows and did not write the statement to the binary log.
          
            MySQL now handles both statements the same way when the
            destination table exists, in that neither statement inserts
            rows or is written to the binary log. The difference between
            them is that MySQL produces a warning when IF NOT
            EXISTS is present and an error when it is not.
        This change means that, for the preceding example, the
        CREATE
        TABLE IF NOT EXISTS ... SELECT statement inserts
        nothing into the destination table as of MySQL 5.5.6.
      
        This change in handling of IF NOT EXISTS
        results in an incompatibility for statement-based replication
        from a MySQL 5.1 master with the original behavior and a MySQL
        5.5 slave with the new behavior. Suppose that
        CREATE
        TABLE IF NOT EXISTS ... SELECT is executed on the
        master and the destination table exists. The result is that rows
        are inserted on the master but not on the slave. (Row-based
        replication does not have this problem.)
      
        To address this issue, statement-based binary logging for
        CREATE
        TABLE IF NOT EXISTS ... SELECT is changed in MySQL 5.1
        as of 5.1.51:
If the destination table does not exist, there is no change: The statement is logged as is.
            If the destination table does exist, the statement is logged
            as the equivalent pair of
            CREATE
            TABLE IF NOT EXISTS and
            INSERT ...
            SELECT statements. (If the
            SELECT in the original
            statement is preceded by IGNORE or
            REPLACE, the
            INSERT becomes
            INSERT
            IGNORE or REPLACE,
            respectively.)
This change provides forward compatibility for statement-based replication from MySQL 5.1 to 5.5 because when the destination table exists, the rows will be inserted on both the master and slave. To take advantage of this compatibility measure, the 5.1 server must be at least 5.1.51 and the 5.5 server must be at least 5.5.6.
To upgrade an existing 5.1-to-5.5 replication scenario, upgrade the master first to 5.1.51 or higher. Note that this differs from the usual replication upgrade advice of upgrading the slave first.
        A workaround for applications that wish to achieve the original
        effect (rows inserted regardless of whether the destination
        table exists) is to use
        CREATE
        TABLE IF NOT EXISTS and
        INSERT ...
        SELECT statements rather than
        CREATE
        TABLE IF NOT EXISTS ... SELECT statements.
      
        Along with the change just described, the following related
        change was made: Previously, if an existing view was named as
        the destination table for
        CREATE
        TABLE IF NOT EXISTS ... SELECT, rows were inserted
        into the underlying base table and the statement was written to
        the binary log. As of MySQL 5.1.51 and 5.5.6, nothing is
        inserted or logged.
      
        To ensure that the binary log can be used to re-create the
        original tables, MySQL does not permit concurrent inserts during
        CREATE TABLE ...
        SELECT.
          You cannot use FOR UPDATE as part of the
          SELECT in a statement such as
          CREATE
          TABLE . If you
          attempt to do so, the statement fails. This represents a
          change in behavior from MySQL 5.5 and earlier, which permitted
          new_table SELECT ... FROM
          old_table ...CREATE
          TABLE ... SELECT statements to make changes in
          tables other than the table being created.
        
This change can also have implications for statement-based replication from an older master to a MySQL 5.6 or newer slave. See Section 17.4.1.5, “Replication of CREATE TABLE ... SELECT Statements”, for more information.
        MySQL supports foreign keys, which let you cross-reference
        related data across tables, and
        foreign key
        constraints, which help keep this spread-out data
        consistent. The essential syntax for a foreign key constraint
        definition in a CREATE TABLE or
        ALTER TABLE statement looks like
        this:
      
[CONSTRAINT [symbol]] FOREIGN KEY [index_name] (index_col_name, ...) REFERENCEStbl_name(index_col_name,...) [ON DELETEreference_option] [ON UPDATEreference_option]reference_option: RESTRICT | CASCADE | SET NULL | NO ACTION
        index_name represents a foreign key
        ID. The index_name value is ignored
        if there is already an explicitly defined index on the child
        table that can support the foreign key. Otherwise, MySQL
        implicitly creates a foreign key index that is named according
        to the following rules:
            If defined, the CONSTRAINT
            symbol value is used. Otherwise,
            the FOREIGN KEY
            index_name value is used.
          
            If neither a CONSTRAINT
            symbol or FOREIGN
            KEY index_name is
            defined, the foreign key index name is generated using the
            name of the referencing foreign key column.
Foreign keys definitions are subject to the following conditions:
            Foreign key relationships involve a
            parent table that
            holds the central data values, and a
            child table with
            identical values pointing back to its parent. The
            FOREIGN KEY clause is specified in the
            child table. The parent and child tables must use the same
            storage engine. They must not be
            TEMPORARY tables.
          
            In MySQL 5.6, creation of a foreign key
            constraint requires at least one of the
            SELECT,
            INSERT,
            UPDATE,
            DELETE, or
            REFERENCES privileges for the
            parent table as of 5.6.22.
          
Corresponding columns in the foreign key and the referenced key must have similar data types. The size and sign of integer types must be the same. The length of string types need not be the same. For nonbinary (character) string columns, the character set and collation must be the same.
            MySQL requires indexes on foreign keys and referenced keys
            so that foreign key checks can be fast and not require a
            table scan. In the referencing table, there must be an index
            where the foreign key columns are listed as the
            first columns in the same order. Such
            an index is created on the referencing table automatically
            if it does not exist. This index might be silently dropped
            later, if you create another index that can be used to
            enforce the foreign key constraint.
            index_name, if given, is used as
            described previously.
          
            InnoDB permits a foreign key to reference
            any index column or group of columns. However, in the
            referenced table, there must be an index where the
            referenced columns are listed as the
            first columns in the same order.
          
            NDB requires an explicit unique key (or
            primary key) on any column referenced as a foreign key.
          
            Index prefixes on foreign key columns are not supported. One
            consequence of this is that
            BLOB and
            TEXT columns cannot be
            included in a foreign key because indexes on those columns
            must always include a prefix length.
          
            If the CONSTRAINT
             clause is given,
            the symbolsymbol value, if used, must
            be unique in the database. A duplicate
            symbol will result in an error
            similar to: ERROR 1022 (2300): Can't write;
            duplicate key in table '#sql- 464_1'. If the
            clause is not given, or a symbol
            is not included following the CONSTRAINT
            keyword, a name for the constraint is created automatically.
          
            InnoDB does not currently
            support foreign keys for tables with user-defined
            partitioning. This includes both parent and child tables.
          
            This restriction does not apply for
            NDB tables that are partitioned
            by KEY or LINEAR KEY
            (the only user partitioning types supported by the
            NDB storage engine); these may have
            foreign key references or be the targets of such references.
          
            For NDB tables, ON
            UPDATE CASCADE is not supported where the
            reference is to the parent table's primary key.
This section describes how foreign keys help guarantee referential integrity.
        For storage engines supporting foreign keys, MySQL rejects any
        INSERT or
        UPDATE operation that attempts to
        create a foreign key value in a child table if there is no a
        matching candidate key value in the parent table.
      
        When an UPDATE or
        DELETE operation affects a key
        value in the parent table that has matching rows in the child
        table, the result depends on the referential
        action specified using ON UPDATE
        and ON DELETE subclauses of the
        FOREIGN KEY clause. MySQL supports five
        options regarding the action to be taken, listed here:
            CASCADE: Delete or update the row from
            the parent table, and automatically delete or update the
            matching rows in the child table. Both ON DELETE
            CASCADE and ON UPDATE CASCADE
            are supported. Between two tables, do not define several
            ON UPDATE CASCADE clauses that act on the
            same column in the parent table or in the child table.
Currently, cascaded foreign key actions do not activate triggers.
            SET NULL: Delete or update the row from
            the parent table, and set the foreign key column or columns
            in the child table to NULL. Both
            ON DELETE SET NULL and ON UPDATE
            SET NULL clauses are supported.
          
            If you specify a SET NULL action,
            make sure that you have not declared the columns
            in the child table as NOT
            NULL.
          
            RESTRICT: Rejects the delete or update
            operation for the parent table. Specifying
            RESTRICT (or NO
            ACTION) is the same as omitting the ON
            DELETE or ON UPDATE clause.
          
            NO ACTION: A keyword from standard SQL.
            In MySQL, equivalent to RESTRICT. The
            MySQL Server rejects the delete or update operation for the
            parent table if there is a related foreign key value in the
            referenced table. Some database systems have deferred
            checks, and NO ACTION is a deferred
            check. In MySQL, foreign key constraints are checked
            immediately, so NO ACTION is the same as
            RESTRICT.
          
            SET DEFAULT: This action is recognized by
            the MySQL parser, but both
            InnoDB and
            NDB reject table definitions
            containing ON DELETE SET DEFAULT or
            ON UPDATE SET DEFAULT clauses.
        For an ON DELETE or ON
        UPDATE that is not specified, the default action is
        always RESTRICT.
      
MySQL supports foreign key references between one column and another within a table. (A column cannot have a foreign key reference to itself.) In these cases, “child table records” really refers to dependent records within the same table.
        Here is a simple example that relates parent
        and child tables through a single-column
        foreign key:
      
CREATE TABLE parent (
    id INT NOT NULL,
    PRIMARY KEY (id)
) ENGINE=INNODB;
CREATE TABLE child (
    id INT, 
    parent_id INT,
    INDEX par_ind (parent_id),
    FOREIGN KEY (parent_id) 
        REFERENCES parent(id)
        ON DELETE CASCADE
) ENGINE=INNODB;
        A more complex example in which a
        product_order table has foreign keys for two
        other tables. One foreign key references a two-column index in
        the product table. The other references a
        single-column index in the customer table:
      
CREATE TABLE product (
    category INT NOT NULL, id INT NOT NULL,
    price DECIMAL,
    PRIMARY KEY(category, id)
)   ENGINE=INNODB;
CREATE TABLE customer (
    id INT NOT NULL,
    PRIMARY KEY (id)
)   ENGINE=INNODB;
CREATE TABLE product_order (
    no INT NOT NULL AUTO_INCREMENT,
    product_category INT NOT NULL,
    product_id INT NOT NULL,
    customer_id INT NOT NULL,
    PRIMARY KEY(no),
    INDEX (product_category, product_id),
    INDEX (customer_id),
    FOREIGN KEY (product_category, product_id)
      REFERENCES product(category, id)
      ON UPDATE CASCADE ON DELETE RESTRICT,
    FOREIGN KEY (customer_id)
      REFERENCES customer(id)
)   ENGINE=INNODB;
        You can add a new foreign key constraint to an existing table by
        using ALTER TABLE. The syntax
        relating to foreign keys for this statement is shown here:
      
ALTER TABLEtbl_nameADD [CONSTRAINT [symbol]] FOREIGN KEY [index_name] (index_col_name, ...) REFERENCEStbl_name(index_col_name,...) [ON DELETEreference_option] [ON UPDATEreference_option]
        The foreign key can be self referential (referring to the same
        table). When you add a foreign key constraint to a table using
        ALTER TABLE, remember
        to create the required indexes first.
        You can also use ALTER TABLE to
        drop foreign keys, using the syntax shown here:
      
ALTER TABLEtbl_nameDROP FOREIGN KEYfk_symbol;
        If the FOREIGN KEY clause included a
        CONSTRAINT name when you created the foreign
        key, you can refer to that name to drop the foreign key.
        Otherwise, the fk_symbol value is
        generated internally when the foreign key is created. To find
        out the symbol value when you want to drop a foreign key, use a
        SHOW CREATE TABLE statement, as
        shown here:
      
mysql>SHOW CREATE TABLE ibtest11c\G*************************** 1. row *************************** Table: ibtest11c Create Table: CREATE TABLE `ibtest11c` ( `A` int(11) NOT NULL auto_increment, `D` int(11) NOT NULL default '0', `B` varchar(200) NOT NULL default '', `C` varchar(175) default NULL, PRIMARY KEY (`A`,`D`,`B`), KEY `B` (`B`,`C`), KEY `C` (`C`), CONSTRAINT `0_38775` FOREIGN KEY (`A`, `D`) REFERENCES `ibtest11a` (`A`, `D`) ON DELETE CASCADE ON UPDATE CASCADE, CONSTRAINT `0_38776` FOREIGN KEY (`B`, `C`) REFERENCES `ibtest11a` (`B`, `C`) ON DELETE CASCADE ON UPDATE CASCADE ) ENGINE=INNODB CHARSET=latin1 1 row in set (0.01 sec) mysql>ALTER TABLE ibtest11c DROP FOREIGN KEY `0_38775`;
        Prior to MySQL 5.6.6, adding and dropping a foreign key in the
        same ALTER TABLE statement may be
        problematic in some cases and is therefore unsupported. Separate
        statements should be used for each operation. As of MySQL 5.6.6,
        adding and dropping a foreign key in the same
        ALTER TABLE statement is
        supported for ALTER
        TABLE ... ALGORITHM=INPLACE but remains unsupported
        for ALTER TABLE ...
        ALGORITHM=COPY.
      
        Before MySQL 5.6.7, using ALTER
        TABLE to change the definition of a foreign key column
        could cause a loss of referential integrity. For example,
        changing a foreign key column that contained
        NULL values to be NOT NULL
        caused the NULL values to be the empty
        string. Similarly, an
        ALTER TABLE
        IGNORE that removed rows in a parent table could break
        referential integrity.
      
        As of 5.6.7, the server prohibits changes to foreign key columns
        with the potential to cause loss of referential integrity. A
        workaround is to use
        ALTER TABLE ...
        DROP FOREIGN KEY before changing the column definition
        and ALTER TABLE ...
        ADD FOREIGN KEY afterward.
        Table and column identifiers in a FOREIGN KEY ...
        REFERENCES ... clause can be quoted within backticks
        (`). Alternatively, double quotation marks
        (") can be used if the
        ANSI_QUOTES SQL mode is
        enabled. The setting of the
        lower_case_table_names system
        variable is also taken into account.
      
        You can view a child table's foreign key definitions as
        part of the output of the SHOW CREATE
        TABLE statement:
      
SHOW CREATE TABLE tbl_name;
        You can also obtain information about foreign keys by querying
        the
        INFORMATION_SCHEMA.KEY_COLUMN_USAGE
        table.
      
        You can find information about foreign keys used by
        InnoDB tables in the
        INNODB_SYS_FOREIGN and
        INNODB_SYS_FOREIGN_COLS tables,
        also in the INFORMATION_SCHEMA database.
      
mysqldump produces correct definitions of tables in the dump file, including the foreign keys for child tables.
        To make it easier to reload dump files for tables that have
        foreign key relationships, mysqldump
        automatically includes a statement in the dump output to set
        foreign_key_checks to 0. This
        avoids problems with tables having to be reloaded in a
        particular order when the dump is reloaded. It is also possible
        to set this variable manually:
      
mysql>SET foreign_key_checks = 0;mysql>SOURCEmysql>dump_file_name;SET foreign_key_checks = 1;
        This enables you to import the tables in any order if the dump
        file contains tables that are not correctly ordered for foreign
        keys. It also speeds up the import operation. Setting
        foreign_key_checks to 0 can
        also be useful for ignoring foreign key constraints during
        LOAD DATA and
        ALTER TABLE operations. However,
        even if foreign_key_checks = 0,
        MySQL does not permit the creation of a foreign key constraint
        where a column references a nonmatching column type. Also, if a
        table has foreign key constraints, ALTER
        TABLE cannot be used to alter the table to use another
        storage engine. To change the storage engine, you must drop any
        foreign key constraints first.
      
        You cannot issue DROP TABLE for a
        table that is referenced by a FOREIGN KEY
        constraint, unless you do SET foreign_key_checks =
        0. When you drop a table, any constraints that were
        defined in the statement used to create that table are also
        dropped.
      
        If you re-create a table that was dropped, it must have a
        definition that conforms to the foreign key constraints
        referencing it. It must have the correct column names and types,
        and it must have indexes on the referenced keys, as stated
        earlier. If these are not satisfied, MySQL returns Error 1005
        and refers to Error 150 in the error message, which means that a
        foreign key constraint was not correctly formed. Similarly, if
        an ALTER TABLE fails due to Error
        150, this means that a foreign key definition would be
        incorrectly formed for the altered table.
      
        For InnoDB tables, you can obtain a detailed
        explanation of the most recent InnoDB foreign
        key error in the MySQL Server, by checking the output of
        SHOW ENGINE INNODB
        STATUS.
          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. MySQL 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 reasons. 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 (including
          PRIMARY) and NOT NULL
          keys.
        
          Furthermore, 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. For storage engines that do not support foreign
          keys (such as MyISAM), MySQL
          Server parses and ignores foreign key specifications.
        In some cases, MySQL silently changes column specifications from
        those given in a CREATE TABLE or
        ALTER TABLE statement. These
        might be changes to a data type, to attributes associated with a
        data type, or to an index specification.
      
All changes are subject to the internal row-size limit of 65,535 bytes, which may cause some attempts at data type changes to fail. See Section D.10.4, “Limits on Table Column Count and Row Size”.
            Columns that are part of a PRIMARY KEY
            are made NOT NULL even if not declared
            that way.
          
            Trailing spaces are automatically deleted from
            ENUM and
            SET member values when the
            table is created.
          
MySQL maps certain data types used by other SQL database vendors to MySQL types. See Section 11.9, “Using Data Types from Other Database Engines”.
            If you include a USING clause to specify
            an index type that is not permitted for a given storage
            engine, but there is another index type available that the
            engine can use without affecting query results, the engine
            uses the available type.
          
            If strict SQL mode is not enabled, a
            VARCHAR column with a length
            specification greater than 65535 is converted to
            TEXT, and a
            VARBINARY column with a
            length specification greater than 65535 is converted to
            BLOB. Otherwise, an error
            occurs in either of these cases.
          
            Specifying the CHARACTER SET binary
            attribute for a character data type causes the column to be
            created as the corresponding binary data type:
            CHAR becomes
            BINARY,
            VARCHAR becomes
            VARBINARY, and
            TEXT becomes
            BLOB. For the
            ENUM and
            SET data types, this does not
            occur; they are created as declared. Suppose that you
            specify a table using this definition:
          
CREATE TABLE t
(
  c1 VARCHAR(10) CHARACTER SET binary,
  c2 TEXT CHARACTER SET binary,
  c3 ENUM('a','b','c') CHARACTER SET binary
);
The resulting table has this definition:
CREATE TABLE t
(
  c1 VARBINARY(10),
  c2 BLOB,
  c3 ENUM('a','b','c') CHARACTER SET binary
);
        To see whether MySQL used a data type other than the one you
        specified, issue a DESCRIBE or
        SHOW CREATE TABLE statement after
        creating or altering the table.
      
Certain other data type changes can occur if you compress a table using myisampack. See Section 15.2.3.3, “Compressed Table Characteristics”.
CREATE TABLESPACEtablespace_nameADD DATAFILE 'file_name' USE LOGFILE GROUPlogfile_group[EXTENT_SIZE [=]extent_size] [INITIAL_SIZE [=]initial_size] [AUTOEXTEND_SIZE [=]autoextend_size] [MAX_SIZE [=]max_size] [NODEGROUP [=]nodegroup_id] [WAIT] [COMMENT [=]comment_text] ENGINE [=]engine_name
      This statement is used to create a tablespace, which can contain
      one or more data files, providing storage space for tables. One
      data file is created and added to the tablespace using this
      statement. Additional data files may be added to the tablespace by
      using the ALTER TABLESPACE
      statement (see Section 13.1.8, “ALTER TABLESPACE Syntax”). For rules
      covering the naming of tablespaces, see
      Section 9.2, “Schema Object Names”.
All MySQL Cluster Disk Data objects share the same namespace. This means that each Disk Data object must be uniquely named (and not merely each Disk Data object of a given type). For example, you cannot have a tablespace and a log file group with the same name, or a tablespace and a data file with the same name.
      A log file group of one or more UNDO log files
      must be assigned to the tablespace to be created with the
      USE LOGFILE GROUP clause.
      logfile_group must be an existing log
      file group created with CREATE LOGFILE
      GROUP (see Section 13.1.14, “CREATE LOGFILE GROUP Syntax”).
      Multiple tablespaces may use the same log file group for
      UNDO logging.
    
      The EXTENT_SIZE sets the size, in bytes, of the
      extents used by any files belonging to the tablespace. The default
      value is 1M. The minimum size is 32K, and theoretical maximum is
      2G, although the practical maximum size depends on a number of
      factors. In most cases, changing the extent size does not have any
      measurable effect on performance, and the default value is
      recommended for all but the most unusual situations.
    
      An extent is a unit of disk space
      allocation. One extent is filled with as much data as that extent
      can contain before another extent is used. In theory, up to 65,535
      (64K) extents may used per data file; however, the recommended
      maximum is 32,768 (32K). The recommended maximum size for a single
      data file is 32G—that is, 32K extents × 1 MB per
      extent. In addition, once an extent is allocated to a given
      partition, it cannot be used to store data from a different
      partition; an extent cannot store data from more than one
      partition. This means, for example that a tablespace having a
      single datafile whose INITIAL_SIZE is 256 MB
      and whose EXTENT_SIZE is 128M has just two
      extents, and so can be used to store data from at most two
      different disk data table partitions.
    
      You can see how many extents remain free in a given data file by
      querying the INFORMATION_SCHEMA.FILES
      table, and so derive an estimate for how much space remains free
      in the file. For further discussion and examples, see
      Section 21.30.1, “The INFORMATION_SCHEMA FILES Table”.
    
      The INITIAL_SIZE parameter sets the data file's
      total size in bytes. Once the file has been created, its size
      cannot be changed; however, you can add more data files to the
      tablespace using ALTER TABLESPACE ... ADD
      DATAFILE. See Section 13.1.8, “ALTER TABLESPACE Syntax”.
    
      INITIAL_SIZE is optional; its default value is
      134217728 (128 MB).
    
      On 32-bit systems, the maximum supported value for
      INITIAL_SIZE is 4294967296 (4 GB). (Bug #29186)
    
      When setting EXTENT_SIZE, you may optionally
      follow the number with a one-letter abbreviation for an order of
      magnitude, similar to those used in my.cnf.
      Generally, this is one of the letters M (for
      megabytes) or G (for gigabytes). In MySQL
      Cluster NDB 7.3.2 and later, these abbreviations are also
      supported when specifying INITIAL_SIZE as well.
      (Bug #13116514, Bug #16104705, Bug #62858)
    
      INITIAL_SIZE, EXTENT_SIZE,
      and UNDO_BUFFER_SIZE are subject to rounding as
      follows:
          EXTENT_SIZE and
          UNDO_BUFFER_SIZE are each rounded up to the
          nearest whole multiple of 32K.
        
          INITIAL_SIZE is rounded
          down to the nearest whole multiple of
          32K.
        
          For data files, INITIAL_SIZE is subject
          to further rounding; the result just obtained is rounded up to
          the nearest whole multiple of EXTENT_SIZE
          (after any rounding).
      The rounding just described is done explicitly, and a warning is
      issued by the MySQL Server when any such rounding is performed.
      The rounded values are also used by the NDB kernel for calculating
      INFORMATION_SCHEMA.FILES column
      values and other purposes. However, to avoid an unexpected result,
      we suggest that you always use whole multiples of 32K in
      specifying these options.
    
      AUTOEXTEND_SIZE, MAX_SIZE,
      NODEGROUP, WAIT, and
      COMMENT are parsed but ignored, and so
      currently have no effect. These options are intended for future
      expansion.
    
      The ENGINE parameter determines the storage
      engine which uses this tablespace, with
      engine_name being the name of the
      storage engine. Currently, engine_name
      must be one of the values NDB or
      NDBCLUSTER.
    
      When CREATE TABLESPACE is used with
      ENGINE = NDB, a tablespace and associated data
      file are created on each Cluster data node. You can verify that
      the data files were created and obtain information about them by
      querying the INFORMATION_SCHEMA.FILES
      table. For example:
    
mysql>SELECT LOGFILE_GROUP_NAME, FILE_NAME, EXTRA->FROM INFORMATION_SCHEMA.FILES->WHERE TABLESPACE_NAME = 'newts' AND FILE_TYPE = 'DATAFILE';+--------------------+-------------+----------------+ | LOGFILE_GROUP_NAME | FILE_NAME | EXTRA | +--------------------+-------------+----------------+ | lg_3 | newdata.dat | CLUSTER_NODE=3 | | lg_3 | newdata.dat | CLUSTER_NODE=4 | +--------------------+-------------+----------------+ 2 rows in set (0.01 sec)
(See Section 21.30.1, “The INFORMATION_SCHEMA FILES Table”.)
      CREATE TABLESPACE is useful only
      with Disk Data storage for MySQL Cluster. See
      Section 18.5.12, “MySQL Cluster Disk Data Tables”.
CREATE
    [DEFINER = { user | CURRENT_USER }]
    TRIGGER trigger_name
    trigger_time trigger_event
    ON tbl_name FOR EACH ROW
    trigger_body
trigger_time: { BEFORE | AFTER }
trigger_event: { INSERT | UPDATE | DELETE }
      This statement creates a new trigger. A trigger is a named
      database object that is associated with a table, and that
      activates when a particular event occurs for the table. The
      trigger becomes associated with the table named
      tbl_name, which must refer to a
      permanent table. You cannot associate a trigger with a
      TEMPORARY table or a view.
    
Trigger names exist in the schema namespace, meaning that all triggers must have unique names within a schema. Triggers in different schemas can have the same name.
      This section describes CREATE
      TRIGGER syntax. For additional discussion, see
      Section 20.3.1, “Trigger Syntax and Examples”.
    
      CREATE TRIGGER requires the
      TRIGGER privilege for the table
      associated with the trigger. The statement might also require the
      SUPER privilege, depending on the
      DEFINER value, as described later in this
      section. If binary logging is enabled, CREATE
      TRIGGER might require the
      SUPER privilege, as described in
      Section 20.7, “Binary Logging of Stored Programs”.
    
      The DEFINER clause determines the security
      context to be used when checking access privileges at trigger
      activation time, as described later in this section.
    
      trigger_time is the trigger action
      time. It can be BEFORE or
      AFTER to indicate that the trigger activates
      before or after each row to be modified.
    
      trigger_event indicates the kind of
      operation that activates the trigger. These
      trigger_event values are permitted:
          INSERT: The trigger activates
          whenever a new row is inserted into the table; for example,
          through INSERT,
          LOAD DATA, and
          REPLACE statements.
        
          UPDATE: The trigger activates
          whenever a row is modified; for example, through
          UPDATE statements.
        
          DELETE: The trigger activates
          whenever a row is deleted from the table; for example, through
          DELETE and
          REPLACE statements.
          DROP TABLE and
          TRUNCATE TABLE statements on
          the table do not activate this trigger,
          because they do not use DELETE.
          Dropping a partition does not activate
          DELETE triggers, either.
      The trigger_event does not represent a
      literal type of SQL statement that activates the trigger so much
      as it represents a type of table operation. For example, an
      INSERT trigger activates not only
      for INSERT statements but also
      LOAD DATA statements because both
      statements insert rows into a table.
    
      A potentially confusing example of this is the INSERT
      INTO ... ON DUPLICATE KEY UPDATE ... syntax: a
      BEFORE INSERT trigger activates for every row,
      followed by either an AFTER INSERT trigger or
      both the BEFORE UPDATE and AFTER
      UPDATE triggers, depending on whether there was a
      duplicate key for the row.
Cascaded foreign key actions do not activate triggers.
      There cannot be multiple triggers for a given table that have the
      same trigger event and action time. For example, you cannot have
      two BEFORE UPDATE triggers for a table. But you
      can have a BEFORE UPDATE and a BEFORE
      INSERT trigger, or a BEFORE UPDATE
      and an AFTER UPDATE trigger.
    
      trigger_body is the statement to
      execute when the trigger activates. To execute multiple
      statements, use the
      BEGIN ... END
      compound statement construct. This also enables you to use the
      same statements that are permissible within stored routines. See
      Section 13.6.1, “BEGIN ... END Compound-Statement Syntax”. Some statements are not permitted in
      triggers; see Section D.1, “Restrictions on Stored Programs”.
    
      Within the trigger body, you can refer to columns in the subject
      table (the table associated with the trigger) by using the aliases
      OLD and NEW.
      OLD. refers
      to a column of an existing row before it is updated or deleted.
      col_nameNEW. refers
      to the column of a new row to be inserted or an existing row after
      it is updated.
    col_name
      MySQL stores the sql_mode system
      variable setting in effect when a trigger is created, and always
      executes the trigger body with this setting in force,
      regardless of the current server SQL mode when the
      trigger begins executing.
    
      The DEFINER clause specifies the MySQL account
      to be used when checking access privileges at trigger activation
      time. If a user value is given, it
      should be a MySQL account specified as
      '
      (the same format used in the user_name'@'host_name'GRANT
      statement), CURRENT_USER, or
      CURRENT_USER(). The default
      DEFINER value is the user who executes the
      CREATE TRIGGER statement. This is
      the same as specifying DEFINER = CURRENT_USER
      explicitly.
    
      If you specify the DEFINER clause, these rules
      determine the valid DEFINER user values:
          If you do not have the SUPER
          privilege, the only permitted user
          value is your own account, either specified literally or by
          using CURRENT_USER. You cannot
          set the definer to some other account.
        
          If you have the SUPER
          privilege, you can specify any syntactically valid account
          name. If the account does not exist, a warning is generated.
        
          Although it is possible to create a trigger with a nonexistent
          DEFINER account, it is not a good idea for
          such triggers to be activated until the account actually does
          exist. Otherwise, the behavior with respect to privilege
          checking is undefined.
      MySQL takes the DEFINER user into account when
      checking trigger privileges as follows:
          At CREATE TRIGGER time, the
          user who issues the statement must have the
          TRIGGER privilege.
        
          At trigger activation time, privileges are checked against the
          DEFINER user. This user must have these
          privileges:
              The TRIGGER privilege for
              the subject table.
            
              The SELECT privilege for
              the subject table if references to table columns occur
              using
              OLD.
              or
              col_nameNEW.
              in the trigger body.
            col_name
              The UPDATE privilege for
              the subject table if table columns are targets of
              SET NEW. assignments in
              the trigger body.
            col_name =
              value
Whatever other privileges normally are required for the statements executed by the trigger.
For more information about trigger security, see Section 20.6, “Access Control for Stored Programs and Views”.
      Within a trigger body, the
      CURRENT_USER() function returns the
      account used to check privileges at trigger activation time. This
      is the DEFINER user, not the user whose actions
      caused the trigger to be activated. For information about user
      auditing within triggers, see
      Section 6.3.14, “SQL-Based MySQL Account Activity Auditing”.
    
      If you use LOCK TABLES to lock a
      table that has triggers, the tables used within the trigger are
      also locked, as described in
      Section 13.3.5.2, “LOCK TABLES and Triggers”.
    
For additional discussion of trigger use, see Section 20.3.1, “Trigger Syntax and Examples”.
CREATE
    [OR REPLACE]
    [ALGORITHM = {UNDEFINED | MERGE | TEMPTABLE}]
    [DEFINER = { user | CURRENT_USER }]
    [SQL SECURITY { DEFINER | INVOKER }]
    VIEW view_name [(column_list)]
    AS select_statement
    [WITH [CASCADED | LOCAL] CHECK OPTION]
      The CREATE VIEW statement creates a
      new view, or replaces an existing view if the OR
      REPLACE clause is given. If the view does not exist,
      CREATE OR REPLACE
      VIEW is the same as CREATE
      VIEW. If the view does exist,
      CREATE OR REPLACE
      VIEW is the same as ALTER
      VIEW.
    
      The select_statement is a
      SELECT statement that provides the
      definition of the view. (Selecting from the view selects, in
      effect, using the SELECT
      statement.) The select_statement can
      select from base tables or other views.
    
      The view definition is “frozen” at creation time.
      Changes to the underlying tables afterward do not affect the view
      definition. For example, if a view is defined as SELECT
      * on a table, new columns added to the table later do
      not become part of the view.
    
      The ALGORITHM clause affects how MySQL
      processes the view. The DEFINER and
      SQL SECURITY clauses specify the security
      context to be used when checking access privileges at view
      invocation time. The WITH CHECK OPTION clause
      can be given to constrain inserts or updates to rows in tables
      referenced by the view. These clauses are described later in this
      section.
    
      The CREATE VIEW statement requires
      the CREATE VIEW privilege for the
      view, and some privilege for each column selected by the
      SELECT statement. For columns used
      elsewhere in the SELECT statement,
      you must have the SELECT privilege.
      If the OR REPLACE clause is present, you must
      also have the DROP privilege for
      the view. CREATE VIEW might also
      require the SUPER privilege,
      depending on the DEFINER value, as described
      later in this section.
    
When a view is referenced, privilege checking occurs as described later in this section.
      A view belongs to a database. By default, a new view is created in
      the default database. To create the view explicitly in a given
      database, use db_name.view_name syntax
      to qualify the view name with the database name:
    
mysql> CREATE VIEW test.v AS SELECT * FROM t;
Within a database, base tables and views share the same namespace, so a base table and a view cannot have the same name.
      Columns retrieved by the SELECT
      statement can be simple references to table columns, or
      expressions that use functions, constant values, operators, and so
      forth.
    
      A view must have unique column names with no duplicates, just like
      a base table. By default, the names of the columns retrieved by
      the SELECT statement are used for
      the view column names. To define explicit names for the view
      columns, the optional column_list
      clause can be given as a list of comma-separated identifiers. The
      number of names in column_list must be
      the same as the number of columns retrieved by the
      SELECT statement.
    
      Unqualified table or view names in the
      SELECT statement are interpreted
      with respect to the default database. A view can refer to tables
      or views in other databases by qualifying the table or view name
      with the appropriate database name.
    
      A view can be created from many kinds of
      SELECT statements. It can refer to
      base tables or other views. It can use joins,
      UNION, and subqueries. The
      SELECT need not even refer to any
      tables.
    
The following example defines a view that selects two columns from another table as well as an expression calculated from those columns:
mysql>CREATE TABLE t (qty INT, price INT);mysql>INSERT INTO t VALUES(3, 50);mysql>CREATE VIEW v AS SELECT qty, price, qty*price AS value FROM t;mysql>SELECT * FROM v;+------+-------+-------+ | qty | price | value | +------+-------+-------+ | 3 | 50 | 150 | +------+-------+-------+
A view definition is subject to the following restrictions:
          The SELECT statement cannot
          contain a subquery in the FROM clause.
        
          The SELECT statement cannot
          refer to system variables or user-defined variables.
        
          Within a stored program, the
          SELECT statement cannot refer
          to program parameters or local variables.
        
          The SELECT statement cannot
          refer to prepared statement parameters.
        
          Any table or view referred to in the definition must exist.
          After the view has been created, it is possible to drop a
          table or view that the definition refers to. In this case, use
          of the view results in an error. To check a view definition
          for problems of this kind, use the CHECK
          TABLE statement.
        
          The definition cannot refer to a TEMPORARY
          table, and you cannot create a TEMPORARY
          view.
        
You cannot associate a trigger with a view.
          Aliases for column names in the
          SELECT statement are checked
          against the maximum column length of 64 characters (not the
          maximum alias length of 256 characters).
      ORDER BY is permitted in a view definition, but
      it is ignored if you select from a view using a statement that has
      its own ORDER BY.
    
      For other options or clauses in the definition, they are added to
      the options or clauses of the statement that references the view,
      but the effect is undefined. For example, if a view definition
      includes a LIMIT clause, and you select from
      the view using a statement that has its own
      LIMIT clause, it is undefined which limit
      applies. This same principle applies to options such as
      ALL, DISTINCT, or
      SQL_SMALL_RESULT that follow the
      SELECT keyword, and to clauses such
      as INTO, FOR UPDATE,
      LOCK IN SHARE MODE, and
      PROCEDURE.
    
If you create a view and then change the query processing environment by changing system variables, that may affect the results you get from the view:
mysql>CREATE VIEW v (mycol) AS SELECT 'abc';Query OK, 0 rows affected (0.01 sec) mysql>SET sql_mode = '';Query OK, 0 rows affected (0.00 sec) mysql>SELECT "mycol" FROM v;+-------+ | mycol | +-------+ | mycol | +-------+ 1 row in set (0.01 sec) mysql>SET sql_mode = 'ANSI_QUOTES';Query OK, 0 rows affected (0.00 sec) mysql>SELECT "mycol" FROM v;+-------+ | mycol | +-------+ | abc | +-------+ 1 row in set (0.00 sec)
      The DEFINER and SQL SECURITY
      clauses determine which MySQL account to use when checking access
      privileges for the view when a statement is executed that
      references the view. The valid SQL SECURITY
      characteristic values are DEFINER (the default)
      and INVOKER. These indicate that the required
      privileges must be held by the user who defined or invoked the
      view, respectively.
    
      If a user value is given for the
      DEFINER clause, it should be a MySQL account
      specified as
      '
      (the same format used in the user_name'@'host_name'GRANT
      statement), CURRENT_USER, or
      CURRENT_USER(). The default
      DEFINER value is the user who executes the
      CREATE VIEW statement. This is the
      same as specifying DEFINER = CURRENT_USER
      explicitly.
    
      If you specify the DEFINER clause, these rules
      determine the valid DEFINER user values:
          If you do not have the SUPER
          privilege, the only valid user
          value is your own account, either specified literally or by
          using CURRENT_USER. You cannot
          set the definer to some other account.
        
          If you have the SUPER
          privilege, you can specify any syntactically valid account
          name. If the account does not exist, a warning is generated.
        
          Although it is possible to create a view with a nonexistent
          DEFINER account, an error occurs when the
          view is referenced if the SQL SECURITY
          value is DEFINER but the definer account
          does not exist.
For more information about view security, see Section 20.6, “Access Control for Stored Programs and Views”.
      Within a view definition,
      CURRENT_USER returns the view's
      DEFINER value by default. For views defined
      with the SQL SECURITY INVOKER characteristic,
      CURRENT_USER returns the account
      for the view's invoker. For information about user auditing within
      views, see Section 6.3.14, “SQL-Based MySQL Account Activity Auditing”.
    
      Within a stored routine that is defined with the SQL
      SECURITY DEFINER characteristic,
      CURRENT_USER returns the routine's
      DEFINER value. This also affects a view defined
      within such a routine, if the view definition contains a
      DEFINER value of
      CURRENT_USER.
    
MySQL checks view privileges like this:
          At view definition time, the view creator must have the
          privileges needed to use the top-level objects accessed by the
          view. For example, if the view definition refers to table
          columns, the creator must have some privilege for each column
          in the select list of the definition, and the
          SELECT privilege for each
          column used elsewhere in the definition. If the definition
          refers to a stored function, only the privileges needed to
          invoke the function can be checked. The privileges required at
          function invocation time can be checked only as it executes:
          For different invocations, different execution paths within
          the function might be taken.
        
          The user who references a view must have appropriate
          privileges to access it (SELECT
          to select from it, INSERT to
          insert into it, and so forth.)
        
          When a view has been referenced, privileges for objects
          accessed by the view are checked against the privileges held
          by the view DEFINER account or invoker,
          depending on whether the SQL SECURITY
          characteristic is DEFINER or
          INVOKER, respectively.
        
          If reference to a view causes execution of a stored function,
          privilege checking for statements executed within the function
          depend on whether the function SQL SECURITY
          characteristic is DEFINER or
          INVOKER. If the security characteristic is
          DEFINER, the function runs with the
          privileges of the DEFINER account. If the
          characteristic is INVOKER, the function
          runs with the privileges determined by the view's SQL
          SECURITY characteristic.
      Example: A view might depend on a stored function, and that
      function might invoke other stored routines. For example, the
      following view invokes a stored function f():
    
CREATE VIEW v AS SELECT * FROM t WHERE t.id = f(t.name);
      Suppose that f() contains a statement such as
      this:
    
IF name IS NULL then CALL p1(); ELSE CALL p2(); END IF;
      The privileges required for executing statements within
      f() need to be checked when
      f() executes. This might mean that privileges
      are needed for p1() or p2(),
      depending on the execution path within f().
      Those privileges must be checked at runtime, and the user who must
      possess the privileges is determined by the SQL
      SECURITY values of the view v and the
      function f().
    
      The DEFINER and SQL SECURITY
      clauses for views are extensions to standard SQL. In standard SQL,
      views are handled using the rules for SQL SECURITY
      DEFINER. The standard says that the definer of the view,
      which is the same as the owner of the view's schema, gets
      applicable privileges on the view (for example,
      SELECT) and may grant them. MySQL
      has no concept of a schema “owner”, so MySQL adds a
      clause to identify the definer. The DEFINER
      clause is an extension where the intent is to have what the
      standard has; that is, a permanent record of who defined the view.
      This is why the default DEFINER value is the
      account of the view creator.
    
      The optional ALGORITHM clause is a MySQL
      extension to standard SQL. It affects how MySQL processes the
      view. ALGORITHM takes three values:
      MERGE, TEMPTABLE, or
      UNDEFINED. The default algorithm is
      UNDEFINED if no ALGORITHM
      clause is present. For more information, see
      Section 20.5.2, “View Processing Algorithms”.
    
      Some views are updatable. That is, you can use them in statements
      such as UPDATE,
      DELETE, or
      INSERT to update the contents of
      the underlying table. For a view to be updatable, there must be a
      one-to-one relationship between the rows in the view and the rows
      in the underlying table. There are also certain other constructs
      that make a view nonupdatable.
    
      The WITH CHECK OPTION clause can be given for
      an updatable view to prevent inserts or updates to rows except
      those for which the WHERE clause in the
      select_statement is true.
    
      In a WITH CHECK OPTION clause for an updatable
      view, the LOCAL and CASCADED
      keywords determine the scope of check testing when the view is
      defined in terms of another view. The LOCAL
      keyword restricts the CHECK OPTION only to the
      view being defined. CASCADED causes the checks
      for underlying views to be evaluated as well. When neither keyword
      is given, the default is CASCADED.
    
      For more information about updatable views and the WITH
      CHECK OPTION clause, see
      Section 20.5.3, “Updatable and Insertable Views”, and
      Section 20.5.4, “The View WITH CHECK OPTION Clause”.
DROP {DATABASE | SCHEMA} [IF EXISTS] db_name
      DROP DATABASE drops all tables in
      the database and deletes the database. Be
      very careful with this statement! To use
      DROP DATABASE, you need the
      DROP privilege on the database.
      DROP
      SCHEMA is a synonym for DROP
      DATABASE.
When a database is dropped, user privileges on the database are not automatically dropped. See Section 13.7.1.4, “GRANT Syntax”.
      IF EXISTS is used to prevent an error from
      occurring if the database does not exist.
    
      If the default database is dropped, the default database is unset
      (the DATABASE() function returns
      NULL).
    
      If you use DROP DATABASE on a
      symbolically linked database, both the link and the original
      database are deleted.
    
      DROP DATABASE returns the number of
      tables that were removed. This corresponds to the number of
      .frm files removed.
    
      The DROP DATABASE statement removes
      from the given database directory those files and directories that
      MySQL itself may create during normal operation:
All files with the following extensions.
| .BAK | .DAT | .HSH | .MRG | 
| .MYD | .MYI | .TRG | .TRN | 
| .db | .frm | .ibd | .ndb | 
| .par | 
          The db.opt file, if it exists.
      If other files or directories remain in the database directory
      after MySQL removes those just listed, the database directory
      cannot be removed. In this case, you must remove any remaining
      files or directories manually and issue the
      DROP DATABASE statement again.
    
      Dropping a database does not remove any
      TEMPORARY tables that were created in that
      database. TEMPORARY tables are automatically
      removed when the session that created them ends. See
      Temporary Tables.
    
You can also drop databases with mysqladmin. See Section 4.5.2, “mysqladmin — Client for Administering a MySQL Server”.
DROP EVENT [IF EXISTS] event_name
      This statement drops the event named
      event_name. The event immediately
      ceases being active, and is deleted completely from the server.
    
      If the event does not exist, the error ERROR 1517
      (HY000): Unknown event
      'event_name' results. You
      can override this and cause the statement to generate a warning
      for nonexistent events instead using IF EXISTS.
    
      This statement requires the EVENT
      privilege for the schema to which the event to be dropped belongs.
      The DROP FUNCTION statement is used
      to drop stored functions and user-defined functions (UDFs):
For information about dropping stored functions, see Section 13.1.26, “DROP PROCEDURE and DROP FUNCTION Syntax”.
For information about dropping user-defined functions, see Section 13.7.3.2, “DROP FUNCTION Syntax”.
DROP INDEX [ONLINE|OFFLINE]index_nameONtbl_name[algorithm_option|lock_option] ...algorithm_option: ALGORITHM [=] {DEFAULT|INPLACE|COPY}lock_option: LOCK [=] {DEFAULT|NONE|SHARED|EXCLUSIVE}
      DROP INDEX drops the index named
      index_name from the table
      tbl_name. This statement is mapped to
      an ALTER TABLE statement to drop
      the index. See Section 13.1.7, “ALTER TABLE Syntax”.
    
      To drop a primary key, the index name is always
      PRIMARY, which must be specified as a quoted
      identifier because PRIMARY is a reserved word:
    
DROP INDEX `PRIMARY` ON t;
      Indexes on variable-width columns of
      NDB tables are dropped online; that
      is, without any table copying. The table is not locked against
      access from other MySQL Cluster API nodes, although it is locked
      against other operations on the same API node
      for the duration of the operation. This is done automatically by
      the server whenever it determines that it is possible to do so;
      you do not have to use any special SQL syntax or server options to
      cause it to happen.
    
      In MySQL Cluster, you can drop indexes offline (which causes the
      table to be locked for all API nodes in the cluster) using the
      OFFLINE keyword. The rules and limitations
      governing DROP OFFLINE INDEX and DROP
      ONLINE INDEX are the same as for ALTER OFFLINE
      TABLE ... DROP INDEX and ALTER ONLINE TABLE ...
      DROP INDEX. You cannot cause the noncopying dropping of
      an index that would normally be dropped offline by using the
      ONLINE keyword: If it is not possible to
      perform the DROP operation without table
      copying, the server ignores the ONLINE keyword.
      For more information, see
      Section 13.1.7.2, “ALTER TABLE Online Operations in MySQL Cluster”.
    
      The ONLINE and OFFLINE
      keywords are available only in MySQL Cluster; attempting to use
      these keywords in standard MySQL Server 5.6 releases
      results in a syntax error. The ONLINE and
      OFFLINE keywords are deprecated in MySQL
      Cluster NDB 7.3; they continue to be supported in MySQL Cluster
      NDB 7.4, but are scheduled for removal in a future MySQL Cluster
      release.
    
      As of MySQL 5.6.6, the ALGORITHM and
      LOCK clauses may be given. These influence the
      table copying method and level of concurrency for reading and
      writing the table while its indexes are being modified. They have
      the same meaning as for the ALTER
      TABLE statement. For more information, see
      Section 13.1.7, “ALTER TABLE Syntax”
DROP LOGFILE GROUPlogfile_groupENGINE [=]engine_name
      This statement drops the log file group named
      logfile_group. The log file group must
      already exist or an error results. (For information on creating
      log file groups, see Section 13.1.14, “CREATE LOGFILE GROUP Syntax”.)
        Before dropping a log file group, you must drop all tablespaces
        that use that log file group for UNDO
        logging.
      The required ENGINE clause provides the name of
      the storage engine used by the log file group to be dropped.
      Currently, the only permitted values for
      engine_name are
      NDB and
      NDBCLUSTER.
    
      DROP LOGFILE GROUP is useful only
      with Disk Data storage for MySQL Cluster. See
      Section 18.5.12, “MySQL Cluster Disk Data Tables”.
DROP {PROCEDURE | FUNCTION} [IF EXISTS] sp_name
      This statement is used to drop a stored procedure or function.
      That is, the specified routine is removed from the server. You
      must have the ALTER ROUTINE
      privilege for the routine. (If the
      automatic_sp_privileges system variable is
      enabled, that privilege and EXECUTE
      are granted automatically to the routine creator when the routine
      is created and dropped from the creator when the routine is
      dropped. See Section 20.2.2, “Stored Routines and MySQL Privileges”.)
    
      The IF EXISTS clause is a MySQL extension. It
      prevents an error from occurring if the procedure or function does
      not exist. A warning is produced that can be viewed with
      SHOW WARNINGS.
    
      DROP FUNCTION is also used to drop
      user-defined functions (see Section 13.7.3.2, “DROP FUNCTION Syntax”).
DROP SERVER [ IF EXISTS ] server_name
      Drops the server definition for the server named
      server_namemysql.servers table is
      deleted. This statement requires the
      SUPER privilege.
    
      Dropping a server for a table does not affect any
      FEDERATED tables that used this connection
      information when they were created. See
      Section 13.1.16, “CREATE SERVER Syntax”.
    
      DROP SERVER does not cause an automatic commit.
    
      In MySQL 5.6, DROP SERVER is not
      written to the binary log, regardless of the logging format that
      is in use.
    
      In MySQL 5.6.11 only, gtid_next
      must be set to AUTOMATIC before issuing this
      statement. (Bug #16062608, Bug #16715809, Bug #69045)
DROP [TEMPORARY] TABLE [IF EXISTS]
    tbl_name [, tbl_name] ...
    [RESTRICT | CASCADE]
      DROP TABLE removes one or more
      tables. You must have the DROP
      privilege for each table. All table data and the table definition
      are removed, so be
      careful with this statement! If any of the tables named
      in the argument list do not exist, MySQL returns an error
      indicating by name which nonexisting tables it was unable to drop,
      but it also drops all of the tables in the list that do exist.
When a table is dropped, user privileges on the table are not automatically dropped. See Section 13.7.1.4, “GRANT Syntax”.
      For a partitioned table, DROP TABLE
      permanently removes the table definition, all of its partitions,
      and all of the data which was stored in those partitions. It also
      removes the partitioning definition (.par)
      file associated with the dropped table.
    
      Use IF EXISTS to prevent an error from
      occurring for tables that do not exist. A NOTE
      is generated for each nonexistent table when using IF
      EXISTS. See Section 13.7.5.41, “SHOW WARNINGS Syntax”.
    
      RESTRICT and CASCADE are
      permitted to make porting easier. In MySQL 5.6, they
      do nothing.
        DROP TABLE automatically commits
        the current active transaction, unless you use the
        TEMPORARY keyword.
      The TEMPORARY keyword has the following
      effects:
          The statement drops only TEMPORARY tables.
        
The statement does not end an ongoing transaction.
          No access rights are checked. (A TEMPORARY
          table is visible only to the session that created it, so no
          check is necessary.)
      Using TEMPORARY is a good way to ensure that
      you do not accidentally drop a non-TEMPORARY
      table.
DROP TABLESPACEtablespace_nameENGINE [=]engine_name
      This statement drops a tablespace that was previously created
      using CREATE TABLESPACE (see
      Section 13.1.18, “CREATE TABLESPACE Syntax”).
        The tablespace to be dropped must not contain any data files; in
        other words, before you can drop a tablespace, you must first
        drop each of its data files using ALTER TABLESPACE ...
        DROP DATAFILE (see
        Section 13.1.8, “ALTER TABLESPACE Syntax”).
      The ENGINE clause (required) specifies the
      storage engine used by the tablespace. Currently, the only
      accepted values for engine_name are
      NDB and
      NDBCLUSTER.
    
      DROP TABLESPACE is useful only with
      Disk Data storage for MySQL Cluster. See
      Section 18.5.12, “MySQL Cluster Disk Data Tables”.
DROP TRIGGER [IF EXISTS] [schema_name.]trigger_name
      This statement drops a trigger. The schema (database) name is
      optional. If the schema is omitted, the trigger is dropped from
      the default schema. DROP TRIGGER
      requires the TRIGGER privilege for
      the table associated with the trigger.
    
      Use IF EXISTS to prevent an error from
      occurring for a trigger that does not exist. A
      NOTE is generated for a nonexistent trigger
      when using IF EXISTS. See
      Section 13.7.5.41, “SHOW WARNINGS Syntax”.
    
Triggers for a table are also dropped if you drop the table.
DROP VIEW [IF EXISTS]
    view_name [, view_name] ...
    [RESTRICT | CASCADE]
      DROP VIEW removes one or more
      views. You must have the DROP
      privilege for each view. If any of the views named in the argument
      list do not exist, MySQL returns an error indicating by name which
      nonexisting views it was unable to drop, but it also drops all of
      the views in the list that do exist.
    
      The IF EXISTS clause prevents an error from
      occurring for views that don't exist. When this clause is given, a
      NOTE is generated for each nonexistent view.
      See Section 13.7.5.41, “SHOW WARNINGS Syntax”.
    
      RESTRICT and CASCADE, if
      given, are parsed and ignored.
RENAME TABLEtbl_nameTOnew_tbl_name[,tbl_name2TOnew_tbl_name2] ...
This statement renames one or more tables.
      The rename operation is done atomically, which means that no other
      session can access any of the tables while the rename is running.
      For example, if you have an existing table
      old_table, you can create another table
      new_table that has the same structure but is
      empty, and then replace the existing table with the empty one as
      follows (assuming that backup_table does not
      already exist):
    
CREATE TABLE new_table (...); RENAME TABLE old_table TO backup_table, new_table TO old_table;
      If the statement renames more than one table, renaming operations
      are done from left to right. If you want to swap two table names,
      you can do so like this (assuming that
      tmp_table does not already exist):
    
RENAME TABLE old_table TO tmp_table,
             new_table TO old_table,
             tmp_table TO new_table;
      As long as two databases are on the same file system, you can use
      RENAME TABLE to move a table from
      one database to another:
    
RENAME TABLEcurrent_db.tbl_nameTOother_db.tbl_name;
      If there are any triggers associated with a table which is moved
      to a different database using RENAME
      TABLE, then the statement fails with the error
      Trigger in wrong schema.
    
      RENAME TABLE also works for views,
      as long as you do not try to rename a view into a different
      database.
    
Any privileges granted specifically for the renamed table or view are not migrated to the new name. They must be changed manually.
      When you execute RENAME, you cannot have any
      locked tables or active transactions. You must also have the
      ALTER and
      DROP privileges on the original
      table, and the CREATE and
      INSERT privileges on the new table.
    
If MySQL encounters any errors in a multiple-table rename, it does a reverse rename for all renamed tables to return everything to its original state.
      You cannot use RENAME to rename a
      TEMPORARY table. However, you can use
      ALTER TABLE instead:
    
mysql> ALTER TABLE orig_name RENAME new_name;
If the rename operation would move the table to a database located on a different file system, outcome success is platform specific and depends on the underlying operating system calls used to move table files.
TRUNCATE [TABLE] tbl_name
      TRUNCATE TABLE empties a table
      completely. It requires the DROP
      privilege.
    
      Logically, TRUNCATE TABLE is
      similar to a DELETE statement that
      deletes all rows, or a sequence of DROP
      TABLE and CREATE TABLE
      statements. To achieve high performance, it bypasses the DML
      method of deleting data. Thus, it cannot be rolled back, it does
      not cause ON DELETE triggers to fire, and it
      cannot be performed for InnoDB tables with
      parent-child foreign key relationships.
    
      Although TRUNCATE TABLE is similar
      to DELETE, it is classified as a
      DDL statement rather than a DML statement. It differs from
      DELETE in the following ways in
      MySQL 5.6:
Truncate operations drop and re-create the table, which is much faster than deleting rows one by one, particularly for large tables.
Truncate operations cause an implicit commit, and so cannot be rolled back.
Truncation operations cannot be performed if the session holds an active table lock.
          TRUNCATE TABLE fails for an
          InnoDB table or
          NDB table if there are any
          FOREIGN KEY constraints from other tables
          that reference the table. Foreign key constraints between
          columns of the same table are permitted.
        
Truncation operations do not return a meaningful value for the number of deleted rows. The usual result is “0 rows affected,” which should be interpreted as “no information.”
          As long as the table format file
          tbl_name.frmTRUNCATE TABLE, even if the
          data or index files have become corrupted.
        
          Any AUTO_INCREMENT value is reset to its
          start value. This is true even for MyISAM
          and InnoDB, which normally do not reuse
          sequence values.
        
          When used with partitioned tables,
          TRUNCATE TABLE preserves the
          partitioning; that is, the data and index files are dropped
          and re-created, while the partition definitions
          (.par) file is unaffected.
        
          The TRUNCATE TABLE statement
          does not invoke ON DELETE triggers.
      TRUNCATE TABLE for a table closes
      all handlers for the table that were opened with
      HANDLER OPEN.
    
      TRUNCATE TABLE is treated for
      purposes of binary logging and replication as
      DROP TABLE followed by
      CREATE TABLE—that is, as DDL
      rather than DML. This is due to the fact that, when using
      InnoDB and other transactional
      storage engines where the transaction isolation level does not
      permit statement-based logging (READ COMMITTED
      or READ UNCOMMITTED), the statement was not
      logged and replicated when using STATEMENT or
      MIXED logging mode. (Bug #36763) However, it is
      still applied on replication slaves using
      InnoDB in the manner described
      previously.
    
      TRUNCATE TABLE can be used with
      Performance Schema summary tables, but the effect is to reset the
      summary columns to 0 or NULL, not to remove
      rows. See Section 22.9.9, “Performance Schema Summary Tables”.
CALLsp_name([parameter[,...]]) CALLsp_name[()]
      The CALL statement invokes a stored
      procedure that was defined previously with
      CREATE PROCEDURE.
    
      Stored procedures that take no arguments can be invoked without
      parentheses. That is, CALL p() and
      CALL p are equivalent.
    
      CALL can pass back values to its
      caller using parameters that are declared as
      OUT or INOUT parameters.
      When the procedure returns, a client program can also obtain the
      number of rows affected for the final statement executed within
      the routine: At the SQL level, call the
      ROW_COUNT() function; from the C
      API, call the
      mysql_affected_rows() function.
    
      To get back a value from a procedure using an
      OUT or INOUT parameter, pass
      the parameter by means of a user variable, and then check the
      value of the variable after the procedure returns. (If you are
      calling the procedure from within another stored procedure or
      function, you can also pass a routine parameter or local routine
      variable as an IN or INOUT
      parameter.) For an INOUT parameter, initialize
      its value before passing it to the procedure. The following
      procedure has an OUT parameter that the
      procedure sets to the current server version, and an
      INOUT value that the procedure increments by
      one from its current value:
    
CREATE PROCEDURE p (OUT ver_param VARCHAR(25), INOUT incr_param INT) BEGIN # Set value of OUT parameter SELECT VERSION() INTO ver_param; # Increment value of INOUT parameter SET incr_param = incr_param + 1; END;
      Before calling the procedure, initialize the variable to be passed
      as the INOUT parameter. After calling the
      procedure, the values of the two variables will have been set or
      modified:
    
mysql>SET @increment = 10;mysql>CALL p(@version, @increment);mysql>SELECT @version, @increment;+--------------+------------+ | @version | @increment | +--------------+------------+ | 5.5.3-m3-log | 11 | +--------------+------------+
      In prepared CALL statements used
      with PREPARE and
      EXECUTE, placeholders can be used
      for IN parameters. For OUT
      and INOUT parameters, placeholder support is
      available as of MySQL 5.5.3. These types of parameters can be used
      as follows:
    
mysql>SET @increment = 10;mysql>PREPARE s FROM 'CALL p(?, ?)';mysql>EXECUTE s USING @version, @increment;mysql>SELECT @version, @increment;+--------------+------------+ | @version | @increment | +--------------+------------+ | 5.5.3-m3-log | 11 | +--------------+------------+
      Before MySQL 5.5.3, placeholder support is not available for
      OUT or INOUT parameters. To
      work around this limitation for OUT and
      INOUT parameters, forego the use of
      placeholders; instead, refer to user variables in the
      CALL statement itself and do not
      specify them in the EXECUTE
      statement:
    
mysql>SET @increment = 10;mysql>PREPARE s FROM 'CALL p(@version, @increment)';mysql>EXECUTE s;mysql>SELECT @version, @increment;+--------------+------------+ | @version | @increment | +--------------+------------+ | 5.5.0-m2-log | 11 | +--------------+------------+
      To write C programs that use the
      CALL SQL statement to execute
      stored procedures that produce result sets, the
      CLIENT_MULTI_RESULTS flag must be enabled. This
      is because each CALL returns a
      result to indicate the call status, in addition to any result sets
      that might be returned by statements executed within the
      procedure. CLIENT_MULTI_RESULTS must also be
      enabled if CALL is used to execute
      any stored procedure that contains prepared statements. It cannot
      be determined when such a procedure is loaded whether those
      statements will produce result sets, so it is necessary to assume
      that they will.
    
      CLIENT_MULTI_RESULTS can be enabled when you
      call mysql_real_connect(), either
      explicitly by passing the CLIENT_MULTI_RESULTS
      flag itself, or implicitly by passing
      CLIENT_MULTI_STATEMENTS (which also enables
      CLIENT_MULTI_RESULTS). In MySQL
      5.6, CLIENT_MULTI_RESULTS is
      enabled by default.
    
      To process the result of a CALL
      statement executed using
      mysql_query() or
      mysql_real_query(), use a loop
      that calls mysql_next_result() to
      determine whether there are more results. For an example, see
      Section 23.8.17, “C API Support for Multiple Statement Execution”.
    
      For programs written in a language that provides a MySQL
      interface, there is no native method prior to MySQL 5.5.3 for
      directly retrieving the results of OUT or
      INOUT parameters from
      CALL statements. To get the
      parameter values, pass user-defined variables to the procedure in
      the CALL statement and then execute
      a SELECT statement to produce a
      result set containing the variable values. To handle an
      INOUT parameter, execute a statement prior to
      the CALL that sets the
      corresponding user variable to the value to be passed to the
      procedure.
    
      The following example illustrates the technique (without error
      checking) for the stored procedure p described
      earlier that has an OUT parameter and an
      INOUT parameter:
    
mysql_query(mysql, "SET @increment = 10"); mysql_query(mysql, "CALL p(@version, @increment)"); mysql_query(mysql, "SELECT @version, @increment"); result = mysql_store_result(mysql); row = mysql_fetch_row(result); mysql_free_result(result);
      After the preceding code executes, row[0] and
      row[1] contain the values of
      @version and @increment,
      respectively.
    
      In MySQL 5.6, C programs can use the
      prepared-statement interface to execute
      CALL statements and access
      OUT and INOUT parameters.
      This is done by processing the result of a
      CALL statement using a loop that
      calls mysql_stmt_next_result() to
      determine whether there are more results. For an example, see
      Section 23.8.20, “C API Support for Prepared CALL Statements”. Languages that
      provide a MySQL interface can use prepared
      CALL statements to directly
      retrieve OUT and INOUT
      procedure parameters.
    
As of MySQL 5.6.6, metadata changes to objects referred to by stored programs are detected and cause automatic reparsing of the affected statements when the program is next executed. For more information, see Section 8.10.4, “Caching of Prepared Statements and Stored Programs”.
      DELETE is a DML statement that removes rows
      from a table.
DELETE [LOW_PRIORITY] [QUICK] [IGNORE] FROMtbl_name[PARTITION (partition_name,...)] [WHEREwhere_condition] [ORDER BY ...] [LIMITrow_count]
      The DELETE statement deletes rows from
      tbl_name and returns the number of
      deleted rows. To check the number of deleted rows, call the
      ROW_COUNT() function described in
      Section 12.14, “Information Functions”.
      The conditions in the optional WHERE clause
      identify which rows to delete. With no WHERE
      clause, all rows are deleted.
    
      where_condition is an expression that
      evaluates to true for each row to be deleted. It is specified as
      described in Section 13.2.9, “SELECT Syntax”.
    
      If the ORDER BY clause is specified, the rows
      are deleted in the order that is specified. The
      LIMIT clause places a limit on the number of
      rows that can be deleted. These clauses apply to single-table
      deletes, but not multi-table deletes.
DELETE [LOW_PRIORITY] [QUICK] [IGNORE]
    tbl_name[.*] [, tbl_name[.*]] ...
    FROM table_references
    [WHERE where_condition]
Or:
DELETE [LOW_PRIORITY] [QUICK] [IGNORE]
    FROM tbl_name[.*] [, tbl_name[.*]] ...
    USING table_references
    [WHERE where_condition]
      You need the DELETE privilege on a
      table to delete rows from it. You need only the
      SELECT privilege for any columns
      that are only read, such as those named in the
      WHERE clause.
      When you do not need to know the number of deleted rows, the
      TRUNCATE TABLE statement is a
      faster way to empty a table than a
      DELETE statement with no
      WHERE clause. Unlike
      DELETE,
      TRUNCATE TABLE cannot be used
      within a transaction or if you have a lock on the table. See
      Section 13.1.33, “TRUNCATE TABLE Syntax” and
      Section 13.3.5, “LOCK TABLES and UNLOCK TABLES Syntax”.
    
The speed of delete operations may also be affected by factors discussed in Section 8.2.2.3, “Speed of DELETE Statements”.
      To ensure that a given DELETE
      statement does not take too much time, the MySQL-specific
      LIMIT 
      clause for row_countDELETE specifies the
      maximum number of rows to be deleted. If the number of rows to
      delete is larger than the limit, repeat the
      DELETE statement until the number of affected
      rows is less than the LIMIT value.
Currently, you cannot delete from a table and select from the same table in a subquery.
      Beginning with MySQL 5.6.2, DELETE supports
      explicit partition selection using the
      PARTITION option, which takes a comma-separated
      list of the names of one or more partitions or subpartitions (or
      both) from which to select rows to be dropped. Partitions not
      included in the list are ignored. Given a partitioned table
      t with a partition named p0,
      executing the statement DELETE FROM t PARTITION
      (p0) has the same effect on the table as executing
      ALTER TABLE t
      TRUNCATE PARTITION (p0); in both cases, all rows in
      partition p0 are dropped.
    
      PARTITION can be used along with a
      WHERE condition, in which case the condition is
      tested only on rows in the listed partitions. For example,
      DELETE FROM t PARTITION (p0) WHERE c < 5
      deletes rows only from partition p0 for which
      the condition c < 5 is true; rows in any
      other partitions are not checked and thus not affected by the
      DELETE.
    
      The PARTITION option can also be used in
      multiple-table DELETE statements. You can use
      up to one such option per table named in the
      FROM option.
    
See Section 19.5, “Partition Selection”, for more information and examples.
      If you delete the row containing the maximum value for an
      AUTO_INCREMENT column, the value is not reused
      for a MyISAM or InnoDB
      table. If you delete all rows in the table with DELETE
      FROM  (without a
      tbl_nameWHERE clause) in
      autocommit mode, the sequence
      starts over for all storage engines except
      InnoDB and MyISAM. There are
      some exceptions to this behavior for InnoDB
      tables, as discussed in
      Section 14.5.5, “AUTO_INCREMENT Handling in InnoDB”.
    
      For MyISAM tables, you can specify an
      AUTO_INCREMENT secondary column in a
      multiple-column key. In this case, reuse of values deleted from
      the top of the sequence occurs even for MyISAM
      tables. See Section 3.6.9, “Using AUTO_INCREMENT”.
      The DELETE statement supports the
      following modifiers:
          If you specify LOW_PRIORITY, the server
          delays execution of the DELETE
          until no other clients are reading from the table. This
          affects only storage engines that use only table-level locking
          (such as MyISAM, MEMORY,
          and MERGE).
        
          For MyISAM tables, if you use the
          QUICK keyword, the storage engine does not
          merge index leaves during delete, which may speed up some
          kinds of delete operations.
        
          The IGNORE keyword causes MySQL to ignore
          errors during the process of deleting rows. (Errors
          encountered during the parsing stage are processed in the
          usual manner.) Errors that are ignored due to the use of
          IGNORE are returned as warnings.
      If the DELETE statement includes an
      ORDER BY clause, rows are deleted in the order
      specified by the clause. This is useful primarily in conjunction
      with LIMIT. For example, the following
      statement finds rows matching the WHERE clause,
      sorts them by timestamp_column, and deletes the
      first (oldest) one:
    
DELETE FROM somelog WHERE user = 'jcole' ORDER BY timestamp_column LIMIT 1;
      ORDER BY also helps to delete rows in an order
      required to avoid referential integrity violations.
      If you are deleting many rows from a large table, you may exceed
      the lock table size for an InnoDB table. To
      avoid this problem, or simply to minimize the time that the table
      remains locked, the following strategy (which does not use
      DELETE at all) might be helpful:
Select the rows not to be deleted into an empty table that has the same structure as the original table:
INSERT INTO t_copy SELECT * FROM t WHERE ... ;
          Use RENAME TABLE to atomically
          move the original table out of the way and rename the copy to
          the original name:
        
RENAME TABLE t TO t_old, t_copy TO t;
Drop the original table:
DROP TABLE t_old;
      No other sessions can access the tables involved while
      RENAME TABLE executes, so the
      rename operation is not subject to concurrency problems. See
      Section 13.1.32, “RENAME TABLE Syntax”.
      In MyISAM tables, deleted rows are maintained
      in a linked list and subsequent
      INSERT operations reuse old row
      positions. To reclaim unused space and reduce file sizes, use the
      OPTIMIZE TABLE statement or the
      myisamchk utility to reorganize tables.
      OPTIMIZE TABLE is easier to use,
      but myisamchk is faster. See
      Section 13.7.2.4, “OPTIMIZE TABLE Syntax”, and Section 4.6.3, “myisamchk — MyISAM Table-Maintenance Utility”.
    
      The QUICK modifier affects whether index leaves
      are merged for delete operations. DELETE QUICK
      is most useful for applications where index values for deleted
      rows are replaced by similar index values from rows inserted
      later. In this case, the holes left by deleted values are reused.
    
      DELETE QUICK is not useful when deleted values
      lead to underfilled index blocks spanning a range of index values
      for which new inserts occur again. In this case, use of
      QUICK can lead to wasted space in the index
      that remains unreclaimed. Here is an example of such a scenario:
          Create a table that contains an indexed
          AUTO_INCREMENT column.
        
Insert many rows into the table. Each insert results in an index value that is added to the high end of the index.
          Delete a block of rows at the low end of the column range
          using DELETE QUICK.
      In this scenario, the index blocks associated with the deleted
      index values become underfilled but are not merged with other
      index blocks due to the use of QUICK. They
      remain underfilled when new inserts occur, because new rows do not
      have index values in the deleted range. Furthermore, they remain
      underfilled even if you later use
      DELETE without
      QUICK, unless some of the deleted index values
      happen to lie in index blocks within or adjacent to the
      underfilled blocks. To reclaim unused index space under these
      circumstances, use OPTIMIZE TABLE.
    
      If you are going to delete many rows from a table, it might be
      faster to use DELETE QUICK followed by
      OPTIMIZE TABLE. This rebuilds the
      index rather than performing many index block merge operations.
      You can specify multiple tables in a
      DELETE statement to delete rows
      from one or more tables depending on the condition in the
      WHERE clause. You cannot use ORDER
      BY or LIMIT in a multiple-table
      DELETE. The
      table_references clause lists the
      tables involved in the join, as described in
      Section 13.2.9.2, “JOIN Syntax”.
    
      For the first multiple-table syntax, only matching rows from the
      tables listed before the FROM clause are
      deleted. For the second multiple-table syntax, only matching rows
      from the tables listed in the FROM clause
      (before the USING clause) are deleted. The
      effect is that you can delete rows from many tables at the same
      time and have additional tables that are used only for searching:
    
DELETE t1, t2 FROM t1 INNER JOIN t2 INNER JOIN t3 WHERE t1.id=t2.id AND t2.id=t3.id;
Or:
DELETE FROM t1, t2 USING t1 INNER JOIN t2 INNER JOIN t3 WHERE t1.id=t2.id AND t2.id=t3.id;
      These statements use all three tables when searching for rows to
      delete, but delete matching rows only from tables
      t1 and t2.
    
      The preceding examples use INNER JOIN, but
      multiple-table DELETE statements
      can use other types of join permitted in
      SELECT statements, such as
      LEFT JOIN. For example, to delete rows that
      exist in t1 that have no match in
      t2, use a LEFT JOIN:
    
DELETE t1 FROM t1 LEFT JOIN t2 ON t1.id=t2.id WHERE t2.id IS NULL;
      The syntax permits .* after each
      tbl_name for compatibility with
      Access.
    
      If you use a multiple-table DELETE
      statement involving InnoDB tables for which
      there are foreign key constraints, the MySQL optimizer might
      process tables in an order that differs from that of their
      parent/child relationship. In this case, the statement fails and
      rolls back. Instead, you should delete from a single table and
      rely on the ON DELETE capabilities that
      InnoDB provides to cause the other tables to be
      modified accordingly.
If you declare an alias for a table, you must use the alias when referring to the table:
DELETE t1 FROM test AS t1, test2 WHERE ...
      Table aliases in a multiple-table
      DELETE should be declared only in
      the table_references part of the
      statement. Elsewhere, alias references are permitted but not alias
      declarations.
    
Correct:
DELETE a1, a2 FROM t1 AS a1 INNER JOIN t2 AS a2 WHERE a1.id=a2.id; DELETE FROM a1, a2 USING t1 AS a1 INNER JOIN t2 AS a2 WHERE a1.id=a2.id;
Incorrect:
DELETE t1 AS a1, t2 AS a2 FROM t1 INNER JOIN t2 WHERE a1.id=a2.id; DELETE FROM t1 AS a1, t2 AS a2 USING t1 INNER JOIN t2 WHERE a1.id=a2.id;
DOexpr[,expr] ...
      DO executes the expressions but
      does not return any results. In most respects,
      DO is shorthand for SELECT
      , but has the
      advantage that it is slightly faster when you do not care about
      the result.
    expr, ...
      DO is useful primarily with
      functions that have side effects, such as
      RELEASE_LOCK().
    
      Example: This SELECT statement
      pauses, but also produces a result set:
    
mysql> SELECT SLEEP(5);
+----------+
| SLEEP(5) |
+----------+
|        0 |
+----------+
1 row in set (5.02 sec)
      DO, on the other hand, pauses
      without producing a result set.:
    
mysql> DO SLEEP(5);
Query OK, 0 rows affected (4.99 sec)
This could be useful, for example in a stored function or trigger, which prohibit statements that produce result sets.
      DO only executes expressions. It
      cannot be used in all cases where SELECT can be
      used. For example, DO id FROM t1 is invalid
      because it references a table.
HANDLERtbl_nameOPEN [ [AS]alias] HANDLERtbl_nameREADindex_name{ = | <= | >= | < | > } (value1,value2,...) [ WHEREwhere_condition] [LIMIT ... ] HANDLERtbl_nameREADindex_name{ FIRST | NEXT | PREV | LAST } [ WHEREwhere_condition] [LIMIT ... ] HANDLERtbl_nameREAD { FIRST | NEXT } [ WHEREwhere_condition] [LIMIT ... ] HANDLERtbl_nameCLOSE
      The HANDLER statement provides direct access to
      table storage engine interfaces. It is available for
      InnoDB and MyISAM tables.
    
      The HANDLER ... OPEN statement opens a table,
      making it accessible using subsequent HANDLER ...
      READ statements. This table object is not shared by
      other sessions and is not closed until the session calls
      HANDLER ... CLOSE or the session terminates. If
      you open the table using an alias, further references to the open
      table with other HANDLER statements must use
      the alias rather than the table name.
    
      The first HANDLER ... READ syntax fetches a row
      where the index specified satisfies the given values and the
      WHERE condition is met. If you have a
      multiple-column index, specify the index column values as a
      comma-separated list. Either specify values for all the columns in
      the index, or specify values for a leftmost prefix of the index
      columns. Suppose that an index my_idx includes
      three columns named col_a,
      col_b, and col_c, in that
      order. The HANDLER statement can specify values
      for all three columns in the index, or for the columns in a
      leftmost prefix. For example:
    
HANDLER ... READ my_idx = (col_a_val,col_b_val,col_c_val) ... HANDLER ... READ my_idx = (col_a_val,col_b_val) ... HANDLER ... READ my_idx = (col_a_val) ...
      To employ the HANDLER interface to refer to a
      table's PRIMARY KEY, use the quoted identifier
      `PRIMARY`:
    
HANDLER tbl_name READ `PRIMARY` ...
      The second HANDLER ... READ syntax fetches a
      row from the table in index order that matches the
      WHERE condition.
    
      The third HANDLER ... READ syntax fetches a row
      from the table in natural row order that matches the
      WHERE condition. It is faster than
      HANDLER  when a full table
      scan is desired. Natural row order is the order in which rows are
      stored in a tbl_name READ
      index_nameMyISAM table data file. This
      statement works for InnoDB tables as well, but
      there is no such concept because there is no separate data file.
    
      Without a LIMIT clause, all forms of
      HANDLER ... READ fetch a single row if one is
      available. To return a specific number of rows, include a
      LIMIT clause. It has the same syntax as for the
      SELECT statement. See
      Section 13.2.9, “SELECT Syntax”.
    
      HANDLER ... CLOSE closes a table that was
      opened with HANDLER ... OPEN.
    
      There are several reasons to use the HANDLER
      interface instead of normal SELECT
      statements:
          HANDLER is faster than
          SELECT:
              A designated storage engine handler object is allocated
              for the HANDLER ... OPEN. The object is
              reused for subsequent HANDLER
              statements for that table; it need not be reinitialized
              for each one.
            
There is less parsing involved.
There is no optimizer or query-checking overhead.
              The handler interface does not have to provide a
              consistent look of the data (for example,
              dirty reads are
              permitted), so the storage engine can use optimizations
              that SELECT does not
              normally permit.
          HANDLER makes it easier to port to MySQL
          applications that use a low-level ISAM-like
          interface. (See Section 14.17, “InnoDB Integration with memcached” for an
          alternative way to adapt applications that use the key-value
          store paradigm.)
        
          HANDLER enables you to traverse a database
          in a manner that is difficult (or even impossible) to
          accomplish with SELECT. The
          HANDLER interface is a more natural way to
          look at data when working with applications that provide an
          interactive user interface to the database.
      HANDLER is a somewhat low-level statement. For
      example, it does not provide consistency. That is,
      HANDLER ... OPEN does not
      take a snapshot of the table, and does not
      lock the table. This means that after a HANDLER ...
      OPEN statement is issued, table data can be modified (by
      the current session or other sessions) and these modifications
      might be only partially visible to HANDLER ...
      NEXT or HANDLER ... PREV scans.
    
An open handler can be closed and marked for reopen, in which case the handler loses its position in the table. This occurs when both of the following circumstances are true:
          Any session executes
          FLUSH TABLES
          or DDL statements on the handler's table.
        
          The session in which the handler is open executes
          non-HANDLER statements that use tables.
      TRUNCATE TABLE for a table closes
      all handlers for the table that were opened with
      HANDLER OPEN.
    
      If a table is flushed with
      FLUSH TABLES
       was
      opened with tbl_name WITH READ LOCKHANDLER, the handler is implicitly
      flushed and loses its position.
    
      HANDLER is not supported with partitioned
      tables.
INSERT [LOW_PRIORITY | DELAYED | HIGH_PRIORITY] [IGNORE]
    [INTO] tbl_name
    [PARTITION (partition_name,...)] 
    [(col_name,...)]
    {VALUES | VALUE} ({expr | DEFAULT},...),(...),...
    [ ON DUPLICATE KEY UPDATE
      col_name=expr
        [, col_name=expr] ... ]
Or:
INSERT [LOW_PRIORITY | DELAYED | HIGH_PRIORITY] [IGNORE]
    [INTO] tbl_name
    [PARTITION (partition_name,...)]
    SET col_name={expr | DEFAULT}, ...
    [ ON DUPLICATE KEY UPDATE
      col_name=expr
        [, col_name=expr] ... ]
Or:
INSERT [LOW_PRIORITY | HIGH_PRIORITY] [IGNORE]
    [INTO] tbl_name
    [PARTITION (partition_name,...)] 
    [(col_name,...)]
    SELECT ...
    [ ON DUPLICATE KEY UPDATE
      col_name=expr
        [, col_name=expr] ... ]
      INSERT inserts new rows into an
      existing table. The INSERT
      ... VALUES and
      INSERT ... SET
      forms of the statement insert rows based on explicitly specified
      values. The INSERT
      ... SELECT form inserts rows selected from another table
      or tables. INSERT
      ... SELECT is discussed further in
      Section 13.2.5.1, “INSERT ... SELECT Syntax”.
    
      In MySQL 5.6.2 and later, when inserting into a partitioned table,
      you can control which partitions and subpartitions accept new
      rows. The PARTITION option takes a
      comma-separated list of the names of one or more partitions or
      subpartitions (or both) of the table. If any of the rows to be
      inserted by a given INSERT statement do not
      match one of the partitions listed, the INSERT
      statement fails with the error Found a row not matching
      the given partition set. See
      Section 19.5, “Partition Selection”, for more information and
      examples.
    
      You can use REPLACE instead of
      INSERT to overwrite old rows.
      REPLACE is the counterpart to
      INSERT IGNORE in
      the treatment of new rows that contain unique key values that
      duplicate old rows: The new rows are used to replace the old rows
      rather than being discarded. See Section 13.2.8, “REPLACE Syntax”.
    
      tbl_name is the table into which rows
      should be inserted. The columns for which the statement provides
      values can be specified as follows:
          You can provide a comma-separated list of column names
          following the table name. In this case, a value for each named
          column must be provided by the VALUES list
          or the SELECT statement.
        
          If you do not specify a list of column names for
          INSERT ...
          VALUES or
          INSERT ...
          SELECT, values for every column in the table must be
          provided by the VALUES list or the
          SELECT statement. If you do not
          know the order of the columns in the table, use
          DESCRIBE
           to find out.
        tbl_name
          The SET clause indicates the column names
          explicitly.
Column values can be given in several ways:
If you are not running in strict SQL mode, any column not explicitly given a value is set to its default (explicit or implicit) value. For example, if you specify a column list that does not name all the columns in the table, unnamed columns are set to their default values. Default value assignment is described in Section 11.6, “Data Type Default Values”. See also Section 1.8.3.3, “Constraints on Invalid Data”.
          If you want an INSERT statement
          to generate an error unless you explicitly specify values for
          all columns that do not have a default value, you should use
          strict mode. See Section 5.1.7, “Server SQL Modes”.
        
          Use the keyword DEFAULT to set a column
          explicitly to its default value. This makes it easier to write
          INSERT statements that assign
          values to all but a few columns, because it enables you to
          avoid writing an incomplete VALUES list
          that does not include a value for each column in the table.
          Otherwise, you would have to write out the list of column
          names corresponding to each value in the
          VALUES list.
        
          You can also use
          DEFAULT(
          as a more general form that can be used in expressions to
          produce a given column's default value.
        col_name)
          If both the column list and the VALUES list
          are empty, INSERT creates a row
          with each column set to its default value:
        
INSERT INTO tbl_name () VALUES();
In strict mode, an error occurs if any column doesn't have a default value. Otherwise, MySQL uses the implicit default value for any column that does not have an explicitly defined default.
          You can specify an expression expr
          to provide a column value. This might involve type conversion
          if the type of the expression does not match the type of the
          column, and conversion of a given value can result in
          different inserted values depending on the data type. For
          example, inserting the string '1999.0e-2'
          into an INT,
          FLOAT,
          DECIMAL(10,6), or
          YEAR column results in the
          values 1999, 19.9921,
          19.992100, and 1999
          being inserted, respectively. The reason the value stored in
          the INT and
          YEAR columns is
          1999 is that the string-to-integer
          conversion looks only at as much of the initial part of the
          string as may be considered a valid integer or year. For the
          floating-point and fixed-point columns, the
          string-to-floating-point conversion considers the entire
          string a valid floating-point value.
        
          An expression expr can refer to any
          column that was set earlier in a value list. For example, you
          can do this because the value for col2
          refers to col1, which has previously been
          assigned:
        
INSERT INTO tbl_name (col1,col2) VALUES(15,col1*2);
          But the following is not legal, because the value for
          col1 refers to col2,
          which is assigned after col1:
        
INSERT INTO tbl_name (col1,col2) VALUES(col2*2,15);
          One exception involves columns that contain
          AUTO_INCREMENT values. Because the
          AUTO_INCREMENT value is generated after
          other value assignments, any reference to an
          AUTO_INCREMENT column in the assignment
          returns a 0.
      INSERT statements that use
      VALUES syntax can insert multiple rows. To do
      this, include multiple lists of column values, each enclosed
      within parentheses and separated by commas. Example:
    
INSERT INTO tbl_name (a,b,c) VALUES(1,2,3),(4,5,6),(7,8,9);
The values list for each row must be enclosed within parentheses. The following statement is illegal because the number of values in the list does not match the number of column names:
INSERT INTO tbl_name (a,b,c) VALUES(1,2,3,4,5,6,7,8,9);
      VALUE is a synonym for
      VALUES in this context. Neither implies
      anything about the number of values lists, and either may be used
      whether there is a single values list or multiple lists.
    
      The affected-rows value for an
      INSERT can be obtained using the
      ROW_COUNT() function (see
      Section 12.14, “Information Functions”), or the
      mysql_affected_rows() C API
      function (see Section 23.8.7.1, “mysql_affected_rows()”).
    
      If you use an INSERT ...
      VALUES statement with multiple value lists or
      INSERT ...
      SELECT, the statement returns an information string in
      this format:
    
Records: 100 Duplicates: 0 Warnings: 0
      Records indicates the number of rows processed
      by the statement. (This is not necessarily the number of rows
      actually inserted because Duplicates can be
      nonzero.) Duplicates indicates the number of
      rows that could not be inserted because they would duplicate some
      existing unique index value. Warnings indicates
      the number of attempts to insert column values that were
      problematic in some way. Warnings can occur under any of the
      following conditions:
          Inserting NULL into a column that has been
          declared NOT NULL. For multiple-row
          INSERT statements or
          INSERT INTO ...
          SELECT statements, the column is set to the implicit
          default value for the column data type. This is
          0 for numeric types, the empty string
          ('') for string types, and the
          “zero” value for date and time types.
          INSERT INTO ...
          SELECT statements are handled the same way as
          multiple-row inserts because the server does not examine the
          result set from the SELECT to
          see whether it returns a single row. (For a single-row
          INSERT, no warning occurs when
          NULL is inserted into a NOT
          NULL column. Instead, the statement fails with an
          error.)
        
Setting a numeric column to a value that lies outside the column's range. The value is clipped to the closest endpoint of the range.
          Assigning a value such as '10.34 a' to a
          numeric column. The trailing nonnumeric text is stripped off
          and the remaining numeric part is inserted. If the string
          value has no leading numeric part, the column is set to
          0.
        
          Inserting a string into a string column
          (CHAR,
          VARCHAR,
          TEXT, or
          BLOB) that exceeds the column's
          maximum length. The value is truncated to the column's maximum
          length.
        
Inserting a value into a date or time column that is illegal for the data type. The column is set to the appropriate zero value for the type.
      If you are using the C API, the information string can be obtained
      by invoking the mysql_info()
      function. See Section 23.8.7.35, “mysql_info()”.
    
      If INSERT inserts a row into a
      table that has an AUTO_INCREMENT column, you
      can find the value used for that column by using the SQL
      LAST_INSERT_ID() function. From
      within the C API, use the
      mysql_insert_id() function.
        These two functions do not always behave identically. The
        behavior of INSERT statements
        with respect to AUTO_INCREMENT columns is
        discussed further in Section 12.14, “Information Functions”,
        and Section 23.8.7.37, “mysql_insert_id()”.
      The INSERT statement supports the
      following modifiers:
          If you use the DELAYED keyword, the server
          puts the row or rows to be inserted into a buffer, and the
          client issuing the INSERT
          DELAYED statement can then continue immediately. If
          the table is in use, the server holds the rows. When the table
          is free, the server begins inserting rows, checking
          periodically to see whether there are any new read requests
          for the table. If there are, the delayed row queue is
          suspended until the table becomes free again. See
          Section 13.2.5.2, “INSERT DELAYED Syntax”.
        
          DELAYED is ignored with
          INSERT ...
          SELECT or
          INSERT
          ... ON DUPLICATE KEY UPDATE.
        
          DELAYED is also disregarded for an
          INSERT that uses functions
          accessing tables or triggers, or that is called from a
          function or a trigger.
            As of MySQL 5.6.6, INSERT
            DELAYED is deprecated, and will be removed in a
            future release. Use INSERT (without
            DELAYED) instead.
          If you use the LOW_PRIORITY keyword,
          execution of the INSERT is
          delayed until no other clients are reading from the table.
          This includes other clients that began reading while existing
          clients are reading, and while the INSERT
          LOW_PRIORITY statement is waiting. It is possible,
          therefore, for a client that issues an INSERT
          LOW_PRIORITY statement to wait for a very long time
          (or even forever) in a read-heavy environment. (This is in
          contrast to INSERT DELAYED,
          which lets the client continue at once.)
            LOW_PRIORITY should normally not be used
            with MyISAM tables because doing so
            disables concurrent inserts. See
            Section 8.11.3, “Concurrent Inserts”.
          If you specify HIGH_PRIORITY, it overrides
          the effect of the
          --low-priority-updates option
          if the server was started with that option. It also causes
          concurrent inserts not to be used. See
          Section 8.11.3, “Concurrent Inserts”.
        
          LOW_PRIORITY and
          HIGH_PRIORITY affect only storage engines
          that use only table-level locking (such as
          MyISAM, MEMORY, and
          MERGE).
        
          If you use the IGNORE keyword, errors that
          occur while executing the
          INSERT statement are ignored.
          For example, without IGNORE, a row that
          duplicates an existing UNIQUE index or
          PRIMARY KEY value in the table causes a
          duplicate-key error and the statement is aborted. With
          IGNORE, the row is discarded and no error
          occurs. Ignored errors may generate warnings instead, although
          duplicate-key errors do not.
        
          
          IGNORE has a similar effect on inserts into
          partitioned tables where no partition matching a given value
          is found. Without IGNORE, such
          INSERT statements are aborted
          with an error; however, when
          INSERT
          IGNORE is used, the insert operation fails silently
          for the row containing the unmatched value, but any rows that
          are matched are inserted. For an example, see
          Section 19.2.2, “LIST Partitioning”.
        
          Data conversions that would trigger errors abort the statement
          if IGNORE is not specified. With
          IGNORE, invalid values are adjusted to the
          closest values and inserted; warnings are produced but the
          statement does not abort. You can determine with the
          mysql_info() C API function
          how many rows were actually inserted into the table.
        
          If you specify ON DUPLICATE KEY UPDATE, and
          a row is inserted that would cause a duplicate value in a
          UNIQUE index or PRIMARY
          KEY, an UPDATE of the
          old row is performed. The affected-rows value per row is 1 if
          the row is inserted as a new row, 2 if an existing row is
          updated, and 0 if an existing row is set to its current
          values. If you specify the
          CLIENT_FOUND_ROWS flag to
          mysql_real_connect() when
          connecting to mysqld, the affected-rows
          value is 1 (not 0) if an existing row is set to its current
          values. See Section 13.2.5.3, “INSERT ... ON DUPLICATE KEY UPDATE Syntax”.
      Inserting into a table requires the
      INSERT privilege for the table. If
      the ON DUPLICATE KEY UPDATE clause is used and
      a duplicate key causes an UPDATE to
      be performed instead, the statement requires the
      UPDATE privilege for the columns to
      be updated. For columns that are read but not modified you need
      only the SELECT privilege (such as
      for a column referenced only on the right hand side of an
      col_name=expr
      assignment in an ON DUPLICATE KEY UPDATE
      clause).
    
      Prior to MySQL 5.6.6, an INSERT that affected a
      partitioned table using a storage engine such as
      MyISAM that employs table-level locks
      locked all partitions of the table. This was true even for
      INSERT ... PARTITION statements. (This did not
      and does not occur with storage engines such as
      InnoDB that employ row-level
      locking.) In MySQL 5.6.6 and later, MySQL uses partition lock
      pruning, so that only partitions into which rows are inserted are
      actually locked. For more information, see
      Section 19.6.4, “Partitioning and Locking”.
INSERT [LOW_PRIORITY | HIGH_PRIORITY] [IGNORE]
    [INTO] tbl_name 
    [PARTITION (partition_name,...)]
    [(col_name,...)]
    SELECT ...
    [ ON DUPLICATE KEY UPDATE col_name=expr, ... ]
        With INSERT ...
        SELECT, you can quickly insert many rows into a table
        from one or many tables. For example:
      
INSERT INTO tbl_temp2 (fld_id) SELECT tbl_temp1.fld_order_id FROM tbl_temp1 WHERE tbl_temp1.fld_order_id > 100;
        The following conditions hold for a
        INSERT ...
        SELECT statements:
            Specify IGNORE to ignore rows that would
            cause duplicate-key violations.
          
            DELAYED is ignored with
            INSERT ...
            SELECT.
          
            The target table of the
            INSERT statement may appear
            in the FROM clause of the
            SELECT part of the query.
            (This was not possible in some older versions of MySQL.)
            However, you cannot insert into a table and select from the
            same table in a subquery.
          
            When selecting from and inserting into a table at the same
            time, MySQL creates a temporary table to hold the rows from
            the SELECT and then inserts
            those rows into the target table. However, it remains true
            that you cannot use INSERT INTO t ... SELECT ...
            FROM t when t is a
            TEMPORARY table, because
            TEMPORARY tables cannot be referred to
            twice in the same statement (see
            Section B.5.7.2, “TEMPORARY Table Problems”).
          
            AUTO_INCREMENT columns work as usual.
          
            To ensure that the binary log can be used to re-create the
            original tables, MySQL does not permit concurrent inserts
            for INSERT
            ... SELECT statements.
          
            To avoid ambiguous column reference problems when the
            SELECT and the
            INSERT refer to the same
            table, provide a unique alias for each table used in the
            SELECT part, and qualify
            column names in that part with the appropriate alias.
        Starting with MySQL 5.6.2, you can explicitly select which
        partitions or subpartitions (or both) of the source or target
        table (or both) are to be used with a
        PARTITION option following the name of the
        table. When PARTITION is used with the name
        of the source table in the SELECT
        portion of the statement, rows are selected only from the
        partitions or subpartitions named in its partition list. When
        PARTITION is used with the name of the target
        table for the INSERT portion of
        the statement, then it must be possible to insert all rows
        selected into the partitions or subpartitions named in the
        partition list following the option, else the INSERT
        ... SELECT statement fails. For more information and
        examples, see Section 19.5, “Partition Selection”.
      
        In the values part of ON DUPLICATE KEY
        UPDATE, you can refer to columns in other tables, as
        long as you do not use GROUP BY in the
        SELECT part. One side effect is
        that you must qualify nonunique column names in the values part.
      
        The order in which rows are returned by a
        SELECT statement with no
        ORDER BY clause is not determined. This means
        that, when using replication, there is no guarantee that such a
        SELECT returns rows in the same order on the
        master and the slave; this can lead to inconsistencies between
        them. To prevent this from occurring, you should always write
        INSERT ... SELECT statements that are to be
        replicated as INSERT ... SELECT ... ORDER BY
        . The choice of
        columncolumn does not matter as long as the
        same order for returning the rows is enforced on both the master
        and the slave. See also
        Section 17.4.1.16, “Replication and LIMIT”.
      
        Due to this issue, beginning with MySQL 5.6.4,
        INSERT ...
        SELECT ON DUPLICATE KEY UPDATE and
        INSERT IGNORE ...
        SELECT statements are flagged as unsafe for
        statement-based replication. With this change, such statements
        produce a warning in the log when using statement-based mode and
        are logged using the row-based format when using
        MIXED mode. (Bug #11758262, Bug #50439)
      
See also Section 17.1.2.1, “Advantages and Disadvantages of Statement-Based and Row-Based Replication”.
        Prior to MySQL 5.6.6, an INSERT ... SELECT
        statement that acted on partitioned tables using a storage
        engine such as MyISAM that employs
        table-level locks locked all partitions of the source and target
        tables. (This did not and does not occur with tables using
        storage engines such as InnoDB that
        employ row-level locking.) In MySQL 5.6.6 and later, only those
        partitions of the source table that are actually read are
        locked, although all partitions of the target table are locked.
        See Section 19.6.4, “Partitioning and Locking”, for more
        information.
INSERT DELAYED ...
        The DELAYED option for the
        INSERT statement is a MySQL
        extension to standard SQL that can be used for certain kinds of
        tables (such as MyISAM). When a client uses
        INSERT DELAYED, it gets an okay
        from the server at once, and the row is queued to be inserted
        when the table is not in use by any other thread.
          INSERT DELAYED is slower than a
          normal INSERT if the table is
          not otherwise in use. There is also the additional overhead
          for the server to handle a separate thread for each table for
          which there are delayed rows. This means that you should use
          INSERT DELAYED only when you
          are really sure that you need it.
        
          As of MySQL 5.6.6, INSERT
          DELAYED is deprecated, and will be removed in a
          future release. Use INSERT (without
          DELAYED) instead.
        The queued rows are held only in memory until they are inserted
        into the table. This means that if you terminate
        mysqld forcibly (for example, with
        kill -9) or if mysqld dies
        unexpectedly, any queued rows that have not been
        written to disk are lost.
      
        There are some constraints on the use of
        DELAYED:
            INSERT DELAYED works only
            with MyISAM, MEMORY,
            ARCHIVE, and BLACKHOLE
            tables. For engines that do not support
            DELAYED, an error occurs.
          
            An error occurs for INSERT
            DELAYED if used with a table that has been locked
            with LOCK TABLES because the insert must
            be handled by a separate thread, not by the session that
            holds the lock.
          
            For MyISAM tables, if there are no free
            blocks in the middle of the data file, concurrent
            SELECT and
            INSERT statements are
            supported. Under these circumstances, you very seldom need
            to use INSERT DELAYED with
            MyISAM.
          
            INSERT DELAYED should be used
            only for INSERT statements
            that specify value lists. The server ignores
            DELAYED for
            INSERT ...
            SELECT or
            INSERT
            ... ON DUPLICATE KEY UPDATE statements.
          
            Because the INSERT DELAYED
            statement returns immediately, before the rows are inserted,
            you cannot use
            LAST_INSERT_ID() to get the
            AUTO_INCREMENT value that the statement
            might generate.
          
            DELAYED rows are not visible to
            SELECT statements until they
            actually have been inserted.
          
            Prior to MySQL 5.6, INSERT
            DELAYED was treated as a normal
            INSERT if the statement
            inserted multiple rows, binary logging was enabled, and the
            global logging format was statement-based (that is, whenever
            binlog_format was set to
            STATEMENT). Beginning with MySQL
            5.6, INSERT
            DELAYED is always handled as a simple
            INSERT (that is, without the
            DELAYED option) whenever the value of
            binlog_format is
            STATEMENT or MIXED.
            (In the latter case, the statement no longer triggers a
            switch to row-based logging, and so is logged using the
            statement-based format.)
          
            This does not apply when using row-based binary logging mode
            (binlog_format set to
            ROW), in which
            INSERT DELAYED statements are
            always executed using the DELAYED option
            as specified, and logged as row-update events.
          
            DELAYED is ignored on slave replication
            servers, so that INSERT
            DELAYED is treated as a normal
            INSERT on slaves. This is
            because DELAYED could cause the slave to
            have different data than the master.
          
            Pending INSERT DELAYED
            statements are lost if a table is write locked and
            ALTER TABLE is used to modify
            the table structure.
          
            INSERT DELAYED is not
            supported for views.
          
            INSERT DELAYED is not
            supported for partitioned tables.
        The following describes in detail what happens when you use the
        DELAYED option to
        INSERT or
        REPLACE. In this description, the
        “thread” is the thread that received an
        INSERT DELAYED statement and
        “handler” is the thread that handles all
        INSERT DELAYED statements for a
        particular table.
            When a thread executes a DELAYED
            statement for a table, a handler thread is created to
            process all DELAYED statements for the
            table, if no such handler already exists.
          
            The thread checks whether the handler has previously
            acquired a DELAYED lock; if not, it tells
            the handler thread to do so. The DELAYED
            lock can be obtained even if other threads have a
            READ or WRITE lock on
            the table. However, the handler waits for all
            ALTER TABLE locks or
            FLUSH
            TABLES statements to finish, to ensure that the
            table structure is up to date.
          
            The thread executes the
            INSERT statement, but instead
            of writing the row to the table, it puts a copy of the final
            row into a queue that is managed by the handler thread. Any
            syntax errors are noticed by the thread and reported to the
            client program.
          
            The client cannot obtain from the server the number of
            duplicate rows or the AUTO_INCREMENT
            value for the resulting row, because the
            INSERT returns before the
            insert operation has been completed. (If you use the C API,
            the mysql_info() function
            does not return anything meaningful, for the same reason.)
          
The binary log is updated by the handler thread when the row is inserted into the table. In case of multiple-row inserts, the binary log is updated when the first row is inserted.
            
            Each time that
            delayed_insert_limit rows
            are written, the handler checks whether any
            SELECT statements are still
            pending. If so, it permits these to execute before
            continuing.
          
            
            When the handler has no more rows in its queue, the table is
            unlocked. If no new INSERT
            DELAYED statements are received within
            delayed_insert_timeout
            seconds, the handler terminates.
          
            If more than
            delayed_queue_size rows are
            pending in a specific handler queue, the thread requesting
            INSERT DELAYED waits until
            there is room in the queue. This is done to ensure that
            mysqld does not use all memory for the
            delayed memory queue.
          
            The handler thread shows up in the MySQL process list with
            delayed_insert in the
            Command column. It is killed if you
            execute a FLUSH
            TABLES statement or kill it with KILL
            . However,
            before exiting, it first stores all queued rows into the
            table. During this time it does not accept any new
            thread_idINSERT statements from other
            threads. If you execute an INSERT
            DELAYED statement after this, a new handler thread
            is created.
          
            This means that INSERT
            DELAYED statements have higher priority than
            normal INSERT statements if
            there is an INSERT DELAYED
            handler running. Other update statements have to wait until
            the INSERT DELAYED queue is
            empty, someone terminates the handler thread (with
            KILL
            ), or someone
            executes a thread_idFLUSH
            TABLES.
          
            The following status variables provide information about
            INSERT DELAYED statements.
| Status Variable | Meaning | 
|---|---|
| Delayed_insert_threads | Number of handler threads | 
| Delayed_writes | Number of rows written with INSERT
DELAYED | 
| Not_flushed_delayed_rows | Number of rows waiting to be written | 
            You can view these variables by issuing a
            SHOW STATUS statement or by
            executing a mysqladmin extended-status
            command.
        If you specify ON DUPLICATE KEY UPDATE, and a
        row is inserted that would cause a duplicate value in a
        UNIQUE index or PRIMARY
        KEY, MySQL performs an
        UPDATE of the old row. For
        example, if column a is declared as
        UNIQUE and contains the value
        1, the following two statements have similar
        effect:
      
INSERT INTO table (a,b,c) VALUES (1,2,3) ON DUPLICATE KEY UPDATE c=c+1; UPDATE table SET c=c+1 WHERE a=1;
        (The effects are not identical for an InnoDB
        table where a is an auto-increment column.
        With an auto-increment column, an INSERT
        statement increases the auto-increment value but
        UPDATE does not.)
      
        The ON DUPLICATE KEY UPDATE clause can
        contain multiple column assignments, separated by commas.
      
        With ON DUPLICATE KEY UPDATE, the
        affected-rows value per row is 1 if the row is inserted as a new
        row, 2 if an existing row is updated, and 0 if an existing row
        is set to its current values. If you specify the
        CLIENT_FOUND_ROWS flag to
        mysql_real_connect() when
        connecting to mysqld, the affected-rows value
        is 1 (not 0) if an existing row is set to its current values.
      
        If column b is also unique, the
        INSERT is equivalent to this
        UPDATE statement instead:
      
UPDATE table SET c=c+1 WHERE a=1 OR b=2 LIMIT 1;
        If a=1 OR b=2 matches several rows, only
        one row is updated. In general, you should
        try to avoid using an ON DUPLICATE KEY UPDATE
        clause on tables with multiple unique indexes.
      
        You can use the
        VALUES(
        function in the col_name)UPDATE clause to
        refer to column values from the
        INSERT portion of the
        INSERT ...
        ON DUPLICATE KEY UPDATE statement. In other words,
        VALUES(
        in the col_name)ON DUPLICATE KEY UPDATE clause refers
        to the value of col_name that would
        be inserted, had no duplicate-key conflict occurred. This
        function is especially useful in multiple-row inserts. The
        VALUES() function is meaningful
        only in INSERT ... UPDATE statements and
        returns NULL otherwise. Example:
      
INSERT INTO table (a,b,c) VALUES (1,2,3),(4,5,6) ON DUPLICATE KEY UPDATE c=VALUES(a)+VALUES(b);
That statement is identical to the following two statements:
INSERT INTO table (a,b,c) VALUES (1,2,3) ON DUPLICATE KEY UPDATE c=3; INSERT INTO table (a,b,c) VALUES (4,5,6) ON DUPLICATE KEY UPDATE c=9;
        If a table contains an AUTO_INCREMENT column
        and INSERT
        ... ON DUPLICATE KEY UPDATE inserts or updates a row,
        the LAST_INSERT_ID() function
        returns the AUTO_INCREMENT value.
      
        The DELAYED option is ignored when you use
        ON DUPLICATE KEY UPDATE.
      
        Because the results of
        INSERT ...
        SELECT statements depend on the ordering of rows from
        the SELECT and this order cannot
        always be guaranteed, it is possible when logging
        INSERT ...
        SELECT ON DUPLICATE KEY UPDATE statements for the
        master and the slave to diverge. Thus, in MySQL 5.6.4 and later,
        INSERT ...
        SELECT ON DUPLICATE KEY UPDATE statements are flagged
        as unsafe for statement-based replication. With this change,
        such statements produce a warning in the log when using
        statement-based mode and are logged using the row-based format
        when using MIXED mode. In addition, beginning
        with MySQL 5.6.6, an
        INSERT ...
        ON DUPLICATE KEY UPDATE statement against a table
        having more than one unique or primary key is also marked as
        unsafe. (Bug #11765650, Bug #58637) See also
        Section 17.1.2.1, “Advantages and Disadvantages of Statement-Based and Row-Based
        Replication”.
      
        Prior to MySQL 5.6.6, an INSERT ... ON DUPLICATE KEY
        UPDATE on a partitioned table using a storage engine
        such as MyISAM that employs
        table-level locks locked all partitions of the table. (This did
        not and does not occur with tables using storage engines such as
        InnoDB that employ row-level
        locking.) In MySQL 5.6.6 and later, such statements lock only
        those partitions in which a partitioning key column is updated.
        See Section 19.6.4, “Partitioning and Locking”, for more
        information.
LOAD DATA [LOW_PRIORITY | CONCURRENT] [LOCAL] INFILE 'file_name' [REPLACE | IGNORE] INTO TABLEtbl_name[PARTITION (partition_name,...)] [CHARACTER SETcharset_name] [{FIELDS | COLUMNS} [TERMINATED BY 'string'] [[OPTIONALLY] ENCLOSED BY 'char'] [ESCAPED BY 'char'] ] [LINES [STARTING BY 'string'] [TERMINATED BY 'string'] ] [IGNOREnumber{LINES | ROWS}] [(col_name_or_user_var,...)] [SETcol_name=expr,...]
      The LOAD DATA
      INFILE statement reads rows from a text file into a
      table at a very high speed.
      LOAD DATA
      INFILE is the complement of
      SELECT ... INTO
      OUTFILE. (See Section 13.2.9.1, “SELECT ... INTO Syntax”.) To write
      data from a table to a file, use
      SELECT ... INTO
      OUTFILE. To read the file back into a table, use
      LOAD DATA
      INFILE. The syntax of the FIELDS and
      LINES clauses is the same for both statements.
      Both clauses are optional, but FIELDS must
      precede LINES if both are specified.
    
      You can also load data files by using the
      mysqlimport utility; it operates by sending a
      LOAD DATA
      INFILE statement to the server. The
      --local option causes
      mysqlimport to read data files from the client
      host. You can specify the
      --compress option to get
      better performance over slow networks if the client and server
      support the compressed protocol. See
      Section 4.5.5, “mysqlimport — A Data Import Program”.
    
      For more information about the efficiency of
      INSERT versus
      LOAD DATA
      INFILE and speeding up
      LOAD DATA
      INFILE, see Section 8.2.2.1, “Speed of INSERT Statements”.
    
      The file name must be given as a literal string. On Windows,
      specify backslashes in path names as forward slashes or doubled
      backslashes. The
      character_set_filesystem system
      variable controls the interpretation of the file name.
    
      In MySQL 5.6.2 and later, LOAD DATA supports
      explicit partition selection using the
      PARTITION option with a comma-separated list of
      more or more names of partitions, subpartitions, or both. When
      this option is used, if any rows from the file cannot be inserted
      into any of the partitions or subpartitions named in the list, the
      statement fails with the error Found a row not matching
      the given partition set. For more information, see
      Section 19.5, “Partition Selection”.
    
      For partitioned tables using storage engines that employ table
      locks, such as MyISAM, LOAD
      DATA cannot prune any partition locks. This does not
      apply to tables using storage engines which employ row-level
      locking, such as InnoDB. For more
      information, see
      Section 19.6.4, “Partitioning and Locking”.
    
      The server uses the character set indicated by the
      character_set_database system
      variable to interpret the information in the file. SET
      NAMES and the setting of
      character_set_client do not
      affect interpretation of input. If the contents of the input file
      use a character set that differs from the default, it is usually
      preferable to specify the character set of the file by using the
      CHARACTER SET clause. A character set of
      binary specifies “no conversion.”
    
      LOAD DATA
      INFILE interprets all fields in the file as having the
      same character set, regardless of the data types of the columns
      into which field values are loaded. For proper interpretation of
      file contents, you must ensure that it was written with the
      correct character set. For example, if you write a data file with
      mysqldump -T or by issuing a
      SELECT ... INTO
      OUTFILE statement in mysql, be sure
      to use a --default-character-set option so that
      output is written in the character set to be used when the file is
      loaded with LOAD DATA
      INFILE.
        It is not possible to load data files that use the
        ucs2, utf16,
        utf16le, or utf32
        character set.
      If you use LOW_PRIORITY, execution of the
      LOAD DATA statement is delayed
      until no other clients are reading from the table. This affects
      only storage engines that use only table-level locking (such as
      MyISAM, MEMORY, and
      MERGE).
    
      If you specify CONCURRENT with a
      MyISAM table that satisfies the condition for
      concurrent inserts (that is, it contains no free blocks in the
      middle), other threads can retrieve data from the table while
      LOAD DATA is executing. This option
      affects the performance of LOAD
      DATA a bit, even if no other thread is using the table
      at the same time.
    
      With row-based replication, CONCURRENT is
      replicated regardless of MySQL version. With statement-based
      replication CONCURRENT is not replicated prior
      to MySQL 5.5.1 (see Bug #34628). For more information, see
      Section 17.4.1.17, “Replication and LOAD DATA INFILE”.
    
      The LOCAL keyword affects expected location of
      the file and error handling, as described later.
      LOCAL works only if your server and your client
      both have been configured to permit it. For example, if
      mysqld was started with
      --local-infile=0,
      LOCAL does not work. See
      Section 6.1.6, “Security Issues with LOAD DATA LOCAL”.
    
      The LOCAL keyword affects where the file is
      expected to be found:
          If LOCAL is specified, the file is read by
          the client program on the client host and sent to the server.
          The file can be given as a full path name to specify its exact
          location. If given as a relative path name, the name is
          interpreted relative to the directory in which the client
          program was started.
        
          When using LOCAL with
          LOAD DATA, a copy of the file
          is created in the server's temporary directory. This is
          not the directory determined by the value
          of tmpdir or
          slave_load_tmpdir, but rather
          the operating system's temporary directory, and is not
          configurable in the MySQL Server. (Typically the system
          temporary directory is /tmp on Linux
          systems and C:\WINDOWS\TEMP on Windows.)
          Lack of sufficient space for the copy in this directory can
          cause the LOAD DATA
          LOCAL statement to fail.
        
          If LOCAL is not specified, the file must be
          located on the server host and is read directly by the server.
          The server uses the following rules to locate the file:
If the file name is an absolute path name, the server uses it as given.
If the file name is a relative path name with one or more leading components, the server searches for the file relative to the server's data directory.
If a file name with no leading components is given, the server looks for the file in the database directory of the default database.
      In the non-LOCAL case, these rules mean that a
      file named as ./myfile.txt is read from the
      server's data directory, whereas the file named as
      myfile.txt is read from the database
      directory of the default database. For example, if
      db1 is the default database, the following
      LOAD DATA statement reads the file
      data.txt from the database directory for
      db1, even though the statement explicitly loads
      the file into a table in the db2 database:
    
LOAD DATA INFILE 'data.txt' INTO TABLE db2.my_table;
      For security reasons, when reading text files located on the
      server, the files must either reside in the database directory or
      be readable by the user account used to run the server. Also, to
      use LOAD DATA
      INFILE on server files, you must have the
      FILE privilege. See
      Section 6.2.1, “Privileges Provided by MySQL”. For
      non-LOCAL load operations, if the
      secure_file_priv system variable
      is set to a nonempty directory name, the file to be loaded must be
      located in that directory.
    
      Using LOCAL is a bit slower than letting the
      server access the files directly, because the contents of the file
      must be sent over the connection by the client to the server. On
      the other hand, you do not need the
      FILE privilege to load local files.
    
      LOCAL also affects error handling:
          With LOAD DATA
          INFILE, data-interpretation and duplicate-key errors
          terminate the operation.
        
          With LOAD DATA
          LOCAL INFILE, data-interpretation and duplicate-key
          errors become warnings and the operation continues because the
          server has no way to stop transmission of the file in the
          middle of the operation. For duplicate-key errors, this is the
          same as if IGNORE is specified.
          IGNORE is explained further later in this
          section.
      The REPLACE and IGNORE
      keywords control handling of input rows that duplicate existing
      rows on unique key values:
          If you specify REPLACE, input rows replace
          existing rows. In other words, rows that have the same value
          for a primary key or unique index as an existing row. See
          Section 13.2.8, “REPLACE Syntax”.
        
          If you specify IGNORE, rows that duplicate
          an existing row on a unique key value are discarded.
        
          If you do not specify either option, the behavior depends on
          whether the LOCAL keyword is specified.
          Without LOCAL, an error occurs when a
          duplicate key value is found, and the rest of the text file is
          ignored. With LOCAL, the default behavior
          is the same as if IGNORE is specified; this
          is because the server has no way to stop transmission of the
          file in the middle of the operation.
      To ignore foreign key constraints during the load operation, issue
      a SET foreign_key_checks = 0 statement before
      executing LOAD DATA.
    
      If you use LOAD DATA
      INFILE on an empty MyISAM table, all
      nonunique indexes are created in a separate batch (as for
      REPAIR TABLE). Normally, this makes
      LOAD DATA
      INFILE much faster when you have many indexes. In some
      extreme cases, you can create the indexes even faster by turning
      them off with ALTER TABLE ... DISABLE KEYS
      before loading the file into the table and using ALTER
      TABLE ... ENABLE KEYS to re-create the indexes after
      loading the file. See Section 8.2.2.1, “Speed of INSERT Statements”.
    
      For both the LOAD DATA
      INFILE and
      SELECT ... INTO
      OUTFILE statements, the syntax of the
      FIELDS and LINES clauses is
      the same. Both clauses are optional, but FIELDS
      must precede LINES if both are specified.
    
      If you specify a FIELDS clause, each of its
      subclauses (TERMINATED BY,
      [OPTIONALLY] ENCLOSED BY, and ESCAPED
      BY) is also optional, except that you must specify at
      least one of them.
    
      If you specify no FIELDS or
      LINES clause, the defaults are the same as if
      you had written this:
    
FIELDS TERMINATED BY '\t' ENCLOSED BY '' ESCAPED BY '\\' LINES TERMINATED BY '\n' STARTING BY ''
      (Backslash is the MySQL escape character within strings in SQL
      statements, so to specify a literal backslash, you must specify
      two backslashes for the value to be interpreted as a single
      backslash. The escape sequences '\t' and
      '\n' specify tab and newline characters,
      respectively.)
    
      In other words, the defaults cause
      LOAD DATA
      INFILE to act as follows when reading input:
Look for line boundaries at newlines.
Do not skip over any line prefix.
Break lines into fields at tabs.
Do not expect fields to be enclosed within any quoting characters.
          Interpret characters preceded by the escape character
          “\” as escape sequences. For
          example, “\t”,
          “\n”, and
          “\\” signify tab, newline, and
          backslash, respectively. See the discussion of FIELDS
          ESCAPED BY later for the full list of escape
          sequences.
      Conversely, the defaults cause
      SELECT ... INTO
      OUTFILE to act as follows when writing output:
Write tabs between fields.
Do not enclose fields within any quoting characters.
          Use “\” to escape instances of
          tab, newline, or “\” that
          occur within field values.
        
Write newlines at the ends of lines.
        If you have generated the text file on a Windows system, you
        might have to use LINES TERMINATED BY '\r\n'
        to read the file properly, because Windows programs typically
        use two characters as a line terminator. Some programs, such as
        WordPad, might use \r as a
        line terminator when writing files. To read such files, use
        LINES TERMINATED BY '\r'.
      If all the lines you want to read in have a common prefix that you
      want to ignore, you can use LINES STARTING BY
      ' to skip over
      the prefix, and anything before it. If a line
      does not include the prefix, the entire line is skipped. Suppose
      that you issue the following statement:
    prefix_string'
LOAD DATA INFILE '/tmp/test.txt' INTO TABLE test FIELDS TERMINATED BY ',' LINES STARTING BY 'xxx';
If the data file looks like this:
xxx"abc",1 something xxx"def",2 "ghi",3
      The resulting rows will be ("abc",1) and
      ("def",2). The third row in the file is skipped
      because it does not contain the prefix.
    
      The IGNORE  option can be used to ignore lines at the start of
      the file. For example, you can use number
      LINESIGNORE 1
      LINES to skip over an initial header line containing
      column names:
    
LOAD DATA INFILE '/tmp/test.txt' INTO TABLE test IGNORE 1 LINES;
      When you use SELECT
      ... INTO OUTFILE in tandem with
      LOAD DATA
      INFILE to write data from a database into a file and
      then read the file back into the database later, the field- and
      line-handling options for both statements must match. Otherwise,
      LOAD DATA
      INFILE will not interpret the contents of the file
      properly. Suppose that you use
      SELECT ... INTO
      OUTFILE to write a file with fields delimited by commas:
    
SELECT * INTO OUTFILE 'data.txt' FIELDS TERMINATED BY ',' FROM table2;
To read the comma-delimited file back in, the correct statement would be:
LOAD DATA INFILE 'data.txt' INTO TABLE table2 FIELDS TERMINATED BY ',';
      If instead you tried to read in the file with the statement shown
      following, it wouldn't work because it instructs
      LOAD DATA
      INFILE to look for tabs between fields:
    
LOAD DATA INFILE 'data.txt' INTO TABLE table2 FIELDS TERMINATED BY '\t';
The likely result is that each input line would be interpreted as a single field.
      LOAD DATA
      INFILE can be used to read files obtained from external
      sources. For example, many programs can export data in
      comma-separated values (CSV) format, such that lines have fields
      separated by commas and enclosed within double quotation marks,
      with an initial line of column names. If the lines in such a file
      are terminated by carriage return/newline pairs, the statement
      shown here illustrates the field- and line-handling options you
      would use to load the file:
    
LOAD DATA INFILE 'data.txt' INTO TABLE tbl_name
  FIELDS TERMINATED BY ',' ENCLOSED BY '"'
  LINES TERMINATED BY '\r\n'
  IGNORE 1 LINES;
      If the input values are not necessarily enclosed within quotation
      marks, use OPTIONALLY before the
      ENCLOSED BY keywords.
    
      Any of the field- or line-handling options can specify an empty
      string (''). If not empty, the FIELDS
      [OPTIONALLY] ENCLOSED BY and FIELDS ESCAPED
      BY values must be a single character. The
      FIELDS TERMINATED BY, LINES STARTING
      BY, and LINES TERMINATED BY values
      can be more than one character. For example, to write lines that
      are terminated by carriage return/linefeed pairs, or to read a
      file containing such lines, specify a LINES TERMINATED BY
      '\r\n' clause.
    
      To read a file containing jokes that are separated by lines
      consisting of %%, you can do this
    
CREATE TABLE jokes (a INT NOT NULL AUTO_INCREMENT PRIMARY KEY, joke TEXT NOT NULL); LOAD DATA INFILE '/tmp/jokes.txt' INTO TABLE jokes FIELDS TERMINATED BY '' LINES TERMINATED BY '\n%%\n' (joke);
      FIELDS [OPTIONALLY] ENCLOSED BY controls
      quoting of fields. For output
      (SELECT ... INTO
      OUTFILE), if you omit the word
      OPTIONALLY, all fields are enclosed by the
      ENCLOSED BY character. An example of such
      output (using a comma as the field delimiter) is shown here:
    
"1","a string","100.20" "2","a string containing a , comma","102.20" "3","a string containing a \" quote","102.20" "4","a string containing a \", quote and comma","102.20"
      If you specify OPTIONALLY, the
      ENCLOSED BY character is used only to enclose
      values from columns that have a string data type (such as
      CHAR,
      BINARY,
      TEXT, or
      ENUM):
    
1,"a string",100.20 2,"a string containing a , comma",102.20 3,"a string containing a \" quote",102.20 4,"a string containing a \", quote and comma",102.20
      Occurrences of the ENCLOSED BY character within
      a field value are escaped by prefixing them with the
      ESCAPED BY character. Also, if you specify an
      empty ESCAPED BY value, it is possible to
      inadvertently generate output that cannot be read properly by
      LOAD DATA
      INFILE. For example, the preceding output just shown
      would appear as follows if the escape character is empty. Observe
      that the second field in the fourth line contains a comma
      following the quote, which (erroneously) appears to terminate the
      field:
    
1,"a string",100.20 2,"a string containing a , comma",102.20 3,"a string containing a " quote",102.20 4,"a string containing a ", quote and comma",102.20
      For input, the ENCLOSED BY character, if
      present, is stripped from the ends of field values. (This is true
      regardless of whether OPTIONALLY is specified;
      OPTIONALLY has no effect on input
      interpretation.) Occurrences of the ENCLOSED BY
      character preceded by the ESCAPED BY character
      are interpreted as part of the current field value.
    
      If the field begins with the ENCLOSED BY
      character, instances of that character are recognized as
      terminating a field value only if followed by the field or line
      TERMINATED BY sequence. To avoid ambiguity,
      occurrences of the ENCLOSED BY character within
      a field value can be doubled and are interpreted as a single
      instance of the character. For example, if ENCLOSED BY
      '"' is specified, quotation marks are handled as shown
      here:
    
"The ""BIG"" boss" -> The "BIG" boss The "BIG" boss -> The "BIG" boss The ""BIG"" boss -> The ""BIG"" boss
      FIELDS ESCAPED BY controls how to read or write
      special characters:
          For input, if the FIELDS ESCAPED BY
          character is not empty, occurrences of that character are
          stripped and the following character is taken literally as
          part of a field value. Some two-character sequences that are
          exceptions, where the first character is the escape character.
          These sequences are shown in the following table (using
          “\” for the escape character).
          The rules for NULL handling are described
          later in this section.
| Character | Escape Sequence | 
|---|---|
| \0 | An ASCII NUL ( 0x00) character | 
| \b | A backspace character | 
| \n | A newline (linefeed) character | 
| \r | A carriage return character | 
| \t | A tab character. | 
| \Z | ASCII 26 (Control+Z) | 
| \N | NULL | 
          For more information about
          “\”-escape syntax, see
          Section 9.1.1, “String Literals”.
        
          If the FIELDS ESCAPED BY character is
          empty, escape-sequence interpretation does not occur.
        
          For output, if the FIELDS ESCAPED BY
          character is not empty, it is used to prefix the following
          characters on output:
              The FIELDS ESCAPED BY character
            
              The FIELDS [OPTIONALLY] ENCLOSED BY
              character
            
              The first character of the FIELDS TERMINATED
              BY and LINES TERMINATED BY
              values
            
              ASCII 0 (what is actually written
              following the escape character is ASCII
              “0”, not a zero-valued
              byte)
          If the FIELDS ESCAPED BY character is
          empty, no characters are escaped and NULL
          is output as NULL, not
          \N. It is probably not a good idea to
          specify an empty escape character, particularly if field
          values in your data contain any of the characters in the list
          just given.
In certain cases, field- and line-handling options interact:
          If LINES TERMINATED BY is an empty string
          and FIELDS TERMINATED BY is nonempty, lines
          are also terminated with FIELDS TERMINATED
          BY.
        
          If the FIELDS TERMINATED BY and
          FIELDS ENCLOSED BY values are both empty
          (''), a fixed-row (nondelimited) format is
          used. With fixed-row format, no delimiters are used between
          fields (but you can still have a line terminator). Instead,
          column values are read and written using a field width wide
          enough to hold all values in the field. For
          TINYINT,
          SMALLINT,
          MEDIUMINT,
          INT, and
          BIGINT, the field widths are 4,
          6, 8, 11, and 20, respectively, no matter what the declared
          display width is.
        
          LINES TERMINATED BY is still used to
          separate lines. If a line does not contain all fields, the
          rest of the columns are set to their default values. If you do
          not have a line terminator, you should set this to
          ''. In this case, the text file must
          contain all fields for each row.
        
          Fixed-row format also affects handling of
          NULL values, as described later.
Fixed-size format does not work if you are using a multibyte character set.
      Handling of NULL values varies according to the
      FIELDS and LINES options in
      use:
          For the default FIELDS and
          LINES values, NULL is
          written as a field value of \N for output,
          and a field value of \N is read as
          NULL for input (assuming that the
          ESCAPED BY character is
          “\”).
        
          If FIELDS ENCLOSED BY is not empty, a field
          containing the literal word NULL as its
          value is read as a NULL value. This differs
          from the word NULL enclosed within
          FIELDS ENCLOSED BY characters, which is
          read as the string 'NULL'.
        
          If FIELDS ESCAPED BY is empty,
          NULL is written as the word
          NULL.
        
          With fixed-row format (which is used when FIELDS
          TERMINATED BY and FIELDS ENCLOSED
          BY are both empty), NULL is
          written as an empty string. This causes both
          NULL values and empty strings in the table
          to be indistinguishable when written to the file because both
          are written as empty strings. If you need to be able to tell
          the two apart when reading the file back in, you should not
          use fixed-row format.
      An attempt to load NULL into a NOT
      NULL column causes assignment of the implicit default
      value for the column's data type and a warning, or an error in
      strict SQL mode. Implicit default values are discussed in
      Section 11.6, “Data Type Default Values”.
    
      Some cases are not supported by
      LOAD DATA
      INFILE:
          Fixed-size rows (FIELDS TERMINATED BY and
          FIELDS ENCLOSED BY both empty) and
          BLOB or
          TEXT columns.
        
          If you specify one separator that is the same as or a prefix
          of another, LOAD
          DATA INFILE cannot interpret the input properly. For
          example, the following FIELDS clause would
          cause problems:
        
FIELDS TERMINATED BY '"' ENCLOSED BY '"'
          If FIELDS ESCAPED BY is empty, a field
          value that contains an occurrence of FIELDS ENCLOSED
          BY or LINES TERMINATED BY
          followed by the FIELDS TERMINATED BY value
          causes LOAD DATA
          INFILE to stop reading a field or line too early.
          This happens because
          LOAD DATA
          INFILE cannot properly determine where the field or
          line value ends.
      The following example loads all columns of the
      persondata table:
    
LOAD DATA INFILE 'persondata.txt' INTO TABLE persondata;
      By default, when no column list is provided at the end of the
      LOAD DATA
      INFILE statement, input lines are expected to contain a
      field for each table column. If you want to load only some of a
      table's columns, specify a column list:
    
LOAD DATA INFILE 'persondata.txt' INTO TABLE persondata (col1,col2,...);
You must also specify a column list if the order of the fields in the input file differs from the order of the columns in the table. Otherwise, MySQL cannot tell how to match input fields with table columns.
      The column list can contain either column names or user variables.
      With user variables, the SET clause enables you
      to perform transformations on their values before assigning the
      result to columns.
    
      User variables in the SET clause can be used in
      several ways. The following example uses the first input column
      directly for the value of t1.column1, and
      assigns the second input column to a user variable that is
      subjected to a division operation before being used for the value
      of t1.column2:
    
LOAD DATA INFILE 'file.txt' INTO TABLE t1 (column1, @var1) SET column2 = @var1/100;
      The SET clause can be used to supply values not
      derived from the input file. The following statement sets
      column3 to the current date and time:
    
LOAD DATA INFILE 'file.txt' INTO TABLE t1 (column1, column2) SET column3 = CURRENT_TIMESTAMP;
You can also discard an input value by assigning it to a user variable and not assigning the variable to a table column:
LOAD DATA INFILE 'file.txt' INTO TABLE t1 (column1, @dummy, column2, @dummy, column3);
      Use of the column/variable list and SET clause
      is subject to the following restrictions:
          Assignments in the SET clause should have
          only column names on the left hand side of assignment
          operators.
        
          You can use subqueries in the right hand side of
          SET assignments. A subquery that returns a
          value to be assigned to a column may be a scalar subquery
          only. Also, you cannot use a subquery to select from the table
          that is being loaded.
        
          Lines ignored by an IGNORE clause are not
          processed for the column/variable list or
          SET clause.
        
User variables cannot be used when loading data with fixed-row format because user variables do not have a display width.
      When processing an input line, LOAD
      DATA splits it into fields and uses the values according
      to the column/variable list and the SET clause,
      if they are present. Then the resulting row is inserted into the
      table. If there are BEFORE INSERT or
      AFTER INSERT triggers for the table, they are
      activated before or after inserting the row, respectively.
    
If an input line has too many fields, the extra fields are ignored and the number of warnings is incremented.
If an input line has too few fields, the table columns for which input fields are missing are set to their default values. Default value assignment is described in Section 11.6, “Data Type Default Values”.
An empty field value is interpreted different from a missing field:
For string types, the column is set to the empty string.
          For numeric types, the column is set to 0.
        
For date and time types, the column is set to the appropriate “zero” value for the type. See Section 11.3, “Date and Time Types”.
      These are the same values that result if you assign an empty
      string explicitly to a string, numeric, or date or time type
      explicitly in an INSERT or
      UPDATE statement.
    
      Treatment of empty or incorrect field values differs from that
      just described if the SQL mode is set to a restrictive value. For
      example, if
      sql_mode='TRADITIONAL, conversion
      of an empty value or a value such as 'x' for a
      numeric column results in an error, not conversion to 0. (With
      LOCAL, warnings occur rather than errors, even
      with a restrictive sql_mode
      value, because the server has no way to stop transmission of the
      file in the middle of the operation.)
    
      TIMESTAMP columns are set to the
      current date and time only if there is a NULL
      value for the column (that is, \N) and the
      column is not declared to permit NULL values,
      or if the TIMESTAMP column's
      default value is the current timestamp and it is omitted from the
      field list when a field list is specified.
    
      LOAD DATA
      INFILE regards all input as strings, so you cannot use
      numeric values for ENUM or
      SET columns the way you can with
      INSERT statements. All
      ENUM and
      SET values must be specified as
      strings.
    
      BIT values cannot be loaded using
      binary notation (for example, b'011010'). To
      work around this, specify the values as regular integers and use
      the SET clause to convert them so that MySQL
      performs a numeric type conversion and loads them into the
      BIT column properly:
    
shell>cat /tmp/bit_test.txt2 127 shell>mysql testmysql>LOAD DATA INFILE '/tmp/bit_test.txt'->INTO TABLE bit_test (@var1) SET b = CAST(@var1 AS UNSIGNED);Query OK, 2 rows affected (0.00 sec) Records: 2 Deleted: 0 Skipped: 0 Warnings: 0 mysql>SELECT BIN(b+0) FROM bit_test;+----------+ | bin(b+0) | +----------+ | 10 | | 1111111 | +----------+ 2 rows in set (0.00 sec)
      On Unix, if you need LOAD DATA to
      read from a pipe, you can use the following technique (the example
      loads a listing of the / directory into the
      table db1.t1):
    
mkfifo /mysql/data/db1/ls.dat chmod 666 /mysql/data/db1/ls.dat find / -ls > /mysql/data/db1/ls.dat & mysql -e "LOAD DATA INFILE 'ls.dat' INTO TABLE t1" db1
Here you must run the command that generates the data to be loaded and the mysql commands either on separate terminals, or run the data generation process in the background (as shown in the preceding example). If you do not do this, the pipe will block until data is read by the mysql process.
      When the LOAD DATA
      INFILE statement finishes, it returns an information
      string in the following format:
    
Records: 1 Deleted: 0 Skipped: 0 Warnings: 0
      Warnings occur under the same circumstances as when values are
      inserted using the INSERT statement
      (see Section 13.2.5, “INSERT Syntax”), except that
      LOAD DATA
      INFILE also generates warnings when there are too few or
      too many fields in the input row.
    
      You can use SHOW WARNINGS to get a
      list of the first max_error_count
      warnings as information about what went wrong. See
      Section 13.7.5.41, “SHOW WARNINGS Syntax”.
    
      If you are using the C API, you can get information about the
      statement by calling the
      mysql_info() function. See
      Section 23.8.7.35, “mysql_info()”.
LOAD XML [LOW_PRIORITY | CONCURRENT] [LOCAL] INFILE 'file_name' [REPLACE | IGNORE] INTO TABLE [db_name.]tbl_name[PARTITION (partition_name,...)] [CHARACTER SETcharset_name] [ROWS IDENTIFIED BY '<tagname>'] [IGNOREnumber{LINES | ROWS}] [(column_or_user_var,...)] [SETcol_name=expr,...]
      The LOAD XML statement reads data
      from an XML file into a table. The
      file_name must be given as a literal
      string. The tagname in the optional
      ROWS IDENTIFIED BY clause must also be given as
      a literal string, and must be surrounded by angle brackets
      (< and >).
    
      LOAD XML acts as the complement of
      running the mysql client in XML output mode
      (that is, starting the client with the
      --xml option). To write data from a
      table to an XML file, use a command such as the following one from
      the system shell:
    
shell> mysql --xml -e 'SELECT * FROM mytable' > file.xml
      To read the file back into a table, use
      LOAD XML
      INFILE. By default, the <row>
      element is considered to be the equivalent of a database table
      row; this can be changed using the ROWS IDENTIFIED
      BY clause.
    
This statement supports three different XML formats:
Column names as attributes and column values as attribute values:
<rowcolumn1="value1"column2="value2" .../>
Column names as tags and column values as the content of these tags:
<row> <column1>value1</column1> <column2>value2</column2> </row>
          Column names are the name attributes of
          <field> tags, and values are the
          contents of these tags:
        
<row> <field name='column1'>value1</field> <field name='column2'>value2</field> </row>
This is the format used by other MySQL tools, such as mysqldump.
All three formats can be used in the same XML file; the import routine automatically detects the format for each row and interprets it correctly. Tags are matched based on the tag or attribute name and the column name.
      The following clauses work essentially the same way for
      LOAD XML as they do for
      LOAD DATA:
          LOW_PRIORITY or
          CONCURRENT
        
          LOCAL
        
          REPLACE or IGNORE
        
          PARTITION
        
          CHARACTER SET
        
          (
        column_or_user_var,...)
          SET
See Section 13.2.6, “LOAD DATA INFILE Syntax”, for more information about these clauses.
      The IGNORE  or number
      LINESIGNORE
       clause causes the
      first number ROWSnumber rows in the XML file to be
      skipped. It is analogous to the LOAD
      DATA statement's IGNORE ... LINES
      clause.
    
To illustrate how this statement is used, suppose that we have a table created as follows:
USE test;
CREATE TABLE person (
    person_id INT NOT NULL PRIMARY KEY,
    fname VARCHAR(40) NULL,
    lname VARCHAR(40) NULL,
    created TIMESTAMP
);
Suppose further that this table is initially empty.
      Now suppose that we have a simple XML file
      person.xml, whose contents are as shown here:
    
<?xml version="1.0"?> <list> <person person_id="1" fname="Pekka" lname="Nousiainen"/> <person person_id="2" fname="Jonas" lname="Oreland"/> <person person_id="3"><fname>Mikael</fname><lname>Ronström</lname></person> <person person_id="4"><fname>Lars</fname><lname>Thalmann</lname></person> <person><field name="person_id">5</field><field name="fname">Tomas</field> <field name="lname">Ulin</field></person> <person><field name="person_id">6</field><field name="fname">Martin</field> <field name="lname">Sköld</field></person> </list>
Each of the permissible XML formats discussed previously is represented in this example file.
      To import the data in person.xml into the
      person table, you can use this statement:
    
mysql>LOAD XML LOCAL INFILE 'person.xml'->INTO TABLE person->ROWS IDENTIFIED BY '<person>';Query OK, 6 rows affected (0.00 sec) Records: 6 Deleted: 0 Skipped: 0 Warnings: 0
      Here, we assume that person.xml is located in
      the MySQL data directory. If the file cannot be found, the
      following error results:
    
ERROR 2 (HY000): File '/person.xml' not found (Errcode: 2)
      The ROWS IDENTIFIED BY '<person>' clause
      means that each <person> element in the
      XML file is considered equivalent to a row in the table into which
      the data is to be imported. In this case, this is the
      person table in the test
      database.
    
      As can be seen by the response from the server, 6 rows were
      imported into the test.person table. This can
      be verified by a simple SELECT
      statement:
    
mysql> SELECT * FROM person;
+-----------+--------+------------+---------------------+
| person_id | fname  | lname      | created             |
+-----------+--------+------------+---------------------+
|         1 | Pekka  | Nousiainen | 2007-07-13 16:18:47 |
|         2 | Jonas  | Oreland    | 2007-07-13 16:18:47 |
|         3 | Mikael | Ronström   | 2007-07-13 16:18:47 |
|         4 | Lars   | Thalmann   | 2007-07-13 16:18:47 |
|         5 | Tomas  | Ulin       | 2007-07-13 16:18:47 |
|         6 | Martin | Sköld      | 2007-07-13 16:18:47 |
+-----------+--------+------------+---------------------+
6 rows in set (0.00 sec)
      This shows, as stated earlier in this section, that any or all of
      the 3 permitted XML formats may appear in a single file and be
      read in using LOAD XML.
    
The inverse of the above operation—that is, dumping MySQL table data into an XML file—can be accomplished using the mysql client from the system shell, as shown here:
        The --xml option causes the
        mysql client to use XML formatting for its
        output; the -e option causes the client to
        execute the SQL statement immediately following the option.
shell>mysql --xml -e "SELECT * FROM test.person" > person-dump.xmlshell>cat person-dump.xml<?xml version="1.0"?> <resultset statement="SELECT * FROM test.person" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"> <row> <field name="person_id">1</field> <field name="fname">Pekka</field> <field name="lname">Nousiainen</field> <field name="created">2007-07-13 16:18:47</field> </row> <row> <field name="person_id">2</field> <field name="fname">Jonas</field> <field name="lname">Oreland</field> <field name="created">2007-07-13 16:18:47</field> </row> <row> <field name="person_id">3</field> <field name="fname">Mikael</field> <field name="lname">Ronström</field> <field name="created">2007-07-13 16:18:47</field> </row> <row> <field name="person_id">4</field> <field name="fname">Lars</field> <field name="lname">Thalmann</field> <field name="created">2007-07-13 16:18:47</field> </row> <row> <field name="person_id">5</field> <field name="fname">Tomas</field> <field name="lname">Ulin</field> <field name="created">2007-07-13 16:18:47</field> </row> <row> <field name="person_id">6</field> <field name="fname">Martin</field> <field name="lname">Sköld</field> <field name="created">2007-07-13 16:18:47</field> </row> </resultset>
      You can verify that the dump is valid by creating a copy of the
      person and then importing the dump file into
      the new table, like this:
    
mysql>USE test;mysql>CREATE TABLE person2 LIKE person;Query OK, 0 rows affected (0.00 sec) mysql>LOAD XML LOCAL INFILE 'person-dump.xml'->INTO TABLE person2;Query OK, 6 rows affected (0.01 sec) Records: 6 Deleted: 0 Skipped: 0 Warnings: 0 mysql>SELECT * FROM person2;+-----------+--------+------------+---------------------+ | person_id | fname | lname | created | +-----------+--------+------------+---------------------+ | 1 | Pekka | Nousiainen | 2007-07-13 16:18:47 | | 2 | Jonas | Oreland | 2007-07-13 16:18:47 | | 3 | Mikael | Ronström | 2007-07-13 16:18:47 | | 4 | Lars | Thalmann | 2007-07-13 16:18:47 | | 5 | Tomas | Ulin | 2007-07-13 16:18:47 | | 6 | Martin | Sköld | 2007-07-13 16:18:47 | +-----------+--------+------------+---------------------+ 6 rows in set (0.00 sec)
      Using a ROWS IDENTIFIED BY
      '< clause, it
      is possible to import data from the same XML file into database
      tables with different definitions. For this example, suppose that
      you have a file named tagname>'address.xml which
      contains the following XML:
    
<?xml version="1.0"?>
<list>
  <person person_id="1">
    <fname>Robert</fname>
    <lname>Jones</lname>
    <address address_id="1" street="Mill Creek Road" zip="45365" city="Sidney"/>
    <address address_id="2" street="Main Street" zip="28681" city="Taylorsville"/>
  </person>
  <person person_id="2">
    <fname>Mary</fname>
    <lname>Smith</lname>
    <address address_id="3" street="River Road" zip="80239" city="Denver"/>
    <!-- <address address_id="4" street="North Street" zip="37920" city="Knoxville"/> -->
  </person>
</list>
      You can again use the test.person table as
      defined previously in this section, after clearing all the
      existing records from the table and then showing its structure as
      shown here:
    
mysql<TRUNCATE person;Query OK, 0 rows affected (0.04 sec) mysql<SHOW CREATE TABLE person\G*************************** 1. row *************************** Table: person Create Table: CREATE TABLE `person` ( `person_id` int(11) NOT NULL, `fname` varchar(40) DEFAULT NULL, `lname` varchar(40) DEFAULT NULL, `created` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`person_id`) ) ENGINE=MyISAM DEFAULT CHARSET=latin1 1 row in set (0.00 sec)
      Now create an address table in the
      test database using the following
      CREATE TABLE statement:
    
CREATE TABLE address (
    address_id INT NOT NULL PRIMARY KEY,
    person_id INT NULL,
    street VARCHAR(40) NULL,
    zip INT NULL,
    city VARCHAR(40) NULL,
    created TIMESTAMP
);
      To import the data from the XML file into the
      person table, execute the following
      LOAD XML statement, which specifies
      that rows are to be specified by the
      <person> element, as shown here;
    
mysql>LOAD XML LOCAL INFILE 'address.xml'->INTO TABLE person->ROWS IDENTIFIED BY '<person>';Query OK, 2 rows affected (0.00 sec) Records: 2 Deleted: 0 Skipped: 0 Warnings: 0
      You can verify that the records were imported using a
      SELECT statement:
    
mysql> SELECT * FROM person;
+-----------+--------+-------+---------------------+
| person_id | fname  | lname | created             |
+-----------+--------+-------+---------------------+
|         1 | Robert | Jones | 2007-07-24 17:37:06 |
|         2 | Mary   | Smith | 2007-07-24 17:37:06 |
+-----------+--------+-------+---------------------+
2 rows in set (0.00 sec)
      Since the <address> elements in the XML
      file have no corresponding columns in the
      person table, they are skipped.
    
      To import the data from the <address>
      elements into the address table, use the
      LOAD XML statement shown here:
    
mysql>LOAD XML LOCAL INFILE 'address.xml'->INTO TABLE address->ROWS IDENTIFIED BY '<address>';Query OK, 3 rows affected (0.00 sec) Records: 3 Deleted: 0 Skipped: 0 Warnings: 0
      You can see that the data was imported using a
      SELECT statement such as this one:
    
mysql> SELECT * FROM address;
+------------+-----------+-----------------+-------+--------------+---------------------+
| address_id | person_id | street          | zip   | city         | created             |
+------------+-----------+-----------------+-------+--------------+---------------------+
|          1 |         1 | Mill Creek Road | 45365 | Sidney       | 2007-07-24 17:37:37 |
|          2 |         1 | Main Street     | 28681 | Taylorsville | 2007-07-24 17:37:37 |
|          3 |         2 | River Road      | 80239 | Denver       | 2007-07-24 17:37:37 |
+------------+-----------+-----------------+-------+--------------+---------------------+
3 rows in set (0.00 sec)
      The data from the <address> element that
      is enclosed in XML comments is not imported. However, since there
      is a person_id column in the
      address table, the value of the
      person_id attribute from the parent
      <person> element for each
      <address> is
      imported into the address table.
    
Security Considerations. 
        As with the LOAD DATA statement,
        the transfer of the XML file from the client host to the server
        host is initiated by the MySQL server. In theory, a patched
        server could be built that would tell the client program to
        transfer a file of the server's choosing rather than the file
        named by the client in the LOAD
        XML statement. Such a server could access any file on
        the client host to which the client user has read access.
      
      In a Web environment, clients usually connect to MySQL from a Web
      server. A user that can run any command against the MySQL server
      can use LOAD XML
      LOCAL to read any files to which the Web server process
      has read access. In this environment, the client with respect to
      the MySQL server is actually the Web server, not the remote
      program being run by the user who connects to the Web server.
    
      You can disable loading of XML files from clients by starting the
      server with --local-infile=0 or
      --local-infile=OFF. This option
      can also be used when starting the mysql client
      to disable LOAD XML for the
      duration of the client session.
    
      To prevent a client from loading XML files from the server, do not
      grant the FILE privilege to the
      corresponding MySQL user account, or revoke this privilege if the
      client user account already has it.
        Revoking the FILE privilege (or
        not granting it in the first place) keeps the user only from
        executing the LOAD XML
        INFILE statement (as well as the
        LOAD_FILE() function; it does
        not prevent the user from executing
        LOAD XML LOCAL
        INFILE. To disallow this statement, you must start the
        server or the client with --local-infile=OFF.
      
        In other words, the FILE
        privilege affects only whether the client can read files on the
        server; it has no bearing on whether the client can read files
        on the local file system.
      For partitioned tables using storage engines that employ table
      locks, such as MyISAM, LOAD
      XML cannot prune any partition locks. This does not
      apply to tables using storage engines which employ row-level
      locking, such as InnoDB. For more
      information, see
      Section 19.6.4, “Partitioning and Locking”.
REPLACE [LOW_PRIORITY | DELAYED]
    [INTO] tbl_name
    [PARTITION (partition_name,...)] 
    [(col_name,...)]
    {VALUES | VALUE} ({expr | DEFAULT},...),(...),...
Or:
REPLACE [LOW_PRIORITY | DELAYED]
    [INTO] tbl_name
    [PARTITION (partition_name,...)] 
    SET col_name={expr | DEFAULT}, ...
Or:
REPLACE [LOW_PRIORITY | DELAYED]
    [INTO] tbl_name
    [PARTITION (partition_name,...)]  
    [(col_name,...)]
    SELECT ...
      REPLACE works exactly like
      INSERT, except that if an old row
      in the table has the same value as a new row for a
      PRIMARY KEY or a UNIQUE
      index, the old row is deleted before the new row is inserted. See
      Section 13.2.5, “INSERT Syntax”.
    
      REPLACE is a MySQL extension to the
      SQL standard. It either inserts, or deletes
      and inserts. For another MySQL extension to standard
      SQL—that either inserts or
      updates—see
      Section 13.2.5.3, “INSERT ... ON DUPLICATE KEY UPDATE Syntax”.
        REPLACE makes sense only if a
        table has a PRIMARY KEY or
        UNIQUE index. Otherwise, it becomes
        equivalent to INSERT, because
        there is no index to be used to determine whether a new row
        duplicates another.
      Values for all columns are taken from the values specified in the
      REPLACE statement. Any missing
      columns are set to their default values, just as happens for
      INSERT. You cannot refer to values
      from the current row and use them in the new row. If you use an
      assignment such as SET
      , the reference
      to the column name on the right hand side is treated as
      col_name =
      col_name + 1DEFAULT(,
      so the assignment is equivalent to col_name)SET
      .
    col_name =
      DEFAULT(col_name) + 1
      To use REPLACE, you must have both
      the INSERT and
      DELETE privileges for the table.
    
      Beginning with MySQL 5.6.2, REPLACE supports
      explicit partition selection using the
      PARTITION option with a comma-separated list of
      names of partitions, subpartitions, or both. As with
      INSERT, if it is not possible to
      insert the new row into any of these partitions or subpartitions,
      the REPLACE statement fails with the error
      Found a row not matching the given partition
      set. See Section 19.5, “Partition Selection”, for
      more information.
    
      The REPLACE statement returns a
      count to indicate the number of rows affected. This is the sum of
      the rows deleted and inserted. If the count is 1 for a single-row
      REPLACE, a row was inserted and no
      rows were deleted. If the count is greater than 1, one or more old
      rows were deleted before the new row was inserted. It is possible
      for a single row to replace more than one old row if the table
      contains multiple unique indexes and the new row duplicates values
      for different old rows in different unique indexes.
    
      The affected-rows count makes it easy to determine whether
      REPLACE only added a row or whether
      it also replaced any rows: Check whether the count is 1 (added) or
      greater (replaced).
    
      If you are using the C API, the affected-rows count can be
      obtained using the
      mysql_affected_rows() function.
    
Currently, you cannot replace into a table and select from the same table in a subquery.
      MySQL uses the following algorithm for
      REPLACE (and LOAD DATA ...
      REPLACE):
Try to insert the new row into the table
While the insertion fails because a duplicate-key error occurs for a primary key or unique index:
Delete from the table the conflicting row that has the duplicate key value
Try again to insert the new row into the table
      It is possible that in the case of a duplicate-key error, a
      storage engine may perform the REPLACE as an
      update rather than a delete plus insert, but the semantics are the
      same. There are no user-visible effects other than a possible
      difference in how the storage engine increments
      Handler_ status
      variables.
    xxx
      Because the results of REPLACE ... SELECT
      statements depend on the ordering of rows from the
      SELECT and this order cannot always
      be guaranteed, it is possible when logging these statements for
      the master and the slave to diverge. For this reason, in MySQL
      5.6.4 and later, REPLACE ... SELECT statements
      are flagged as unsafe for statement-based replication. With this
      change, such statements produce a warning in the log when using
      the STATEMENT binary logging mode, and are
      logged using the row-based format when using
      MIXED mode. See also
      Section 17.1.2.1, “Advantages and Disadvantages of Statement-Based and Row-Based
        Replication”.
    
      When modifying an existing table that is not partitioned to
      accommodate partitioning, or, when modifying the partitioning of
      an already partitioned table, you may consider altering the
      table's primary key (see
      Section 19.6.1, “Partitioning Keys, Primary Keys, and Unique Keys”).
      You should be aware that, if you do this, the results of
      REPLACE statements may be affected, just as
      they would be if you modified the primary key of a nonpartitioned
      table. Consider the table created by the following
      CREATE TABLE statement:
    
CREATE TABLE test ( id INT UNSIGNED NOT NULL AUTO_INCREMENT, data VARCHAR(64) DEFAULT NULL, ts TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (id) );
When we create this table and run the statements shown in the mysql client, the result is as follows:
mysql>REPLACE INTO test VALUES (1, 'Old', '2014-08-20 18:47:00');Query OK, 1 row affected (0.04 sec) mysql>REPLACE INTO test VALUES (1, 'New', '2014-08-20 18:47:42');Query OK, 2 rows affected (0.04 sec) mysql>SELECT * FROM test;+----+------+---------------------+ | id | data | ts | +----+------+---------------------+ | 1 | New | 2014-08-20 18:47:42 | +----+------+---------------------+ 1 row in set (0.00 sec)
Now we create a second table almost identical to the first, except that the primary key now covers 2 columns, as shown here (emphasized text):
CREATE TABLE test2 (
  id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  data VARCHAR(64) DEFAULT NULL,
  ts TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  PRIMARY KEY (id, ts)
);
      When we run on test2 the same two
      REPLACE statements as we did on the original
      test table, we obtain a different result:
    
mysql>REPLACE INTO test2 VALUES (1, 'Old', '2014-08-20 18:47:00');Query OK, 1 row affected (0.05 sec) mysql>REPLACE INTO test2 VALUES (1, 'New', '2014-08-20 18:47:42');Query OK, 1 row affected (0.06 sec) mysql>SELECT * FROM test2;+----+------+---------------------+ | id | data | ts | +----+------+---------------------+ | 1 | Old | 2014-08-20 18:47:00 | | 1 | New | 2014-08-20 18:47:42 | +----+------+---------------------+ 2 rows in set (0.00 sec)
      This is due to the fact that, when run on
      test2, both the id and
      ts column values must match those of an
      existing row for the row to be replaced; otherwise, a row is
      inserted.
    
      Prior to MySQL 5.6.6, a REPLACE that affected a
      partitioned table using a storage engine such as
      MyISAM that employs table-level locks
      locked all partitions of the table. This was true even for
      REPLACE ... PARTITION statements. (This did not
      and does not occur with storage engines such as
      InnoDB that employ row-level
      locking.) In MySQL 5.6.6 and later, MySQL uses partition lock
      pruning, so that only partitions containing rows matching the
      REPLACE statement's
      WHERE clause are actually locked, as long as
      none of the table's partitioning columns are updated;
      otherwise the entire table is locked. For more information, see
      Section 19.6.4, “Partitioning and Locking”.
SELECT
    [ALL | DISTINCT | DISTINCTROW ]
      [HIGH_PRIORITY]
      [STRAIGHT_JOIN]
      [SQL_SMALL_RESULT] [SQL_BIG_RESULT] [SQL_BUFFER_RESULT]
      [SQL_CACHE | SQL_NO_CACHE] [SQL_CALC_FOUND_ROWS]
    select_expr [, select_expr ...]
    [FROM table_references
      [PARTITION partition_list]
    [WHERE where_condition]
    [GROUP BY {col_name | expr | position}
      [ASC | DESC], ... [WITH ROLLUP]]
    [HAVING where_condition]
    [ORDER BY {col_name | expr | position}
      [ASC | DESC], ...]
    [LIMIT {[offset,] row_count | row_count OFFSET offset}]
    [PROCEDURE procedure_name(argument_list)]
    [INTO OUTFILE 'file_name'
        [CHARACTER SET charset_name]
        export_options
      | INTO DUMPFILE 'file_name'
      | INTO var_name [, var_name]]
    [FOR UPDATE | LOCK IN SHARE MODE]]
      SELECT is used to retrieve rows
      selected from one or more tables, and can include
      UNION statements and subqueries.
      See Section 13.2.9.3, “UNION Syntax”, and Section 13.2.10, “Subquery Syntax”.
    
      The most commonly used clauses of
      SELECT statements are these:
          Each select_expr indicates a column
          that you want to retrieve. There must be at least one
          select_expr.
        
          table_references indicates the
          table or tables from which to retrieve rows. Its syntax is
          described in Section 13.2.9.2, “JOIN Syntax”.
        
          Starting in MySQL 5.6.2, SELECT supports
          explicit partition selection using the
          PARTITION keyword with a list of partitions
          or subpartitions (or both) following the name of the table in
          a table_reference (see
          Section 13.2.9.2, “JOIN Syntax”). In this case, rows are selected only
          from the partitions listed, and any other partitions of the
          table are ignored. For more information and examples, see
          Section 19.5, “Partition Selection”.
        
          In MySQL 5.6.6 and later, SELECT ...
          PARTITION from tables using storage engines such as
          MyISAM that perform table-level
          locks (and thus partition locks) lock only the partitions or
          subpartitions named by the PARTITION
          option.
        
See Section 19.6.4, “Partitioning and Locking”, for more information.
          The WHERE clause, if given, indicates the
          condition or conditions that rows must satisfy to be selected.
          where_condition is an expression
          that evaluates to true for each row to be selected. The
          statement selects all rows if there is no
          WHERE clause.
        
          In the WHERE expression, you can use any of
          the functions and operators that MySQL supports, except for
          aggregate (summary) functions. See
          Section 9.5, “Expression Syntax”, and
          Chapter 12, Functions and Operators.
      SELECT can also be used to retrieve
      rows computed without reference to any table.
    
For example:
mysql> SELECT 1 + 1;
        -> 2
      
      You are permitted to specify DUAL as a dummy
      table name in situations where no tables are referenced:
    
mysql> SELECT 1 + 1 FROM DUAL;
        -> 2
      DUAL is purely for the convenience of people
      who require that all SELECT
      statements should have FROM and possibly other
      clauses. MySQL may ignore the clauses. MySQL does not require
      FROM DUAL if no tables are referenced.
    
      In general, clauses used must be given in exactly the order shown
      in the syntax description. For example, a
      HAVING clause must come after any
      GROUP BY clause and before any ORDER
      BY clause. The exception is that the
      INTO clause can appear either as shown in the
      syntax description or immediately following the
      select_expr list. For more information
      about INTO, see Section 13.2.9.1, “SELECT ... INTO Syntax”.
    
      The list of select_expr terms comprises
      the select list that indicates which columns to retrieve. Terms
      specify a column or expression or can use
      *-shorthand:
          A select list consisting only of a single unqualified
          * can be used as shorthand to select all
          columns from all tables:
        
SELECT * FROM t1 INNER JOIN t2 ...
          tbl_name.*
SELECT t1.*, t2.* FROM t1 INNER JOIN t2 ...
          Use of an unqualified * with other items in
          the select list may produce a parse error. To avoid this
          problem, use a qualified
          tbl_name.*
SELECT AVG(score), t1.* FROM t1 ...
      The following list provides additional information about other
      SELECT clauses:
          
          
          A select_expr can be given an alias
          using AS
          . The alias is
          used as the expression's column name and can be used in
          alias_nameGROUP BY, ORDER BY, or
          HAVING clauses. For example:
        
SELECT CONCAT(last_name,', ',first_name) AS full_name FROM mytable ORDER BY full_name;
          The AS keyword is optional when aliasing a
          select_expr with an identifier. The
          preceding example could have been written like this:
        
SELECT CONCAT(last_name,', ',first_name) full_name FROM mytable ORDER BY full_name;
          However, because the AS is optional, a
          subtle problem can occur if you forget the comma between two
          select_expr expressions: MySQL
          interprets the second as an alias name. For example, in the
          following statement, columnb is treated as
          an alias name:
        
SELECT columna columnb FROM mytable;
          For this reason, it is good practice to be in the habit of
          using AS explicitly when specifying column
          aliases.
        
          It is not permissible to refer to a column alias in a
          WHERE clause, because the column value
          might not yet be determined when the WHERE
          clause is executed. See Section B.5.5.4, “Problems with Column Aliases”.
        
          
          
          The FROM
           clause
          indicates the table or tables from which to retrieve rows. If
          you name more than one table, you are performing a join. For
          information on join syntax, see Section 13.2.9.2, “JOIN Syntax”. For
          each table specified, you can optionally specify an alias.
        table_references
tbl_name[[AS]alias] [index_hint]
The use of index hints provides the optimizer with information about how to choose indexes during query processing. For a description of the syntax for specifying these hints, see Section 8.9.3, “Index Hints”.
          You can use SET
          max_seeks_for_key=
          as an alternative way to force MySQL to prefer key scans
          instead of table scans. See
          Section 5.1.4, “Server System Variables”.
        value
          You can refer to a table within the default database as
          tbl_name, or as
          db_name.tbl_name
          to specify a database explicitly. You can refer to a column as
          col_name,
          tbl_name.col_name,
          or
          db_name.tbl_name.col_name.
          You need not specify a tbl_name or
          db_name.tbl_name
          prefix for a column reference unless the reference would be
          ambiguous. See Section 9.2.1, “Identifier Qualifiers”, for
          examples of ambiguity that require the more explicit column
          reference forms.
        
          
          
          A table reference can be aliased using
          tbl_name AS
          alias_nametbl_name alias_name:
        
SELECT t1.name, t2.salary FROM employee AS t1, info AS t2 WHERE t1.name = t2.name; SELECT t1.name, t2.salary FROM employee t1, info t2 WHERE t1.name = t2.name;
          
          Columns selected for output can be referred to in
          ORDER BY and GROUP BY
          clauses using column names, column aliases, or column
          positions. Column positions are integers and begin with 1:
        
SELECT college, region, seed FROM tournament ORDER BY region, seed; SELECT college, region AS r, seed AS s FROM tournament ORDER BY r, s; SELECT college, region, seed FROM tournament ORDER BY 2, 3;
          To sort in reverse order, add the DESC
          (descending) keyword to the name of the column in the
          ORDER BY clause that you are sorting by.
          The default is ascending order; this can be specified
          explicitly using the ASC keyword.
        
          If ORDER BY occurs within a subquery and
          also is applied in the outer query, the outermost
          ORDER BY takes precedence. For example,
          results for the following statement are sorted in descending
          order, not ascending order:
        
(SELECT ... ORDER BY a) ORDER BY a DESC;
Use of column positions is deprecated because the syntax has been removed from the SQL standard.
          
          
          If you use GROUP BY, output rows are sorted
          according to the GROUP BY columns as if you
          had an ORDER BY for the same columns. To
          avoid the overhead of sorting that GROUP BY
          produces, add ORDER BY NULL:
        
SELECT a, COUNT(b) FROM test_table GROUP BY a ORDER BY NULL;
          Relying on implicit GROUP BY sorting in
          MySQL 5.6 is deprecated. To achieve a specific
          sort order of grouped results, it is preferable to use an
          explicit ORDER BY clause. GROUP
          BY sorting is a MySQL extension that may change in a
          future release; for example, to make it possible for the
          optimizer to order groupings in whatever manner it deems most
          efficient and to avoid the sorting overhead.
        
          
          MySQL extends the GROUP BY clause so that
          you can also specify ASC and
          DESC after columns named in the clause:
        
SELECT a, COUNT(b) FROM test_table GROUP BY a DESC;
          MySQL extends the use of GROUP BY to permit
          selecting fields that are not mentioned in the GROUP
          BY clause. If you are not getting the results that
          you expect from your query, please read the description of
          GROUP BY found in
          Section 12.19, “Functions and Modifiers for Use with GROUP BY Clauses”.
        
          GROUP BY permits a WITH
          ROLLUP modifier. See
          Section 12.19.2, “GROUP BY Modifiers”.
        
          
          The HAVING clause is applied nearly last,
          just before items are sent to the client, with no
          optimization. (LIMIT is applied after
          HAVING.)
        
          The SQL standard requires that HAVING must
          reference only columns in the GROUP BY
          clause or columns used in aggregate functions. However, MySQL
          supports an extension to this behavior, and permits
          HAVING to refer to columns in the
          SELECT list and columns in
          outer subqueries as well.
        
          If the HAVING clause refers to a column
          that is ambiguous, a warning occurs. In the following
          statement, col2 is ambiguous because it is
          used as both an alias and a column name:
        
SELECT COUNT(col1) AS col2 FROM t GROUP BY col2 HAVING col2 = 2;
          Preference is given to standard SQL behavior, so if a
          HAVING column name is used both in
          GROUP BY and as an aliased column in the
          output column list, preference is given to the column in the
          GROUP BY column.
        
          Do not use HAVING for items that should be
          in the WHERE clause. For example, do not
          write the following:
        
SELECTcol_nameFROMtbl_nameHAVINGcol_name> 0;
Write this instead:
SELECTcol_nameFROMtbl_nameWHEREcol_name> 0;
          The HAVING clause can refer to aggregate
          functions, which the WHERE clause cannot:
        
SELECT user, MAX(salary) FROM users GROUP BY user HAVING MAX(salary) > 10;
(This did not work in some older versions of MySQL.)
          MySQL permits duplicate column names. That is, there can be
          more than one select_expr with the
          same name. This is an extension to standard SQL. Because MySQL
          also permits GROUP BY and
          HAVING to refer to
          select_expr values, this can result
          in an ambiguity:
        
SELECT 12 AS a, a FROM t GROUP BY a;
          In that statement, both columns have the name
          a. To ensure that the correct column is
          used for grouping, use different names for each
          select_expr.
        
          MySQL resolves unqualified column or alias references in
          ORDER BY clauses by searching in the
          select_expr values, then in the
          columns of the tables in the FROM clause.
          For GROUP BY or HAVING
          clauses, it searches the FROM clause before
          searching in the select_expr
          values. (For GROUP BY and
          HAVING, this differs from the pre-MySQL 5.0
          behavior that used the same rules as for ORDER
          BY.)
        
          
          The LIMIT clause can be used to constrain
          the number of rows returned by the
          SELECT statement.
          LIMIT takes one or two numeric arguments,
          which must both be nonnegative integer constants, with these
          exceptions:
              Within prepared statements, LIMIT
              parameters can be specified using ?
              placeholder markers.
            
              Within stored programs, LIMIT
              parameters can be specified using integer-valued routine
              parameters or local variables.
With two arguments, the first argument specifies the offset of the first row to return, and the second specifies the maximum number of rows to return. The offset of the initial row is 0 (not 1):
SELECT * FROM tbl LIMIT 5,10; # Retrieve rows 6-15
To retrieve all rows from a certain offset up to the end of the result set, you can use some large number for the second parameter. This statement retrieves all rows from the 96th row to the last:
SELECT * FROM tbl LIMIT 95,18446744073709551615;
With one argument, the value specifies the number of rows to return from the beginning of the result set:
SELECT * FROM tbl LIMIT 5; # Retrieve first 5 rows
          In other words, LIMIT
           is equivalent
          to row_countLIMIT 0,
          .
        row_count
          For prepared statements, you can use placeholders. The
          following statements will return one row from the
          tbl table:
        
SET @a=1; PREPARE STMT FROM 'SELECT * FROM tbl LIMIT ?'; EXECUTE STMT USING @a;
          The following statements will return the second to sixth row
          from the tbl table:
        
SET @skip=1; SET @numrows=5; PREPARE STMT FROM 'SELECT * FROM tbl LIMIT ?, ?'; EXECUTE STMT USING @skip, @numrows;
          For compatibility with PostgreSQL, MySQL also supports the
          LIMIT  syntax.
        row_count OFFSET
          offset
          If LIMIT occurs within a subquery and also
          is applied in the outer query, the outermost
          LIMIT takes precedence. For example, the
          following statement produces two rows, not one:
        
(SELECT ... LIMIT 1) LIMIT 2;
          
          A PROCEDURE clause names a procedure that
          should process the data in the result set. For an example, see
          Section 8.4.2.4, “Using PROCEDURE ANALYSE”, which describes
          ANALYSE, a procedure that can be used to
          obtain suggestions for optimal column data types that may help
          reduce table sizes.
        
          The SELECT ...
          INTO form of SELECT
          enables the query result to be written to a file or stored in
          variables. For more information, see
          Section 13.2.9.1, “SELECT ... INTO Syntax”.
        
          
          
          If you use FOR UPDATE with a storage engine
          that uses page or row locks, rows examined by the query are
          write-locked until the end of the current transaction. Using
          LOCK IN SHARE MODE sets a shared lock that
          permits other transactions to read the examined rows but not
          to update or delete them. See
          Section 14.2.2.3, “Locking Reads (SELECT ... FOR UPDATE and SELECT ... LOCK IN SHARE MODE)”.
        
          In addition, you cannot use FOR UPDATE as
          part of the SELECT in a
          statement such as
          CREATE
          TABLE . (If you
          attempt to do so, the statement is rejected with the error
          Can't update table
          'new_table SELECT ... FROM
          old_table ...old_table' while
          'new_table' is being
          created.) This is a change in behavior from MySQL
          5.5 and earlier, which permitted
          CREATE
          TABLE ... SELECT statements to make changes in
          tables other than the table being created.
      Following the SELECT keyword, you
      can use a number of options that affect the operation of the
      statement. HIGH_PRIORITY,
      STRAIGHT_JOIN, and options beginning with
      SQL_ are MySQL extensions to standard SQL.
          
          
          
          The ALL and DISTINCT
          options specify whether duplicate rows should be returned.
          ALL (the default) specifies that all
          matching rows should be returned, including duplicates.
          DISTINCT specifies removal of duplicate
          rows from the result set. It is an error to specify both
          options. DISTINCTROW is a synonym for
          DISTINCT.
        
          
          HIGH_PRIORITY gives the
          SELECT higher priority than a
          statement that updates a table. You should use this only for
          queries that are very fast and must be done at once. A
          SELECT HIGH_PRIORITY query that is issued
          while the table is locked for reading runs even if there is an
          update statement waiting for the table to be free. This
          affects only storage engines that use only table-level locking
          (such as MyISAM, MEMORY,
          and MERGE).
        
          HIGH_PRIORITY cannot be used with
          SELECT statements that are part
          of a UNION.
        
          
          STRAIGHT_JOIN forces the optimizer to join
          the tables in the order in which they are listed in the
          FROM clause. You can use this to speed up a
          query if the optimizer joins the tables in nonoptimal order.
          STRAIGHT_JOIN also can be used in the
          table_references list. See
          Section 13.2.9.2, “JOIN Syntax”.
        
          
          
          STRAIGHT_JOIN does not apply to any table
          that the optimizer treats as a
          const or
          system table. Such a table
          produces a single row, is read during the optimization phase
          of query execution, and references to its columns are replaced
          with the appropriate column values before query execution
          proceeds. These tables will appear first in the query plan
          displayed by EXPLAIN. See
          Section 8.8.1, “Optimizing Queries with EXPLAIN”. This exception may not apply
          to const or
          system tables that are used
          on the NULL-complemented side of an outer
          join (that is, the right-side table of a LEFT
          JOIN or the left-side table of a RIGHT
          JOIN.
        
          
          
          SQL_BIG_RESULT or
          SQL_SMALL_RESULT can be used with
          GROUP BY or DISTINCT to
          tell the optimizer that the result set has many rows or is
          small, respectively. For SQL_BIG_RESULT,
          MySQL directly uses disk-based temporary tables if needed, and
          prefers sorting to using a temporary table with a key on the
          GROUP BY elements. For
          SQL_SMALL_RESULT, MySQL uses fast temporary
          tables to store the resulting table instead of using sorting.
          This should not normally be needed.
        
          
          SQL_BUFFER_RESULT forces the result to be
          put into a temporary table. This helps MySQL free the table
          locks early and helps in cases where it takes a long time to
          send the result set to the client. This option can be used
          only for top-level SELECT
          statements, not for subqueries or following
          UNION.
        
          
          SQL_CALC_FOUND_ROWS tells MySQL to
          calculate how many rows there would be in the result set,
          disregarding any LIMIT clause. The number
          of rows can then be retrieved with SELECT
          FOUND_ROWS(). See
          Section 12.14, “Information Functions”.
        
          
          
          The SQL_CACHE and
          SQL_NO_CACHE options affect caching of
          query results in the query cache (see
          Section 8.10.3, “The MySQL Query Cache”). SQL_CACHE
          tells MySQL to store the result in the query cache if it is
          cacheable and the value of the
          query_cache_type system
          variable is 2 or DEMAND.
          With SQL_NO_CACHE, the server does not use
          the query cache. It neither checks the query cache to see
          whether the result is already cached, nor does it cache the
          query result. (Due to a limitation in the parser, a space
          character must precede and follow the
          SQL_NO_CACHE keyword; a nonspace such as a
          newline causes the server to check the query cache to see
          whether the result is already cached.)
        
          For views, SQL_NO_CACHE applies if it
          appears in any SELECT in the
          query. For a cacheable query, SQL_CACHE
          applies if it appears in the first
          SELECT of a view referred to by
          the query.
        
          In MySQL 5.6, these two options are mutually
          exclusive and an error occurs if they are both specified.
          Also, these options are not permitted in subqueries (including
          subqueries in the FROM clause), and
          SELECT statements in unions
          other than the first SELECT.
      Prior to MySQL 5.6.6, a SELECT from a
      partitioned table using a storage engine such as
      MyISAM that employs table-level locks
      locked all partitions of the table. This was true even for
      SELECT ... PARTITION queries. (This did not and
      does not occur with storage engines such as
      InnoDB that employ row-level
      locking.) In MySQL 5.6.6 and later, MySQL uses partition lock
      pruning, so that only partitions containing rows matching the
      SELECT statement's
      WHERE clause are actually locked. For more
      information, see
      Section 19.6.4, “Partitioning and Locking”.
        The SELECT ...
        INTO form of SELECT
        enables a query result to be stored in variables or written to a
        file:
            SELECT ... INTO
             selects column
            values and stores them into variables.
          var_list
            SELECT ... INTO OUTFILE writes the
            selected rows to a file. Column and line terminators can be
            specified to produce a specific output format.
          
            SELECT ... INTO DUMPFILE writes a single
            row to a file without any formatting.
        The SELECT syntax description
        (see Section 13.2.9, “SELECT Syntax”) shows the INTO
        clause near the end of the statement. It is also possible to use
        INTO immediately following the
        select_expr list.
      
        An INTO clause should not be used in a nested
        SELECT because such a
        SELECT must return its result to
        the outer context.
      
        The INTO clause can name a list of one or
        more variables, which can be user-defined variables, stored
        procedure or function parameters, or stored program local
        variables. (Within a prepared SELECT ... INTO
        OUTFILE statement, only user-defined variables are
        permitted;see Section 13.6.4.2, “Local Variable Scope and Resolution”.)
      
        The selected values are assigned to the variables. The number of
        variables must match the number of columns. The query should
        return a single row. If the query returns no rows, a warning
        with error code 1329 occurs (No data), and
        the variable values remain unchanged. If the query returns
        multiple rows, error 1172 occurs (Result consisted of
        more than one row). If it is possible that the
        statement may retrieve multiple rows, you can use LIMIT
        1 to limit the result set to a single row.
      
SELECT id, data INTO @x, @y FROM test.t1 LIMIT 1;
User variable names are not case sensitive. See Section 9.4, “User-Defined Variables”.
        The SELECT ... INTO
        OUTFILE ' form of
        file_name'SELECT writes the selected rows
        to a file. The file is created on the server host, so you must
        have the FILE privilege to use
        this syntax. file_name cannot be an
        existing file, which among other things prevents files such as
        /etc/passwd and database tables from being
        destroyed. The
        character_set_filesystem system
        variable controls the interpretation of the file name.
      
        The SELECT ... INTO
        OUTFILE statement is intended primarily to let you
        very quickly dump a table to a text file on the server machine.
        If you want to create the resulting file on some other host than
        the server host, you normally cannot use
        SELECT ... INTO
        OUTFILE since there is no way to write a path to the
        file relative to the server host's file system.
      
        However, if the MySQL client software is installed on the remote
        machine, you can instead use a client command such as
        mysql -e "SELECT ..." >
         to generate the
        file on the client host.
      file_name
It is also possible to create the resulting file on a different host other than the server host, if the location of the file on the remote host can be accessed using a network-mapped path on the server's file system. In this case, the presence of mysql (or some other MySQL client program) is not required on the target host.
        SELECT ... INTO
        OUTFILE is the complement of
        LOAD DATA
        INFILE. Column values are written converted to the
        character set specified in the CHARACTER SET
        clause. If no such clause is present, values are dumped using
        the binary character set. In effect, there is
        no character set conversion. If a result set contains columns in
        several character sets, the output data file will as well and
        you may not be able to reload the file correctly.
      
        The syntax for the export_options
        part of the statement consists of the same
        FIELDS and LINES clauses
        that are used with the
        LOAD DATA
        INFILE statement. See Section 13.2.6, “LOAD DATA INFILE Syntax”, for
        information about the FIELDS and
        LINES clauses, including their default values
        and permissible values.
      
        FIELDS ESCAPED BY controls how to write
        special characters. If the FIELDS ESCAPED BY
        character is not empty, it is used when necessary to avoid
        ambiguity as a prefix that precedes following characters on
        output:
            The FIELDS ESCAPED BY character
          
            The FIELDS [OPTIONALLY] ENCLOSED BY
            character
          
            The first character of the FIELDS TERMINATED
            BY and LINES TERMINATED BY
            values
          
            ASCII NUL (the zero-valued byte; what is
            actually written following the escape character is ASCII
            “0”, not a zero-valued byte)
        The FIELDS TERMINATED BY, ENCLOSED
        BY, ESCAPED BY, or LINES
        TERMINATED BY characters must be
        escaped so that you can read the file back in reliably. ASCII
        NUL is escaped to make it easier to view with
        some pagers.
      
The resulting file does not have to conform to SQL syntax, so nothing else need be escaped.
        If the FIELDS ESCAPED BY character is empty,
        no characters are escaped and NULL is output
        as NULL, not \N. It is
        probably not a good idea to specify an empty escape character,
        particularly if field values in your data contain any of the
        characters in the list just given.
      
Here is an example that produces a file in the comma-separated values (CSV) format used by many programs:
SELECT a,b,a+b INTO OUTFILE '/tmp/result.txt' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"' LINES TERMINATED BY '\n' FROM test_table;
        If you use INTO DUMPFILE instead of
        INTO OUTFILE, MySQL writes only one row into
        the file, without any column or line termination and without
        performing any escape processing. This is useful if you want to
        store a BLOB value in a file.
          Any file created by INTO OUTFILE or
          INTO DUMPFILE is writable by all users on
          the server host. The reason for this is that the MySQL server
          cannot create a file that is owned by anyone other than the
          user under whose account it is running. (You should
          never run mysqld as
          root for this and other reasons.) The file
          thus must be world-writable so that you can manipulate its
          contents.
        
          If the secure_file_priv
          system variable is set to a nonempty directory name, the file
          to be written must be located in that directory.
        In the context of
        SELECT ...
        INTO statements that occur as part of events executed
        by the Event Scheduler, diagnostics messages (not only errors,
        but also warnings) are written to the error log, and, on
        Windows, to the application event log. For additional
        information, see Section 20.4.5, “Event Scheduler Status”.
        MySQL supports the following JOIN syntaxes
        for the table_references part of
        SELECT statements and
        multiple-table DELETE and
        UPDATE statements:
      
table_references:escaped_table_reference[,escaped_table_reference] ...escaped_table_reference:table_reference| { OJtable_reference}table_reference:table_factor|join_tabletable_factor:tbl_name[PARTITION (partition_names)] [[AS]alias] [index_hint_list] |table_subquery[AS]alias| (table_references)join_table:table_reference[INNER | CROSS] JOINtable_factor[join_condition] |table_referenceSTRAIGHT_JOINtable_factor|table_referenceSTRAIGHT_JOINtable_factorONconditional_expr|table_reference{LEFT|RIGHT} [OUTER] JOINtable_referencejoin_condition|table_referenceNATURAL [{LEFT|RIGHT} [OUTER]] JOINtable_factorjoin_condition: ONconditional_expr| USING (column_list)index_hint_list:index_hint[,index_hint] ...index_hint: USE {INDEX|KEY} [FOR {JOIN|ORDER BY|GROUP BY}] ([index_list]) | IGNORE {INDEX|KEY} [FOR {JOIN|ORDER BY|GROUP BY}] (index_list) | FORCE {INDEX|KEY} [FOR {JOIN|ORDER BY|GROUP BY}] (index_list)index_list:index_name[,index_name] ...
A table reference is also known as a join expression.
        In MySQL 5.6.2 and later, a table reference (when it refers to a
        partitioned table) may contain a PARTITION
        option, including a comma-separated list of partitions,
        subpartitions, or both. This option follows the name of the
        table and precedes any alias declaration. The effect of this
        option is that rows are selected only from the listed partitions
        or subpartitions—in other words, any partitions or
        subpartitions not named in the list are ignored For more
        information, see Section 19.5, “Partition Selection”.
      
        The syntax of table_factor is
        extended in comparison with the SQL Standard. The latter accepts
        only table_reference, not a list of
        them inside a pair of parentheses.
      
        This is a conservative extension if we consider each comma in a
        list of table_reference items as
        equivalent to an inner join. For example:
      
SELECT * FROM t1 LEFT JOIN (t2, t3, t4)
                 ON (t2.a=t1.a AND t3.b=t1.b AND t4.c=t1.c)
is equivalent to:
SELECT * FROM t1 LEFT JOIN (t2 CROSS JOIN t3 CROSS JOIN t4)
                 ON (t2.a=t1.a AND t3.b=t1.b AND t4.c=t1.c)
        In MySQL, JOIN, CROSS
        JOIN, and INNER JOIN are syntactic
        equivalents (they can replace each other). In standard SQL, they
        are not equivalent. INNER JOIN is used with
        an ON clause, CROSS JOIN
        is used otherwise.
      
In general, parentheses can be ignored in join expressions containing only inner join operations. MySQL also supports nested joins (see Section 8.2.1.11, “Nested Join Optimization”).
Index hints can be specified to affect how the MySQL optimizer makes use of indexes. For more information, see Section 8.9.3, “Index Hints”.
The following list describes general factors to take into account when writing joins.
            A table reference can be aliased using
            tbl_name AS
            alias_nametbl_name alias_name:
          
SELECT t1.name, t2.salary FROM employee AS t1 INNER JOIN info AS t2 ON t1.name = t2.name; SELECT t1.name, t2.salary FROM employee t1 INNER JOIN info t2 ON t1.name = t2.name;
            A table_subquery is also known as
            a subquery in the FROM clause. Such
            subqueries must include an alias to
            give the subquery result a table name. A trivial example
            follows; see also Section 13.2.10.8, “Subqueries in the FROM Clause”.
          
SELECT * FROM (SELECT 1, 2, 3) AS t1;
            INNER JOIN and ,
            (comma) are semantically equivalent in the absence of a join
            condition: both produce a Cartesian product between the
            specified tables (that is, each and every row in the first
            table is joined to each and every row in the second table).
          
            However, the precedence of the comma operator is less than
            of INNER JOIN, CROSS
            JOIN, LEFT JOIN, and so on. If
            you mix comma joins with the other join types when there is
            a join condition, an error of the form Unknown
            column ' may occur. Information about dealing with
            this problem is given later in this section.
          col_name' in 'on
            clause'
            The conditional_expr used with
            ON is any conditional expression of the
            form that can be used in a WHERE clause.
            Generally, you should use the ON clause
            for conditions that specify how to join tables, and the
            WHERE clause to restrict which rows you
            want in the result set.
          
            If there is no matching row for the right table in the
            ON or USING part in a
            LEFT JOIN, a row with all columns set to
            NULL is used for the right table. You can
            use this fact to find rows in a table that have no
            counterpart in another table:
          
SELECT left_tbl.* FROM left_tbl LEFT JOIN right_tbl ON left_tbl.id = right_tbl.id WHERE right_tbl.id IS NULL;
            This example finds all rows in left_tbl
            with an id value that is not present in
            right_tbl (that is, all rows in
            left_tbl with no corresponding row in
            right_tbl). This assumes that
            right_tbl.id is declared NOT
            NULL. See
            Section 8.2.1.9, “LEFT JOIN and RIGHT JOIN Optimization”.
          
            The
            USING(
            clause names a list of columns that must exist in both
            tables. If tables column_list)a and
            b both contain columns
            c1, c2, and
            c3, the following join compares
            corresponding columns from the two tables:
          
a LEFT JOIN b USING (c1,c2,c3)
            The NATURAL [LEFT] JOIN of two tables is
            defined to be semantically equivalent to an INNER
            JOIN or a LEFT JOIN with a
            USING clause that names all columns that
            exist in both tables.
          
            RIGHT JOIN works analogously to
            LEFT JOIN. To keep code portable across
            databases, it is recommended that you use LEFT
            JOIN instead of RIGHT JOIN.
          
            
            
            The { OJ ... } syntax shown in the join
            syntax description exists only for compatibility with ODBC.
            The curly braces in the syntax should be written literally;
            they are not metasyntax as used elsewhere in syntax
            descriptions.
          
SELECT left_tbl.*
    FROM { OJ left_tbl LEFT OUTER JOIN right_tbl ON left_tbl.id = right_tbl.id }
    WHERE right_tbl.id IS NULL;
            You can use other types of joins within { OJ ...
            }, such as INNER JOIN or
            RIGHT OUTER JOIN. This helps with
            compatibility with some third-party applications, but is not
            official ODBC syntax.
          
            STRAIGHT_JOIN is similar to
            JOIN, except that the left table is
            always read before the right table. This can be used for
            those (few) cases for which the join optimizer puts the
            tables in the wrong order.
Some join examples:
SELECT * FROM table1, table2; SELECT * FROM table1 INNER JOIN table2 ON table1.id=table2.id; SELECT * FROM table1 LEFT JOIN table2 ON table1.id=table2.id; SELECT * FROM table1 LEFT JOIN table2 USING (id); SELECT * FROM table1 LEFT JOIN table2 ON table1.id=table2.id LEFT JOIN table3 ON table2.id=table3.id;
Join Processing Changes in MySQL 5.0.12
          Natural joins and joins with USING,
          including outer join variants, are processed according to the
          SQL:2003 standard. The goal was to align the syntax and
          semantics of MySQL with respect to NATURAL
          JOIN and JOIN ... USING according
          to SQL:2003. However, these changes in join processing can
          result in different output columns for some joins. Also, some
          queries that appeared to work correctly in older versions
          (prior to 5.0.12) must be rewritten to comply with the
          standard.
These changes have five main aspects:
            The way that MySQL determines the result columns of
            NATURAL or USING join
            operations (and thus the result of the entire
            FROM clause).
          
            Expansion of SELECT * and SELECT
             into a list
            of selected columns.
          tbl_name.*
            Resolution of column names in NATURAL or
            USING joins.
          
            Transformation of NATURAL or
            USING joins into JOIN ...
            ON.
          
            Resolution of column names in the ON
            condition of a JOIN ... ON.
The following list provides more detail about several effects of current join processing versus join processing in older versions. The term “previously” means “prior to MySQL 5.0.12.”
            The columns of a NATURAL join or a
            USING join may be different from
            previously. Specifically, redundant output columns no longer
            appear, and the order of columns for SELECT
            * expansion may be different from before.
          
Consider this set of statements:
CREATE TABLE t1 (i INT, j INT); CREATE TABLE t2 (k INT, j INT); INSERT INTO t1 VALUES(1,1); INSERT INTO t2 VALUES(1,1); SELECT * FROM t1 NATURAL JOIN t2; SELECT * FROM t1 JOIN t2 USING (j);
Previously, the statements produced this output:
+------+------+------+------+ | i | j | k | j | +------+------+------+------+ | 1 | 1 | 1 | 1 | +------+------+------+------+ +------+------+------+------+ | i | j | k | j | +------+------+------+------+ | 1 | 1 | 1 | 1 | +------+------+------+------+
            In the first SELECT
            statement, column j appears in both
            tables and thus becomes a join column, so, according to
            standard SQL, it should appear only once in the output, not
            twice. Similarly, in the second SELECT statement, column
            j is named in the
            USING clause and should appear only once
            in the output, not twice. But in both cases, the redundant
            column is not eliminated. Also, the order of the columns is
            not correct according to standard SQL.
          
Now the statements produce this output:
+------+------+------+ | j | i | k | +------+------+------+ | 1 | 1 | 1 | +------+------+------+ +------+------+------+ | j | i | k | +------+------+------+ | 1 | 1 | 1 | +------+------+------+
The redundant column is eliminated and the column order is correct according to standard SQL:
First, coalesced common columns of the two joined tables, in the order in which they occur in the first table
Second, columns unique to the first table, in order in which they occur in that table
Third, columns unique to the second table, in order in which they occur in that table
            The single result column that replaces two common columns is
            defined using the coalesce operation. That is, for two
            t1.a and t2.a the
            resulting single join column a is defined
            as a = COALESCE(t1.a, t2.a), where:
          
COALESCE(x, y) = (CASE WHEN V1 IS NOT NULL THEN V1 ELSE V2 END)
If the join operation is any other join, the result columns of the join consists of the concatenation of all columns of the joined tables. This is the same as previously.
            A consequence of the definition of coalesced columns is
            that, for outer joins, the coalesced column contains the
            value of the non-NULL column if one of
            the two columns is always NULL. If
            neither or both columns are NULL, both
            common columns have the same value, so it doesn't matter
            which one is chosen as the value of the coalesced column. A
            simple way to interpret this is to consider that a coalesced
            column of an outer join is represented by the common column
            of the inner table of a JOIN. Suppose
            that the tables t1(a,b) and
            t2(a,c) have the following contents:
          
t1 t2 ---- ---- 1 x 2 z 2 y 3 w
Then:
mysql> SELECT * FROM t1 NATURAL LEFT JOIN t2;
+------+------+------+
| a    | b    | c    |
+------+------+------+
|    1 | x    | NULL |
|    2 | y    | z    |
+------+------+------+
            Here column a contains the values of
            t1.a.
          
mysql> SELECT * FROM t1 NATURAL RIGHT JOIN t2;
+------+------+------+
| a    | c    | b    |
+------+------+------+
|    2 | z    | y    |
|    3 | w    | NULL |
+------+------+------+
            Here column a contains the values of
            t2.a.
          
            Compare these results to the otherwise equivalent queries
            with JOIN ... ON:
          
mysql> SELECT * FROM t1 LEFT JOIN t2 ON (t1.a = t2.a);
+------+------+------+------+
| a    | b    | a    | c    |
+------+------+------+------+
|    1 | x    | NULL | NULL |
|    2 | y    |    2 | z    |
+------+------+------+------+
mysql> SELECT * FROM t1 RIGHT JOIN t2 ON (t1.a = t2.a);
+------+------+------+------+
| a    | b    | a    | c    |
+------+------+------+------+
|    2 | y    |    2 | z    |
| NULL | NULL |    3 | w    |
+------+------+------+------+
            Previously, a USING clause could be
            rewritten as an ON clause that compares
            corresponding columns. For example, the following two
            clauses were semantically identical:
          
a LEFT JOIN b USING (c1,c2,c3) a LEFT JOIN b ON a.c1=b.c1 AND a.c2=b.c2 AND a.c3=b.c3
Now the two clauses no longer are quite the same:
With respect to determining which rows satisfy the join condition, both joins remain semantically identical.
                With respect to determining which columns to display for
                SELECT * expansion, the two joins are
                not semantically identical. The USING
                join selects the coalesced value of corresponding
                columns, whereas the ON join selects
                all columns from all tables. For the preceding
                USING join, SELECT
                * selects these values:
              
COALESCE(a.c1,b.c1), COALESCE(a.c2,b.c2), COALESCE(a.c3,b.c3)
                For the ON join, SELECT
                * selects these values:
              
a.c1, a.c2, a.c3, b.c1, b.c2, b.c3
                With an inner join,
                COALESCE(a.c1,b.c1) is
                the same as either a.c1 or
                b.c1 because both columns will have
                the same value. With an outer join (such as
                LEFT JOIN), one of the two columns
                can be NULL. That column will be
                omitted from the result.
            The evaluation of multi-way natural joins differs in a very
            important way that affects the result of
            NATURAL or USING joins
            and that can require query rewriting. Suppose that you have
            three tables t1(a,b),
            t2(c,b), and t3(a,c)
            that each have one row: t1(1,2),
            t2(10,2), and
            t3(7,10). Suppose also that you have this
            NATURAL JOIN on the three tables:
          
SELECT ... FROM t1 NATURAL JOIN t2 NATURAL JOIN t3;
            Previously, the left operand of the second join was
            considered to be t2, whereas it should be
            the nested join (t1 NATURAL JOIN t2). As
            a result, the columns of t3 are checked
            for common columns only in t2, and, if
            t3 has common columns with
            t1, these columns are not used as
            equi-join columns. Thus, previously, the preceding query was
            transformed to the following equi-join:
          
SELECT ... FROM t1, t2, t3 WHERE t1.b = t2.b AND t2.c = t3.c;
            That join is missing one more equi-join predicate
            (t1.a = t3.a). As a result, it produces
            one row, not the empty result that it should. The correct
            equivalent query is this:
          
SELECT ... FROM t1, t2, t3 WHERE t1.b = t2.b AND t2.c = t3.c AND t1.a = t3.a;
If you require the same query result in current versions of MySQL as in older versions, rewrite the natural join as the first equi-join.
            Previously, the comma operator (,) and
            JOIN both had the same precedence, so the
            join expression t1, t2 JOIN t3 was
            interpreted as ((t1, t2) JOIN t3). Now
            JOIN has higher precedence, so the
            expression is interpreted as (t1, (t2 JOIN
            t3)). This change affects statements that use an
            ON clause, because that clause can refer
            only to columns in the operands of the join, and the change
            in precedence changes interpretation of what those operands
            are.
          
Example:
CREATE TABLE t1 (i1 INT, j1 INT); CREATE TABLE t2 (i2 INT, j2 INT); CREATE TABLE t3 (i3 INT, j3 INT); INSERT INTO t1 VALUES(1,1); INSERT INTO t2 VALUES(1,1); INSERT INTO t3 VALUES(1,1); SELECT * FROM t1, t2 JOIN t3 ON (t1.i1 = t3.i3);
            Previously, the SELECT was
            legal due to the implicit grouping of
            t1,t2 as (t1,t2). Now
            the JOIN takes precedence, so the
            operands for the ON clause are
            t2 and t3. Because
            t1.i1 is not a column in either of the
            operands, the result is an Unknown column 't1.i1'
            in 'on clause' error. To allow the join to be
            processed, group the first two tables explicitly with
            parentheses so that the operands for the
            ON clause are (t1,t2)
            and t3:
          
SELECT * FROM (t1, t2) JOIN t3 ON (t1.i1 = t3.i3);
            Alternatively, avoid the use of the comma operator and use
            JOIN instead:
          
SELECT * FROM t1 JOIN t2 JOIN t3 ON (t1.i1 = t3.i3);
            This change also applies to statements that mix the comma
            operator with INNER JOIN, CROSS
            JOIN, LEFT JOIN, and
            RIGHT JOIN, all of which now have higher
            precedence than the comma operator.
          
            Previously, the ON clause could refer to
            columns in tables named to its right. Now an
            ON clause can refer only to its operands.
          
Example:
CREATE TABLE t1 (i1 INT); CREATE TABLE t2 (i2 INT); CREATE TABLE t3 (i3 INT); SELECT * FROM t1 JOIN t2 ON (i1 = i3) JOIN t3;
            Previously, the SELECT
            statement was legal. Now the statement fails with an
            Unknown column 'i3' in 'on clause' error
            because i3 is a column in
            t3, which is not an operand of the
            ON clause. The statement should be
            rewritten as follows:
          
SELECT * FROM t1 JOIN t2 JOIN t3 ON (i1 = i3);
            Resolution of column names in NATURAL or
            USING joins is different than previously.
            For column names that are outside the
            FROM clause, MySQL now handles a superset
            of the queries compared to previously. That is, in cases
            when MySQL formerly issued an error that some column is
            ambiguous, the query now is handled correctly. This is due
            to the fact that MySQL now treats the common columns of
            NATURAL or USING joins
            as a single column, so when a query refers to such columns,
            the query compiler does not consider them as ambiguous.
          
Example:
SELECT * FROM t1 NATURAL JOIN t2 WHERE b > 1;
            Previously, this query would produce an error ERROR
            1052 (23000): Column 'b' in where clause is
            ambiguous. Now the query produces the correct
            result:
          
+------+------+------+ | b | c | y | +------+------+------+ | 4 | 2 | 3 | +------+------+------+
            One extension of MySQL compared to the SQL:2003 standard is
            that MySQL enables you to qualify the common (coalesced)
            columns of NATURAL or
            USING joins (just as previously), while
            the standard disallows that.
SELECT ... UNION [ALL | DISTINCT] SELECT ... [UNION [ALL | DISTINCT] SELECT ...]
        UNION is used to combine the
        result from multiple SELECT
        statements into a single result set.
      
        The column names from the first
        SELECT statement are used as the
        column names for the results returned. Selected columns listed
        in corresponding positions of each
        SELECT statement should have the
        same data type. (For example, the first column selected by the
        first statement should have the same type as the first column
        selected by the other statements.)
      
        If the data types of corresponding
        SELECT columns do not match, the
        types and lengths of the columns in the
        UNION result take into account
        the values retrieved by all of the
        SELECT statements. For example,
        consider the following:
      
mysql> SELECT REPEAT('a',1) UNION SELECT REPEAT('b',10);
+---------------+
| REPEAT('a',1) |
+---------------+
| a             |
| bbbbbbbbbb    |
+---------------+
        The SELECT statements are normal
        select statements, but with the following restrictions:
            Only the last SELECT
            statement can use INTO OUTFILE. (However,
            the entire UNION result is
            written to the file.)
          
            HIGH_PRIORITY cannot be used with
            SELECT statements that are
            part of a UNION. If you
            specify it for the first
            SELECT, it has no effect. If
            you specify it for any subsequent
            SELECT statements, a syntax
            error results.
        The default behavior for UNION is
        that duplicate rows are removed from the result. The optional
        DISTINCT keyword has no effect other than the
        default because it also specifies duplicate-row removal. With
        the optional ALL keyword, duplicate-row
        removal does not occur and the result includes all matching rows
        from all the SELECT statements.
      
        You can mix UNION
        ALL and UNION
        DISTINCT in the same query. Mixed
        UNION types are treated such that
        a DISTINCT union overrides any
        ALL union to its left. A
        DISTINCT union can be produced explicitly by
        using UNION
        DISTINCT or implicitly by using
        UNION with no following
        DISTINCT or ALL keyword.
      
        To apply ORDER BY or LIMIT
        to an individual SELECT, place
        the clause inside the parentheses that enclose the
        SELECT:
      
(SELECT a FROM t1 WHERE a=10 AND B=1 ORDER BY a LIMIT 10) UNION (SELECT a FROM t2 WHERE a=11 AND B=2 ORDER BY a LIMIT 10);
        However, use of ORDER BY for individual
        SELECT statements implies nothing
        about the order in which the rows appear in the final result
        because UNION by default produces
        an unordered set of rows. Therefore, the use of ORDER
        BY in this context is typically in conjunction with
        LIMIT, so that it is used to determine the
        subset of the selected rows to retrieve for the
        SELECT, even though it does not
        necessarily affect the order of those rows in the final
        UNION result. If ORDER
        BY appears without LIMIT in a
        SELECT, it is optimized away
        because it will have no effect anyway.
      
        To use an ORDER BY or
        LIMIT clause to sort or limit the entire
        UNION result, parenthesize the
        individual SELECT statements and
        place the ORDER BY or
        LIMIT after the last one. The following
        example uses both clauses:
      
(SELECT a FROM t1 WHERE a=10 AND B=1) UNION (SELECT a FROM t2 WHERE a=11 AND B=2) ORDER BY a LIMIT 10;
A statement without parentheses is equivalent to one parenthesized as just shown.
        This kind of ORDER BY cannot use column
        references that include a table name (that is, names in
        tbl_name.col_name
        format). Instead, provide a column alias in the first
        SELECT statement and refer to the
        alias in the ORDER BY. (Alternatively, refer
        to the column in the ORDER BY using its
        column position. However, use of column positions is
        deprecated.)
      
        Also, if a column to be sorted is aliased, the ORDER
        BY clause must refer to the
        alias, not the column name. The first of the following
        statements will work, but the second will fail with an
        Unknown column 'a' in 'order clause' error:
      
(SELECT a AS b FROM t) UNION (SELECT ...) ORDER BY b; (SELECT a AS b FROM t) UNION (SELECT ...) ORDER BY a;
        To cause rows in a UNION result
        to consist of the sets of rows retrieved by each
        SELECT one after the other,
        select an additional column in each
        SELECT to use as a sort column
        and add an ORDER BY following the last
        SELECT:
      
(SELECT 1 AS sort_col, col1a, col1b, ... FROM t1) UNION (SELECT 2, col2a, col2b, ... FROM t2) ORDER BY sort_col;
        To additionally maintain sort order within individual
        SELECT results, add a secondary
        column to the ORDER BY clause:
      
(SELECT 1 AS sort_col, col1a, col1b, ... FROM t1) UNION (SELECT 2, col2a, col2b, ... FROM t2) ORDER BY sort_col, col1a;
        Use of an additional column also enables you to determine which
        SELECT each row comes from. Extra
        columns can provide other identifying information as well, such
        as a string that indicates a table name.
      A subquery is a SELECT statement
      within another statement.
    
Starting with MySQL 4.1, all subquery forms and operations that the SQL standard requires are supported, as well as a few features that are MySQL-specific.
Here is an example of a subquery:
SELECT * FROM t1 WHERE column1 = (SELECT column1 FROM t2);
      In this example, SELECT * FROM t1 ... is the
      outer query (or outer
      statement), and (SELECT column1 FROM
      t2) is the subquery. We say that
      the subquery is nested within the outer
      query, and in fact it is possible to nest subqueries within other
      subqueries, to a considerable depth. A subquery must always appear
      within parentheses.
    
The main advantages of subqueries are:
They allow queries that are structured so that it is possible to isolate each part of a statement.
They provide alternative ways to perform operations that would otherwise require complex joins and unions.
Many people find subqueries more readable than complex joins or unions. Indeed, it was the innovation of subqueries that gave people the original idea of calling the early SQL “Structured Query Language.”
Here is an example statement that shows the major points about subquery syntax as specified by the SQL standard and supported in MySQL:
DELETE FROM t1
WHERE s11 > ANY
 (SELECT COUNT(*) /* no hint */ FROM t2
  WHERE NOT EXISTS
   (SELECT * FROM t3
    WHERE ROW(5*t2.s1,77)=
     (SELECT 50,11*s1 FROM t4 UNION SELECT 50,77 FROM
      (SELECT * FROM t5) AS t5)));
A subquery can return a scalar (a single value), a single row, a single column, or a table (one or more rows of one or more columns). These are called scalar, column, row, and table subqueries. Subqueries that return a particular kind of result often can be used only in certain contexts, as described in the following sections.
      There are few restrictions on the type of statements in which
      subqueries can be used. A subquery can contain many of the
      keywords or clauses that an ordinary
      SELECT can contain:
      DISTINCT, GROUP BY,
      ORDER BY, LIMIT, joins,
      index hints, UNION constructs,
      comments, functions, and so on.
    
      A subquery's outer statement can be any one of:
      SELECT,
      INSERT,
      UPDATE,
      DELETE,
      SET, or
      DO.
    
      In MySQL, you cannot modify a table and select from the same table
      in a subquery. This applies to statements such as
      DELETE,
      INSERT,
      REPLACE,
      UPDATE, and (because subqueries can
      be used in the SET clause)
      LOAD DATA
      INFILE.
    
For information about how the optimizer handles subqueries, see Section 8.2.1.18, “Subquery Optimization”. For a discussion of restrictions on subquery use, including performance issues for certain forms of subquery syntax, see Section D.4, “Restrictions on Subqueries”.
        In its simplest form, a subquery is a scalar subquery that
        returns a single value. A scalar subquery is a simple operand,
        and you can use it almost anywhere a single column value or
        literal is legal, and you can expect it to have those
        characteristics that all operands have: a data type, a length,
        an indication that it can be NULL, and so on.
        For example:
      
CREATE TABLE t1 (s1 INT, s2 CHAR(5) NOT NULL); INSERT INTO t1 VALUES(100, 'abcde'); SELECT (SELECT s2 FROM t1);
        The subquery in this SELECT
        returns a single value ('abcde') that has a
        data type of CHAR, a length of 5,
        a character set and collation equal to the defaults in effect at
        CREATE TABLE time, and an
        indication that the value in the column can be
        NULL. Nullability of the value selected by a
        scalar subquery is not copied because if the subquery result is
        empty, the result is NULL. For the subquery
        just shown, if t1 were empty, the result
        would be NULL even though
        s2 is NOT NULL.
      
        There are a few contexts in which a scalar subquery cannot be
        used. If a statement permits only a literal value, you cannot
        use a subquery. For example, LIMIT requires
        literal integer arguments, and
        LOAD DATA
        INFILE requires a literal string file name. You cannot
        use subqueries to supply these values.
      
        When you see examples in the following sections that contain the
        rather spartan construct (SELECT column1 FROM
        t1), imagine that your own code contains much more
        diverse and complex constructions.
      
Suppose that we make two tables:
CREATE TABLE t1 (s1 INT); INSERT INTO t1 VALUES (1); CREATE TABLE t2 (s1 INT); INSERT INTO t2 VALUES (2);
        Then perform a SELECT:
      
SELECT (SELECT s1 FROM t2) FROM t1;
        The result is 2 because there is a row in
        t2 containing a column s1
        that has a value of 2.
      
A scalar subquery can be part of an expression, but remember the parentheses, even if the subquery is an operand that provides an argument for a function. For example:
SELECT UPPER((SELECT s1 FROM t1)) FROM t2;
The most common use of a subquery is in the form:
non_subquery_operandcomparison_operator(subquery)
        Where comparison_operator is one of
        these operators:
      
= > < >= <= <> != <=>
For example:
... WHERE 'a' = (SELECT column1 FROM t1)
MySQL also permits this construct:
non_subquery_operandLIKE (subquery)
At one time the only legal place for a subquery was on the right side of a comparison, and you might still find some old DBMSs that insist on this.
        Here is an example of a common-form subquery comparison that you
        cannot do with a join. It finds all the rows in table
        t1 for which the column1
        value is equal to a maximum value in table
        t2:
      
SELECT * FROM t1 WHERE column1 = (SELECT MAX(column2) FROM t2);
        Here is another example, which again is impossible with a join
        because it involves aggregating for one of the tables. It finds
        all rows in table t1 containing a value that
        occurs twice in a given column:
      
SELECT * FROM t1 AS t WHERE 2 = (SELECT COUNT(*) FROM t1 WHERE t1.id = t.id);
For a comparison of the subquery to a scalar, the subquery must return a scalar. For a comparison of the subquery to a row constructor, the subquery must be a row subquery that returns a row with the same number of values as the row constructor. See Section 13.2.10.5, “Row Subqueries”.
Syntax:
operandcomparison_operatorANY (subquery)operandIN (subquery)operandcomparison_operatorSOME (subquery)
        Where comparison_operator is one of
        these operators:
      
= > < >= <= <> !=
        The ANY keyword, which must follow a
        comparison operator, means “return TRUE
        if the comparison is TRUE for
        ANY of the values in the column that the
        subquery returns.” For example:
      
SELECT s1 FROM t1 WHERE s1 > ANY (SELECT s1 FROM t2);
        Suppose that there is a row in table t1
        containing (10). The expression is
        TRUE if table t2 contains
        (21,14,7) because there is a value
        7 in t2 that is less than
        10. The expression is
        FALSE if table t2 contains
        (20,10), or if table t2 is
        empty. The expression is unknown (that is,
        NULL) if table t2 contains
        (NULL,NULL,NULL).
      
        When used with a subquery, the word IN is an
        alias for = ANY. Thus, these two statements
        are the same:
      
SELECT s1 FROM t1 WHERE s1 = ANY (SELECT s1 FROM t2); SELECT s1 FROM t1 WHERE s1 IN (SELECT s1 FROM t2);
        IN and = ANY are not
        synonyms when used with an expression list.
        IN can take an expression list, but
        = ANY cannot. See
        Section 12.3.2, “Comparison Functions and Operators”.
      
        NOT IN is not an alias for <>
        ANY, but for <> ALL. See
        Section 13.2.10.4, “Subqueries with ALL”.
      
        The word SOME is an alias for
        ANY. Thus, these two statements are the same:
      
SELECT s1 FROM t1 WHERE s1 <> ANY (SELECT s1 FROM t2); SELECT s1 FROM t1 WHERE s1 <> SOME (SELECT s1 FROM t2);
        Use of the word SOME is rare, but this
        example shows why it might be useful. To most people, the
        English phrase “a is not equal to any b” means
        “there is no b which is equal to a,” but that is
        not what is meant by the SQL syntax. The syntax means
        “there is some b to which a is not equal.” Using
        <> SOME instead helps ensure that
        everyone understands the true meaning of the query.
Syntax:
operandcomparison_operatorALL (subquery)
        The word ALL, which must follow a comparison
        operator, means “return TRUE if the
        comparison is TRUE for ALL
        of the values in the column that the subquery returns.”
        For example:
      
SELECT s1 FROM t1 WHERE s1 > ALL (SELECT s1 FROM t2);
        Suppose that there is a row in table t1
        containing (10). The expression is
        TRUE if table t2 contains
        (-5,0,+5) because 10 is
        greater than all three values in t2. The
        expression is FALSE if table
        t2 contains
        (12,6,NULL,-100) because there is a single
        value 12 in table t2 that
        is greater than 10. The expression is
        unknown (that is, NULL)
        if table t2 contains
        (0,NULL,1).
      
        Finally, the expression is TRUE if table
        t2 is empty. So, the following expression is
        TRUE when table t2 is
        empty:
      
SELECT * FROM t1 WHERE 1 > ALL (SELECT s1 FROM t2);
        But this expression is NULL when table
        t2 is empty:
      
SELECT * FROM t1 WHERE 1 > (SELECT s1 FROM t2);
        In addition, the following expression is NULL
        when table t2 is empty:
      
SELECT * FROM t1 WHERE 1 > ALL (SELECT MAX(s1) FROM t2);
        In general, tables containing NULL
        values and empty tables are
        “edge cases.” When writing subqueries, always
        consider whether you have taken those two possibilities into
        account.
      
        NOT IN is an alias for <>
        ALL. Thus, these two statements are the same:
      
SELECT s1 FROM t1 WHERE s1 <> ALL (SELECT s1 FROM t2); SELECT s1 FROM t1 WHERE s1 NOT IN (SELECT s1 FROM t2);
Scalar or column subqueries return a single value or a column of values. A row subquery is a subquery variant that returns a single row and can thus return more than one column value. Legal operators for row subquery comparisons are:
= > < >= <= <> != <=>
Here are two examples:
SELECT * FROM t1 WHERE (col1,col2) = (SELECT col3, col4 FROM t2 WHERE id = 10); SELECT * FROM t1 WHERE ROW(col1,col2) = (SELECT col3, col4 FROM t2 WHERE id = 10);
        For both queries, if the table t2 contains a
        single row with id = 10, the subquery returns
        a single row. If this row has col3 and
        col4 values equal to the
        col1 and col2 values of
        any rows in t1, the WHERE
        expression is TRUE and each query returns
        those t1 rows. If the t2
        row col3 and col4 values
        are not equal the col1 and
        col2 values of any t1 row,
        the expression is FALSE and the query returns
        an empty result set. The expression is
        unknown (that is, NULL)
        if the subquery produces no rows. An error occurs if the
        subquery produces multiple rows because a row subquery can
        return at most one row.
      
For information about how each operator works for row comparisons, see Section 12.3.2, “Comparison Functions and Operators”.
        The expressions (1,2) and
        ROW(1,2) are sometimes called row
        constructors. The two are equivalent. The row
        constructor and the row returned by the subquery must contain
        the same number of values.
      
A row constructor is used for comparisons with subqueries that return two or more columns. When a subquery returns a single column, this is regarded as a scalar value and not as a row, so a row constructor cannot be used with a subquery that does not return at least two columns. Thus, the following query fails with a syntax error:
SELECT * FROM t1 WHERE ROW(1) = (SELECT column1 FROM t2)
Row constructors are legal in other contexts. For example, the following two statements are semantically equivalent (and are handled in the same way by the optimizer):
SELECT * FROM t1 WHERE (column1,column2) = (1,1); SELECT * FROM t1 WHERE column1 = 1 AND column2 = 1;
        The following query answers the request, “find all rows in
        table t1 that also exist in table
        t2”:
      
SELECT column1,column2,column3
  FROM t1
  WHERE (column1,column2,column3) IN
         (SELECT column1,column2,column3 FROM t2);
        If a subquery returns any rows at all, EXISTS
         is
        subqueryTRUE, and NOT EXISTS
         is
        subqueryFALSE. For example:
      
SELECT column1 FROM t1 WHERE EXISTS (SELECT * FROM t2);
        Traditionally, an EXISTS subquery starts with
        SELECT *, but it could begin with
        SELECT 5 or SELECT column1
        or anything at all. MySQL ignores the
        SELECT list in such a subquery,
        so it makes no difference.
      
        For the preceding example, if t2 contains any
        rows, even rows with nothing but NULL values,
        the EXISTS condition is
        TRUE. This is actually an unlikely example
        because a [NOT] EXISTS subquery almost always
        contains correlations. Here are some more realistic examples:
What kind of store is present in one or more cities?
SELECT DISTINCT store_type FROM stores
  WHERE EXISTS (SELECT * FROM cities_stores
                WHERE cities_stores.store_type = stores.store_type);
What kind of store is present in no cities?
SELECT DISTINCT store_type FROM stores
  WHERE NOT EXISTS (SELECT * FROM cities_stores
                    WHERE cities_stores.store_type = stores.store_type);
What kind of store is present in all cities?
SELECT DISTINCT store_type FROM stores s1
  WHERE NOT EXISTS (
    SELECT * FROM cities WHERE NOT EXISTS (
      SELECT * FROM cities_stores
       WHERE cities_stores.city = cities.city
       AND cities_stores.store_type = stores.store_type));
        The last example is a double-nested NOT
        EXISTS query. That is, it has a NOT
        EXISTS clause within a NOT EXISTS
        clause. Formally, it answers the question “does a city
        exist with a store that is not in
        Stores”? But it is easier to say that
        a nested NOT EXISTS answers the question
        “is x TRUE
        for all y?”
A correlated subquery is a subquery that contains a reference to a table that also appears in the outer query. For example:
SELECT * FROM t1
  WHERE column1 = ANY (SELECT column1 FROM t2
                       WHERE t2.column2 = t1.column2);
        Notice that the subquery contains a reference to a column of
        t1, even though the subquery's
        FROM clause does not mention a table
        t1. So, MySQL looks outside the subquery, and
        finds t1 in the outer query.
      
        Suppose that table t1 contains a row where
        column1 = 5 and column2 =
        6; meanwhile, table t2 contains a
        row where column1 = 5 and column2 =
        7. The simple expression ... WHERE column1 =
        ANY (SELECT column1 FROM t2) would be
        TRUE, but in this example, the
        WHERE clause within the subquery is
        FALSE (because (5,6) is
        not equal to (5,7)), so the expression as a
        whole is FALSE.
      
Scoping rule: MySQL evaluates from inside to outside. For example:
SELECT column1 FROM t1 AS x
  WHERE x.column1 = (SELECT column1 FROM t2 AS x
    WHERE x.column1 = (SELECT column1 FROM t3
      WHERE x.column2 = t3.column1));
        In this statement, x.column2 must be a column
        in table t2 because SELECT column1
        FROM t2 AS x ... renames t2. It is
        not a column in table t1 because
        SELECT column1 FROM t1 ... is an outer query
        that is farther out.
      
        For subqueries in HAVING or ORDER
        BY clauses, MySQL also looks for column names in the
        outer select list.
      
For certain cases, a correlated subquery is optimized. For example:
valIN (SELECTkey_valFROMtbl_nameWHEREcorrelated_condition)
Otherwise, they are inefficient and likely to be slow. Rewriting the query as a join might improve performance.
Aggregate functions in correlated subqueries may contain outer references, provided the function contains nothing but outer references, and provided the function is not contained in another function or expression.
        Subqueries are legal in a SELECT
        statement's FROM clause. The actual syntax
        is:
      
SELECT ... FROM (subquery) [AS]name...
        The [AS] 
        clause is mandatory, because every table in a
        nameFROM clause must have a name. Any columns in
        the subquery select list must have
        unique names.
      
For the sake of illustration, assume that you have this table:
CREATE TABLE t1 (s1 INT, s2 CHAR(5), s3 FLOAT);
        Here is how to use a subquery in the FROM
        clause, using the example table:
      
INSERT INTO t1 VALUES (1,'1',1.0); INSERT INTO t1 VALUES (2,'2',2.0); SELECT sb1,sb2,sb3 FROM (SELECT s1 AS sb1, s2 AS sb2, s3*2 AS sb3 FROM t1) AS sb WHERE sb1 > 1;
        Result: 2, '2', 4.0.
      
Here is another example: Suppose that you want to know the average of a set of sums for a grouped table. This does not work:
SELECT AVG(SUM(column1)) FROM t1 GROUP BY column1;
However, this query provides the desired information:
SELECT AVG(sum_column1)
  FROM (SELECT SUM(column1) AS sum_column1
        FROM t1 GROUP BY column1) AS t1;
        Notice that the column name used within the subquery
        (sum_column1) is recognized in the outer
        query.
      
        Subqueries in the FROM clause can return a
        scalar, column, row, or table. Subqueries in the
        FROM clause cannot be correlated subqueries,
        unless used within the ON clause of a
        JOIN operation.
      
        Before MySQL 5.6.3, subqueries in the FROM
        clause are executed even for the
        EXPLAIN statement (that is,
        derived temporary tables are materialized). This occurs because
        upper-level queries need information about all tables during the
        optimization phase, and the table represented by a subquery in
        the FROM clause is unavailable unless the
        subquery is executed. As of MySQL 5.6.3, the optimizer
        determines information about derived tables in a different way
        and materialization of them does not occur for
        EXPLAIN. See
        Section 8.2.1.18.3, “Optimizing Derived Tables (Subqueries) in the FROM Clause”.
      
        It is possible under certain circumstances to modify table data
        using EXPLAIN
        SELECT. This can occur if the outer query accesses any
        tables and an inner query invokes a stored function that changes
        one or more rows of a table. Suppose that there are two tables
        t1 and t2 in database
        d1, created as shown here:
      
mysql>CREATE DATABASE d1;Query OK, 1 row affected (0.00 sec) mysql>USE d1;Database changed mysql>CREATE TABLE t1 (c1 INT);Query OK, 0 rows affected (0.15 sec) mysql>CREATE TABLE t2 (c1 INT);Query OK, 0 rows affected (0.08 sec)
        Now we create a stored function f1 which
        modifies t2:
      
mysql>DELIMITER //mysql>CREATE FUNCTION f1(p1 INT) RETURNS INTmysql>BEGINmysql>INSERT INTO t2 VALUES (p1);mysql>RETURN p1;mysql>END //Query OK, 0 rows affected (0.01 sec) mysql>DELIMITER ;
        Referencing the function directly in an
        EXPLAIN
        SELECT does not have any effect on
        t2, as shown here:
      
mysql>SELECT * FROM t2;Empty set (0.00 sec) mysql>EXPLAIN SELECT f1(5);+----+-------------+-------+------+---------------+------+---------+------+------+----------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+------+---------------+------+---------+------+------+----------------+ | 1 | SIMPLE | NULL | NULL | NULL | NULL | NULL | NULL | NULL | No tables used | +----+-------------+-------+------+---------------+------+---------+------+------+----------------+ 1 row in set (0.00 sec) mysql>SELECT * FROM t2;Empty set (0.00 sec)
        This is because the SELECT
        statement did not reference any tables, as can be seen in the
        table and Extra columns of
        the output. This is also true of the following nested
        SELECT:
      
mysql>EXPLAIN SELECT NOW() AS a1, (SELECT f1(5)) AS a2;+----+-------------+-------+------+---------------+------+---------+------+------+----------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+-------+------+---------------+------+---------+------+------+----------------+ | 1 | PRIMARY | NULL | NULL | NULL | NULL | NULL | NULL | NULL | No tables used | +----+-------------+-------+------+---------------+------+---------+------+------+----------------+ 1 row in set, 1 warning (0.00 sec) mysql>SHOW WARNINGS;+-------+------+------------------------------------------+ | Level | Code | Message | +-------+------+------------------------------------------+ | Note | 1249 | Select 2 was reduced during optimization | +-------+------+------------------------------------------+ 1 row in set (0.00 sec) mysql>SELECT * FROM t2;Empty set (0.00 sec)
        However, if the outer SELECT
        references any tables, the optimizer executes the statement in
        the subquery as well:
      
mysql>EXPLAIN SELECT * FROM t1 AS a1, (SELECT f1(5)) AS a2;+----+-------------+------------+--------+---------------+------+---------+------+------+---------------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+------------+--------+---------------+------+---------+------+------+---------------------+ | 1 | PRIMARY | a1 | system | NULL | NULL | NULL | NULL | 0 | const row not found | | 1 | PRIMARY | <derived2> | system | NULL | NULL | NULL | NULL | 1 | | | 2 | DERIVED | NULL | NULL | NULL | NULL | NULL | NULL | NULL | No tables used | +----+-------------+------------+--------+---------------+------+---------+------+------+---------------------+ 3 rows in set (0.00 sec) mysql>SELECT * FROM t2;+------+ | c1 | +------+ | 5 | +------+ 1 row in set (0.00 sec)
        This also means that an
        EXPLAIN
        SELECT statement such as the one shown here may take a
        long time to execute because the
        BENCHMARK() function is executed
        once for each row in t1:
      
EXPLAIN SELECT * FROM t1 AS a1, (SELECT BENCHMARK(1000000, MD5(NOW())));
There are some errors that apply only to subqueries. This section describes them.
Unsupported subquery syntax:
ERROR 1235 (ER_NOT_SUPPORTED_YET) SQLSTATE = 42000 Message = "This version of MySQL doesn't yet support 'LIMIT & IN/ALL/ANY/SOME subquery'"
This means that MySQL does not support statements of the following form:
SELECT * FROM t1 WHERE s1 IN (SELECT s2 FROM t2 ORDER BY s1 LIMIT 1)
Incorrect number of columns from subquery:
ERROR 1241 (ER_OPERAND_COL) SQLSTATE = 21000 Message = "Operand should contain 1 column(s)"
This error occurs in cases like this:
SELECT (SELECT column1, column2 FROM t2) FROM t1;
You may use a subquery that returns multiple columns, if the purpose is row comparison. In other contexts, the subquery must be a scalar operand. See Section 13.2.10.5, “Row Subqueries”.
Incorrect number of rows from subquery:
ERROR 1242 (ER_SUBSELECT_NO_1_ROW) SQLSTATE = 21000 Message = "Subquery returns more than 1 row"
This error occurs for statements where the subquery must return at most one row but returns multiple rows. Consider the following example:
SELECT * FROM t1 WHERE column1 = (SELECT column1 FROM t2);
            If SELECT column1 FROM t2 returns just
            one row, the previous query will work. If the subquery
            returns more than one row, error 1242 will occur. In that
            case, the query should be rewritten as:
          
SELECT * FROM t1 WHERE column1 = ANY (SELECT column1 FROM t2);
Incorrectly used table in subquery:
Error 1093 (ER_UPDATE_TABLE_USED) SQLSTATE = HY000 Message = "You can't specify target table 'x' for update in FROM clause"
This error occurs in cases such as the following, which attempts to modify a table and select from the same table in the subquery:
UPDATE t1 SET column2 = (SELECT MAX(column1) FROM t1);
            You can use a subquery for assignment within an
            UPDATE statement because
            subqueries are legal in
            UPDATE and
            DELETE statements as well as
            in SELECT statements.
            However, you cannot use the same table (in this case, table
            t1) for both the subquery
            FROM clause and the update target.
For transactional storage engines, the failure of a subquery causes the entire statement to fail. For nontransactional storage engines, data modifications made before the error was encountered are preserved.
Development is ongoing, so no optimization tip is reliable for the long term. The following list provides some interesting tricks that you might want to play with:
Use subquery clauses that affect the number or order of the rows in the subquery. For example:
SELECT * FROM t1 WHERE t1.column1 IN (SELECT column1 FROM t2 ORDER BY column1); SELECT * FROM t1 WHERE t1.column1 IN (SELECT DISTINCT column1 FROM t2); SELECT * FROM t1 WHERE EXISTS (SELECT * FROM t2 LIMIT 1);
Replace a join with a subquery. For example, try this:
SELECT DISTINCT column1 FROM t1 WHERE t1.column1 IN ( SELECT column1 FROM t2);
Instead of this:
SELECT DISTINCT t1.column1 FROM t1, t2 WHERE t1.column1 = t2.column1;
Some subqueries can be transformed to joins for compatibility with older versions of MySQL that do not support subqueries. However, in some cases, converting a subquery to a join may improve performance. See Section 13.2.10.11, “Rewriting Subqueries as Joins”.
Move clauses from outside to inside the subquery. For example, use this query:
SELECT * FROM t1 WHERE s1 IN (SELECT s1 FROM t1 UNION ALL SELECT s1 FROM t2);
Instead of this query:
SELECT * FROM t1 WHERE s1 IN (SELECT s1 FROM t1) OR s1 IN (SELECT s1 FROM t2);
For another example, use this query:
SELECT (SELECT column1 + 5 FROM t1) FROM t2;
Instead of this query:
SELECT (SELECT column1 FROM t1) + 5 FROM t2;
Use a row subquery instead of a correlated subquery. For example, use this query:
SELECT * FROM t1 WHERE (column1,column2) IN (SELECT column1,column2 FROM t2);
Instead of this query:
SELECT * FROM t1
  WHERE EXISTS (SELECT * FROM t2 WHERE t2.column1=t1.column1
                AND t2.column2=t1.column2);
            Use NOT (a = ANY (...)) rather than
            a <> ALL (...).
          
            Use x = ANY ( rather than table containing
            (1,2))x=1 OR
            x=2.
          
            Use = ANY rather than
            EXISTS.
          
            For uncorrelated subqueries that always return one row,
            IN is always slower than
            =. For example, use this query:
          
SELECT * FROM t1 WHERE t1.col_name= (SELECT a FROM t2 WHERE b =some_const);
Instead of this query:
SELECT * FROM t1 WHERE t1.col_nameIN (SELECT a FROM t2 WHERE b =some_const);
        These tricks might cause programs to go faster or slower. Using
        MySQL facilities like the
        BENCHMARK() function, you can get
        an idea about what helps in your own situation. See
        Section 12.14, “Information Functions”.
      
Some optimizations that MySQL itself makes are:
            MySQL executes uncorrelated subqueries only once. Use
            EXPLAIN to make sure that a
            given subquery really is uncorrelated.
          
            MySQL rewrites IN,
            ALL, ANY, and
            SOME subqueries in an attempt to take
            advantage of the possibility that the select-list columns in
            the subquery are indexed.
          
            MySQL replaces subqueries of the following form with an
            index-lookup function, which
            EXPLAIN describes as a
            special join type
            (unique_subquery or
            index_subquery):
          
... IN (SELECTindexed_columnFROMsingle_table...)
            MySQL enhances expressions of the following form with an
            expression involving MIN() or
            MAX(), unless
            NULL values or empty sets are involved:
          
value{ALL|ANY|SOME} {> | < | >= | <=} (uncorrelated subquery)
            For example, this WHERE clause:
          
WHERE 5 > ALL (SELECT x FROM t)
might be treated by the optimizer like this:
WHERE 5 > (SELECT MAX(x) FROM t)
        Sometimes there are other ways to test membership in a set of
        values than by using a subquery. Also, on some occasions, it is
        not only possible to rewrite a query without a subquery, but it
        can be more efficient to make use of some of these techniques
        rather than to use subqueries. One of these is the
        IN() construct:
      
For example, this query:
SELECT * FROM t1 WHERE id IN (SELECT id FROM t2);
Can be rewritten as:
SELECT DISTINCT t1.* FROM t1, t2 WHERE t1.id=t2.id;
The queries:
SELECT * FROM t1 WHERE id NOT IN (SELECT id FROM t2); SELECT * FROM t1 WHERE NOT EXISTS (SELECT id FROM t2 WHERE t1.id=t2.id);
Can be rewritten as:
SELECT table1.* FROM table1 LEFT JOIN table2 ON table1.id=table2.id WHERE table2.id IS NULL;
        A LEFT [OUTER] JOIN can be faster than an
        equivalent subquery because the server might be able to optimize
        it better—a fact that is not specific to MySQL Server
        alone. Prior to SQL-92, outer joins did not exist, so subqueries
        were the only way to do certain things. Today, MySQL Server and
        many other modern database systems offer a wide range of outer
        join types.
      
        MySQL Server supports multiple-table
        DELETE statements that can be
        used to efficiently delete rows based on information from one
        table or even from many tables at the same time. Multiple-table
        UPDATE statements are also
        supported. See Section 13.2.2, “DELETE Syntax”, and
        Section 13.2.11, “UPDATE Syntax”.
Single-table syntax:
UPDATE [LOW_PRIORITY] [IGNORE]table_referenceSETcol_name1={expr1|DEFAULT} [,col_name2={expr2|DEFAULT}] ... [WHEREwhere_condition] [ORDER BY ...] [LIMITrow_count]
Multiple-table syntax:
UPDATE [LOW_PRIORITY] [IGNORE]table_referencesSETcol_name1={expr1|DEFAULT} [,col_name2={expr2|DEFAULT}] ... [WHEREwhere_condition]
      For the single-table syntax, the
      UPDATE statement updates columns of
      existing rows in the named table with new values. The
      SET clause indicates which columns to modify
      and the values they should be given. Each value can be given as an
      expression, or the keyword DEFAULT to set a
      column explicitly to its default value. The
      WHERE clause, if given, specifies the
      conditions that identify which rows to update. With no
      WHERE clause, all rows are updated. If the
      ORDER BY clause is specified, the rows are
      updated in the order that is specified. The
      LIMIT clause places a limit on the number of
      rows that can be updated.
    
      For the multiple-table syntax,
      UPDATE updates rows in each table
      named in table_references that satisfy
      the conditions. Each matching row is updated once, even if it
      matches the conditions multiple times. For multiple-table syntax,
      ORDER BY and LIMIT cannot be
      used.
    
      For partitioned tables, both the single-single and multiple-table
      forms of this statement support the use of a
      PARTITION option as part of a table reference.
      This option takes a list of one or more partitions or
      subpartitions (or both). Only the partitions (or subpartitions)
      listed are checked for matches, and a row that is not in any of
      these partitions or subpartitions is not updated, whether it
      satisfies the where_condition or not.
        Unlike the case when using PARTITION with an
        INSERT or
        REPLACE statement, an otherwise
        valid UPDATE ... PARTITION statement is
        considered successful even if no rows in the listed partitions
        (or subpartitions) match the
        where_condition.
See Section 19.5, “Partition Selection”, for more information and examples.
      where_condition is an expression that
      evaluates to true for each row to be updated. For expression
      syntax, see Section 9.5, “Expression Syntax”.
    
      table_references and
      where_condition are specified as
      described in Section 13.2.9, “SELECT Syntax”.
    
      You need the UPDATE privilege only
      for columns referenced in an UPDATE
      that are actually updated. You need only the
      SELECT privilege for any columns
      that are read but not modified.
    
      The UPDATE statement supports the
      following modifiers:
          With the LOW_PRIORITY keyword, execution of
          the UPDATE is delayed until no
          other clients are reading from the table. This affects only
          storage engines that use only table-level locking (such as
          MyISAM, MEMORY, and
          MERGE).
        
          With the IGNORE keyword, the update
          statement does not abort even if errors occur during the
          update. Rows for which duplicate-key conflicts occur on a
          unique key value are not updated. Rows updated to values that
          would cause data conversion errors are updated to the closest
          valid values instead.
      In MySQL 5.6.4 and later,
      UPDATE IGNORE
      statements, including those having an ORDER BY
      clause, are flagged as unsafe for statement-based replication.
      (This is because the order in which the rows are updated
      determines which rows are ignored.) With this change, such
      statements produce a warning in the log when using statement-based
      mode and are logged using the row-based format when using
      MIXED mode. (Bug #11758262, Bug #50439) See
      Section 17.1.2.3, “Determination of Safe and Unsafe Statements in Binary Logging”, for more
      information.
    
      If you access a column from the table to be updated in an
      expression, UPDATE uses the current
      value of the column. For example, the following statement sets
      col1 to one more than its current value:
    
UPDATE t1 SET col1 = col1 + 1;
      The second assignment in the following statement sets
      col2 to the current (updated)
      col1 value, not the original
      col1 value. The result is that
      col1 and col2 have the same
      value. This behavior differs from standard SQL.
    
UPDATE t1 SET col1 = col1 + 1, col2 = col1;
      Single-table UPDATE assignments are
      generally evaluated from left to right. For multiple-table
      updates, there is no guarantee that assignments are carried out in
      any particular order.
    
If you set a column to the value it currently has, MySQL notices this and does not update it.
      If you update a column that has been declared NOT
      NULL by setting to NULL, an error
      occurs if strict SQL mode is enabled; otherwise, the column is set
      to the implicit default value for the column data type and the
      warning count is incremented. The implicit default value is
      0 for numeric types, the empty string
      ('') for string types, and the
      “zero” value for date and time types. See
      Section 11.6, “Data Type Default Values”.
    
      UPDATE returns the number of rows
      that were actually changed. The
      mysql_info() C API function
      returns the number of rows that were matched and updated and the
      number of warnings that occurred during the
      UPDATE.
    
      You can use LIMIT
       to restrict the
      scope of the row_countUPDATE. A
      LIMIT clause is a rows-matched restriction. The
      statement stops as soon as it has found
      row_count rows that satisfy the
      WHERE clause, whether or not they actually were
      changed.
    
      If an UPDATE statement includes an
      ORDER BY clause, the rows are updated in the
      order specified by the clause. This can be useful in certain
      situations that might otherwise result in an error. Suppose that a
      table t contains a column id
      that has a unique index. The following statement could fail with a
      duplicate-key error, depending on the order in which rows are
      updated:
    
UPDATE t SET id = id + 1;
      For example, if the table contains 1 and 2 in the
      id column and 1 is updated to 2 before 2 is
      updated to 3, an error occurs. To avoid this problem, add an
      ORDER BY clause to cause the rows with larger
      id values to be updated before those with
      smaller values:
    
UPDATE t SET id = id + 1 ORDER BY id DESC;
      You can also perform UPDATE
      operations covering multiple tables. However, you cannot use
      ORDER BY or LIMIT with a
      multiple-table UPDATE. The
      table_references clause lists the
      tables involved in the join. Its syntax is described in
      Section 13.2.9.2, “JOIN Syntax”. Here is an example:
    
UPDATE items,month SET items.price=month.price WHERE items.id=month.id;
      The preceding example shows an inner join that uses the comma
      operator, but multiple-table UPDATE
      statements can use any type of join permitted in
      SELECT statements, such as
      LEFT JOIN.
    
      If you use a multiple-table UPDATE
      statement involving InnoDB tables for which
      there are foreign key constraints, the MySQL optimizer might
      process tables in an order that differs from that of their
      parent/child relationship. In this case, the statement fails and
      rolls back. Instead, update a single table and rely on the
      ON UPDATE capabilities that
      InnoDB provides to cause the other tables to be
      modified accordingly. See
      Section 14.5.6, “InnoDB and FOREIGN KEY Constraints”.
    
Currently, you cannot update a table and select from the same table in a subquery.
      Prior to MySQL 5.6.6, an UPDATE on a
      partitioned table using a storage engine such as
      MyISAM that employs table-level locks
      locked all partitions of the table. This was true even for
      UPDATE ... PARTITION queries. (This did not and
      does not occur with storage engines such as
      InnoDB that employ row-level
      locking.) In MySQL 5.6.6 and later, MySQL uses partition lock
      pruning, so that only partitions containing rows matching the
      UPDATE statement's
      WHERE clause are actually locked, as long as
      none of the table's partitioning columns are updated. For
      more information, see
      Section 19.6.4, “Partitioning and Locking”.
    MySQL supports local transactions (within a given client session)
    through statements such as
    SET autocommit,
    START TRANSACTION,
    COMMIT, and
    ROLLBACK. See
    Section 13.3.1, “START TRANSACTION, COMMIT, and ROLLBACK Syntax”. XA transaction support enables MySQL to
    participate in distributed transactions as well. See
    Section 13.3.7, “XA Transactions”.
START TRANSACTION
    [transaction_characteristic [, transaction_characteristic] ...]
transaction_characteristic:
    WITH CONSISTENT SNAPSHOT
  | READ WRITE
  | READ ONLY
BEGIN [WORK]
COMMIT [WORK] [AND [NO] CHAIN] [[NO] RELEASE]
ROLLBACK [WORK] [AND [NO] CHAIN] [[NO] RELEASE]
SET autocommit = {0 | 1}
These statements provide control over use of transactions:
          START TRANSACTION or
          BEGIN start a new transaction.
        
          COMMIT commits the current transaction,
          making its changes permanent.
        
          ROLLBACK rolls back the current
          transaction, canceling its changes.
        
          SET autocommit disables or enables the
          default autocommit mode for the current session.
By default, MySQL runs with autocommit mode enabled. This means that as soon as you execute a statement that updates (modifies) a table, MySQL stores the update on disk to make it permanent. The change cannot be rolled back.
      To disable autocommit mode implicitly for a single series of
      statements, use the START TRANSACTION
      statement:
    
START TRANSACTION; SELECT @A:=SUM(salary) FROM table1 WHERE type=1; UPDATE table2 SET summary=@A WHERE type=1; COMMIT;
      With START TRANSACTION, autocommit remains
      disabled until you end the transaction with
      COMMIT or ROLLBACK. The
      autocommit mode then reverts to its previous state.
    
      START TRANSACTION permits several modifiers
      that control transaction characteristics. To specify multiple
      modifiers, separate them by commas.
          The WITH CONSISTENT SNAPSHOT modifier
          starts a
          consistent
          read for storage engines that are capable of it. This
          applies only to InnoDB. The effect is the
          same as issuing a START TRANSACTION
          followed by a SELECT from any
          InnoDB table. See
          Section 14.2.2.2, “Consistent Nonlocking Reads”. The
          WITH CONSISTENT SNAPSHOT modifier does not
          change the current transaction
          isolation level,
          so it provides a consistent snapshot only if the current
          isolation level is one that permits a consistent read. The
          only isolation level that permits a consistent read is
          REPEATABLE READ. For all
          other isolation levels, the WITH CONSISTENT
          SNAPSHOT clause is ignored.
        
          The READ WRITE and READ
          ONLY modifiers set the transaction access mode. They
          permit or prohibit changes to tables used in the transaction.
          The READ ONLY restriction prevents the
          transaction from modifying or locking both transactional and
          nontransactional tables that are visible to other
          transactions; the transaction can still modify or lock
          temporary tables. These modifiers are available as of MySQL
          5.6.5.
        
          MySQL enables extra optimizations for queries on
          InnoDB tables when the transaction is known
          to be read-only. Specifying READ ONLY
          ensures these optimizations are applied in cases where the
          read-only status cannot be determined automatically. See
          Section 8.5.3, “Optimizing InnoDB Read-Only Transactions” for more
          information.
        
          If no access mode is specified, the default mode applies.
          Unless the default has been changed, it is read/write. It is
          not permitted to specify both READ WRITE
          and READ ONLY in the same statement.
        
          In read-only mode, it remains possible to change tables
          created with the TEMPORARY keyword using
          DML statements. Changes made with DDL statements are not
          permitted, just as with permanent tables.
        
For additional information about transaction access mode, including ways to change the default mode, see Section 13.3.6, “SET TRANSACTION Syntax”.
          If the read_only system
          variable is enabled, explicitly starting a transaction with
          START TRANSACTION READ WRITE requires the
          SUPER privilege.
        Many APIs used for writing MySQL client applications (such as
        JDBC) provide their own methods for starting transactions that
        can (and sometimes should) be used instead of sending a
        START TRANSACTION statement from the client.
        See Chapter 23, Connectors and APIs, or the documentation for
        your API, for more information.
To disable autocommit mode explicitly, use the following statement:
SET autocommit=0;
      After disabling autocommit mode by setting the
      autocommit variable to zero,
      changes to transaction-safe tables (such as those for
      InnoDB or
      NDB) are not made permanent
      immediately. You must use COMMIT to
      store your changes to disk or ROLLBACK to
      ignore the changes.
    
      autocommit is a session variable
      and must be set for each session. To disable autocommit mode for
      each new connection, see the description of the
      autocommit system variable at
      Section 5.1.4, “Server System Variables”.
    
      BEGIN and BEGIN WORK are
      supported as aliases of START TRANSACTION for
      initiating a transaction. START TRANSACTION is
      standard SQL syntax, is the recommended way to start an ad-hoc
      transaction, and permits modifiers that BEGIN
      does not.
    
      The BEGIN statement differs from the use of the
      BEGIN keyword that starts a
      BEGIN ... END
      compound statement. The latter does not begin a transaction. See
      Section 13.6.1, “BEGIN ... END Compound-Statement Syntax”.
        Within all stored programs (stored procedures and functions,
        triggers, and events), the parser treats BEGIN
        [WORK] as the beginning of a
        BEGIN ...
        END block. Begin a transaction in this context with
        START
        TRANSACTION instead.
      The optional WORK keyword is supported for
      COMMIT and ROLLBACK, as are
      the CHAIN and RELEASE
      clauses. CHAIN and RELEASE
      can be used for additional control over transaction completion.
      The value of the completion_type
      system variable determines the default completion behavior. See
      Section 5.1.4, “Server System Variables”.
    
      The AND CHAIN clause causes a new transaction
      to begin as soon as the current one ends, and the new transaction
      has the same isolation level as the just-terminated transaction.
      The RELEASE clause causes the server to
      disconnect the current client session after terminating the
      current transaction. Including the NO keyword
      suppresses CHAIN or RELEASE
      completion, which can be useful if the
      completion_type system variable
      is set to cause chaining or release completion by default.
    
Beginning a transaction causes any pending transaction to be committed. See Section 13.3.3, “Statements That Cause an Implicit Commit”, for more information.
      Beginning a transaction also causes table locks acquired with
      LOCK TABLES to be released, as
      though you had executed
      UNLOCK
      TABLES. Beginning a transaction does not release a
      global read lock acquired with
      FLUSH TABLES WITH READ
      LOCK.
    
For best results, transactions should be performed using only tables managed by a single transaction-safe storage engine. Otherwise, the following problems can occur:
          If you use tables from more than one transaction-safe storage
          engine (such as InnoDB), and the
          transaction isolation level is not
          SERIALIZABLE, it is
          possible that when one transaction commits, another ongoing
          transaction that uses the same tables will see only some of
          the changes made by the first transaction. That is, the
          atomicity of transactions is not guaranteed with mixed engines
          and inconsistencies can result. (If mixed-engine transactions
          are infrequent, you can use
          SET
          TRANSACTION ISOLATION LEVEL to set the isolation
          level to SERIALIZABLE on a
          per-transaction basis as necessary.)
        
If you use tables that are not transaction-safe within a transaction, changes to those tables are stored at once, regardless of the status of autocommit mode.
          If you issue a
          ROLLBACK
          statement after updating a nontransactional table within a
          transaction, an
          ER_WARNING_NOT_COMPLETE_ROLLBACK
          warning occurs. Changes to transaction-safe tables are rolled
          back, but not changes to nontransaction-safe tables.
      Each transaction is stored in the binary log in one chunk, upon
      COMMIT. Transactions that are
      rolled back are not logged.
      (Exception: Modifications to
      nontransactional tables cannot be rolled back. If a transaction
      that is rolled back includes modifications to nontransactional
      tables, the entire transaction is logged with a
      ROLLBACK
      statement at the end to ensure that modifications to the
      nontransactional tables are replicated.) See
      Section 5.2.4, “The Binary Log”.
    
      You can change the isolation level or access mode for transactions
      with the SET TRANSACTION statement.
      See Section 13.3.6, “SET TRANSACTION Syntax”.
    
      Rolling back can be a slow operation that may occur implicitly
      without the user having explicitly asked for it (for example, when
      an error occurs). Because of this, SHOW
      PROCESSLIST displays Rolling back in
      the State column for the session, not only for
      explicit rollbacks performed with the
      ROLLBACK
      statement but also for implicit rollbacks.
        In MySQL 5.6, BEGIN,
        COMMIT, and ROLLBACK are
        not affected by --replicate-do-db
        or --replicate-ignore-db rules.
Some statements cannot be rolled back. In general, these include data definition language (DDL) statements, such as those that create or drop databases, those that create, drop, or alter tables or stored routines.
      You should design your transactions not to include such
      statements. If you issue a statement early in a transaction that
      cannot be rolled back, and then another statement later fails, the
      full effect of the transaction cannot be rolled back in such cases
      by issuing a
      ROLLBACK
      statement.
      The statements listed in this section (and any synonyms for them)
      implicitly end any transaction active in the current session, as
      if you had done a COMMIT before
      executing the statement. As of MySQL 5.5.3, most of these
      statements also cause an implicit commit after executing; for
      additional details, see the end of this section.
          Data definition language (DDL)
          statements that define or modify database objects.
          ALTER DATABASE ... UPGRADE DATA DIRECTORY
          NAME, ALTER EVENT,
          ALTER PROCEDURE,
          ALTER SERVER,
          ALTER TABLE,
          ALTER VIEW,
          CREATE DATABASE,
          CREATE EVENT,
          CREATE INDEX,
          CREATE PROCEDURE,
          CREATE SERVER,
          CREATE TABLE,
          CREATE TRIGGER,
          CREATE VIEW,
          DROP DATABASE,
          DROP EVENT,
          DROP INDEX,
          DROP PROCEDURE,
          DROP SERVER,
          DROP TABLE,
          DROP TRIGGER,
          DROP VIEW,
          RENAME TABLE,
          TRUNCATE TABLE.
        
          ALTER FUNCTION,
          CREATE FUNCTION and
          DROP FUNCTION also cause an
          implicit commit when used with stored functions, but not with
          UDFs. (ALTER FUNCTION can only
          be used with stored functions.)
        
          CREATE TABLE and
          DROP TABLE statements do not
          commit a transaction if the TEMPORARY
          keyword is used. (This does not apply to other operations on
          temporary tables such as ALTER
          TABLE and CREATE
          INDEX, which do cause a commit.) However, although
          no implicit commit occurs, neither can the statement be rolled
          back, which means that the use of such statements causes
          transactional atomicity to be violated. For example, if you
          use CREATE
          TEMPORARY TABLE and then roll back the transaction,
          the table remains in existence.
        
          The CREATE TABLE statement in
          InnoDB is processed as a single
          transaction. This means that a
          ROLLBACK
          from the user does not undo CREATE
          TABLE statements the user made during that
          transaction.
        
          CREATE TABLE ...
          SELECT causes an implicit commit before and after
          the statement is executed when you are creating nontemporary
          tables. (No commit occurs for CREATE TEMPORARY TABLE
          ... SELECT.) This is to prevent an issue during
          replication where the table could be created on the master
          after a rollback, but fail to be recorded in the binary log,
          and therefore not replicated to the slave. For more
          information, see Bug #22865.
        
          Statements that implicitly use or modify
          tables in the mysql database.
          ALTER USER,
          CREATE USER,
          DROP USER,
          GRANT,
          RENAME USER,
          REVOKE,
          SET PASSWORD.
        
          Transaction-control and locking
          statements.
          BEGIN,
          LOCK TABLES, SET
          autocommit = 1 (if the value is not already 1),
          START
          TRANSACTION,
          UNLOCK
          TABLES.
        
          UNLOCK
          TABLES commits a transaction only if any tables
          currently have been locked with LOCK
          TABLES to acquire nontransactional table locks. A
          commit does not occur for
          UNLOCK
          TABLES following
          FLUSH TABLES WITH READ
          LOCK because the latter statement does not acquire
          table-level locks.
        
          Transactions cannot be nested. This is a consequence of the
          implicit commit performed for any current transaction when you
          issue a START
          TRANSACTION statement or one of its synonyms.
        
          Statements that cause an implicit commit cannot be used in an
          XA transaction while the transaction is in an
          ACTIVE state.
        
          The BEGIN
          statement differs from the use of the BEGIN
          keyword that starts a
          BEGIN ...
          END compound statement. The latter does not cause an
          implicit commit. See Section 13.6.1, “BEGIN ... END Compound-Statement Syntax”.
        
          Data loading statements.
          LOAD DATA
          INFILE.
          LOAD DATA
          INFILE causes an implicit commit only for tables
          using the NDB storage engine. For
          more information, see Bug #11151.
        
          Administrative statements.
          ANALYZE TABLE,
          CACHE INDEX,
          CHECK TABLE,
          LOAD INDEX INTO
          CACHE, OPTIMIZE
          TABLE, REPAIR TABLE.
        
          Replication control
          statements. Beginning with MySQL 5.6.7:
          START SLAVE,
          STOP SLAVE,
          RESET SLAVE,
          CHANGE MASTER TO. (Bug
          #13858841)
As of MySQL 5.5.3, most statements that previously caused an implicit commit before executing also do so after executing. The intent is to handle each such statement in its own special transaction because it cannot be rolled back anyway. The following list provides additional details pertaining to this change:
          The CREATE TABLE variants
          (CREATE TABLE for
          InnoDB tables and
          CREATE TABLE ...
          SELECT) that previously were special cases no longer
          are so because CREATE TABLE
          uniformly causes an implicit commit before and after
          executing.
        
Transaction-control and locking statements behave as before.
SAVEPOINTidentifierROLLBACK [WORK] TO [SAVEPOINT]identifierRELEASE SAVEPOINTidentifier
      InnoDB supports the SQL statements
      SAVEPOINT,
      ROLLBACK TO
      SAVEPOINT,
      RELEASE
      SAVEPOINT and the optional WORK
      keyword for
      ROLLBACK.
    
      The SAVEPOINT statement sets a
      named transaction savepoint with a name of
      identifier. If the current transaction
      has a savepoint with the same name, the old savepoint is deleted
      and a new one is set.
    
      The ROLLBACK TO
      SAVEPOINT statement rolls back a transaction to the
      named savepoint without terminating the transaction. Modifications
      that the current transaction made to rows after the savepoint was
      set are undone in the rollback, but InnoDB does
      not release the row locks that were stored in
      memory after the savepoint. (For a new inserted row, the lock
      information is carried by the transaction ID stored in the row;
      the lock is not separately stored in memory. In this case, the row
      lock is released in the undo.) Savepoints that were set at a later
      time than the named savepoint are deleted.
    
      If the ROLLBACK TO
      SAVEPOINT statement returns the following error, it
      means that no savepoint with the specified name exists:
    
ERROR 1305 (42000): SAVEPOINT identifier does not exist
      The RELEASE
      SAVEPOINT statement removes the named savepoint from the
      set of savepoints of the current transaction. No commit or
      rollback occurs. It is an error if the savepoint does not exist.
    
      All savepoints of the current transaction are deleted if you
      execute a COMMIT, or a
      ROLLBACK that
      does not name a savepoint.
    
A new savepoint level is created when a stored function is invoked or a trigger is activated. The savepoints on previous levels become unavailable and thus do not conflict with savepoints on the new level. When the function or trigger terminates, any savepoints it created are released and the previous savepoint level is restored.
LOCK TABLES
    tbl_name [[AS] alias] lock_type
    [, tbl_name [[AS] alias] lock_type] ...
lock_type:
    READ [LOCAL]
  | [LOW_PRIORITY] WRITE
UNLOCK TABLES
MySQL enables client sessions to acquire table locks explicitly for the purpose of cooperating with other sessions for access to tables, or to prevent other sessions from modifying tables during periods when a session requires exclusive access to them. A session can acquire or release locks only for itself. One session cannot acquire locks for another session or release locks held by another session.
Locks may be used to emulate transactions or to get more speed when updating tables. This is explained in more detail later in this section.
      LOCK TABLES explicitly acquires
      table locks for the current client session. Table locks can be
      acquired for base tables or views. You must have the
      LOCK TABLES privilege, and the
      SELECT privilege for each object to
      be locked.
    
      For view locking, LOCK TABLES adds
      all base tables used in the view to the set of tables to be locked
      and locks them automatically. If you lock a table explicitly with
      LOCK TABLES, any tables used in
      triggers are also locked implicitly, as described in
      Section 13.3.5.2, “LOCK TABLES and Triggers”.
    
      UNLOCK
      TABLES explicitly releases any table locks held by the
      current session. LOCK TABLES
      implicitly releases any table locks held by the current session
      before acquiring new locks.
    
      Another use for
      UNLOCK
      TABLES is to release the global read lock acquired with
      the FLUSH TABLES WITH READ
      LOCK statement, which enables you to lock all tables in
      all databases. See Section 13.7.6.3, “FLUSH Syntax”. (This is a very
      convenient way to get backups if you have a file system such as
      Veritas that can take snapshots in time.)
    
      A table lock only protects against inappropriate reads or writes
      by other sessions. A session holding a WRITE
      lock can perform table-level operations such as
      DROP TABLE or
      TRUNCATE TABLE. For sessions
      holding a READ lock, DROP
      TABLE and TRUNCATE TABLE
      operations are not permitted. TRUNCATE
      TABLE operations are not transaction-safe, so an error
      occurs if the session attempts one during an active transaction or
      while holding a READ lock.
    
      The following discussion applies only to
      non-TEMPORARY tables. LOCK
      TABLES is permitted (but ignored) for a
      TEMPORARY table. The table can be accessed
      freely by the session within which it was created, regardless of
      what other locking may be in effect. No lock is necessary because
      no other session can see the table.
    
      For information about other conditions on the use of
      LOCK TABLES and statements that
      cannot be used while LOCK TABLES is
      in effect, see Section 13.3.5.3, “Table-Locking Restrictions and Conditions”
    
Rules for Lock Acquisition
      To acquire table locks within the current session, use the
      LOCK TABLES statement. The
      following lock types are available:
    
      READ [LOCAL] lock:
The session that holds the lock can read the table (but not write it).
          Multiple sessions can acquire a READ lock
          for the table at the same time.
        
          Other sessions can read the table without explicitly acquiring
          a READ lock.
        
          The LOCAL modifier enables nonconflicting
          INSERT statements (concurrent
          inserts) by other sessions to execute while the lock is held.
          (See Section 8.11.3, “Concurrent Inserts”.) However,
          READ LOCAL cannot be used if you are going
          to manipulate the database using processes external to the
          server while you hold the lock. For InnoDB
          tables, READ LOCAL is the same as
          READ.
      [LOW_PRIORITY] WRITE lock:
The session that holds the lock can read and write the table.
Only the session that holds the lock can access the table. No other session can access it until the lock is released.
          Lock requests for the table by other sessions block while the
          WRITE lock is held.
        
          The LOW_PRIORITY modifier has no effect. In
          previous versions of MySQL, it affected locking behavior, but
          this is no longer true. As of MySQL 5.6.5, it is deprecated
          and its use produces a warning. Use WRITE
          without LOW_PRIORITY instead.
      If the LOCK TABLES statement must
      wait due to locks held by other sessions on any of the tables, it
      blocks until all locks can be acquired.
    
      A session that requires locks must acquire all the locks that it
      needs in a single LOCK TABLES
      statement. While the locks thus obtained are held, the session can
      access only the locked tables. For example, in the following
      sequence of statements, an error occurs for the attempt to access
      t2 because it was not locked in the
      LOCK TABLES statement:
    
mysql>LOCK TABLES t1 READ;mysql>SELECT COUNT(*) FROM t1;+----------+ | COUNT(*) | +----------+ | 3 | +----------+ mysql>SELECT COUNT(*) FROM t2;ERROR 1100 (HY000): Table 't2' was not locked with LOCK TABLES
      Tables in the INFORMATION_SCHEMA database are
      an exception. They can be accessed without being locked explicitly
      even while a session holds table locks obtained with
      LOCK TABLES.
    
You cannot refer to a locked table multiple times in a single query using the same name. Use aliases instead, and obtain a separate lock for the table and each alias:
mysql>LOCK TABLE t WRITE, t AS t1 READ;mysql>INSERT INTO t SELECT * FROM t;ERROR 1100: Table 't' was not locked with LOCK TABLES mysql>INSERT INTO t SELECT * FROM t AS t1;
      The error occurs for the first
      INSERT because there are two
      references to the same name for a locked table. The second
      INSERT succeeds because the
      references to the table use different names.
    
If your statements refer to a table by means of an alias, you must lock the table using that same alias. It does not work to lock the table without specifying the alias:
mysql>LOCK TABLE t READ;mysql>SELECT * FROM t AS myalias;ERROR 1100: Table 'myalias' was not locked with LOCK TABLES
Conversely, if you lock a table using an alias, you must refer to it in your statements using that alias:
mysql>LOCK TABLE t AS myalias READ;mysql>SELECT * FROM t;ERROR 1100: Table 't' was not locked with LOCK TABLES mysql>SELECT * FROM t AS myalias;
      WRITE locks normally have higher priority than
      READ locks to ensure that updates are processed
      as soon as possible. This means that if one session obtains a
      READ lock and then another session requests a
      WRITE lock, subsequent READ
      lock requests wait until the session that requested the
      WRITE lock has obtained the lock and released
      it.
    
      LOCK TABLES acquires locks as
      follows:
Sort all tables to be locked in an internally defined order. From the user standpoint, this order is undefined.
If a table is to be locked with a read and a write lock, put the write lock request before the read lock request.
Lock one table at a time until the session gets all locks.
This policy ensures that table locking is deadlock free.
        LOCK TABLES or UNLOCK
        TABLES, when applied to a partitioned table, always
        locks or unlocks the entire table; these statements do not
        support partition lock pruning. See
        Section 19.6.4, “Partitioning and Locking”.
Rules for Lock Release
When the table locks held by a session are released, they are all released at the same time. A session can release its locks explicitly, or locks may be released implicitly under certain conditions.
          A session can release its locks explicitly with
          UNLOCK
          TABLES.
        
          If a session issues a LOCK
          TABLES statement to acquire a lock while already
          holding locks, its existing locks are released implicitly
          before the new locks are granted.
        
          If a session begins a transaction (for example, with
          START
          TRANSACTION), an implicit
          UNLOCK
          TABLES is performed, which causes existing locks to
          be released. (For additional information about the interaction
          between table locking and transactions, see
          Section 13.3.5.1, “Interaction of Table Locking and Transactions”.)
If the connection for a client session terminates, whether normally or abnormally, the server implicitly releases all table locks held by the session (transactional and nontransactional). If the client reconnects, the locks will no longer be in effect. In addition, if the client had an active transaction, the server rolls back the transaction upon disconnect, and if reconnect occurs, the new session begins with autocommit enabled. For this reason, clients may wish to disable auto-reconnect. With auto-reconnect in effect, the client is not notified if reconnect occurs but any table locks or current transaction will have been lost. With auto-reconnect disabled, if the connection drops, an error occurs for the next statement issued. The client can detect the error and take appropriate action such as reacquiring the locks or redoing the transaction. See Section 23.8.16, “Controlling Automatic Reconnection Behavior”.
        If you use ALTER TABLE on a
        locked table, it may become unlocked. For example, if you
        attempt a second ALTER TABLE
        operation, the result may be an error Table
        '. To handle this, lock the table again prior to
        the second alteration. See also
        Section B.5.7.1, “Problems with ALTER TABLE”.
tbl_name' was not locked with LOCK
        TABLES
        LOCK TABLES and
        UNLOCK
        TABLES interact with the use of transactions as
        follows:
            LOCK TABLES is not
            transaction-safe and implicitly commits any active
            transaction before attempting to lock the tables.
          
            UNLOCK
            TABLES implicitly commits any active transaction,
            but only if LOCK TABLES has
            been used to acquire table locks. For example, in the
            following set of statements,
            UNLOCK
            TABLES releases the global read lock but does not
            commit the transaction because no table locks are in effect:
          
FLUSH TABLES WITH READ LOCK; START TRANSACTION; SELECT ... ; UNLOCK TABLES;
            Beginning a transaction (for example, with
            START
            TRANSACTION) implicitly commits any current
            transaction and releases existing table locks.
          
            FLUSH TABLES WITH
            READ LOCK acquires a global read lock and not
            table locks, so it is not subject to the same behavior as
            LOCK TABLES and
            UNLOCK
            TABLES with respect to table locking and implicit
            commits. For example,
            START
            TRANSACTION does not release the global read lock.
            See Section 13.7.6.3, “FLUSH Syntax”.
          
Other statements that implicitly cause transactions to be committed do not release existing table locks. For a list of such statements, see Section 13.3.3, “Statements That Cause an Implicit Commit”.
            The correct way to use LOCK
            TABLES and
            UNLOCK
            TABLES with transactional tables, such as
            InnoDB tables, is to begin a transaction
            with SET autocommit = 0 (not
            START
            TRANSACTION) followed by LOCK
            TABLES, and to not call
            UNLOCK
            TABLES until you commit the transaction
            explicitly. For example, if you need to write to table
            t1 and read from table
            t2, you can do this:
          
SET autocommit=0;
LOCK TABLES t1 WRITE, t2 READ, ...;
... do something with tables t1 and t2 here ...
COMMIT;
UNLOCK TABLES;
            When you call LOCK TABLES,
            InnoDB internally takes its own table
            lock, and MySQL takes its own table lock.
            InnoDB releases its internal table lock
            at the next commit, but for MySQL to release its table lock,
            you have to call
            UNLOCK
            TABLES. You should not have
            autocommit = 1, because
            then InnoDB releases its internal table
            lock immediately after the call of LOCK
            TABLES, and deadlocks can very easily happen.
            InnoDB does not acquire the internal
            table lock at all if autocommit =
            1, to help old applications avoid unnecessary
            deadlocks.
          
            ROLLBACK
            does not release table locks.
        If you lock a table explicitly with LOCK
        TABLES, any tables used in triggers are also locked
        implicitly:
            The locks are taken as the same time as those acquired
            explicitly with the LOCK
            TABLES statement.
          
The lock on a table used in a trigger depends on whether the table is used only for reading. If so, a read lock suffices. Otherwise, a write lock is used.
            If a table is locked explicitly for reading with
            LOCK TABLES, but needs to be
            locked for writing because it might be modified within a
            trigger, a write lock is taken rather than a read lock.
            (That is, an implicit write lock needed due to the table's
            appearance within a trigger causes an explicit read lock
            request for the table to be converted to a write lock
            request.)
        Suppose that you lock two tables, t1 and
        t2, using this statement:
      
LOCK TABLES t1 WRITE, t2 READ;
        If t1 or t2 have any
        triggers, tables used within the triggers will also be locked.
        Suppose that t1 has a trigger defined like
        this:
      
CREATE TRIGGER t1_a_ins AFTER INSERT ON t1 FOR EACH ROW
BEGIN
  UPDATE t4 SET count = count+1
      WHERE id = NEW.id AND EXISTS (SELECT a FROM t3);
  INSERT INTO t2 VALUES(1, 2);
END;
        The result of the LOCK TABLES
        statement is that t1 and
        t2 are locked because they appear in the
        statement, and t3 and t4
        are locked because they are used within the trigger:
            t1 is locked for writing per the
            WRITE lock request.
          
            t2 is locked for writing, even though the
            request is for a READ lock. This occurs
            because t2 is inserted into within the
            trigger, so the READ request is converted
            to a WRITE request.
          
            t3 is locked for reading because it is
            only read from within the trigger.
          
            t4 is locked for writing because it might
            be updated within the trigger.
        You can safely use KILL to
        terminate a session that is waiting for a table lock. See
        Section 13.7.6.4, “KILL Syntax”.
      
        Do not lock any tables that you are using
        with INSERT DELAYED. An
        INSERT DELAYED in this case
        results in an error because the insert must be handled by a
        separate thread, not by the session which holds the lock.
      
        LOCK TABLES and
        UNLOCK
        TABLES cannot be used within stored programs.
      
        Tables in the performance_schema database
        cannot be locked with LOCK
        TABLES, except the
        setup_ tables.
      xxx
        The following statements are prohibited while a
        LOCK TABLES statement is in
        effect: CREATE TABLE,
        CREATE TABLE ...
        LIKE, CREATE VIEW,
        DROP VIEW, and DDL statements on
        stored functions and procedures and events.
      
        For some operations, system tables in the
        mysql database must be accessed. For example,
        the HELP statement requires the
        contents of the server-side help tables, and
        CONVERT_TZ() might need to read
        the time zone tables. The server implicitly locks the system
        tables for reading as necessary so that you need not lock them
        explicitly. These tables are treated as just described:
      
mysql.help_category mysql.help_keyword mysql.help_relation mysql.help_topic mysql.proc mysql.time_zone mysql.time_zone_leap_second mysql.time_zone_name mysql.time_zone_transition mysql.time_zone_transition_type
        If you want to explicitly place a WRITE lock
        on any of those tables with a LOCK
        TABLES statement, the table must be the only one
        locked; no other table can be locked with the same statement.
      
        Normally, you do not need to lock tables, because all single
        UPDATE statements are atomic; no
        other session can interfere with any other currently executing
        SQL statement. However, there are a few cases when locking
        tables may provide an advantage:
            If you are going to run many operations on a set of
            MyISAM tables, it is much faster to lock
            the tables you are going to use. Locking
            MyISAM tables speeds up inserting,
            updating, or deleting on them because MySQL does not flush
            the key cache for the locked tables until
            UNLOCK
            TABLES is called. Normally, the key cache is
            flushed after each SQL statement.
          
            The downside to locking the tables is that no session can
            update a READ-locked table (including the
            one holding the lock) and no session can access a
            WRITE-locked table other than the one
            holding the lock.
          
            If you are using tables for a nontransactional storage
            engine, you must use LOCK
            TABLES if you want to ensure that no other session
            modifies the tables between a
            SELECT and an
            UPDATE. The example shown
            here requires LOCK TABLES to
            execute safely:
          
LOCK TABLES trans READ, customer WRITE; SELECT SUM(value) FROM trans WHERE customer_id=some_id; UPDATE customer SET total_value=sum_from_previous_statementWHERE customer_id=some_id; UNLOCK TABLES;
            Without LOCK TABLES, it is
            possible that another session might insert a new row in the
            trans table between execution of the
            SELECT and
            UPDATE statements.
        You can avoid using LOCK TABLES
        in many cases by using relative updates (UPDATE
        customer SET
        )
        or the value=value+new_valueLAST_INSERT_ID() function.
      
        You can also avoid locking tables in some cases by using the
        user-level advisory lock functions
        GET_LOCK() and
        RELEASE_LOCK(). These locks are
        saved in a hash table in the server and implemented with
        pthread_mutex_lock() and
        pthread_mutex_unlock() for high speed. See
        Section 12.18, “Miscellaneous Functions”.
      
See Section 8.11.1, “Internal Locking Methods”, for more information on locking policy.
SET [GLOBAL | SESSION] TRANSACTION
    transaction_characteristic [, transaction_characteristic] ...
transaction_characteristic:
    ISOLATION LEVEL level
  | READ WRITE
  | READ ONLY
level:
     REPEATABLE READ
   | READ COMMITTED
   | READ UNCOMMITTED
   | SERIALIZABLE
      This statement specifies
      transaction
      characteristics. It takes a list of one or more characteristic
      values separated by commas. These characteristics set the
      transaction isolation
      level or access mode. The isolation level is used for
      operations on InnoDB tables. The
      access mode may be specified as of MySQL 5.6.5 and indicates
      whether transactions operate in read/write or read-only mode.
    
      In addition, SET TRANSACTION can
      include an optional GLOBAL or
      SESSION keyword to indicate the scope of the
      statement.
You can set transaction characteristics globally, for the current session, or for the next transaction:
          With the GLOBAL keyword, the statement
          applies globally for all subsequent sessions. Existing
          sessions are unaffected.
        
          With the SESSION keyword, the statement
          applies to all subsequent transactions performed within the
          current session.
        
          Without any SESSION or
          GLOBAL keyword, the statement applies to
          the next (not started) transaction performed within the
          current session.
      A global change to transaction characteristics requires the
      SUPER privilege. Any session is
      free to change its session characteristics (even in the middle of
      a transaction), or the characteristics for its next transaction.
    
      SET TRANSACTION without
      GLOBAL or SESSION is not
      permitted while there is an active transaction:
    
mysql>START TRANSACTION;Query OK, 0 rows affected (0.02 sec) mysql>SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;ERROR 1568 (25001): Transaction characteristics can't be changed while a transaction is in progress
      To set the global default isolation level at server startup, use
      the
      --transaction-isolation=
      option to mysqld on the command line or in an
      option file. Values of levellevel for this
      option use dashes rather than spaces, so the permissible values
      are READ-UNCOMMITTED,
      READ-COMMITTED,
      REPEATABLE-READ, or
      SERIALIZABLE. For example, to
      set the default isolation level to
      REPEATABLE READ, use these
      lines in the [mysqld] section of an option
      file:
    
[mysqld] transaction-isolation = REPEATABLE-READ
      It is possible to check or set the global and session transaction
      isolation levels at runtime by using the
      tx_isolation system variable:
    
SELECT @@GLOBAL.tx_isolation, @@tx_isolation; SET GLOBAL tx_isolation='REPEATABLE-READ'; SET SESSION tx_isolation='SERIALIZABLE';
      Similarly, to set the transaction access mode at server startup or
      at runtime, use the
      --transaction-read-only option or
      tx_read_only system variable. By
      default, these are OFF (the mode is read/write)
      but can be set to ON for a default mode of read
      only.
    
      Setting the global or session value of
      tx_isolation or
      tx_read_only is equivalent to
      setting the isolation level or access mode with
      SET GLOBAL
      TRANSACTION or
      SET SESSION
      TRANSACTION.
      InnoDB supports each of the transaction
      isolation levels described here using different
      locking strategies. You can
      enforce a high degree of consistency with the default
      REPEATABLE READ level, for
      operations on crucial data where
      ACID compliance is important. Or
      you can relax the consistency rules with
      READ COMMITTED or even
      READ UNCOMMITTED, in situations
      such as bulk reporting where precise consistency and repeatable
      results are less important than minimizing the amount of overhead
      for locking. SERIALIZABLE
      enforces even stricter rules than
      REPEATABLE READ, and is used
      mainly in specialized situations, such as with
      XA transactions and for
      troubleshooting issues with concurrency and
      deadlocks.
    
      For full information about how these isolation levels work with
      InnoDB transactions, see
      Section 14.2.2, “The InnoDB Transaction Model and Locking”. In particular, for
      additional information about InnoDB
      record-level locks and how it uses them to execute various types
      of statements, see Section 14.2.2.4, “InnoDB Record, Gap, and Next-Key Locks” and
      Section 14.2.2.6, “Locks Set by Different SQL Statements in InnoDB”.
    
The following list describes how MySQL supports the different transaction levels. The list goes from the most commonly used level to the least used.
          This is the default isolation level for
          InnoDB. For
          consistent reads,
          there is an important difference from the
          READ COMMITTED isolation
          level: All consistent reads within the same transaction read
          the snapshot established by the first read. This convention
          means that if you issue several plain (nonlocking)
          SELECT statements within the
          same transaction, these SELECT
          statements are consistent also with respect to each other. See
          Section 14.2.2.2, “Consistent Nonlocking Reads”.
        
          For locking reads
          (SELECT with FOR
          UPDATE or LOCK IN SHARE MODE),
          UPDATE, and
          DELETE statements, locking
          depends on whether the statement uses a unique index with a
          unique search condition, or a range-type search condition. For
          a unique index with a unique search condition,
          InnoDB locks only the index record found,
          not the gap before it. For
          other search conditions, InnoDB locks the
          index range scanned, using gap
          locks or next-key
          locks to block insertions by other sessions into the
          gaps covered by the range.
        
A somewhat Oracle-like isolation level with respect to consistent (nonlocking) reads: Each consistent read, even within the same transaction, sets and reads its own fresh snapshot. See Section 14.2.2.2, “Consistent Nonlocking Reads”.
          For locking reads
          (SELECT with FOR
          UPDATE or LOCK IN SHARE MODE),
          UPDATE statements, and
          DELETE statements,
          InnoDB locks only index records, not the
          gaps before them, and thus
          permits the free insertion of new records next to locked
          records.
            In MySQL 5.6, when READ
            COMMITTED isolation level is used, or the
            deprecated
            innodb_locks_unsafe_for_binlog
            system variable is enabled, there is no
            InnoDB gap locking except for foreign-key
            constraint checking and duplicate-key checking. Also, record
            locks for nonmatching rows are released after MySQL has
            evaluated the WHERE condition.
          
            If you use READ COMMITTED or enable
            innodb_locks_unsafe_for_binlog,
            you must use row-based binary logging.
          SELECT statements are performed
          in a nonlocking fashion, but a possible earlier version of a
          row might be used. Thus, using this isolation level, such
          reads are not consistent. This is also called a
          dirty read. Otherwise,
          this isolation level works like READ
          COMMITTED.
        
          This level is like REPEATABLE
          READ, but InnoDB implicitly
          converts all plain SELECT
          statements to SELECT
          ... LOCK IN SHARE MODE if
          autocommitis disabled. If
          autocommit is enabled, the
          SELECT is its own transaction.
          It therefore is known to be read only and can be serialized if
          performed as a consistent (nonlocking) read and need not block
          for other transactions. (To force a plain
          SELECT to block if other
          transactions have modified the selected rows, disable
          autocommit.)
      As of MySQL 5.6.5, the transaction access mode may be specified
      with SET TRANSACTION. By default, a
      transaction takes place in read/write mode, with both reads and
      writes permitted to tables used in the transaction. This mode may
      be specified explicitly using an access mode of READ
      WRITE.
    
      If the transaction access mode is set to READ
      ONLY, changes to tables are prohibited. This may enable
      storage engines to make performance improvements that are possible
      when writes are not permitted.
    
      It is not permitted to specify both READ WRITE
      and READ ONLY in the same statement.
    
      In read-only mode, it remains possible to change tables created
      with the TEMPORARY keyword using DML
      statements. Changes made with DDL statements are not permitted,
      just as with permanent tables.
    
      The READ WRITE and READ ONLY
      access modes also may be specified for an individual transaction
      using the START
      TRANSACTION statement.
      Support for XA transactions is
      available for the InnoDB storage
      engine. The MySQL XA implementation is based on the X/Open CAE
      document Distributed Transaction Processing: The XA
      Specification. This document is published by The Open
      Group and available at
      http://www.opengroup.org/public/pubs/catalog/c193.htm.
      Limitations of the current XA implementation are described in
      Section D.6, “Restrictions on XA Transactions”.
    
      On the client side, there are no special requirements. The XA
      interface to a MySQL server consists of SQL statements that begin
      with the XA keyword. MySQL client programs must
      be able to send SQL statements and to understand the semantics of
      the XA statement interface. They do not need be linked against a
      recent client library. Older client libraries also will work.
    
Currently, among the MySQL Connectors, MySQL Connector/J 5.0.0 and higher supports XA directly, by means of a class interface that handles the XA SQL statement interface for you.
XA supports distributed transactions, that is, the ability to permit multiple separate transactional resources to participate in a global transaction. Transactional resources often are RDBMSs but may be other kinds of resources.
      A global transaction involves several actions that are
      transactional in themselves, but that all must either complete
      successfully as a group, or all be rolled back as a group. In
      essence, this extends ACID properties “up a level” so
      that multiple ACID transactions can be executed in concert as
      components of a global operation that also has ACID properties.
      (However, for a distributed transaction, you must use the
      SERIALIZABLE isolation level to
      achieve ACID properties. It is enough to use
      REPEATABLE READ for a
      nondistributed transaction, but not for a distributed
      transaction.)
    
Some examples of distributed transactions:
An application may act as an integration tool that combines a messaging service with an RDBMS. The application makes sure that transactions dealing with message sending, retrieval, and processing that also involve a transactional database all happen in a global transaction. You can think of this as “transactional email.”
An application performs actions that involve different database servers, such as a MySQL server and an Oracle server (or multiple MySQL servers), where actions that involve multiple servers must happen as part of a global transaction, rather than as separate transactions local to each server.
A bank keeps account information in an RDBMS and distributes and receives money through automated teller machines (ATMs). It is necessary to ensure that ATM actions are correctly reflected in the accounts, but this cannot be done with the RDBMS alone. A global transaction manager integrates the ATM and database resources to ensure overall consistency of financial transactions.
Applications that use global transactions involve one or more Resource Managers and a Transaction Manager:
A Resource Manager (RM) provides access to transactional resources. A database server is one kind of resource manager. It must be possible to either commit or roll back transactions managed by the RM.
A Transaction Manager (TM) coordinates the transactions that are part of a global transaction. It communicates with the RMs that handle each of these transactions. The individual transactions within a global transaction are “branches” of the global transaction. Global transactions and their branches are identified by a naming scheme described later.
The MySQL implementation of XA MySQL enables a MySQL server to act as a Resource Manager that handles XA transactions within a global transaction. A client program that connects to the MySQL server acts as the Transaction Manager.
To carry out a global transaction, it is necessary to know which components are involved, and bring each component to a point when it can be committed or rolled back. Depending on what each component reports about its ability to succeed, they must all commit or roll back as an atomic group. That is, either all components must commit, or all components must roll back. To manage a global transaction, it is necessary to take into account that any component or the connecting network might fail.
The process for executing a global transaction uses two-phase commit (2PC). This takes place after the actions performed by the branches of the global transaction have been executed.
In the first phase, all branches are prepared. That is, they are told by the TM to get ready to commit. Typically, this means each RM that manages a branch records the actions for the branch in stable storage. The branches indicate whether they are able to do this, and these results are used for the second phase.
In the second phase, the TM tells the RMs whether to commit or roll back. If all branches indicated when they were prepared that they will be able to commit, all branches are told to commit. If any branch indicated when it was prepared that it will not be able to commit, all branches are told to roll back.
In some cases, a global transaction might use one-phase commit (1PC). For example, when a Transaction Manager finds that a global transaction consists of only one transactional resource (that is, a single branch), that resource can be told to prepare and commit at the same time.
To perform XA transactions in MySQL, use the following statements:
XA {START|BEGIN} xid [JOIN|RESUME]
XA END xid [SUSPEND [FOR MIGRATE]]
XA PREPARE xid
XA COMMIT xid [ONE PHASE]
XA ROLLBACK xid
XA RECOVER
        For XA
        START, the JOIN and
        RESUME clauses are not supported.
      
        For XA
        END the SUSPEND [FOR MIGRATE]
        clause is not supported.
      
        Each XA statement begins with the XA keyword,
        and most of them require an xid
        value. An xid is an XA transaction
        identifier. It indicates which transaction the statement applies
        to. xid values are supplied by the
        client, or generated by the MySQL server. An
        xid value has from one to three
        parts:
      
xid:gtrid[,bqual[,formatID]]
        gtrid is a global transaction
        identifier, bqual is a branch
        qualifier, and formatID is a number
        that identifies the format used by the
        gtrid and
        bqual values. As indicated by the
        syntax, bqual and
        formatID are optional. The default
        bqual value is ''
        if not given. The default formatID
        value is 1 if not given.
      
        gtrid and
        bqual must be string literals, each
        up to 64 bytes (not characters) long.
        gtrid and
        bqual can be specified in several
        ways. You can use a quoted string ('ab'), hex
        string (0x6162, X'ab'), or
        bit value
        (b').
      nnnn'
        formatID is an unsigned integer.
      
        The gtrid and
        bqual values are interpreted in bytes
        by the MySQL server's underlying XA support routines. However,
        while an SQL statement containing an XA statement is being
        parsed, the server works with some specific character set. To be
        safe, write gtrid and
        bqual as hex strings.
      
        xid values typically are generated by
        the Transaction Manager. Values generated by one TM must be
        different from values generated by other TMs. A given TM must be
        able to recognize its own xid values
        in a list of values returned by the
        XA
        RECOVER statement.
      
        For XA START
         starts an XA
        transaction with the given xidxid value.
        Each XA transaction must have a unique
        xid value, so the value must not
        currently be used by another XA transaction. Uniqueness is
        assessed using the gtrid and
        bqual values. All following XA
        statements for the XA transaction must be specified using the
        same xid value as that given in the
        XA
        START statement. If you use any of those statements
        but specify an xid value that does
        not correspond to some existing XA transaction, an error occurs.
      
        One or more XA transactions can be part of the same global
        transaction. All XA transactions within a given global
        transaction must use the same gtrid
        value in the xid value. For this
        reason, gtrid values must be globally
        unique so that there is no ambiguity about which global
        transaction a given XA transaction is part of. The
        bqual part of the
        xid value must be different for each
        XA transaction within a global transaction. (The requirement
        that bqual values be different is a
        limitation of the current MySQL XA implementation. It is not
        part of the XA specification.)
      
        The XA
        RECOVER statement returns information for those XA
        transactions on the MySQL server that are in the
        PREPARED state. (See
        Section 13.3.7.2, “XA Transaction States”.) The output includes a row for each
        such XA transaction on the server, regardless of which client
        started it.
      
        XA
        RECOVER output rows look like this (for an example
        xid value consisting of the parts
        'abc', 'def', and
        7):
      
mysql> XA RECOVER;
+----------+--------------+--------------+--------+
| formatID | gtrid_length | bqual_length | data   |
+----------+--------------+--------------+--------+
|        7 |            3 |            3 | abcdef |
+----------+--------------+--------------+--------+
The output columns have the following meanings:
            formatID is the
            formatID part of the transaction
            xid
          
            gtrid_length is the length in bytes of
            the gtrid part of the
            xid
          
            bqual_length is the length in bytes of
            the bqual part of the
            xid
          
            data is the concatenation of the
            gtrid and
            bqual parts of the
            xid
An XA transaction progresses through the following states:
            Use XA
            START to start an XA transaction and put it in the
            ACTIVE state.
          
            For an ACTIVE XA transaction, issue the
            SQL statements that make up the transaction, and then issue
            an XA
            END statement.
            XA
            END puts the transaction in the
            IDLE state.
          
            For an IDLE XA transaction, you can issue
            either an XA
            PREPARE statement or an XA COMMIT ... ONE
            PHASE statement:
                XA
                PREPARE puts the transaction in the
                PREPARED state. An
                XA
                RECOVER statement at this point will include
                the transaction's xid value
                in its output, because
                XA
                RECOVER lists all XA transactions that are in
                the PREPARED state.
              
                XA COMMIT ... ONE PHASE prepares and
                commits the transaction. The
                xid value will not be listed
                by XA
                RECOVER because the transaction terminates.
            For a PREPARED XA transaction, you can
            issue an XA
            COMMIT statement to commit and terminate the
            transaction, or
            XA
            ROLLBACK to roll back and terminate the
            transaction.
Here is a simple XA transaction that inserts a row into a table as part of a global transaction:
mysql>XA START 'xatest';Query OK, 0 rows affected (0.00 sec) mysql>INSERT INTO mytable (i) VALUES(10);Query OK, 1 row affected (0.04 sec) mysql>XA END 'xatest';Query OK, 0 rows affected (0.00 sec) mysql>XA PREPARE 'xatest';Query OK, 0 rows affected (0.00 sec) mysql>XA COMMIT 'xatest';Query OK, 0 rows affected (0.00 sec)
        Within the context of a given client connection, XA transactions
        and local (non-XA) transactions are mutually exclusive. For
        example, if XA
        START has been issued to begin an XA transaction, a
        local transaction cannot be started until the XA transaction has
        been committed or rolled back. Conversely, if a local
        transaction has been started with
        START
        TRANSACTION, no XA statements can be used until the
        transaction has been committed or rolled back.
      
        If an XA transaction is in the ACTIVE state,
        you cannot issue any statements that cause an implicit commit.
        That would violate the XA contract because you could not roll
        back the XA transaction. You will receive the following error if
        you try to execute such a statement:
      
ERROR 1399 (XAE07): XAER_RMFAIL: The command cannot be executed when global transaction is in the ACTIVE state
Statements to which the preceding remark applies are listed at Section 13.3.3, “Statements That Cause an Implicit Commit”.
Replication can be controlled through the SQL interface using the statements described in this section. One group of statements controls master servers, the other controls slave servers.
This section discusses statements for managing master replication servers. Section 13.4.2, “SQL Statements for Controlling Slave Servers”, discusses statements for managing slave servers.
      In addition to the statements described here, the following
      SHOW statements are used with
      master servers in replication. For information about these
      statements, see Section 13.7.5, “SHOW Syntax”.
PURGE { BINARY | MASTER } LOGS
    { TO 'log_name' | BEFORE datetime_expr }
The binary log is a set of files that contain information about data modifications made by the MySQL server. The log consists of a set of binary log files, plus an index file (see Section 5.2.4, “The Binary Log”).
        The PURGE BINARY LOGS statement
        deletes all the binary log files listed in the log index file
        prior to the specified log file name or date.
        BINARY and MASTER are
        synonyms. Deleted log files also are removed from the list
        recorded in the index file, so that the given log file becomes
        the first in the list.
      
        This statement has no effect if the server was not started with
        the --log-bin option to enable
        binary logging.
      
Examples:
PURGE BINARY LOGS TO 'mysql-bin.010'; PURGE BINARY LOGS BEFORE '2008-04-02 22:46:26';
        The BEFORE variant's
        datetime_expr argument should
        evaluate to a DATETIME value (a
        value in 'YYYY-MM-DD hh:mm:ss' format).
      
This statement is safe to run while slaves are replicating. You need not stop them. If you have an active slave that currently is reading one of the log files you are trying to delete, this statement does nothing. In MySQL 5.6.12 and later, it fails with an error in such cases. (Bug #13727933) However, if a slave is not connected and you happen to purge one of the log files it has yet to read, the slave will be unable to replicate after it reconnects.
To safely purge binary log files, follow this procedure:
            On each slave server, use SHOW SLAVE
            STATUS to check which log file it is reading.
          
            Obtain a listing of the binary log files on the master
            server with SHOW BINARY LOGS.
          
Determine the earliest log file among all the slaves. This is the target file. If all the slaves are up to date, this is the last log file on the list.
Make a backup of all the log files you are about to delete. (This step is optional, but always advisable.)
Purge all log files up to but not including the target file.
        You can also set the
        expire_logs_days system
        variable to expire binary log files automatically after a given
        number of days (see Section 5.1.4, “Server System Variables”).
        If you are using replication, you should set the variable no
        lower than the maximum number of days your slaves might lag
        behind the master.
      
        PURGE BINARY LOGS TO and PURGE
        BINARY LOGS BEFORE both fail with an error when binary
        log files listed in the .index file had
        been removed from the system by some other means (such as using
        rm on Linux). (Bug #18199, Bug #18453) To
        handle such errors, edit the .index file
        (which is a simple text file) manually to ensure that it lists
        only the binary log files that are actually present, then run
        again the PURGE BINARY LOGS
        statement that failed.
RESET MASTER
Deletes all binary log files listed in the index file, resets the binary log index file to be empty, and creates a new binary log file.
        In MySQL 5.6.5 and later, RESET MASTER also
        clears the values of the
        gtid_purged system variable
        (known as gtid_lost in MySQL
        5.6.8 and earlier) as well as the global value of the
        gtid_executed
        (gtid_done, prior to MySQL
        5.6.9) system variable (but not its session value); that is,
        executing this statement sets each of these values to an empty
        string ('').
      
This statement is intended to be used only when the master is started for the first time.
          The effects of RESET MASTER
          differ from those of PURGE BINARY
          LOGS in 2 key ways:
              RESET MASTER removes
              all binary log files that are listed
              in the index file, leaving only a single, empty binary log
              file with a numeric suffix of .000001,
              whereas the numbering is not reset by
              PURGE BINARY LOGS.
            
              RESET MASTER is
              not intended to be used while any
              replication slaves are running. The behavior of
              RESET MASTER when used
              while slaves are running is undefined (and thus
              unsupported), whereas PURGE BINARY
              LOGS may be safely used while replication slaves
              are running.
        RESET MASTER can prove useful
        when you first set up the master and the slave, so that you can
        verify the setup as follows:
Start the master and slave, and start replication (see Section 17.1.1, “How to Set Up Replication”).
Execute a few test queries on the master.
Check that the queries were replicated to the slave.
            When replication is running correctly, issue
            STOP SLAVE followed by
            RESET SLAVE on the slave,
            then verify that any unwanted data no longer exists on the
            slave.
          
            Issue RESET MASTER on the
            master to clean up the test queries.
After verifying the setup and getting rid of any unwanted and log files generated by testing, you can start the slave and begin replicating.
SET sql_log_bin = {0|1}
        The sql_log_bin variable
        controls whether logging to the binary log is done. The default
        value is 1 (do logging). To change logging for the current
        session, change the session value of this variable. The session
        user must have the SUPER
        privilege to set this variable. Set this variable to 0 for a
        session to temporarily disable binary logging while making
        changes to the master which you do not want to replicate to the
        slave.
      
        As of MySQL 5.5, sql_log_bin
        can be set as a global or session variable. Setting
        sql_log_bin globally is only
        detected when a new session is started. Any sessions previously
        running are not impacted when setting
        sql_log_bin globally.
          Incorrect use of sql_log_bin
          with a global scope means any changes made in an already
          running session are still being recorded
          to the binary log and therefore replicated. Exercise extreme
          caution using sql_log_bin
          with a global scope as the above situation could cause
          unexpected results including replication failure.
        In MySQL 5.6, it is not possible to set
        @@session.sql_log_bin within a transaction or
        subquery. (Bug #53437)
This section discusses statements for managing slave replication servers. Section 13.4.1, “SQL Statements for Controlling Master Servers”, discusses statements for managing master servers.
      In addition to the statements described here,
      SHOW SLAVE STATUS and
      SHOW RELAYLOG EVENTS are also used
      with replication slaves. For information about these statements,
      see Section 13.7.5.35, “SHOW SLAVE STATUS Syntax”, and
      Section 13.7.5.33, “SHOW RELAYLOG EVENTS Syntax”.
CHANGE MASTER TOoption[,option] ...option: MASTER_BIND = 'interface_name' | MASTER_HOST = 'host_name' | MASTER_USER = 'user_name' | MASTER_PASSWORD = 'password' | MASTER_PORT =port_num| MASTER_CONNECT_RETRY =interval| MASTER_RETRY_COUNT =count| MASTER_DELAY =interval| MASTER_HEARTBEAT_PERIOD =interval| MASTER_LOG_FILE = 'master_log_name' | MASTER_LOG_POS =master_log_pos| MASTER_AUTO_POSITION = {0|1} | RELAY_LOG_FILE = 'relay_log_name' | RELAY_LOG_POS =relay_log_pos| MASTER_SSL = {0|1} | MASTER_SSL_CA = 'ca_file_name' | MASTER_SSL_CAPATH = 'ca_directory_name' | MASTER_SSL_CERT = 'cert_file_name' | MASTER_SSL_CRL = 'crl_file_name' | MASTER_SSL_CRLPATH = 'crl_directory_name' | MASTER_SSL_KEY = 'key_file_name' | MASTER_SSL_CIPHER = 'cipher_list' | MASTER_SSL_VERIFY_SERVER_CERT = {0|1} | IGNORE_SERVER_IDS = (server_id_list)server_id_list: [server_id[,server_id] ... ]
        CHANGE MASTER TO changes the
        parameters that the slave server uses for connecting to the
        master server, for reading the master binary log, and reading
        the slave relay log. It also updates the contents of the master
        info and relay log info repositories (see
        Section 17.2.2, “Replication Relay and Status Logs”). To use
        CHANGE MASTER TO, the slave
        replication threads must be stopped (use
        STOP SLAVE if necessary). In
        MySQL 5.6.11 and later,
        gtid_next must also be set to
        AUTOMATIC (Bug #16062608).
      
Options not specified retain their value, except as indicated in the following discussion. Thus, in most cases, there is no need to specify options that do not change. For example, if the password to connect to your MySQL master has changed, you just need to issue these statements to tell the slave about the new password:
STOP SLAVE; -- if replication was running CHANGE MASTER TO MASTER_PASSWORD='new3cret'; START SLAVE; -- if you want to restart replication
        MASTER_HOST, MASTER_USER,
        MASTER_PASSWORD, and
        MASTER_PORT provide information to the slave
        about how to connect to its master:
            MASTER_HOST and
            MASTER_PORT are the host name (or IP
            address) of the master host and its TCP/IP port.
Replication cannot use Unix socket files. You must be able to connect to the master MySQL server using TCP/IP.
            If you specify the MASTER_HOST or
            MASTER_PORT option, the slave assumes
            that the master server is different from before (even if the
            option value is the same as its current value.) In this
            case, the old values for the master binary log file name and
            position are considered no longer applicable, so if you do
            not specify MASTER_LOG_FILE and
            MASTER_LOG_POS in the statement,
            MASTER_LOG_FILE='' and
            MASTER_LOG_POS=4 are silently appended to
            it.
          
            Setting MASTER_HOST='' (that is, setting
            its value explicitly to an empty string) is
            not the same as not setting
            MASTER_HOST at all. Beginning with MySQL
            5.5, trying to set MASTER_HOST to an
            empty string fails with an error. Previously, setting
            MASTER_HOST to an empty string caused
            START SLAVE subsequently to
            fail. (Bug #28796)
          
            In MySQL 5.6.5 and later, values used for
            MASTER_HOST and other CHANGE
            MASTER TO options are checked for linefeed
            (\n or 0x0A)
            characters; the presence of such characters in these values
            causes the statement to fail with
            ER_MASTER_INFO. (Bug #11758581, Bug
            #50801)
          
            MASTER_USER and
            MASTER_PASSWORD are the user name and
            password of the account to use for connecting to the master.
          
            In MySQL 5.6.4 and later, MASTER_USER
            cannot be made empty; setting MASTER_USER =
            '' or leaving it unset when setting a value for
            MASTER_PASSWORD causes an error (Bug
            #13427949).
          
            The password used for a MySQL Replication slave account in a
            CHANGE MASTER TO statement is limited to
            32 characters in length; if the password is longer, the
            statement succeeds, but any excess characters are silently
            truncated. This is an issue specific to MySQL Replication,
            which is fixed in MySQL 5.7. (Bug #11752299, Bug #43439)
          
            The text of a running CHANGE MASTER
            TO statement, including values for
            MASTER_USER and
            MASTER_PASSWORD, can be seen in the
            output of a concurrent SHOW
            PROCESSLIST statement. (The complete text of a
            START SLAVE statement is also
            visible to SHOW PROCESSLIST.)
        The MASTER_SSL_
        options provide information about using SSL for the connection.
        They correspond to the
        xxx--ssl- options
        described in Section 6.3.10.4, “SSL Command Options”, and
        Section 17.3.7, “Setting Up Replication Using SSL”. These options can
        be changed even on slaves that are compiled without SSL support.
        They are saved to the master info repository, but are ignored if
        the slave does not have SSL support enabled.
        xxxMASTER_SSL_CRL and
        MASTER_SSL_CRLPATH were added in MySQL 5.6.3.
      
        MASTER_CONNECT_RETRY specifies how many
        seconds to wait between connect retries. The default is 60.
      
        MASTER_RETRY_COUNT, added in MySQL 5.6.1,
        limits the number of reconnection attempts
        and updates the value of the
        Master_Retry_Count column in the output of
        SHOW SLAVE STATUS (also added in
        MySQL 5.6.1). The default value is 24 * 3600 = 86400.
        MASTER_RETRY_COUNT is intended to replace the
        older --master-retry-count server
        option, and is now the preferred method for setting this limit.
        You are encouraged not to rely on
        --master-retry-count in new
        applications and, when upgrading to MySQL 5.6.1 or later from
        earlier versions of MySQL, to update any existing applications
        that rely on it, so that they use CHANGE MASTER TO ...
        MASTER_RETRY_COUNT instead.
      
        MASTER_DELAY specifies how many seconds
        behind the master the slave must lag. An event received from the
        master is not executed until at least
        interval seconds later than its
        execution on the master. The default is 0. An error occurs if
        interval is not a nonnegative integer
        in the range from 0 to 231−1.
        For more information, see Section 17.3.9, “Delayed Replication”.
        This option was added in MySQL 5.6.0.
      
        MASTER_BIND is for use on replication slaves
        having multiple network interfaces, and determines which of the
        slave's network interfaces is chosen for connecting to the
        master.
      
        The address configured with this option, if any, can be seen in
        the Master_Bind column of the output from
        SHOW SLAVE STATUS. If you are
        using slave status log tables (server started with
        --master-info-repository=TABLE),
        the value can also be seen as the Master_bind
        column of the mysql.slave_master_info table.
      
The ability to bind a replication slave to a specific network interface was added in MySQL 5.6.2. This is also supported by MySQL Cluster NDB 7.3.1 and later.
        MASTER_HEARTBEAT_PERIOD sets the interval in
        seconds between replication heartbeats. Whenever the master's
        binary log is updated with an event, the waiting period for the
        next heartbeat is reset. interval is
        a decimal value having the range 0 to 4294967 seconds and a
        resolution in milliseconds; the smallest nonzero value is 0.001.
        Heartbeats are sent by the master only if there are no unsent
        events in the binary log file for a period longer than
        interval.
      
        If you are logging master connection information to tables,
        MASTER_HEARTBEAT_PERIOD can be seen as the
        value of the Heartbeat column of the
        mysql.slave_master_info table.
      
        Setting interval to 0 disables
        heartbeats altogether. The default value for
        interval is equal to the value of
        slave_net_timeout divided by 2.
      
        Setting @@global.slave_net_timeout to a value
        less than that of the current heartbeat interval results in a
        warning being issued. The effect of issuing
        RESET SLAVE on the heartbeat
        interval is to reset it to the default value.
      
        MASTER_LOG_FILE and
        MASTER_LOG_POS are the coordinates at which
        the slave I/O thread should begin reading from the master the
        next time the thread starts. RELAY_LOG_FILE
        and RELAY_LOG_POS are the coordinates at
        which the slave SQL thread should begin reading from the relay
        log the next time the thread starts. If you specify either of
        MASTER_LOG_FILE or
        MASTER_LOG_POS, you cannot specify
        RELAY_LOG_FILE or
        RELAY_LOG_POS. In MySQL 5.6.5 and later, if
        you specify either of MASTER_LOG_FILE or
        MASTER_LOG_POS, you also cannot specify
        MASTER_AUTO_POSITION = 1 (described later in
        this section). If neither of MASTER_LOG_FILE
        or MASTER_LOG_POS is specified, the slave
        uses the last coordinates of the slave SQL
        thread before CHANGE MASTER
        TO was issued. This ensures that there is no
        discontinuity in replication, even if the slave SQL thread was
        late compared to the slave I/O thread, when you merely want to
        change, say, the password to use.
      
        MASTER_AUTO_POSITION was added in MySQL
        5.6.5. If MASTER_AUTO_POSITION = 1 is used
        with CHANGE MASTER TO, the slave attempts to
        connect to the master using the GTID-based replication protocol.
      
        When using GTIDs, the slave tells the master which transactions
        it has already received, executed, or both. To compute this set,
        it reads the global value of
        gtid_executed and the value of
        the Retrieved_gtid_set column from
        SHOW SLAVE STATUS. Since the GTID
        of the last transmitted transaction is included in
        Retrieved_gtid_set even if the transaction
        was only partially transmitted, the last received GTID is
        subtracted from this set. Thus, the slave computes the following
        set:
      
UNION(@@global.gtid_executed, Retrieved_gtid_set - last_received_GTID)
This set is sent to the master as part of the initial handshake, and the master sends back all transactions that it has executed which are not part of the set. If any of these transactions have been already purged from the master's binary log, the master sends the error ER_MASTER_HAS_PURGED_REQUIRED_GTIDS to the slave, and replication does not start.
        When GTID-based replication is employed, the coordinates
        represented by MASTER_LOG_FILE and
        MASTER_LOG_POS are not used, and global
        transaction identifiers are used instead. Thus the use of either
        or both of these options together with
        MASTER_AUTO_POSITION causes an error.
      
        Beginning with MySQL 5.6.10, you can see whether replication is
        running with autopositioning enabled by checking the output of
        SHOW SLAVE STATUS. (Bug
        #15992220)
      
        gtid_mode must also be enabled
        before issuing CHANGE MASTER TO ...
        MASTER_AUTO_POSITION = 1. Otherwise, the statement
        fails with an error.
      
        To revert to the older file-based replication protocol after
        using GTIDs, you can issue a new CHANGE MASTER
        TO statement that specifies
        MASTER_AUTO_POSITION = 0, as well as at least
        one of MASTER_LOG_FILE or
        MASTER_LOG_POSITION.
      
        CHANGE MASTER TO
        deletes all relay log files and starts a
        new one, unless you specify RELAY_LOG_FILE or
        RELAY_LOG_POS. In that case, relay log files
        are kept; the relay_log_purge
        global variable is set silently to 0.
      
        Prior to MySQL 5.6.2, RELAY_LOG_FILE required
        an absolute path. Beginning with MySQL 5.6.2, the path can be
        relative, in which case it is assumed to be relative to the
        slave's data directory. (Bug #12190)
      
        IGNORE_SERVER_IDS takes a comma-separated
        list of 0 or more server IDs. Events originating from the
        corresponding servers are ignored, with the exception of log
        rotation and deletion events, which are still recorded in the
        relay log.
      
        In circular replication, the originating server normally acts as
        the terminator of its own events, so that they are not applied
        more than once. Thus, this option is useful in circular
        replication when one of the servers in the circle is removed.
        Suppose that you have a circular replication setup with 4
        servers, having server IDs 1, 2, 3, and 4, and server 3 fails.
        When bridging the gap by starting replication from server 2 to
        server 4, you can include IGNORE_SERVER_IDS =
        (3) in the CHANGE MASTER
        TO statement that you issue on server 4 to tell it to
        use server 2 as its master instead of server 3. Doing so causes
        it to ignore and not to propagate any statements that originated
        with the server that is no longer in use.
      
        When a CHANGE MASTER TO statement
        is issued without any IGNORE_SERVER_IDS
        option, any existing list is preserved. To clear the list of
        ignored servers, it is necessary to use the option with an empty
        list:
      
CHANGE MASTER TO IGNORE_SERVER_IDS = ();
        RESET SLAVE
        ALL has no effect on the server ID list. This issue is
        fixed in MySQL 5.7. (Bug #18816897)
      
        If IGNORE_SERVER_IDS contains the
        server's own ID and the server was started with the
        --replicate-same-server-id option
        enabled, an error results.
      
        In MySQL 5.6, the master info repository and the
        output of SHOW SLAVE STATUS
        provide the list of servers that are currently ignored. For more
        information, see Section 17.2.2.2, “Slave Status Logs”, and
        Section 13.7.5.35, “SHOW SLAVE STATUS Syntax”.
      
        In MySQL 5.6, invoking CHANGE
        MASTER TO causes the previous values for
        MASTER_HOST, MASTER_PORT,
        MASTER_LOG_FILE, and
        MASTER_LOG_POS to be written to the error
        log, along with other information about the slave's state
        prior to execution.
      
        In MySQL 5.6.7 and later, CHANGE MASTER TO
        causes an implicit commit of an ongoing transaction. See
        Section 13.3.3, “Statements That Cause an Implicit Commit”.
      
        CHANGE MASTER TO is useful for
        setting up a slave when you have the snapshot of the master and
        have recorded the master binary log coordinates corresponding to
        the time of the snapshot. After loading the snapshot into the
        slave to synchronize it with the master, you can run
        CHANGE MASTER TO
        MASTER_LOG_FILE=' on
        the slave to specify the coordinates at which the slave should
        begin reading the master binary log.
      log_name',
        MASTER_LOG_POS=log_pos
The following example changes the master server the slave uses and establishes the master binary log coordinates from which the slave begins reading. This is used when you want to set up the slave to replicate the master:
CHANGE MASTER TO MASTER_HOST='master2.mycompany.com', MASTER_USER='replication', MASTER_PASSWORD='bigs3cret', MASTER_PORT=3306, MASTER_LOG_FILE='master2-bin.001', MASTER_LOG_POS=4, MASTER_CONNECT_RETRY=10;
        The next example shows an operation that is less frequently
        employed. It is used when the slave has relay log files that you
        want it to execute again for some reason. To do this, the master
        need not be reachable. You need only use
        CHANGE MASTER TO and start the
        SQL thread (START SLAVE SQL_THREAD):
      
CHANGE MASTER TO RELAY_LOG_FILE='slave-relay-bin.006', RELAY_LOG_POS=4025;
        You can even use the second operation in a nonreplication setup
        with a standalone, nonslave server for recovery following a
        crash. Suppose that your server has crashed and you have
        restored it from a backup. You want to replay the server's own
        binary log files (not relay log files, but regular binary log
        files), named (for example) myhost-bin.*.
        First, make a backup copy of these binary log files in some safe
        place, in case you don't exactly follow the procedure below and
        accidentally have the server purge the binary log. Use
        SET GLOBAL relay_log_purge=0 for additional
        safety. Then start the server without the
        --log-bin option, Instead, use
        the --replicate-same-server-id,
        --relay-log=myhost-bin (to make
        the server believe that these regular binary log files are relay
        log files) and --skip-slave-start
        options. After the server starts, issue these statements:
      
CHANGE MASTER TO RELAY_LOG_FILE='myhost-bin.153', RELAY_LOG_POS=410, MASTER_HOST='some_dummy_string'; START SLAVE SQL_THREAD;
        The server reads and executes its own binary log files, thus
        achieving crash recovery. Once the recovery is finished, run
        STOP SLAVE, shut down the server,
        clear the master info and relay log info repositories, and
        restart the server with its original options.
      
        Specifying the MASTER_HOST option (even with
        a dummy value) is required to make the server think it is a
        slave.
      
The following table shows the maximum permissible length for the string-valued options.
| Option | Maximum Length | 
|---|---|
| MASTER_HOST | 60 | 
| MASTER_USER | 16 | 
| MASTER_PASSWORD | 32 | 
| MASTER_LOG_FILE | 255 | 
| RELAY_LOG_FILE | 255 | 
| MASTER_SSL_CA | 255 | 
| MASTER_SSL_CAPATH | 255 | 
| MASTER_SSL_CERT | 255 | 
| MASTER_SSL_CRL | 255 | 
| MASTER_SSL_CRLPATH | 255 | 
| MASTER_SSL_KEY | 255 | 
| MASTER_SSL_CIPHER | 511 | 
SELECT MASTER_POS_WAIT('master_log_file', master_log_pos [, timeout])
This is actually a function, not a statement. It is used to ensure that the slave has read and executed events up to a given position in the master's binary log. See Section 12.18, “Miscellaneous Functions”, for a full description.
RESET SLAVE [ALL]
        RESET SLAVE makes the slave
        forget its replication position in the master's binary log. This
        statement is meant to be used for a clean start: It clears the
        master info and relay log info repositories, deletes all the
        relay log files, and starts a new relay log file. It also resets
        to 0 the replication delay specified with the
        MASTER_DELAY option to CHANGE MASTER
        TO. To use RESET SLAVE,
        the slave replication threads must be stopped (use
        STOP SLAVE if necessary).
          All relay log files are deleted, even if they have not been
          completely executed by the slave SQL thread. (This is a
          condition likely to exist on a replication slave if you have
          issued a STOP SLAVE statement
          or if the slave is highly loaded.)
        In MySQL 5.6 (unlike the case in MySQL 5.1 and
        earlier), RESET SLAVE does not
        change any replication connection parameters such as master
        host, master port, master user, or master password, which are
        retained in memory. This means that START
        SLAVE can be issued without requiring a
        CHANGE MASTER TO statement
        following RESET SLAVE.
      
        Connection parameters are reset if the slave
        mysqld is shut down following RESET
        SLAVE. In MySQL 5.6.3 and later, you can instead use
        RESET SLAVE ALL to reset these connection
        parameters (Bug #11809016).
      
        RESET SLAVE ALL does not clear the
        IGNORE_SERVER_IDS list set by
        CHANGE MASTER TO. This issue is
        fixed in MySQL 5.7. (Bug #18816897)
      
        In MySQL 5.6.7 and later, RESET SLAVE causes
        an implicit commit of an ongoing transaction. See
        Section 13.3.3, “Statements That Cause an Implicit Commit”.
      
        If the slave SQL thread was in the middle of replicating
        temporary tables when it was stopped, and
        RESET SLAVE is issued, these
        replicated temporary tables are deleted on the slave.
SET GLOBAL sql_slave_skip_counter = N
        This statement skips the next N
        events from the master. This is useful for recovering from
        replication stops caused by a statement.
      
This statement is valid only when the slave threads are not running. Otherwise, it produces an error.
When using this statement, it is important to understand that the binary log is actually organized as a sequence of groups known as event groups. Each event group consists of a sequence of events.
For transactional tables, an event group corresponds to a transaction.
For nontransactional tables, an event group corresponds to a single SQL statement.
A single transaction can contain changes to both transactional and nontransactional tables.
        When you use SET GLOBAL
        sql_slave_skip_counter to skip events and the result
        is in the middle of a group, the slave continues to skip events
        until it reaches the end of the group. Execution then starts
        with the next event group.
      
        In MySQL 5.6, issuing this statement causes the
        previous values of RELAY_LOG_FILE,
        RELAY_LOG_POS, and
        sql_slave_skip_counter to be
        written to the error log.
START SLAVE [thread_types] [until_option] [connection_options]thread_types: [thread_type[,thread_type] ... ]thread_type: IO_THREAD | SQL_THREADuntil_option: UNTIL { {SQL_BEFORE_GTIDS | SQL_AFTER_GTIDS} =gtid_set| MASTER_LOG_FILE = 'log_name', MASTER_LOG_POS =log_pos| RELAY_LOG_FILE = 'log_name', RELAY_LOG_POS =log_pos| SQL_AFTER_MTS_GAPS }connection_options: [USER='user_name'] [PASSWORD='user_pass'] [DEFAULT_AUTH='plugin_name'] [PLUGIN_DIR='plugin_dir']gtid_set:uuid_set[,uuid_set] ... | ''uuid_set:uuid:interval[:interval]...uuid:hhhhhhhh-hhhh-hhhh-hhhh-hhhhhhhhhhhhh: [0-9,A-F]interval:n[-n] (n>= 1)
        START SLAVE with no
        thread_type options starts both of
        the slave threads. The I/O thread reads events from the master
        server and stores them in the relay log. The SQL thread reads
        events from the relay log and executes them.
        START SLAVE requires the
        SUPER privilege.
      
        If START SLAVE succeeds in
        starting the slave threads, it returns without any error.
        However, even in that case, it might be that the slave threads
        start and then later stop (for example, because they do not
        manage to connect to the master or read its binary log, or some
        other problem). START SLAVE does
        not warn you about this. You must check the slave's error log
        for error messages generated by the slave threads, or check that
        they are running satisfactorily with SHOW
        SLAVE STATUS.
      
        In MySQL 5.6.7 and later, START SLAVE causes
        an implicit commit of an ongoing transaction. See
        Section 13.3.3, “Statements That Cause an Implicit Commit”.
      
        Beginning with MySQL 5.6.11,
        gtid_next must be set to
        AUTOMATIC before issuing this statement (Bug
        #16062608).
      
        MySQL 5.6.4 and later supports pluggable user-password
        authentication with START SLAVE with the
        USER, PASSWORD,
        DEFAULT_AUTH and
        PLUGIN_DIR options, as described in the
        following list:
            USER: User name. Cannot be set to an
            empty or null string, or left unset if
            PASSWORD is used.
          
            PASSWORD: Password.
          
            DEFAULT_AUTH: Name of plugin; default is
            MySQL native authentication.
          
            PLUGIN_DIR: Location of plugin.
        Starting with MySQL 5.6.4, you cannot use the
        SQL_THREAD option when specifying any of
        USER, PASSWORD,
        DEFAULT_AUTH, or
        PLUGIN_DIR, unless the
        IO_THREAD option is also provided (Bug
        #13083642).
      
See Section 6.3.7, “Pluggable Authentication”, for more information.
If an insecure connection is used with any these options, the server issues the warning Sending passwords in plain text without SSL/TLS is extremely insecure.
        Starting with MySQL 5.6.6, START SLAVE ...
        UNTIL supports two additional options for use with
        global transaction identifiers (GTIDs) (see
        Section 17.1.3, “Replication with Global Transaction Identifiers”). Each of these takes a set
        of one or more global transaction identifiers
        gtid_set as an argument (see
        GTID Sets, for more
        information).
      
        When no thread_type is specified,
        START SLAVE UNTIL SQL_BEFORE_GTIDS causes the
        slave SQL thread to process transactions until it has reached
        the first transaction whose GTID is listed
        in the gtid_set. START SLAVE
        UNTIL SQL_AFTER_GTIDS causes the slave threads to
        process all transactions until the
        last transaction in the
        gtid_set has been processed by both
        threads. In other words, START SLAVE UNTIL
        SQL_BEFORE_GTIDS causes the slave SQL thread to
        process all transactions occurring before the first GTID in the
        gtid_set is reached, and
        START SLAVE UNTIL SQL_AFTER_GTIDS causes the
        slave threads to handle all transactions, including those whose
        GTIDs are found in gtid_set, until
        each has encountered a transaction whose GTID is not part of the
        set. SQL_BEFORE_GTIDS and
        SQL_AFTER_GTIDS each support the
        SQL_THREAD and IO_THREAD
        options, although using IO_THREAD with them
        currently has no effect.
      
        For example, START SLAVE SQL_THREAD UNTIL
        SQL_BEFORE_GTIDS =
        3E11FA47-71CA-11E1-9E33-C80AA9429562:11-56 causes the
        slave SQL thread to process all transactions originating from
        the master whose server_uuid is
        3E11FA47-71CA-11E1-9E33-C80AA9429562 until it
        encounters the transaction having sequence number 11; it then
        stops without processing this transaction. In other words, all
        transactions up to and including the transaction with sequence
        number 10 are processed. Executing START SLAVE
        SQL_THREAD UNTIL SQL_AFTER_GTIDS =
        3E11FA47-71CA-11E1-9E33-C80AA9429562:11-56, on the
        other hand, would cause the slave SQL thread to obtain all
        transactions just mentioned from the master, including all of
        the transactions having the sequence numbers 11 through 56, and
        then to stop without processing any additional transactions;
        that is, the transaction having sequence number 56 would be the
        last transaction fetched by the slave SQL thread.
      
        Prior to MySQL 5.6.14, SQL_AFTER_GTIDS did
        not stop the slave once the indicated transaction was completed,
        but waited until another GTID event was received (Bug
        #14767986).
          The SQL_BEFORE_GTIDS and
          SQL_AFTER_GTIDS keywords are present in the
          MySQL 5.6.5 server; however, neither of them functioned
          correctly as options with START SLAVE [SQL_THREAD |
          IO_THREAD] UNTIL in that version, and are therefore
          supported beginning only with MySQL 5.6.6. (Bug#13810456)
        START SLAVE UNTIL SQL_AFTER_MTS_GAPS is
        available in MySQL 5.6.6 or later. This statement causes a
        multi-threaded slave's SQL threads to run until no more
        gaps are found in the relay log, and then to stop. This
        statement can take an SQL_THREAD option, but
        the effects of the statement remain unchanged. It has no effect
        on the slave I/O thread (and cannot be used with the
        IO_THREAD option). START SLAVE UNTIL
        SQL_AFTER_MTS_GAPS should be used before switching the
        slave from multi-threaded mode to single-threaded mode (that is,
        when resetting
        slave_parallel_workers back to
        0 from a positive, nonzero value) after slave has failed with
        errors in multi-threaded mode.
      
To change a failed multi-threaded slave to single-threaded mode, you can issue the following series of statements, in the order shown:
START SLAVE UNTIL SQL_AFTER_MTS_GAPS; SET @@GLOBAL.slave_parallel_workers = 0; START SLAVE SQL_THREAD;
        If you were running the failed multi-threaded slave with
        relay_log_recovery enabled,
        then you must issue START SLAVE UNTIL
        SQL_AFTER_MTS_GAPS prior to executing
        CHANGE MASTER TO. Otherwise the
        latter statement fails.
          It is possible to view the entire text of a running
          START SLAVE ... statement, including any
          USER or PASSWORD values
          used, in the output of SHOW
          PROCESSLIST. This is also true for the text of a
          running CHANGE MASTER TO
          statement, including any values it employs for
          MASTER_USER or
          MASTER_PASSWORD.
        START SLAVE sends an
        acknowledgment to the user after both the I/O thread and the SQL
        thread have started. However, the I/O thread may not yet have
        connected. For this reason, a successful
        START SLAVE causes
        SHOW SLAVE STATUS to show
        Slave_SQL_Running=Yes, but this does not
        guarantee that Slave_IO_Running=Yes (because
        Slave_IO_Running=Yes only if the I/O thread
        is running and connected). For more
        information, see Section 13.7.5.35, “SHOW SLAVE STATUS Syntax”, and
        Section 17.1.5.1, “Checking Replication Status”.
      
        You can add IO_THREAD and
        SQL_THREAD options to the statement to name
        which of the threads to start. In MySQL 5.6.4 and later, the
        SQL_THREAD option is disallowed when
        specifying any of USER,
        PASSWORD, DEFAULT_AUTH, or
        PLUGIN_DIR, unless the
        IO_THREAD option is also provided (Bug
        #13083642).
      
        An UNTIL clause
        (until_option, in the preceding
        grammar) may be added to specify that the slave should start and
        run until the SQL thread reaches a given point in the master
        binary log, specified by the MASTER_LOG_POS
        and MASTER_LOG_FILE options, or a given point in the slave relay
        log, indicated with the RELAY_LOG_POS and
        RELAY_LOG_FILE options. When the SQL thread
        reaches the point specified, it stops. If the
        SQL_THREAD option is specified in the
        statement, it starts only the SQL thread. Otherwise, it starts
        both slave threads. If the SQL thread is running, the
        UNTIL clause is ignored and a warning is
        issued. You cannot use an UNTIL clause with
        the IO_THREAD option.
      
        In MySQL 5.6.6 and later, it is also possible with
        START SLAVE UNTIL to specify a stop point
        relative to a given GTID or set of GTIDs using one of the
        options SQL_BEFORE_GTIDS or
        SQL_AFTER_GTIDS, as explained previously in
        this section. When using one of these options, you can specify
        SQL_THREAD, IO_THREAD,
        both of these, or neither of them. If you specify only
        SQL_THREAD, then only the slave SQL thread is
        affected by the statement; if only IO_THREAD
        is used, then only the slave I/O is affected. If both
        SQL_THREAD and IO_THREAD
        are used, or if neither of them is used, then both the SQL and
        I/O threads are affected by the statement.
      
        The UNTIL clause is not supported for
        multi-threaded slaves except when also using
        SQL_AFTER_MTS_GAPS. Prior to MySQL 5.6.6,
        UNTIL was not supported at all for
        multi-threaded slaves.
      
        For an UNTIL clause, you must specify any one
        of the following:
Both a log file name and a position in that file
            (MySQL 5.6.6 or later:) Either of
            SQL_BEFORE_GTIDS or
            SQL_AFTER_GTIDS
          
            (MySQL 5.6.6 or later:)
            SQL_AFTER_MTS_GAPS
Do not mix master and relay log options. In MySQL 5.6.6 and later, do not mix log file options with GTID options.
        Any UNTIL condition is reset by a subsequent
        STOP SLAVE statement, a
        START SLAVE statement that
        includes no UNTIL clause, or a server
        restart.
      
        When specifying a log file and position, you can use the
        IO_THREAD option with START SLAVE
        ... UNTIL even though only the SQL thread is affected
        by this statement. The IO_THREAD option is
        ignored in such cases. The preceding restriction does not apply
        when using one of the GTID options
        (SQL_BEFORE_GTIDS and
        SQL_AFTER_GTIDS) introduced in MySQL 5.6.6;
        the GTID options support both SQL_THREAD and
        IO_THREAD, as explained previously in this
        section.
      
        The UNTIL clause can be useful for debugging
        replication, or to cause replication to proceed until just
        before the point where you want to avoid having the slave
        replicate an event. For example, if an unwise
        DROP TABLE statement was executed
        on the master, you can use UNTIL to tell the
        slave to execute up to that point but no farther. To find what
        the event is, use mysqlbinlog with the master
        binary log or slave relay log, or by using a
        SHOW BINLOG EVENTS statement.
      
        If you are using UNTIL to have the slave
        process replicated queries in sections, it is recommended that
        you start the slave with the
        --skip-slave-start option to
        prevent the SQL thread from running when the slave server
        starts. It is probably best to use this option in an option file
        rather than on the command line, so that an unexpected server
        restart does not cause it to be forgotten.
      
        The SHOW SLAVE STATUS statement
        includes output fields that display the current values of the
        UNTIL condition.
      
        In very old versions of MySQL (before 4.0.5), this statement was
        called SLAVE START. That syntax is no longer
        accepted as of MySQL 5.6.1.
STOP SLAVE [thread_types]thread_types: [thread_type[,thread_type] ... ]thread_type: IO_THREAD | SQL_THREAD
        Stops the slave threads. STOP
        SLAVE requires the
        SUPER privilege. Recommended best
        practice is to execute STOP SLAVE on the
        slave before stopping the slave server (see
        Section 5.1.12, “The Shutdown Process”, for more information).
      
        When using the row-based logging format:
        You should execute STOP SLAVE or
        STOP SLAVE SQL_THREAD on the slave prior to
        shutting down the slave server if you are replicating any tables
        that use a nontransactional storage engine (see the
        Note later in this section).
      
        Like START SLAVE, this statement
        may be used with the IO_THREAD and
        SQL_THREAD options to name the thread or
        threads to be stopped.
      
        In MySQL 5.6.7 and later, STOP SLAVE causes
        an implicit commit of an ongoing transaction. See
        Section 13.3.3, “Statements That Cause an Implicit Commit”.
      
        Beginning with MySQL 5.6.11,
        gtid_next must be set to
        AUTOMATIC before issuing this statement (Bug
        #16062608).
      
        In MySQL 5.6.13 and later, you can control how long
        STOP SLAVE waits before timing out by setting
        the rpl_stop_slave_timeout
        system variable. This can be used to avoid deadlocks between
        STOP SLAVE and other slave SQL statements
        using different client connections to the slave. (Bug #16856735)
          In MySQL 5.6, STOP
          SLAVE waits until the current replication event
          group affecting one or more nontransactional tables has
          finished executing (if there is any such replication group),
          or until the user issues a
          KILL QUERY or
          KILL
          CONNECTION statement. (Bug #319, Bug #38205)
        In old versions of MySQL (before 4.0.5), this statement was
        called SLAVE STOP. That syntax is no longer
        accepted as of MySQL 5.6.1.
MySQL 5.6 provides support for server-side prepared statements. This support takes advantage of the efficient client/server binary protocol available since MySQL 4.1. Using prepared statements with placeholders for parameter values has the following benefits:
        Less overhead for parsing the statement each time it is
        executed. Typically, database applications process large volumes
        of almost-identical statements, with only changes to literal or
        variable values in clauses such as WHERE for
        queries and deletes, SET for updates, and
        VALUES for inserts.
      
Protection against SQL injection attacks. The parameter values can contain unescaped SQL quote and delimiter characters.
    You can use server-side prepared statements through client
    programming interfaces, including the MySQL C
    API client library or MySQL
    Connector/C for C programs, MySQL
    Connector/J for Java programs, and
    MySQL Connector/Net for
    programs using .NET technologies. For example, the C API provides a
    set of function calls that make up its prepared statement API. See
    Section 23.8.8, “C API Prepared Statements”. Other language
    interfaces can provide support for prepared statements that use the
    binary protocol by linking in the C client library, one example
    being the
    mysqli
    extension, available in PHP 5.0 and later.
An alternative SQL interface to prepared statements is available. This interface is not as efficient as using the binary protocol through a prepared statement API, but requires no programming because it is available directly at the SQL level:
You can use it when no programming interface is available to you.
You can use it from any program that can send SQL statements to the server to be executed, such as the mysql client program.
You can use it even if the client is using an old version of the client library, as long as you connect to a server running MySQL 4.1 or higher.
SQL syntax for prepared statements is intended to be used for situations such as these:
To test how prepared statements work in your application before coding it.
To use prepared statements when you do not have access to a programming API that supports them.
To interactively troubleshoot application issues with prepared statements.
To create a test case that reproduces a problem with prepared statements, so that you can file a bug report.
SQL syntax for prepared statements is based on three SQL statements:
        PREPARE prepares a statement for
        execution (see Section 13.5.1, “PREPARE Syntax”).
      
        EXECUTE executes a prepared
        statement (see Section 13.5.2, “EXECUTE Syntax”).
      
        DEALLOCATE PREPARE releases a
        prepared statement (see Section 13.5.3, “DEALLOCATE PREPARE Syntax”).
The following examples show two equivalent ways of preparing a statement that computes the hypotenuse of a triangle given the lengths of the two sides.
The first example shows how to create a prepared statement by using a string literal to supply the text of the statement:
mysql>PREPARE stmt1 FROM 'SELECT SQRT(POW(?,2) + POW(?,2)) AS hypotenuse';mysql>SET @a = 3;mysql>SET @b = 4;mysql>EXECUTE stmt1 USING @a, @b;+------------+ | hypotenuse | +------------+ | 5 | +------------+ mysql>DEALLOCATE PREPARE stmt1;
The second example is similar, but supplies the text of the statement as a user variable:
mysql>SET @s = 'SELECT SQRT(POW(?,2) + POW(?,2)) AS hypotenuse';mysql>PREPARE stmt2 FROM @s;mysql>SET @a = 6;mysql>SET @b = 8;mysql>EXECUTE stmt2 USING @a, @b;+------------+ | hypotenuse | +------------+ | 10 | +------------+ mysql>DEALLOCATE PREPARE stmt2;
Here is an additional example that demonstrates how to choose the table on which to perform a query at runtime, by storing the name of the table as a user variable:
mysql>USE test;mysql>CREATE TABLE t1 (a INT NOT NULL);mysql>INSERT INTO t1 VALUES (4), (8), (11), (32), (80);mysql>SET @table = 't1';mysql>SET @s = CONCAT('SELECT * FROM ', @table);mysql>PREPARE stmt3 FROM @s;mysql>EXECUTE stmt3;+----+ | a | +----+ | 4 | | 8 | | 11 | | 32 | | 80 | +----+ mysql>DEALLOCATE PREPARE stmt3;
A prepared statement is specific to the session in which it was created. If you terminate a session without deallocating a previously prepared statement, the server deallocates it automatically.
A prepared statement is also global to the session. If you create a prepared statement within a stored routine, it is not deallocated when the stored routine ends.
    To guard against too many prepared statements being created
    simultaneously, set the
    max_prepared_stmt_count system
    variable. To prevent the use of prepared statements, set the value
    to 0.
The following SQL statements can be used as prepared statements:
ALTER TABLE
ALTER USER (as of MySQL 5.6.8)
ANALYZE TABLE
CACHE INDEX
CALL
CHANGE MASTER
CHECKSUM {TABLE | TABLES}
COMMIT
{CREATE | RENAME | DROP} DATABASE
{CREATE | DROP} INDEX
{CREATE | RENAME | DROP} TABLE
{CREATE | RENAME | DROP} USER
{CREATE | DROP} VIEW
DELETE
DO
FLUSH {TABLE | TABLES | TABLES WITH READ LOCK | HOSTS | PRIVILEGES
  | LOGS | STATUS | MASTER | SLAVE | DES_KEY_FILE | USER_RESOURCES}
GRANT
INSERT
INSTALL PLUGIN
KILL
LOAD INDEX INTO CACHE
OPTIMIZE TABLE
REPAIR TABLE
REPLACE
RESET {MASTER | SLAVE | QUERY CACHE}
REVOKE
SELECT
SET
SHOW {AUTHORS | CONTRIBUTORS | WARNINGS | ERRORS}
SHOW BINLOG EVENTS
SHOW CREATE {PROCEDURE | FUNCTION | EVENT | TABLE | VIEW}
SHOW {MASTER | BINARY} LOGS
SHOW {MASTER | SLAVE} STATUS
SLAVE {START | STOP}
TRUNCATE TABLE
UNINSTALL PLUGIN
UPDATE
Other statements are not supported in MySQL 5.6.
Generally, statements not permitted in SQL prepared statements are also not permitted in stored programs. Exceptions are noted in Section D.1, “Restrictions on Stored Programs”.
Metadata changes to tables or views referred to by prepared statements are detected and cause automatic repreparation of the statement when it is next executed. For more information, see Section 8.10.4, “Caching of Prepared Statements and Stored Programs”.
    Placeholders can be used for the arguments of the
    LIMIT clause when using prepared statements. See
    Section 13.2.9, “SELECT Syntax”.
  
    In prepared CALL statements used with
    PREPARE and
    EXECUTE, placeholder support for
    OUT and INOUT parameters is
    available beginning with MySQL 5.6. See
    Section 13.2.1, “CALL Syntax”, for an example and a workaround for earlier
    versions. Placeholders can be used for IN
    parameters regardless of version.
  
    SQL syntax for prepared statements cannot be used in nested fashion.
    That is, a statement passed to
    PREPARE cannot itself be a
    PREPARE,
    EXECUTE, or
    DEALLOCATE PREPARE statement.
  
    SQL syntax for prepared statements is distinct from using prepared
    statement API calls. For example, you cannot use the
    mysql_stmt_prepare() C API function
    to prepare a PREPARE,
    EXECUTE, or
    DEALLOCATE PREPARE statement.
  
    SQL syntax for prepared statements can be used within stored
    procedures, but not in stored functions or triggers. However, a
    cursor cannot be used for a dynamic statement that is prepared and
    executed with PREPARE and
    EXECUTE. The statement for a cursor
    is checked at cursor creation time, so the statement cannot be
    dynamic.
  
    SQL syntax for prepared statements does not support multi-statements
    (that is, multiple statements within a single string separated by
    “;” characters).
  
Prepared statements use the query cache under the conditions described in Section 8.10.3.1, “How the Query Cache Operates”.
    To write C programs that use the CALL
    SQL statement to execute stored procedures that contain prepared
    statements, the CLIENT_MULTI_RESULTS flag must be
    enabled. This is because each CALL
    returns a result to indicate the call status, in addition to any
    result sets that might be returned by statements executed within the
    procedure.
  
    CLIENT_MULTI_RESULTS can be enabled when you call
    mysql_real_connect(), either
    explicitly by passing the CLIENT_MULTI_RESULTS
    flag itself, or implicitly by passing
    CLIENT_MULTI_STATEMENTS (which also enables
    CLIENT_MULTI_RESULTS). For additional
    information, see Section 13.2.1, “CALL Syntax”.
PREPAREstmt_nameFROMpreparable_stmt
      The PREPARE statement prepares a
      SQL statement and assigns it a name,
      stmt_name, by which to refer to the
      statement later. The prepared statement is executed with
      EXECUTE and released with
      DEALLOCATE PREPARE. For examples,
      see Section 13.5, “SQL Syntax for Prepared Statements”.
    
      Statement names are not case sensitive.
      preparable_stmt is either a string
      literal or a user variable that contains the text of the SQL
      statement. The text must represent a single statement, not
      multiple statements. Within the statement, ?
      characters can be used as parameter markers to indicate where data
      values are to be bound to the query later when you execute it. The
      ? characters should not be enclosed within
      quotation marks, even if you intend to bind them to string values.
      Parameter markers can be used only where data values should
      appear, not for SQL keywords, identifiers, and so forth.
    
If a prepared statement with the given name already exists, it is deallocated implicitly before the new statement is prepared. This means that if the new statement contains an error and cannot be prepared, an error is returned and no statement with the given name exists.
The scope of a prepared statement is the session within which it is created, which as several implications:
A prepared statement created in one session is not available to other sessions.
When a session ends, whether normally or abnormally, its prepared statements no longer exist. If auto-reconnect is enabled, the client is not notified that the connection was lost. For this reason, clients may wish to disable auto-reconnect. See Section 23.8.16, “Controlling Automatic Reconnection Behavior”.
A prepared statement created within a stored program continues to exist after the program finishes executing and can be executed outside the program later.
A statement prepared in stored program context cannot refer to stored procedure or function parameters or local variables because they go out of scope when the program ends and would be unavailable were the statement to be executed later outside the program. As a workaround, refer instead to user-defined variables, which also have session scope; see Section 9.4, “User-Defined Variables”.
EXECUTEstmt_name[USING @var_name[, @var_name] ...]
      After preparing a statement with
      PREPARE, you execute it with an
      EXECUTE statement that refers to
      the prepared statement name. If the prepared statement contains
      any parameter markers, you must supply a USING
      clause that lists user variables containing the values to be bound
      to the parameters. Parameter values can be supplied only by user
      variables, and the USING clause must name
      exactly as many variables as the number of parameter markers in
      the statement.
    
You can execute a given prepared statement multiple times, passing different variables to it or setting the variables to different values before each execution.
For examples, see Section 13.5, “SQL Syntax for Prepared Statements”.
{DEALLOCATE | DROP} PREPARE stmt_name
      To deallocate a prepared statement produced with
      PREPARE, use a
      DEALLOCATE PREPARE statement that
      refers to the prepared statement name. Attempting to execute a
      prepared statement after deallocating it results in an error. If
      too many prepared statements are created and not deallocated by
      either the DEALLOCATE PREPARE statement or the
      end of the session, you might encounter the upper limit enforced
      by the max_prepared_stmt_count
      system variable.
    
For examples, see Section 13.5, “SQL Syntax for Prepared Statements”.
    This section describes the syntax for the
    BEGIN ... END
    compound statement and other statements that can be used in the body
    of stored programs: Stored procedures and functions, triggers, and
    events. These objects are defined in terms of SQL code that is
    stored on the server for later invocation (see
    Chapter 20, Stored Programs and Views).
  
A compound statement is a block that can contain other blocks; declarations for variables, condition handlers, and cursors; and flow control constructs such as loops and conditional tests.
[begin_label:] BEGIN [statement_list] END [end_label]
      BEGIN ... END
      syntax is used for writing compound statements, which can appear
      within stored programs (stored procedures and functions, triggers,
      and events). A compound statement can contain multiple statements,
      enclosed by the BEGIN and
      END keywords.
      statement_list represents a list of one
      or more statements, each terminated by a semicolon
      (;) statement delimiter. The
      statement_list itself is optional, so
      the empty compound statement (BEGIN END) is
      legal.
    
      BEGIN ... END
      blocks can be nested.
    
      Use of multiple statements requires that a client is able to send
      statement strings containing the ; statement
      delimiter. In the mysql command-line client,
      this is handled with the delimiter command.
      Changing the ; end-of-statement delimiter (for
      example, to //) permit ; to
      be used in a program body. For an example, see
      Section 20.1, “Defining Stored Programs”.
    
      A BEGIN ...
      END block can be labeled. See
      Section 13.6.2, “Statement Label Syntax”.
    
      The optional [NOT] ATOMIC clause is not
      supported. This means that no transactional savepoint is set at
      the start of the instruction block and the
      BEGIN clause used in this context has no effect
      on the current transaction.
        Within all stored programs, the parser treats
        BEGIN [WORK]
        as the beginning of a
        BEGIN ...
        END block. To begin a transaction in this context, use
        START
        TRANSACTION instead.
[begin_label:] BEGIN [statement_list] END [end_label] [begin_label:] LOOPstatement_listEND LOOP [end_label] [begin_label:] REPEATstatement_listUNTILsearch_conditionEND REPEAT [end_label] [begin_label:] WHILEsearch_conditionDOstatement_listEND WHILE [end_label]
      Labels are permitted for
      BEGIN ... END
      blocks and for the LOOP,
      REPEAT, and
      WHILE statements. Label use for
      those statements follows these rules:
          begin_label must be followed by a
          colon.
        
          begin_label can be given without
          end_label. If
          end_label is present, it must be
          the same as begin_label.
        
          end_label cannot be given without
          begin_label.
        
Labels at the same nesting level must be distinct.
Labels can be up to 16 characters long.
      To refer to a label within the labeled construct, use an
      ITERATE or
      LEAVE statement. The following
      example uses those statements to continue iterating or terminate
      the loop:
    
CREATE PROCEDURE doiterate(p1 INT)
BEGIN
  label1: LOOP
    SET p1 = p1 + 1;
    IF p1 < 10 THEN ITERATE label1; END IF;
    LEAVE label1;
  END LOOP label1;
END;
The scope of a block label does not include the code for handlers declared within the block. For details, see Section 13.6.7.2, “DECLARE ... HANDLER Syntax”.
      The DECLARE statement is used to
      define various items local to a program:
Local variables. See Section 13.6.4, “Variables in Stored Programs”.
Conditions and handlers. See Section 13.6.7, “Condition Handling”.
Cursors. See Section 13.6.6, “Cursors”.
      DECLARE is permitted only inside a
      BEGIN ... END
      compound statement and must be at its start, before any other
      statements.
    
Declarations must follow a certain order. Cursor declarations must appear before handler declarations. Variable and condition declarations must appear before cursor or handler declarations.
      System variables and user-defined variables can be used in stored
      programs, just as they can be used outside stored-program context.
      In addition, stored programs can use DECLARE to
      define local variables, and stored routines (procedures and
      functions) can be declared to take parameters that communicate
      values between the routine and its caller.
          To declare local variables, use the
          DECLARE
          statement, as described in
          Section 13.6.4.1, “Local Variable DECLARE Syntax”.
        
          Variables can be set directly with the
          SET
          statement. See Section 13.7.4, “SET Syntax”.
        
          Results from queries can be retrieved into local variables
          using SELECT ...
          INTO  or by
          opening a cursor and using
          var_listFETCH ... INTO
          . See
          Section 13.2.9.1, “SELECT ... INTO Syntax”, and Section 13.6.6, “Cursors”.
var_list
For information about the scope of local variables and how MySQL resolves ambiguous names, see Section 13.6.4.2, “Local Variable Scope and Resolution”.
      It is not permitted to assign the value DEFAULT
      to stored procedure or function parameters or stored program local
      variables (for example with a SET
      
      statement). As of MySQL 5.6.6, this results in a syntax error.
var_name = DEFAULT
DECLAREvar_name[,var_name] ...type[DEFAULTvalue]
        This statement declares local variables within stored programs.
        To provide a default value for a variable, include a
        DEFAULT clause. The value can be specified as
        an expression; it need not be a constant. If the
        DEFAULT clause is missing, the initial value
        is NULL.
      
Local variables are treated like stored routine parameters with respect to data type and overflow checking. See Section 13.1.15, “CREATE PROCEDURE and CREATE FUNCTION Syntax”.
Variable declarations must appear before cursor or handler declarations.
Local variable names are not case sensitive. Permissible characters and quoting rules are the same as for other identifiers, as described in Section 9.2, “Schema Object Names”.
        The scope of a local variable is the
        BEGIN ...
        END block within which it is declared. The variable
        can be referred to in blocks nested within the declaring block,
        except those blocks that declare a variable with the same name.
        The scope of a local variable is the
        BEGIN ...
        END block within which it is declared. The variable
        can be referred to in blocks nested within the declaring block,
        except those blocks that declare a variable with the same name.
      
        Because local variables are in scope only during stored program
        execution, references to them are not permitted in prepared
        statements created within a stored program. Prepared statement
        scope is the current session, not the stored program, so the
        statement could be executed after the program ends, at which
        point the variables would no longer be in scope. For example,
        SELECT ... INTO
         cannot be used as
        a prepared statement. This restriction also applies to stored
        procedure and function parameters. See
        Section 13.5.1, “PREPARE Syntax”.
      local_var
        A local variable should not have the same name as a table
        column. If an SQL statement, such as a
        SELECT ...
        INTO statement, contains a reference to a column and a
        declared local variable with the same name, MySQL currently
        interprets the reference as the name of a variable. Consider the
        following procedure definition:
      
CREATE PROCEDURE sp1 (x VARCHAR(5))
BEGIN
  DECLARE xname VARCHAR(5) DEFAULT 'bob';
  DECLARE newname VARCHAR(5);
  DECLARE xid INT;
  SELECT xname, id INTO newname, xid
    FROM table1 WHERE xname = xname;
  SELECT newname;
END;
        MySQL interprets xname in the
        SELECT statement as a reference
        to the xname variable
        rather than the xname
        column. Consequently, when the procedure
        sp1()is called, the
        newname variable returns the value
        'bob' regardless of the value of the
        table1.xname column.
      
        Similarly, the cursor definition in the following procedure
        contains a SELECT statement that
        refers to xname. MySQL interprets this as a
        reference to the variable of that name rather than a column
        reference.
      
CREATE PROCEDURE sp2 (x VARCHAR(5))
BEGIN
  DECLARE xname VARCHAR(5) DEFAULT 'bob';
  DECLARE newname VARCHAR(5);
  DECLARE xid INT;
  DECLARE done TINYINT DEFAULT 0;
  DECLARE cur1 CURSOR FOR SELECT xname, id FROM table1;
  DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1;
  OPEN cur1;
  read_loop: LOOP
    FETCH FROM cur1 INTO newname, xid;
    IF done THEN LEAVE read_loop; END IF;
    SELECT newname;
  END LOOP;
  CLOSE cur1;
END;
      MySQL supports the IF,
      CASE,
      ITERATE,
      LEAVE
      LOOP,
      WHILE, and
      REPEAT constructs for flow control
      within stored programs. It also supports
      RETURN within stored functions.
    
      Many of these constructs contain other statements, as indicated by
      the grammar specifications in the following sections. Such
      constructs may be nested. For example, an
      IF statement might contain a
      WHILE loop, which itself contains a
      CASE statement.
    
      MySQL does not support FOR loops.
CASEcase_valueWHENwhen_valueTHENstatement_list[WHENwhen_valueTHENstatement_list] ... [ELSEstatement_list] END CASE
Or:
CASE
    WHEN search_condition THEN statement_list
    [WHEN search_condition THEN statement_list] ...
    [ELSE statement_list]
END CASE
        The CASE statement for stored
        programs implements a complex conditional construct.
          There is also a CASE
          expression, which differs from the
          CASE
          statement described here. See
          Section 12.4, “Control Flow Functions”. The
          CASE statement cannot have an
          ELSE NULL clause, and it is terminated with
          END CASE instead of END.
        For the first syntax, case_value is
        an expression. This value is compared to the
        when_value expression in each
        WHEN clause until one of them is equal. When
        an equal when_value is found, the
        corresponding THEN clause
        statement_list executes. If no
        when_value is equal, the
        ELSE clause
        statement_list executes, if there is
        one.
      
        This syntax cannot be used to test for equality with
        NULL because NULL = NULL
        is false. See Section 3.3.4.6, “Working with NULL Values”.
      
        For the second syntax, each WHEN clause
        search_condition expression is
        evaluated until one is true, at which point its corresponding
        THEN clause
        statement_list executes. If no
        search_condition is equal, the
        ELSE clause
        statement_list executes, if there is
        one.
      
        If no when_value or
        search_condition matches the value
        tested and the CASE statement
        contains no ELSE clause, a Case
        not found for CASE statement error results.
      
        Each statement_list consists of one
        or more SQL statements; an empty
        statement_list is not permitted.
      
        To handle situations where no value is matched by any
        WHEN clause, use an ELSE
        containing an empty
        BEGIN ...
        END block, as shown in this example. (The indentation
        used here in the ELSE clause is for purposes
        of clarity only, and is not otherwise significant.)
      
DELIMITER |
CREATE PROCEDURE p()
  BEGIN
    DECLARE v INT DEFAULT 1;
    CASE v
      WHEN 2 THEN SELECT v;
      WHEN 3 THEN SELECT 0;
      ELSE
        BEGIN
        END;
    END CASE;
  END;
  |
IFsearch_conditionTHENstatement_list[ELSEIFsearch_conditionTHENstatement_list] ... [ELSEstatement_list] END IF
        The IF statement for stored
        programs implements a basic conditional construct.
          There is also an IF()
          function, which differs from the
          IF
          statement described here. See
          Section 12.4, “Control Flow Functions”. The
          IF statement can have
          THEN, ELSE, and
          ELSEIF clauses, and it is terminated with
          END IF.
        If the search_condition evaluates to
        true, the corresponding THEN or
        ELSEIF clause
        statement_list executes. If no
        search_condition matches, the
        ELSE clause
        statement_list executes.
      
        Each statement_list consists of one
        or more SQL statements; an empty
        statement_list is not permitted.
      
        An IF ... END IF block, like all other
        flow-control blocks used within stored programs, must be
        terminated with a semicolon, as shown in this example:
      
DELIMITER //
CREATE FUNCTION SimpleCompare(n INT, m INT)
  RETURNS VARCHAR(20)
  BEGIN
    DECLARE s VARCHAR(20);
    IF n > m THEN SET s = '>';
    ELSEIF n = m THEN SET s = '=';
    ELSE SET s = '<';
    END IF;
    SET s = CONCAT(n, ' ', s, ' ', m);
    RETURN s;
  END //
DELIMITER ;
        As with other flow-control constructs, IF ... END
        IF blocks may be nested within other flow-control
        constructs, including other IF
        statements. Each IF must be
        terminated by its own END IF followed by a
        semicolon. You can use indentation to make nested flow-control
        blocks more easily readable by humans (although this is not
        required by MySQL), as shown here:
      
DELIMITER //
CREATE FUNCTION VerboseCompare (n INT, m INT)
  RETURNS VARCHAR(50)
  BEGIN
    DECLARE s VARCHAR(50);
    IF n = m THEN SET s = 'equals';
    ELSE
      IF n > m THEN SET s = 'greater';
      ELSE SET s = 'less';
      END IF;
      SET s = CONCAT('is ', s, ' than');
    END IF;
    SET s = CONCAT(n, ' ', s, ' ', m, '.');
    RETURN s;
  END //
DELIMITER ;
        In this example, the inner IF is
        evaluated only if n is not equal to
        m.
ITERATE label
        ITERATE can appear only within
        LOOP,
        REPEAT, and
        WHILE statements.
        ITERATE means “start the
        loop again.”
      
For an example, see Section 13.6.5.5, “LOOP Syntax”.
LEAVE label
        This statement is used to exit the flow control construct that
        has the given label. If the label is for the outermost stored
        program block, LEAVE exits the
        program.
      
        LEAVE can be used within
        BEGIN ...
        END or loop constructs
        (LOOP,
        REPEAT,
        WHILE).
      
For an example, see Section 13.6.5.5, “LOOP Syntax”.
[begin_label:] LOOPstatement_listEND LOOP [end_label]
        LOOP implements a simple loop
        construct, enabling repeated execution of the statement list,
        which consists of one or more statements, each terminated by a
        semicolon (;) statement delimiter. The
        statements within the loop are repeated until the loop is
        terminated. Usually, this is accomplished with a
        LEAVE statement. Within a stored
        function, RETURN can also be
        used, which exits the function entirely.
      
Neglecting to include a loop-termination statement results in an infinite loop.
        A LOOP statement can be labeled.
        For the rules regarding label use, see
        Section 13.6.2, “Statement Label Syntax”.
      
Example:
CREATE PROCEDURE doiterate(p1 INT)
BEGIN
  label1: LOOP
    SET p1 = p1 + 1;
    IF p1 < 10 THEN
      ITERATE label1;
    END IF;
    LEAVE label1;
  END LOOP label1;
  SET @x = p1;
END;
[begin_label:] REPEATstatement_listUNTILsearch_conditionEND REPEAT [end_label]
        The statement list within a
        REPEAT statement is repeated
        until the search_condition expression
        is true. Thus, a REPEAT always
        enters the loop at least once.
        statement_list consists of one or
        more statements, each terminated by a semicolon
        (;) statement delimiter.
      
        A REPEAT statement can be
        labeled. For the rules regarding label use, see
        Section 13.6.2, “Statement Label Syntax”.
      
Example:
mysql>delimiter //mysql>CREATE PROCEDURE dorepeat(p1 INT)->BEGIN->SET @x = 0;->REPEAT->SET @x = @x + 1;->UNTIL @x > p1 END REPEAT;->END->//Query OK, 0 rows affected (0.00 sec) mysql>CALL dorepeat(1000)//Query OK, 0 rows affected (0.00 sec) mysql>SELECT @x//+------+ | @x | +------+ | 1001 | +------+ 1 row in set (0.00 sec)
RETURN expr
        The RETURN statement terminates
        execution of a stored function and returns the value
        expr to the function caller. There
        must be at least one RETURN
        statement in a stored function. There may be more than one if
        the function has multiple exit points.
      
        This statement is not used in stored procedures, triggers, or
        events. The LEAVE statement can
        be used to exit a stored program of those types.
[begin_label:] WHILEsearch_conditionDOstatement_listEND WHILE [end_label]
        The statement list within a WHILE
        statement is repeated as long as the
        search_condition expression is true.
        statement_list consists of one or
        more SQL statements, each terminated by a semicolon
        (;) statement delimiter.
      
        A WHILE statement can be labeled.
        For the rules regarding label use, see
        Section 13.6.2, “Statement Label Syntax”.
      
Example:
CREATE PROCEDURE dowhile()
BEGIN
  DECLARE v1 INT DEFAULT 5;
  WHILE v1 > 0 DO
    ...
    SET v1 = v1 - 1;
  END WHILE;
END;
MySQL supports cursors inside stored programs. The syntax is as in embedded SQL. Cursors have these properties:
Asensitive: The server may or may not make a copy of its result table
Read only: Not updatable
Nonscrollable: Can be traversed only in one direction and cannot skip rows
Cursor declarations must appear before handler declarations and after variable and condition declarations.
Example:
CREATE PROCEDURE curdemo()
BEGIN
  DECLARE done INT DEFAULT FALSE;
  DECLARE a CHAR(16);
  DECLARE b, c INT;
  DECLARE cur1 CURSOR FOR SELECT id,data FROM test.t1;
  DECLARE cur2 CURSOR FOR SELECT i FROM test.t2;
  DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
  OPEN cur1;
  OPEN cur2;
  read_loop: LOOP
    FETCH cur1 INTO a, b;
    FETCH cur2 INTO c;
    IF done THEN
      LEAVE read_loop;
    END IF;
    IF b < c THEN
      INSERT INTO test.t3 VALUES (a,b);
    ELSE
      INSERT INTO test.t3 VALUES (a,c);
    END IF;
  END LOOP;
  CLOSE cur1;
  CLOSE cur2;
END;
CLOSE cursor_name
This statement closes a previously opened cursor. For an example, see Section 13.6.6, “Cursors”.
An error occurs if the cursor is not open.
        If not closed explicitly, a cursor is closed at the end of the
        BEGIN ...
        END block in which it was declared.
DECLAREcursor_nameCURSOR FORselect_statement
        This statement declares a cursor and associates it with a
        SELECT statement that retrieves
        the rows to be traversed by the cursor. To fetch the rows later,
        use a FETCH statement. The number
        of columns retrieved by the
        SELECT statement must match the
        number of output variables specified in the
        FETCH statement.
      
        The SELECT statement cannot have
        an INTO clause.
      
Cursor declarations must appear before handler declarations and after variable and condition declarations.
A stored program may contain multiple cursor declarations, but each cursor declared in a given block must have a unique name. For an example, see Section 13.6.6, “Cursors”.
        For information available through
        SHOW statements, it is possible
        in many cases to obtain equivalent information by using a cursor
        with an INFORMATION_SCHEMA table.
FETCH [[NEXT] FROM]cursor_nameINTOvar_name[,var_name] ...
        This statement fetches the next row for the
        SELECT statement associated with
        the specified cursor (which must be open), and advances the
        cursor pointer. If a row exists, the fetched columns are stored
        in the named variables. The number of columns retrieved by the
        SELECT statement must match the
        number of output variables specified in the
        FETCH statement.
      
        If no more rows are available, a No Data condition occurs with
        SQLSTATE value '02000'. To detect this
        condition, you can set up a handler for it (or for a
        NOT FOUND condition). For an example, see
        Section 13.6.6, “Cursors”.
OPEN cursor_name
This statement opens a previously declared cursor. For an example, see Section 13.6.6, “Cursors”.
Conditions may arise during stored program execution that require special handling, such as exiting the current program block or continuing execution. Handlers can be defined for general conditions such as warnings or exceptions, or for specific conditions such as a particular error code. Specific conditions can be assigned names and referred to that way in handlers.
      To name a condition, use the
      DECLARE ...
      CONDITION statement. To declare a handler, use the
      DECLARE ...
      HANDLER statement. See
      Section 13.6.7.1, “DECLARE ... CONDITION Syntax”, and
      Section 13.6.7.2, “DECLARE ... HANDLER Syntax”. For information about how the
      server chooses handlers when a condition occurs, see
      Section 13.6.7.6, “Scope Rules for Handlers”.
    
      To raise a condition, use the
      SIGNAL statement. To modify
      condition information within a condition handler, use
      RESIGNAL. See
      Section 13.6.7.1, “DECLARE ... CONDITION Syntax”, and
      Section 13.6.7.2, “DECLARE ... HANDLER Syntax”.
    
      To retrieve information from the diagnostics area, use the
      GET DIAGNOSTICS statement (see
      Section 13.6.7.3, “GET DIAGNOSTICS Syntax”). For information about the
      diagnostics area, see Section 13.6.7.7, “The MySQL Diagnostics Area”.
DECLAREcondition_nameCONDITION FORcondition_valuecondition_value:mysql_error_code| SQLSTATE [VALUE]sqlstate_value
        The DECLARE
        ... CONDITION statement declares a named error
        condition, associating a name with a condition that needs
        specific handling. The name can be referred to in a subsequent
        DECLARE ...
        HANDLER statement (see
        Section 13.6.7.2, “DECLARE ... HANDLER Syntax”).
      
Condition declarations must appear before cursor or handler declarations.
        The condition_value for
        DECLARE ...
        CONDITION can be a MySQL error code (a number) or an
        SQLSTATE value (a 5-character string literal). You should not
        use MySQL error code 0 or SQLSTATE values that begin with
        '00', because those indicate success rather
        than an error condition. For a list of MySQL error codes and
        SQLSTATE values, see Section B.3, “Server Error Codes and Messages”.
      
Using names for conditions can help make stored program code clearer. For example, this handler applies to attempts to drop a nonexistent table, but that is apparent only if you know the meaning of MySQL error code 1051:
DECLARE CONTINUE HANDLER FOR 1051
  BEGIN
    -- body of handler
  END;
By declaring a name for the condition, the purpose of the handler is more readily seen:
DECLARE no_such_table CONDITION FOR 1051;
DECLARE CONTINUE HANDLER FOR no_such_table
  BEGIN
    -- body of handler
  END;
Here is a named condition for the same condition, but based on the corresponding SQLSTATE value rather than the MySQL error code:
DECLARE no_such_table CONDITION FOR SQLSTATE '42S02';
DECLARE CONTINUE HANDLER FOR no_such_table
  BEGIN
    -- body of handler
  END;
        Condition names referred to in
        SIGNAL or use
        RESIGNAL statements must be
        associated with SQLSTATE values, not MySQL error codes.
DECLAREhandler_actionHANDLER FORcondition_value[,condition_value] ...statementhandler_action: CONTINUE | EXIT | UNDOcondition_value:mysql_error_code| SQLSTATE [VALUE]sqlstate_value|condition_name| SQLWARNING | NOT FOUND | SQLEXCEPTION
        The DECLARE ...
        HANDLER statement specifies a handler that deals with
        one or more conditions. If one of these conditions occurs, the
        specified statement executes.
        statement can be a simple statement
        such as SET , or a compound
        statement written using var_name =
        valueBEGIN and
        END (see Section 13.6.1, “BEGIN ... END Compound-Statement Syntax”).
      
Handler declarations must appear after variable or condition declarations.
        The handler_action value indicates
        what action the handler takes after execution of the handler
        statement:
            CONTINUE: Execution of the current
            program continues.
          
            EXIT: Execution terminates for the
            BEGIN ...
            END compound statement in which the handler is
            declared. This is true even if the condition occurs in an
            inner block.
          
            UNDO: Not supported.
        The condition_value for
        DECLARE ...
        HANDLER indicates the specific condition or class of
        conditions that activates the handler:
            A MySQL error code (a number) or an SQLSTATE value (a
            5-character string literal). You should not use MySQL error
            code 0 or SQLSTATE values that begin with
            '00', because those indicate success
            rather than an error condition. For a list of MySQL error
            codes and SQLSTATE values, see
            Section B.3, “Server Error Codes and Messages”.
          
            A condition name previously specified with
            DECLARE
            ... CONDITION. A condition name can be associated
            with a MySQL error code or SQLSTATE value. See
            Section 13.6.7.1, “DECLARE ... CONDITION Syntax”.
          
            SQLWARNING is shorthand for the class of
            SQLSTATE values that begin with '01'.
          
            NOT FOUND is shorthand for the class of
            SQLSTATE values that begin with '02'.
            This is relevant within the context of cursors and is used
            to control what happens when a cursor reaches the end of a
            data set. If no more rows are available, a No Data condition
            occurs with SQLSTATE value '02000'. To
            detect this condition, you can set up a handler for it (or
            for a NOT FOUND condition). For an
            example, see Section 13.6.6, “Cursors”. This condition also
            occurs for SELECT ... INTO
             statements
            that retrieve no rows.
          var_list
            SQLEXCEPTION is shorthand for the class
            of SQLSTATE values that do not begin with
            '00', '01', or
            '02'.
For information about how the server chooses handlers when a condition occurs, see Section 13.6.7.6, “Scope Rules for Handlers”.
If a condition occurs for which no handler has been declared, the action taken depends on the condition class:
            For SQLEXCEPTION conditions, the stored
            program terminates at the statement that raised the
            condition, as if there were an EXIT
            handler. If the program was called by another stored
            program, the calling program handles the condition using the
            handler selection rules applied to its own handlers.
          
            For SQLWARNING conditions, the program
            continues executing, as if there were a
            CONTINUE handler.
          
            For NOT FOUND conditions, if the
            condition was raised normally, the action is
            CONTINUE. If it was raised by
            SIGNAL or
            RESIGNAL, the action is
            EXIT.
        The following example uses a handler for SQLSTATE
        '23000', which occurs for a duplicate-key error:
      
mysql>CREATE TABLE test.t (s1 INT, PRIMARY KEY (s1));Query OK, 0 rows affected (0.00 sec) mysql>delimiter //mysql>CREATE PROCEDURE handlerdemo ()->BEGIN->DECLARE CONTINUE HANDLER FOR SQLSTATE '23000' SET @x2 = 1;->SET @x = 1;->INSERT INTO test.t VALUES (1);->SET @x = 2;->INSERT INTO test.t VALUES (1);->SET @x = 3;->END;->//Query OK, 0 rows affected (0.00 sec) mysql>CALL handlerdemo()//Query OK, 0 rows affected (0.00 sec) mysql>SELECT @x//+------+ | @x | +------+ | 3 | +------+ 1 row in set (0.00 sec)
        Notice that @x is 3 after
        the procedure executes, which shows that execution continued to
        the end of the procedure after the error occurred. If the
        DECLARE ...
        HANDLER statement had not been present, MySQL would
        have taken the default action (EXIT) after
        the second INSERT failed due to
        the PRIMARY KEY constraint, and
        SELECT @x would have returned
        2.
      
        To ignore a condition, declare a CONTINUE
        handler for it and associate it with an empty block. For
        example:
      
DECLARE CONTINUE HANDLER FOR SQLWARNING BEGIN END;
        The scope of a block label does not include the code for
        handlers declared within the block. Therefore, the statement
        associated with a handler cannot use
        ITERATE or
        LEAVE to refer to labels for
        blocks that enclose the handler declaration. Consider the
        following example, where the
        REPEAT block has a label of
        retry:
      
CREATE PROCEDURE p ()
BEGIN
  DECLARE i INT DEFAULT 3;
  retry:
    REPEAT
      BEGIN
        DECLARE CONTINUE HANDLER FOR SQLWARNING
          BEGIN
            ITERATE retry;    # illegal
          END;
        IF i < 0 THEN
          LEAVE retry;        # legal
        END IF;
        SET i = i - 1;
      END;
    UNTIL FALSE END REPEAT;
END;
        The retry label is in scope for the
        IF statement within the block. It
        is not in scope for the CONTINUE handler, so
        the reference there is invalid and results in an error:
      
ERROR 1308 (42000): LEAVE with no matching label: retry
To avoid references to outer labels in handlers, use one of these strategies:
            To leave the block, use an EXIT handler.
            If no block cleanup is required, the
            BEGIN ...
            END handler body can be empty:
          
DECLARE EXIT HANDLER FOR SQLWARNING BEGIN END;
Otherwise, put the cleanup statements in the handler body:
DECLARE EXIT HANDLER FOR SQLWARNING
  BEGIN
    block cleanup statements
  END;
            To continue execution, set a status variable in a
            CONTINUE handler that can be checked in
            the enclosing block to determine whether the handler was
            invoked. The following example uses the variable
            done for this purpose:
          
CREATE PROCEDURE p ()
BEGIN
  DECLARE i INT DEFAULT 3;
  DECLARE done INT DEFAULT FALSE;
  retry:
    REPEAT
      BEGIN
        DECLARE CONTINUE HANDLER FOR SQLWARNING
          BEGIN
            SET done = TRUE;
          END;
        IF done OR i < 0 THEN
          LEAVE retry;
        END IF;
        SET i = i - 1;
      END;
    UNTIL FALSE END REPEAT;
END;
GET [CURRENT] DIAGNOSTICS
{
    statement_information_item
    [, statement_information_item] ... 
  | CONDITION condition_number
    condition_information_item
    [, condition_information_item] ...
}
statement_information_item:
    target = statement_information_item_name
condition_information_item:
    target = condition_information_item_name
statement_information_item_name:
    NUMBER
  | ROW_COUNT
condition_information_item_name:
    CLASS_ORIGIN
  | SUBCLASS_ORIGIN
  | RETURNED_SQLSTATE
  | MESSAGE_TEXT
  | MYSQL_ERRNO
  | CONSTRAINT_CATALOG
  | CONSTRAINT_SCHEMA
  | CONSTRAINT_NAME
  | CATALOG_NAME
  | SCHEMA_NAME
  | TABLE_NAME
  | COLUMN_NAME
  | CURSOR_NAME
condition_number, target:
    (see following discussion)
        SQL statements produce diagnostic information that populates the
        diagnostics area. The GET
        DIAGNOSTICS statement enables applications to inspect
        this information. It is available as of MySQL 5.6.4. (You can
        also use SHOW WARNINGS or
        SHOW ERRORS to see conditions or
        errors.)
      
        No special privileges are required to execute
        GET DIAGNOSTICS.
      
        The keyword CURRENT means to retrieve
        information from the current diagnostics area. In MySQL, it has
        no effect because that is the default behavior.
      
        GET DIAGNOSTICS is typically used
        in a handler within a stored program, but it is a MySQL
        extension that it is permitted outside handler context to check
        the execution of any SQL statement. For example, if you invoke
        the mysql client program, you can enter these
        statements at the prompt:
      
mysql>DROP TABLE test.no_such_table;ERROR 1051 (42S02): Unknown table 'test.no_such_table' mysql>GET DIAGNOSTICS CONDITION 1->@p1 = RETURNED_SQLSTATE, @p2 = MESSAGE_TEXT;mysql>SELECT @p1, @p2;+-------+------------------------------------+ | @p1 | @p2 | +-------+------------------------------------+ | 42S02 | Unknown table 'test.no_such_table' | +-------+------------------------------------+
For a description of the diagnostics area, see Section 13.6.7.7, “The MySQL Diagnostics Area”. Briefly, it contains two kinds of information:
Statement information, such as the number of conditions that occurred or the affected-rows count.
Condition information, such as the error code and message. If a statement raises multiple conditions, this part of the diagnostics area has a condition area for each one. If a statement raises no conditions, this part of the diagnostics area is empty.
For a statement that produces three conditions, the diagnostics area contains statement and condition information like this:
Statement information:
  row count
  ... other statement information items ...
Condition area list:
  Condition area 1:
    error code for condition 1
    error message for condition 1
    ... other condition information items ...
  Condition area 2:
    error code for condition 2:
    error message for condition 2
    ... other condition information items ...
  Condition area 3:
    error code for condition 3
    error message for condition 3
    ... other condition information items ...
        GET DIAGNOSTICS can obtain either
        statement or condition information, but not both in the same
        statement:
            To obtain statement information, retrieve the desired
            statement items into target variables. This instance of
            GET DIAGNOSTICS assigns the
            number of available conditions and the rows-affected count
            to the user variables @p1 and
            @p2:
          
GET DIAGNOSTICS @p1 = NUMBER, @p2 = ROW_COUNT;
            To obtain condition information, specify the condition
            number and retrieve the desired condition items into target
            variables. This instance of GET
            DIAGNOSTICS assigns the SQLSTATE value and error
            message to the user variables @p3 and
            @p4:
          
GET DIAGNOSTICS CONDITION 1 @p3 = RETURNED_SQLSTATE, @p4 = MESSAGE_TEXT;
        The retrieval list specifies one or more
        target =
        item_namestatement_information_item_name or
        condition_information_item_name
        designator, depending on whether the statement retrieves
        statement or condition information.
      
        Valid target designators for storing
        item information can be stored procedure or function parameters,
        stored program local variables declared with
        DECLARE, or user-defined
        variables.
      
        Valid condition_number designators
        can be stored procedure or function parameters, stored program
        local variables declared with
        DECLARE, user-defined variables,
        system variables, or literals. A character literal may include a
        _charset introducer. A warning occurs
        if the condition number is not in the range from 1 to the number
        of condition areas that have information. In this case, the
        warning is added to the diagnostics area without clearing it.
      
        Currently, when a condition occurs, MySQL does not populate all
        condition items recognized by GET
        DIAGNOSTICS. For example:
      
mysql>GET DIAGNOSTICS CONDITION 1->@p5 = SCHEMA_NAME, @p6 = TABLE_NAME;mysql>SELECT @p5, @p6;+------+------+ | @p5 | @p6 | +------+------+ | | | +------+------+
        In standard SQL, if there are multiple conditions, the first
        condition relates to the SQLSTATE value
        returned for the previous SQL statement. In MySQL, this is not
        guaranteed. To get the main error, you cannot do this:
      
GET DIAGNOSTICS CONDITION 1 @errno = MYSQL_ERRNO;
Instead, retrieve the condition count first, then use it to specify which condition number to inspect:
GET DIAGNOSTICS @cno = NUMBER; GET DIAGNOSTICS CONDITION @cno @errno = MYSQL_ERRNO;
For information about permissible statement and condition information items, and which ones are populated when a condition occurs, see Section 13.6.7.7.2, “Diagnostics Area Information Items”.
        Here is an example that uses GET
        DIAGNOSTICS and an exception handler in stored
        procedure context to assess the outcome of an insert operation.
        If the insert was successful, the procedure uses
        GET DIAGNOSTICS to get the
        rows-affected count. This shows that you can use
        GET DIAGNOSTICS multiple times to
        retrieve information about a statement as long as the
        diagnostics area has not been cleared.
      
CREATE PROCEDURE do_insert(value INT)
BEGIN
  -- Declare variables to hold diagnostics area information
  DECLARE code CHAR(5) DEFAULT '00000';
  DECLARE msg TEXT;
  DECLARE rows INT;
  DECLARE result TEXT;
  -- Declare exception handler for failed insert
  DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
    BEGIN
      GET DIAGNOSTICS CONDITION 1
        code = RETURNED_SQLSTATE, msg = MESSAGE_TEXT;
    END;
  -- Perform the insert
  INSERT INTO t1 (int_col) VALUES(value);
  -- Check whether the insert was successful
  IF code = '00000' THEN
    GET DIAGNOSTICS rows = ROW_COUNT;
    SET result = CONCAT('insert succeeded, row count = ',rows);
  ELSE
    SET result = CONCAT('insert failed, error = ',code,', message = ',msg);
  END IF;
  -- Say what happened
  SELECT result;
END;
        Suppose that t1.int_col is an integer column
        that is declared as NOT NULL. The procedure
        produces these results when invoked to insert
        non-NULL and NULL values,
        respectively:
      
mysql>CALL do_insert(1);+---------------------------------+ | result | +---------------------------------+ | insert succeeded, row count = 1 | +---------------------------------+ mysql>CALL do_insert(NULL);+-------------------------------------------------------------------------+ | result | +-------------------------------------------------------------------------+ | insert failed, error = 23000, message = Column 'int_col' cannot be null | +-------------------------------------------------------------------------+
        Within a condition handler, GET
        DIAGNOSTICS should be used before other statements
        that might clear the diagnostics area and cause information to
        be lost about the condition that activated the handler. For
        information about when the diagnostics area is set and cleared,
        see Section 13.6.7.7, “The MySQL Diagnostics Area”.
RESIGNAL [condition_value] [SETsignal_information_item[,signal_information_item] ...]condition_value: SQLSTATE [VALUE]sqlstate_value|condition_namesignal_information_item:condition_information_item_name=simple_value_specificationcondition_information_item_name: CLASS_ORIGIN | SUBCLASS_ORIGIN | MESSAGE_TEXT | MYSQL_ERRNO | CONSTRAINT_CATALOG | CONSTRAINT_SCHEMA | CONSTRAINT_NAME | CATALOG_NAME | SCHEMA_NAME | TABLE_NAME | COLUMN_NAME | CURSOR_NAMEcondition_name,simple_value_specification: (see following discussion)
        RESIGNAL passes on the error
        condition information that is available during execution of a
        condition handler within a compound statement inside a stored
        procedure or function, trigger, or event.
        RESIGNAL may change some or all
        information before passing it on.
        RESIGNAL is related to
        SIGNAL, but instead of
        originating a condition as SIGNAL
        does, RESIGNAL relays existing
        condition information, possibly after modifying it.
      
        RESIGNAL makes it possible to
        both handle an error and return the error information.
        Otherwise, by executing an SQL statement within the handler,
        information that caused the handler's activation is destroyed.
        RESIGNAL also can make some
        procedures shorter if a given handler can handle part of a
        situation, then pass the condition “up the line” to
        another handler.
      
        No special privileges are required to execute the
        RESIGNAL statement.
      
        All forms of RESIGNAL require
        that the current context be a condition handler. Otherwise,
        RESIGNAL is illegal and a
        RESIGNAL when handler not active error
        occurs.
      
        To retrieve information from the diagnostics area, use the
        GET DIAGNOSTICS statement (see
        Section 13.6.7.3, “GET DIAGNOSTICS Syntax”). For information about the
        diagnostics area, see Section 13.6.7.7, “The MySQL Diagnostics Area”.
      
        For condition_value and
        signal_information_item, the
        definitions and rules are the same for
        RESIGNAL as for
        SIGNAL. For example, the
        condition_value can be an
        SQLSTATE value, and the value can indicate
        errors, warnings, or “not found.” For additional
        information, see Section 13.6.7.5, “SIGNAL Syntax”.
      
        The RESIGNAL statement takes
        condition_value and
        SET clauses, both of which are optional. This
        leads to several possible uses:
These use cases all cause changes to the diagnostics and condition areas:
A diagnostics area contains one or more condition areas.
            A condition area contains condition information items, such
            as the SQLSTATE value,
            MYSQL_ERRNO, or
            MESSAGE_TEXT.
        The maximum number of condition areas in a diagnostics area is
        determined by the value of the
        max_error_count system
        variable. See
        Section 13.6.7.7.4, “Diagnostics Area-Related System Variables”.
          A simple RESIGNAL alone means
          “pass on the error with no change.” It restores
          the last diagnostics area and makes it the current diagnostics
          area. That is, it “pops” the diagnostics area
          stack.
        
          Within a condition handler that catches a condition, one use
          for RESIGNAL alone is to
          perform some other actions, and then pass on without change
          the original condition information (the information that
          existed before entry into the handler).
        
Example:
DROP TABLE IF EXISTS xx;
delimiter //
CREATE PROCEDURE p ()
BEGIN
  DECLARE EXIT HANDLER FOR SQLEXCEPTION
  BEGIN
    SET @error_count = @error_count + 1;
    IF @a = 0 THEN RESIGNAL; END IF;
  END;
  DROP TABLE xx;
END//
delimiter ;
SET @error_count = 0;
SET @a = 0;
CALL p();
          Suppose that the DROP TABLE xx statement
          fails. The diagnostics area stack looks like this:
        
DA 1. ERROR 1051 (42S02): Unknown table 'xx'
          Then execution enters the EXIT handler. It
          starts by pushing a diagnostics area to the top of the stack,
          which now looks like this:
        
DA 1. ERROR 1051 (42S02): Unknown table 'xx' DA 2. ERROR 1051 (42S02): Unknown table 'xx'
At this point, the contents of the first (current) and second (stacked) diagnostics areas are the same. The first diagnostics area may be modified by statements executing subsequently within the handler.
          Usually a procedure statement clears the first diagnostics
          area. BEGIN is an exception, it does not
          clear, it does nothing. SET is not an
          exception, it clears, performs the operation, and produces a
          result of “success.” The diagnostics area stack
          now looks like this:
        
DA 1. ERROR 0000 (00000): Successful operation DA 2. ERROR 1051 (42S02): Unknown table 'xx'
          At this point, if @a = 0,
          RESIGNAL pops the diagnostics
          area stack, which now looks like this:
        
DA 1. ERROR 1051 (42S02): Unknown table 'xx'
And that is what the caller sees.
          If @a is not 0, the handler simply ends,
          which means that there is no more use for the current
          diagnostics area (it has been “handled”), so it
          can be thrown away, causing the stacked diagnostics area to
          become the current diagnostics area again. The diagnostics
          area stack looks like this:
        
DA 1. ERROR 0000 (00000): Successful operation
The details make it look complex, but the end result is quite useful: Handlers can execute without destroying information about the condition that caused activation of the handler.
          RESIGNAL with a
          SET clause provides new signal information,
          so the statement means “pass on the error with
          changes”:
        
RESIGNAL SETsignal_information_item[,signal_information_item] ...;
          As with RESIGNAL alone, the
          idea is to pop the diagnostics area stack so that the original
          information will go out. Unlike
          RESIGNAL alone, anything
          specified in the SET clause changes.
        
Example:
DROP TABLE IF EXISTS xx;
delimiter //
CREATE PROCEDURE p ()
BEGIN
  DECLARE EXIT HANDLER FOR SQLEXCEPTION
  BEGIN
    SET @error_count = @error_count + 1;
    IF @a = 0 THEN RESIGNAL SET MYSQL_ERRNO = 5; END IF;
  END;
  DROP TABLE xx;
END//
delimiter ;
SET @error_count = 0;
SET @a = 0;
CALL p();
          Remember from the previous discussion that
          RESIGNAL alone results in a
          diagnostics area stack like this:
        
DA 1. ERROR 1051 (42S02): Unknown table 'xx'
          The RESIGNAL SET MYSQL_ERRNO = 5 statement
          results in this stack instead, which is what the caller sees:
        
DA 1. ERROR 5 (42S02): Unknown table 'xx'
In other words, it changes the error number, and nothing else.
          The RESIGNAL statement can
          change any or all of the signal information items, making the
          first condition area of the diagnostics area look quite
          different.
          RESIGNAL with a condition value
          means “push a condition into the current diagnostics
          area.” If the SET clause is present,
          it also changes the error information.
        
RESIGNALcondition_value[SETsignal_information_item[,signal_information_item] ...];
          This form of RESIGNAL restores
          the last diagnostics area and makes it the current diagnostics
          area. That is, it “pops” the diagnostics area
          stack, which is the same as what a simple
          RESIGNAL alone would do.
          However, it also changes the diagnostics area depending on the
          condition value or signal information.
        
Example:
DROP TABLE IF EXISTS xx;
delimiter //
CREATE PROCEDURE p ()
BEGIN
  DECLARE EXIT HANDLER FOR SQLEXCEPTION
  BEGIN
    SET @error_count = @error_count + 1;
    IF @a = 0 THEN RESIGNAL SQLSTATE '45000' SET MYSQL_ERRNO=5; END IF;
  END;
  DROP TABLE xx;
END//
delimiter ;
SET @error_count = 0;
SET @a = 0;
SET @@max_error_count = 2;
CALL p();
SHOW ERRORS;
          This is similar to the previous example, and the effects are
          the same, except that if
          RESIGNAL happens, the current
          condition area looks different at the end. (The reason the
          condition adds to rather than replaces the existing condition
          is the use of a condition value.)
        
          The RESIGNAL statement includes
          a condition value (SQLSTATE '45000'), so it
          adds a new condition area, resulting in a diagnostics area
          stack that looks like this:
        
DA 1. (condition 2) ERROR 1051 (42S02): Unknown table 'xx'
      (condition 1) ERROR 5 (45000) Unknown table 'xx'
          The result of CALL
          p() and SHOW ERRORS
          for this example is:
        
mysql>CALL p();ERROR 5 (45000): Unknown table 'xx' mysql>SHOW ERRORS;+-------+------+----------------------------------+ | Level | Code | Message | +-------+------+----------------------------------+ | Error | 1051 | Unknown table 'xx' | | Error | 5 | Unknown table 'xx' | +-------+------+----------------------------------+
          All forms of RESIGNAL require
          that the current context be a condition handler. Otherwise,
          RESIGNAL is illegal and a
          RESIGNAL when handler not active error
          occurs. For example:
        
mysql>CREATE PROCEDURE p () RESIGNAL;Query OK, 0 rows affected (0.00 sec) mysql>CALL p();ERROR 1645 (0K000): RESIGNAL when handler not active
Here is a more difficult example:
delimiter // CREATE FUNCTION f () RETURNS INT BEGIN RESIGNAL; RETURN 5; END// CREATE PROCEDURE p () BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION SET @a=f(); SIGNAL SQLSTATE '55555'; END// delimiter ; CALL p();
          RESIGNAL occurs within the
          stored function f(). Although
          f() itself is invoked within the context of
          the EXIT handler, execution within
          f() has its own context, which is not
          handler context. Thus, RESIGNAL within
          f() results in a “handler not
          active” error.
        
          In MySQL 5.5, handler scope rules are less developed.
          f() is considered to execute within handler
          context and RESIGNAL within
          f() is legal.
SIGNALcondition_value[SETsignal_information_item[,signal_information_item] ...]condition_value: SQLSTATE [VALUE]sqlstate_value|condition_namesignal_information_item:condition_information_item_name=simple_value_specificationcondition_information_item_name: CLASS_ORIGIN | SUBCLASS_ORIGIN | MESSAGE_TEXT | MYSQL_ERRNO | CONSTRAINT_CATALOG | CONSTRAINT_SCHEMA | CONSTRAINT_NAME | CATALOG_NAME | SCHEMA_NAME | TABLE_NAME | COLUMN_NAME | CURSOR_NAMEcondition_name,simple_value_specification: (see following discussion)
        SIGNAL is the way to
        “return” an error.
        SIGNAL provides error information
        to a handler, to an outer portion of the application, or to the
        client. Also, it provides control over the error's
        characteristics (error number, SQLSTATE
        value, message). Without SIGNAL,
        it is necessary to resort to workarounds such as deliberately
        referring to a nonexistent table to cause a routine to return an
        error.
      
        No special privileges are required to execute the
        SIGNAL statement.
      
        To retrieve information from the diagnostics area, use the
        GET DIAGNOSTICS statement (see
        Section 13.6.7.3, “GET DIAGNOSTICS Syntax”). For information about the
        diagnostics area, see Section 13.6.7.7, “The MySQL Diagnostics Area”.
      
        The condition_value in a
        SIGNAL statement indicates the
        error value to be returned. It can be an
        SQLSTATE value (a 5-character string literal)
        or a condition_name that refers to a
        named condition previously defined with
        DECLARE ...
        CONDITION (see Section 13.6.7.1, “DECLARE ... CONDITION Syntax”).
      
        An SQLSTATE value can indicate errors,
        warnings, or “not found.” The first two characters
        of the value indicate its error class, as discussed in
        Section 13.6.7.5.1, “Signal Condition Information Items”. Some
        signal values cause statement termination; see
        Section 13.6.7.5.2, “Effect of Signals on Handlers, Cursors, and Statements”.
      
        The SQLSTATE value for a
        SIGNAL statement should not start
        with '00' because such values indicate
        success and are not valid for signaling an error. This is true
        whether the SQLSTATE value is specified
        directly in the SIGNAL statement
        or in a named condition referred to in the statement. If the
        value is invalid, a Bad SQLSTATE error
        occurs.
      
        To signal a generic SQLSTATE value, use
        '45000', which means “unhandled
        user-defined exception.”
      
        The SIGNAL statement optionally
        includes a SET clause that contains multiple
        signal items, in a comma-separated list of
        condition_information_item_name =
        simple_value_specification
        assignments.
      
        Each condition_information_item_name
        may be specified only once in the SET clause.
        Otherwise, a Duplicate condition information
        item error occurs.
      
        Valid simple_value_specification
        designators can be specified using stored procedure or function
        parameters, stored program local variables declared with
        DECLARE, user-defined variables,
        system variables, or literals. A character literal may include a
        _charset introducer.
      
        For information about permissible
        condition_information_item_name
        values, see
        Section 13.6.7.5.1, “Signal Condition Information Items”.
      
        The following procedure signals an error or warning depending on
        the value of pval, its input parameter:
      
CREATE PROCEDURE p (pval INT)
BEGIN
  DECLARE specialty CONDITION FOR SQLSTATE '45000';
  IF pval = 0 THEN
    SIGNAL SQLSTATE '01000';
  ELSEIF pval = 1 THEN
    SIGNAL SQLSTATE '45000'
      SET MESSAGE_TEXT = 'An error occurred';
  ELSEIF pval = 2 THEN
    SIGNAL specialty
      SET MESSAGE_TEXT = 'An error occurred';
  ELSE
    SIGNAL SQLSTATE '01000'
      SET MESSAGE_TEXT = 'A warning occurred', MYSQL_ERRNO = 1000;
    SIGNAL SQLSTATE '45000'
      SET MESSAGE_TEXT = 'An error occurred', MYSQL_ERRNO = 1001;
  END IF;
END;
        If pval is 0, p() signals
        a warning because SQLSTATE values that begin
        with '01' are signals in the warning class.
        The warning does not terminate the procedure, and can be seen
        with SHOW WARNINGS after the
        procedure returns.
      
        If pval is 1, p() signals
        an error and sets the MESSAGE_TEXT condition
        information item. The error terminates the procedure, and the
        text is returned with the error information.
      
        If pval is 2, the same error is signaled,
        although the SQLSTATE value is specified
        using a named condition in this case.
      
        If pval is anything else,
        p() first signals a warning and sets the
        message text and error number condition information items. This
        warning does not terminate the procedure, so execution continues
        and p() then signals an error. The error does
        terminate the procedure. The message text and error number set
        by the warning are replaced by the values set by the error,
        which are returned with the error information.
      
        SIGNAL is typically used within
        stored programs, but it is a MySQL extension that it is
        permitted outside handler context. For example, if you invoke
        the mysql client program, you can enter any
        of these statements at the prompt:
      
mysql>SIGNAL SQLSTATE '77777';mysql>CREATE TRIGGER t_bi BEFORE INSERT ON t->FOR EACH ROW SIGNAL SQLSTATE '77777';mysql>CREATE EVENT e ON SCHEDULE EVERY 1 SECOND->DO SIGNAL SQLSTATE '77777';
        SIGNAL executes according to the
        following rules:
      
        If the SIGNAL statement indicates
        a particular SQLSTATE value, that value is
        used to signal the condition specified. Example:
      
CREATE PROCEDURE p (divisor INT)
BEGIN
  IF divisor = 0 THEN
    SIGNAL SQLSTATE '22012';
  END IF;
END;
        If the SIGNAL statement uses a
        named condition, the condition must be declared in some scope
        that applies to the SIGNAL
        statement, and must be defined using an
        SQLSTATE value, not a MySQL error number.
        Example:
      
CREATE PROCEDURE p (divisor INT)
BEGIN
  DECLARE divide_by_zero CONDITION FOR SQLSTATE '22012';
  IF divisor = 0 THEN
    SIGNAL divide_by_zero;
  END IF;
END;
        If the named condition does not exist in the scope of the
        SIGNAL statement, an
        Undefined CONDITION error occurs.
      
        If SIGNAL refers to a named
        condition that is defined with a MySQL error number rather than
        an SQLSTATE value, a SIGNAL/RESIGNAL
        can only use a CONDITION defined with SQLSTATE error
        occurs. The following statements cause that error because the
        named condition is associated with a MySQL error number:
      
DECLARE no_such_table CONDITION FOR 1051; SIGNAL no_such_table;
If a condition with a given name is declared multiple times in different scopes, the declaration with the most local scope applies. Consider the following procedure:
CREATE PROCEDURE p (divisor INT)
BEGIN
  DECLARE my_error CONDITION FOR SQLSTATE '45000';
  IF divisor = 0 THEN
    BEGIN
      DECLARE my_error CONDITION FOR SQLSTATE '22012';
      SIGNAL my_error;
    END;
  END IF;
  SIGNAL my_error;
END;
        If divisor is 0, the first
        SIGNAL statement executes. The
        innermost my_error condition declaration
        applies, raising SQLSTATE
        '22012'.
      
        If divisor is not 0, the second
        SIGNAL statement executes. The
        outermost my_error condition declaration
        applies, raising SQLSTATE
        '45000'.
      
For information about how the server chooses handlers when a condition occurs, see Section 13.6.7.6, “Scope Rules for Handlers”.
Signals can be raised within exception handlers:
CREATE PROCEDURE p ()
BEGIN
  DECLARE EXIT HANDLER FOR SQLEXCEPTION
  BEGIN
    SIGNAL SQLSTATE VALUE '99999'
      SET MESSAGE_TEXT = 'An error occurred';
  END;
  DROP TABLE no_such_table;
END;
        CALL p() reaches the
        DROP TABLE statement. There is no
        table named no_such_table, so the error
        handler is activated. The error handler destroys the original
        error (“no such table”) and makes a new error with
        SQLSTATE '99999' and
        message An error occurred.
          The following table lists the names of diagnostics area
          condition information items that can be set in a
          SIGNAL (or
          RESIGNAL) statement. All items
          are standard SQL except MYSQL_ERRNO, which
          is a MySQL extension. For more information about these items
          see Section 13.6.7.7, “The MySQL Diagnostics Area”.
        
Item Name Definition --------- ---------- CLASS_ORIGIN VARCHAR(64) SUBCLASS_ORIGIN VARCHAR(64) CONSTRAINT_CATALOG VARCHAR(64) CONSTRAINT_SCHEMA VARCHAR(64) CONSTRAINT_NAME VARCHAR(64) CATALOG_NAME VARCHAR(64) SCHEMA_NAME VARCHAR(64) TABLE_NAME VARCHAR(64) COLUMN_NAME VARCHAR(64) CURSOR_NAME VARCHAR(64) MESSAGE_TEXT VARCHAR(128) MYSQL_ERRNO SMALLINT UNSIGNED
The character set for character items is UTF-8.
          It is illegal to assign NULL to a condition
          information item in a SIGNAL
          statement.
        
          A SIGNAL statement always
          specifies an SQLSTATE value, either
          directly, or indirectly by referring to a named condition
          defined with an SQLSTATE value. The first
          two characters of an SQLSTATE value are its
          class, and the class determines the default value for the
          condition information items:
              Class = '00' (success)
            
              Illegal. SQLSTATE values that begin
              with '00' indicate success and are not
              valid for SIGNAL.
            
              Class = '01' (warning)
            
MESSAGE_TEXT = 'Unhandled user-defined warning condition';
MYSQL_ERRNO = ER_SIGNAL_WARN
              Class = '02' (not found)
            
MESSAGE_TEXT = 'Unhandled user-defined not found condition';
MYSQL_ERRNO = ER_SIGNAL_NOT_FOUND
              Class > '02' (exception)
            
MESSAGE_TEXT = 'Unhandled user-defined exception condition';
MYSQL_ERRNO = ER_SIGNAL_EXCEPTION
For legal classes, the other condition information items are set as follows:
CLASS_ORIGIN = SUBCLASS_ORIGIN = ''; CONSTRAINT_CATALOG = CONSTRAINT_SCHEMA = CONSTRAINT_NAME = ''; CATALOG_NAME = SCHEMA_NAME = TABLE_NAME = COLUMN_NAME = ''; CURSOR_NAME = '';
          The error values that are accessible after
          SIGNAL executes are the
          SQLSTATE value raised by the
          SIGNAL statement and the
          MESSAGE_TEXT and
          MYSQL_ERRNO items. These values are
          available from the C API:
              SQLSTATE value: Call
              mysql_sqlstate()
            
              MYSQL_ERRNO value: Call
              mysql_errno()
            
              MESSAGE_TEXT value: Call
              mysql_error()
          From SQL, the output from SHOW
          WARNINGS and SHOW
          ERRORS indicates the MYSQL_ERRNO
          and MESSAGE_TEXT values in the
          Code and Message
          columns.
        
          To retrieve information from the diagnostics area, use the
          GET DIAGNOSTICS statement (see
          Section 13.6.7.3, “GET DIAGNOSTICS Syntax”). For information about the
          diagnostics area, see Section 13.6.7.7, “The MySQL Diagnostics Area”.
          Signals have different effects on statement execution
          depending on the signal class. The class determines how severe
          an error is. MySQL ignores the value of the
          sql_mode system variable; in
          particular, strict SQL mode does not matter. MySQL also
          ignores IGNORE: The intent of
          SIGNAL is to raise a
          user-generated error explicitly, so a signal is never ignored.
        
          In the following descriptions, “unhandled” means
          that no handler for the signaled SQLSTATE
          value has been defined with
          DECLARE ...
          HANDLER.
              Class = '00' (success)
            
              Illegal. SQLSTATE values that begin
              with '00' indicate success and are not
              valid for SIGNAL.
            
              Class = '01' (warning)
            
              The value of the
              warning_count system
              variable goes up. SHOW
              WARNINGS shows the signal.
              SQLWARNING handlers catch the signal.
              If the signal is unhandled in a function, statements do
              not end.
            
              Class = '02' (not found)
            
              NOT FOUND handlers catch the signal.
              There is no effect on cursors. If the signal is unhandled
              in a function, statements end.
            
              Class > '02' (exception)
            
              SQLEXCEPTION handlers catch the signal.
              If the signal is unhandled in a function, statements end.
            
              Class = '40'
            
Treated as an ordinary exception.
Example:
mysql>delimiter //mysql>CREATE FUNCTION f () RETURNS INT->BEGIN->SIGNAL SQLSTATE '01234'; -- signal a warning->RETURN 5;->END//mysql>delimiter ;mysql>CREATE TABLE t (s1 INT);mysql>INSERT INTO t VALUES (f());
          The result is that a row containing 5 is inserted into table
          t. The warning that is signaled can be
          viewed with SHOW WARNINGS.
A stored program may include handlers to be invoked when certain conditions occur within the program. The applicability of each handler depends on its location within the program definition and on the condition or conditions that it handles:
            A handler declared in a
            BEGIN ...
            END block is in scope only for the SQL statements
            following the handler declarations in the block. If the
            handler itself raises a condition, it cannot handle that
            condition, nor can any other handlers declared in the block.
            In the following example, handlers H1 and
            H2 are in scope for conditions raised by
            statements stmt1 and
            stmt2. But neither
            H1 nor H2 are in scope
            for conditions raised in the body of H1
            or H2.
          
BEGIN -- outer block DECLARE EXIT HANDLER FOR ...; -- handler H1 DECLARE EXIT HANDLER FOR ...; -- handler H2stmt1;stmt2; END;
            A handler is in scope only for the block in which it is
            declared, and cannot be activated for conditions occurring
            outside that block. In the following example, handler
            H1 is in scope for
            stmt1 in the inner block, but not
            for stmt2 in the outer block:
          
BEGIN -- outer block
  BEGIN -- inner block
    DECLARE EXIT HANDLER FOR ...;  -- handler H1
    stmt1;
  END;
  stmt2;
END;
            A handler can be specific or general. A specific handler is
            for a MySQL error code, SQLSTATE value,
            or condition name. A general handler is for a condition in
            the SQLWARNING,
            SQLEXCEPTION, or NOT
            FOUND class. Condition specificity is related to
            condition precedence, as described later.
        Multiple handlers can be declared in different scopes and with
        different specificities. For example, there might be a specific
        MySQL error code handler in an outer block, and a general
        SQLWARNING handler in an inner block. Or
        there might be handlers for a specific MySQL error code and the
        general SQLWARNING class in the same block.
      
        Whether a handler is activated depends not only on its own scope
        and condition value, but on what other handlers are present.
        When a condition occurs in a stored program, the server searches
        for applicable handlers in the current scope (current
        BEGIN ...
        END block). If there are no applicable handlers, the
        search continues outward with the handlers in each successive
        containing scope (block). When the server finds one or more
        applicable handlers at a given scope, it chooses among them
        based on condition precedence:
            A MySQL error code handler takes precedence over an
            SQLSTATE value handler.
          
            An SQLSTATE value handler takes
            precedence over general SQLWARNING,
            SQLEXCEPTION, or NOT
            FOUND handlers.
          
            An SQLEXCEPTION handler takes precedence
            over an SQLWARNING handler.
          
            The precedence of NOT FOUND depends on
            how the condition is raised:
                Normally, a condition in the NOT
                FOUND class can be handled by an
                SQLWARNING or NOT
                FOUND handler, with the
                SQLWARNING handler taking precedence
                if both are present. Normal occurrence of NOT
                FOUND takes place when a cursor used to fetch
                a set of rows reaches the end of the data set, or for
                instances of SELECT ... INTO
                 such that
                the var_listWHERE clause finds no rows.
              
                If a NOT FOUND condition is raised by
                a SIGNAL (or
                RESIGNAL) statement, the
                condition can be handled by a NOT
                FOUND handler but not an
                SQLWARNING handler.
It is possible to have several applicable handlers with the same precedence. For example, a statement could generate multiple warnings with different error codes, for each of which an error-specific handler exists. In this case, the choice of which handler the server activates is indeterminate, and may change depending on the circumstances under which the condition occurs.
One implication of the handler selection rules is that if multiple applicable handlers occur in different scopes, handlers with the most local scope take precedence over handlers in outer scopes, even over those for more specific conditions.
If there is no appropriate handler when a condition occurs, the action taken depends on the class of the condition:
            For SQLEXCEPTION conditions, the stored
            program terminates at the statement that raised the
            condition, as if there were an EXIT
            handler. If the program was called by another stored
            program, the calling program handles the condition using the
            handler selection rules applied to its own handlers.
          
            For SQLWARNING conditions, the program
            continues executing, as if there were a
            CONTINUE handler.
          
            For NOT FOUND conditions, if the
            condition was raised normally, the action is
            CONTINUE. If it was raised by
            SIGNAL or
            RESIGNAL, the action is
            EXIT.
The following examples demonstrate how MySQL applies the handler selection rules.
        This procedure contains two handlers, one for the specific
        SQLSTATE value ('42S02')
        that occurs for attempts to drop a nonexistent table, and one
        for the general SQLEXCEPTION class:
      
CREATE PROCEDURE p1()
BEGIN
  DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02'
    SELECT 'SQLSTATE handler was activated' AS msg;
  DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
    SELECT 'SQLEXCEPTION handler was activated' AS msg;
  DROP TABLE test.t;
END;
        Both handlers are declared in the same block and have the same
        scope. However, SQLSTATE handlers take
        precedence over SQLEXCEPTION handlers, so if
        the table t is nonexistent, the
        DROP TABLE statement raises a
        condition that activates the SQLSTATE
        handler:
      
mysql> CALL p1();
+--------------------------------+
| msg                            |
+--------------------------------+
| SQLSTATE handler was activated |
+--------------------------------+
        This procedure contains the same two handlers. But this time,
        the DROP TABLE statement and
        SQLEXCEPTION handler are in an inner block
        relative to the SQLSTATE handler:
      
CREATE PROCEDURE p2()
BEGIN -- outer block
    DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02'
      SELECT 'SQLSTATE handler was activated' AS msg;
  BEGIN -- inner block
    DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
      SELECT 'SQLEXCEPTION handler was activated' AS msg;
    DROP TABLE test.t; -- occurs within inner block
  END;
END;
        In this case, the handler that is more local to where the
        condition occurs takes precedence. The
        SQLEXCEPTION handler activates, even though
        it is more general than the SQLSTATE handler:
      
mysql> CALL p2();
+------------------------------------+
| msg                                |
+------------------------------------+
| SQLEXCEPTION handler was activated |
+------------------------------------+
        In this procedure, one of the handlers is declared in a block
        inner to the scope of the DROP
        TABLE statement:
      
CREATE PROCEDURE p3()
BEGIN -- outer block
  DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
    SELECT 'SQLEXCEPTION handler was activated' AS msg;
  BEGIN -- inner block
    DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02'
      SELECT 'SQLSTATE handler was activated' AS msg;
  END;
  DROP TABLE test.t; -- occurs within outer block
END;
        Only the SQLEXCEPTION handler applies because
        the other one is not in scope for the condition raised by the
        DROP TABLE:
      
mysql> CALL p3();
+------------------------------------+
| msg                                |
+------------------------------------+
| SQLEXCEPTION handler was activated |
+------------------------------------+
        In this procedure, both handlers are declared in a block inner
        to the scope of the DROP TABLE
        statement:
      
CREATE PROCEDURE p4()
BEGIN -- outer block
  BEGIN -- inner block
    DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
      SELECT 'SQLEXCEPTION handler was activated' AS msg;
    DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02'
      SELECT 'SQLSTATE handler was activated' AS msg;
  END;
  DROP TABLE test.t; -- occurs within outer block
END;
        Neither handler applies because they are not in scope for the
        DROP TABLE. The condition raised
        by the statement goes unhandled and terminates the procedure
        with an error:
      
mysql> CALL p4();
ERROR 1051 (42S02): Unknown table 'test.t'
        SQL statements produce diagnostic information that populates the
        diagnostics area. Standard SQL has a diagnostics area stack,
        containing a diagnostics area for each nested execution context.
        Standard SQL also supports GET STACKED
        DIAGNOSTICS syntax for referring to the second
        diagnostics area during condition handler execution. MySQL does
        not support the STACKED keyword until MySQL
        5.7. In MySQL 5.6, there is a single diagnostics area containing
        information from the most recent statement that wrote to it.
      
This section describes the structure of the diagnostics area in MySQL, the information items recognized by MySQL and how statements clear and set the diagnostics area.
The diagnostics area contains two kinds of information:
Statement information, such as the number of conditions that occurred or the affected-rows count.
Condition information, such as the error code and message. If a statement raises multiple conditions, this part of the diagnostics area has a condition area for each one. If a statement raises no conditions, this part of the diagnostics area is empty.
For a statement that produces three conditions, the diagnostics area contains statement and condition information like this:
Statement information:
  row count
  ... other statement information items ...
Condition area list:
  Condition area 1:
    error code for condition 1
    error message for condition 1
    ... other condition information items ...
  Condition area 2:
    error code for condition 2:
    error message for condition 2
    ... other condition information items ...
  Condition area 3:
    error code for condition 3
    error message for condition 3
    ... other condition information items ...
          The diagnostics area contains statement and condition
          information items. Numeric items are integers. The character
          set for character items is UTF-8. No item can be
          NULL. If a statement or condition item is
          not set by a statement that populates the diagnostics area,
          its value will be 0 or the empty string, depending on the item
          data type.
        
The statement information part of the diagnostics area contains these items:
              NUMBER: An integer indicating the
              number of condition areas that have information.
            
              ROW_COUNT: An integer indicating the
              number of rows affected by the statement.
              ROW_COUNT has the same value as the
              ROW_COUNT() function (see
              Section 12.14, “Information Functions”).
          The condition information part of the diagnostics area
          contains a condition area for each condition. Condition areas
          are numbered from 1 to the value of the
          NUMBER statement condition item. If
          NUMBER is 0, there are no condition areas.
        
          Each condition area contains the items in the following list.
          All items are standard SQL except
          MYSQL_ERRNO, which is a MySQL extension.
          The definitions apply for conditions generated other than by a
          signal (that is, by a SIGNAL or
          RESIGNAL statement). For
          nonsignal conditions, MySQL populates only those condition
          items not described as always empty. The effects of signals on
          the condition area are described later.
              CLASS_ORIGIN: A string containing the
              class of the RETURNED_SQLSTATE value.
              If the RETURNED_SQLSTATE value begins
              with a class value defined in SQL standards document ISO
              9075-2 (section 24.1, SQLSTATE),
              CLASS_ORIGIN is 'ISO
              9075'. Otherwise,
              CLASS_ORIGIN is
              'MySQL'.
            
              SUBCLASS_ORIGIN: A string containing
              the subclass of the RETURNED_SQLSTATE
              value. If CLASS_ORIGIN is 'ISO
              9075' or RETURNED_SQLSTATE
              ends with '000',
              SUBCLASS_ORIGIN is 'ISO
              9075'. Otherwise,
              SUBCLASS_ORIGIN is
              'MySQL'.
            
              RETURNED_SQLSTATE: A string that
              indicates the SQLSTATE value for the
              condition.
            
              MESSAGE_TEXT: A string that indicates
              the error message for the condition.
            
              MYSQL_ERRNO: An integer that indicates
              the MySQL error code for the condition.
            
              CONSTRAINT_CATALOG,
              CONSTRAINT_SCHEMA,
              CONSTRAINT_NAME: Strings that indicate
              the catalog, schema, and name for a violated constraint.
              They are always empty.
            
              CATALOG_NAME,
              SCHEMA_NAME,
              TABLE_NAME,
              COLUMN_NAME: Strings that indicate the
              catalog, schema, table, and column related to the
              condition. They are always empty.
            
              CURSOR_NAME: A string that indicates
              the cursor name. This is always empty.
          For the RETURNED_SQLSTATE,
          MESSAGE_TEXT, and
          MYSQL_ERRNO values for particular errors,
          see Section B.3, “Server Error Codes and Messages”.
        
          If a SIGNAL (or
          RESIGNAL) statement populates
          the diagnostics area, its SET clause can
          assign to any condition information item except
          RETURNED_SQLSTATE any value that is legal
          for the item data type. SIGNAL
          also sets the RETURNED_SQLSTATE value, but
          not directly in its SET clause. That value
          comes from the SIGNAL statement
          SQLSTATE argument.
        
          SIGNAL also sets statement
          information items. It sets NUMBER to 1, and
          ROW_COUNT to −1 for errors and 0
          otherwise.
          Most nondiagnostic SQL statements populate the diagnostics
          area automatically, and its contents can be set explicitly
          with the SIGNAL and
          RESIGNAL statements. The
          diagnostics area can be examined with GET
          DIAGNOSTICS to extract specific items, or with
          SHOW WARNINGS or
          SHOW ERRORS to see conditions
          or errors.
        
SQL statements clear and set the diagnostics area as follows:
              When the server starts executing a statement after parsing
              it, it clears the diagnostics area for nondiagnostic
              statements that use tables. Diagnostic statements do not
              clear the diagnostics area (SHOW
              WARNINGS, SHOW
              ERRORS, GET
              DIAGNOSTICS).
            
              If a statement raises a condition, the diagnostics area is
              cleared of conditions that belong to earlier statements.
              The exception is that conditions raised by
              GET DIAGNOSTICS and
              RESIGNAL are added to the
              diagnostics area without clearing it.
Thus, even a statement that does not normally clear the diagnostics area when it begins executing clears it if the statement raises a condition.
          The following example shows the effect of various statements
          on the diagnostics area, using SHOW
          WARNINGS to display information about conditions
          stored there.
        
          This DROP TABLE statement uses
          a table, so it clears the diagnostics area and populates it
          when the condition occurs:
        
mysql>DROP TABLE IF EXISTS test.no_such_table;Query OK, 0 rows affected, 1 warning (0.01 sec) mysql>SHOW WARNINGS;+-------+------+------------------------------------+ | Level | Code | Message | +-------+------+------------------------------------+ | Note | 1051 | Unknown table 'test.no_such_table' | +-------+------+------------------------------------+ 1 row in set (0.00 sec)
          This
          SET
          statement does not use tables and does not generate warnings,
          so it leaves the diagnostics area unchanged:
        
mysql>SET @x = 1;Query OK, 0 rows affected (0.00 sec) mysql>SHOW WARNINGS;+-------+------+------------------------------------+ | Level | Code | Message | +-------+------+------------------------------------+ | Note | 1051 | Unknown table 'test.no_such_table' | +-------+------+------------------------------------+ 1 row in set (0.00 sec)
          This
          SET
          statement generates an error, so it clears and populates the
          diagnostics area:
        
mysql>SET @x = @@x;ERROR 1193 (HY000): Unknown system variable 'x' mysql>SHOW WARNINGS;+-------+------+-----------------------------+ | Level | Code | Message | +-------+------+-----------------------------+ | Error | 1193 | Unknown system variable 'x' | +-------+------+-----------------------------+ 1 row in set (0.00 sec)
          The previous
          SET
          statement produced a single condition, so 1 is the only valid
          condition number for GET
          DIAGNOSTICS at this point. The following statement
          uses a condition number of 2, which produces a warning that is
          added to the diagnostics area without clearing it:
        
mysql>GET DIAGNOSTICS CONDITION 2 @p = MESSAGE_TEXT;Query OK, 0 rows affected, 1 warning (0.00 sec) mysql>SHOW WARNINGS;+-------+------+------------------------------+ | Level | Code | Message | +-------+------+------------------------------+ | Error | 1193 | Unknown system variable 'xx' | | Error | 1753 | Invalid condition number | +-------+------+------------------------------+ 2 rows in set (0.00 sec)
          Now there are two conditions in the diagnostics area, so the
          same GET DIAGNOSTICS statement
          succeeds:
        
mysql>GET DIAGNOSTICS CONDITION 2 @p = MESSAGE_TEXT;Query OK, 0 rows affected (0.00 sec) mysql>SELECT @p;+--------------------------+ | @p | +--------------------------+ | Invalid condition number | +--------------------------+ 1 row in set (0.01 sec)
Certain system variables control or are related to some aspects of the diagnostics area:
              max_error_count controls
              the number of condition areas in the diagnostics area. If
              more conditions than this occur, MySQL silently discards
              information for the excess conditions. (Conditions added
              by RESIGNAL are always
              added, with older conditions being discarded as necessary
              to make room.)
            
              warning_count indicates
              the number of conditions that occurred. This includes
              errors, warnings, and notes. Normally,
              NUMBER and
              warning_count are the
              same. However, as the number of conditions generated
              exceeds max_error_count,
              the value of
              warning_count continues
              to rise whereas NUMBER remains capped
              at max_error_count
              because no additional conditions are stored in the
              diagnostics area.
            
              error_count indicates the
              number of errors that occurred. This value includes
              “not found” and exception conditions, but
              excludes warnings and notes. Like
              warning_count, its value
              can exceed
              max_error_count.
            
              If the sql_notes system
              variable is set to 0, notes are not stored and do not
              increment warning_count.
          Example: If max_error_count
          is 10, the diagnostics area can contain a maximum of 10
          condition areas. Suppose that a statement raises 20
          conditions, 12 of which are errors. In that case, the
          diagnostics area contains the first 10 conditions,
          NUMBER is 10,
          warning_count is 20, and
          error_count is 12.
        
          Changes to the value of
          max_error_count have no
          effect until the next attempt to modify the diagnostics area.
          If the diagnostics area contains 10 condition areas and
          max_error_count is set to 5,
          that has no immediate effect on the size or content of the
          diagnostics area.
        
          Before MySQL 5.6, statement information items are not
          available directly. ROW_COUNT can be
          obtained by calling the ROW_COUNT()
          function. NUMBER is approximated by the
          value of the warning_count system variable.
          However, whereas NUMBER is capped to the
          value of max_error_count,
          warning_count is not.
      MySQL account information is stored in the tables of the
      mysql database. This database and the access
      control system are discussed extensively in
      Chapter 5, MySQL Server Administration, which you should consult
      for additional details.
Some releases of MySQL introduce changes to the structure of the grant tables to add new privileges or features. To ensure that you can take advantage of any new capabilities, update your grant tables to have the current structure whenever you update to a new version of MySQL. See Section 4.4.7, “mysql_upgrade — Check and Upgrade MySQL Tables”.
      When the read_only system
      variable is enabled, account-management statements require the
      SUPER privilege, in addition to any
      other required privileges. This is because they modify tables in
      the mysql database.
ALTER USERuser_specification[,user_specification] ...user_specification:userPASSWORD EXPIRE
        The ALTER USER statement alters
        MySQL accounts. To use it, you must have the global
        CREATE USER privilege or the
        UPDATE privilege for the
        mysql database.
      
        When the read_only system
        variable is enabled, ALTER USER
        requires the SUPER privilege, in
        addition to any other required privileges.
          ALTER USER was added in MySQL
          5.6.6. However, in 5.6.6, ALTER
          USER also sets the Password
          column to the empty string, so do not use this statement until
          5.6.7.
        Each account name uses the format described in
        Section 6.2.3, “Specifying Account Names”. If you specify only the user
        name part of the account name, a host name part of
        '%' is used. It is also possible to specify
        CURRENT_USER or
        CURRENT_USER() to refer to the
        account associated with the current session.
      
        For each account, ALTER USER
        expires its password. For example:
      
ALTER USER 'jeffrey'@'localhost' PASSWORD EXPIRE;
        Password expiration for an account affects the corresponding row
        of the mysql.user table: The server sets the
        password_expired column to
        'Y'.
      
A client session operates in restricted mode if the account password has been expired. In restricted mode, operations performed within the session result in an error until the user establishes a new account password:
mysql>SELECT 1;ERROR 1820 (HY000): You must SET PASSWORD before executing this statement mysql>SET PASSWORD = PASSWORD('Query OK, 0 rows affected (0.01 sec) mysql>new_password');SELECT 1;+---+ | 1 | +---+ | 1 | +---+ 1 row in set (0.00 sec)
        As of MySQL 5.6.8, this restricted mode of operation permits
        SET
        statements, which is useful if the account password has a
        hashing format that requires
        old_passwords to be set to a
        value different from its default before using
        SET PASSWORD.
      
It is possible for an administrative user to reset the account password, but any existing sessions for the account remain restricted. A client using the account must disconnect and reconnect before statements can be executed successfully.
It is possible to “reset” a password by setting it to its current value. As a matter of good policy, it is preferable to choose a different password.
CREATE USERuser_specification[,user_specification] ...user_specification:user[identified_option]auth_option: { IDENTIFIED BY 'auth_string' | IDENTIFIED BY PASSWORD 'hash_string' | IDENTIFIED WITHauth_plugin| IDENTIFIED WITHauth_pluginAS 'hash_string' }
        The CREATE USER statement creates
        new MySQL accounts. An error occurs if you try to create an
        account that already exists. To use this statement, you must
        have the global CREATE USER
        privilege or the INSERT privilege
        for the mysql database.
      
        When the read_only system
        variable is enabled, CREATE USER
        requires the SUPER privilege, in
        addition to any other required privileges.
      
        For each account, CREATE USER
        creates a new row in the mysql.user table
        with no privileges and assigns the account an authentication
        plugin. Depending on the syntax used,
        CREATE USER may also assign the
        account a password.
      
        Each user_specification clause
        consists of an account name and information about how
        authentication occurs for clients that use the account. This
        part of CREATE USER syntax is
        shared with GRANT, so the
        description here applies to GRANT
        as well.
      
Each account name uses the format described in Section 6.2.3, “Specifying Account Names”. For example:
CREATE USER 'jeffrey'@'localhost' IDENTIFIED BY 'mypass';
        If you specify only the user name part of the account name, a
        host name part of '%' is used.
      
        The server assigns an authentication plugin and password to each
        account as follows, depending on whether the user specification
        clause includes IDENTIFIED WITH to specify a
        plugin or IDENTIFIED BY to specify a
        password:
            With IDENTIFIED WITH, the server assigns
            the specified plugin and the account has no password. If the
            optional AS
            ' clause is
            also given, the string is stored as is in the
            hash_string'authentication_string column (it is
            assumed to be already hashed in the format required by the
            plugin).
          
            With IDENTIFIED BY, the server assigns
            the plugin implicitly and assigns the specified password.
          
            With neither IDENTIFIED WITH nor
            IDENTIFIED BY, the server assigns the
            plugin implicitly and the account has no password.
        If the account has no password, the Password
        column in the account's mysql.user table row
        remains empty, which is insecure. To set the password, use
        SET PASSWORD. See
        Section 13.7.1.7, “SET PASSWORD Syntax”.
      
For implicit authentication plugin assignment, the server uses these rules:
            As of MySQL 5.6.6, the server assigns the default plugin to
            the account. This plugin becomes the value of the
            plugin column in the account's
            mysql.user table row. The default plugin
            is mysql_native_password unless the
            --default-authentication-plugin
            option is set otherwise at server startup.
          
            Before MySQL 5.6.6, the server assigns no plugin to the
            account. The plugin column in the
            account's mysql.user table row remains
            empty.
For client connections that use a given account, the server invokes the authentication plugin assigned to the account and the client must provide credentials as required by the authentication method that the plugin implements. If the server cannot find the plugin, either at account-creation time or connect time, an error occurs.
        If an account's mysql.user table row has a
        nonempty plugin column:
The server authenticates client connection attempts using the named plugin.
            Changes to the account password using
            SET PASSWORD with
            PASSWORD() must be made with
            the old_passwords system
            variable set to the value required by the authentication
            plugin, so that PASSWORD()
            uses the appropriate password hashing method. If the plugin
            is mysql_old_password, the password can
            also be changed using SET
            PASSWORD with
            OLD_PASSWORD(), which uses
            pre-4.1 password hashing regardless of the value of
            old_passwords.
        If an account's mysql.user table row has an
        empty plugin column:
            The server authenticates client connection attempts using
            the mysql_native_password or
            mysql_old_password authentication plugin,
            depending on the hash format of the password stored in the
            Password column.
          
            Changes to the account password using
            SET PASSWORD can be made with
            PASSWORD(), with
            old_passwords set to 0 or 1
            for 4.1 or pre-4.1 password hashing, respectively, or with
            OLD_PASSWORD(), which uses
            pre-4.1 password hashing regardless of the value of
            old_passwords.
        CREATE USER examples:
            To specify an authentication plugin for an account, use
            IDENTIFIED WITH
            . The plugin
            name can be a quoted string literal or an unquoted name.
            auth_plugin'
            is an optional quoted string literal to pass to the plugin.
            The plugin interprets the meaning of the string, so its
            format is plugin specific and it is stored in the
            auth_string'authentication_string column as given.
            (This value is meaningful only for plugins that use that
            column.) Consult the documentation for a given plugin for
            information about the authentication string values it
            accepts, if any.
          
CREATE USER 'jeffrey'@'localhost' IDENTIFIED WITH mysql_native_password;
            The server assigns the given authentication plugin to the
            account but no password. Clients must provide no password
            when they connect. However, an account with no password is
            insecure. To ensure that an account uses a specific
            authentication plugin and has a password with the
            corresponding hash format, specify the plugin explicitly
            with IDENTIFIED WITH, then use
            SET PASSWORD to set the
            password:
          
CREATE USER 'jeffrey'@'localhost' IDENTIFIED WITH mysql_native_password;
SET old_passwords = 0;
SET PASSWORD FOR 'jeffrey'@'localhost' = PASSWORD('mypass');
            Changes to the account password using
            SET PASSWORD with
            PASSWORD() must be made with
            the old_passwords system
            variable set to the value required by the account's
            authentication plugin, so that
            PASSWORD() uses the
            appropriate password hashing method. Therefore, to use the
            sha256_password or
            mysql_old_password plugin instead, name
            that plugin in the CREATE
            USER statement and set
            old_passwords to 2 or 1,
            respectively, before using SET
            PASSWORD. (Use of
            mysql_old_password is not recommended. It
            is deprecated and support for it will be removed in a future
            MySQL release.)
          
            To specify a password for an account at account-creation
            time, use IDENTIFIED BY with the literal
            cleartext password value:
          
CREATE USER 'jeffrey'@'localhost' IDENTIFIED BY 'mypass';
The server assigns an authentication plugin to the account implicitly, as described previously, and assigns the given password. Clients must provide the given password when they connect.
            If the implicitly assigned plugin is
            mysql_native_password, the
            old_passwords system
            variable must be set to 0. Otherwise,
            CREATE USER does not hash the
            password in the format required by the plugin and an error
            occurs:
          
mysql>SET old_passwords = 1;mysql>CREATE USER 'jeffrey'@'localhost' IDENTIFIED BY 'mypass';ERROR 1827 (HY000): The password hash doesn't have the expected format. Check if the correct password algorithm is being used with the PASSWORD() function. mysql>SET old_passwords = 0;mysql>CREATE USER 'jeffrey'@'localhost' IDENTIFIED BY 'mypass';Query OK, 0 rows affected (0.00 sec)
            To avoid specifying the cleartext password if you know its
            hash value (the value that
            PASSWORD() would return for
            the password), specify the hash value preceded by the
            keyword PASSWORD:
          
CREATE USER 'jeffrey'@'localhost' IDENTIFIED BY PASSWORD '*90E462C37378CED12064BB3388827D2BA3A9B689';
The server assigns an authentication plugin to the account implicitly, as described previously, and assigns the given password. The password hash must be in the format required by the assigned plugin. Clients must provide the password when they connect.
            To enable the user to connect with no password, include no
            IDENTIFIED BY clause:
          
CREATE USER 'jeffrey'@'localhost';
            The server assigns an authentication plugin to the account
            implicitly, as described previously, but no password.
            Clients must provide no password when they connect. However,
            an account with no password is insecure. To avoid this, use
            SET PASSWORD to set the
            account password.
        As mentioned previously, implicit plugin assignment depends on
        the default authentication plugin. Permitted values of
        --default-authentication-plugin
        are mysql_native_plugin and
        sha256_password, but not
        mysql_old_password. This means it is not
        possible to set the default plugin so as to be able to create an
        account that uses mysql_old_password with
        CREATE USER ... IDENTIFIED BY syntax. To
        create an account that uses
        mysql_old_password, use CREATE USER
        ... IDENTIFIED WITH to name the plugin explicitly,
        then set the password:
CREATE USER 'jeffrey'@'localhost' IDENTIFIED WITH mysql_old_password;
SET old_passwords = 1;
SET PASSWORD FOR 'jeffrey'@'localhost' = PASSWORD('mypass');
        However, the preceding procedure is not recommended because
        mysql_old_password is deprecated.
      
For additional information about setting passwords and authentication plugins, see Section 6.3.5, “Assigning Account Passwords”, and Section 6.3.7, “Pluggable Authentication”.
          Under some circumstances, CREATE
          USER may be recorded in server logs or on the client
          side in a history file such as
          ~/.mysql_history, which means that
          cleartext passwords may be read by anyone having read access
          to that information. For information about the conditions
          under which this occurs for the server logs and how to control
          it, see Section 6.1.2.3, “Passwords and Logging”. For similar
          information about client-side logging, see
          Section 4.5.1.3, “mysql Logging”.
DROP USERuser[,user] ...
        The DROP USER statement removes
        one or more MySQL accounts and their privileges. It removes
        privilege rows for the account from all grant tables. An error
        occurs for accounts that do not exist. To use this statement,
        you must have the global CREATE
        USER privilege or the
        DELETE privilege for the
        mysql database.
      
        When the read_only system
        variable is enabled, DROP USER
        requires the SUPER privilege, in
        addition to any other required privileges.
      
Each account name uses the format described in Section 6.2.3, “Specifying Account Names”. For example:
DROP USER 'jeffrey'@'localhost';
        If you specify only the user name part of the account name, a
        host name part of '%' is used.
          DROP USER does not
          automatically close any open user sessions. Rather, in the
          event that a user with an open session is dropped, the
          statement does not take effect until that user's session is
          closed. Once the session is closed, the user is dropped, and
          that user's next attempt to log in will fail. This
          is by design.
        DROP USER does not automatically
        drop or invalidate databases or objects within them that the old
        user created. This includes stored programs or views for which
        the DEFINER attribute names the dropped user.
        Attempts to access such objects may produce an error if they
        execute in definer security context. (For information about
        security context, see
        Section 20.6, “Access Control for Stored Programs and Views”.)
GRANT
    priv_type [(column_list)]
      [, priv_type [(column_list)]] ...
    ON [object_type] priv_level
    TO user_specification [, user_specification] ...
    [REQUIRE {NONE | ssl_option [[AND] ssl_option] ...}]
    [WITH {GRANT OPTION | resource_option} ...]
GRANT PROXY ON user_specification
    TO user_specification [, user_specification] ...
    [WITH GRANT OPTION]
object_type: {
    TABLE
  | FUNCTION
  | PROCEDURE
}
priv_level: {
    *
  | *.*
  | db_name.*
  | db_name.tbl_name
  | tbl_name
  | db_name.routine_name
}
user_specification:
    user [ auth_option ]
auth_option: {
    IDENTIFIED BY 'auth_string'
  | IDENTIFIED BY PASSWORD 'hash_string'
  | IDENTIFIED WITH auth_plugin
  | IDENTIFIED WITH auth_plugin AS 'hash_string'
}
ssl_option: {
    SSL
  | X509
  | CIPHER 'cipher'
  | ISSUER 'issuer'
  | SUBJECT 'subject'
}
resource_option: {
  | MAX_QUERIES_PER_HOUR count
  | MAX_UPDATES_PER_HOUR count
  | MAX_CONNECTIONS_PER_HOUR count
  | MAX_USER_CONNECTIONS count
}
        The GRANT statement grants
        privileges to MySQL user accounts. To use
        GRANT, you must have the
        GRANT OPTION privilege, and you
        must have the privileges that you are granting.
      
        GRANT also serves to specify
        other account characteristics such as use of secure connections
        and limits on access to server resources.
      
        When the read_only system
        variable is enabled, GRANT
        requires the SUPER privilege, in
        addition to any other required privileges.
      
        The REVOKE statement is related
        to GRANT and enables
        administrators to remove account privileges. See
        Section 13.7.1.6, “REVOKE Syntax”.
      
        Normally, a database administrator first uses
        CREATE USER to create an account,
        then GRANT to define its
        privileges and characteristics. For example:
      
CREATE USER 'jeffrey'@'localhost' IDENTIFIED BY 'mypass'; GRANT ALL ON db1.* TO 'jeffrey'@'localhost'; GRANT SELECT ON db2.invoice TO 'jeffrey'@'localhost'; GRANT USAGE ON *.* TO 'jeffrey'@'localhost' WITH MAX_QUERIES_PER_HOUR 90;
          Examples shown here include no IDENTIFIED
          clause. It is assumed that you establish passwords with
          CREATE USER at account-creation
          time to avoid creating insecure accounts.
        If an account named in a GRANT
        statement does not already exist,
        GRANT may create it under the
        conditions described later in the discussion of the
        NO_AUTO_CREATE_USER SQL mode.
      
        From the mysql program,
        GRANT responds with
        Query OK, 0 rows affected when executed
        successfully. To determine what privileges result from the
        operation, use SHOW GRANTS. See
        Section 13.7.5.22, “SHOW GRANTS Syntax”.
      
        There are several aspects to the
        GRANT statement, described under
        the following topics in this section:
        GRANT supports host names up to
        60 characters long. Database, table, column, and routine names
        can be up to 64 characters. User names can be up to 16
        characters.
          The permissible length for user names cannot be
          changed by altering the mysql.user table.
          Attempting to do so results in unpredictable behavior which
          may even make it impossible for users to log in to the MySQL
          server. You should never alter the structure of
          tables in the mysql database in any manner
          whatsoever except by means of the procedure described in
          Section 4.4.7, “mysql_upgrade — Check and Upgrade MySQL Tables”.
          Under some circumstances, GRANT
          may be recorded in server logs or on the client side in a
          history file such as ~/.mysql_history,
          which means that cleartext passwords may be read by anyone
          having read access to that information. For information about
          the conditions under which this occurs for the server logs and
          how to control it, see Section 6.1.2.3, “Passwords and Logging”. For
          similar information about client-side logging, see
          Section 4.5.1.3, “mysql Logging”.
        The following table summarizes the permissible
        priv_type privilege types that can be
        specified for the GRANT and
        REVOKE statements, and the levels
        at which each privilege can be granted. For additional
        information about these privileges, see
        Section 6.2.1, “Privileges Provided by MySQL”.
Table 13.1 Permissible Privileges for GRANT and REVOKE
| Privilege | Meaning and Grantable Levels | 
|---|---|
| ALL [PRIVILEGES] | Grant all privileges at specified access level except GRANT OPTION | 
| ALTER | Enable use of ALTER TABLE. Levels:
                Global, database, table. | 
| ALTER ROUTINE | Enable stored routines to be altered or dropped. Levels: Global, database, procedure. | 
| CREATE | Enable database and table creation. Levels: Global, database, table. | 
| CREATE ROUTINE | Enable stored routine creation. Levels: Global, database. | 
| CREATE TABLESPACE | Enable tablespaces and log file groups to be created, altered, or dropped. Level: Global. | 
| CREATE TEMPORARY TABLES | Enable use of CREATE
                TEMPORARY TABLE. Levels: Global, database. | 
| CREATE USER | Enable use of CREATE USER,DROP USER,RENAME USER, andREVOKE ALL
                PRIVILEGES. Level: Global. | 
| CREATE VIEW | Enable views to be created or altered. Levels: Global, database, table. | 
| DELETE | Enable use of DELETE. Level: Global,
                database, table. | 
| DROP | Enable databases, tables, and views to be dropped. Levels: Global, database, table. | 
| EVENT | Enable use of events for the Event Scheduler. Levels: Global, database. | 
| EXECUTE | Enable the user to execute stored routines. Levels: Global, database, table. | 
| FILE | Enable the user to cause the server to read or write files. Level: Global. | 
| GRANT OPTION | Enable privileges to be granted to or removed from other accounts. Levels: Global, database, table, procedure, proxy. | 
| INDEX | Enable indexes to be created or dropped. Levels: Global, database, table. | 
| INSERT | Enable use of INSERT. Levels: Global,
                database, table, column. | 
| LOCK TABLES | Enable use of LOCK TABLESon tables for
                which you have theSELECTprivilege. Levels: Global, database. | 
| PROCESS | Enable the user to see all processes with SHOW
                PROCESSLIST. Level: Global. | 
| PROXY | Enable user proxying. Level: From user to user. | 
| REFERENCES | Enable foreign key creation. Levels: Global, database, table, column. | 
| RELOAD | Enable use of FLUSHoperations. Level:
                Global. | 
| REPLICATION CLIENT | Enable the user to ask where master or slave servers are. Level: Global. | 
| REPLICATION SLAVE | Enable replication slaves to read binary log events from the master. Level: Global. | 
| SELECT | Enable use of SELECT. Levels: Global,
                database, table, column. | 
| SHOW DATABASES | Enable SHOW DATABASESto show all
                databases. Level: Global. | 
| SHOW VIEW | Enable use of SHOW CREATE VIEW. Levels:
                Global, database, table. | 
| SHUTDOWN | Enable use of mysqladmin shutdown. Level: Global. | 
| SUPER | Enable use of other administrative operations such as CHANGE MASTER TO,KILL,PURGE BINARY LOGS,SET
                GLOBAL, and mysqladmin
                debug command. Level: Global. | 
| TRIGGER | Enable trigger operations. Levels: Global, database, table. | 
| UPDATE | Enable use of UPDATE. Levels: Global,
database, table, column. | 
| USAGE | Synonym for “no privileges” | 
        A trigger is associated with a table, so to create or drop a
        trigger, you must have the
        TRIGGER privilege for the table,
        not the trigger.
      
        In GRANT statements, the
        ALL [PRIVILEGES]
        or PROXY privilege must be named
        by itself and cannot be specified along with other privileges.
        ALL [PRIVILEGES]
        stands for all privileges available for the level at which
        privileges are to be granted except for the
        GRANT OPTION and
        PROXY privileges.
      
        USAGE can be specified to create
        a user that has no privileges, or to specify the
        REQUIRE or WITH clauses
        for an account without changing its existing privileges.
      
        MySQL account information is stored in the tables of the
        mysql database. For additional details,
        consult Section 6.2, “The MySQL Access Privilege System”, which discusses the
        mysql database and the access control system
        extensively.
      
        If the grant tables hold privilege rows that contain mixed-case
        database or table names and the
        lower_case_table_names system
        variable is set to a nonzero value,
        REVOKE cannot be used to revoke
        these privileges. It will be necessary to manipulate the grant
        tables directly. (GRANT will not
        create such rows when
        lower_case_table_names is set,
        but such rows might have been created prior to setting that
        variable.)
      
        Privileges can be granted at several levels, depending on the
        syntax used for the ON clause. For
        REVOKE, the same
        ON syntax specifies which privileges to
        remove.
      
        For the global, database, table, and routine levels,
        GRANT ALL
        assigns only the privileges that exist at the level you are
        granting. For example, GRANT ALL ON
         is a
        database-level statement, so it does not grant any global-only
        privileges such as db_name.*FILE. Granting
        ALL does not assign the
        GRANT OPTION or
        PROXY privilege.
      
        The object_type clause, if present,
        should be specified as TABLE,
        FUNCTION, or PROCEDURE
        when the following object is a table, a stored function, or a
        stored procedure.
      
        The privileges for a database, table, column, or routine are
        formed additively as the logical OR
        of the privileges at each of the privilege levels. For example,
        if a user has a global SELECT
        privilege, the privilege cannot be denied by an absence of the
        privilege at the database, table, or column level. Details of
        the privilege-checking procedure are presented in
        Section 6.2.5, “Access Control, Stage 2: Request Verification”.
      
If you are using table, column, or routine privileges for even one user, the server examines table, column, and routine privileges for all users and this slows down MySQL a bit. Similarly, if you limit the number of queries, updates, or connections for any users, the server must monitor these values.
        MySQL enables you to grant privileges on databases or tables
        that do not exist. For tables, the privileges to be granted must
        include the CREATE privilege.
        This behavior is by design, and is intended
        to enable the database administrator to prepare user accounts
        and privileges for databases or tables that are to be created at
        a later time.
MySQL does not automatically revoke any privileges when you drop a database or table. However, if you drop a routine, any routine-level privileges granted for that routine are revoked.
        Global privileges are administrative or apply to all databases
        on a given server. To assign global privileges, use ON
        *.* syntax:
      
GRANT ALL ON *.* TO 'someuser'@'somehost'; GRANT SELECT, INSERT ON *.* TO 'someuser'@'somehost';
        The CREATE TABLESPACE,
        CREATE USER,
        FILE,
        PROCESS,
        RELOAD,
        REPLICATION CLIENT,
        REPLICATION SLAVE,
        SHOW DATABASES,
        SHUTDOWN, and
        SUPER privileges are
        administrative and can only be granted globally.
      
Other privileges can be granted globally or at more specific levels.
        MySQL stores global privileges in the
        mysql.user table.
        Database privileges apply to all objects in a given database. To
        assign database-level privileges, use ON
         syntax:
      db_name.*
GRANT ALL ON mydb.* TO 'someuser'@'somehost'; GRANT SELECT, INSERT ON mydb.* TO 'someuser'@'somehost';
        If you use ON * syntax (rather than
        ON *.*) and you have selected a default
        database, privileges are assigned at the database level for the
        default database. An error occurs if there is no default
        database.
      
        The CREATE,
        DROP,
        EVENT, GRANT
        OPTION, LOCK TABLES,
        and REFERENCES privileges can be
        specified at the database level. Table or routine privileges
        also can be specified at the database level, in which case they
        apply to all tables or routines in the database.
      
        MySQL stores database privileges in the
        mysql.db table.
        Table privileges apply to all columns in a given table. To
        assign table-level privileges, use ON
         syntax:
      db_name.tbl_name
GRANT ALL ON mydb.mytbl TO 'someuser'@'somehost'; GRANT SELECT, INSERT ON mydb.mytbl TO 'someuser'@'somehost';
        If you specify tbl_name rather than
        db_name.tbl_name, the statement
        applies to tbl_name in the default
        database. An error occurs if there is no default database.
      
        The permissible priv_type values at
        the table level are ALTER,
        CREATE VIEW,
        CREATE,
        DELETE,
        DROP, GRANT
        OPTION, INDEX,
        INSERT,
        REFERENCES,
        SELECT, SHOW
        VIEW, TRIGGER, and
        UPDATE.
      
        MySQL stores table privileges in the
        mysql.tables_priv table.
Column privileges apply to single columns in a given table. Each privilege to be granted at the column level must be followed by the column or columns, enclosed within parentheses.
GRANT SELECT (col1), INSERT (col1,col2) ON mydb.mytbl TO 'someuser'@'somehost';
        The permissible priv_type values for
        a column (that is, when you use a
        column_list clause) are
        INSERT,
        REFERENCES,
        SELECT, and
        UPDATE.
      
        MySQL stores column privileges in the
        mysql.columns_priv table.
        The ALTER ROUTINE,
        CREATE ROUTINE,
        EXECUTE, and
        GRANT OPTION privileges apply to
        stored routines (procedures and functions). They can be granted
        at the global and database levels. Except for
        CREATE ROUTINE, these privileges
        can be granted at the routine level for individual routines.
      
GRANT CREATE ROUTINE ON mydb.* TO 'someuser'@'somehost'; GRANT EXECUTE ON PROCEDURE mydb.myproc TO 'someuser'@'somehost';
        The permissible priv_type values at
        the routine level are ALTER
        ROUTINE, EXECUTE, and
        GRANT OPTION.
        CREATE ROUTINE is not a
        routine-level privilege because you must have this privilege to
        create a routine in the first place.
      
        MySQL stores routine-level privileges in the
        mysql.procs_priv table.
        The PROXY privilege enables one
        user to be a proxy for another. The proxy user impersonates or
        takes the identity of the proxied user.
      
GRANT PROXY ON 'localuser'@'localhost' TO 'externaluser'@'somehost';
        When PROXY is granted, it must be
        the only privilege named in the
        GRANT statement, the
        REQUIRE clause cannot be given, and the only
        permitted WITH option is WITH GRANT
        OPTION.
      
        Proxying requires that the proxy user authenticate through a
        plugin that returns the name of the proxied user to the server
        when the proxy user connects, and that the proxy user have the
        PROXY privilege for the proxied user. For
        details and examples, see Section 6.3.9, “Proxy Users”.
      
        MySQL stores proxy privileges in the
        mysql.proxies_priv table.
        The user_specification clause names a
        user and optionally provides authentication information such as
        a password.
      
        The user value indicates the MySQL
        account to which the GRANT
        statement applies. To accommodate granting rights to users from
        arbitrary hosts, MySQL supports specifying the
        user value in the form
        user_name@host_nameuser_name or
        host_name value is legal as an
        unquoted identifier, you need not quote it. However, quotation
        marks are necessary to specify a
        user_name string containing special
        characters (such as “-”), or a
        host_name string containing special
        characters or wildcard characters (such as
        “%”); for example,
        'test-user'@'%.com'. Quote the user name and
        host name separately.
      
        You can specify wildcards in the host name. For example,
        user_name@'%.example.com'user_name for any host in
        the example.com domain, and
        user_name@'192.168.1.%'user_name for any host in
        the 192.168.1 class C subnet.
      
        The simple form user_name is a
        synonym for
        user_name@'%'
        MySQL does not support wildcards in user
        names. To refer to an anonymous user, specify an
        account with an empty user name with the
        GRANT statement:
      
GRANT ALL ON test.* TO ''@'localhost' ...;
In this case, any user who connects from the local host with the correct password for the anonymous user will be permitted access, with the privileges associated with the anonymous-user account.
For additional information about user name and host name values in account names, see Section 6.2.3, “Specifying Account Names”.
To specify quoted values, quote database, table, column, and routine names as identifiers. Quote user names and host names as identifiers or as strings. Quote passwords as strings. For string-quoting and identifier-quoting guidelines, see Section 9.1.1, “String Literals”, and Section 9.2, “Schema Object Names”.
        The “_” and
        “%” wildcards are permitted when
        specifying database names in
        GRANT statements that grant
        privileges at the global or database levels. This means, for
        example, that if you want to use a
        “_” character as part of a
        database name, you should specify it as
        “\_” in the
        GRANT statement, to prevent the
        user from being able to access additional databases matching the
        wildcard pattern; for example, GRANT ... ON
        `foo\_bar`.* TO ....
          If you permit anonymous users to connect to the MySQL server,
          you should also grant privileges to all local users as
          user_name@localhostlocalhost in the
          mysql.user table (created during MySQL
          installation) is used when named users try to log in to the
          MySQL server from the local machine. For details, see
          Section 6.2.4, “Access Control, Stage 1: Connection Verification”.
To determine whether the preceding warning applies to you, execute the following query, which lists any anonymous users:
SELECT Host, User FROM mysql.user WHERE User='';
To avoid the problem just described, delete the local anonymous user account using this statement:
DROP USER ''@'localhost';
        To indicate how the user should authenticate when connecting to
        the server, the user_specification
        value may include an IDENTIFIED clause to
        specify an authentication plugin, a password, or both. Syntax of
        the user specification is the same as for the
        CREATE USER statement. For
        details, see Section 13.7.1.2, “CREATE USER Syntax”.
      
        When IDENTIFIED BY is present and you have
        the global grant privilege (GRANT
        OPTION), the password becomes the new password for the
        account, even if the account exists and already has a password.
        Without IDENTIFIED BY, the account password
        remains unchanged.
      
        If an account named in a GRANT
        statement does not exist, the action taken depends on the
        NO_AUTO_CREATE_USER SQL mode:
            If NO_AUTO_CREATE_USER is
            not enabled, GRANT creates
            the account. This is very insecure
            unless you specify a nonempty password using
            IDENTIFIED BY.
          
            If NO_AUTO_CREATE_USER is
            enabled, GRANT fails and does
            not create the account, unless you specify a nonempty
            password using IDENTIFIED BY or name an
            authentication plugin using IDENTIFIED
            WITH.
        As of MySQL 5.6.12, if the account already exists,
        IDENTIFIED WITH is prohibited because it is
        intended only for use when creating new accounts.
MySQL can check X509 certificate attributes in addition to the usual authentication that is based on the user name and credentials. For background information on the use of SSL with MySQL, see Section 6.3.10, “Using SSL for Secure Connections”.
        The optional REQUIRE clause specifies
        SSL-related options for a MySQL account, using one or more
        ssl_option values.
      
        GRANT permits these
        ssl_option values:
            NONE
          
            Indicates that the account has no SSL or X509 requirements.
            Unencrypted connections are permitted if the user name and
            password are valid. However, encrypted connections can also
            be used, at the client's option, if the client has the
            proper certificate and key files. That is, the client need
            not specify any SSL command options, in which case the
            connection will be unencrypted. To use an encrypted
            connection, the client must specify either the
            --ssl-ca option, or all
            three of the --ssl-ca,
            --ssl-key, and
            --ssl-cert options.
          
            NONE is the default if no SSL-related
            REQUIRE options are specified.
          
            SSL
          
Tells the server to permit only SSL-encrypted connections for the account.
GRANT ALL PRIVILEGES ON test.* TO 'root'@'localhost' REQUIRE SSL;
            To connect, the client must specify the
            --ssl-ca option to
            authenticate the server certificate, and may additionally
            specify the --ssl-key and
            --ssl-cert options. If
            neither --ssl-ca option nor
            --ssl-capath option is
            specified, the client does not authenticate the server
            certificate.
          
            X509
          
Requires that the client must have a valid certificate but the exact certificate, issuer, and subject do not matter. The only requirement is that it should be possible to verify its signature with one of the CA certificates.
GRANT ALL PRIVILEGES ON test.* TO 'root'@'localhost' REQUIRE X509;
            To connect, the client must specify the
            --ssl-ca,
            --ssl-key, and
            --ssl-cert options. This is
            also true for ISSUER and
            SUBJECT because those
            REQUIRE options imply
            X509.
          
            ISSUER
            '
          issuer'
            Places the restriction on connection attempts that the
            client must present a valid X509 certificate issued by CA
            '. If
            the client presents a certificate that is valid but has a
            different issuer, the server rejects the connection. Use of
            X509 certificates always implies encryption, so the
            issuer'SSL option is unnecessary in this case.
          
GRANT ALL PRIVILEGES ON test.* TO 'root'@'localhost'
  REQUIRE ISSUER '/C=SE/ST=Stockholm/L=Stockholm/
    O=MySQL/CN=CA/emailAddress=ca@example.com';
              If MySQL is linked against a version of OpenSSL older than
              0.9.6h, use Email rather than
              emailAddress in the
              '
              value.
issuer'
            SUBJECT
            '
          subject'
            Places the restriction on connection attempts that the
            client must present a valid X509 certificate containing the
            subject subject. If the client
            presents a certificate that is valid but has a different
            subject, the server rejects the connection.
          
GRANT ALL PRIVILEGES ON test.* TO 'root'@'localhost'
  REQUIRE SUBJECT '/C=SE/ST=Stockholm/L=Stockholm/
    O=MySQL demo client certificate/
    CN=client/emailAddress=client@example.com';
            MySQL does a simple string comparison of the
            '
            value to the value in the certificate, so lettercase and
            component ordering must be given exactly as present in the
            certificate.
subject'
              Regarding emailAddress, see the note in
              the description of REQUIRE ISSUER.
            CIPHER
            '
          cipher'
Requests a specific cipher method for connections. This option is needed to ensure that ciphers and key lengths of sufficient strength are used. SSL itself can be weak if old algorithms using short encryption keys are used.
GRANT ALL PRIVILEGES ON test.* TO 'root'@'localhost' REQUIRE CIPHER 'EDH-RSA-DES-CBC3-SHA';
        The SUBJECT, ISSUER, and
        CIPHER options can be combined in the
        REQUIRE clause like this:
      
GRANT ALL PRIVILEGES ON test.* TO 'root'@'localhost'
  REQUIRE SUBJECT '/C=SE/ST=Stockholm/L=Stockholm/
    O=MySQL demo client certificate/
    CN=client/emailAddress=client@example.com'
  AND ISSUER '/C=SE/ST=Stockholm/L=Stockholm/
    O=MySQL/CN=CA/emailAddress=ca@example.com'
  AND CIPHER 'EDH-RSA-DES-CBC3-SHA';
        The order of the options does not matter, but no option can be
        specified twice. The AND keyword is optional
        between REQUIRE options.
      
        The optional WITH clause is used for these
        purposes:
To enable a user to grant privileges to other users
To specify resource limits for a user
        The WITH GRANT OPTION clause gives the user
        the ability to give to other users any privileges the user has
        at the specified privilege level.
      
        To grant the GRANT OPTION
        privilege to an account without otherwise changing its
        privileges, do this:
      
GRANT USAGE ON *.* TO 'someuser'@'somehost' WITH GRANT OPTION;
        Be careful to whom you give the GRANT
        OPTION privilege because two users with different
        privileges may be able to combine privileges!
      
        You cannot grant another user a privilege which you yourself do
        not have; the GRANT OPTION
        privilege enables you to assign only those privileges which you
        yourself possess.
      
        Be aware that when you grant a user the
        GRANT OPTION privilege at a
        particular privilege level, any privileges the user possesses
        (or may be given in the future) at that level can also be
        granted by that user to other users. Suppose that you grant a
        user the INSERT privilege on a
        database. If you then grant the
        SELECT privilege on the database
        and specify WITH GRANT OPTION, that user can
        give to other users not only the
        SELECT privilege, but also
        INSERT. If you then grant the
        UPDATE privilege to the user on
        the database, the user can grant
        INSERT,
        SELECT, and
        UPDATE.
      
        For a nonadministrative user, you should not grant the
        ALTER privilege globally or for
        the mysql database. If you do that, the user
        can try to subvert the privilege system by renaming tables!
      
For additional information about security risks associated with particular privileges, see Section 6.2.1, “Privileges Provided by MySQL”.
        It is possible to place limits on use of server resources by an
        account, as discussed in Section 6.3.4, “Setting Account Resource Limits”. To do
        so, use a WITH clause that specifies one or
        more resource_option values. Limits
        not specified retain their current values.
      
        GRANT permits these
        resource_option values:
            MAX_QUERIES_PER_HOUR
            ,
            countMAX_UPDATES_PER_HOUR
            ,
            countMAX_CONNECTIONS_PER_HOUR
            
          count
            These options restrict the number of queries, updates, and
            connections to the server permitted to this account during
            any given one-hour period. (Queries for which results are
            served from the query cache do not count against the
            MAX_QUERIES_PER_HOUR limit.) If
            count is 0
            (the default), this means that there is no limitation for
            the account.
          
            MAX_USER_CONNECTIONS
            
          count
            Restricts the maximum number of simultaneous connections to
            the server by the account. A nonzero
            count specifies the limit for the
            account explicitly. If count is
            0 (the default), the server determines
            the number of simultaneous connections for the account from
            the global value of the
            max_user_connections system
            variable. If
            max_user_connections is
            also zero, there is no limit for the account.
If a given resource limit is specified multiple times, the last instance takes precedence.
        To specify resource limits for an existing user without
        affecting existing privileges, use
        GRANT USAGE at
        the global level (ON *.*) and name the limits
        to be changed. For example:
      
GRANT USAGE ON *.* TO ... WITH MAX_QUERIES_PER_HOUR 500 MAX_UPDATES_PER_HOUR 100;
        The biggest differences between the MySQL and standard SQL
        versions of GRANT are:
MySQL associates privileges with the combination of a host name and user name and not with only a user name.
Standard SQL does not have global or database-level privileges, nor does it support all the privilege types that MySQL supports.
            MySQL does not support the standard SQL
            UNDER privilege.
          
            Standard SQL privileges are structured in a hierarchical
            manner. If you remove a user, all privileges the user has
            been granted are revoked. This is also true in MySQL if you
            use DROP USER. See
            Section 13.7.1.3, “DROP USER Syntax”.
          
            In standard SQL, when you drop a table, all privileges for
            the table are revoked. In standard SQL, when you revoke a
            privilege, all privileges that were granted based on that
            privilege are also revoked. In MySQL, privileges can be
            dropped only with explicit DROP
            USER or REVOKE
            statements or by manipulating the MySQL grant tables
            directly.
          
            In MySQL, it is possible to have the
            INSERT privilege for only
            some of the columns in a table. In this case, you can still
            execute INSERT statements on
            the table, provided that you insert values only for those
            columns for which you have the
            INSERT privilege. The omitted
            columns are set to their implicit default values if strict
            SQL mode is not enabled. In strict mode, the statement is
            rejected if any of the omitted columns have no default
            value. (Standard SQL requires you to have the
            INSERT privilege on all
            columns.) Section 5.1.7, “Server SQL Modes”, discusses strict mode.
            Section 11.6, “Data Type Default Values”, discusses implicit
            default values.
RENAME USERold_userTOnew_user[,old_userTOnew_user] ...
        The RENAME USER statement renames
        existing MySQL accounts. An error occurs for old accounts that
        do not exist or new accounts that already exist. To use this
        statement, you must have the global CREATE
        USER privilege or the
        UPDATE privilege for the
        mysql database.
      
        When the read_only system
        variable is enabled, RENAME USER
        requires the SUPER privilege, in
        addition to any other required privileges.
      
Each account name uses the format described in Section 6.2.3, “Specifying Account Names”. For example:
RENAME USER 'jeffrey'@'localhost' TO 'jeff'@'127.0.0.1';
        If you specify only the user name part of the account name, a
        host name part of '%' is used.
      
        RENAME USER causes the privileges
        held by the old user to be those held by the new user. However,
        RENAME USER does not
        automatically drop or invalidate databases or objects within
        them that the old user created. This includes stored programs or
        views for which the DEFINER attribute names
        the old user. Attempts to access such objects may produce an
        error if they execute in definer security context. (For
        information about security context, see
        Section 20.6, “Access Control for Stored Programs and Views”.)
      
The privilege changes take effect as indicated in Section 6.2.6, “When Privilege Changes Take Effect”.
REVOKE
    priv_type [(column_list)]
      [, priv_type [(column_list)]] ...
    ON [object_type] priv_level
    FROM user [, user] ...
REVOKE ALL PRIVILEGES, GRANT OPTION
    FROM user [, user] ...
REVOKE PROXY ON user
    FROM user [, user] ...
        The REVOKE statement enables
        system administrators to revoke privileges from MySQL accounts.
        Each account name uses the format described in
        Section 6.2.3, “Specifying Account Names”. For example:
      
REVOKE INSERT ON *.* FROM 'jeffrey'@'localhost';
        When the read_only system
        variable is enabled, REVOKE
        requires the SUPER privilege, in
        addition to any other required privileges.
      
        If you specify only the user name part of the account name, a
        host name part of '%' is used.
      
        For details on the levels at which privileges exist, the
        permissible priv_type and
        priv_level values, and the syntax for
        specifying users and passwords, see Section 13.7.1.4, “GRANT Syntax”
      
        To use the first REVOKE syntax,
        you must have the GRANT OPTION
        privilege, and you must have the privileges that you are
        revoking.
      
To revoke all privileges, use the second syntax, which drops all global, database, table, column, and routine privileges for the named user or users:
REVOKE ALL PRIVILEGES, GRANT OPTION FROMuser[,user] ...
        To use this REVOKE syntax, you
        must have the global CREATE USER
        privilege or the UPDATE privilege
        for the mysql database.
      
        REVOKE removes privileges, but
        does not drop mysql.user table entries. To
        remove a user account entirely, use DROP
        USER (see Section 13.7.1.3, “DROP USER Syntax”) or
        DELETE.
      
        If the grant tables hold privilege rows that contain mixed-case
        database or table names and the
        lower_case_table_names system
        variable is set to a nonzero value,
        REVOKE cannot be used to revoke
        these privileges. It will be necessary to manipulate the grant
        tables directly. (GRANT will not
        create such rows when
        lower_case_table_names is set,
        but such rows might have been created prior to setting the
        variable.)
      
        When successfully executed from the mysql
        program, REVOKE responds with
        Query OK, 0 rows affected. To determine what
        privileges result from the operation, use
        SHOW GRANTS. See
        Section 13.7.5.22, “SHOW GRANTS Syntax”.
SET PASSWORD [FORuser] =password_optionpassword_option: { PASSWORD('auth_string') | OLD_PASSWORD('auth_string') | 'hash_string' }
        The SET PASSWORD statement
        assigns a password to a MySQL user account:
            With no FOR
             clause, this
            statement sets the password for the current user:
          user
SET PASSWORD = password_option;
            Any client who connects to the server using a nonanonymous
            account can change the password for that account. To see
            which account the server authenticated you as, invoke the
            CURRENT_USER() function:
          
SELECT CURRENT_USER();
            Permitted old_passwords
            values are described later in this section.
          
            With a FOR
             clause, this
            statement sets the password for the named account, which
            must exist:
          user
SET PASSWORD FOR 'jeffrey'@'localhost' = password_option;
            In this case, you must have the
            UPDATE privilege for the
            mysql database.
        When the read_only system
        variable is enabled, SET PASSWORD
        requires the SUPER privilege, in
        addition to any other required privileges.
      
        If a FOR 
        clause is given, the account name uses the format described in
        Section 6.2.3, “Specifying Account Names”. The
        useruser value should be given as
        ',
        where user_name'@'host_name''
        and user_name''
        are exactly as listed in the host_name'User and
        Host columns of the account's
        mysql.user table row. If you specify only a
        user name, a host name of '%' is used. For
        example, to set the password for an account with
        User and Host column
        values of 'bob' and
        '%.example.org', write the statement like
        this:
      
SET PASSWORD FOR 'bob'@'%.example.org' = PASSWORD('cleartext password');
The password can be specified in these ways:
            Using the PASSWORD() function
          
            The
            '
            function argument is the cleartext (unencrypted) password.
            auth_string'PASSWORD() hashes the
            password and returns the encrypted password string for
            storage in the mysql.user account row.
          
            The old_passwords system
            variable value determines the hashing method used by
            PASSWORD(). If
            SET PASSWORD rejects the
            password as not being in the correct format, it may be
            necessary to change
            old_passwords to change the
            hashing method. For example, if the account uses the
            mysql_native_password plugin, the
            old_passwords value must be
            0:
          
SET old_passwords = 0;
SET PASSWORD FOR 'jeffrey'@'localhost' = PASSWORD('mypass');
            If the old_passwords value
            differs from that required by the authentication plugin, the
            hashed password value returned by
            PASSWORD() is not acceptable
            for that plugin, and attempts to set the password produce an
            error. For example:
          
mysql>SET old_passwords = 1;mysql>SET PASSWORD FOR 'jeffrey'@'localhost' = PASSWORD('mypass');ERROR 1372 (HY000): Password hash should be a 41-digit hexadecimal number
            Permitted old_passwords
            values are described later in this section.
          
            Using the OLD_PASSWORD()
            function:
          
            The
            '
            function argument is the cleartext (unencrypted) password.
            auth_string'OLD_PASSWORD() hashes the
            password using pre-4.1 hashing and returns the encrypted
            password string for storage in the
            mysql.user account row. This hashing
            method is appropriate only for accounts that use the
            mysql_old_password authentication plugin.
          
Using an already encrypted password string
The password is specified as a string literal. It must represent the already encrypted password value, in the hash format required by the authentication method used for the account.
        The following table shows the permitted values of
        old_passwords, the password
        hashing method for each value, and which authentication plugins
        use passwords hashed with each method. These values are
        permitted as of MySQL 5.6.6. Before 5.6.6, the permitted values
        are 0 (or OFF) and 1 (or
        ON).
| Value | Password Hashing Method | Associated Authentication Plugin | 
|---|---|---|
| 0 | MySQL 4.1 native hashing | mysql_native_password | 
| 1 | Pre-4.1 (“old”) hashing | mysql_old_password | 
| 2 | SHA-256 hashing | sha256_password | 
For more information about setting passwords, see Section 6.3.5, “Assigning Account Passwords”
          Under some circumstances, SET
          PASSWORD may be recorded in server logs or on the
          client side in a history file such as
          ~/.mysql_history, which means that
          cleartext passwords may be read by anyone having read access
          to that information. For information about the conditions
          under which this occurs for the server logs and how to control
          it, see Section 6.1.2.3, “Passwords and Logging”. For similar
          information about client-side logging, see
          Section 4.5.1.3, “mysql Logging”.
If you are connecting to a MySQL 4.1 or later server using a pre-4.1 client program, do not change your password without first reading Section 6.1.2.4, “Password Hashing in MySQL”. The default password hashing format changed in MySQL 4.1, and if you change your password, it might be stored using a hashing format that pre-4.1 clients cannot generate, thus preventing you from connecting to the server afterward.
        If you are using MySQL Replication, be aware that, currently, a
        password used by a replication slave as part of a
        CHANGE MASTER TO statement is
        effectively limited to 32 characters in length; if the password
        is longer, any excess characters are truncated. This is not due
        to any limit imposed by the MySQL Server generally, but rather
        is an issue specific to MySQL Replication. (For more
        information, see Bug #43439.)
ANALYZE [NO_WRITE_TO_BINLOG | LOCAL] TABLE
    tbl_name [, tbl_name] ...
        ANALYZE TABLE analyzes and stores the key
        distribution for a table. During the analysis, the table is
        locked with a read lock for InnoDB and
        MyISAM. This statement works with
        InnoDB, NDB, and
        MyISAM tables. For MyISAM
        tables, this statement is equivalent to using myisamchk
        --analyze.
      
        For more information on how the analysis works within
        InnoDB, see
        Section 14.3.11.1, “Configuring Persistent Optimizer Statistics Parameters” and
        Section 14.3.11.3, “Estimating ANALYZE TABLE Complexity for InnoDB Tables”. Also see
        Section 14.5.7, “Limits on InnoDB Tables”. In particular, when you
        enable the
        innodb_stats_persistent option,
        you must run ANALYZE TABLE after loading
        substantial data into an InnoDB table, or
        creating a new index for one.
      
MySQL uses the stored key distribution to decide the order in which tables should be joined when you perform a join on something other than a constant. In addition, key distributions can be used when deciding which indexes to use for a specific table within a query.
        This statement requires SELECT
        and INSERT privileges for the
        table.
      
        ANALYZE TABLE is supported for partitioned
        tables, and you can use ALTER TABLE ... ANALYZE
        PARTITION to analyze one or more partitions; for more
        information, see Section 13.1.7, “ALTER TABLE Syntax”, and
        Section 19.3.4, “Maintenance of Partitions”.
      
        In MySQL 5.6.11 only, gtid_next
        must be set to AUTOMATIC before issuing this
        statement. (Bug #16062608, Bug #16715809, Bug #69045)
      
        ANALYZE TABLE returns a result set with the
        following columns.
| Column | Value | 
|---|---|
| Table | The table name | 
| Op | Always analyze | 
| Msg_type | status,error,info,note, orwarning | 
| Msg_text | An informational message | 
        You can check the stored key distribution with the
        SHOW INDEX statement. See
        Section 13.7.5.23, “SHOW INDEX Syntax”.
      
        If the table has not changed since the last ANALYZE
        TABLE statement, the table is not analyzed again.
      
        By default, the server writes ANALYZE
        TABLE statements to the binary log so that they
        replicate to replication slaves. To suppress logging, specify
        the optional NO_WRITE_TO_BINLOG keyword or
        its alias LOCAL.
CHECK TABLEtbl_name[,tbl_name] ... [option] ...option= { FOR UPGRADE | QUICK | FAST | MEDIUM | EXTENDED | CHANGED }
        CHECK TABLE checks a table or tables for
        errors. CHECK TABLE works for
        InnoDB,
        MyISAM,
        ARCHIVE, and
        CSV tables. For
        MyISAM tables, the key statistics are updated
        as well.
      
To check a table, you must have some privilege for it.
        CHECK TABLE can also check views for
        problems, such as tables that are referenced in the view
        definition that no longer exist.
      
        CHECK TABLE is supported for partitioned
        tables, and you can use ALTER TABLE ... CHECK
        PARTITION to check one or more partitions; for more
        information, see Section 13.1.7, “ALTER TABLE Syntax”, and
        Section 19.3.4, “Maintenance of Partitions”.
      
        In MySQL 5.6.11 only, gtid_next
        must be set to AUTOMATIC before issuing this
        statement. (Bug #16062608, Bug #16715809, Bug #69045)
        CHECK TABLE returns a result set with the
        following columns.
| Column | Value | 
|---|---|
| Table | The table name | 
| Op | Always check | 
| Msg_type | status,error,info,note, orwarning | 
| Msg_text | An informational message | 
        The statement might produce many rows of information for each
        checked table. The last row has a Msg_type
        value of status and the
        Msg_text normally should be
        OK. If you don't get OK,
        or Table is already up to date you should or
        Table is already up to date for a
        MyISAM table, you should normally run a
        repair of the table. See
        Section 7.6, “MyISAM Table Maintenance and Crash Recovery”. Table is
        already up to date means that the storage engine for
        the table indicated that there was no need to check the table.
        The FOR UPGRADE option checks whether the
        named tables are compatible with the current version of MySQL.
        With FOR UPGRADE, the server checks each
        table to determine whether there have been any incompatible
        changes in any of the table's data types or indexes since the
        table was created. If not, the check succeeds. Otherwise, if
        there is a possible incompatibility, the server runs a full
        check on the table (which might take some time). If the full
        check succeeds, the server marks the table's
        .frm file with the current MySQL version
        number. Marking the .frm file ensures that
        further checks for the table with the same version of the server
        will be fast.
      
Incompatibilities might occur because the storage format for a data type has changed or because its sort order has changed. Our aim is to avoid these changes, but occasionally they are necessary to correct problems that would be worse than an incompatibility between releases.
        Currently, FOR UPGRADE discovers these
        incompatibilities:
            The indexing order for end-space in
            TEXT columns for
            InnoDB and MyISAM
            tables changed between MySQL 4.1 and 5.0.
          
            The storage method of the new
            DECIMAL data type changed
            between MySQL 5.0.3 and 5.0.5.
          
            If your table was created by a different version of the
            MySQL server than the one you are currently running,
            FOR UPGRADE indicates that the table has
            an .frm file with an incompatible
            version. In this case, the result set returned by
            CHECK TABLE contains a line
            with a Msg_type value of
            error and a Msg_text
            value of Table upgrade required. Please do "REPAIR
            TABLE `
          tbl_name`" to fix
            it!
            Changes are sometimes made to character sets or collations
            that require table indexes to be rebuilt. For details about
            these changes and when FOR UPGRADE
            detects them, see
            Section 2.11.3, “Checking Whether Tables or Indexes Must Be Rebuilt”.
          
            The YEAR(2) data type is
            deprecated as of MySQL 5.6.6. For tables containing
            YEAR(2) columns,
            CHECK TABLE recommends
            REPAIR TABLE, which converts
            YEAR(2) to
            YEAR(4).
The following table shows the other check options that can be given. These options are passed to the storage engine, which may use them or not.
| Type | Meaning | 
|---|---|
| QUICK | Do not scan the rows to check for incorrect links. Applies to InnoDBandMyISAMtables and views. | 
| FAST | Check only tables that have not been closed properly. Applies only to MyISAMtables and views; ignored forInnoDB. | 
| CHANGED | Check only tables that have been changed since the last check or that
                have not been closed properly. Applies only to MyISAMtables and views; ignored forInnoDB. | 
| MEDIUM | Scan rows to verify that deleted links are valid. This also calculates a
                key checksum for the rows and verifies this with a
                calculated checksum for the keys. Applies only to MyISAMtables and views; ignored forInnoDB. | 
| EXTENDED | Do a full key lookup for all keys for each row. This ensures that the
                table is 100% consistent, but takes a long time. Applies
                only to MyISAMtables and views;
ignored forInnoDB. | 
        If none of the options QUICK,
        MEDIUM, or EXTENDED are
        specified, the default check type for dynamic-format
        MyISAM tables is MEDIUM.
        This has the same result as running myisamchk
        --medium-check tbl_name on
        the table. The default check type also is
        MEDIUM for static-format
        MyISAM tables, unless
        CHANGED or FAST is
        specified. In that case, the default is
        QUICK. The row scan is skipped for
        CHANGED and FAST because
        the rows are very seldom corrupted.
      
You can combine check options, as in the following example that does a quick check on the table to determine whether it was closed properly:
CHECK TABLE test_table FAST QUICK;
          CHECK TABLE may change the
          table if the table is marked as “corrupted” or
          “not closed properly” but
          CHECK TABLE does not find any
          problems in the table. In this case,
          CHECK TABLE marks the table as
          okay.
If a table is corrupted, the problem is most likely in the indexes and not in the data part. All of the preceding check types check the indexes thoroughly and should thus find most errors.
        If you just want to check a table that you assume is okay, you
        should use no check options or the QUICK
        option. The latter should be used when you are in a hurry and
        can take the very small risk that QUICK does
        not find an error in the data file. (In most cases, under normal
        usage, MySQL should find any error in the data file. If this
        happens, the table is marked as “corrupted” and
        cannot be used until it is repaired.)
      
        FAST and CHANGED are
        mostly intended to be used from a script (for example, to be
        executed from cron) if you want to check
        tables from time to time. In most cases, FAST
        is to be preferred over CHANGED. (The only
        case when it is not preferred is when you suspect that you have
        found a bug in the MyISAM code.)
      
        EXTENDED is to be used only after you have
        run a normal check but still get strange errors from a table
        when MySQL tries to update a row or find a row by key. This is
        very unlikely if a normal check has succeeded.
      
        Use of CHECK TABLE
        ... EXTENDED might influence the execution plan
        generated by the query optimizer.
      
        Some problems reported by CHECK
        TABLE cannot be corrected automatically:
            Found row where the auto_increment column has the
            value 0.
          
            This means that you have a row in the table where the
            AUTO_INCREMENT index column contains the
            value 0. (It is possible to create a row where the
            AUTO_INCREMENT column is 0 by explicitly
            setting the column to 0 with an
            UPDATE statement.)
          
            This is not an error in itself, but could cause trouble if
            you decide to dump the table and restore it or do an
            ALTER TABLE on the table. In
            this case, the AUTO_INCREMENT column
            changes value according to the rules of
            AUTO_INCREMENT columns, which could cause
            problems such as a duplicate-key error.
          
            To get rid of the warning, execute an
            UPDATE statement to set the
            column to some value other than 0.
        The following notes apply to InnoDB
        tables:
            If CHECK TABLE finds a
            problem for an InnoDB table, the server
            may shut down to prevent error propagation. Details of the
            error will be written to the error log.
          
            If CHECK TABLE encounters
            corruptions or errors in InnoDB tables or
            indexes, it reports an error. It does not shut down the
            server. Starting with MySQL 5.5, CHECK
            TABLE usually marks the index and sometimes marks
            the table as corrupted, preventing further use of the index
            or table.
          
            If CHECK TABLE finds the
            wrong number of entries in a secondary index, it will report
            an error but will not shut down the server or prevent access
            to the file.
          
            CHECK TABLE surveys the index
            page structure, then surveys each key entry. It does not
            validate the key pointer to a clustered record or follow the
            path for BLOB pointers.
          
            When an InnoDB table is stored in its own
            .ibd file in
            file-per-table
            mode, the first 3 pages of
            the .ibd contain header information
            rather than table or index data. The CHECK
            TABLE statement does not detect inconsistencies
            that affect only the header data. To verify the entire
            contents of an InnoDB
            .ibd file, use the
            innochecksum command.
          
            When running CHECK TABLE on large
            InnoDB tables, other threads may be
            blocked during CHECK TABLE execution. To
            avoid timeouts, the semaphore wait threshold (600 seconds)
            is extended by 2 hours (7200 seconds) for CHECK
            TABLE operations. If InnoDB
            detects semaphore waits of 240 seconds or more it starts
            printing InnoDB monitor output to the
            error log. If a lock request extends beyond the semaphore
            wait threshold, InnoDB will abort the
            process. To avoid the possibility of a semaphore wait
            timeout entirely, you can run CHECK TABLE
            QUICK instead of CHECK TABLE.
CHECKSUM TABLEtbl_name[,tbl_name] ... [ QUICK | EXTENDED ]
        CHECKSUM TABLE reports a
        checksum for the contents
        of a table. During the checksum operation, the table is locked
        with a read lock for InnoDB and
        MyISAM. You can use this statement to verify
        that the contents are the same before and after a backup,
        rollback, or other operation that is intended to put the data
        back to a known state. This statement requires the
        SELECT privilege for the table.
        By default, the entire table is read row by row and the checksum
        is calculated. For large tables, this could take a long time,
        thus you would only perform this operation occasionally. This
        row-by-row calculation is what you get with the
        EXTENDED clause, with
        InnoDB and all other storage engines other
        than MyISAM, and with
        MyISAM tables not created with the
        CHECKSUM=1 clause.
      
        For MyISAM tables created with the
        CHECKSUM=1 clause, CHECKSUM
        TABLE or CHECKSUM TABLE ... QUICK
        returns the “live” table checksum that can be
        returned very fast. If the table does not meet all these
        conditions, the QUICK method returns
        NULL. See Section 13.1.17, “CREATE TABLE Syntax” for
        the syntax of the CHECKSUM clause.
      
        For a nonexistent table, CHECKSUM
        TABLE returns NULL and generates a
        warning.
      
        Prior to MySQL 5.6.4, CHECKSUM
        TABLE returned 0 for partitioned tables unless the
        EXTENDED option was used. (Bug #11933226, Bug
        #60681)
      
        The checksum value depends on the table row format. If the row
        format changes, the checksum also changes. For example, the
        storage format for VARCHAR
        changed between MySQL 4.1 and 5.0, so if a 4.1 table is upgraded
        to MySQL 5.0, the checksum value may change.
          If the checksums for two tables are different, then it is
          almost certain that the tables are different in some way.
          However, because the hashing function used by
          CHECKSUM TABLE is not
          guaranteed to be collision-free, there is a slight chance that
          two tables which are not identical can produce the same
          checksum.
OPTIMIZE [NO_WRITE_TO_BINLOG | LOCAL] TABLE
    tbl_name [, tbl_name] ...
Reorganizes the physical storage of table data and associated index data, to reduce storage space and improve I/O efficiency when accessing the table. The exact changes made to each table depend on the storage engine used by that table.
        Use OPTIMIZE TABLE in these
        cases, depending on the type of table:
            After doing substantial insert, update, or delete operations
            on an InnoDB table that has its own
            .ibd file because it
            was created with the
            innodb_file_per_table
            option enabled. The table and indexes are reorganized, and
            disk space can be reclaimed for use by the operating system.
          
            After doing substantial insert, update, or delete operations
            on columns that are part of a FULLTEXT
            index in an InnoDB table. Set the
            configuration option
            innodb_optimize_fulltext_only=1
            first. To keep the index maintenance period to a reasonable
            time, set the
            innodb_ft_num_word_optimize
            option to specify how many words to update in the search
            index, and run a sequence of OPTIMIZE
            TABLE statements until the search index is fully
            updated.
          
            After deleting a large part of a MyISAM
            or ARCHIVE table, or making many changes
            to a MyISAM or ARCHIVE
            table with variable-length rows (tables that have
            VARCHAR,
            VARBINARY,
            BLOB, or
            TEXT columns). Deleted rows
            are maintained in a linked list and subsequent
            INSERT operations reuse old
            row positions. You can use OPTIMIZE
            TABLE to reclaim the unused space and to
            defragment the data file. After extensive changes to a
            table, this statement may also improve performance of
            statements that use the table, sometimes significantly.
        This statement requires SELECT
        and INSERT privileges for the
        table.
      
        OPTIMIZE TABLE is also supported
        for partitioned tables. For information about using this
        statement with partitioned tables and table partitions, see
        Section 19.3.4, “Maintenance of Partitions”.
      
        In MySQL 5.6.11 only, gtid_next
        must be set to AUTOMATIC before issuing this
        statement. (Bug #16062608, Bug #16715809, Bug #69045)
      
        OPTIMIZE TABLE works for
        InnoDB,
        MyISAM, and
        ARCHIVE tables.
        OPTIMIZE TABLE is also supported
        for dynamic columns of in-memory
        NDB tables. It does not work for
        Disk Data tables. The performance of OPTIMIZE
        on Cluster tables can be tuned by adjusting the value of the
        ndb_optimization_delay system variable, which
        controls the number of milliseconds to wait between processing
        batches of rows by OPTIMIZE
        TABLE. For more information, see
        Section 18.1.6.11, “Previous MySQL Cluster Issues Resolved in MySQL Cluster NDB 7.3”.
      
        For MySQL Cluster tables, OPTIMIZE
        TABLE can be interrupted by (for example) killing the
        SQL thread performing the OPTIMIZE operation.
      
        By default, OPTIMIZE TABLE does
        not work for tables created using any other
        storage engine and returns a result indicating this lack of
        support. You can make OPTIMIZE
        TABLE work for other storage engines by starting
        mysqld with the --skip-new
        option. In this case, OPTIMIZE
        TABLE is just mapped to ALTER
        TABLE.
        For InnoDB tables,
        OPTIMIZE TABLE is mapped to
        ALTER TABLE ...
        FORCE, which rebuilds the table to update index
        statistics and free unused space in the clustered index. This is
        displayed in the output of OPTIMIZE
        TABLE when you run it on an InnoDB
        table, as shown here:
      
mysql> OPTIMIZE TABLE foo; +----------+----------+----------+-------------------------------------------------------------------+ | Table | Op | Msg_type | Msg_text | +----------+----------+----------+-------------------------------------------------------------------+ | test.foo | optimize | note | Table does not support optimize, doing recreate + analyze instead | | test.foo | optimize | status | OK | +----------+----------+----------+-------------------------------------------------------------------+
        Prior to Mysql 5.6.17, OPTIMIZE
        TABLE does not use
        online DDL
        (ALGORITHM=INPLACE). Consequently, concurrent
        DML (INSERT,
        UPDATE,
        DELETE) is not permitted on a
        table while OPTIMIZE TABLE is
        running, i.e. the table is locked. Also, secondary indexes are
        not created as efficiently because keys are inserted in the
        order they appeared in the primary key.
      
        As of 5.6.17, OPTIMIZE TABLE uses
        online DDL
        (ALGORITHM=INPLACE) for both regular and
        partitioned InnoDB tables. The table rebuild,
        triggered by OPTIMIZE TABLE and
        performed under the cover by
        ALTER TABLE ...
        FORCE, is now performed using
        online DDL
        (ALGORITHM=INPLACE) and only locks the table
        for a brief interval, which reduces downtime for concurrent DML
        operations.
      
        OPTIMIZE TABLE continues to use
        ALGORITHM=COPY under the following
        conditions:
            When the old_alter_table
            system variable is turned ON.
          
            When the mysqld
            --skip-new option is enabled.
        OPTIMIZE TABLE using
        online DDL
        (ALGORITHM=INPLACE) is not supported for
        InnoDB tables that contain
        FULLTEXT indexes.
        ALGORITHM=COPY must be used instead.
      
        InnoDB stores data using a page-allocation
        method and does not suffer from fragmentation in the same way
        that legacy storage engines (such as MyISAM)
        will. When considering whether or not to run optimize, consider
        the workload of transactions that your server will process:
              Some level of fragmentation is expected.
              InnoDB only fills
              pages 93% full, to leave
              room for updates without having to split pages.
            
Delete operations might leave gaps that leave pages less filled than desired, which could make it worthwhile to optimize the table.
Updates to rows usually rewrite the data within the same page, depending on the data type and row format, when sufficient space is available. See Section 14.6.5, “How Compression Works for InnoDB Tables” and Section 14.8.1, “Overview of InnoDB Row Storage”.
              High-concurrency workloads might leave gaps in indexes
              over time, as InnoDB retains multiple
              versions of the same data due through its
              MVCC mechanism. See
              Section 14.2.3, “InnoDB Multi-Versioning”.
        For MyISAM tables,
        OPTIMIZE TABLE works as follows:
If the table has deleted or split rows, repair the table.
If the index pages are not sorted, sort them.
If the table's statistics are not up to date (and the repair could not be accomplished by sorting the index), update them.
        OPTIMIZE TABLE returns a result
        set with the following columns.
| Column | Value | 
|---|---|
| Table | The table name | 
| Op | Always optimize | 
| Msg_type | status,error,info,note, orwarning | 
| Msg_text | An informational message | 
        For InnoDB tables prior to 5.6.17 and other
        table types, MySQL locks the
        table during the time OPTIMIZE
        TABLE is running. As of MySQL 5.6.17,
        OPTIMIZE TABLE is performed
        online for regular and partitioned InnoDB
        tables.
      
        By default, the server writes OPTIMIZE
        TABLE statements to the binary log so that they
        replicate to replication slaves. To suppress logging, specify
        the optional NO_WRITE_TO_BINLOG keyword or
        its alias LOCAL.
      
        OPTIMIZE TABLE does not sort
        R-tree indexes, such as spatial indexes on
        POINT columns. (Bug #23578)
      
        OPTIMIZE TABLE table catches and
        throws any errors that occur while copying table statistics from
        the old file to the newly created file. For example. if the user
        ID of the owner of the .frm,
        .MYD, or .MYI file is
        different from the user ID of the mysqld
        process, OPTIMIZE TABLE generates
        a "cannot change ownership of the file" error unless
        mysqld is started by the
        root user.
REPAIR [NO_WRITE_TO_BINLOG | LOCAL] TABLE
    tbl_name [, tbl_name] ...
    [QUICK] [EXTENDED] [USE_FRM]
        REPAIR TABLE repairs a possibly
        corrupted table, for certain storage engines only. By default,
        it has the same effect as myisamchk --recover
        tbl_name.
          REPAIR TABLE only applies to
          MyISAM, ARCHIVE, and
          CSV tables. See
          Section 15.2, “The MyISAM Storage Engine”, and
          Section 15.5, “The ARCHIVE Storage Engine”, and
          Section 15.4, “The CSV Storage Engine”
        This statement requires SELECT
        and INSERT privileges for the
        table.
      
        REPAIR TABLE is supported for
        partitioned tables. However, the USE_FRM
        option cannot be used with this statement on a partitioned
        table.
      
        In MySQL 5.6.11 only, gtid_next
        must be set to AUTOMATIC before issuing this
        statement. (Bug #16062608, Bug #16715809, Bug #69045)
      
        You can use ALTER TABLE ... REPAIR PARTITION
        to repair one or more partitions; for more information, see
        Section 13.1.7, “ALTER TABLE Syntax”, and
        Section 19.3.4, “Maintenance of Partitions”.
      
        Although normally you should never have to run
        REPAIR TABLE, if disaster
        strikes, this statement is very likely to get back all your data
        from a MyISAM table. If your tables become
        corrupted often, try to find the reason for it, to eliminate the
        need to use REPAIR TABLE. See
        Section B.5.4.2, “What to Do If MySQL Keeps Crashing”, and
        Section 15.2.4, “MyISAM Table Problems”.
Make a backup of a table before performing a table repair operation; under some circumstances the operation might cause data loss. Possible causes include but are not limited to file system errors. See Chapter 7, Backup and Recovery.
          If the server crashes during a REPAIR
          TABLE operation, it is essential after restarting it
          that you immediately execute another
          REPAIR TABLE statement for the
          table before performing any other operations on it. In the
          worst case, you might have a new clean index file without
          information about the data file, and then the next operation
          you perform could overwrite the data file. This is an unlikely
          but possible scenario that underscores the value of making a
          backup first.
        REPAIR TABLE returns a result set
        with the following columns.
| Column | Value | 
|---|---|
| Table | The table name | 
| Op | Always repair | 
| Msg_type | status,error,info,note, orwarning | 
| Msg_text | An informational message | 
        The REPAIR TABLE statement might
        produce many rows of information for each repaired table. The
        last row has a Msg_type value of
        status and Msg_test
        normally should be OK. If you do not get
        OK for a MyISAM table, you
        should try repairing it with myisamchk
        --safe-recover. (REPAIR
        TABLE does not implement all the options of
        myisamchk.) With myisamchk
        --safe-recover, you can also use options that
        REPAIR TABLE does not support,
        such as --max-record-length.
      
        If you use the QUICK option,
        REPAIR TABLE tries to repair only
        the index file, and not the data file. This type of repair is
        like that done by myisamchk --recover
        --quick.
      
        If you use the EXTENDED option, MySQL creates
        the index row by row instead of creating one index at a time
        with sorting. This type of repair is like that done by
        myisamchk --safe-recover.
      
        The USE_FRM option is available for use if
        the .MYI index file is missing or if its
        header is corrupted. This option tells MySQL not to trust the
        information in the .MYI file header and to
        re-create it using information from the
        .frm file. This kind of repair cannot be
        done with myisamchk.
          Use the USE_FRM option
          only if you cannot use regular
          REPAIR modes! Telling the server to ignore
          the .MYI file makes important table
          metadata stored in the .MYI unavailable
          to the repair process, which can have deleterious
          consequences:
              The current AUTO_INCREMENT value is
              lost.
            
The link to deleted records in the table is lost, which means that free space for deleted records will remain unoccupied thereafter.
              The .MYI header indicates whether the
              table is compressed. If the server ignores this
              information, it cannot tell that a table is compressed and
              repair can cause change or loss of table contents. This
              means that USE_FRM should not be used
              with compressed tables. That should not be necessary,
              anyway: Compressed tables are read only, so they should
              not become corrupt.
          If you use USE_FRM for a table that was
          created by a different version of the MySQL server than the
          one you are currently running, REPAIR
          TABLE will not attempt to repair the table. In this
          case, the result set returned by REPAIR
          TABLE contains a line with a
          Msg_type value of error
          and a Msg_text value of Failed
          repairing incompatible .FRM file.
        If USE_FRM is not used,
        REPAIR TABLE checks the table to
        see whether an upgrade is required. If so, it performs the
        upgrade, following the same rules as
        CHECK TABLE ... FOR
        UPGRADE. See Section 13.7.2.2, “CHECK TABLE Syntax”, for more
        information. REPAIR TABLE without
        USE_FRM upgrades the
        .frm file to the current version.
      
        By default, the server writes REPAIR
        TABLE statements to the binary log so that they
        replicate to replication slaves. To suppress logging, specify
        the optional NO_WRITE_TO_BINLOG keyword or
        its alias LOCAL.
          In the event that a table on the master becomes corrupted and
          you run REPAIR TABLE on it, any
          resulting changes to the original table are
          not propagated to slaves.
        You may be able to increase REPAIR
        TABLE performance by setting certain system variables.
        See Section 8.6.3, “Speed of REPAIR TABLE Statements”.
      
        REPAIR TABLE table catches and
        throws any errors that occur while copying table statistics from
        the old corrupted file to the newly created file. For example.
        if the user ID of the owner of the .frm,
        .MYD, or .MYI file is
        different from the user ID of the mysqld
        process, REPAIR TABLE generates a
        "cannot change ownership of the file" error unless
        mysqld is started by the
        root user.
CREATE [AGGREGATE] FUNCTIONfunction_nameRETURNS {STRING|INTEGER|REAL|DECIMAL} SONAMEshared_library_name
        A user-defined function (UDF) is a way to extend MySQL with a
        new function that works like a native (built-in) MySQL function
        such as ABS() or
        CONCAT().
      
        function_name is the name that should
        be used in SQL statements to invoke the function. The
        RETURNS clause indicates the type of the
        function's return value. DECIMAL
        is a legal value after RETURNS, but currently
        DECIMAL functions return string
        values and should be written like STRING
        functions.
      
        shared_library_name is the basename
        of the shared object file that contains the code that implements
        the function. The file must be located in the plugin directory.
        This directory is given by the value of the
        plugin_dir system variable. For
        more information, see Section 24.3.2.5, “Compiling and Installing User-Defined Functions”.
      
        To create a function, you must have the
        INSERT privilege for the
        mysql database. This is necessary because
        CREATE FUNCTION adds a row to the
        mysql.func system table that records the
        function's name, type, and shared library name. If you do not
        have this table, you should run the
        mysql_upgrade command to create it. See
        Section 4.4.7, “mysql_upgrade — Check and Upgrade MySQL Tables”.
      
        An active function is one that has been loaded with
        CREATE FUNCTION and not removed
        with DROP FUNCTION. All active
        functions are reloaded each time the server starts, unless you
        start mysqld with the
        --skip-grant-tables option. In
        this case, UDF initialization is skipped and UDFs are
        unavailable.
      
For instructions on writing user-defined functions, see Section 24.3.2, “Adding a New User-Defined Function”. For the UDF mechanism to work, functions must be written in C or C++ (or another language that can use C calling conventions), your operating system must support dynamic loading and you must have compiled mysqld dynamically (not statically).
        An AGGREGATE function works exactly like a
        native MySQL aggregate (summary) function such as
        SUM or
        COUNT(). For
        AGGREGATE to work, your
        mysql.func table must contain a
        type column. If your
        mysql.func table does not have this column,
        you should run the mysql_upgrade program to
        create it (see Section 4.4.7, “mysql_upgrade — Check and Upgrade MySQL Tables”).
          To upgrade the shared library associated with a UDF, issue a
          DROP FUNCTION statement,
          upgrade the shared library, and then issue a
          CREATE FUNCTION statement. If
          you upgrade the shared library first and then use
          DROP FUNCTION, the server may
          crash.
DROP FUNCTION function_name
        This statement drops the user-defined function (UDF) named
        function_name.
      
        To drop a function, you must have the
        DELETE privilege for the
        mysql database. This is because
        DROP FUNCTION removes a row from
        the mysql.func system table that records the
        function's name, type, and shared library name.
          To upgrade the shared library associated with a UDF, issue a
          DROP FUNCTION statement,
          upgrade the shared library, and then issue a
          CREATE FUNCTION statement. If
          you upgrade the shared library first and then use
          DROP FUNCTION, the server may
          crash.
        DROP FUNCTION is also used to
        drop stored functions (see Section 13.1.26, “DROP PROCEDURE and DROP FUNCTION Syntax”).
INSTALL PLUGINplugin_nameSONAME 'shared_library_name'
        This statement installs a server plugin. It requires the
        INSERT privilege for the
        mysql.plugin table.
      
        plugin_name is the name of the plugin
        as defined in the plugin descriptor structure contained in the
        library file (see Section 24.2.4.2, “Plugin Data Structures”).
        Plugin names are not case sensitive. For maximal compatibility,
        plugin names should be limited to ASCII letters, digits, and
        underscore because they are used in C source files, shell
        command lines, M4 and Bourne shell scripts, and SQL
        environments.
      
        shared_library_name is the name of
        the shared library that contains the plugin code. The name
        includes the file name extension (for example,
        libmyplugin.so,
        libmyplugin.dll, or
        libmyplugin.dylib).
      
        The shared library must be located in the plugin directory (the
        directory named by the
        plugin_dir system variable).
        The library must be in the plugin directory itself, not in a
        subdirectory. By default,
        plugin_dir is the
        plugin directory under the directory named
        by the pkglibdir configuration variable, but
        it can be changed by setting the value of
        plugin_dir at server startup.
        For example, set its value in a my.cnf
        file:
      
[mysqld]
plugin_dir=/path/to/plugin/directory
        If the value of plugin_dir is a
        relative path name, it is taken to be relative to the MySQL base
        directory (the value of the
        basedir system variable).
      
        INSTALL PLUGIN loads and
        initializes the plugin code to make the plugin available for
        use. A plugin is initialized by executing its initialization
        function, which handles any setup that the plugin must perform
        before it can be used. When the server shuts down, it executes
        the deinitialization function for each plugin that is loaded so
        that the plugin has a chance to perform any final cleanup.
      
        INSTALL PLUGIN also registers the
        plugin by adding a line that indicates the plugin name and
        library file name to the mysql.plugin table.
        At server startup, the server loads and initializes any plugin
        that is listed in the mysql.plugin table.
        This means that a plugin is installed with
        INSTALL PLUGIN only once, not
        every time the server starts. Plugin loading at startup does not
        occur if the server is started with the
        --skip-grant-tables option.
      
        A plugin library can contain multiple plugins. For each of them
        to be installed, use a separate INSTALL
        PLUGIN statement. Each statement names a different
        plugin, but all of them specify the same library name.
      
        INSTALL PLUGIN causes the server
        to read option (my.cnf) files just as
        during server startup. This enables the plugin to pick up any
        relevant options from those files. It is possible to add plugin
        options to an option file even before loading a plugin (if the
        loose prefix is used). It is also possible to
        uninstall a plugin, edit my.cnf, and
        install the plugin again. Restarting the plugin this way enables
        it to the new option values without a server restart.
      
        For options that control individual plugin loading at server
        startup, see Section 5.1.8.1, “Installing and Uninstalling Plugins”. If you
        need to load plugins for a single server startup when the
        --skip-grant-tables option is
        given (which tells the server not to read system tables), use
        the --plugin-load option. See
        Section 5.1.3, “Server Command Options”.
      
        To remove a plugin, use the UNINSTALL
        PLUGIN statement.
      
For additional information about plugin loading, see Section 5.1.8.1, “Installing and Uninstalling Plugins”.
        To see what plugins are installed, use the
        SHOW PLUGINS statement or query
        the INFORMATION_SCHEMA.PLUGINS
        table.
      
If you recompile a plugin library and need to reinstall it, you can use either of the following methods:
            Use UNINSTALL PLUGIN to
            uninstall all plugins in the library, install the new plugin
            library file in the plugin directory, and then use
            INSTALL PLUGIN to install all
            plugins in the library. This procedure has the advantage
            that it can be used without stopping the server. However, if
            the plugin library contains many plugins, you must issue
            many INSTALL PLUGIN and
            UNINSTALL PLUGIN statements.
          
Stop the server, install the new plugin library file in the plugin directory, and restart the server.
UNINSTALL PLUGIN plugin_name
        This statement removes an installed server plugin. It requires
        the DELETE privilege for the
        mysql.plugin table.
      
        plugin_name must be the name of some
        plugin that is listed in the mysql.plugin
        table. The server executes the plugin's deinitialization
        function and removes the row for the plugin from the
        mysql.plugin table, so that subsequent server
        restarts will not load and initialize the plugin.
        UNINSTALL PLUGIN does not remove
        the plugin's shared library file.
      
You cannot uninstall a plugin if any table that uses it is open.
        Plugin removal has implications for the use of associated
        tables. For example, if a full-text parser plugin is associated
        with a FULLTEXT index on the table,
        uninstalling the plugin makes the table unusable. Any attempt to
        access the table results in an error. The table cannot even be
        opened, so you cannot drop an index for which the plugin is
        used. This means that uninstalling a plugin is something to do
        with care unless you do not care about the table contents. If
        you are uninstalling a plugin with no intention of reinstalling
        it later and you care about the table contents, you should dump
        the table with mysqldump and remove the
        WITH PARSER clause from the dumped
        CREATE TABLE statement so that
        you can reload the table later. If you do not care about the
        table, DROP TABLE can be used
        even if any plugins associated with the table are missing.
      
For additional information about plugin loading, see Section 5.1.8.1, “Installing and Uninstalling Plugins”.
SETvariable_assignment[,variable_assignment] ...variable_assignment:user_var_name=expr| [GLOBAL | SESSION]system_var_name=expr| [@@global. | @@session. | @@]system_var_name=expr
      The SET
      statement assigns values to different types of variables that
      affect the operation of the server or your client.
    
      This section describes use of
      SET for
      assigning values to variables. The
      SET
      statement can be used to assign values to these types of
      variables:
System variables. See Section 5.1.4, “Server System Variables”. System variables also can be set at server startup, as described in Section 5.1.5, “Using System Variables”.
User-defined variables. See Section 9.4, “User-Defined Variables”.
Stored procedure and function parameters, and stored program local variables. See Section 13.6.4, “Variables in Stored Programs”.
      Some variants of
      SET
      syntax are used in other contexts:
          SET CHARACTER SET and SET
          NAMES assign values to character set and collation
          variables associated with the connection to the server.
          SET ONE_SHOT is used for replication. These
          variants are described later in this section.
        
          SET PASSWORD assigns account
          passwords. See Section 13.7.1.7, “SET PASSWORD Syntax”.
        
          SET
          TRANSACTION ISOLATION LEVEL sets the isolation level
          for transaction processing. See
          Section 13.3.6, “SET TRANSACTION Syntax”.
      The following discussion shows the different
      SET
      syntaxes that you can use to set variables. The examples use the
      = assignment
      operator, but you can also use the
      :=
      assignment operator for this purpose.
    
      A user variable is written as
      @ and can be
      set as follows:
    var_name
SET @var_name=expr;
      Many system variables are dynamic and can be changed while the
      server runs by using the
      SET
      statement. For a list, see
      Section 5.1.5.2, “Dynamic System Variables”. To change a system
      variable with
      SET,
      refer to it as var_name, optionally
      preceded by a modifier:
          To indicate explicitly that a variable is a global variable,
          precede its name by GLOBAL or
          @@global.. The
          SUPER privilege is required to
          set global variables.
        
          To indicate explicitly that a variable is a session variable,
          precede its name by SESSION,
          @@session., or @@.
          Setting a session variable normally requires no special
          privilege, although there are exceptions (such as
          sql_log_bin.) A client can
          change its own session variables, but not those of any other
          client.
        
          LOCAL and @@local. are
          synonyms for SESSION and
          @@session..
        
          If no modifier is present,
          SET
          changes the session variable.
      A SET
      statement can contain multiple variable assignments, separated by
      commas. For example, the statement can assign values to a
      user-defined variable and a system variable. If you set several
      system variables, the most recent GLOBAL or
      SESSION modifier in the statement is used for
      following variables that have no modifier specified.
    
Examples:
SET sort_buffer_size=10000; SET @@local.sort_buffer_size=10000; SET GLOBAL sort_buffer_size=1000000, SESSION sort_buffer_size=1000000; SET @@sort_buffer_size=1000000; SET @@global.sort_buffer_size=1000000, @@local.sort_buffer_size=1000000;
      The @@
      syntax for system variables is supported for compatibility with
      some other database systems.
    var_name
If you change a session system variable, the value remains in effect until your session ends or until you change the variable to a different value. The change is not visible to other clients.
      If you change a global system variable, the value is remembered
      and used for new connections until the server restarts. (To make a
      global system variable setting permanent, you should set it in an
      option file.) The change is visible to any client that accesses
      that global variable. However, the change affects the
      corresponding session variable only for clients that connect after
      the change. The global variable change does not affect the session
      variable for any client that is currently connected (not even that
      of the client that issues the
      SET
      GLOBAL statement).
    
      To prevent incorrect usage, MySQL produces an error if you use
      SET
      GLOBAL with a variable that can only be used with
      SET
      SESSION or if you do not specify
      GLOBAL (or @@global.) when
      setting a global variable.
    
      To set a SESSION variable to the
      GLOBAL value or a GLOBAL
      value to the compiled-in MySQL default value, use the
      DEFAULT keyword. For example, the following two
      statements are identical in setting the session value of
      max_join_size to the global
      value:
    
SET max_join_size=DEFAULT; SET @@session.max_join_size=@@global.max_join_size;
      Not all system variables can be set to DEFAULT.
      In such cases, use of DEFAULT results in an
      error.
    
      It is not permitted to assign the value DEFAULT
      to user-defined variables, stored procedure or function
      parameters, or stored program local variables. This results in a
      syntax error for user-defined variables, and also for parameters
      or local variables as of MySQL 5.6.6.
    
      You can refer to the values of specific global or session system
      variables in expressions by using one of the
      @@-modifiers. For example, you can retrieve
      values in a SELECT statement like
      this:
    
SELECT @@global.sql_mode, @@session.sql_mode, @@sql_mode;
      When you refer to a system variable in an expression as
      @@ (that is,
      when you do not specify var_name@@global. or
      @@session.), MySQL returns the session value if
      it exists and the global value otherwise. (This differs from
      SET @@, which always refers to
      the session value.)
var_name =
      value
        Some variables displayed by SHOW VARIABLES
        may not be available using SELECT
        @@ syntax; an
        var_nameUnknown system variable occurs. As a
        workaround in such cases, you can use SHOW VARIABLES
        LIKE '.
var_name'
      Suffixes for specifying a value multiplier can be used when
      setting a variable at server startup, but not to set the value
      with SET
      at runtime. On the other hand, with
      SET you
      can assign a variable's value using an expression, which is not
      true when you set a variable at server startup. For example, the
      first of the following lines is legal at server startup, but the
      second is not:
    
shell>mysql --max_allowed_packet=16Mshell>mysql --max_allowed_packet=16*1024*1024
Conversely, the second of the following lines is legal at runtime, but the first is not:
mysql>SET GLOBAL max_allowed_packet=16M;mysql>SET GLOBAL max_allowed_packet=16*1024*1024;
      To display system variables names and values, use the
      SHOW VARIABLES statement. (See
      Section 13.7.5.40, “SHOW VARIABLES Syntax”.)
    
      The following list describes
      SET
      options that have nonstandard syntax (that is, options that are
      not set with name =
      value
          
          CHARACTER SET
          {
        charset_name | DEFAULT}
          This maps all strings from and to the client with the given
          mapping. You can add new mappings by editing
          sql/convert.cc in the MySQL source
          distribution. SET CHARACTER SET sets three
          session system variables:
          character_set_client and
          character_set_results are set
          to the given character set, and
          character_set_connection to
          the value of
          character_set_database. See
          Section 10.1.4, “Connection Character Sets and Collations”.
        
          The default mapping can be restored by using the value
          DEFAULT. The default depends on the server
          configuration.
        
          ucs2, utf16, and
          utf32 cannot be used as a client character
          set, which means that they do not work for SET
          CHARACTER SET.
        
          
          NAMES {'
        charset_name'
          [COLLATE 'collation_name'] |
          DEFAULT}
          SET NAMES sets the three session system
          variables
          character_set_client,
          character_set_connection, and
          character_set_results to the
          given character set. Setting
          character_set_connection to
          charset_name also sets
          collation_connection to the
          default collation for charset_name. The
          optional COLLATE clause may be used to
          specify a collation explicitly. See
          Section 10.1.4, “Connection Character Sets and Collations”.
        
          The default mapping can be restored by using a value of
          DEFAULT. The default depends on the server
          configuration.
        
          ucs2, utf16, and
          utf32 cannot be used as a client character
          set, which means that they do not work for SET
          NAMES.
        
          ONE_SHOT is for internal use only, has been
          deprecated since MySQL 5.0, and was removed in MySQL 5.6.1.
      SHOW has many forms that provide
      information about databases, tables, columns, or status
      information about the server. This section describes those
      following:
    
SHOW AUTHORS
SHOW {BINARY | MASTER} LOGS
SHOW BINLOG EVENTS [IN 'log_name'] [FROM pos] [LIMIT [offset,] row_count]
SHOW CHARACTER SET [like_or_where]
SHOW COLLATION [like_or_where]
SHOW [FULL] COLUMNS FROM tbl_name [FROM db_name] [like_or_where]
SHOW CONTRIBUTORS
SHOW CREATE DATABASE db_name
SHOW CREATE EVENT event_name
SHOW CREATE FUNCTION func_name
SHOW CREATE PROCEDURE proc_name
SHOW CREATE TABLE tbl_name
SHOW CREATE TRIGGER trigger_name
SHOW CREATE VIEW view_name
SHOW DATABASES [like_or_where]
SHOW ENGINE engine_name {STATUS | MUTEX}
SHOW [STORAGE] ENGINES
SHOW ERRORS [LIMIT [offset,] row_count]
SHOW EVENTS
SHOW FUNCTION CODE func_name
SHOW FUNCTION STATUS [like_or_where]
SHOW GRANTS FOR user
SHOW INDEX FROM tbl_name [FROM db_name]
SHOW MASTER STATUS
SHOW OPEN TABLES [FROM db_name] [like_or_where]
SHOW PLUGINS
SHOW PROCEDURE CODE proc_name
SHOW PROCEDURE STATUS [like_or_where]
SHOW PRIVILEGES
SHOW [FULL] PROCESSLIST
SHOW PROFILE [types] [FOR QUERY n] [OFFSET n] [LIMIT n]
SHOW PROFILES
SHOW SLAVE HOSTS
SHOW SLAVE STATUS
SHOW [GLOBAL | SESSION] STATUS [like_or_where]
SHOW TABLE STATUS [FROM db_name] [like_or_where]
SHOW [FULL] TABLES [FROM db_name] [like_or_where]
SHOW TRIGGERS [FROM db_name] [like_or_where]
SHOW [GLOBAL | SESSION] VARIABLES [like_or_where]
SHOW WARNINGS [LIMIT [offset,] row_count]
like_or_where:
    LIKE 'pattern'
  | WHERE expr
      If the syntax for a given SHOW
      statement includes a LIKE
      ' part,
      pattern'' is a
      string that can contain the SQL
      “pattern'%” and
      “_” wildcard characters. The
      pattern is useful for restricting statement output to matching
      values.
    
      Several SHOW statements also accept
      a WHERE clause that provides more flexibility
      in specifying which rows to display. See
      Section 21.32, “Extensions to SHOW Statements”.
    
      Many MySQL APIs (such as PHP) enable you to treat the result
      returned from a SHOW statement as
      you would a result set from a
      SELECT; see
      Chapter 23, Connectors and APIs, or your API documentation for
      more information. In addition, you can work in SQL with results
      from queries on tables in the
      INFORMATION_SCHEMA database, which you cannot
      easily do with results from SHOW
      statements. See Chapter 21, INFORMATION_SCHEMA Tables.
SHOW AUTHORS
        The SHOW AUTHORS statement
        displays information about the people who work on MySQL. For
        each author, it displays Name,
        Location, and Comment
        values.
      
This statement is removed as of MySQL 5.6.8.
SHOW BINARY LOGS SHOW MASTER LOGS
Lists the binary log files on the server. This statement is used as part of the procedure described in Section 13.4.1.1, “PURGE BINARY LOGS Syntax”, that shows how to determine which logs can be purged.
mysql> SHOW BINARY LOGS;
+---------------+-----------+
| Log_name      | File_size |
+---------------+-----------+
| binlog.000015 |    724935 |
| binlog.000016 |    733481 |
+---------------+-----------+
        SHOW MASTER
        LOGS is equivalent to SHOW BINARY
        LOGS.
      
        In MySQL 5.6.5 and earlier, the
        SUPER privilege was required to
        use this statement. Starting with MySQL 5.6.6, a user with the
        REPLICATION CLIENT privilege may
        also execute this statement.
SHOW BINLOG EVENTS [IN 'log_name'] [FROMpos] [LIMIT [offset,]row_count]
        Shows the events in the binary log. If you do not specify
        ', the
        first binary log is displayed.
      log_name'
        The LIMIT clause has the same syntax as for
        the SELECT statement. See
        Section 13.2.9, “SELECT Syntax”.
          Issuing a SHOW BINLOG EVENTS
          with no LIMIT clause could start a very
          time- and resource-consuming process because the server
          returns to the client the complete contents of the binary log
          (which includes all statements executed by the server that
          modify data). As an alternative to SHOW
          BINLOG EVENTS, use the
          mysqlbinlog utility to save the binary log
          to a text file for later examination and analysis. See
          Section 4.6.8, “mysqlbinlog — Utility for Processing Binary Log Files”.
          Some events relating to the setting of user and system
          variables are not included in the output from
          SHOW BINLOG EVENTS. To get
          complete coverage of events within a binary log, use
          mysqlbinlog.
          SHOW BINLOG EVENTS does
          not work with relay log files. You can
          use SHOW RELAYLOG EVENTS for
          this purpose.
SHOW CHARACTER SET
    [LIKE 'pattern' | WHERE expr]
        The SHOW CHARACTER SET statement
        shows all available character sets. The
        LIKE clause, if present, indicates
        which character set names to match. The WHERE
        clause can be given to select rows using more general
        conditions, as discussed in Section 21.32, “Extensions to SHOW Statements”. For
        example:
      
mysql> SHOW CHARACTER SET LIKE 'latin%';
+---------+-----------------------------+-------------------+--------+
| Charset | Description                 | Default collation | Maxlen |
+---------+-----------------------------+-------------------+--------+
| latin1  | cp1252 West European        | latin1_swedish_ci |      1 |
| latin2  | ISO 8859-2 Central European | latin2_general_ci |      1 |
| latin5  | ISO 8859-9 Turkish          | latin5_turkish_ci |      1 |
| latin7  | ISO 8859-13 Baltic          | latin7_general_ci |      1 |
+---------+-----------------------------+-------------------+--------+
        The Maxlen column shows the maximum number of
        bytes required to store one character.
      
        The filename character set is for internal
        use only; consequently, SHOW CHARACTER
        SET does not display it.
SHOW COLLATION
    [LIKE 'pattern' | WHERE expr]
        This statement lists collations supported by the server. By
        default, the output from SHOW
        COLLATION includes all available collations. The
        LIKE clause, if present, indicates
        which collation names to match. The WHERE
        clause can be given to select rows using more general
        conditions, as discussed in Section 21.32, “Extensions to SHOW Statements”. For
        example:
      
mysql> SHOW COLLATION LIKE 'latin1%';
+-------------------+---------+----+---------+----------+---------+
| Collation         | Charset | Id | Default | Compiled | Sortlen |
+-------------------+---------+----+---------+----------+---------+
| latin1_german1_ci | latin1  |  5 |         |          |       0 |
| latin1_swedish_ci | latin1  |  8 | Yes     | Yes      |       0 |
| latin1_danish_ci  | latin1  | 15 |         |          |       0 |
| latin1_german2_ci | latin1  | 31 |         | Yes      |       2 |
| latin1_bin        | latin1  | 47 |         | Yes      |       0 |
| latin1_general_ci | latin1  | 48 |         |          |       0 |
| latin1_general_cs | latin1  | 49 |         |          |       0 |
| latin1_spanish_ci | latin1  | 94 |         |          |       0 |
+-------------------+---------+----+---------+----------+---------+
        The Collation and Charset
        columns indicate the names of the collation and the character
        set with which it is associated. Id is the
        collation ID. Default indicates whether the
        collation is the default for its character set.
        Compiled indicates whether the character set
        is compiled into the server. Sortlen is
        related to the amount of memory required to sort strings
        expressed in the character set.
      
        To see the default collation for each character set, use the
        following statement. Default is a reserved
        word, so to use it as an identifier, it must be quoted as such:
      
mysql> SHOW COLLATION WHERE `Default` = 'Yes';
+---------------------+----------+----+---------+----------+---------+
| Collation           | Charset  | Id | Default | Compiled | Sortlen |
+---------------------+----------+----+---------+----------+---------+
| big5_chinese_ci     | big5     |  1 | Yes     | Yes      |       1 |
| dec8_swedish_ci     | dec8     |  3 | Yes     | Yes      |       1 |
| cp850_general_ci    | cp850    |  4 | Yes     | Yes      |       1 |
| hp8_english_ci      | hp8      |  6 | Yes     | Yes      |       1 |
| koi8r_general_ci    | koi8r    |  7 | Yes     | Yes      |       1 |
| latin1_swedish_ci   | latin1   |  8 | Yes     | Yes      |       1 |
...
SHOW [FULL] COLUMNS {FROM | IN} tbl_name [{FROM | IN} db_name]
    [LIKE 'pattern' | WHERE expr]
        SHOW COLUMNS displays information
        about the columns in a given table. It also works for views. The
        LIKE clause, if present, indicates
        which column names to match. The WHERE clause
        can be given to select rows using more general conditions, as
        discussed in Section 21.32, “Extensions to SHOW Statements”.
      
        SHOW COLUMNS displays information
        only for those columns for which you have some privilege.
      
mysql> SHOW COLUMNS FROM City;
+------------+----------+------+-----+---------+----------------+
| Field      | Type     | Null | Key | Default | Extra          |
+------------+----------+------+-----+---------+----------------+
| Id         | int(11)  | NO   | PRI | NULL    | auto_increment |
| Name       | char(35) | NO   |     |         |                |
| Country    | char(3)  | NO   | UNI |         |                |
| District   | char(20) | YES  | MUL |         |                |
| Population | int(11)  | NO   |     | 0       |                |
+------------+----------+------+-----+---------+----------------+
5 rows in set (0.00 sec)
        If the data types differ from what you expect them to be based
        on a CREATE TABLE statement, note
        that MySQL sometimes changes data types when you create or alter
        a table. The conditions under which this occurs are described in
        Section 13.1.17.4, “Silent Column Specification Changes”.
      
        The FULL keyword causes the output to include
        the column collation and comments, as well as the privileges you
        have for each column.
      
        You can use db_name.tbl_name as an
        alternative to the tbl_name
        FROM db_name
mysql>SHOW COLUMNS FROM mytable FROM mydb;mysql>SHOW COLUMNS FROM mydb.mytable;
        SHOW COLUMNS displays the
        following values for each table column:
      
        Field indicates the column name.
      
        Type indicates the column data type.
      
        Collation indicates the collation for
        nonbinary string columns, or NULL for other
        columns. This value is displayed only if you use the
        FULL keyword.
      
        The Null field contains
        YES if NULL values can be
        stored in the column, NO if not.
      
        The Key field indicates whether the column is
        indexed:
            If Key is empty, the column either is not
            indexed or is indexed only as a secondary column in a
            multiple-column, nonunique index.
          
            If Key is PRI, the
            column is a PRIMARY KEY or is one of the
            columns in a multiple-column PRIMARY KEY.
          
            If Key is UNI, the
            column is the first column of a UNIQUE
            index. (A UNIQUE index permits multiple
            NULL values, but you can tell whether the
            column permits NULL by checking the
            Null field.)
          
            If Key is MUL, the
            column is the first column of a nonunique index in which
            multiple occurrences of a given value are permitted within
            the column.
        If more than one of the Key values applies to
        a given column of a table, Key displays the
        one with the highest priority, in the order
        PRI, UNI,
        MUL.
      
        A UNIQUE index may be displayed as
        PRI if it cannot contain
        NULL values and there is no PRIMARY
        KEY in the table. A UNIQUE index
        may display as MUL if several columns form a
        composite UNIQUE index; although the
        combination of the columns is unique, each column can still hold
        multiple occurrences of a given value.
      
        The Default field indicates the default value
        that is assigned to the column. This is NULL
        if the column has an explicit default of
        NULL, or if the column definition has no
        DEFAULT clause.
      
        The Extra field contains any additional
        information that is available about a given column. The value is
        nonempty in these cases: auto_increment for
        columns that have the AUTO_INCREMENT
        attribute; on update CURRENT_TIMESTAMP for
        TIMESTAMP or
        DATETIME columns that have the
        ON UPDATE CURRENT_TIMESTAMP attribute.
      
        Privileges indicates the privileges you have
        for the column. This value is displayed only if you use the
        FULL keyword.
      
        Comment indicates any comment the column has.
        This value is displayed only if you use the
        FULL keyword.
      
        SHOW FIELDS is a synonym for
        SHOW COLUMNS. You can also list a
        table's columns with the mysqlshow
        db_name
        tbl_name command.
      
        The DESCRIBE statement provides
        information similar to SHOW
        COLUMNS. See Section 13.8.1, “DESCRIBE Syntax”.
      
        The SHOW CREATE TABLE,
        SHOW TABLE STATUS, and
        SHOW INDEX statements also
        provide information about tables. See Section 13.7.5, “SHOW Syntax”.
SHOW CONTRIBUTORS
        The SHOW CONTRIBUTORS statement
        displays information about the people who contribute to MySQL
        source or to causes that we support. For each contributor, it
        displays Name, Location,
        and Comment values.
      
This statement is removed as of MySQL 5.6.8.
SHOW CREATE {DATABASE | SCHEMA} [IF NOT EXISTS] db_name
        Shows the CREATE DATABASE
        statement that creates the named database. If the
        SHOW statement includes an IF NOT
        EXISTS clause, the output too includes such a clause.
        SHOW
        CREATE SCHEMA is a synonym for
        SHOW CREATE DATABASE.
      
mysql>SHOW CREATE DATABASE test\G*************************** 1. row *************************** Database: test Create Database: CREATE DATABASE `test` /*!40100 DEFAULT CHARACTER SET latin1 */ mysql>SHOW CREATE SCHEMA test\G*************************** 1. row *************************** Database: test Create Database: CREATE DATABASE `test` /*!40100 DEFAULT CHARACTER SET latin1 */
        SHOW CREATE DATABASE quotes table
        and column names according to the value of the
        sql_quote_show_create option.
        See Section 5.1.4, “Server System Variables”.
SHOW CREATE EVENT event_name
        This statement displays the CREATE
        EVENT statement needed to re-create a given event. It
        requires the EVENT privilege for
        the database from which the event is to be shown. For example
        (using the same event e_daily defined and
        then altered in Section 13.7.5.19, “SHOW EVENTS Syntax”):
      
mysql> SHOW CREATE EVENT test.e_daily\G
*************************** 1. row ***************************
               Event: e_daily
            sql_mode:
           time_zone: SYSTEM
        Create Event: CREATE EVENT `e_daily`
                        ON SCHEDULE EVERY 1 DAY
                        STARTS CURRENT_TIMESTAMP + INTERVAL 6 HOUR
                        ON COMPLETION NOT PRESERVE
                        ENABLE
                        COMMENT 'Saves total number of sessions then
                                clears the table each day'
                        DO BEGIN
                          INSERT INTO site_activity.totals (time, total)
                            SELECT CURRENT_TIMESTAMP, COUNT(*)
                            FROM site_activity.sessions;
                          DELETE FROM site_activity.sessions;
                        END
character_set_client: latin1
collation_connection: latin1_swedish_ci
  Database Collation: latin1_swedish_ci
        character_set_client is the session value of
        the character_set_client system
        variable when the event was created.
        collation_connection is the session value of
        the collation_connection system
        variable when the event was created. Database
        Collation is the collation of the database with which
        the event is associated.
      
        The output reflects the current status of the event
        (ENABLE) rather than the status with which it
        was created.
SHOW CREATE FUNCTION func_name
        This statement is similar to SHOW CREATE
        PROCEDURE but for stored functions. See
        Section 13.7.5.11, “SHOW CREATE PROCEDURE Syntax”.
SHOW CREATE PROCEDURE proc_name
        This statement is a MySQL extension. It returns the exact string
        that can be used to re-create the named stored procedure. A
        similar statement, SHOW CREATE
        FUNCTION, displays information about stored functions
        (see Section 13.7.5.10, “SHOW CREATE FUNCTION Syntax”).
      
        To use either statement, you must be the user named in the
        routine DEFINER clause or have
        SELECT access to the
        mysql.proc table. If you do not have
        privileges for the routine itself, the value displayed for the
        Create Procedure or Create
        Function field will be NULL.
      
mysql>SHOW CREATE PROCEDURE test.simpleproc\G*************************** 1. row *************************** Procedure: simpleproc sql_mode: Create Procedure: CREATE PROCEDURE `simpleproc`(OUT param1 INT) BEGIN SELECT COUNT(*) INTO param1 FROM t; END character_set_client: latin1 collation_connection: latin1_swedish_ci Database Collation: latin1_swedish_ci mysql>SHOW CREATE FUNCTION test.hello\G*************************** 1. row *************************** Function: hello sql_mode: Create Function: CREATE FUNCTION `hello`(s CHAR(20)) RETURNS CHAR(50) RETURN CONCAT('Hello, ',s,'!') character_set_client: latin1 collation_connection: latin1_swedish_ci Database Collation: latin1_swedish_ci
        character_set_client is the session value of
        the character_set_client system
        variable when the routine was created.
        collation_connection is the session value of
        the collation_connection system
        variable when the routine was created. Database
        Collation is the collation of the database with which
        the routine is associated.
SHOW CREATE TABLE tbl_name
        Shows the CREATE TABLE statement
        that creates the named table. To use this statement, you must
        have some privilege for the table. This statement also works
        with views.
      
mysql> SHOW CREATE TABLE t\G
*************************** 1. row ***************************
       Table: t
Create Table: CREATE TABLE t (
  id INT(11) default NULL auto_increment,
  s char(60) default NULL,
  PRIMARY KEY (id)
) ENGINE=MyISAM
        SHOW CREATE TABLE quotes table
        and column names according to the value of the
        sql_quote_show_create option.
        See Section 5.1.4, “Server System Variables”.
SHOW CREATE TRIGGER trigger_name
        This statement shows the CREATE
        TRIGGER statement that creates the named trigger.
      
mysql> SHOW CREATE TRIGGER ins_sum\G
*************************** 1. row ***************************
               Trigger: ins_sum
              sql_mode: NO_ENGINE_SUBSTITUTION
SQL Original Statement: CREATE DEFINER=`me`@`localhost` TRIGGER ins_sum
                        BEFORE INSERT ON account
                        FOR EACH ROW SET @sum = @sum + NEW.amount
  character_set_client: utf8
  collation_connection: utf8_general_ci
    Database Collation: latin1_swedish_ci
        SHOW CREATE TRIGGER output has
        the following columns:
            Trigger: The trigger name.
          
            sql_mode: The SQL mode in effect when the
            trigger executes.
          
            SQL Original Statement: The
            CREATE TRIGGER statement that
            defines the trigger.
          
            character_set_client: The session value
            of the character_set_client
            system variable when the trigger was created.
          
            collation_connection: The session value
            of the collation_connection
            system variable when the trigger was created.
          
            Database Collation: The collation of the
            database with which the trigger is associated.
        You can also obtain information about trigger objects from
        INFORMATION_SCHEMA, which contains a
        TRIGGERS table. See
        Section 21.26, “The INFORMATION_SCHEMA TRIGGERS Table”.
SHOW CREATE VIEW view_name
        This statement shows the CREATE
        VIEW statement that creates the named view.
      
mysql> SHOW CREATE VIEW v\G
*************************** 1. row ***************************
                View: v
         Create View: CREATE ALGORITHM=UNDEFINED
                      DEFINER=`bob`@`localhost`
                      SQL SECURITY DEFINER VIEW
                      `v` AS select 1 AS `a`,2 AS `b`
character_set_client: latin1
collation_connection: latin1_swedish_ci
        character_set_client is the session value of
        the character_set_client system
        variable when the view was created.
        collation_connection is the session value of
        the collation_connection system
        variable when the view was created.
      
        Use of SHOW CREATE VIEW requires
        the SHOW VIEW privilege and the
        SELECT privilege for the view in
        question.
      
        You can also obtain information about view objects from
        INFORMATION_SCHEMA, which contains a
        VIEWS table. See
        Section 21.28, “The INFORMATION_SCHEMA VIEWS Table”.
      
        MySQL lets you use different
        sql_mode settings to tell the
        server the type of SQL syntax to support. For example, you might
        use the ANSI SQL mode to
        ensure MySQL correctly interprets the standard SQL concatenation
        operator, the double bar (||), in your
        queries. If you then create a view that concatenates items, you
        might worry that changing the
        sql_mode setting to a value
        different from ANSI could
        cause the view to become invalid. But this is not the case. No
        matter how you write out a view definition, MySQL always stores
        it the same way, in a canonical form. Here is an example that
        shows how the server changes a double bar concatenation operator
        to a CONCAT() function:
      
mysql>SET sql_mode = 'ANSI';Query OK, 0 rows affected (0.00 sec) mysql>CREATE VIEW test.v AS SELECT 'a' || 'b' as col1;Query OK, 0 rows affected (0.01 sec) mysql>SHOW CREATE VIEW test.v\G*************************** 1. row *************************** View: v Create View: CREATE VIEW "v" AS select concat('a','b') AS "col1" ... 1 row in set (0.00 sec)
        The advantage of storing a view definition in canonical form is
        that changes made later to the value of
        sql_mode will not affect the
        results from the view. However an additional consequence is that
        comments prior to SELECT are
        stripped from the definition by the server.
SHOW {DATABASES | SCHEMAS}
    [LIKE 'pattern' | WHERE expr]
        SHOW DATABASES lists the
        databases on the MySQL server host.
        SHOW
        SCHEMAS is a synonym for SHOW
        DATABASES. The LIKE
        clause, if present, indicates which database names to match. The
        WHERE clause can be given to select rows
        using more general conditions, as discussed in
        Section 21.32, “Extensions to SHOW Statements”.
      
        You see only those databases for which you have some kind of
        privilege, unless you have the global SHOW
        DATABASES privilege. You can also get this list using
        the mysqlshow command.
      
        If the server was started with the
        --skip-show-database option, you
        cannot use this statement at all unless you have the
        SHOW DATABASES privilege.
      
MySQL implements databases as directories in the data directory, so this statement simply lists directories in that location. However, the output may include names of directories that do not correspond to actual databases.
SHOW ENGINE engine_name {STATUS | MUTEX}
        SHOW ENGINE displays operational
        information about a storage engine. It requires the
        PROCESS privilege. The statement
        has these variants:
      
SHOW ENGINE INNODB STATUS
SHOW ENGINE INNODB MUTEX
SHOW ENGINE {NDB | NDBCLUSTER} STATUS
SHOW ENGINE PERFORMANCE_SCHEMA STATUS
        SHOW ENGINE INNODB
        STATUS displays extensive information from the
        standard InnoDB Monitor about the state of
        the InnoDB storage engine. For information
        about the standard monitor and other InnoDB
        Monitors that provide information about
        InnoDB processing, see
        Section 14.14, “InnoDB Monitors”.
      
        SHOW ENGINE INNODB
        MUTEX displays InnoDB
        mutex and
        rw-lock statistics.
        Statement output has the following columns:
          Most SHOW ENGINE
          INNODB MUTEX output is removed in 5.6.14.
          SHOW ENGINE
          INNODB MUTEX output is removed entirely in MySQL
          5.7.2. InnoDB mutexes can be monitored
          using Performance
          Schema tables. For an example, see
          Section 14.13.1, “Monitoring InnoDB Mutex Waits Using Performance Schema”.
            Type
          
            Always InnoDB.
          
            Name
          
The source file where the mutex is implemented, and the line number in the file where the mutex is created. The line number is specific to your version of MySQL.
            Status
          
            The mutex status. This field displays several values if
            WITH_DEBUG was defined at
            MySQL compilation time. If
            WITH_DEBUG was not defined,
            the statement displays only the os_waits
            value. In the latter case (without
            WITH_DEBUG), the information
            on which the output is based is insufficient to distinguish
            regular mutexes and mutexes that protect rw-locks (which
            permit multiple readers or a single writer). Consequently,
            the output may appear to contain multiple rows for the same
            mutex.
                count indicates how many times the
                mutex was requested.
              
                spin_waits indicates how many times
                the spinlock had to run.
              
                spin_rounds indicates the number of
                spinlock rounds. (spin_rounds divided
                by spin_waits provides the average
                round count.)
              
                os_waits indicates the number of
                operating system waits. This occurs when the spinlock
                did not work (the mutex was not locked during the
                spinlock and it was necessary to yield to the operating
                system and wait).
              
                os_yields indicates the number of
                times a thread trying to lock a mutex gave up its
                timeslice and yielded to the operating system (on the
                presumption that permitting other threads to run will
                free the mutex so that it can be locked).
              
                os_wait_times indicates the amount of
                time (in ms) spent in operating system waits. In MySQL
                5.6 timing is disabled and this value is
                always 0.
        SHOW ENGINE INNODB MUTEX skips the
        mutexes and
        rw-locks of
        buffer pool blocks, as
        the amount of output can be overwhelming on systems with a large
        buffer pool. (There is one mutex and one rw-lock in each 16K
        buffer pool block, and there are 65,536 blocks per gigabyte.)
        SHOW ENGINE INNODB MUTEX also does not list
        any mutexes or rw-locks that have never been waited on
        (os_waits=0). Thus, SHOW ENGINE
        INNODB MUTEX only displays information about mutexes
        and rw-locks outside of the buffer pool that have caused at
        least one OS-level wait.
      
        SHOW ENGINE INNODB MUTEX information can be
        used to diagnose system problems. For example, large values of
        spin_waits and spin_rounds
        may indicate scalability problems.
      
        Use SHOW ENGINE
        PERFORMANCE_SCHEMA STATUS to inspect the internal
        operation of the Performance Schema code:
      
mysql> SHOW ENGINE PERFORMANCE_SCHEMA STATUS\G
...
*************************** 3. row ***************************
  Type: performance_schema
  Name: events_waits_history.row_size
Status: 76
*************************** 4. row ***************************
  Type: performance_schema
  Name: events_waits_history.row_count
Status: 10000
*************************** 5. row ***************************
  Type: performance_schema
  Name: events_waits_history.memory
Status: 760000
...
*************************** 57. row ***************************
  Type: performance_schema
  Name: performance_schema.memory
Status: 26459600
...
This statement is intended to help the DBA understand the effects that different Performance Schema options have on memory requirements.
        Name values consist of two parts, which name
        an internal buffer and a buffer attribute, respectively.
        Interpret buffer names as follows:
            An internal buffer that is not exposed as a table is named
            within parentheses. Examples:
            (pfs_cond_class).row_size,
            (pfs_mutex_class).memory.
          
            An internal buffer that is exposed as a table in the
            performance_schema database is named
            after the table, without parentheses. Examples:
            events_waits_history.row_size,
            mutex_instances.row_count.
          
            A value that applies to the Performance Schema as a whole
            begins with performance_schema. Example:
            performance_schema.memory.
Buffer attributes have these meanings:
            row_size is the size of the internal
            record used by the implementation, such as the size of a row
            in a table. row_size values cannot be
            changed.
          
            row_count is the number of internal
            records, such as the number of rows in a table.
            row_count values can be changed using
            Performance Schema configuration options.
          
            For a table,
            tbl_name.memoryrow_size and
            row_count. For the Performance Schema as
            a whole, performance_schema.memory is the
            sum of all the memory used (the sum of all other
            memory values).
        In some cases, there is a direct relationship between a
        Performance Schema configuration parameter and a SHOW
        ENGINE value. For example,
        events_waits_history_long.row_count
        corresponds to
        performance_schema_events_waits_history_long_size.
        In other cases, the relationship is more complex. For example,
        events_waits_history.row_count corresponds to
        performance_schema_events_waits_history_size
        (the number of rows per thread) multiplied by
        performance_schema_max_thread_instances
        ( the number of threads).
      
SHOW ENGINE NDB STATUS. 
          If the server has the NDB storage
          engine enabled, SHOW ENGINE NDB STATUS
          displays cluster status information such as the number of
          connected data nodes, the cluster connectstring, and cluster
          binary log epochs, as well as counts of various Cluster API
          objects created by the MySQL Server when connected to the
          cluster. Sample output from this statement is shown here:
        
mysql> SHOW ENGINE NDB STATUS;
+------------+-----------------------+--------------------------------------------------+
| Type       | Name                  | Status                                           |
+------------+-----------------------+--------------------------------------------------+
| ndbcluster | connection            | cluster_node_id=7,
  connected_host=192.168.0.103, connected_port=1186, number_of_data_nodes=4,
  number_of_ready_data_nodes=3, connect_count=0                                         |
| ndbcluster | NdbTransaction        | created=6, free=0, sizeof=212                    |
| ndbcluster | NdbOperation          | created=8, free=8, sizeof=660                    |
| ndbcluster | NdbIndexScanOperation | created=1, free=1, sizeof=744                    |
| ndbcluster | NdbIndexOperation     | created=0, free=0, sizeof=664                    |
| ndbcluster | NdbRecAttr            | created=1285, free=1285, sizeof=60               |
| ndbcluster | NdbApiSignal          | created=16, free=16, sizeof=136                  |
| ndbcluster | NdbLabel              | created=0, free=0, sizeof=196                    |
| ndbcluster | NdbBranch             | created=0, free=0, sizeof=24                     |
| ndbcluster | NdbSubroutine         | created=0, free=0, sizeof=68                     |
| ndbcluster | NdbCall               | created=0, free=0, sizeof=16                     |
| ndbcluster | NdbBlob               | created=1, free=1, sizeof=264                    |
| ndbcluster | NdbReceiver           | created=4, free=0, sizeof=68                     |
| ndbcluster | binlog                | latest_epoch=155467, latest_trans_epoch=148126,
  latest_received_binlog_epoch=0, latest_handled_binlog_epoch=0,
  latest_applied_binlog_epoch=0                                                         |
+------------+-----------------------+--------------------------------------------------+
        The rows with connection and
        binlog in the Name column
        were added to the output of this statement in MySQL 5.1. The
        Status column in each of these rows provides
        information about the MySQL server's connection to the cluster
        and about the cluster binary log's status, respectively. The
        Status information is in the form of
        comma-delimited set of name/value pairs.
      
        The connection row's
        Status column contains the name/value pairs
        described in the following table.
| Name | Value | 
|---|---|
| cluster_node_id | The node ID of the MySQL server in the cluster | 
| connected_host | The host name or IP address of the cluster management server to which the MySQL server is connected | 
| connected_port | The port used by the MySQL server to connect to the management server
                ( connected_host) | 
| number_of_data_nodes | The number of data nodes configured for the cluster (that is, the number
                of [ndbd]sections in the clusterconfig.inifile) | 
| number_of_ready_data_nodes | The number of data nodes in the cluster that are actually running | 
| connect_count | The number of times this mysqld has connected or reconnected to cluster data nodes | 
        The binlog row's Status
        column contains information relating to MySQL Cluster
        Replication. The name/value pairs it contains are described in
        the following table.
| Name | Value | 
|---|---|
| latest_epoch | The most recent epoch most recently run on this MySQL server (that is, the sequence number of the most recent transaction run on the server) | 
| latest_trans_epoch | The most recent epoch processed by the cluster's data nodes | 
| latest_received_binlog_epoch | The most recent epoch received by the binary log thread | 
| latest_handled_binlog_epoch | The most recent epoch processed by the binary log thread (for writing to the binary log) | 
| latest_applied_binlog_epoch | The most recent epoch actually written to the binary log | 
See Section 18.6, “MySQL Cluster Replication”, for more information.
        The remaining rows from the output of SHOW ENGINE NDB
        STATUS which are most likely to prove useful in
        monitoring the cluster are listed here by
        Name:
            NdbTransaction: The number and size of
            NdbTransaction objects that have been
            created. An NdbTransaction is created
            each time a table schema operation (such as
            CREATE TABLE or
            ALTER TABLE) is performed on
            an NDB table.
          
            NdbOperation: The number and size of
            NdbOperation objects that have been
            created.
          
            NdbIndexScanOperation: The number and
            size of NdbIndexScanOperation objects
            that have been created.
          
            NdbIndexOperation: The number and size of
            NdbIndexOperation objects that have been
            created.
          
            NdbRecAttr: The number and size of
            NdbRecAttr objects that have been
            created. In general, one of these is created each time a
            data manipulation statement is performed by an SQL node.
          
            NdbBlob: The number and size of
            NdbBlob objects that have been created.
            An NdbBlob is created for each new
            operation involving a BLOB
            column in an NDB table.
          
            NdbReceiver: The number and size of any
            NdbReceiver object that have been
            created. The number in the created column
            is the same as the number of data nodes in the cluster to
            which the MySQL server has connected.
          SHOW ENGINE NDB STATUS returns an empty
          result if no operations involving
          NDB tables have been performed
          during the current session by the MySQL client accessing the
          SQL node on which this statement is run.
SHOW [STORAGE] ENGINES
        SHOW ENGINES displays status
        information about the server's storage engines. This is
        particularly useful for checking whether a storage engine is
        supported, or to see what the default engine is. This
        information can also be obtained from the
        INFORMATION_SCHEMA
        ENGINES table. See
        Section 21.6, “The INFORMATION_SCHEMA ENGINES Table”.
      
mysql> SHOW ENGINES\G
*************************** 1. row ***************************
      Engine: MEMORY
     Support: YES
     Comment: Hash based, stored in memory, useful for temporary tables
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 2. row ***************************
      Engine: MyISAM
     Support: YES
     Comment: MyISAM storage engine
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 3. row ***************************
      Engine: InnoDB
     Support: DEFAULT
     Comment: Supports transactions, row-level locking, and foreign keys
Transactions: YES
          XA: YES
  Savepoints: YES
*************************** 4. row ***************************
      Engine: EXAMPLE
     Support: YES
     Comment: Example storage engine
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 5. row ***************************
      Engine: ARCHIVE
     Support: YES
     Comment: Archive storage engine
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 6. row ***************************
      Engine: CSV
     Support: YES
     Comment: CSV storage engine
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 7. row ***************************
      Engine: BLACKHOLE
     Support: YES
     Comment: /dev/null storage engine (anything you write »
              to it disappears)
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 8. row ***************************
      Engine: FEDERATED
     Support: YES
     Comment: Federated MySQL storage engine
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 9. row ***************************
      Engine: MRG_MYISAM
     Support: YES
     Comment: Collection of identical MyISAM tables
Transactions: NO
          XA: NO
  Savepoints: NO
        The output from SHOW ENGINES may
        vary according to the MySQL version used and other factors. The
        values shown in the Support column indicate
        the server's level of support for the storage engine, as shown
        in the following table.
| Value | Meaning | 
|---|---|
| YES | The engine is supported and is active | 
| DEFAULT | Like YES, plus this is the default engine | 
| NO | The engine is not supported | 
| DISABLED | The engine is supported but has been disabled | 
        A value of NO means that the server was
        compiled without support for the engine, so it cannot be enabled
        at runtime.
      
        A value of DISABLED occurs either because the
        server was started with an option that disables the engine, or
        because not all options required to enable it were given. In the
        latter case, the error log file should contain a reason
        indicating why the option is disabled. See
        Section 5.2.2, “The Error Log”.
      
        You might also see DISABLED for a storage
        engine if the server was compiled to support it, but was started
        with a
        --skip-
        option. For the engine_nameNDB storage engine,
        DISABLED means the server was compiled with
        support for MySQL Cluster, but was not started with the
        --ndbcluster option.
      
        All MySQL servers support MyISAM tables. It
        is not possible to disable MyISAM.
      
        The Transactions, XA, and
        Savepoints columns indicate whether the
        storage engine supports transactions, XA transactions, and
        savepoints, respectively.
SHOW ERRORS [LIMIT [offset,]row_count] SHOW COUNT(*) ERRORS
        SHOW ERRORS is a diagnostic
        statement that is similar to SHOW
        WARNINGS, except that it displays information only for
        errors, rather than for errors, warnings, and notes.
      
        The LIMIT clause has the same syntax as for
        the SELECT statement. See
        Section 13.2.9, “SELECT Syntax”.
      
        The SHOW COUNT(*)
        ERRORS statement displays the number of errors. You
        can also retrieve this number from the
        error_count variable:
      
SHOW COUNT(*) ERRORS; SELECT @@error_count;
        SHOW ERRORS and
        error_count apply only to
        errors, not warnings or notes. In other respects, they are
        similar to SHOW WARNINGS and
        warning_count. In particular,
        SHOW ERRORS cannot display
        information for more than
        max_error_count messages, and
        error_count can exceed the
        value of max_error_count if the
        number of errors exceeds
        max_error_count.
      
For more information, see Section 13.7.5.41, “SHOW WARNINGS Syntax”.
SHOW EVENTS [{FROM | IN} schema_name]
    [LIKE 'pattern' | WHERE expr]
        This statement displays information about Event Manager events.
        It requires the EVENT privilege
        for the database from which the events are to be shown.
      
        In its simplest form, SHOW EVENTS
        lists all of the events in the current schema:
      
mysql>SELECT CURRENT_USER(), SCHEMA();+----------------+----------+ | CURRENT_USER() | SCHEMA() | +----------------+----------+ | jon@ghidora | myschema | +----------------+----------+ 1 row in set (0.00 sec) mysql>SHOW EVENTS\G*************************** 1. row *************************** Db: myschema Name: e_daily Definer: jon@ghidora Time zone: SYSTEM Type: RECURRING Execute at: NULL Interval value: 10 Interval field: SECOND Starts: 2006-02-09 10:41:23 Ends: NULL Status: ENABLED Originator: 0 character_set_client: latin1 collation_connection: latin1_swedish_ci Database Collation: latin1_swedish_ci
        To see events for a specific schema, use the
        FROM clause. For example, to see events for
        the test schema, use the following statement:
      
SHOW EVENTS FROM test;
        The LIKE clause, if present,
        indicates which event names to match. The
        WHERE clause can be given to select rows
        using more general conditions, as discussed in
        Section 21.32, “Extensions to SHOW Statements”.
      
        SHOW EVENTS output has the
        following columns:
            Db: The schema (database) on which the
            event is defined.
          
            Name: The name of the event.
          
            Time zone: The event time zone, which is
            the time zone used for scheduling the event and that is in
            effect within the event as it executes. The default value is
            SYSTEM.
          
            Definer: The account of the user who
            created the event, in
            '
            format.
          user_name'@'host_name'
            Type: The event repetition type, either
            ONE TIME (transient) or
            RECURRING (repeating).
          
            Execute At: The date and time when a
            transient event is set to execute. Shown as a
            DATETIME value.
          
            For a recurring event, the value of this column is always
            NULL.
          
            Interval Value: For a recurring event,
            the number of intervals to wait between event executions.
          
            For a transient event, the value of this column is always
            NULL.
          
            Interval Field: The time units used for
            the interval which a recurring event waits before repeating.
          
            For a transient event, the value of this column is always
            NULL.
          
            Starts: The start date and time for a
            recurring event. This is displayed as a
            DATETIME value, and is
            NULL if no start date and time are
            defined for the event.
          
            For a transient event, this column is always
            NULL.
          
            Ends: The end date and time for a
            recurring event. This is displayed as a
            DATETIME value, and defaults
            to NULL if no end date and time is
            defined for the event.
          
            For a transient event, this column is always
            NULL.
          
            Status: The event status. One of
            ENABLED, DISABLED, or
            SLAVESIDE_DISABLED.
          
            SLAVESIDE_DISABLED indicates that the
            creation of the event occurred on another MySQL server
            acting as a replication master and replicated to the current
            MySQL server which is acting as a slave, but the event is
            not presently being executed on the slave.
          
            Originator: The server ID of the MySQL
            server on which the event was created. Defaults to 0.
          
            character_set_client is the session value
            of the character_set_client
            system variable when the routine was created.
            collation_connection is the session value
            of the collation_connection
            system variable when the routine was created.
            Database Collation is the collation of
            the database with which the routine is associated.
        For more information about SLAVE_DISABLED and
        the Originator column, see
        Section 17.4.1.11, “Replication of Invoked Features”.
      
        The event action statement is not shown in the output of
        SHOW EVENTS. Use
        SHOW CREATE EVENT or the
        INFORMATION_SCHEMA.EVENTS table.
      
        Times displayed by SHOW EVENTS
        are given in the event time zone, as discussed in
        Section 20.4.4, “Event Metadata”.
      
        The columns in the output of SHOW
        EVENTS are similar to, but not identical to the
        columns in the
        INFORMATION_SCHEMA.EVENTS table.
        See Section 21.7, “The INFORMATION_SCHEMA EVENTS Table”.
SHOW FUNCTION CODE func_name
        This statement is similar to SHOW PROCEDURE
        CODE but for stored functions. See
        Section 13.7.5.28, “SHOW PROCEDURE CODE Syntax”.
SHOW FUNCTION STATUS
    [LIKE 'pattern' | WHERE expr]
        This statement is similar to SHOW PROCEDURE
        STATUS but for stored functions. See
        Section 13.7.5.29, “SHOW PROCEDURE STATUS Syntax”.
SHOW GRANTS [FOR user]
        This statement lists the GRANT
        statement or statements that must be issued to duplicate the
        privileges that are granted to a MySQL user account.
        SHOW GRANTS requires the
        SELECT privilege for the
        mysql database, except to see the privileges
        for the current user.
      
        The account is named using the same format as for the
        GRANT statement; for example,
        'jeffrey'@'localhost'. If you specify only
        the user name part of the account name, a host name part of
        '%' is used. For additional information about
        specifying account names, see Section 13.7.1.4, “GRANT Syntax”.
      
mysql> SHOW GRANTS FOR 'root'@'localhost';
+---------------------------------------------------------------------+
| Grants for root@localhost                                           |
+---------------------------------------------------------------------+
| GRANT ALL PRIVILEGES ON *.* TO 'root'@'localhost' WITH GRANT OPTION |
+---------------------------------------------------------------------+
To list the privileges granted to the account that you are using to connect to the server, you can use any of the following statements:
SHOW GRANTS; SHOW GRANTS FOR CURRENT_USER; SHOW GRANTS FOR CURRENT_USER();
        If SHOW GRANTS FOR CURRENT_USER (or any of
        the equivalent syntaxes) is used in DEFINER
        context, such as within a stored procedure that is defined with
        SQL SECURITY DEFINER), the grants displayed
        are those of the definer and not the invoker.
      
        SHOW GRANTS displays only the
        privileges granted explicitly to the named account. Other
        privileges might be available to the account, but they are not
        displayed. For example, if an anonymous account exists, the
        named account might be able to use its privileges, but
        SHOW GRANTS will not display
        them.
SHOW {INDEX | INDEXES | KEYS}
    {FROM | IN} tbl_name
    [{FROM | IN} db_name]
    [WHERE expr]
        SHOW INDEX returns table index
        information. The format resembles that of the
        SQLStatistics call in ODBC. This statement
        requires some privilege for any column in the table.
      
        SHOW INDEX returns the following
        fields:
            Table
          
The name of the table.
            Non_unique
          
0 if the index cannot contain duplicates, 1 if it can.
            Key_name
          
            The name of the index. If the index is the primary key, the
            name is always PRIMARY.
          
            Seq_in_index
          
The column sequence number in the index, starting with 1.
            Column_name
          
The column name.
            How the column is sorted in the index. In MySQL, this can
            have values “A” (Ascending)
            or NULL (Not sorted).
          
            An estimate of the number of unique values in the index.
            This is updated by running ANALYZE
            TABLE or myisamchk -a.
            Cardinality is counted based on
            statistics stored as integers, so the value is not
            necessarily exact even for small tables. The higher the
            cardinality, the greater the chance that MySQL uses the
            index when doing joins.
          
            Sub_part
          
            The number of indexed characters if the column is only
            partly indexed, NULL if the entire column
            is indexed.
          
            Packed
          
            Indicates how the key is packed. NULL if
            it is not.
          
            Null
          
            Contains YES if the column may contain
            NULL values and '' if
            not.
          
            Index_type
          
            The index method used (BTREE,
            FULLTEXT, HASH,
            RTREE).
          
            Comment
          
            Information about the index not described in its own column,
            such as disabled if the index is
            disabled.
          
            Index_comment
          
            Any comment provided for the index with a
            COMMENT attribute when the index was
            created.
        You can use
        db_name.tbl_name
        as an alternative to the
        tbl_name FROM
        db_name
SHOW INDEX FROM mytable FROM mydb; SHOW INDEX FROM mydb.mytable;
        The WHERE clause can be given to select rows
        using more general conditions, as discussed in
        Section 21.32, “Extensions to SHOW Statements”.
      
        You can also list a table's indexes with the mysqlshow
        -k db_name
        tbl_name command.
SHOW MASTER STATUS
        This statement provides status information about the binary log
        files of the master. It requires either the
        SUPER or
        REPLICATION CLIENT privilege.
      
Example:
mysql> SHOW MASTER STATUS\G
*************************** 1. row ***************************
             File: master-bin.000002
         Position: 1307
     Binlog_Do_DB: test
 Binlog_Ignore_DB: manual, mysql
Executed_Gtid_Set: 3E11FA47-71CA-11E1-9E33-C80AA9429562:1-5
1 row in set (0.00 sec)
        The Executed_Gtid_Set column was added in
        MySQL 5.6.5. When global transaction IDs are in use, this column
        shows the set of GTIDs for transactions that have been executed
        on the master. This is the same as the value for the
        gtid_executed system variable
        (named gtid_done prior to MySQL
        5.6.9) on this server, as well as the value for
        Executed_Gtid_Set in the output of
        SHOW SLAVE STATUS on this server.
SHOW OPEN TABLES [{FROM | IN} db_name]
    [LIKE 'pattern' | WHERE expr]
        SHOW OPEN TABLES lists the
        non-TEMPORARY tables that are currently open
        in the table cache. See Section 8.4.3.1, “How MySQL Opens and Closes Tables”. The
        FROM clause, if present, restricts the tables
        shown to those present in the db_name
        database. The LIKE clause, if
        present, indicates which table names to match. The
        WHERE clause can be given to select rows
        using more general conditions, as discussed in
        Section 21.32, “Extensions to SHOW Statements”.
      
        SHOW OPEN TABLES output has the
        following columns:
            Database
          
The database containing the table.
            Table
          
The table name.
            In_use
          
            The number of table locks or lock requests there are for the
            table. For example, if one client acquires a lock for a
            table using LOCK TABLE t1 WRITE,
            In_use will be 1. If another client
            issues LOCK TABLE t1 WRITE while the
            table remains locked, the client will block waiting for the
            lock, but the lock request causes In_use
            to be 2. If the count is zero, the table is open but not
            currently being used. In_use is also
            increased by the
            HANDLER ...
            OPEN statement and decreased by
            HANDLER ...
            CLOSE.
          
            Name_locked
          
Whether the table name is locked. Name locking is used for operations such as dropping or renaming tables.
        If you have no privileges for a table, it does not show up in
        the output from SHOW OPEN TABLES.
SHOW PLUGINS
        SHOW PLUGINS displays information
        about server plugins. Plugin information is also available in
        the INFORMATION_SCHEMA.PLUGINS table. See
        Section 21.14, “The INFORMATION_SCHEMA PLUGINS Table”.
      
        Example of SHOW PLUGINS output:
      
mysql> SHOW PLUGINS\G
*************************** 1. row ***************************
   Name: binlog
 Status: ACTIVE
   Type: STORAGE ENGINE
Library: NULL
License: GPL
*************************** 2. row ***************************
   Name: CSV
 Status: ACTIVE
   Type: STORAGE ENGINE
Library: NULL
License: GPL
*************************** 3. row ***************************
   Name: MEMORY
 Status: ACTIVE
   Type: STORAGE ENGINE
Library: NULL
License: GPL
*************************** 4. row ***************************
   Name: MyISAM
 Status: ACTIVE
   Type: STORAGE ENGINE
Library: NULL
License: GPL
...
        SHOW PLUGINS output has the
        following columns:
            Name: The name used to refer to the
            plugin in statements such as INSTALL
            PLUGIN and UNINSTALL
            PLUGIN.
          
            Status: The plugin status, one of
            ACTIVE, INACTIVE,
            DISABLED, or DELETED.
          
            Type: The type of plugin, such as
            STORAGE ENGINE,
            INFORMATION_SCHEMA, or
            AUTHENTICATION.
          
            Library: The name of the plugin shared
            object file. This is the name used to refer to the plugin
            file in statements such as INSTALL
            PLUGIN and UNINSTALL
            PLUGIN. This file is located in the directory
            named by the plugin_dir
            system variable. If the library name is
            NULL, the plugin is compiled in and
            cannot be uninstalled with UNINSTALL
            PLUGIN.
          
            License: How the plugin is licensed; for
            example, GPL.
        For plugins installed with INSTALL
        PLUGIN, the Name and
        Library values are also registered in the
        mysql.plugin table.
      
        For information about plugin data structures that form the basis
        of the information displayed by SHOW
        PLUGINS, see Section 24.2, “The MySQL Plugin API”.
SHOW PRIVILEGES
        SHOW PRIVILEGES shows the list of
        system privileges that the MySQL server supports. The exact list
        of privileges depends on the version of your server.
      
mysql> SHOW PRIVILEGES\G
*************************** 1. row ***************************
Privilege: Alter
  Context: Tables
  Comment: To alter the table
*************************** 2. row ***************************
Privilege: Alter routine
  Context: Functions,Procedures
  Comment: To alter or drop stored functions/procedures
*************************** 3. row ***************************
Privilege: Create
  Context: Databases,Tables,Indexes
  Comment: To create new databases and tables
*************************** 4. row ***************************
Privilege: Create routine
  Context: Databases
  Comment: To use CREATE FUNCTION/PROCEDURE
*************************** 5. row ***************************
Privilege: Create temporary tables
  Context: Databases
  Comment: To use CREATE TEMPORARY TABLE
...
        Privileges belonging to a specific user are displayed by the
        SHOW GRANTS statement. See
        Section 13.7.5.22, “SHOW GRANTS Syntax”, for more information.
SHOW PROCEDURE CODE proc_name
        This statement is a MySQL extension that is available only for
        servers that have been built with debugging support. It displays
        a representation of the internal implementation of the named
        stored procedure. A similar statement, SHOW
        FUNCTION CODE, displays information about stored
        functions (see Section 13.7.5.20, “SHOW FUNCTION CODE Syntax”).
      
        To use either statement, you must be the owner of the routine or
        have SELECT access to the
        mysql.proc table.
      
        If the named routine is available, each statement produces a
        result set. Each row in the result set corresponds to one
        “instruction” in the routine. The first column is
        Pos, which is an ordinal number beginning
        with 0. The second column is Instruction,
        which contains an SQL statement (usually changed from the
        original source), or a directive which has meaning only to the
        stored-routine handler.
      
mysql>DELIMITER //mysql>CREATE PROCEDURE p1 ()->BEGIN->DECLARE fanta INT DEFAULT 55;->DROP TABLE t2;->LOOP->INSERT INTO t3 VALUES (fanta);->END LOOP;->END//Query OK, 0 rows affected (0.00 sec) mysql>SHOW PROCEDURE CODE p1//+-----+----------------------------------------+ | Pos | Instruction | +-----+----------------------------------------+ | 0 | set fanta@0 55 | | 1 | stmt 9 "DROP TABLE t2" | | 2 | stmt 5 "INSERT INTO t3 VALUES (fanta)" | | 3 | jump 2 | +-----+----------------------------------------+ 4 rows in set (0.00 sec)
        In this example, the nonexecutable BEGIN and
        END statements have disappeared, and for the
        DECLARE
         statement,
        only the executable part appears (the part where the default is
        assigned). For each statement that is taken from source, there
        is a code word variable_namestmt followed by a type (9
        means DROP, 5 means
        INSERT, and so on). The final row
        contains an instruction jump 2, meaning
        GOTO instruction #2.
SHOW PROCEDURE STATUS
    [LIKE 'pattern' | WHERE expr]
        This statement is a MySQL extension. It returns characteristics
        of a stored procedure, such as the database, name, type,
        creator, creation and modification dates, and character set
        information. A similar statement, SHOW
        FUNCTION STATUS, displays information about stored
        functions (see Section 13.7.5.21, “SHOW FUNCTION STATUS Syntax”).
      
        The LIKE clause, if present,
        indicates which procedure or function names to match. The
        WHERE clause can be given to select rows
        using more general conditions, as discussed in
        Section 21.32, “Extensions to SHOW Statements”.
      
mysql> SHOW PROCEDURE STATUS LIKE 'sp1'\G
*************************** 1. row ***************************
                  Db: test
                Name: sp1
                Type: PROCEDURE
             Definer: testuser@localhost
            Modified: 2004-08-03 15:29:37
             Created: 2004-08-03 15:29:37
       Security_type: DEFINER
             Comment:
character_set_client: latin1
collation_connection: latin1_swedish_ci
  Database Collation: latin1_swedish_ci
        character_set_client is the session value of
        the character_set_client system
        variable when the routine was created.
        collation_connection is the session value of
        the collation_connection system
        variable when the routine was created. Database
        Collation is the collation of the database with which
        the routine is associated.
      
        You can also get information about stored routines from the
        ROUTINES table in
        INFORMATION_SCHEMA. See
        Section 21.18, “The INFORMATION_SCHEMA ROUTINES Table”.
SHOW [FULL] PROCESSLIST
        SHOW PROCESSLIST shows you which
        threads are running. You can also get this information from the
        INFORMATION_SCHEMA
        PROCESSLIST table or the
        mysqladmin processlist command. If you have
        the PROCESS privilege, you can
        see all threads. Otherwise, you can see only your own threads
        (that is, threads associated with the MySQL account that you are
        using). If you do not use the FULL keyword,
        only the first 100 characters of each statement are shown in the
        Info field.
      
        Process information is also available from the
        performance_schema.threads table.
        However, access to threads does not
        require a mutex and has minimal impact on server performance.
        INFORMATION_SCHEMA.PROCESSLIST and
        SHOW PROCESSLIST have negative
        performance consequences because they require a mutex.
        threads also shows information
        about background threads, which
        INFORMATION_SCHEMA.PROCESSLIST and
        SHOW PROCESSLIST do not. This
        means that threads can be used to
        monitor activity the other thread information sources cannot.
      
        The SHOW PROCESSLIST statement is
        very useful if you get the “too many connections”
        error message and want to find out what is going on. MySQL
        reserves one extra connection to be used by accounts that have
        the SUPER privilege, to ensure
        that administrators should always be able to connect and check
        the system (assuming that you are not giving this privilege to
        all your users).
      
        Threads can be killed with the
        KILL statement. See
        Section 13.7.6.4, “KILL Syntax”.
      
        Here is an example of SHOW
        PROCESSLIST output:
      
mysql> SHOW FULL PROCESSLIST\G
*************************** 1. row ***************************
Id: 1
User: system user
Host:
db: NULL
Command: Connect
Time: 1030455
State: Waiting for master to send event
Info: NULL
*************************** 2. row ***************************
Id: 2
User: system user
Host:
db: NULL
Command: Connect
Time: 1004
State: Has read all relay log; waiting for the slave
       I/O thread to update it
Info: NULL
*************************** 3. row ***************************
Id: 3112
User: replikator
Host: artemis:2204
db: NULL
Command: Binlog Dump
Time: 2144
State: Has sent all binlog to slave; waiting for binlog to be updated
Info: NULL
*************************** 4. row ***************************
Id: 3113
User: replikator
Host: iconnect2:45781
db: NULL
Command: Binlog Dump
Time: 2086
State: Has sent all binlog to slave; waiting for binlog to be updated
Info: NULL
*************************** 5. row ***************************
Id: 3123
User: stefan
Host: localhost
db: apollon
Command: Query
Time: 0
State: NULL
Info: SHOW FULL PROCESSLIST
5 rows in set (0.00 sec)
        The columns produced by SHOW
        PROCESSLIST have the following meanings:
            The connection identifier. This is the same type of value
            displayed in the ID column of the
            INFORMATION_SCHEMA.PROCESSLIST
            table, the PROCESSLIST_ID column of the
            Performance Schema threads
            table, and returned by the
            CONNECTION_ID() function.
          
            The MySQL user who issued the statement. If this is
            system user, it refers to a nonclient
            thread spawned by the server to handle tasks internally.
            This could be the I/O or SQL thread used on replication
            slaves or a delayed-row handler. unauthenticated
            user refers to a thread that has become associated
            with a client connection but for which authentication of the
            client user has not yet been done.
            event_scheduler refers to the thread that
            monitors scheduled events. For system
            user, there is no host specified in the
            Host column.
          
            The host name of the client issuing the statement (except
            for system user where there is no host).
            SHOW PROCESSLIST reports the
            host name for TCP/IP connections in
            host_name:client_port
            The default database, if one is selected, otherwise
            NULL.
          
            The type of command the thread is executing. For
            descriptions for thread commands, see
            Section 8.14, “Examining Thread Information”. The value of this
            column corresponds to the
            COM_
            commands of the client/server protocol and
            xxxCom_ status
            variables. See Section 5.1.6, “Server Status Variables”
          xxx
The time in seconds that the thread has been in its current state. For a slave SQL thread, the value is the number of seconds between the timestamp of the last replicated event and the real time of the slave machine. See Section 17.2.1, “Replication Implementation Details”.
            An action, event, or state that indicates what the thread is
            doing. Descriptions for State values can
            be found at Section 8.14, “Examining Thread Information”.
          
Most states correspond to very quick operations. If a thread stays in a given state for many seconds, there might be a problem that needs to be investigated.
            For the SHOW PROCESSLIST
            statement, the value of State is
            NULL.
          
            The statement the thread is executing, or
            NULL if it is not executing any
            statement. The statement might be the one sent to the
            server, or an innermost statement if the statement executes
            other statements. For example, if a CALL
            statement executes a stored procedure that is executing a
            SELECT statement, the
            Info value shows the
            SELECT statement.
SHOW PROFILE [type[,type] ... ] [FOR QUERYn] [LIMITrow_count[OFFSEToffset]]type: ALL | BLOCK IO | CONTEXT SWITCHES | CPU | IPC | MEMORY | PAGE FAULTS | SOURCE | SWAPS
        The SHOW PROFILE and
        SHOW PROFILES statements display
        profiling information that indicates resource usage for
        statements executed during the course of the current session.
These statements are deprecated as of MySQL 5.6.7 and will be removed in a future MySQL release. Use the Performance Schema instead; see Chapter 22, MySQL Performance Schema.
        Profiling is controlled by the
        profiling session variable,
        which has a default value of 0 (OFF).
        Profiling is enabled by setting
        profiling to 1 or
        ON:
      
mysql> SET profiling = 1;
        SHOW PROFILES displays a list of
        the most recent statements sent to the server. The size of the
        list is controlled by the
        profiling_history_size session
        variable, which has a default value of 15. The maximum value is
        100. Setting the value to 0 has the practical effect of
        disabling profiling.
      
        All statements are profiled except SHOW
        PROFILE and SHOW
        PROFILES, so you will find neither of those statements
        in the profile list. Malformed statements are profiled. For
        example, SHOW PROFILING is an illegal
        statement, and a syntax error occurs if you try to execute it,
        but it will show up in the profiling list.
      
        SHOW PROFILE displays detailed
        information about a single statement. Without the FOR
        QUERY  clause, the output
        pertains to the most recently executed statement. If
        nFOR QUERY  is
        included, nSHOW PROFILE displays
        information for statement n. The
        values of n correspond to the
        Query_ID values displayed by
        SHOW PROFILES.
      
        The LIMIT
         clause may be
        given to limit the output to
        row_countrow_count rows. If
        LIMIT is given, OFFSET
         may be added to
        begin the output offsetoffset rows into the
        full set of rows.
      
        By default, SHOW PROFILE displays
        Status and Duration
        columns. The Status values are like the
        State values displayed by
        SHOW PROCESSLIST, although there
        might be some minor differences in interpretion for the two
        statements for some status values (see
        Section 8.14, “Examining Thread Information”).
      
        Optional type values may be specified
        to display specific additional types of information:
            ALL displays all information
          
            BLOCK IO displays counts for block input
            and output operations
          
            CONTEXT SWITCHES displays counts for
            voluntary and involuntary context switches
          
            CPU displays user and system CPU usage
            times
          
            IPC displays counts for messages sent and
            received
          
            MEMORY is not currently implemented
          
            PAGE FAULTS displays counts for major and
            minor page faults
          
            SOURCE displays the names of functions
            from the source code, together with the name and line number
            of the file in which the function occurs
          
            SWAPS displays swap counts
Profiling is enabled per session. When a session ends, its profiling information is lost.
mysql>SELECT @@profiling;+-------------+ | @@profiling | +-------------+ | 0 | +-------------+ 1 row in set (0.00 sec) mysql>SET profiling = 1;Query OK, 0 rows affected (0.00 sec) mysql>DROP TABLE IF EXISTS t1;Query OK, 0 rows affected, 1 warning (0.00 sec) mysql>CREATE TABLE T1 (id INT);Query OK, 0 rows affected (0.01 sec) mysql>SHOW PROFILES;+----------+----------+--------------------------+ | Query_ID | Duration | Query | +----------+----------+--------------------------+ | 0 | 0.000088 | SET PROFILING = 1 | | 1 | 0.000136 | DROP TABLE IF EXISTS t1 | | 2 | 0.011947 | CREATE TABLE t1 (id INT) | +----------+----------+--------------------------+ 3 rows in set (0.00 sec) mysql>SHOW PROFILE;+----------------------+----------+ | Status | Duration | +----------------------+----------+ | checking permissions | 0.000040 | | creating table | 0.000056 | | After create | 0.011363 | | query end | 0.000375 | | freeing items | 0.000089 | | logging slow query | 0.000019 | | cleaning up | 0.000005 | +----------------------+----------+ 7 rows in set (0.00 sec) mysql>SHOW PROFILE FOR QUERY 1;+--------------------+----------+ | Status | Duration | +--------------------+----------+ | query end | 0.000107 | | freeing items | 0.000008 | | logging slow query | 0.000015 | | cleaning up | 0.000006 | +--------------------+----------+ 4 rows in set (0.00 sec) mysql>SHOW PROFILE CPU FOR QUERY 2;+----------------------+----------+----------+------------+ | Status | Duration | CPU_user | CPU_system | +----------------------+----------+----------+------------+ | checking permissions | 0.000040 | 0.000038 | 0.000002 | | creating table | 0.000056 | 0.000028 | 0.000028 | | After create | 0.011363 | 0.000217 | 0.001571 | | query end | 0.000375 | 0.000013 | 0.000028 | | freeing items | 0.000089 | 0.000010 | 0.000014 | | logging slow query | 0.000019 | 0.000009 | 0.000010 | | cleaning up | 0.000005 | 0.000003 | 0.000002 | +----------------------+----------+----------+------------+ 7 rows in set (0.00 sec)
          Profiling is only partially functional on some architectures.
          For values that depend on the getrusage()
          system call, NULL is returned on systems
          such as Windows that do not support the call. In addition,
          profiling is per process and not per thread. This means that
          activity on threads within the server other than your own may
          affect the timing information that you see.
        You can also get profiling information from the
        PROFILING table in
        INFORMATION_SCHEMA. See
        Section 21.16, “The INFORMATION_SCHEMA PROFILING Table”. For example, the following
        queries produce the same result:
      
SHOW PROFILE FOR QUERY 2; SELECT STATE, FORMAT(DURATION, 6) AS DURATION FROM INFORMATION_SCHEMA.PROFILING WHERE QUERY_ID = 2 ORDER BY SEQ;
SHOW PROFILES
        The SHOW PROFILES statement,
        together with SHOW PROFILE,
        displays profiling information that indicates resource usage for
        statements executed during the course of the current session.
        For more information, see Section 13.7.5.31, “SHOW PROFILE Syntax”.
These statements are deprecated as of MySQL 5.6.7 and will be removed in a future MySQL release. Use the Performance Schema instead; see Chapter 22, MySQL Performance Schema.
SHOW RELAYLOG EVENTS [IN 'log_name'] [FROMpos] [LIMIT [offset,]row_count]
        Shows the events in the relay log of a replication slave. If you
        do not specify
        ', the
        first relay log is displayed. This statement has no effect on
        the master.
      log_name'
        The LIMIT clause has the same syntax as for
        the SELECT statement. See
        Section 13.2.9, “SELECT Syntax”.
          Issuing a SHOW RELAYLOG EVENTS
          with no LIMIT clause could start a very
          time- and resource-consuming process because the server
          returns to the client the complete contents of the relay log
          (including all statements modifying data that have been
          received by the slave).
          Some events relating to the setting of user and system
          variables are not included in the output from
          SHOW RELAYLOG EVENTS. To get
          complete coverage of events within a relay log, use
          mysqlbinlog.
SHOW SLAVE HOSTS
Displays a list of replication slaves currently registered with the master.
        SHOW SLAVE HOSTS should be executed on a
        server that acts as a replication master. The statement displays
        information about servers that are or have been connected as
        replication slaves, with each row of the result corresponding to
        one slave server, as shown here:
      
mysql> SHOW SLAVE HOSTS;
+-----------+-----------+-------+-----------+--------------------------------------+
| Server_id | Host      | Port  | Master_id | Slave_UUID                           |
+-----------+-----------+-------+-----------+--------------------------------------+
|  192168010 | iconnect2 | 3306 | 192168011 | 14cb6624-7f93-11e0-b2c0-c80aa9429562 |
| 1921680101 | athena    | 3306 | 192168011 | 07af4990-f41f-11df-a566-7ac56fdaf645 |
+------------+-----------+------+-----------+--------------------------------------+
            Server_id: The unique server ID of the
            slave server, as configured in the slave server's
            option file, or on the command line with
            --server-id=.
          value
            Host: The host name of the slave server
            as specified on the slave with the
            --report-host option. This
            can differ from the machine name as configured in the
            operating system.
          
            User: The slave server user name as,
            specified on the slave with the
            --report-user option.
            Statement output includes this column only if the master
            server is started with the
            --show-slave-auth-info
            option.
          
            Password: The slave server password as,
            specified on the slave with the
            --report-password option.
            Statement output includes this column only if the master
            server is started with the
            --show-slave-auth-info
            option.
          
            Port: The port on the master to which the
            slave server is listening, as specified on the slave with
            the --report-port option.
          
            In MySQL 5.6.5 and later, a zero in this column means that
            the slave port
            (--report-port) was not set.
            Prior to MySQL 5.6.5, 3306 was used as the default in such
            cases (Bug #13333431).
          
            Master_id: The unique server ID of the
            master server that the slave server is replicating from.
            This is the server ID of the server on which SHOW
            SLAVE HOSTS is executed, so this same value is
            listed for each row in the result.
          
            
            Slave_UUID: The globally unique ID of
            this slave, as generated on the slave and found in the
            slave's auto.cnf file.
          
This column was added in MySQL 5.6.0.
SHOW SLAVE STATUS
        This statement provides status information on essential
        parameters of the slave threads. It requires either the
        SUPER or
        REPLICATION CLIENT privilege.
      
        If you issue this statement using the mysql
        client, you can use a \G statement terminator
        rather than a semicolon to obtain a more readable vertical
        layout:
      
mysql> SHOW SLAVE STATUS\G
*************************** 1. row ***************************
               Slave_IO_State: Waiting for master to send event
                  Master_Host: localhost
                  Master_User: root
                  Master_Port: 13000
                Connect_Retry: 60
              Master_Log_File: master-bin.000002
          Read_Master_Log_Pos: 1307
               Relay_Log_File: slave-relay-bin.000003
                Relay_Log_Pos: 1508
        Relay_Master_Log_File: master-bin.000002
             Slave_IO_Running: Yes
            Slave_SQL_Running: Yes
              Replicate_Do_DB:
          Replicate_Ignore_DB:
           Replicate_Do_Table:
       Replicate_Ignore_Table:
      Replicate_Wild_Do_Table:
  Replicate_Wild_Ignore_Table:
                   Last_Errno: 0
                   Last_Error:
                 Skip_Counter: 0
          Exec_Master_Log_Pos: 1307
              Relay_Log_Space: 1858
              Until_Condition: None
               Until_Log_File:
                Until_Log_Pos: 0
           Master_SSL_Allowed: No
           Master_SSL_CA_File:
           Master_SSL_CA_Path:
              Master_SSL_Cert:
            Master_SSL_Cipher:
               Master_SSL_Key:
        Seconds_Behind_Master: 0
Master_SSL_Verify_Server_Cert: No
                Last_IO_Errno: 0
                Last_IO_Error:
               Last_SQL_Errno: 0
               Last_SQL_Error:
  Replicate_Ignore_Server_Ids:
             Master_Server_Id: 1
                  Master_UUID: 3e11fa47-71ca-11e1-9e33-c80aa9429562
             Master_Info_File: /var/mysqld.2/data/master.info
                    SQL_Delay: 0
          SQL_Remaining_Delay: NULL
      Slave_SQL_Running_State: Slave has read all relay log; waiting for the slave I/O thread to update it
           Master_Retry_Count: 10
                  Master_Bind:
      Last_IO_Error_Timestamp:
     Last_SQL_Error_Timestamp:
               Master_SSL_Crl:
           Master_SSL_Crlpath:
           Retrieved_Gtid_Set: 3e11fa47-71ca-11e1-9e33-c80aa9429562:1-5
            Executed_Gtid_Set: 3e11fa47-71ca-11e1-9e33-c80aa9429562:1-5
                Auto_Position: 1
1 row in set (0.00 sec)
        The following list describes the fields returned by
        SHOW SLAVE STATUS. For additional
        information about interpreting their meanings, see
        Section 8.14.6, “Replication Slave I/O Thread States”.
            Slave_IO_State
          
            A copy of the State field of the
            SHOW PROCESSLIST output for
            the slave I/O thread. This tells you what the thread is
            doing: trying to connect to the master, waiting for events
            from the master, reconnecting to the master, and so on. For
            a listing of possible states, see
            Section 8.14.6, “Replication Slave I/O Thread States”.
          
            Master_Host
          
The master host that the slave is connected to.
            Master_User
          
The user name of the account used to connect to the master.
            Master_Port
          
The port used to connect to the master.
            Connect_Retry
          
            The number of seconds between connect retries (default 60).
            This can be set with the CHANGE MASTER
            TO statement.
          
            Master_Log_File
          
The name of the master binary log file from which the I/O thread is currently reading.
            Read_Master_Log_Pos
          
The position in the current master binary log file up to which the I/O thread has read.
            Relay_Log_File
          
The name of the relay log file from which the SQL thread is currently reading and executing.
            Relay_Log_Pos
          
The position in the current relay log file up to which the SQL thread has read and executed.
            Relay_Master_Log_File
          
The name of the master binary log file containing the most recent event executed by the SQL thread.
            Slave_IO_Running
          
Whether the I/O thread is started and has connected successfully to the master. Internally, the state of this thread is represented by one of the following three values:
MYSQL_SLAVE_NOT_RUN. 
                  The slave I/O thread is not running. For this state,
                  Slave_IO_Running is
                  No.
                
MYSQL_SLAVE_RUN_NOT_CONNECT. 
                  The slave I/O thread is running, but is not connected
                  to a replication master. For this state,
                  Slave_IO_Running depends on the
                  server version as shown in the following table.
| MySQL Version | Slave_IO_Running | 
|---|---|
| 4.1 (4.1.13 and earlier); 5.0 (5.0.11 and earlier) | Yes | 
| 4.1 (4.1.14 and later); 5.0 (5.0.12 and later) | No | 
| 5.1 (5.1.45 and earlier) | No | 
| 5.1 (5.1.46 and later); 5.5; 5.6 | Connecting | 
MYSQL_SLAVE_RUN_CONNECT. 
                  The slave I/O thread is running, and is connected to a
                  replication master. For this state,
                  Slave_IO_Running is
                  Yes.
            The value of the
            Slave_running system
            status variable corresponds with this value.
          
            Slave_SQL_Running
          
Whether the SQL thread is started.
            Replicate_Do_DB,
            Replicate_Ignore_DB
          
            The lists of databases that were specified with the
            --replicate-do-db and
            --replicate-ignore-db
            options, if any.
          
            Replicate_Do_Table,
            Replicate_Ignore_Table,
            Replicate_Wild_Do_Table,
            Replicate_Wild_Ignore_Table
          
            The lists of tables that were specified with the
            --replicate-do-table,
            --replicate-ignore-table,
            --replicate-wild-do-table,
            and
            --replicate-wild-ignore-table
            options, if any.
          
            Last_Errno, Last_Error
          
            These columns are aliases for
            Last_SQL_Errno and
            Last_SQL_Error.
          
            Issuing RESET MASTER or
            RESET SLAVE resets the values
            shown in these columns.
              When the slave SQL thread receives an error, it reports
              the error first, then stops the SQL thread. This means
              that there is a small window of time during which
              SHOW SLAVE STATUS shows a
              nonzero value for Last_SQL_Errno even
              though Slave_SQL_Running still displays
              Yes.
            Skip_Counter
          
            The current value of the
            sql_slave_skip_counter
            system variable. See
            Section 13.4.2.4, “SET GLOBAL sql_slave_skip_counter Syntax”.
          
            Exec_Master_Log_Pos
          
            The position in the current master binary log file to which
            the SQL thread has read and executed, marking the start of
            the next transaction or event to be processed. You can use
            this value with the CHANGE MASTER
            TO statement's
            MASTER_LOG_POS option when starting a new
            slave from an existing slave, so that the new slave reads
            from this point. The coordinates given by
            (Relay_Master_Log_File,
            Exec_Master_Log_Pos) in the master's
            binary log correspond to the coordinates given by
            (Relay_Log_File,
            Relay_Log_Pos) in the relay log.
          
            When using a multi-threaded slave (by setting
            slave_parallel_workers to a
            nonzero value in MySQL 5.6.3 and later), the value in this
            column actually represents a “low-water” mark,
            before which no uncommitted transactions remain. Because the
            current implementation allows execution of transactions on
            different databases in a different order on the slave than
            on the master, this is not necessarily the position of the
            most recently executed transaction.
          
            Relay_Log_Space
          
The total combined size of all existing relay log files.
            Until_Condition,
            Until_Log_File,
            Until_Log_Pos
          
            The values specified in the UNTIL clause
            of the START SLAVE statement.
          
            Until_Condition has these values:
                None if no UNTIL
                clause was specified
              
                Master if the slave is reading until
                a given position in the master's binary log
              
                Relay if the slave is reading until a
                given position in its relay log
            Starting with MySQL 5.6.6 UNTIL clauses
            related to GTIDs were added that have these values:
                SQL_BEFORE_GTIDS if the slave SQL
                thread is processing transactions until it has reached
                the first transaction whose GTID is listed in the
                gtid_set.
              
                SQL_AFTER_GTIDS if the slave threads
                are processing all transactions until the last
                transaction in the gtid_set has been
                processed by both threads.
              
                SQL_AFTER_MTS_GAPS if a
                multi-threaded slave's SQL threads are running until no
                more gaps are found in the relay log.
            Until_Log_File and
            Until_Log_Pos indicate the log file name
            and position that define the coordinates at which the SQL
            thread stops executing.
          
            For more information on UNTIL clauses,
            see Section 13.4.2.5, “START SLAVE Syntax”.
          
            Master_SSL_Allowed,
            Master_SSL_CA_File,
            Master_SSL_CA_Path,
            Master_SSL_Cert,
            Master_SSL_Cipher,
            Master_SSL_CRL_File,
            Master_SSL_CRL_Path,
            Master_SSL_Key,
            Master_SSL_Verify_Server_Cert
          
These fields show the SSL parameters used by the slave to connect to the master, if any.
            Master_SSL_Allowed has these values:
                Yes if an SSL connection to the
                master is permitted
              
                No if an SSL connection to the master
                is not permitted
              
                Ignored if an SSL connection is
                permitted but the slave server does not have SSL support
                enabled
            The values of the other SSL-related fields correspond to the
            values of the MASTER_SSL_CA,
            MASTER_SSL_CAPATH,
            MASTER_SSL_CERT,
            MASTER_SSL_CIPHER,
            MASTER_SSL_CRL,
            MASTER_SSL_CRLPATH,
            MASTER_SSL_KEY, and
            MASTER_SSL_VERIFY_SERVER_CERT options to
            the CHANGE MASTER TO
            statement. See Section 13.4.2.1, “CHANGE MASTER TO Syntax”.
          
            Master_SSL_CRL_File and
            Master_SSL_CRL_Path were added in MySQL
            5.6.3.
          
            Seconds_Behind_Master
          
This field is an indication of how “late” the slave is:
When the slave is actively processing updates, this field shows the difference between the current timestamp on the slave and the original timestamp logged on the master for the event currently being processed on the slave.
When no event is currently being processed on the slave, this value is 0.
            In essence, this field measures the time difference in
            seconds between the slave SQL thread and the slave I/O
            thread. If the network connection between master and slave
            is fast, the slave I/O thread is very close to the master,
            so this field is a good approximation of how late the slave
            SQL thread is compared to the master. If the network is
            slow, this is not a good approximation;
            the slave SQL thread may quite often be caught up with the
            slow-reading slave I/O thread, so
            Seconds_Behind_Master often shows a value
            of 0, even if the I/O thread is late compared to the master.
            In other words, this column is useful only for
            fast networks.
          
            This time difference computation works even if the master
            and slave do not have identical clock times, provided that
            the difference, computed when the slave I/O thread starts,
            remains constant from then on. Any changes—including
            NTP updates—can lead to clock skews that can make
            calculation of Seconds_Behind_Master less
            reliable.
          
            In MySQL 5.6.9 and later, this field is
            NULL (undefined or unknown) if the slave
            SQL thread is not running, or if the SQL thread has consumed
            all of the relay log and the slave I/O thread is not
            running. Previously, this field was NULL
            if the slave SQL thread or the slave I/O thread was not
            running or was not connected to the master. (Bug #12946333)
            For example, if (prior to MySQL 5.6.9) the slave I/O thread
            was running but was not connected to the master and was
            sleeping for the number of seconds given by the
            CHANGE MASTER TO statement or
            --master-connect-retry option
            (default 60) before reconnecting, the value was
            NULL. Now in such cases, the connection
            to the master is not tested; instead, if the I/O thread is
            running but the relay log is exhausted,
            Seconds_Behind_Master is set to 0.
          
            The value of Seconds_Behind_Master is
            based on the timestamps stored in events, which are
            preserved through replication. This means that if a master
            M1 is itself a slave of M0, any event from M1's binary log
            that originates from M0's binary log has M0's timestamp for
            that event. This enables MySQL to replicate
            TIMESTAMP successfully.
            However, the problem for
            Seconds_Behind_Master is that if M1 also
            receives direct updates from clients, the
            Seconds_Behind_Master value randomly
            fluctuates because sometimes the last event from M1
            originates from M0 and sometimes is the result of a direct
            update on M1.
          
            When using a multi-threaded slave (MySQL 5.6.3 and later),
            you should keep in mind that this value is based on
            Exec_Master_Log_Pos, and so may not
            reflect the position of the most recently committed
            transaction.
          
            Last_IO_Errno,
            Last_IO_Error
          
            The error number and error message of the most recent error
            that caused the I/O thread to stop. An error number of 0 and
            message of the empty string mean “no error.” If
            the Last_IO_Error value is not empty, the
            error values also appear in the slave's error log.
          
            Beginning with MySQL 5.6.1, I/O error information includes a
            timestamp showing when the most recent I/O thread error
            occurred. This timestamp uses the format YYMMDD
            HH:MM:SS.
          
            Previous to MySQL 5.6.3, this timestamp was prefixed to the
            error message text shown in the
            Last_IO_Error column. In MySQL 5.6.3 and
            later, the timestamp appears instead in the
            Last_SQL_Error_Timestamp column.
          
            Issuing RESET MASTER or
            RESET SLAVE resets the values
            shown in these columns.
          
            Last_SQL_Errno,
            Last_SQL_Error
          
            The error number and error message of the most recent error
            that caused the SQL thread to stop. An error number of 0 and
            message of the empty string mean “no error.” If
            the Last_SQL_Error value is not empty,
            the error values also appear in the slave's error log.
          
            Beginning with MySQL 5.6.1, SQL error information includes a
            timestamp showing when the most recent SQL thread error
            occurred. This timestamp uses the format YYMMDD
            HH:MM:SS.
          
            Previous to MySQL 5.6.3, this timestamp was prefixed to the
            error message text shown in the
            Last_SQL_Error column. In MySQL 5.6.3 and
            later, the timestamp appears instead in the
            Last_SQL_Error_Timestamp column.
          
            Issuing RESET MASTER or
            RESET SLAVE resets the values
            shown in these columns.
          
            Replicate_Ignore_Server_Ids
          
            In MySQL 5.6, you set a slave to ignore events
            from 0 or more masters using the
            IGNORE_SERVER_IDS option of the
            CHANGE MASTER TO statement.
            By default this is blank, and is usually modified only when
            using a circular or other multi-master replication setup.
            The message shown for
            Replicate_Ignore_Server_Ids when not
            blank consists of a comma-delimited list of one or more
            numbers, indicating the server IDs to be ignored. For
            example:
          
Replicate_Ignore_Server_Ids: 2, 6, 9
              Ignored_server_ids also shows the
              server IDs to be ignored, but is a space-delimited list,
              which is preceded by the total number of server IDs to be
              ignored. For example, if a CHANGE
              MASTER TO statement containing the
              IGNORE_SERVER_IDS = (2,6,9) option has
              been issued to tell a slave to ignore masters having the
              server ID 2, 6, or 9, that information appears as:
            
Ignored_server_ids: 3 2 6 9
              where 3 is the total number of server
              IDs being ignored.
            Replicate_Ignore_Server_Ids filtering is
            performed by the I/O thread, rather than by the SQL thread,
            which means that events which are filtered out are not
            written to the relay log. This differs from the filtering
            actions taken by server options such
            --replicate-do-table, which
            apply to the SQL thread.
          
            Master_Server_Id
          
            The server_id value from
            the master.
          
            Master_UUID
          
            The server_uuid value from
            the master. This field was added in MySQL 5.6.0.
          
            Master_Info_File
          
            The location of the master.info file.
            This field was added in MySQL 5.6.0.
          
            SQL_Delay
          
The number of seconds that the slave must lag the master. This field was added in MySQL 5.6.0.
            SQL_Remaining_Delay
          
            When Slave_SQL_Running_State is
            Waiting until MASTER_DELAY seconds after master
            executed event, this field contains the number of
            delay seconds remaining. At other times, this field is
            NULL. This field was added in MySQL
            5.6.0.
          
            Slave_SQL_Running_State
          
            The state of the SQL thread (analogous to
            Slave_IO_State). The value is identical
            to the State value of the SQL thread as
            displayed by SHOW
            PROCESSLIST;
            Section 8.14.7, “Replication Slave SQL Thread States”, provides a
            listing of possible states. This field was added in MySQL
            5.6.0.
          
            Master_Retry_Count
          
            The number of times the slave can attempt to reconnect to
            the master in the event of a lost connection. This value can
            be set using the MASTER_RETRY_COUNT
            option of the CHANGE MASTER
            TO statement (preferred) or the older
            --master-retry-count server
            option (still supported for backward compatibility). This
            field was added in MySQL 5.6.1.
          
            Master_Bind
          
            The network interface that the slave is bound to, if any.
            This is set using the MASTER_BIND option
            for the CHANGE MASTER TO
            statement.
          
This column was added in MySQL 5.6.2.
            Last_IO_Error_Timestamp
          
            A timestamp in YYMMDD HH:MM:SS format
            that shows when the most recent I/O error took place.
          
            This column was added in MySQL 5.6.3. Previously in MySQL
            5.6, this timestamp was prepended to the error text shown in
            Last_IO_Error.
          
            Last_SQL_Error_Timestamp
          
            A timestamp in YYMMDD HH:MM:SS format
            that shows when the most recent SQL error occurred.
          
            This column was added in MySQL 5.6.3. Previously in MySQL
            5.6, this timestamp was prepended to the error text shown in
            Last_SQL_Error.
          
            Retrieved_Gtid_Set
          
The set of global transaction IDs corresponding to all transactions received by this slave. Empty if GTIDs are not in use.
            This is the set of all GTIDs that exist or have existed in
            the relay logs. Each GTID is added as soon as the
            Gtid_log_event is received. This can
            cause partially transmitted transactions to have their GTIDs
            included in the set.
          
            When all relay logs are lost due to executing
            RESET SLAVE or
            CHANGE MASTER TO, or due to
            the effects of the
            --relay-log-recovery option,
            the set is cleared. When
            relay_log_purge = 1, the
            newest relay log is always kept, and the set is not cleared.
          
This column was added in MySQL 5.6.5.
Prior to MySQL 5.6.10, this value was printed using uppercase. In MySQL 5.6.10 and later, it is always printed using lowercase. (Bug #15869441)
            Executed_Gtid_Set
          
            The set of global transaction IDs written in the binary log.
            This is the same as the value for the global
            gtid_executed system
            variable (named gtid_done
            prior to MySQL 5.6.9) on this server, as well as the value
            for Executed_Gtid_Set in the output of
            SHOW MASTER STATUS on this
            server. Empty if GTIDs are not in use.
          
This column was added in MySQL 5.6.5.
Prior to MySQL 5.6.10, this value was printed using uppercase. In MySQL 5.6.10 and later, it is always printed using lowercase. (Bug #15869441)
            Auto_Position
          
1 if autopositioning is in use; otherwise 0.
This column was added in MySQL 5.6.10. (Bug #15992220)
SHOW [GLOBAL | SESSION] STATUS
    [LIKE 'pattern' | WHERE expr]
        SHOW STATUS provides server
        status information (see
        Section 5.1.6, “Server Status Variables”). This statement does
        not require any privilege. It requires only the ability to
        connect to the server.
      
Status variable information is also available from these sources:
        For SHOW STATUS, a
        LIKE clause, if present, indicates
        which variable names to match. A WHERE clause
        can be given to select rows using more general conditions, as
        discussed in Section 21.32, “Extensions to SHOW Statements”.
      
        SHOW STATUS accepts an optional
        GLOBAL or SESSION variable
        scope modifier:
            With a GLOBAL modifier, the statement
            displays the global status values. A global status variable
            may represent status for some aspect of the server itself
            (for example, Aborted_connects), or the
            aggregated status over all connections to MySQL (for
            example, Bytes_received and
            Bytes_sent). If a variable has no global
            value, the session value is displayed.
          
            With a SESSION modifier, the statement
            displays the status variable values for the current
            connection. If a variable has no session value, the global
            value is displayed. LOCAL is a synonym
            for SESSION.
          
            If no modifier is present, the default is
            SESSION.
The scope for each status variable is listed at Section 5.1.6, “Server Status Variables”.
        Each invocation of the SHOW
        STATUS statement uses an internal temporary table and
        increments the global
        Created_tmp_tables value.
      
Partial output is shown here. The list of names and values may differ for your server. The meaning of each variable is given in Section 5.1.6, “Server Status Variables”.
mysql> SHOW STATUS;
+--------------------------+------------+
| Variable_name            | Value      |
+--------------------------+------------+
| Aborted_clients          | 0          |
| Aborted_connects         | 0          |
| Bytes_received           | 155372598  |
| Bytes_sent               | 1176560426 |
| Connections              | 30023      |
| Created_tmp_disk_tables  | 0          |
| Created_tmp_tables       | 8340       |
| Created_tmp_files        | 60         |
...
| Open_tables              | 1          |
| Open_files               | 2          |
| Open_streams             | 0          |
| Opened_tables            | 44600      |
| Questions                | 2026873    |
...
| Table_locks_immediate    | 1920382    |
| Table_locks_waited       | 0          |
| Threads_cached           | 0          |
| Threads_created          | 30022      |
| Threads_connected        | 1          |
| Threads_running          | 1          |
| Uptime                   | 80380      |
+--------------------------+------------+
        With a LIKE clause, the statement
        displays only rows for those variables with names that match the
        pattern:
      
mysql> SHOW STATUS LIKE 'Key%';
+--------------------+----------+
| Variable_name      | Value    |
+--------------------+----------+
| Key_blocks_used    | 14955    |
| Key_read_requests  | 96854827 |
| Key_reads          | 162040   |
| Key_write_requests | 7589728  |
| Key_writes         | 3813196  |
+--------------------+----------+
SHOW TABLE STATUS [{FROM | IN} db_name]
    [LIKE 'pattern' | WHERE expr]
        SHOW TABLE STATUS works likes
        SHOW TABLES, but provides a lot
        of information about each non-TEMPORARY
        table. You can also get this list using the mysqlshow
        --status db_name command.
        The LIKE clause, if present,
        indicates which table names to match. The
        WHERE clause can be given to select rows
        using more general conditions, as discussed in
        Section 21.32, “Extensions to SHOW Statements”.
      
This statement also displays information about views.
        SHOW TABLE STATUS output has the
        following columns:
            Name
          
The name of the table.
            Engine
          
The storage engine for the table. See Chapter 15, Alternative Storage Engines.
            Version
          
            The version number of the table's .frm
            file.
          
            Row_format
          
            The row-storage format (Fixed,
            Dynamic, Compressed,
            Redundant, Compact).
            For MyISAM tables,
            (Dynamic corresponds to what
            myisamchk -dvv reports as
            Packed. The format of
            InnoDB tables is reported as
            Redundant or Compact.
            For the Barracuda file format of the
            InnoDB Plugin, the format may be
            Compressed or Dynamic.
          
            Rows
          
            The number of rows. Some storage engines, such as
            MyISAM, store the exact count. For other
            storage engines, such as InnoDB, this
            value is an approximation, and may vary from the actual
            value by as much as 40 to 50%. In such cases, use
            SELECT COUNT(*) to obtain an accurate
            count.
          
            The Rows value is NULL
            for tables in the INFORMATION_SCHEMA
            database.
          
            Avg_row_length
          
The average row length.
            Data_length
          
The length of the data file.
            Max_data_length
          
The maximum length of the data file. This is the total number of bytes of data that can be stored in the table, given the data pointer size used.
            Index_length
          
The length of the index file.
            Data_free
          
The number of allocated but unused bytes.
            This information is also shown for InnoDB
            tables (previously, it was in the Comment
            value). InnoDB tables report the free
            space of the tablespace to which the table belongs. For a
            table located in the shared tablespace, this is the free
            space of the shared tablespace. If you are using multiple
            tablespaces and the table has its own tablespace, the free
            space is for only that table. Free space means the number of
            bytes in completely free extents minus a safety margin. Even
            if free space displays as 0, it may be possible to insert
            rows as long as new extents need not be allocated.
          
            For partitioned tables, this value is only an estimate and
            may not be absolutely correct. A more accurate method of
            obtaining this information in such cases is to query the
            INFORMATION_SCHEMA.PARTITIONS table, as
            shown in this example:
          
SELECT    SUM(DATA_FREE)
    FROM  INFORMATION_SCHEMA.PARTITIONS
    WHERE TABLE_SCHEMA = 'mydb'
    AND   TABLE_NAME   = 'mytable';
For more information, see Section 21.13, “The INFORMATION_SCHEMA PARTITIONS Table”.
            Auto_increment
          
            The next AUTO_INCREMENT value.
          
            Create_time
          
When the table was created.
            Update_time
          
            When the data file was last updated. For some storage
            engines, this value is NULL. For example,
            InnoDB stores multiple tables in its
            system
            tablespace and the data file timestamp does not
            apply. Even with
            file-per-table
            mode with each InnoDB table in a separate
            .ibd file,
            change
            buffering can delay the write to the data file, so
            the file modification time is different from the time of the
            last insert, update, or delete. For
            MyISAM, the data file timestamp is used;
            however, on Windows the timestamp is not updated by updates
            so the value is inaccurate.
          
            Check_time
          
            When the table was last checked. Not all storage engines
            update this time, in which case the value is always
            NULL.
          
            Collation
          
The table's character set and collation.
            Checksum
          
The live checksum value (if any).
            Create_options
          
            Extra options used with CREATE
            TABLE. The original options supplied when
            CREATE TABLE is called are
            retained and the options reported here may differ from the
            active table settings and options.
          
            Comment
          
The comment used when creating the table (or information as to why MySQL could not access the table information).
        For MEMORY tables, the
        Data_length,
        Max_data_length, and
        Index_length values approximate the actual
        amount of allocated memory. The allocation algorithm reserves
        memory in large amounts to reduce the number of allocation
        operations.
      
        For NDB tables, the output of this
        statement shows appropriate values for the
        Avg_row_length and
        Data_length columns, with the exception that
        BLOB columns are not taken into
        account
      
        For views, all the fields displayed by SHOW
        TABLE STATUS are NULL except that
        Name indicates the view name and
        Comment says view.
SHOW [FULL] TABLES [{FROM | IN} db_name]
    [LIKE 'pattern' | WHERE expr]
        SHOW TABLES lists the
        non-TEMPORARY tables in a given database. You
        can also get this list using the mysqlshow
        db_name command. The
        LIKE clause, if present, indicates
        which table names to match. The WHERE clause
        can be given to select rows using more general conditions, as
        discussed in Section 21.32, “Extensions to SHOW Statements”.
      
        Matching performed by the LIKE clause is
        dependent on the setting of the
        lower_case_table_names system
        variable.
      
        This statement also lists any views in the database. The
        FULL modifier is supported such that
        SHOW FULL
        TABLES displays a second output column. Values for the
        second column are BASE TABLE for a table and
        VIEW for a view.
      
        If you have no privileges for a base table or view, it does not
        show up in the output from SHOW
        TABLES or mysqlshow db_name.
SHOW TRIGGERS [{FROM | IN} db_name]
    [LIKE 'pattern' | WHERE expr]
        SHOW TRIGGERS lists the triggers
        currently defined for tables in a database (the default database
        unless a FROM clause is given). This
        statement returns results only for databases and tables for
        which you have the TRIGGER
        privilege. The LIKE clause, if
        present, indicates which table names to match (not trigger
        names) and causes the statement to display triggers for those
        tables. The WHERE clause can be given to
        select rows using more general conditions, as discussed in
        Section 21.32, “Extensions to SHOW Statements”.
      
        For the trigger ins_sum as defined in
        Section 20.3, “Using Triggers”, the output of this statement is as
        shown here:
      
mysql> SHOW TRIGGERS LIKE 'acc%'\G
*************************** 1. row ***************************
             Trigger: ins_sum
               Event: INSERT
               Table: account
           Statement: SET @sum = @sum + NEW.amount
              Timing: BEFORE
             Created: NULL
            sql_mode: NO_ENGINE_SUBSTITUTION
             Definer: me@localhost
character_set_client: utf8
collation_connection: utf8_general_ci
  Database Collation: latin1_swedish_ci
        SHOW TRIGGERS output has the
        following columns:
            Trigger: The trigger name.
          
            Event: The type of operation that causes
            trigger activation. The value is
            'INSERT', 'UPDATE', or
            'DELETE'.
          
            Table: The table for which the trigger is
            defined.
          
            Statement: The trigger body; that is, the
            statement executed when the trigger activates.
          
            Timing: Whether the trigger activates
            before or after the triggering event. The value is
            'BEFORE' or 'AFTER'.
          
            Created: Currently, the value of this
            column is always NULL.
          
            sql_mode: The SQL mode in effect when the
            trigger executes.
          
            Definer: The account of the user who
            created the trigger, in
            '
            format.
          user_name'@'host_name'
            character_set_client: The session value
            of the character_set_client
            system variable when the trigger was created.
          
            collation_connection: The session value
            of the collation_connection
            system variable when the trigger was created.
          
            Database Collation: The collation of the
            database with which the trigger is associated.
        You can also obtain information about trigger objects from
        INFORMATION_SCHEMA, which contains a
        TRIGGERS table. See
        Section 21.26, “The INFORMATION_SCHEMA TRIGGERS Table”.
SHOW [GLOBAL | SESSION] VARIABLES
    [LIKE 'pattern' | WHERE expr]
        SHOW VARIABLES shows the values
        of MySQL system variables (see
        Section 5.1.4, “Server System Variables”). This statement does
        not require any privilege. It requires only the ability to
        connect to the server.
      
System variable information is also available from these sources:
        For SHOW VARIABLES, a
        LIKE clause, if present, indicates
        which variable names to match. A WHERE clause
        can be given to select rows using more general conditions, as
        discussed in Section 21.32, “Extensions to SHOW Statements”.
      
        SHOW VARIABLES accepts an
        optional GLOBAL or SESSION
        variable scope modifier:
            With a GLOBAL modifier, the statement
            displays global system variable values. These are the values
            used to initialize the corresponding session variables for
            new connections to MySQL. If a variable has no global value,
            no value is displayed.
          
            With a SESSION modifier, the statement
            displays the system varaible values that are in effect for
            the current connection. If a variable has no session value,
            the global value is displayed. LOCAL is a
            synonym for SESSION.
          
            If no modifier is present, the default is
            SESSION.
The scope for each system variable is listed at Section 5.1.4, “Server System Variables”.
        SHOW VARIABLES is subject to a
        version-dependent display-width limit. For variables with very
        long values that are not completely displayed, use
        SELECT as a workaround. For
        example:
      
SELECT @@GLOBAL.innodb_data_file_path;
        Most system variables can be set at server startup (read-only
        variables such as
        version_comment are
        exceptions). Many can be changed at runtime with the
        SET
        statement. See Section 5.1.5, “Using System Variables”, and
        Section 13.7.4, “SET Syntax”.
      
Partial output is shown here. The list of names and values may differ for your server. Section 5.1.4, “Server System Variables”, describes the meaning of each variable, and Section 8.12.2, “Tuning Server Parameters”, provides information about tuning them.
mysql> SHOW VARIABLES;
+-----------------------------------------+---------------------------+
| Variable_name                           | Value                     |
+-----------------------------------------+---------------------------+
| auto_increment_increment                | 1                         |
| auto_increment_offset                   | 1                         |
| autocommit                              | ON                        |
| automatic_sp_privileges                 | ON                        |
| back_log                                | 50                        |
| basedir                                 | /home/jon/bin/mysql-5.5   |
| big_tables                              | OFF                       |
| binlog_cache_size                       | 32768                     |
| binlog_direct_non_transactional_updates | OFF                       |
| binlog_format                           | STATEMENT                 |
| binlog_stmt_cache_size                  | 32768                     |
| bulk_insert_buffer_size                 | 8388608                   |
...
| max_allowed_packet                      | 1048576                   |
| max_binlog_cache_size                   | 18446744073709547520      |
| max_binlog_size                         | 1073741824                |
| max_binlog_stmt_cache_size              | 18446744073709547520      |
| max_connect_errors                      | 100                       |
| max_connections                         | 151                       |
| max_delayed_threads                     | 20                        |
| max_error_count                         | 64                        |
| max_heap_table_size                     | 16777216                  |
| max_insert_delayed_threads              | 20                        |
| max_join_size                           | 18446744073709551615      |
...
| thread_handling                         | one-thread-per-connection |
| thread_stack                            | 262144                    |
| time_format                             | %H:%i:%s                  |
| time_zone                               | SYSTEM                    |
| timed_mutexes                           | OFF                       |
| timestamp                               | 1316689732                |
| tmp_table_size                          | 16777216                  |
| tmpdir                                  | /tmp                      |
| transaction_alloc_block_size            | 8192                      |
| transaction_prealloc_size               | 4096                      |
| tx_isolation                            | REPEATABLE-READ           |
| unique_checks                           | ON                        |
| updatable_views_with_limit              | YES                       |
| version                                 | 5.5.17-log                |
| version_comment                         | Source distribution       |
| version_compile_machine                 | x86_64                    |
| version_compile_os                      | Linux                     |
| wait_timeout                            | 28800                     |
| warning_count                           | 0                         |
+-----------------------------------------+---------------------------+
        With a LIKE clause, the statement
        displays only rows for those variables with names that match the
        pattern. To obtain the row for a specific variable, use a
        LIKE clause as shown:
      
SHOW VARIABLES LIKE 'max_join_size'; SHOW SESSION VARIABLES LIKE 'max_join_size';
        To get a list of variables whose name match a pattern, use the
        “%” wildcard character in a
        LIKE clause:
      
SHOW VARIABLES LIKE '%size%'; SHOW GLOBAL VARIABLES LIKE '%size%';
        Wildcard characters can be used in any position within the
        pattern to be matched. Strictly speaking, because
        “_” is a wildcard that matches
        any single character, you should escape it as
        “\_” to match it literally. In
        practice, this is rarely necessary.
SHOW WARNINGS [LIMIT [offset,]row_count] SHOW COUNT(*) WARNINGS
        SHOW WARNINGS is a diagnostic
        statement that displays information about the conditions
        (errors, warnings, and notes) resulting from executing a
        statement in the current session. Warnings are generated for DML
        statements such as INSERT,
        UPDATE, and
        LOAD DATA
        INFILE as well as DDL statements such as
        CREATE TABLE and
        ALTER TABLE.
      
        The LIMIT clause has the same syntax as for
        the SELECT statement. See
        Section 13.2.9, “SELECT Syntax”.
      
        SHOW WARNINGS is also used
        following EXPLAIN EXTENDED, to
        display the extra information generated by
        EXPLAIN when the
        EXTENDED keyword is used. See
        Section 8.8.3, “EXPLAIN EXTENDED Output Format”.
      
        SHOW WARNINGS displays
        information about the conditions resulting from the most recent
        statement in the current session that generated messages. It
        shows nothing if the most recent statement used a table and
        generated no messages. (That is, statements that use a table but
        generate no messages clear the message list.) Statements that do
        not use tables and do not generate messages have no effect on
        the message list.
      
        The SHOW COUNT(*)
        WARNINGS diagnostic statement displays the total
        number of errors, warnings, and notes. You can also retrieve
        this number from the
        warning_count system variable:
      
SHOW COUNT(*) WARNINGS; SELECT @@warning_count;
        A related diagnostic statement, SHOW
        ERRORS, shows only error conditions (it excludes
        warnings and notes), and
        SHOW COUNT(*)
        ERRORS statement displays the total number of errors.
        See Section 13.7.5.18, “SHOW ERRORS Syntax”. GET
        DIAGNOSTICS can be used to examine information for
        individual conditions. See Section 13.6.7.3, “GET DIAGNOSTICS Syntax”.
      
        Here is a simple example that shows data-conversion warnings for
        INSERT:
      
mysql>CREATE TABLE t1 (a TINYINT NOT NULL, b CHAR(4));Query OK, 0 rows affected (0.05 sec) mysql>INSERT INTO t1 VALUES(10,'mysql'), (NULL,'test'), (300,'xyz');Query OK, 3 rows affected, 3 warnings (0.00 sec) Records: 3 Duplicates: 0 Warnings: 3 mysql>SHOW WARNINGS\G*************************** 1. row *************************** Level: Warning Code: 1265 Message: Data truncated for column 'b' at row 1 *************************** 2. row *************************** Level: Warning Code: 1048 Message: Column 'a' cannot be null *************************** 3. row *************************** Level: Warning Code: 1264 Message: Out of range value for column 'a' at row 3 3 rows in set (0.00 sec)
        The max_error_count system
        variable controls the maximum number of error, warning, and note
        messages for which the server stores information, and thus the
        number of messages that SHOW
        WARNINGS displays. To change the number of messages
        the server can store, change the value of
        max_error_count. The default is
        64.
      
        max_error_count controls only
        how many messages are stored, not how many are counted. The
        value of warning_count is not
        limited by max_error_count,
        even if the number of messages generated exceeds
        max_error_count. The following
        example demonstrates this. The ALTER
        TABLE statement produces three warning messages
        (strict SQL mode is disabled for the example to prevent an error
        from occuring after a single conversion issue). Only one message
        is stored and displayed because
        max_error_count has been set to
        1, but all three are counted (as shown by the value of
        warning_count):
      
mysql>SHOW VARIABLES LIKE 'max_error_count';+-----------------+-------+ | Variable_name | Value | +-----------------+-------+ | max_error_count | 64 | +-----------------+-------+ 1 row in set (0.00 sec) mysql>SET max_error_count=1, sql_mode = '';Query OK, 0 rows affected (0.00 sec) mysql>ALTER TABLE t1 MODIFY b CHAR;Query OK, 3 rows affected, 3 warnings (0.00 sec) Records: 3 Duplicates: 0 Warnings: 3 mysql>SHOW WARNINGS;+---------+------+----------------------------------------+ | Level | Code | Message | +---------+------+----------------------------------------+ | Warning | 1263 | Data truncated for column 'b' at row 1 | +---------+------+----------------------------------------+ 1 row in set (0.00 sec) mysql>SELECT @@warning_count;+-----------------+ | @@warning_count | +-----------------+ | 3 | +-----------------+ 1 row in set (0.01 sec)
        To disable message storage, set
        max_error_count to 0. In this
        case, warning_count still
        indicates how many warnings occurred, but messages are not
        stored and cannot be displayed.
      
        The sql_notes system variable
        controls whether note messages increment
        warning_count and whether the
        server stores them. By default,
        sql_notes is 1, but if set to
        0, notes do not increment
        warning_count and the server
        does not store them:
      
mysql>SET sql_notes = 1;mysql>DROP TABLE IF EXISTS test.no_such_table;Query OK, 0 rows affected, 1 warning (0.00 sec) mysql>SHOW WARNINGS;+-------+------+------------------------------------+ | Level | Code | Message | +-------+------+------------------------------------+ | Note | 1051 | Unknown table 'test.no_such_table' | +-------+------+------------------------------------+ 1 row in set (0.00 sec) mysql>SET sql_notes = 0;mysql>DROP TABLE IF EXISTS test.no_such_table;Query OK, 0 rows affected (0.00 sec) mysql>SHOW WARNINGS;Empty set (0.00 sec)
        The MySQL server sends to each client a count indicating the
        total number of errors, warnings, and notes resulting from the
        most recent statement executed by that client. From the C API,
        this value can be obtained by calling
        mysql_warning_count(). See
        Section 23.8.7.73, “mysql_warning_count()”.
BINLOG 'str'
        BINLOG is an internal-use
        statement. It is generated by the mysqlbinlog
        program as the printable representation of certain events in
        binary log files. (See Section 4.6.8, “mysqlbinlog — Utility for Processing Binary Log Files”.) The
        ' value is a
        base 64-encoded string the that server decodes to determine the
        data change indicated by the corresponding event. This statement
        requires the str'SUPER privilege.
      
As of MySQL 5.6, this statement can execute only format description events and row events. Previously it could execute all types of events.
CACHE INDEXtbl_index_list[,tbl_index_list] ... [PARTITION (partition_list| ALL)] INkey_cache_nametbl_index_list:tbl_name[[INDEX|KEY] (index_name[,index_name] ...)]partition_list:partition_name[,partition_name][, ...]
        The CACHE INDEX statement assigns
        table indexes to a specific key cache. It is used only for
        MyISAM tables. After the indexes have been
        assigned, they can be preloaded into the cache if desired with
        LOAD INDEX INTO
        CACHE.
      
        The following statement assigns indexes from the tables
        t1, t2, and
        t3 to the key cache named
        hot_cache:
      
mysql> CACHE INDEX t1, t2, t3 IN hot_cache;
+---------+--------------------+----------+----------+
| Table   | Op                 | Msg_type | Msg_text |
+---------+--------------------+----------+----------+
| test.t1 | assign_to_keycache | status   | OK       |
| test.t2 | assign_to_keycache | status   | OK       |
| test.t3 | assign_to_keycache | status   | OK       |
+---------+--------------------+----------+----------+
        The syntax of CACHE INDEX enables
        you to specify that only particular indexes from a table should
        be assigned to the cache. The current implementation assigns all
        the table's indexes to the cache, so there is no reason to
        specify anything other than the table name.
      
        The key cache referred to in a CACHE
        INDEX statement can be created by setting its size
        with a parameter setting statement or in the server parameter
        settings. For example:
      
mysql> SET GLOBAL keycache1.key_buffer_size=128*1024;
Key cache parameters can be accessed as members of a structured system variable. See Section 5.1.5.1, “Structured System Variables”.
A key cache must exist before you can assign indexes to it:
mysql> CACHE INDEX t1 IN non_existent_cache;
ERROR 1284 (HY000): Unknown key cache 'non_existent_cache'
By default, table indexes are assigned to the main (default) key cache created at the server startup. When a key cache is destroyed, all indexes assigned to it become assigned to the default key cache again.
Index assignment affects the server globally: If one client assigns an index to a given cache, this cache is used for all queries involving the index, no matter which client issues the queries.
        In MySQL 5.6, this statement is also supported for
        partitioned MyISAM tables. You can assign one
        or more indexes for one, several, or all partitions to a given
        key cache. For example, you can do the following:
      
CREATE TABLE pt (c1 INT, c2 VARCHAR(50), INDEX i(c1))
    PARTITION BY HASH(c1)
    PARTITIONS 4;
SET GLOBAL kc_fast.key_buffer_size = 128 * 1024;
SET GLOBAL kc_slow.key_buffer_size = 128 * 1024;
CACHE INDEX pt PARTITION (p0) IN kc_fast;
CACHE INDEX pt PARTITION (p1, p3) IN kc_slow;
The previous set of statements performs the following actions:
            Creates a partitioned table with 4 partitions; these
            partitions are automatically named p0,
            ..., p3; this table has an index named
            i on column c1.
          
            Creates 2 key caches named kc_fast and
            kc_slow
          
            Assigns the index for partition p0 to the
            kc_fast key cache and the index for
            partitions p1 and p3
            to the kc_slow key cache; the index for
            the remaining partition (p2) uses the
            server's default key cache.
        If you wish instead to assign the indexes for all partitions in
        table pt to a single key cache named
        kc_all, you can use either one of the
        following 2 statements:
      
CACHE INDEX pt PARTITION (ALL) IN kc_all; CACHE INDEX pt IN kc_all;
        The two statements just shown are equivalent, and issuing either
        one of them has exactly the same effect. In other words, if you
        wish to assign indexes for all partitions of a partitioned table
        to the same key cache, then the PARTITION
        (ALL) clause is optional.
      
When assigning indexes for multiple partitions to a key cache, the partitions do not have to be contiguous, and you are not required to list their names in any particular order. Indexes for any partitions that are not explicitly assigned to a key cache automatically use the server's default key cache.
        In MySQL 5.6, index preloading is also supported
        for partitioned MyISAM tables. For more
        information, see Section 13.7.6.5, “LOAD INDEX INTO CACHE Syntax”.
      
        In MySQL 5.6.11 only, gtid_next
        must be set to AUTOMATIC before issuing this
        statement. (Bug #16062608, Bug #16715809, Bug #69045)
FLUSH [NO_WRITE_TO_BINLOG | LOCAL]
    flush_option [, flush_option] ...
        The FLUSH statement has several
        variant forms that clear or reload various internal caches,
        flush tables, or acquire locks. To execute
        FLUSH, you must have the
        RELOAD privilege. Specific flush
        options might require additional privileges, as described later.
      
        By default, the server writes
        FLUSH statements to the binary
        log so that they replicate to replication slaves. To suppress
        logging, specify the optional
        NO_WRITE_TO_BINLOG keyword or its alias
        LOCAL.
          FLUSH LOGS,
          FLUSH TABLES WITH READ
          LOCK (with or without a table list), and
          FLUSH TABLES
          
          are not written to the binary log in any case because they
          would cause problems if replicated to a slave.
tbl_name ... FOR EXPORT
        Sending a SIGHUP signal to the server causes
        several flush operations to occur that are similar to various
        forms of the FLUSH statement. See
        Section 5.1.11, “Server Response to Signals”.
      
        The FLUSH statement causes an
        implicit commit. See Section 13.3.3, “Statements That Cause an Implicit Commit”.
      
        The RESET statement is similar to
        FLUSH. See
        Section 13.7.6.6, “RESET Syntax”, for information about using the
        RESET statement with replication.
      
        flush_option can be any of the
        following items.
            DES_KEY_FILE
          
            Reloads the DES keys from the file that was specified with
            the --des-key-file option at
            server startup time.
          
            HOSTS
          
            Empties the host cache. You should flush the host cache if
            some of your hosts change IP address or if the error message
            Host ' occurs. (See
            Section B.5.2.6, “Host 'host_name' is blocked”.) When more than
            host_name' is
            blockedmax_connect_errors errors
            occur successively for a given host while connecting to the
            MySQL server, MySQL assumes that something is wrong and
            blocks the host from further connection requests. Flushing
            the host cache enables further connection attempts from the
            host. The default value of
            max_connect_errors is 100
            (10 before MySQL 5.6.6). To avoid this error message, start
            the server with
            max_connect_errors set to a
            large value.
          
            [
          log_type]
            LOGS
            With no log_type option,
            FLUSH LOGS
            closes and reopens all log files. If binary logging is
            enabled, the sequence number of the binary log file is
            incremented by one relative to the previous file.
          
            FLUSH LOGS has no effect on tables used
            for the general query log or for the slow query log (see
            Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”). It also has no effect
            on tables used for the binary or relay log
            (--master-info-repository and
            --relay-log-info-repository
            server options).
          
            With a log_type option, only the
            specified log type is flushed. These
            log_type options are permitted:
                BINARY closes and reopens the binary
                log files.
              
                ENGINE closes and reopens any
                flushable logs for installed storage engines. Currently,
                this causes InnoDB to flush
                its logs to disk.
              
                ERROR closes and reopens the error
                log file.
              
                GENERAL closes and reopens the
                general query log file.
              
                RELAY closes and reopens the relay
                log files.
              
                SLOW closes and reopens the slow
                query log file.
            PRIVILEGES
          
            Reloads the privileges from the grant tables in the
            mysql database.
          
            The server caches information in memory as a result of
            GRANT,
            CREATE USER,
            CREATE SERVER, and
            INSTALL PLUGIN statements.
            This memory is not released by the corresponding
            REVOKE,
            DROP USER,
            DROP SERVER, and
            UNINSTALL PLUGIN statements,
            so for a server that executes many instances of the
            statements that cause caching, there will be an increase in
            memory use. This cached memory can be freed with
            FLUSH
            PRIVILEGES.
          
            QUERY CACHE
          
            Defragment the query cache to better utilize its memory.
            FLUSH QUERY
            CACHE does not remove any queries from the cache,
            unlike FLUSH
            TABLES or RESET QUERY CACHE.
          
            STATUS
          
            This option adds the current thread's session status
            variable values to the global values and resets the session
            values to zero. Some global variables may be reset to zero
            as well. It also resets the counters for key caches (default
            and named) to zero and sets
            Max_used_connections to
            the current number of open connections. This is something
            you should use only when debugging a query. See
            Section 1.7, “How to Report Bugs or Problems”.
          
            TABLES
          
            FLUSH
            TABLES flushes tables, and, depending on the
            variant used, acquires locks. The permitted syntax is
            discussed later in this section.
          
            USER_RESOURCES
          
            Resets all per-hour user resources to zero. This enables
            clients that have reached their hourly connection, query, or
            update limits to resume activity immediately.
            FLUSH
            USER_RESOURCES does not apply to the limit on
            maximum simultaneous connections. See
            Section 6.3.4, “Setting Account Resource Limits”.
        The mysqladmin utility provides a
        command-line interface to some flush operations, using commands
        such as flush-hosts,
        flush-logs,
        flush-privileges,
        flush-status, and
        flush-tables. See
        Section 4.5.2, “mysqladmin — Client for Administering a MySQL Server”.
          It is not possible to issue
          FLUSH statements within stored
          functions or triggers. However, you may use
          FLUSH in stored procedures, so
          long as these are not called from stored functions or
          triggers. See Section D.1, “Restrictions on Stored Programs”.
        In MySQL 5.6.11 only, gtid_next
        must be set to AUTOMATIC before issuing this
        statement. (Bug #16062608, Bug #16715809, Bug #69045)
        FLUSH TABLES
        has several forms, described following. If any variant of the
        TABLES option is used in a
        FLUSH statement, it must be the
        only option used. FLUSH
        TABLE is a synonym for
        FLUSH TABLES.
            FLUSH TABLES
          
            Closes all open tables, forces all tables in use to be
            closed, and flushes the query cache.
            FLUSH
            TABLES also removes all query results from the
            query cache, like the RESET QUERY CACHE
            statement.
          
            In MySQL 5.6,
            FLUSH
            TABLES is not permitted when there is an active
            LOCK TABLES ...
            READ. To flush and lock tables, use
            FLUSH TABLES
             instead.
          tbl_name ... WITH READ
            LOCK
            FLUSH TABLES 
          tbl_name [,
            tbl_name] ...
            With a list of one or more comma-separated table names, this
            statement is like
            FLUSH
            TABLES with no names except that the server
            flushes only the named tables. No error occurs if a named
            table does not exist.
          
            FLUSH TABLES WITH READ LOCK
          
            Closes all open tables and locks all tables for all
            databases with a global read lock. This is a very convenient
            way to get backups if you have a file system such as Veritas
            or ZFS that can take snapshots in time. Use
            UNLOCK
            TABLES to release the lock.
          
            FLUSH TABLES WITH
            READ LOCK acquires a global read lock and not
            table locks, so it is not subject to the same behavior as
            LOCK TABLES and
            UNLOCK
            TABLES with respect to table locking and implicit
            commits:
                UNLOCK
                TABLES implicitly commits any active
                transaction only if any tables currently have been
                locked with LOCK TABLES.
                The commit does not occur for
                UNLOCK
                TABLES following
                FLUSH TABLES WITH
                READ LOCK because the latter statement does
                not acquire table locks.
              
                Beginning a transaction causes table locks acquired with
                LOCK TABLES to be
                released, as though you had executed
                UNLOCK
                TABLES. Beginning a transaction does not
                release a global read lock acquired with
                FLUSH TABLES WITH
                READ LOCK.
            FLUSH TABLES WITH
            READ LOCK does not prevent the server from
            inserting rows into the log tables (see
            Section 5.2.1, “Selecting General Query and Slow Query Log Output Destinations”).
          
            FLUSH TABLES 
          tbl_name [,
            tbl_name] ... WITH READ
            LOCK
            This statement flushes and acquires read locks for the named
            tables. The statement first acquires exclusive metadata
            locks for the tables, so it waits for transactions that have
            those tables open to complete. Then the statement flushes
            the tables from the table cache, reopens the tables,
            acquires table locks (like
            LOCK TABLES ...
            READ), and downgrades the metadata locks from
            exclusive to shared. After the statement acquires locks and
            downgrades the metadata locks, other sessions can read but
            not modify the tables.
          
            Because this statement acquires table locks, you must have
            the LOCK TABLES privilege for
            each table, in addition to the
            RELOAD privilege that is
            required to use any FLUSH
            statement.
          
            This statement applies only to existing base tables. If a
            name refers to a base table, that table is used. If it
            refers to a TEMPORARY table, it is
            ignored. If a name applies to a view, an
            ER_WRONG_OBJECT error
            occurs. Otherwise, an
            ER_NO_SUCH_TABLE error
            occurs.
          
            Use UNLOCK
            TABLES to release the locks,
            LOCK TABLES to release the
            locks and acquire other locks, or
            START
            TRANSACTION to release the locks and begin a new
            transaction.
          
            This variant of FLUSH enables tables to
            be flushed and locked in a single operation. It provides a
            workaround for the restriction in MySQL 5.6
            that FLUSH
            TABLES is not permitted when there is an active
            LOCK TABLES ...
            READ.
          
            This statement does not perform an implicit
            UNLOCK
            TABLES, so an error results if you use the
            statement while there is any active
            LOCK TABLES or use it a
            second time without first releasing the locks acquired.
          
            If a flushed table was opened with
            HANDLER, the handler is
            implicitly flushed and loses its position.
          
            FLUSH TABLES 
          tbl_name [,
            tbl_name] ... FOR
            EXPORT
            This FLUSH TABLES variant applies to
            InnoDB tables. It is available as of
            MySQL 5.6.6. The statement ensures that changes to the named
            tables have been flushed to disk so that binary table copies
            can be made while the server is running.
          
The statement works like this:
It acquires shared metadata locks for the named tables. The statement blocks as long as other sessions have active transactions that have modified those tables or hold table locks for them. When the locks have been acquired, the statement blocks transactions that attempt to update the tables while permitting read-only operations to continue.
                It checks whether all storage engines for the tables
                support FOR EXPORT. If any do not, an
                ER_ILLEGAL_HA error
                occurs and the statement fails.
              
The statement notifies the storage engine for each table to make the table ready for export. The storage engine must ensure that any pending changes are written to disk.
                The statement puts the session in lock-tables mode so
                that the metadata locks acquired earlier are not
                released when the FOR EXPORT
                statement completes.
            The FLUSH TABLES ... FOR EXPORT statement
            requires that you have the
            SELECT privilege for each
            table. Because this statement acquires table locks, you must
            also have the LOCK TABLES
            privilege for each table, in addition to the
            RELOAD privilege that is
            required to use any FLUSH
            statement.
          
            This statement applies only to existing base tables. If a
            name refers to a base table, that table is used. If it
            refers to a TEMPORARY table, it is
            ignored. If a name applies to a view, an
            ER_WRONG_OBJECT error
            occurs. Otherwise, an
            ER_NO_SUCH_TABLE error
            occurs.
          
            InnoDB supports FOR
            EXPORT for tables that have their own
            .ibd file file (that
            is, tables that were created with the
            innodb_file_per_table
            setting enabled). InnoDB ensures when
            notified by the FOR EXPORT statement that
            any changes have been flushed to disk. This permits a binary
            copy of table contents to be made while the FOR
            EXPORT statement is in effect because the
            .ibd file is transaction consistent and
            can be copied while the server is running. FOR
            EXPORT does not apply to InnoDB
            system tablespace files, or to InnoDB
            tables that have any FULLTEXT indexes.
          
            FLUSH TABLES ...FOR EXPORT does not work
            with partitioned InnoDB tables prior to
            MySQL 5.6.17, but is supported for such tables in MySQL
            5.6.17 and later. (Bug #16943907)
          
            When notified by FOR EXPORT,
            InnoDB writes to disk certain kinds of
            data that is normally held in memory or in separate disk
            buffers outside the tablespace files. For each table,
            InnoDB also produces a file named
            table_name.cfg.cfg file contains metadata needed to
            reimport the tablespace files later, into the same or
            different server.
          
            When the FOR EXPORT statement completes,
            InnoDB will have flushed all
            dirty pages to the
            table data files. Any
            change buffer
            entries are merged prior to flushing. At this point, the
            tables are locked and quiescent: The tables are in a
            transactionally consistent state on disk and you can copy
            the .ibd tablespace files along with
            the corresponding .cfg files to get a
            consistent snapshot of those tables.
          
For the procedure to reimport the copied table data into a MySQL instance, see Section 14.4.6, “Copying File-Per-Table Tablespaces to Another Server”.
            After you are done with the tables, use
            UNLOCK
            TABLES to release the locks,
            LOCK TABLES to release the
            locks and acquire other locks, or
            START
            TRANSACTION to release the locks and begin a new
            transaction.
          
            While any of these statements is in effect within the
            session, attempts to use
            FLUSH TABLES ... FOR
            EXPORT produce an error:
          
FLUSH TABLES ... WITH READ LOCK FLUSH TABLES ... FOR EXPORT LOCK TABLES ... READ LOCK TABLES ... WRITE
            While FLUSH TABLES
            ... FOR EXPORT is in effect within the session,
            attempts to use any of these statements produce an error:
          
FLUSH TABLES WITH READ LOCK FLUSH TABLES ... WITH READ LOCK FLUSH TABLES ... FOR EXPORT
KILL [CONNECTION | QUERY] processlist_id
        Each connection to mysqld runs in a separate
        thread. You can kill a thread with the KILL
         statement.
      processlist_id
        Thread processlist identifiers can be determined from the
        ID column of the
        INFORMATION_SCHEMA.PROCESSLIST
        table, the Id column of
        SHOW PROCESSLIST output, and the
        PROCESSLIST_ID column of the Performance
        Schema threads table. The value for
        the current thread is returned by the
        CONNECTION_ID() function.
      
        KILL permits an optional
        CONNECTION or QUERY
        modifier:
            KILL
            CONNECTION is the same as
            KILL with no modifier: It
            terminates the connection associated with the given
            processlist_id, after terminating
            any statement the connection is executing.
          
            KILL QUERY
            terminates the statement the connection is currently
            executing, but leaves the connection itself intact.
        If you have the PROCESS
        privilege, you can see all threads. If you have the
        SUPER privilege, you can kill all
        threads and statements. Otherwise, you can see and kill only
        your own threads and statements.
      
You can also use the mysqladmin processlist and mysqladmin kill commands to examine and kill threads.
          You cannot use KILL with the
          Embedded MySQL Server library because the embedded server
          merely runs inside the threads of the host application. It
          does not create any connection threads of its own.
        When you use KILL, a
        thread-specific kill flag is set for the thread. In most cases,
        it might take some time for the thread to die because the kill
        flag is checked only at specific intervals:
            During SELECT operations, for
            ORDER BY and GROUP BY
            loops, the flag is checked after reading a block of rows. If
            the kill flag is set, the statement is aborted.
          
            During ALTER TABLE
            operations, the kill flag is checked before each block of
            rows are read from the original table. If the kill flag was
            set, the statement is aborted and the temporary table is
            deleted.
          
            During UPDATE or
            DELETE operations, the kill
            flag is checked after each block read and after each updated
            or deleted row. If the kill flag is set, the statement is
            aborted. If you are not using transactions, the changes are
            not rolled back.
          
            GET_LOCK() aborts and returns
            NULL.
          
            An INSERT DELAYED thread
            quickly flushes (inserts) all rows it has in memory and then
            terminates.
          
            If the thread is in the table lock handler (state:
            Locked), the table lock is quickly
            aborted.
          
If the thread is waiting for free disk space in a write call, the write is aborted with a “disk full” error message.
          Killing a REPAIR TABLE or
          OPTIMIZE TABLE operation on a
          MyISAM table results in a table that is
          corrupted and unusable. Any reads or writes to such a table
          fail until you optimize or repair it again (without
          interruption).
LOAD INDEX INTO CACHEtbl_index_list[,tbl_index_list] ...tbl_index_list:tbl_name[PARTITION (partition_list| ALL)] [[INDEX|KEY] (index_name[,index_name] ...)] [IGNORE LEAVES]partition_list:partition_name[,partition_name][, ...]
        The LOAD INDEX INTO
        CACHE statement preloads a table index into the key
        cache to which it has been assigned by an explicit
        CACHE INDEX statement, or into
        the default key cache otherwise.
      
        LOAD INDEX INTO
        CACHE is used only for MyISAM
        tables. In MySQL 5.6, it is also supported for
        partitioned MyISAM tables; in addition,
        indexes on partitioned tables can be preloaded for one, several,
        or all partitions.
      
        The IGNORE LEAVES modifier causes only blocks
        for the nonleaf nodes of the index to be preloaded.
      
        IGNORE LEAVES is also supported for
        partitioned MyISAM tables.
      
        The following statement preloads nodes (index blocks) of indexes
        for the tables t1 and t2:
      
mysql> LOAD INDEX INTO CACHE t1, t2 IGNORE LEAVES;
+---------+--------------+----------+----------+
| Table   | Op           | Msg_type | Msg_text |
+---------+--------------+----------+----------+
| test.t1 | preload_keys | status   | OK       |
| test.t2 | preload_keys | status   | OK       |
+---------+--------------+----------+----------+
        This statement preloads all index blocks from
        t1. It preloads only blocks for the nonleaf
        nodes from t2.
      
        The syntax of LOAD
        INDEX INTO CACHE enables you to specify that only
        particular indexes from a table should be preloaded. The current
        implementation preloads all the table's indexes into the cache,
        so there is no reason to specify anything other than the table
        name.
      
        In MySQL 5.6.11 only, gtid_next
        must be set to AUTOMATIC before issuing this
        statement. (Bug #16062608, Bug #16715809, Bug #69045)
      
        In MySQL 5.6, it is possible to preload indexes on
        specific partitions of partitioned MyISAM
        tables. For example, of the following 2 statements, the first
        preloads indexes for partition p0 of a
        partitioned table pt, while the second
        preloads the indexes for partitions p1 and
        p3 of the same table:
      
LOAD INDEX INTO CACHE pt PARTITION (p0); LOAD INDEX INTO CACHE pt PARTITION (p1, p3);
        To preload the indexes for all partitions in table
        pt, you can use either one of the following 2
        statements:
      
LOAD INDEX INTO CACHE pt PARTITION (ALL); LOAD INDEX INTO CACHE pt;
        The two statements just shown are equivalent, and issuing either
        one of them has exactly the same effect. In other words, if you
        wish to preload indexes for all partitions of a partitioned
        table, then the PARTITION (ALL) clause is
        optional.
      
When preloading indexes for multiple partitions, the partitions do not have to be contiguous, and you are not required to list their names in any particular order.
        LOAD INDEX INTO
        CACHE ... IGNORE LEAVES fails unless all indexes in a
        table have the same block size. You can determine index block
        sizes for a table by using myisamchk -dv and
        checking the Blocksize column.
RESETreset_option[,reset_option] ...
        The RESET statement is used to
        clear the state of various server operations. You must have the
        RELOAD privilege to execute
        RESET.
      
        RESET acts as a stronger version
        of the FLUSH statement. See
        Section 13.7.6.3, “FLUSH Syntax”.
      
        The RESET statement causes an
        implicit commit. See Section 13.3.3, “Statements That Cause an Implicit Commit”.
      
        In MySQL 5.6.11 only, gtid_next
        must be set to AUTOMATIC before issuing this
        statement. (Bug #16062608, Bug #16715809, Bug #69045)
      
        reset_option can be any of the
        following:
            MASTER
          
Deletes all binary logs listed in the index file, resets the binary log index file to be empty, and creates a new binary log file.
            QUERY CACHE
          
Removes all query results from the query cache.
            SLAVE
          
Makes the slave forget its replication position in the master binary logs. Also resets the relay log by deleting any existing relay log files and beginning a new one.
      The DESCRIBE and
      EXPLAIN statements are synonyms,
      used either to obtain information about table structure or query
      execution plans. For more information, see
      Section 13.7.5.6, “SHOW COLUMNS Syntax”, and Section 13.8.2, “EXPLAIN Syntax”.
{EXPLAIN | DESCRIBE | DESC}
    tbl_name [col_name | wild]
{EXPLAIN | DESCRIBE | DESC}
    [explain_type]
    explainable_stmt
explain_type: {
    EXTENDED
  | PARTITIONS
  | FORMAT = format_name
}
format_name: {
    TRADITIONAL
  | JSON
}
explainable_stmt: {
    SELECT statement
  | DELETE statement
  | INSERT statement
  | REPLACE statement
  | UPDATE statement
}
      The DESCRIBE and
      EXPLAIN statements are synonyms. In
      practice, the DESCRIBE keyword is
      more often used to obtain information about table structure,
      whereas EXPLAIN is used to obtain a
      query execution plan (that is, an explanation of how MySQL would
      execute a query). The following discussion uses the
      DESCRIBE and
      EXPLAIN keywords in accordance with
      those uses, but the MySQL parser treats them as completely
      synonymous.
      DESCRIBE provides information about
      the columns in a table:
    
mysql> DESCRIBE City;
+------------+----------+------+-----+---------+----------------+
| Field      | Type     | Null | Key | Default | Extra          |
+------------+----------+------+-----+---------+----------------+
| Id         | int(11)  | NO   | PRI | NULL    | auto_increment |
| Name       | char(35) | NO   |     |         |                |
| Country    | char(3)  | NO   | UNI |         |                |
| District   | char(20) | YES  | MUL |         |                |
| Population | int(11)  | NO   |     | 0       |                |
+------------+----------+------+-----+---------+----------------+
      DESCRIBE is a shortcut for
      SHOW COLUMNS. These statements also
      display information for views. The description for
      SHOW COLUMNS provides more
      information about the output columns. See
      Section 13.7.5.6, “SHOW COLUMNS Syntax”.
    
      By default, DESCRIBE displays
      information about all columns in the table.
      col_name, if given, is the name of a
      column in the table. In this case, the statement displays
      information only for the named column.
      wild, if given, is a pattern string. It
      can contain the SQL “%” and
      “_” wildcard characters. In this
      case, the statement displays output only for the columns with
      names matching the string. There is no need to enclose the string
      within quotation marks unless it contains spaces or other special
      characters.
    
      The DESCRIBE statement is provided
      for compatibility with Oracle.
    
      The SHOW CREATE TABLE,
      SHOW TABLE STATUS, and
      SHOW INDEX statements also provide
      information about tables. See Section 13.7.5, “SHOW Syntax”.
      The EXPLAIN statement provides
      information about how MySQL executes statements:
          As of MySQL 5.6.3, permitted explainable statements for
          EXPLAIN are
          SELECT,
          DELETE,
          INSERT,
          REPLACE, and
          UPDATE. Before MySQL 5.6.3,
          SELECT is the only explainable
          statement.
        
          When EXPLAIN is used with an
          explainable statement, MySQL displays information from the
          optimizer about the statement execution plan. That is, MySQL
          explains how it would process the statement, including
          information about how tables are joined and in which order.
          For information about using
          EXPLAIN to obtain execution
          plan information, see Section 8.8.2, “EXPLAIN Output Format”.
        
          EXPLAIN EXTENDED can be used to
          obtain additional execution plan information. See
          Section 8.8.3, “EXPLAIN EXTENDED Output Format”.
        
          EXPLAIN
          PARTITIONS is useful for examining queries involving
          partitioned tables. See Section 19.3.5, “Obtaining Information About Partitions”.
        
          As of MySQL 5.6.5, the FORMAT option can be
          used to select the output format.
          TRADITIONAL presents the output in tabular
          format. This is the default if no FORMAT
          option is present. JSON format displays the
          information in JSON format. With FORMAT =
          JSON, the output includes extended and partition
          information.
      
      With the help of EXPLAIN, you can
      see where you should add indexes to tables so that the statement
      executes faster by using indexes to find rows. You can also use
      EXPLAIN to check whether the
      optimizer joins the tables in an optimal order. To give a hint to
      the optimizer to use a join order corresponding to the order in
      which the tables are named in a
      SELECT statement, begin the
      statement with SELECT STRAIGHT_JOIN rather than
      just SELECT. (See
      Section 13.2.9, “SELECT Syntax”.)
    
      If you have a problem with indexes not being used when you believe
      that they should be, run ANALYZE
      TABLE to update table statistics, such as cardinality of
      keys, that can affect the choices the optimizer makes. See
      Section 13.7.2.1, “ANALYZE TABLE Syntax”.
HELP 'search_string'
      The HELP statement returns online
      information from the MySQL Reference manual. Its proper operation
      requires that the help tables in the mysql
      database be initialized with help topic information (see
      Section 5.1.10, “Server-Side Help”).
    
      The HELP statement searches the
      help tables for the given search string and displays the result of
      the search. The search string is not case sensitive.
    
      The search string can contain the wildcard characters
      “%” and
      “_”. These have the same meaning
      as for pattern-matching operations performed with the
      LIKE operator. For example,
      HELP 'rep%' returns a list of topics that begin
      with rep.
    
The HELP statement understands several types of search strings:
          At the most general level, use contents to
          retrieve a list of the top-level help categories:
        
HELP 'contents'
          For a list of topics in a given help category, such as
          Data Types, use the category name:
        
HELP 'data types'
          For help on a specific help topic, such as the
          ASCII() function or the
          CREATE TABLE statement, use the
          associated keyword or keywords:
        
HELP 'ascii' HELP 'create table'
      In other words, the search string matches a category, many topics,
      or a single topic. You cannot necessarily tell in advance whether
      a given search string will return a list of items or the help
      information for a single help topic. However, you can tell what
      kind of response HELP returned by
      examining the number of rows and columns in the result set.
    
The following descriptions indicate the forms that the result set can take. Output for the example statements is shown using the familiar “tabular” or “vertical” format that you see when using the mysql client.
Empty result set
No match could be found for the search string.
Result set containing a single row with three columns
This means that the search string yielded a hit for the help topic. The result has three columns:
              name: The topic name.
            
              description: Descriptive help text for
              the topic.
            
              example: Usage example or examples.
              This column might be blank.
          Example: HELP 'replace'
        
Yields:
name: REPLACE
description: Syntax:
REPLACE(str,from_str,to_str)
Returns the string str with all occurrences of the string from_str
replaced by the string to_str. REPLACE() performs a case-sensitive
match when searching for from_str.
example: mysql> SELECT REPLACE('www.mysql.com', 'w', 'Ww');
        -> 'WwWwWw.mysql.com'
Result set containing multiple rows with two columns
This means that the search string matched many help topics. The result set indicates the help topic names:
              name: The help topic name.
            
              is_it_category: Y if
              the name represents a help category, N
              if it does not. If it does not, the
              name value when specified as the
              argument to the HELP
              statement should yield a single-row result set containing
              a description for the named item.
          Example: HELP 'status'
        
Yields:
+-----------------------+----------------+ | name | is_it_category | +-----------------------+----------------+ | SHOW | N | | SHOW ENGINE | N | | SHOW MASTER STATUS | N | | SHOW PROCEDURE STATUS | N | | SHOW SLAVE STATUS | N | | SHOW STATUS | N | | SHOW TABLE STATUS | N | +-----------------------+----------------+
Result set containing multiple rows with three columns
This means the search string matches a category. The result set contains category entries:
              source_category_name: The help category
              name.
            
              name: The category or topic name
            
              is_it_category: Y if
              the name represents a help category, N
              if it does not. If it does not, the
              name value when specified as the
              argument to the HELP
              statement should yield a single-row result set containing
              a description for the named item.
          Example: HELP 'functions'
        
Yields:
+----------------------+-------------------------+----------------+ | source_category_name | name | is_it_category | +----------------------+-------------------------+----------------+ | Functions | CREATE FUNCTION | N | | Functions | DROP FUNCTION | N | | Functions | Bit Functions | Y | | Functions | Comparison operators | Y | | Functions | Control flow functions | Y | | Functions | Date and Time Functions | Y | | Functions | Encryption Functions | Y | | Functions | Information Functions | Y | | Functions | Logical operators | Y | | Functions | Miscellaneous Functions | Y | | Functions | Numeric Functions | Y | | Functions | String Functions | Y | +----------------------+-------------------------+----------------+
USE db_name
      The USE 
      statement tells MySQL to use the
      db_namedb_name database as the default
      (current) database for subsequent statements. The database remains
      the default until the end of the session or another
      USE statement is issued:
    
USE db1; SELECT COUNT(*) FROM mytable; # selects from db1.mytable USE db2; SELECT COUNT(*) FROM mytable; # selects from db2.mytable
      Making a particular database the default by means of the
      USE statement does not preclude you
      from accessing tables in other databases. The following example
      accesses the author table from the
      db1 database and the editor
      table from the db2 database:
    
USE db1; SELECT author_name,editor_name FROM author,db2.editor WHERE author.editor_id = db2.editor.editor_id;