18.7 The MERGE Storage Engine (original) (raw)

The MERGE storage engine, also known as theMRG_MyISAM engine, is a collection of identicalMyISAM tables that can be used as one.“Identical” means that all tables have identical column data types and index information. You cannot mergeMyISAM tables in which the columns are listed in a different order, do not have exactly the same data types in corresponding columns, or have the indexes in different order. However, any or all of the MyISAM tables can be compressed with myisampack. SeeSection 6.6.6, “myisampack — Generate Compressed, Read-Only MyISAM Tables”. Differences between tables such as these do not matter:

An alternative to a MERGE table is a partitioned table, which stores partitions of a single table in separate files and enables some operations to be performed more efficiently. For more information, see Chapter 26, Partitioning.

When you create a MERGE table, MySQL creates a.MRG file on disk that contains the names of the underlying MyISAM tables that should be used as one. The table format of the MERGE table is stored in the MySQL data dictionary. The underlying tables do not have to be in the same database as the MERGE table.

You can use SELECT,DELETE,UPDATE, andINSERT on MERGE tables. You must have SELECT,DELETE, andUPDATE privileges on theMyISAM tables that you map to aMERGE table.

Note

The use of MERGE tables entails the following security issue: If a user has access to MyISAM table t, that user can create aMERGE table m that accesses t. However, if the user's privileges on t are subsequently revoked, the user can continue to access_t_ by doing so through_m_.

Use of DROP TABLE with aMERGE table drops only theMERGE specification. The underlying tables are not affected.

To create a MERGE table, you must specify aUNION=(_`list-of-tables`_) option that indicates which MyISAM tables to use. You can optionally specify an INSERT_METHOD option to control how inserts into the MERGE table take place. Use a value of FIRST orLAST to cause inserts to be made in the first or last underlying table, respectively. If you specify noINSERT_METHOD option or if you specify it with a value of NO, inserts into theMERGE table are not permitted and attempts to do so result in an error.

The following example shows how to create a MERGE table:

mysql> CREATE TABLE t1 (
    ->    a INT NOT NULL AUTO_INCREMENT PRIMARY KEY,
    ->    message CHAR(20)) ENGINE=MyISAM;
mysql> CREATE TABLE t2 (
    ->    a INT NOT NULL AUTO_INCREMENT PRIMARY KEY,
    ->    message CHAR(20)) ENGINE=MyISAM;
mysql> INSERT INTO t1 (message) VALUES ('Testing'),('table'),('t1');
mysql> INSERT INTO t2 (message) VALUES ('Testing'),('table'),('t2');
mysql> CREATE TABLE total (
    ->    a INT NOT NULL AUTO_INCREMENT,
    ->    message CHAR(20), INDEX(a))
    ->    ENGINE=MERGE UNION=(t1,t2) INSERT_METHOD=LAST;

Column a is indexed as a PRIMARY KEY in the underlying MyISAM tables, but not in the MERGE table. There it is indexed but not as a PRIMARY KEY because aMERGE table cannot enforce uniqueness over the set of underlying tables. (Similarly, a column with aUNIQUE index in the underlying tables should be indexed in the MERGE table but not as aUNIQUE index.)

After creating the MERGE table, you can use it to issue queries that operate on the group of tables as a whole:

mysql> SELECT * FROM total;
+---+---------+
| a | message |
+---+---------+
| 1 | Testing |
| 2 | table   |
| 3 | t1      |
| 1 | Testing |
| 2 | table   |
| 3 | t2      |
+---+---------+

To remap a MERGE table to a different collection of MyISAM tables, you can use one of the following methods:

The underlying table definitions and indexes must conform closely to the definition of the MERGE table. Conformance is checked when a table that is part of a MERGE table is opened, not when the MERGE table is created. If any table fails the conformance checks, the operation that triggered the opening of the table fails. This means that changes to the definitions of tables within aMERGE may cause a failure when theMERGE table is accessed. The conformance checks applied to each table are:

If a MERGE table cannot be opened or used because of a problem with an underlying table, CHECK TABLE displays information about which table caused the problem.

Additional Resources