The following are known problems with MERGE
tables:
MERGEchild tables are locked through the parent table. If the parent is a temporary table, it is not locked, and thus the child tables are also not locked; this means that parallel use of the underlyingMyISAMtables corrupts them.If you use
ALTER TABLEto change aMERGEtable to another storage engine, the mapping to the underlying tables is lost. Instead, the rows from the underlyingMyISAMtables are copied into the altered table, which then uses the specified storage engine.The
INSERT_METHODtable option for aMERGEtable indicates which underlyingMyISAMtable to use for inserts into theMERGEtable. However, use of theAUTO_INCREMENTtable option for thatMyISAMtable has no effect for inserts into theMERGEtable until at least one row has been inserted directly into theMyISAMtable.A
MERGEtable cannot maintain uniqueness constraints over the entire table. When you perform anINSERT, the data goes into the first or lastMyISAMtable (as determined by theINSERT_METHODoption). MySQL ensures that unique key values remain unique within thatMyISAMtable, but not over all the underlying tables in the collection.Because the
MERGEengine cannot enforce uniqueness over the set of underlying tables,REPLACEdoes not work as expected. The two key facts are:REPLACEcan detect unique key violations only in the underlying table to which it is going to write (which is determined by theINSERT_METHODoption). This differs from violations in theMERGEtable itself.If
REPLACEdetects 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_METHODoption.
Similar considerations apply for
INSERT ... ON DUPLICATE KEY UPDATE.MERGEtables do not support partitioning. That is, you cannot partition aMERGEtable, nor can any of aMERGEtable's underlyingMyISAMtables be partitioned.You should not use
ANALYZE TABLE,REPAIR TABLE,OPTIMIZE TABLE,ALTER TABLE,DROP TABLE,DELETEwithout aWHEREclause, orTRUNCATE TABLEon any of the tables that are mapped into an openMERGEtable. If you do so, theMERGEtable may still refer to the original table and yield unexpected results. To work around this problem, ensure that noMERGEtables remain open by issuing aFLUSH TABLESstatement prior to performing any of the named operations.The unexpected results include the possibility that the operation on the
MERGEtable reports table corruption. If this occurs after one of the named operations on the underlyingMyISAMtables, the corruption message is spurious. To deal with this, issue aFLUSH TABLESstatement after modifying theMyISAMtables.DROP TABLEon a table that is in use by aMERGEtable does not work on Windows because theMERGEstorage 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 allMERGEtables (withFLUSH TABLES) or drop theMERGEtable before dropping the table.The definition of the
MyISAMtables and theMERGEtable are checked when the tables are accessed (for example, as part of aSELECTorINSERTstatement). The checks ensure that the definitions of the tables and the parentMERGEtable 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 causes the statement to fail.The order of indexes in the
MERGEtable and its underlying tables should be the same. If you useALTER TABLEto add aUNIQUEindex to a table used in aMERGEtable, and then useALTER TABLEto add a nonunique index on theMERGEtable, the index ordering is different for the tables if there was already a nonunique index in the underlying table. (This happens becauseALTER TABLEputsUNIQUEindexes 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 theMyISAMstorage engine. Confirm that all of these tables areMyISAM.The maximum number of rows in a
MERGEtable is 264 (~1.844E+19; the same as for aMyISAMtable). It is not possible to merge multipleMyISAMtables into a singleMERGEtable that would have more than this number of rows.Use of underlying
MyISAMtables of differing row formats with a parentMERGEtable is currently known to fail. See Bug #32364.You cannot change the union list of a nontemporary
MERGEtable whenLOCK TABLESis 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
MERGEtable.You cannot create a
MERGEtable withCREATE ... SELECT, neither as a temporaryMERGEtable, nor as a nontemporaryMERGEtable. For example:CREATE TABLE m1 ... ENGINE=MRG_MYISAM ... SELECT ...;Attempts to do this result in an error:
tbl_nameis notBASE TABLE.In some cases, differing
PACK_KEYStable option values among theMERGEand underlying tables cause unexpected results if the underlying tables containCHARorBINARYcolumns. As a workaround, useALTER TABLEto ensure that all involved tables have the samePACK_KEYSvalue. (Bug #50646)