MySQL 5.0 Reference Manual  /  Storage Engines

Chapter 14 Storage Engines

Table of Contents     [+/-]

14.1 The MyISAM Storage Engine     [+/-]
14.2 The InnoDB Storage Engine     [+/-]
14.3 The MERGE Storage Engine     [+/-]
14.4 The MEMORY (HEAP) Storage Engine
14.5 The BDB (BerkeleyDB) Storage Engine     [+/-]
14.6 The EXAMPLE Storage Engine
14.7 The FEDERATED Storage Engine     [+/-]
14.8 The ARCHIVE Storage Engine
14.9 The CSV Storage Engine
14.10 The BLACKHOLE Storage Engine

MySQL supports several storage engines that act as handlers for different table types. MySQL storage engines include both those that handle transaction-safe tables and those that handle nontransaction-safe tables:

  • MyISAM manages nontransactional tables. It provides high-speed storage and retrieval, as well as fulltext searching capabilities. MyISAM is supported in all MySQL configurations, and is the default storage engine unless you have configured MySQL to use a different one by default.

  • The MEMORY storage engine provides in-memory tables. The MERGE storage engine enables a collection of identical MyISAM tables to be handled as a single table. Like MyISAM, the MEMORY and MERGE storage engines handle nontransactional tables, and both are also included in MySQL by default.


    The MEMORY storage engine formerly was known as the HEAP engine.

  • The InnoDB and BDB storage engines provide transaction-safe tables. To maintain data integrity, InnoDB also supports FOREIGN KEY referential-integrity constraints.

  • The EXAMPLE storage engine is a stub engine that does nothing. You can create tables with this engine, but no data can be stored in them or retrieved from them. The purpose of this engine is to serve as an example in the MySQL source code that illustrates how to begin writing new storage engines. As such, it is primarily of interest to developers.

  • NDBCLUSTER (also known as NDB) is the storage engine used by MySQL Cluster to implement tables that are partitioned over many computers. It is available in MySQL 5.0 binary distributions. This storage engine is currently supported on a number of Unix platforms. Experimental support for Windows is available beginning in MySQL Cluster NDB 7.0; however, we do not intend to backport this functionality to MySQL 5.0.

    MySQL Cluster is covered in a separate chapter of this Manual. See Chapter 17, MySQL Cluster, for more information.


    MySQL Cluster users wishing to upgrade from MySQL 5.0 should instead migrate to MySQL Cluster NDB 6.3, 7.0, or 7.1; these are based on MySQL 5.1 but contain the latest improvements and fixes for NDBCLUSTER. The NDBCLUSTER storage engine is not supported in standard MySQL 5.1 releases.

  • The ARCHIVE storage engine is used for storing large amounts of data without indexes with a very small footprint.

  • The CSV storage engine stores data in text files using comma-separated values format.

  • The BLACKHOLE storage engine accepts but does not store data and retrievals always return an empty set.

  • The FEDERATED storage engine was added in MySQL 5.0.3. This engine stores data in a remote database. It works with MySQL only, using the MySQL C Client API.

To determine which storage engines your server supports by using the SHOW ENGINES statement. The value in the Support column indicates whether an engine can be used. A value of YES, NO, or DEFAULT indicates that an engine is available, not available, or available and currently set as the default storage engine.

*************************** 1. row ***************************
 Engine: MyISAM
Support: DEFAULT
Comment: Default engine as of MySQL 3.23 with great performance
*************************** 2. row ***************************
 Engine: MEMORY
Support: YES
Comment: Hash based, stored in memory, useful for temporary tables
*************************** 3. row ***************************
 Engine: InnoDB
Support: YES
Comment: Supports transactions, row-level locking, and foreign keys
*************************** 4. row ***************************
 Engine: BerkeleyDB
Support: NO
Comment: Supports transactions and page-level locking
*************************** 5. row ***************************
Support: YES
Comment: /dev/null storage engine (anything you write to it disappears)

This chapter describes each of the MySQL storage engines except for NDBCLUSTER, which is covered in Chapter 17, MySQL Cluster.

For information about storage engine support offered in commercial MySQL Server binaries, see MySQL Enterprise Server 5.1, on the MySQL Web site. The storage engines available might depend on which edition of Enterprise Server you are using.

For answers to some commonly asked questions about MySQL storage engines, see Section A.2, “MySQL 5.0 FAQ: Storage Engines”.

When you create a new table, you can specify which storage engine to use by adding an ENGINE or TYPE table option to the CREATE TABLE statement:


The older term TYPE is supported as a synonym for ENGINE for backward compatibility, but ENGINE is the preferred term and TYPE is deprecated.

If you omit the ENGINE or TYPE option, the default storage engine is used. Normally, this is MyISAM, but you can change it by using the --default-storage-engine or --default-table-type server startup option, or by setting the default-storage-engine or default-table-type option in the my.cnf configuration file.

You can set the default storage engine to be used during the current session by setting the storage_engine or table_type variable:

SET storage_engine=MYISAM;
SET table_type=BDB;

When MySQL is installed on Windows using the MySQL Configuration Wizard, the InnoDB or MyISAM storage engine can be selected as the default. See Section, “The Database Usage Dialog”.

To convert a table from one storage engine to another, use an ALTER TABLE statement that indicates the new engine:


See Section 13.1.10, “CREATE TABLE Syntax”, and Section 13.1.4, “ALTER TABLE Syntax”.

If you try to use a storage engine that is not compiled in or that is compiled in but deactivated, MySQL instead creates a table using the default storage engine. This behavior is convenient when you want to copy tables between MySQL servers that support different storage engines. (For example, in a replication setup, perhaps your master server supports transactional storage engines for increased safety, but the slave servers use only nontransactional storage engines for greater speed.)

This automatic substitution of the default storage engine for unavailable engines can be confusing for new MySQL users. A warning is generated whenever a storage engine is automatically changed.

For new tables, MySQL always creates an .frm file to hold the table and column definitions. The table's index and data may be stored in one or more other files, depending on the storage engine. The server creates the .frm file above the storage engine level. Individual storage engines create any additional files required for the tables that they manage.

A database may contain tables of different types. That is, tables need not all be created with the same storage engine.

Transaction-safe tables (TSTs) have several advantages over nontransaction-safe tables (NTSTs):

  • They are safer. Even if MySQL crashes or you get hardware problems, you can get your data back, either by automatic recovery or from a backup plus the transaction log.

  • You can combine many statements and accept them all at the same time with the COMMIT statement (if autocommit is disabled).

  • You can execute ROLLBACK to ignore your changes (if autocommit is disabled).

  • If an update fails, all of your changes are reverted. (With nontransaction-safe tables, all changes that have taken place are permanent.)

  • Transaction-safe storage engines can provide better concurrency for tables that get many updates concurrently with reads.

You can combine transaction-safe and nontransaction-safe tables in the same statements to get the best of both worlds. However, although MySQL supports several transaction-safe storage engines, for best results, you should not mix different storage engines within a transaction with autocommit disabled. For example, if you do this, changes to nontransaction-safe tables still are committed immediately and cannot be rolled back. For information about this and other problems that can occur in transactions that use mixed storage engines, see Section 13.3.1, “START TRANSACTION, COMMIT, and ROLLBACK Syntax”.

Nontransaction-safe tables have several advantages of their own, all of which occur because there is no transaction overhead:

  • Much faster

  • Lower disk space requirements

  • Less memory required to perform updates

Download this Manual
User Comments
  Posted by Adrian Singer on January 26, 2008
More information about how to pick the best MySQL Storage engine for your real life scenario:
Sign Up Login You must be logged in to post a comment.