The following are known problems with MERGE
tables:
MERGE
child tables are locked through the parent table. If the parent is temporary, it is not locked, and thus the child tables are also not locked; this means that parallel use of the underlyingMyISAM
tables corrupts them.If you use
ALTER TABLE
to change aMERGE
table to another storage engine, the mapping to the underlying tables is lost. Instead, the rows from the underlyingMyISAM
tables are copied into the altered table, which then uses the specified storage engine.The
INSERT_METHOD
table option for aMERGE
table indicates which underlyingMyISAM
table to use for inserts into theMERGE
table. However, use of theAUTO_INCREMENT
table option for thatMyISAM
table has no effect for inserts into theMERGE
table until at least one row has been inserted directly into theMyISAM
table.A
MERGE
table cannot maintain uniqueness constraints over the entire table. When you perform anINSERT
, the data goes into the first or lastMyISAM
table (as determined by theINSERT_METHOD
option). MySQL ensures that unique key values remain unique within thatMyISAM
table, but not over all the underlying tables in the collection.Because the
MERGE
engine cannot enforce uniqueness over the set of underlying tables,REPLACE
does not work as expected. The two key facts are:REPLACE
can detect unique key violations only in the underlying table to which it is going to write (which is determined by theINSERT_METHOD
option). This differs from violations in theMERGE
table itself.If
REPLACE
detects a unique key violation, it changes only the corresponding row in the underlying table it is writing to; that is, the first or last table, as determined by theINSERT_METHOD
option.
Similar considerations apply for
INSERT ... ON DUPLICATE KEY UPDATE
.MERGE
tables do not support partitioning. That is, you cannot partition aMERGE
table, nor can any of aMERGE
table's underlyingMyISAM
tables be partitioned.You should not use
ANALYZE TABLE
,REPAIR TABLE
,OPTIMIZE TABLE
,ALTER TABLE
,DROP TABLE
,DELETE
without aWHERE
clause, orTRUNCATE TABLE
on any of the tables that are mapped into an openMERGE
table. If you do so, theMERGE
table may still refer to the original table and yield unexpected results. To work around this problem, ensure that noMERGE
tables remain open by issuing aFLUSH TABLES
statement prior to performing any of the named operations.The unexpected results include the possibility that the operation on the
MERGE
table reports table corruption. If this occurs after one of the named operations on the underlyingMyISAM
tables, the corruption message is spurious. To deal with this, issue aFLUSH TABLES
statement after modifying theMyISAM
tables.DROP TABLE
on a table that is in use by aMERGE
table does not work on Windows because theMERGE
storage engine's table mapping is hidden from the upper layer of MySQL. Windows does not permit open files to be deleted, so you first must flush allMERGE
tables (withFLUSH TABLES
) or drop theMERGE
table before dropping the table.The definition of the
MyISAM
tables and theMERGE
table are checked when the tables are accessed (for example, as part of aSELECT
orINSERT
statement). The checks ensure that the definitions of the tables and the parentMERGE
table definition match by comparing column order, types, sizes and associated indexes. If there is a difference between the tables, an error is returned and the statement fails. Because these checks take place when the tables are opened, any changes to the definition of a single table, including column changes, column ordering, and engine alterations cause the statement to fail.The order of indexes in the
MERGE
table and its underlying tables should be the same. If you useALTER TABLE
to add aUNIQUE
index to a table used in aMERGE
table, and then useALTER TABLE
to add a nonunique index on theMERGE
table, the index ordering is different for the tables if there was already a nonunique index in the underlying table. (This happens becauseALTER TABLE
putsUNIQUE
indexes before nonunique indexes to facilitate rapid detection of duplicate keys.) Consequently, queries on tables with such indexes may return unexpected results.If you encounter an error message similar to ERROR 1017 (HY000): Can't find file: '
tbl_name
.MRG' (errno: 2), it generally indicates that some of the underlying tables do not use theMyISAM
storage engine. Confirm that all of these tables areMyISAM
.The maximum number of rows in a
MERGE
table is 264 (~1.844E+19; the same as for aMyISAM
table). It is not possible to merge multipleMyISAM
tables into a singleMERGE
table that would have more than this number of rows.Use of underlying
MyISAM
tables of differing row formats with a parentMERGE
table is currently known to fail. See Bug #32364.You cannot change the union list of a nontemporary
MERGE
table whenLOCK TABLES
is in effect. The following does not work:CREATE TABLE m1 ... ENGINE=MRG_MYISAM ...; LOCK TABLES t1 WRITE, t2 WRITE, m1 WRITE; ALTER TABLE m1 ... UNION=(t1,t2) ...;
However, you can do this with a temporary
MERGE
table.You cannot create a
MERGE
table withCREATE ... SELECT
, neither as a temporaryMERGE
table, nor as a nontemporaryMERGE
table. For example:CREATE TABLE m1 ... ENGINE=MRG_MYISAM ... SELECT ...;
Attempts to do this result in an error:
tbl_name
is notBASE TABLE
.In some cases, differing
PACK_KEYS
table option values among theMERGE
and underlying tables cause unexpected results if the underlying tables containCHAR
orBINARY
columns. As a workaround, useALTER TABLE
to ensure that all involved tables have the samePACK_KEYS
value. (Bug #50646)