MySQL 5.0 Reference Manual  /  ...  /  Replication and System Functions Replication and System Functions

Certain functions do not replicate well under some conditions:

  • The USER(), CURRENT_USER(), UUID(), VERSION(), and LOAD_FILE() functions are replicated without change and thus do not work reliably on the slave.

  • For NOW(), the binary log includes the timestamp. This means that the value as returned by the call to this function on the master is replicated to the slave. This can lead to a possibly unexpected result when replicating between MySQL servers in different time zones. Suppose that the master is located in New York, the slave is located in Stockholm, and both servers are using local time. Suppose further that, on the master, you create a table mytable, perform an INSERT statement on this table, and then select from the table, as shown here:

    mysql> CREATE TABLE mytable (mycol TEXT);
    Query OK, 0 rows affected (0.06 sec)
    mysql> INSERT INTO mytable VALUES ( NOW() );
    Query OK, 1 row affected (0.00 sec)
    mysql> SELECT * FROM mytable;
    | mycol               |
    | 2009-09-01 12:00:00 |
    1 row in set (0.00 sec)

    Local time in Stockholm is 6 hours later than in New York; so, if you issue SELECT NOW() on the slave at that exact same instant, the value 2009-09-01 18:00:00 is returned. For this reason, if you select from the slave's copy of mytable after the CREATE TABLE and INSERT statements just shown have been replicated, you might expect mycol to contain the value 2009-09-01 18:00:00. However, this is not the case; when you select from the slave's copy of mytable, you obtain exactly the same result as on the master:

    mysql> SELECT * FROM mytable;
    | mycol               |
    | 2009-09-01 12:00:00 |
    1 row in set (0.00 sec)

    As of MySQL 5.0.13, the SYSDATE() function is no longer equivalent to NOW(). Implications are that SYSDATE() is not replication-safe because it is not affected by SET TIMESTAMP statements in the binary log and is nondeterministic. To avoid this, you can start the server with the --sysdate-is-now option to cause SYSDATE() to be an alias for NOW().

    See also Section, “Replication and Time Zones”.

  • 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 the master. Therefore, these functions should not be used to insert into a master table because the content on the slave would differ. For example, do not issue a statement such as INSERT INTO mytable VALUES(GET_LOCK(...)).

As a workaround for the preceding limitations, you can use the strategy of saving the problematic function result in a user variable and referring to the variable in a later statement. For example, the following single-row INSERT is problematic due to the reference to the UUID() function:


To work around the problem, do this instead:

SET @my_uuid = UUID();

That sequence of statements replicates because the value of @my_uuid is stored in the binary log as a user-variable event prior to the INSERT statement and is available for use in the INSERT.

The same idea applies to multiple-row inserts, but is more cumbersome to use. For a two-row insert, you can do this:

SET @my_uuid1 = UUID(); @my_uuid2 = UUID();
INSERT INTO t VALUES(@my_uuid1),(@my_uuid2);

However, if the number of rows is large or unknown, the workaround is difficult or impracticable. For example, you cannot convert the following statement to one in which a given individual user variable is associated with each row:


Non-delayed INSERT statements that refer to RAND() or user-defined variables replicate correctly. However, changing the statements to use INSERT DELAYED can result in different results on master and slave.

Within a stored function, RAND() replicates correctly as long as it is invoked only once during the execution of the function. (You can consider the function execution timestamp and random number seed as implicit inputs that are identical on the master and slave.)

The FOUND_ROWS() and ROW_COUNT() functions are 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:


However, if you are replicating mytable, you should use SELECT ... INTO, and then store the variable in the table, like this:

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.

Download this Manual
User Comments
Sign Up Login You must be logged in to post a comment.