Chapter 15 Alternative Storage Engines

Table of Contents

15.1 Setting the Storage Engine
15.2 The MyISAM Storage Engine
15.2.1 MyISAM Startup Options
15.2.2 Space Needed for Keys
15.2.3 MyISAM Table Storage Formats
15.2.4 MyISAM Table Problems
15.3 The MEMORY Storage Engine
15.4 The CSV Storage Engine
15.4.1 Repairing and Checking CSV Tables
15.4.2 CSV Limitations
15.5 The ARCHIVE Storage Engine
15.6 The BLACKHOLE Storage Engine
15.7 The MERGE Storage Engine
15.7.1 MERGE Table Advantages and Disadvantages
15.7.2 MERGE Table Problems
15.8 The FEDERATED Storage Engine
15.8.1 FEDERATED Storage Engine Overview
15.8.2 How to Create FEDERATED Tables
15.8.3 FEDERATED Storage Engine Notes and Tips
15.8.4 FEDERATED Storage Engine Resources
15.9 The EXAMPLE Storage Engine
15.10 Other Storage Engines
15.11 Overview of MySQL Storage Engine Architecture
15.11.1 Pluggable Storage Engine Architecture
15.11.2 The Common Database Server Layer

Storage engines are MySQL components that handle the SQL operations for different table types. InnoDB is the default and most general-purpose storage engine, and Oracle recommends using it for tables except for specialized use cases. (The CREATE TABLE statement in MySQL 5.6 creates InnoDB tables by default.)

MySQL Server uses a pluggable storage engine architecture that enables storage engines to be loaded into and unloaded from a running MySQL server.

To determine which storage engines your server supports, use 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.

mysql> SHOW ENGINES\G
*************************** 1. row ***************************
      Engine: PERFORMANCE_SCHEMA
     Support: YES
     Comment: Performance Schema
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 2. row ***************************
      Engine: InnoDB
     Support: DEFAULT
     Comment: Supports transactions, row-level locking, and foreign keys
Transactions: YES
          XA: YES
  Savepoints: YES
*************************** 3. row ***************************
      Engine: MRG_MYISAM
     Support: YES
     Comment: Collection of identical MyISAM tables
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 4. row ***************************
      Engine: BLACKHOLE
     Support: YES
     Comment: /dev/null storage engine (anything you write to it disappears)
Transactions: NO
          XA: NO
  Savepoints: NO
*************************** 5. row ***************************
      Engine: MyISAM
     Support: YES
     Comment: MyISAM storage engine
Transactions: NO
          XA: NO
  Savepoints: NO
...
  

This chapter covers use cases for special-purpose MySQL storage engines. It does not cover the default InnoDB storage engine or the NDB storage engine which are covered in Chapter 14, The InnoDB Storage Engine and Chapter 18, MySQL Cluster NDB 7.3. For advanced users, this chapter also contains a description of the pluggable storage engine architecture (see Section 15.11, “Overview of MySQL Storage Engine Architecture”).

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

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

MySQL 5.6 Supported Storage Engines

You are not restricted to using the same storage engine for an entire server or schema. You can specify the storage engine for any table. For example, an application might use mostly InnoDB tables, with one CSV table for exporting data to a spreadsheet and a few MEMORY tables for temporary workspaces.

Choosing a Storage Engine

The various storage engines provided with MySQL are designed with different use cases in mind. The following table provides an overview of some storage engines provided with MySQL:

Table 15.1 Storage Engines Feature Summary

FeatureMyISAMMemoryInnoDBArchiveNDB
Storage limits256TBRAM64TBNone384EB
TransactionsNoNoYesNoYes
Locking granularityTableTableRowTableRow
MVCCNoNoYesNoNo
Geospatial data type supportYesNoYesYesYes
Geospatial indexing supportYesNoNoNoNo
B-tree indexesYesYesYesNoNo
T-tree indexesNoNoNoNoYes
Hash indexesNoYesNo[a]NoYes
Full-text search indexesYesNoYes[b]NoNo
Clustered indexesNoNoYesNoNo
Data cachesNoN/AYesNoYes
Index cachesYesN/AYesNoYes
Compressed dataYes[c]NoYes[d]YesNo
Encrypted data[e]YesYesYesYesYes
Cluster database supportNoNoNoNoYes
Replication support[f]YesYesYesYesYes
Foreign key supportNoNoYesNoNo
Backup / point-in-time recovery[g]YesYesYesYesYes
Query cache supportYesYesYesYesYes
Update statistics for data dictionaryYesYesYesYesYes

[a] InnoDB utilizes hash indexes internally for its Adaptive Hash Index feature.

[b] InnoDB support for FULLTEXT indexes is available in MySQL 5.6.4 and higher.

[c] Compressed MyISAM tables are supported only when using the compressed row format. Tables using the compressed row format with MyISAM are read only.

[d] Compressed InnoDB tables require the InnoDB Barracuda file format.

[e] Implemented in the server (via encryption functions), rather than in the storage engine.

[f] Implemented in the server, rather than in the storage engine.

[g] Implemented in the server, rather than in the storage engine.