In general, replication compatibility at the SQL level requires
that any features used be supported by both the master and the
slave servers. If you use a feature on a master server that is
available only as of a given version of MySQL, you cannot
replicate to a slave that is older than that version. Such
incompatibilities are likely to occur between series, so that, for
example, you cannot replicate from MySQL 4.1 to
4.0. However, these incompatibilities also can occur
for within-series replication. For example, the
CONVERT_TZ()
function is available
in MySQL 4.1.3 and up. If you use this function on the master
server, you cannot replicate to a slave server that is older than
MySQL 4.1.3.
Another compatibility problem can be encountered when you are
attempting to replicate from an older master to a newer slave, and
you make use of identifiers on the master that are reserved words
in the newer MySQL version running on the slave. An example of
this is using a table column named current_user
on a 4.0 master that is replicating to a 4.1 or higher slave,
because CURRENT_USER
is a reserved word
beginning in MySQL 4.1. Replication can fail in such cases with
Error 1064 You have an error in your SQL
syntax..., even if a database or table named
using the reserved word or a table having a column named using the
reserved word is excluded from replication. This is due
to the fact that each SQL statement must be parsed by the slave
prior to execution, so that the slave knows which database object
or objects would be effected by the statement; only after the
statement is parsed can the slave apply any filtering rules
defined by --replicate-do-db
,
--replicate-do-table
,
--replicate-ignore-db
, and
--replicate-ignore-table
.
To work around the problem of database, table, or column names on the master which would be regarded as reserved words by the slave, do one of the following:
Use one or more ALTER TABLE
statements on the master to change the names of any database
objects where these names would be considered reserved words
on the slave, and change any SQL statements that use the old
names to use the new names instead.
In any SQL statements using these database object names, set
the names off using backtick characters
(`
).
For listings of reserved words by MySQL version, see Reserved Words,.in the MySQL Server Version Reference.
The following list provides details about what is supported and
what is not. Additional information specific to
InnoDB
and replication is given in
Section 13.2.5.5, “InnoDB
and MySQL Replication”.
Replication of AUTO_INCREMENT
,
LAST_INSERT_ID()
, and
TIMESTAMP
values is done
correctly, subject to the following exceptions.
INSERT DELAYED ... VALUES(LAST_INSERT_ID())
inserts a different value on the master and the slave.
(Bug#20819)
Adding an AUTO_INCREMENT
column to a table
with ALTER TABLE
might not
produce the same ordering of the rows on the slave and the
master. This occurs because the order in which the rows are
numbered depends on the specific storage engine used for the
table and the order in which the rows were inserted. If it is
important to have the same order on the master and slave, the
rows must be ordered before assigning an
AUTO_INCREMENT
number. Assuming that you
want to add an AUTO_INCREMENT
column to the
table t1
, the following statements produce
a new table t2
identical to
t1
but with an
AUTO_INCREMENT
column:
CREATE TABLE t2 LIKE t1; ALTER TABLE t2 ADD id INT AUTO_INCREMENT PRIMARY KEY; INSERT INTO t2 SELECT * FROM t1 ORDER BY col1, col2;
This assumes that the table t1
has columns
col1
and col2
.
To guarantee the same ordering on both master and slave,
all columns of t1
must be referenced in the ORDER BY
clause.
The instructions just given are subject to the limitations of
CREATE TABLE ... LIKE
: Foreign key
definitions are ignored, as are the DATA
DIRECTORY
and INDEX DIRECTORY
table options. If a table definition includes any of those
characteristics, create t2
using a
CREATE TABLE
statement that is
identical to the one used to create t1
, but
with the addition of the AUTO_INCREMENT
column.
Regardless of the method used to create and populate the copy
having the AUTO_INCREMENT
column, the final
step is to drop the original table and then rename the copy:
DROP t1; ALTER TABLE t2 RENAME t1;
The USER()
,
CURRENT_USER()
,
UUID()
, and
LOAD_FILE()
functions are
replicated without change and thus do not work reliably on the
slave. This is also true for
CONNECTION_ID()
in slave
versions older than 4.1.1. The
new
PASSWORD()
function in MySQL
4.1 is well replicated in masters from 4.1.1 and up; your
slaves also must be 4.1.1 or above to replicate it. If you
have older slaves and need to replicate
PASSWORD()
from your 4.1.x
master, you must start your master with the
--old-passwords
option, so that
it uses the old implementation of
PASSWORD()
. (Note that the
PASSWORD()
implementation in
MySQL 4.1.0 differs from every other version of MySQL. It is
best to avoid 4.1.0 in a replication scenario.)
The GET_LOCK()
,
RELEASE_LOCK()
,
IS_FREE_LOCK()
, and
IS_USED_LOCK()
functions that
handle user-level locks are replicated without the slave
knowing the concurrency context on master. Therefore, these
functions should not be used to insert into a master's table
because the content on the slave would differ. (For example,
do not issue a statement such as INSERT INTO mytable
VALUES(GET_LOCK(...))
.)
The FOUND_ROWS()
function is
also not replicated reliably. A workaround is to store the
result of the function call in a user variable, and then use
that in the INSERT
statement.
For example, if you wish to store the result in a table named
mytable
, you might normally do so like
this:
SELECT SQL_CALC_FOUND_ROWS FROM mytable LIMIT 1; INSERT INTO mytable VALUES( FOUND_ROWS() );
However, if you are replicating mytable
,
then you should use SELECT INTO
, and then
store the variable in the table, like this:
SELECT SQL_CALC_FOUND_ROWS INTO @found_rows FROM mytable LIMIT 1; INSERT INTO mytable VALUES(@found_rows);
In this way, the user variable is replicated as part of the context, and applied on the slave correctly.
User privileges are replicated only if the
mysql
database is replicated. That is, the
GRANT
,
REVOKE
,
SET PASSWORD
, and
DROP USER
(available as of
MySQL 4.1.1) statements take effect on the slave only if the
replication setup includes the mysql
database.
If you're replicating all databases, but don't want statements
that affect user privileges to be replicated, set up the slave
to not replicate the mysql
database, using
the
--replicate-wild-ignore-table=mysql.%
option. That option is available as of MySQL 4.0.13. The slave
will recognize that issuing privilege-related SQL statements
won't have an effect, and thus not execute those statements.
The foreign_key_checks
variable is replicated as of MySQL 4.0.14. The
sql_mode
,
unique_checks
,
sql_auto_is_null
, and
storage_engine
(also known as
table_type
) variables are not
replicated in MySQL 4.1 or earlier versions.
The following applies to replication between MySQL servers that use different character sets:
You must always use the same
global character set and collation on
the master and the slave. (These are controlled by the
--character-set-server
and
--collation-server
options.) Otherwise, you may get duplicate-key errors on
the slave, because a key that is unique in the master
character set might not be unique in the slave character
set.
If the master is older than MySQL 4.1.3, the character set
of any client should never be made different from its
global value because this character set change is not
known to the slave. In other words, clients should not use
SET NAMES
, SET CHARACTER
SET
, and so forth. If both the master and the
slave are 4.1.3 or newer, clients can freely set session
values for character set variables because these settings
are written to the binary log and so are known to the
slave. That is, clients can use SET
NAMES
or SET CHARACTER SET
or
can set variables such as
collation_client
or
collation_server
.
However, clients are prevented from changing the
global value of these variables; as
stated previously, the master and slave must always have
identical global character set values.
If on the master you have databases with different
character sets from the global
collation_server
value,
you should design your CREATE
TABLE
statements so that they do not implicitly
rely on the default database's character set, because
there currently is a bug (Bug#2326); a good workaround is
to state the character set and collation explicitly in
CREATE TABLE
.
The same system time zone should be set for both master and
slave. Otherwise some statements will not be replicated
properly, such as statements that use the
NOW()
or
FROM_UNIXTIME()
functions. You
can set the time zone in which MySQL server runs by using the
--timezone=
option of the timezone_name
mysqld_safe
script or by
setting the TZ
environment variable.
Starting with MySQL 4.1.3, both master and slave should have
the same default connection time zone set, that is the
--default-time-zone
parameter
should have the same value for both master and slave. However,
if the master runs MySQL 5.0 or later, this is not necessary.
CONVERT_TZ(...,...,@@global.time_zone)
is not properly replicated.
Session variables are not replicated properly when used in
statements which update tables; for example: SET
MAX_JOIN_SIZE=1000; INSERT INTO mytable
VALUES(@@MAX_JOIN_SIZE);
will not insert the same
data on the master and on the slave.
It is possible to replicate transactional tables on the master
using nontransactional tables on the slave. For example, you
can replicate an InnoDB
master table as a
MyISAM
slave table. However, there are
issues that you should consider before you do this:
There are problems if the slave is stopped in the middle
of a
BEGIN
/COMMIT
block because the slave restarts at the beginning of the
BEGIN
block.
When the storage engine type of the slave is nontransactional, transactions on the master that mix updates of transactional and nontransactional tables should be avoided because they can cause inconsistency of the data between the master's transactional table and the slave's nontransactional table. That is, such transactions can lead to master storage engine-specific behavior with the possible effect of replication going out of synchrony. MySQL does not issue a warning about this currently, so extra care should be taken when replicating transactional tables from the master to nontransactional ones on the slaves.
Update statements that refer to user-defined variables (that
is, variables of the form
@
) are
badly replicated in 3.23 and 4.0. This is fixed in 4.1.
var_name
The slave can connect to the master using SSL if both are 4.1.1 or newer.
Starting from MySQL 4.1.11, there is a global system variable
slave_transaction_retries
: If
the replication slave SQL thread fails to execute a
transaction because of an InnoDB
deadlock
or because it exceeded the InnoDB
innodb_lock_wait_timeout
or
the NDBCLUSTER
TransactionDeadlockDetectionTimeout
or
TransactionInactiveTimeout
value, the
transaction automatically retries
slave_transaction_retries
times before stopping with an error. The default value is 0 in
MySQL 4.1. Starting from MySQL 4.1.11, the total retry count
can be seen in SHOW STATUS
; see
Section 5.1.6, “Server Status Variables”.
If a DATA DIRECTORY
or INDEX
DIRECTORY
table option is used in a
CREATE TABLE
statement on the
master server, the table option is also used on the slave.
This can cause problems if no corresponding directory exists
in the slave host file system or if it exists but is not
accessible to the slave server. As of MySQL 4.0.15, there is
an sql_mode
option called
NO_DIR_IN_CREATE
. If the
slave server is run with this SQL mode enabled, it ignores the
DATA DIRECTORY
and INDEX
DIRECTORY
table options when replicating
CREATE TABLE
statements. The
result is that MyISAM
data and index files
are created in the table's database directory.
It is possible for the data on the master and slave to become different if a statement is designed in such a way that the data modification is nondeterministic; that is, left to the will of the query optimizer. (This is in general not a good practice, even outside of replication.) For a detailed explanation of this issue, see Section A.5.8.4, “Open Issues in MySQL”.
If on the master a
LOAD DATA
INFILE
is interrupted (for example, by a integrity
constraint violation or a killed connection), the slave skips
this LOAD DATA
INFILE
entirely. This means that if this command
permanently inserted or updated table records before being
interrupted, these modifications are not
replicated to the slave.
In addition, LOAD
DATA INFILE
does not replicate correctly when
--binlog-do-db
is used.
(Bug#19662)
LOAD DATA
INFILE
also does not replicate well from 4.0 and
earlier masters to 5.1 or later slaves. In such cases, it is
best to upgrade the master to 5.0 or later. (Bug#31240)
The LOAD DATA
INFILE
statement's
CONCURRENT
option is not replicated; that
is, LOAD DATA CONCURRENT INFILE
is
replicated as LOAD
DATA INFILE
, and LOAD DATA CONCURRENT LOCAL
INFILE
is replicated as
LOAD DATA LOCAL
INFILE
. (Bug#34628)
Before MySQL 4.1.1, the FLUSH
,
ANALYZE TABLE
,
OPTIMIZE TABLE
, and
REPAIR TABLE
statements are not
written to the binary log and thus are not replicated to the
slaves. This is not normally a problem because these
statements do not modify table data. However, it can cause
difficulties under certain circumstances. If you replicate the
privilege tables in the mysql
database and
update those tables directly without using the
GRANT
statement, you must issue
a FLUSH
PRIVILEGES
statement on your slaves to put the new
privileges into effect. Also if you use
FLUSH TABLES
when renaming a MyISAM
table that is part
of a MERGE
table, you have to issue
FLUSH TABLES
manually on the slaves. As of MySQL 4.1.1, these statements
are written to the binary log (unless you specify
NO_WRITE_TO_BINLOG
, or its alias
LOCAL
). Exceptions are that
FLUSH LOGS
,
FLUSH MASTER
,
FLUSH SLAVE
,
and FLUSH TABLES WITH
READ LOCK
are not logged in any case. (Any of these
may cause problems if replicated to a slave.) For a syntax
example, see Section 12.4.6.2, “FLUSH
Syntax”.
MySQL 4.1 and earlier support only replication scenarios involving one master and many slaves.
When a server shuts down and restarts, its
MEMORY
(HEAP
) tables
become empty. As of MySQL 4.0.18, the master replicates this
effect to slaves as follows: The first time that the master
uses each MEMORY
table after startup, it
logs an event that notifies the slaves that the table needs to
be emptied by writing a DELETE
statement for that table to the binary log. See
Section 13.4, “The MEMORY
(HEAP
) Storage Engine”, for more information
about MEMORY
tables.
Temporary tables are replicated except in the case where you shut down the slave server (not just the slave threads) and you have replicated temporary tables that are used in updates that have not yet been executed on the slave. If you shut down the slave server, the temporary tables needed by those updates are no longer available when the slave is restarted. To avoid this problem, do not shut down the slave while it has temporary tables open. Instead, use the following procedure:
Issue a STOP SLAVE
statement.
Use SHOW STATUS
to check
the value of the
Slave_open_temp_tables
variable.
If the value is 0, issue a mysqladmin shutdown command to stop the slave.
If the value is not 0, restart the slave SQL thread with
START SLAVE SQL_THREAD
.
Repeat the procedure later until the
Slave_open_temp_tables
variable is 0 and you can stop the slave.
The syntax for multiple-table
DELETE
statements that use
table aliases changed between MySQL 4.0 and 4.1. In MySQL 4.0,
you should use the true table name to refer to any table from
which rows should be deleted:
DELETE test FROM test AS t1, test2 WHERE ...
In MySQL 4.1, you must use the alias:
DELETE t1 FROM test AS t1, test2 WHERE ...
If you use such DELETE
statements, the change in syntax means that a 4.0 master
cannot replicate to 4.1 (or higher) slaves.
It is safe to connect servers in a circular master/slave
relationship if you use the
--log-slave-updates
option.
That means that you can create a setup such as this:
A -> B -> C -> A
However, many statements do not work correctly in this kind of setup unless your client code is written to take care of the potential problems that can occur from updates that occur in different sequence on different servers.
Server IDs are encoded in binary log events, so server A knows
when an event that it reads was originally created by itself
and does not execute the event (unless server A was started
with the
--replicate-same-server-id
option, which is meaningful only in rare cases). Thus, there
are no infinite loops. This type of circular setup works only
if you perform no conflicting updates between the tables. In
other words, if you insert data in both A and C, you should
never insert a row in A that may have a key that conflicts
with a row inserted in C. You should also not update the same
rows on two servers if the order in which the updates are
applied is significant.
If a statement on a slave produces an error, the slave SQL
thread terminates, and the slave writes a message to its error
log. You should then connect to the slave manually and
determine the cause of the problem. (SHOW
SLAVE STATUS
is useful for this.) Then fix the
problem (for example, you might need to create a nonexistent
table) and run START SLAVE
.
It is safe to shut down a master server and restart it later.
When a slave loses its connection to the master, the slave
tries to reconnect immediately and retries periodically if
that fails. The default is to retry every 60 seconds. This may
be changed with the CHANGE MASTER
TO
statement or
--master-connect-retry
option.
A slave also is able to deal with network connectivity
outages. However, the slave notices the network outage only
after receiving no data from the master for
slave_net_timeout
seconds. If
your outages are short, you may want to decrease
slave_net_timeout
. See
Section 5.1.3, “Server System Variables”.
Shutting down the slave (cleanly) is also safe because it
keeps track of where it left off. Unclean shutdowns might
produce problems, especially if the disk cache was not flushed
to disk before the system went down. Your system fault
tolerance is greatly increased if you have a good
uninterruptible power supply. Unclean shutdowns of the master
may cause inconsistencies between the content of tables and
the binary log in master; this can be avoided by using
InnoDB
tables and the
--innodb_safe_binlog
option on
the master. See Section 5.3.4, “The Binary Log”.
A crash on the master side can result in the master's binary
log having a final position less than the most recent position
read by the slave, due to the master's binary log file not
being flushed. This can cause the slave not to be able to
replicate when the master comes back up. Setting
sync_binlog=1
in the master
my.cnf
file helps to minimize this
problem because it causes the master to flush its binary log
more frequently.
Due to the nontransactional nature of
MyISAM
tables, it is possible to have a
statement that only partially updates a table and returns an
error code. This can happen, for example, on a multiple-row
insert that has one row violating a key constraint, or if a
long update statement is killed after updating some of the
rows. If that happens on the master, the slave thread exits
and waits for the database administrator to decide what to do
about it unless the error code is legitimate and execution of
the statement results in the same error code on the slave. If
this error code validation behavior is not desirable, some or
all errors can be masked out (ignored) with the
--slave-skip-errors
option.
This option is available starting with MySQL 3.23.47.
If you update transactional tables from nontransactional
tables inside a
BEGIN
/COMMIT
sequence, updates to the binary log may be out of synchrony
with table states if the nontransactional table is updated
before the transaction commits. This occurs because the
transaction is written to the binary log only when it is
committed.
You should avoid transactions that update both transactional and nontransactional tables in a replication environment.
Before version 4.0.15, any update to a nontransactional table
is written to the binary log at once when the update is made,
whereas transactional updates are written on
COMMIT
or not written at all if
you use
ROLLBACK
.
You must take this into account when updating both
transactional tables and nontransactional tables within the
same transaction. (This is true not only for replication, but
also if you are using binary logging for backups.)
As of version 4.0.15, we changed the logging behavior for
transactions that mix updates to transactional and
nontransactional tables, which solves the problems (order of
statements is good in the binary log, and all needed
statements are written to the binary log even in case of
ROLLBACK
).
The problem that remains is that when a second connection
updates the nontransactional table while the first
connection's transaction is not finished yet, incorrect
ordering can still occur because the second connection's
update is written immediately after it is done.
When a 4.x slave replicates a
LOAD DATA
INFILE
from a 3.23 master, the values of the
Exec_Master_Log_Pos
and
Relay_Log_Space
columns of
SHOW SLAVE STATUS
become
incorrect. The inaccuracy in
Exec_Master_Log_Pos
causes problems when
you stop and restart replication; so it is a good idea to
correct the value before this, by doing
FLUSH LOGS
on
the master.
Replication slaves do not write replicated queries to the slow query log, even if the same queries were written to the slow query log on the master. This is a known issue. (Bug#23300)
DELETE
,
UPDATE
, and
INSERT ...
SELECT
statements containing a
LIMIT
clause are not guaranteed to produce
the same result on the slave as on the master, since the order
of the rows affected is not defined. Such statements can be
replicated correctly only if they also contain an
ORDER BY
clause.
The following problems with replication in MySQL 3.23 are fixed in MySQL 4.0:
LOAD DATA
INFILE
is handled properly, as long as the data file
still resides on the master server at the time of update
propagation.
LOAD DATA LOCAL
INFILE
is no longer skipped on the slave as it was
in 3.23.
In 3.23, RAND()
in updates does
not replicate properly. Use
RAND(
if you are replicating updates with
determinstic_expression
)RAND()
. You can, for example,
use UNIX_TIMESTAMP()
as the
argument to RAND()
.
Floating-point values are approximate, so comparisons involving them are inexact. This is true for operations that use floating-point values explicitly, or values that are converted to floating-point implicitly. Comparisons of floating-point values might yield different results on master and slave servers due to differences in computer architecture, the compiler used to build MySQL, and so forth. See Section 11.2.2, “Type Conversion in Expression Evaluation”, and Section A.5.5.8, “Problems with Floating-Point Values”.
User Comments
I use deleting requests from slave in one of my projects to save requests history on master. So I noticed that INSERT IGNORE query with affected rows 0 wouldn't be replicated.
So if you want to get asynchronous data on slave use INSERT ON DUPLICATE KEY UPDATE or REPLACE.
Add your own comment.