Chapter 53. How to Set Up Replication

Here is a quick description of how to set up complete replication on your current MySQL server. It assumes you want to replicate all your databases and have not configured replication before. You will need to shut down your master server briefly to complete the steps outlined here.

The procedure is written in terms of setting up a single slave, but you can use it to set up multiple slaves.

While this method is the most straightforward way to set up a slave, it is not the only one. For example, if you already have a snapshot of the master's data, and the master already has its server ID set and binary logging enabled, you can set up a slave without shutting down the master or even blocking updates to it. For more details, please see Replication FAQ.

If you want to administer a MySQL replication setup, we suggest that you read this entire chapter through and try all commands mentioned in Replication Master SQL ans Replication Slave SQL. You should also familiarise yourself with replication startup options in my.cnf in Replication Options.

Note that this procedure and some of the replication SQL statements in later sections refer to the SUPER privilege. Prior to MySQL 4.0.2, use the PROCESS privilege instead.

  1. Make sure you have a recent version of MySQL installed on the master and and slaves, and that these versions are compatible according to the table shown in Replication Upgrade.

    Please do not report bugs until you have verified that the problem is present in the latest release.

  2. Set up an account on the master server that the slave server can use to connnect. This account must be given the REPLICATION SLAVE privilege. (If MySQL versions older than 4.0.2, give the account the FILE privilege instead.) If the account is only for replication (which is recommended), you don't need to grant any additional privileges.

    The hostname in the account name should be such that each of the slave servers can use the account to connect to the master. For example, to create a user named repl which can access your master from any host, you might use this command:

     mysql> GRANT REPLICATION SLAVE ON *.* TO repl@'%' IDENTIFIED BY '<password>';
     

    For MySQL versions older than 4.0.2, use this command instead:

     mysql> GRANT FILE ON *.* TO repl@'%' IDENTIFIED BY '<password>';
     

    If you plan to use the LOAD TABLE FROM MASTER or LOAD DATA FROM MASTER statements from the slave host, you will need to grant this account additional privileges:

    • Grant to the account the SUPER and RELOAD global privileges.

    • Grant the SELECT privilege for all tables that you want to load. Any master tables from which the account cannot SELECT will be ignored by LOAD DATA FROM MASTER.

  3. If you are using MyISAM tables, flush all the tables and block write queries by executing FLUSH TABLES WITH READ LOCK command.

     mysql> FLUSH TABLES WITH READ LOCK;
     

    and then take a snapshot of the data on your master server.

    The easiest way to create a snapshot is to simply use an archiving program (tar on Unix, PowerArchiver, WinRAR, WinZip or any similar software on Windows) to produce an archive of the databases in your master's data directory. For example, to use tar to create an archive that includes all databases, change location into the master server's data directory, then execute this command:

     shell> tar -cvf /tmp/mysql-snapshot.tar .
     

    If you want the archive to include only a database called this_db, use this command instead:

     shell> tar -cvf /tmp/mysql-snapshot.tar ./this_db
     

    Then copy the archive file to the /tmp directory on the slave server host. On that machine, change location into the slave's data directory, and unpack the archive file using this command:

     shell> tar -xvf /tmp/mysql-snapshot.tar
     

    You may not want to replicate the mysql database. If not, you can exclude it from the archive. You also need not include any log files in the archive, or the master.info or relay-log.info files.

    While the read lock placed by FLUSH TABLES WITH READ LOCK is in effect, read the value of the current binary log name and offset on the master:

     mysql > SHOW MASTER STATUS;
     +---------------+----------+--------------+------------------+
     | File          | Position | Binlog_Do_DB | Binlog_Ignore_DB |
     +---------------+----------+--------------+------------------+
     | mysql-bin.003 | 73       | test,bar     | foo,manual,mysql |
     +---------------+----------+--------------+------------------+
     1 row in set (0.06 sec)
     

    The File column shows the name of the log, while Position shows the offset. In the above example, the binary log value is mysql-bin.003 and the offset is 73. Record the values. You will need to use them later when you are setting up the slave.

    Once you have taken the snapshot and recorded the log name and offset, you can re-enable write activity on the master:

     mysql> UNLOCK TABLES;
     

    If you are using InnoDB tables, ideally you should use the InnoDB Hot Backup tool that is available to those who purchase MySQL commercial licenses, support, or the backup tool itself. It takes a consistent snapshot without acquiring any locks on the master server, and records the log name and offset corresponding to the snapshot to be later used on the slave. More information about the tool is available at http://www.innodb.com/order.php.

    Without the Hot Backup tool, the quickest way to take a snapshot of InnoDB tables is to shut down the master server and copy the InnoDB datafiles and logs, and the table definition files (.frm). To record the current log file name and offset, you should do the following before you shut down the server:

     mysql> FLUSH TABLES WITH READ LOCK;
     mysql> SHOW MASTER STATUS;
     

    And then record the log name and the offset from the output of SHOW MASTER STATUS as was shown earlier. Once you have recorded the log name and the offset, shut down the server without unlocking the tables to make sure it goes down with the snapshot corresponding to the current log file and offset:

     shell> mysqladmin -uroot shutdown
     

    An alternative for both MyISAM and InnoDB tables is to take an SQL dump of the master instead of a binary copy like above; for this you can use mysqldump --master-data on your master and later run this SQL dump into your slave. However, this is slower than doing a binary copy.

    If the master has been previously running without --log-bin enabled, the log name and position values displayed by SHOW MASTER STATUS or mysqldump will be empty. In that case, record empty string ('') for the log name, and 4 for the offset.

  4. Make sure the [mysqld] section of the my.cnf file on the master host includes a log-bin option. The section should also have a server-id=master_id option, where master_id must be an integer value from 1 to 2^32 - 1. For example:

     [mysqld]
     log-bin
     server-id=1
     

    If those options are not present, add them and restart the server.

  5. Stop the server that is to be used as a slave server and add the following to its my.cnf file:

     [mysqld]
     server-id=slave_id
     

    The slave_id value, like the master_id value, must be an integer value from 1 to 2^32 - 1. In addition, it is very important that the ID of the slave be different than the ID of the master. For example:

     [mysqld]
     server-id=2
     

    If you are setting up multiple slaves, each one must have a server-id value that differs from that of the master and from each of the other slaves. Think of server-id values as something similar to IP addresses: These IDs uniquely identify each server instance in the community of replication partners.

    If you don't specify a server-id value, it will be set to 1 if you have not defined master-host, else it will be set to 2. Note that in the case of server-id omission, a master will refuse connections from all slaves, and a slave will refuse to connect to a master. Thus, omitting server-id is only good for backup with a binary log.

  6. If you made a binary backup of the master server's data, copy it to the slave server's data directory before starting the slave. Make sure that the privileges on the files and directories are correct. The user which MySQL runs as needs to be able to read from and write to them, just as on the master.

    If you made a backup using mysqldump, start the slave first (see next step).

  7. Start the slave server. If it has been replicating previously, start the slave server with the --skip-slave-start option. You also may want to start the slave server with the --log-warnings option. That way, you will get more messages about problems (for example, network or connection problems).

  8. If you made a backup of the master server's data using mysqldump, load the dump file into the slave server:

     shell> mysql -u root -p < dump_file.sql
     
  9. Execute the following command on the slave, replacing the values within <> with the actual values relevant to your system:

     mysql> CHANGE MASTER TO
         ->     MASTER_HOST='<master hostname>',
         ->     MASTER_USER='<replication username>',
         ->     MASTER_PASSWORD='<replication password>',
         ->     MASTER_LOG_FILE='<recorded log file name>',
         ->     MASTER_LOG_POS=<recorded log offset>;
     

    The following table lists the maximum string length for these variables:

    MASTER_HOST60
    MASTER_USER16
    MASTER_PASSWORD32
    MASTER_LOG_FILE255
  10. Start the slave threads:

    mysql> START SLAVE; 
    

After you have performed this procedure, the slave should connect to the master and catch up on any updates that have occurred since the snapshot was taken.

If you have forgotten to set server-id for the master, slaves will not be able to connect to it.

If you have forgotten to set server-id for the slave, you will get the following error in its error log:

Warning: one should set server_id to a non-0 value if master_host is set.
The server will not act as a slave.

You will also find error messages in the slave's error log if it is not able to replicate for any other reason.

Once a slave is replicating, you will find in its data directory one file called master.info and another called relay-log.info. The slave uses these two files to keep track of how much of the master's binary log it has processed. Do not remove or edit these files, unless you really know what you are doing and understand the implications. Even in that case, it is preferred that you use CHANGE MASTER TO command.

NOTE: The content of master.info overrides some options specified on the command-line or in my.cnf See Replication Options for more details.

Once you have a snapshot, you can use it to set up other slaves by following the slave portion of the procedure just described. You do not need to take another snapshot of the master.