16.4.1.10 Replication with Differing Table Definitions on Source and Replica (original) (raw)

16.4.1.10 Replication with Differing Table Definitions on Source and Replica

Source and target tables for replication do not have to be identical. A table on the source can have more or fewer columns than the replica's copy of the table. In addition, corresponding table columns on the source and the replica can use different data types, subject to certain conditions.

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 source and the replica. Additional conditions are discussed, with examples, in the following two sections.

16.4.1.10.1 Replication with More Columns on Source or Replica

You can replicate a table from the source to the replica such that the source and replica copies of the table have differing numbers of columns, subject to the following conditions:

CREATE TABLE t (  
    c1 INT,  
    c2 INT,  
    c3 INT  
);  

Suppose that the ALTER TABLE statement shown here is executed on the replica:

ALTER TABLE t ADD COLUMN cnew1 INT AFTER c3;  

The previous ALTER TABLE is permitted on the replica because the columnsc1, c2, andc3 that are common to both versions of table t remain grouped together in both versions of the table, before any columns that differ.
However, the following ALTER TABLE statement cannot be executed on the replica without causing replication to break:

ALTER TABLE t ADD COLUMN cnew2 INT AFTER c2;  

Replication fails after execution on the replica of theALTER TABLE statement just shown, because the new column cnew2 comes between columns common to both versions oft.

In addition, when the replica's copy of the table has more columns than the source'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 source. The following table definitions are valid and replicate correctly:

source> CREATE TABLE t1 (c1 INT, c2 INT, c3 INT);
replica>  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 replica than they are on the source:

source> CREATE TABLE t1 (c1 INT, c2 INT, c3 INT);
replica>  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 source appears before the definitions of the columns common to both versions of the table:

source> CREATE TABLE t1 (c3 INT, c1 INT, c2 INT);
replica>  CREATE TABLE t1 (c1 INT, c2 INT);

More columns on the replica. The following table definitions are valid and replicate correctly:

source> CREATE TABLE t1 (c1 INT, c2 INT);
replica>  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 source and the replica:

source> CREATE TABLE t1 (c1 INT, c2 INT);
replica>  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 replica's version of the table appears before the definitions for the columns which are common to both versions of the table:

source> CREATE TABLE t1 (c1 INT, c2 INT);
replica>  CREATE TABLE t1 (c3 INT, c1 INT, c2 INT);

The following table definitions fail because the replica's version of the table has additional columns compared to the source's version, and the two versions of the table use different data types for the common columnc2:

source> CREATE TABLE t1 (c1 INT, c2 BIGINT);
replica>  CREATE TABLE t1 (c1 INT, c2 INT, c3 INT);
16.4.1.10.2 Replication of Columns Having Different Data Types

Corresponding columns on the source's and the replica'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 anotherCHAR(10), or from aCHAR(10) column to aCHAR(25) column without any problems. In certain cases, it also possible to replicate from a column having one data type (on the source) to a column having a different data type (on the replica); when the data type of the source's version of the column is promoted to a type that is the same size or larger on the replica, 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 source or the replica. 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.

Important

Whether you use statement-based or row-based replication, the replica's copy of the table cannot contain more columns than the source'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 source would also execute successfully on the replica, 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 replica, the statement can be replicated. For example, you can insert any value that fits in a TINYINT column into aBIGINT column as well; it follows that, even if you change the type of a TINYINT column in the replica's copy of a table toBIGINT, any insert into that column on the source that succeeds should also succeed on the replica, since it is impossible to have a legalTINYINT 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 source and the replica; otherwise, updates could be applied to the wrong table on the replica. (Bug #12669186)

Row-based replication: attribute promotion and demotion. Row-based replication 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 anon-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 replica. This variable takes a set of values from the following table, which shows the effects of each mode on the replica'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 anINT column to be converted toTINYINT (a lossy conversion), but not a TINYINT column to anINT column (non-lossy). Attempting the latter conversion in this case would cause replication to stop with an error on the replica.
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 theALL_LOSSY mode. If onlyALL_NON_LOSSY is set, but notALL_LOSSY, then attempting a conversion that would result in the loss of data (such as INT toTINYINT, orCHAR(25) toVARCHAR(20)) causes the replica to stop with an error.
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 slave_type_conversions is not set, no attribute promotion or demotion is permitted; this means that all columns in the source and target tables must be of the same types. This mode is the default.

When an integer type is promoted, its signedness is not preserved. By default, the replica 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 replica to treat all promoted integer types as signed;ALL_UNSIGNED instructs it to treat these as unsigned. Specifying both causes the replica 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 norALL_UNSIGNED has any effect if at least one of ALL_LOSSY orALL_NONLOSSY is not also used.

Changing the type conversion mode requires restarting the replica with the new slave_type_conversions setting.

Supported conversions. Supported conversions between different but similar data types are shown in the following list:

Conversions between types not in the previous list are not permitted.