Source and target tables for replication do not have to be identical. A table on the master can have more or fewer columns than the slave's copy of the table. In addition, corresponding table columns on the master and the slave can use different data types, subject to certain conditions.
Replication between tables which are partitioned differently from one another is not supported. See Section 16.4.1.19, “Replication and Partitioning”.
In all cases where the source and target tables do not have identical definitions, the database and table names must be the same on both the master and the slave. Additional conditions are discussed, with examples, in the following two sections.
You can replicate a table from the master to the slave such that the master and slave copies of the table have differing numbers of columns, subject to the following conditions:
Columns common to both versions of the table must be defined in the same order on the master and the slave.
(This is true even if both tables have the same number of columns.)
Columns common to both versions of the table must be defined before any additional columns.
This means that executing an
ALTER TABLEstatement on the slave where a new column is inserted into the table within the range of columns common to both tables causes replication to fail, as shown in the following example:Suppose that a table
t, existing on the master and the slave, is defined by the followingCREATE TABLEstatement:CREATE TABLE t ( c1 INT, c2 INT, c3 INT );Suppose that the
ALTER TABLEstatement shown here is executed on the slave:ALTER TABLE t ADD COLUMN cnew1 INT AFTER c3;The previous
ALTER TABLEis permitted on the slave because the columnsc1,c2, andc3that are common to both versions of tabletremain grouped together in both versions of the table, before any columns that differ.However, the following
ALTER TABLEstatement cannot be executed on the slave without causing replication to break:ALTER TABLE t ADD COLUMN cnew2 INT AFTER c2;Replication fails after execution on the slave of the
ALTER TABLEstatement just shown, because the new columncnew2comes between columns common to both versions oft.Each “extra” column in the version of the table having more columns must have a default value.
A column's default value is determined by a number of factors, including its type, whether it is defined with a
DEFAULToption, whether it is declared asNULL, and the server SQL mode in effect at the time of its creation; for more information, see Section 11.7, “Data Type Default Values”).
In addition, when the slave's copy of the table has more columns than the master's copy, each column common to the tables must use the same data type in both tables.
Examples. The following examples illustrate some valid and invalid table definitions:
More columns on the master. The following table definitions are valid and replicate correctly:
master> CREATE TABLE t1 (c1 INT, c2 INT, c3 INT);
slave> CREATE TABLE t1 (c1 INT, c2 INT);The following table definitions would raise an error because the definitions of the columns common to both versions of the table are in a different order on the slave than they are on the master:
master> CREATE TABLE t1 (c1 INT, c2 INT, c3 INT);
slave> CREATE TABLE t1 (c2 INT, c1 INT);The following table definitions would also raise an error because the definition of the extra column on the master appears before the definitions of the columns common to both versions of the table:
master> CREATE TABLE t1 (c3 INT, c1 INT, c2 INT);
slave> CREATE TABLE t1 (c1 INT, c2 INT);More columns on the slave. The following table definitions are valid and replicate correctly:
master> CREATE TABLE t1 (c1 INT, c2 INT);
slave> CREATE TABLE t1 (c1 INT, c2 INT, c3 INT);The following definitions raise an error because the columns common to both versions of the table are not defined in the same order on both the master and the slave:
master> CREATE TABLE t1 (c1 INT, c2 INT);
slave> CREATE TABLE t1 (c2 INT, c1 INT, c3 INT);The following table definitions also raise an error because the definition for the extra column in the slave's version of the table appears before the definitions for the columns which are common to both versions of the table:
master> CREATE TABLE t1 (c1 INT, c2 INT);
slave> CREATE TABLE t1 (c3 INT, c1 INT, c2 INT);
The following table definitions fail because the slave's
version of the table has additional columns compared to the
master's version, and the two versions of the table use
different data types for the common column
c2:
master> CREATE TABLE t1 (c1 INT, c2 BIGINT);
slave> CREATE TABLE t1 (c1 INT, c2 INT, c3 INT);
Corresponding columns on the master's and the slave's copies of the same table ideally should have the same data type. However, this is not always strictly enforced, as long as certain conditions are met.
It is usually possible to replicate from a column of a given
data type to another column of the same type and same size or
width, where applicable, or larger. For example, you can
replicate from a CHAR(10) column to another
CHAR(10), or from a
CHAR(10) column to a
CHAR(25) column without any problems. In
certain cases, it also possible to replicate from a column
having one data type (on the master) to a column having a
different data type (on the slave); when the data type of the
master's version of the column is promoted to a type that
is the same size or larger on the slave, this is known as
attribute promotion.
Attribute promotion can be used with both statement-based and row-based replication, and is not dependent on the storage engine used by either the master or the slave. However, the choice of logging format does have an effect on the type conversions that are permitted; the particulars are discussed later in this section.
Whether you use statement-based or row-based replication, the slave's copy of the table cannot contain more columns than the master's copy if you wish to employ attribute promotion.
Statement-based replication.
When using statement-based replication, a simple rule of
thumb to follow is, “If the statement run on the
master would also execute successfully on the slave, it
should also replicate successfully”. In other words,
if the statement uses a value that is compatible with the
type of a given column on the slave, the statement can be
replicated. For example, you can insert any value that fits
in a TINYINT column into a
BIGINT column as well; it follows that,
even if you change the type of a TINYINT
column in the slave's copy of a table to
BIGINT, any insert into that column on
the master that succeeds should also succeed on the slave,
since it is impossible to have a legal
TINYINT value that is large enough to
exceed a BIGINT column.
Prior to MySQL 5.7.1, when using statement-based replication,
AUTO_INCREMENT columns were required to be
the same on both the master and the slave; otherwise, updates
could be applied to the wrong table on the slave. (Bug
#12669186)
Row-based replication: attribute promotion and demotion. Row-based replication in MySQL 5.7 supports attribute promotion and demotion between smaller data types and larger types. It is also possible to specify whether or not to permit lossy (truncated) or non-lossy conversions of demoted column values, as explained later in this section.
Lossy and non-lossy conversions. In the event that the target type cannot represent the value being inserted, a decision must be made on how to handle the conversion. If we permit the conversion but truncate (or otherwise modify) the source value to achieve a “fit” in the target column, we make what is known as a lossy conversion. A conversion which does not require truncation or similar modifications to fit the source column value in the target column is a non-lossy conversion.
Type conversion modes (slave_type_conversions variable).
The setting of the slave_type_conversions
global server variable controls the type conversion mode
used on the slave. This variable takes a set of values from
the following table, which shows the effects of each mode on
the slave's type-conversion behavior:
| Mode | Effect |
|---|---|
ALL_LOSSY | In this mode, type conversions that would mean loss of information are permitted.
This does not imply that non-lossy conversions are
permitted, merely that only cases requiring either
lossy conversions or no conversion at all are
permitted; for example, enabling
only this mode permits an
|
ALL_NON_LOSSY | This mode permits conversions that do not require truncation or other special handling of the source value; that is, it permits conversions where the target type has a wider range than the source type.
Setting this mode has no bearing on whether lossy
conversions are permitted; this is controlled with
the |
ALL_LOSSY,ALL_NON_LOSSY | When this mode is set, all supported type conversions are permitted, whether or not they are lossy conversions. |
ALL_SIGNED | Treat promoted integer types as signed values (the default behavior). |
ALL_UNSIGNED | Treat promoted integer types as unsigned values. |
ALL_SIGNED,ALL_UNSIGNED | Treat promoted integer types as signed if possible, otherwise as unsigned. |
| [empty] |
When This mode is the default. |
When an integer type is promoted, its signedness is not
preserved. By default, the slave treats all such values as
signed. Beginning with MySQL 5.7.2, you can control this
behavior using ALL_SIGNED,
ALL_UNSIGNED, or both. (Bug#15831300)
ALL_SIGNED tells the slave to treat all
promoted integer types as signed;
ALL_UNSIGNED instructs it to treat these as
unsigned. Specifying both causes the slave to treat the value
as signed if possible, otherwise to treat it as unsigned; the
order in which they are listed is not significant. Neither
ALL_SIGNED nor
ALL_UNSIGNED has any effect if at least one
of ALL_LOSSY or
ALL_NONLOSSY is not also used.
Changing the type conversion mode requires restarting the
slave with the new slave_type_conversions
setting.
Supported conversions. Supported conversions between different but similar data types are shown in the following list:
Between any of the integer types
TINYINT,SMALLINT,MEDIUMINT,INT, andBIGINT.This includes conversions between the signed and unsigned versions of these types.
Lossy conversions are made by truncating the source value to the maximum (or minimum) permitted by the target column. For ensuring non-lossy conversions when going from unsigned to signed types, the target column must be large enough to accommodate the range of values in the source column. For example, you can demote
TINYINT UNSIGNEDnon-lossily toSMALLINT, but not toTINYINT.Between any of the decimal types
DECIMAL,FLOAT,DOUBLE, andNUMERIC.FLOATtoDOUBLEis a non-lossy conversion;DOUBLEtoFLOATcan only be handled lossily. A conversion fromDECIMAL(toM,D)DECIMAL(whereM',D')andD'>=D() is non-lossy; for any case whereM'-D') >= (M-D,M'<M, or both, only a lossy conversion can be made.D'<DFor any of the decimal types, if a value to be stored cannot be fit in the target type, the value is rounded down according to the rounding rules defined for the server elsewhere in the documentation. See Section 12.21.4, “Rounding Behavior”, for information about how this is done for decimal types.
Between any of the string types
CHAR,VARCHAR, andTEXT, including conversions between different widths.Conversion of a
CHAR,VARCHAR, orTEXTto aCHAR,VARCHAR, orTEXTcolumn the same size or larger is never lossy. Lossy conversion is handled by inserting only the firstNcharacters of the string on the slave, whereNis the width of the target column.ImportantReplication between columns using different character sets is not supported.
Between any of the binary data types
BINARY,VARBINARY, andBLOB, including conversions between different widths.Conversion of a
BINARY,VARBINARY, orBLOBto aBINARY,VARBINARY, orBLOBcolumn the same size or larger is never lossy. Lossy conversion is handled by inserting only the firstNbytes of the string on the slave, whereNis the width of the target column.Between any 2
BITcolumns of any 2 sizes.When inserting a value from a
BIT(column into aM)BIT(column, whereM'), the most significant bits of theM'>MBIT(columns are cleared (set to zero) and theM')Mbits of theBIT(value are set as the least significant bits of theM)BIT(column.M')When inserting a value from a source
BIT(column into a targetM)BIT(column, whereM'), the maximum possible value for theM'<MBIT(column is assigned; in other words, an “all-set” value is assigned to the target column.M')
Conversions between types not in the previous list are not permitted.