MySQL 8.0 Reference Manual Including MySQL NDB Cluster 8.0
The following are known problems with MERGE
tables:
MERGE child 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 underlying
MyISAM tables corrupts them.
If you use ALTER TABLE to
change a MERGE table to another storage
engine, the mapping to the underlying tables is lost. Instead,
the rows from the underlying MyISAM tables
are copied into the altered table, which then uses the
specified storage engine.
The INSERT_METHOD table option for a
MERGE table indicates which underlying
MyISAM table to use for inserts into the
MERGE table. However, use of the
AUTO_INCREMENT table option for that
MyISAM table has no effect for inserts into
the MERGE table until at least one row has
been inserted directly into the MyISAM
table.
A MERGE table cannot maintain uniqueness
constraints over the entire table. When you perform an
INSERT, the data goes into the
first or last MyISAM table (as determined
by the INSERT_METHOD option). MySQL ensures
that unique key values remain unique within that
MyISAM 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 the
INSERT_METHOD option). This differs
from violations in the MERGE 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 the
INSERT_METHOD option.
Similar considerations apply for
INSERT
... ON DUPLICATE KEY UPDATE.
MERGE tables do not support partitioning.
That is, you cannot partition a MERGE
table, nor can any of a MERGE table's
underlying MyISAM tables be partitioned.
You should not use ANALYZE
TABLE, REPAIR TABLE,
OPTIMIZE TABLE,
ALTER TABLE,
DROP TABLE,
DELETE without a
WHERE clause, or
TRUNCATE TABLE on any of the
tables that are mapped into an open MERGE
table. If you do so, the MERGE table may
still refer to the original table and yield unexpected
results. To work around this problem, ensure that no
MERGE tables remain open by issuing a
FLUSH 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 underlying MyISAM tables, the
corruption message is spurious. To deal with this, issue a
FLUSH TABLES statement after
modifying the MyISAM tables.
DROP TABLE on a table that is
in use by a MERGE table does not work on
Windows because the MERGE 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 all MERGE tables (with
FLUSH TABLES) or drop the
MERGE table before dropping the table.
The definition of the MyISAM tables and the
MERGE table are checked when the tables are
accessed (for example, as part of a
SELECT or
INSERT statement). The checks
ensure that the definitions of the tables and the parent
MERGE 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 use
ALTER TABLE to add a
UNIQUE index to a table used in a
MERGE table, and then use
ALTER TABLE to add a nonunique
index on the MERGE table, the index
ordering is different for the tables if there was already a
nonunique index in the underlying table. (This happens because
ALTER TABLE puts
UNIQUE 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 the MyISAM
storage engine. Confirm that all of these tables are
MyISAM.
The maximum number of rows in a MERGE table
is 264 (~1.844E+19; the same as for
a MyISAM table). It is not possible to
merge multiple MyISAM tables into a single
MERGE table that would have more than this
number of rows.
Use of underlying MyISAM tables of
differing row formats with a parent MERGE
table is currently known to fail. See Bug #32364.
You cannot change the union list of a nontemporary
MERGE table when LOCK
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 with
CREATE ... SELECT, neither as a temporary
MERGE table, nor as a nontemporary
MERGE table. For example:
CREATE TABLE m1 ... ENGINE=MRG_MYISAM ... SELECT ...;
Attempts to do this result in an error:
tbl_name is not BASE
TABLE.
In some cases, differing PACK_KEYS table
option values among the MERGE and
underlying tables cause unexpected results if the underlying
tables contain CHAR or
BINARY columns. As a workaround, use
ALTER TABLE to ensure that all involved
tables have the same PACK_KEYS value. (Bug
#50646)