Do not convert MySQL system tables in the
mysql database from MyISAM
to InnoDB tables. This is an unsupported
operation. If you do this, MySQL does not restart until you
restore the old system tables from a backup or regenerate them
by reinitializing the data directory (see
Section 2.10.1, “Initializing the Data Directory”).
It is not a good idea to configure InnoDB to
use data files or log files on NFS volumes. Otherwise, the files
might be locked by other processes and become unavailable for
use by MySQL.
Maximums and Minimums
A table can contain a maximum of 1000 columns.
A table can contain a maximum of 64 secondary indexes.
By default, the index key prefix length limit is 767 bytes. See Section 13.1.13, “CREATE INDEX Syntax”. For example, you might hit this limit with a column prefix index of more than 255 characters on a
TEXTorVARCHARcolumn, assuming autf8mb3character set and the maximum of 3 bytes for each character. When theinnodb_large_prefixconfiguration option is enabled, the index key prefix length limit is raised to 3072 bytes forInnoDBtables that useDYNAMICorCOMPRESSEDrow format.If you specify an index key prefix length that exceeds the limit, the length is silently reduced to the maximum length.
When
innodb_large_prefixis enabled, attempting to create an index key prefix with a length greater than 3072 bytes for aDYNAMICorCOMPRESSEDtable causes anER_INDEX_COLUMN_TOO_LONGerror.The limits that apply to index key prefixes also apply to full-column index keys.
A maximum of 16 columns is permitted for multicolumn indexes. Exceeding the limit returns an error.
ERROR 1070 (42000): Too many key parts specified; max 16 parts allowed
The maximum row length, except for variable-length columns (
VARBINARY,VARCHAR,BLOBandTEXT), is slightly less than half of a page. That is, the maximum row length is about 8000 bytes.LONGBLOBandLONGTEXTcolumns must be less than 4GB, and the total row length, includingBLOBandTEXTcolumns, must be less than 4GB.If a row is less than half a page long, all of it is stored locally within the page. If it exceeds half a page, variable-length columns are chosen for external off-page storage until the row fits within half a page, as described in Section 14.15.2, “File Space Management”.
The row size for
BLOBcolumns that are chosen for external off-page storage should not exceed 10% of the combined redo log file size. If the row size exceeds 10% of the combined redo log file size,InnoDBcould overwrite the most recent checkpoint which may result in lost data during crash recovery. (Bug#69477).Although
InnoDBsupports row sizes larger than 65,535 bytes internally, MySQL itself imposes a row-size limit of 65,535 for the combined size of all columns:mysql>
CREATE TABLE t (a VARCHAR(8000), b VARCHAR(10000),->c VARCHAR(10000), d VARCHAR(10000), e VARCHAR(10000),->f VARCHAR(10000), g VARCHAR(10000)) ENGINE=InnoDB;ERROR 1118 (42000): Row size too large. The maximum row size for the used table type, not counting BLOBs, is 65535. You have to change some columns to TEXT or BLOBsSee Section C.10.4, “Limits on Table Column Count and Row Size”.
On some older operating systems, files must be less than 2GB. This is not a limitation of
InnoDBitself, but if you require a large tablespace, configure it using several smaller data files rather than one large data file.The combined size of the
InnoDBlog files must be less than 4GB.The minimum tablespace size is slightly larger than 10MB. The maximum tablespace size is four billion pages (64TB). This is also the maximum size for a table.
The default page size in
InnoDBis 16KB.Changing the page size is not a supported operation and there is no guarantee that
InnoDBfunctions normally with a page size other than 16KB. Problems compiling or runningInnoDBmay occur. In particular,ROW_FORMAT=COMPRESSEDin the Barracuda file format assumes that the page size is at most 16KB and uses 14-bit pointers.A version of
InnoDBbuilt for one page size cannot use data files or log files from a version built for a different page size. This limitation could affect restore or downgrade operations using data from MySQL 5.6, which does support page sizes other than 16KB.
Index Types
InnoDBtables do not supportFULLTEXTindexes.InnoDBtables support spatial data types, but not indexes on them.
Restrictions on InnoDB Tables
ANALYZE TABLEdetermines index cardinality (as displayed in theCardinalitycolumn ofSHOW INDEXoutput) by doing random dives to each of the index trees and updating index cardinality estimates accordingly. Because these are only estimates, repeated runs ofANALYZE TABLEcould produce different numbers. This makesANALYZE TABLEfast onInnoDBtables but not 100% accurate because it does not take all rows into account.You can change the number of random dives by modifying the
innodb_stats_sample_pagessystem variable.MySQL uses index cardinality estimates only in join optimization. If some join is not optimized in the right way, you can try using
ANALYZE TABLE. In the few cases thatANALYZE TABLEdoes not produce values good enough for your particular tables, you can useFORCE INDEXwith your queries to force the use of a particular index, or set themax_seeks_for_keysystem variable to ensure that MySQL prefers index lookups over table scans. See Section 5.1.5, “Server System Variables”, and Section B.5.5, “Optimizer-Related Issues”.If statements or transactions are running on a table and
ANALYZE TABLEis run on the same table followed by a secondANALYZE TABLEoperation, the secondANALYZE TABLEoperation is blocked until the statements or transactions are completed. This behavior occurs becauseANALYZE TABLEmarks the currently loaded table definition as obsolete whenANALYZE TABLEis finished running. New statements or transactions (including a secondANALYZE TABLEstatement) must load the new table definition into the table cache, which cannot occur until currently running statements or transactions are completed and the old table definition is purged. Loading multiple concurrent table definitions is not supported.SHOW TABLE STATUSdoes not give accurate statistics onInnoDBtables, except for the physical size reserved by the table. The row count is only a rough estimate used in SQL optimization.InnoDBdoes not keep an internal count of rows in a table because concurrent transactions might “see” different numbers of rows at the same time. Consequently,SELECT COUNT(*) FROM tstatements only count rows visible to the current transaction.To process a
SELECT COUNT(*) FROM tstatement,InnoDBscans an index of the table, which takes some time if the index is not entirely in the buffer pool. For a faster count, you can create a counter table and let your application update it according to the inserts and deletes it does. However, this method may not scale well in situations where thousands of concurrent transactions are initiating updates to the same counter table. If an approximate row count is sufficient,SHOW TABLE STATUScan be used.InnoDBhandlesSELECT COUNT(*)andSELECT COUNT(1)operations in the same way. There is no performance difference.On Windows,
InnoDBalways stores database and table names internally in lowercase. To move databases in a binary format from Unix to Windows or from Windows to Unix, create all databases and tables using lowercase names.An
AUTO_INCREMENTcolumnai_colmust be defined as part of an index such that it is possible to perform the equivalent of an indexedSELECT MAX(lookup on the table to obtain the maximum column value. Typically, this is achieved by making the column the first column of some table index.ai_col)InnoDBsets an exclusive lock on the end of the index associated with theAUTO_INCREMENTcolumn while initializing a previously specifiedAUTO_INCREMENTcolumn on a table.With
innodb_autoinc_lock_mode=0,InnoDBuses a specialAUTO-INCtable lock mode where the lock is obtained and held to the end of the current SQL statement while accessing the auto-increment counter. Other clients cannot insert into the table while theAUTO-INCtable lock is held. The same behavior occurs for “bulk inserts” withinnodb_autoinc_lock_mode=1. Table-levelAUTO-INClocks are not used withinnodb_autoinc_lock_mode=2. For more information, See Section 14.11.6, “AUTO_INCREMENT Handling in InnoDB”.When you restart the MySQL server,
InnoDBmay reuse an old value that was generated for anAUTO_INCREMENTcolumn but never stored (that is, a value that was generated during an old transaction that was rolled back).When an
AUTO_INCREMENTinteger column runs out of values, a subsequentINSERToperation returns a duplicate-key error. This is general MySQL behavior, similar to howMyISAMworks.DELETE FROMdoes not regenerate the table but instead deletes all rows, one by one.tbl_nameUnder some conditions,
TRUNCATEfor antbl_nameInnoDBtable is mapped toDELETE FROM. See Section 13.1.33, “TRUNCATE TABLE Syntax”.tbl_nameCascaded foreign key actions do not activate triggers.
You cannot create a table with a column name that matches the name of an internal
InnoDBcolumn (includingDB_ROW_ID,DB_TRX_ID,DB_ROLL_PTR, andDB_MIX_ID). This restriction applies to use of the names in any letter case.mysql>
CREATE TABLE t1 (c1 INT, db_row_id INT) ENGINE=INNODB;ERROR 1166 (42000): Incorrect column name 'db_row_id'
Locking and Transactions
LOCK TABLESacquires two locks on each table ifinnodb_table_locks=1(the default). In addition to a table lock on the MySQL layer, it also acquires anInnoDBtable lock. Versions of MySQL before 4.1.2 did not acquireInnoDBtable locks; the old behavior can be selected by settinginnodb_table_locks=0. If noInnoDBtable lock is acquired,LOCK TABLEScompletes even if some records of the tables are being locked by other transactions.As of MySQL 5.5.3,
innodb_table_locks=0has no effect for tables locked explicitly withLOCK TABLES ... WRITE. It still has an effect for tables locked for read or write byLOCK TABLES ... WRITEimplicitly (for example, through triggers) or byLOCK TABLES ... READ.All
InnoDBlocks held by a transaction are released when the transaction is committed or aborted. Thus, it does not make much sense to invokeLOCK TABLESonInnoDBtables inautocommit=1mode because the acquiredInnoDBtable locks would be released immediately.You cannot lock additional tables in the middle of a transaction because
LOCK TABLESperforms an implicitCOMMITandUNLOCK TABLES.The limit of 1023 concurrent data-modifying transactions has been raised in MySQL 5.5 and above. The limit is now 128 * 1023 concurrent transactions that generate undo records. You can remove any workarounds that require changing the proper structure of your transactions, such as committing more frequently.