This section briefly describes how to set up complete replication of a MySQL server. It assumes that you want to replicate all databases on the master and have not previously configured replication. You must shut down your master server briefly to complete the steps outlined here.
This procedure is written in terms of setting up a single slave, but you can repeat it to set up multiple slaves.
Although this method is the most straightforward way to set up a slave, it is not the only one. For example, if you 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 Section 14.10, “Replication FAQ”.
If you want to administer a MySQL replication setup, we suggest that you read this entire chapter through and try all statements mentioned in Section 12.5.1, “SQL Statements for Controlling Master Servers”, and Section 12.5.2, “SQL Statements for Controlling Slave Servers”. You should also familiarize yourself with the replication startup options described in Section 14.8, “Replication and Binary Logging Options and Variables”.
This procedure and some of the replication SQL statements shown
in later sections refer to the
SUPER
privilege. Prior to MySQL
4.0.2, use the PROCESS
privilege
instead.
Make sure that you have a recent version of MySQL installed on the master and slaves, and that these versions are compatible according to the table shown in Section 14.5, “Replication Compatibility Between MySQL Versions”.
If you encounter a problem, please do not report it as a bug until you have verified that the problem is present in the latest MySQL release.
Set up an account on the master server that the slave server
can use to connect. This account must be given the
REPLICATION SLAVE
privilege. If
the account is used only for replication (which is
recommended), you don't need to grant any additional
privileges.
MySQL Enterprise.
Subscribers to the MySQL Enterprise Monitor are quickly
notified if there is a replication master and no account
with the REPLICATION SLAVE
privilege. For more information, see
http://www.mysql.com/products/enterprise/advisors.html.
Suppose that your domain is mydomain.com
and that you want to create an account with a user name of
repl
such that slave servers can use the
account to access the master server from any host in your
domain using a password of slavepass
. To
create the account, use this
GRANT
statement:
mysql>GRANT REPLICATION SLAVE ON *.*
->TO 'repl'@'%.mydomain.com' IDENTIFIED BY 'slavepass';
For MySQL versions older than 4.0.2, the
REPLICATION SLAVE
privilege
does not exist. Grant the FILE
privilege instead:
mysql>GRANT FILE ON *.*
->TO 'repl'@'%.mydomain.com' IDENTIFIED BY 'slavepass';
For additional information about setting up user accounts and privileges, see Section 5.6, “MySQL User Account Management”.
Flush all the tables and block write statements by executing a
FLUSH TABLES WITH READ
LOCK
statement:
mysql> FLUSH TABLES WITH READ LOCK;
For example, if you are using InnoDB
tables, you should use the InnoDB
Hot Backup tool to obtain a consistent snapshot.
This tool records the log name and offset corresponding to the
snapshot to be later used on the slave. Hot
Backup is a nonfree (commercial) tool that is not
included in the standard MySQL distribution. See the
InnoDB
Hot Backup home
page at
http://www.innodb.com/wp/products/hot-backup/
for detailed information.
Otherwise, you can obtain a reliable binary snapshot of
InnoDB
tables only after shutting down the
MySQL Server.
An alternative that works for both MyISAM
and InnoDB
tables is to take an SQL dump of
the master instead of a binary copy as described in the
preceding discussion. For this, you can use mysqldump
--master-data on your master and later load the SQL
dump file into your slave. However, this is slower than doing
a binary copy.
Leave running the client from which you issue the
FLUSH TABLES
statement so that the read lock remains in effect. (If you
exit the client, the lock is released.) Then take a snapshot
of the data on your master server.
The easiest way to create a snapshot is to use an archiving program to make a binary backup of the databases in your master's data directory. For example, use tar on Unix, or PowerArchiver, WinRAR, WinZip, or any similar software on Windows. 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 the slave server has a different set of user
accounts from those that exist on the master. In this case,
you should 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 | manual,mysql |
+---------------+----------+--------------+------------------+
The File
column shows the name of the log
and Position
shows the offset within the
file. In this example, the binary log file is
mysql-bin.003
and the offset is 73. Record
these values. You need them later when you are setting up the
slave. They represent the replication coordinates at which the
slave should begin processing new updates from the master.
If the master has been running previously without binary
logging enabled, the log name and position values displayed by
SHOW MASTER STATUS
or
mysqldump --master-data will be empty. In
that case, the values that you need to use later when
specifying the slave's log file and position are the empty
string (''
) and 4
.
After you have taken the snapshot and recorded the log name and offset, you can re-enable write activity on the master:
mysql> UNLOCK TABLES;
Make sure that 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=
option, where master_id
master_id
must be a
positive integer value from 1 to
232 – 1. For example:
[mysqld] log-bin=mysql-bin server-id=1
If those options are not present, add them and restart the server. The server cannot act as a replication master unless binary logging is enabled.
For the greatest possible durability and consistency in a
replication setup using InnoDB
with
transactions, you should use
innodb_flush_log_at_trx_commit=1
,
sync_binlog=1
, and
innodb_safe_binlog
in your master
my.cnf
file.
Stop the server that is to be used as a slave and add the
following lines to its my.cnf
file:
[mysqld]
server-id=slave_id
The slave_id
value, like the
master_id
value, must be a positive
integer value from 1 to 232 –
1. In addition, it is necessary that the ID of the slave be
different from the ID of the master. For example:
[mysqld] server-id=2
If you are setting up multiple slaves, each one must have a
unique 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 do not specify a
server-id
value, it defaults to
0.
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 system account that you use to run the slave server must be able to read and write the files, just as on the master.
If you made a backup using mysqldump, start the slave first. The dump file is loaded in a later step.
Start the slave server. If it has been replicating previously,
start the slave server with the
--skip-slave-start
option so
that it doesn't immediately try to connect to its master. You
also may want to start the slave server with the
--log-warnings
option to get
more messages in the error log about problems (for example,
network or connection problems). The option is enabled by
default as of MySQL 4.0.19 and 4.1.2, but as of MySQL 4.0.21
and 4.1.3, aborted connections are not logged to the error log
unless the value is greater than 1.
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
Execute the following statement on the slave, replacing the option values with the actual values relevant to your system:
mysql>CHANGE MASTER TO
->MASTER_HOST='
->master_host_name
',MASTER_USER='
->replication_user_name
',MASTER_PASSWORD='
->replication_password
',MASTER_LOG_FILE='
->recorded_log_file_name
',MASTER_LOG_POS=
recorded_log_position
;
Replication cannot use Unix socket files. You must be able to connect to the master MySQL server using TCP/IP.
The following table shows the maximum allowable length for the string-valued options.
MASTER_HOST |
60 |
MASTER_USER |
16 |
MASTER_PASSWORD |
32 |
MASTER_LOG_FILE |
255 |
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 the server-id
option for the master, slaves cannot connect to it.
If you have forgotten to set the server-id
option for the slave, you get the following error in the slave's
error log:
Warning: You should set server-id to a non-0 value if master_host is set; we will force server id to 2, but this MySQL server will not act as a slave.
You 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 can find in its data directory
one file named master.info
and another named
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 know exactly what you are doing and fully understand
the implications. Even in that case, it is preferred that you use
the CHANGE MASTER TO
statement to
change replication parameters. The slave will use the values
specified in the statement to update the status files
automatically.
The content of master.info
overrides some
of the server options specified on the command line or in
my.cnf
. See
Section 14.8, “Replication and Binary Logging Options and Variables”, for more details.
Once you have a snapshot of the master, 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; you can use the same one for each slave.
User Comments
If you are setting up replication through an SSH channel, be sure to specify "127.0.0.1" as the address of the database, not "localhost", as MySQL will use "localhost" as a trigger to use a pipe for the connection instead of TCP/IP, and thus will fail.
For Debian users : after copying all mysql data files from master to slave you can get the following error message :
---
/usr/bin/mysqladmin: connect to server at 'localhost' failed
error: 'Access denied for user 'debian-sys-maint'@'localhost' (using password: YES)'
---
* Which means that Mysql password for user 'debian-sys-maint' isn't the same as in file /etc/mysql/debian.cnf.
* Because this password is randomly generated, they are different for each installation, and we have to 'synchronize' this password between debian.cnf file and Mysql privileges.
1 - On the master, get a copy of the password string in /etc/mysql/debian.cnf
2 - On the slave, stop the Mysql server, edit /etc/mysql/debian.cnf and replace the password by the one of the master. Start the slave server.
If you want to change it
1 - Launch a Mysql client and select 'mysql' database
2 - run this : UPDATE `user` SET `Password` = password('[password]') where user='debian-sys-maint'
(the password seems to be encrypted but is not)
3 - stop the Mysql server (you get an error for 'debian-sys-maint')
4 - change and put same [password] in /etc/mysql/debian.cnf file
For people getting:
"ERROR 1218 (08S01): Error connecting to master: Lost connection to MySQL server during query"
Make sure that ,on you're master replication server, you change the following line in your my.cnf:
bind-address 127.0.0.1
to
#bind-address 127.0.0.1
Or change the address to your FQDN or ip-addres
It is possible to sync a database to a master while the master is in active use. Commands starting "M:" are run on the master, "S:" are run in the slave. Until the end, the slave state is undefined.
This works for InnoDB tables, if you have set transactionality to REPEATABLE-READ.
M: begin;
M: flush tables with read lock;
M: show master status;
M: show databases;
M: (for each db:)
M:__ show tables in $db;
M:__ (for each table:)
M:____ select 1 from $db.$table limit 1;
M: unlock tables;
M: set time_zone = '+00:00';
S: set foreign_key_checks = 0;
S: stop slave io_thread;
S: stop slave;
S: reset slave;
S: reset master;
S: set time_zone = '+00:00';
_: (for each database:)
S:__ show databases like '$db';
_:__ (if it does not exist:)
S:____ create database $db;
_:__ (for each table:)
M:____ show create table $db.$table;
S:____ show create table $db.$table;
_:____ (if different:)
S:______ drop table $db.$table;
_:____ (if different or not on slave:)
S:______ create table $db.$table .... ;
S:____ delete from $db.$table;
M:____ select * from $db.$table;
S:____ insert into $db.$table values ([...from above...]);
S:__ show tables in $db;
_:__ (for each table that shouldn't be there:)
S:____ drop table $db.$table;
S: show databases;
_: (for each db that shouldn't be there:)
S:__ drop database $db;
S: change master to [...details from show master above...];
S: start slave io_thread;
S: start slave;
M: rollback;
(Urghh... I see no way to embed code into these posts. Hence the ugly "____" thing to indicate indentation. I suggest copying into something with a non-proportinal font, to make it easier to read)
When setting up replication from a Windows installation and replicated to a Unix installation of 5.0.x; Remember that the database tables are Case Sensitive under the Unix variant (See 9.2.2. Identifier Case Sensitivity). So if your application does not take this into effect, sql commands work fine with the Windows copy, but break when ran against the backup/replicated server, or worse, the replication breaks due to the fact the Unix server can't find the table.
Be Safe, target your SQL for the Unix standard of "LowerCase" and you will be a happy developer/administrator!
These are the configuration i had try out:
MySQL Failover Circular Replication
===================================
Assume we have 2 servers: Server1 and Server2.
Server1 Settings
================
1. Put the option file my.cnf to Server1 path /etc with these settings:
[mysqld]
log-bin=mysql-bin
server-id = 1
auto_increment_increment = 10
auto_increment_offset = 1
2. Change mode/permission for my.cnf to _rw_r__r__ else mysql will igonore it.
sudo chmod 644 my.cnf
3. Stop and start mysql.
cd /Library/StartupItems/MySQLCOM
sudo ./MySQLCOM stop
sudo ./MySQLCOM start
4. Configure the server:
# create a user for replication process:
cd /usr/local/mysql/bin
./mysql -p -u root
create user replicant@'%' identified by 'password';
# Grant access rights:
GRANT SELECT, PROCESS, FILE, SUPER, REPLICATION CLIENT, REPLICATION SLAVE, RELOAD ON *.* TO replicant@'%';
Flush Privileges;
# Specify the info for the serve2:
CHANGE MASTER TO
MASTER_HOST='ip_of_server2',
MASTER_USER='replication_user_name_on_server2',
MASTER_PASSWORD='replication_password_on_server2';
# Start the listerner:
Start slave;
# Verify whether the replication is working:
show slave status\G
Server2 Settings
================
1. Put the option file my.cnf on to Server2 path /etc
with these settings:
[mysqld]
log-bin=mysql-bin
server-id = 2
auto_increment_increment = 10
auto_increment_offset = 2
2. Change mode/permission for my.cnf to _rw_r__r__ else mysql will igonore it.
sudo chmod 644 my.cnf
3. Stop and start mysql.
cd /Library/StartupItems/MySQLCOM
sudo ./MySQLCOM stop
sudo ./MySQLCOM start
4. Configure the server:
# create a user for replication process:
cd /usr/local/mysql/bin
./mysql -p -u root
create user replicant@'%' identified by 'password';
# Grant access rights:
GRANT SELECT, PROCESS, FILE, SUPER, REPLICATION CLIENT, REPLICATION SLAVE, RELOAD ON *.* TO replicant@'%';
Flush Privileges;
# Specify the info for the serve1:
CHANGE MASTER TO
MASTER_HOST='ip_of_server1',
MASTER_USER='replication_user_name_on_server1',
MASTER_PASSWORD='replication_password_on_server1';
# Example:
#
# CHANGE MASTER TO MASTER_HOST='125.564.12.1',
# MASTER_USER='replicant', MASTER_PASSWORD='password';
# Load data from Server1:
Load Data from Master;
# Start the listerner:
Start slave;
It is worth to mention that "SELECT ... FOR UPDATE" doesn't distribute the locks to all slaves, which creates room for "funny" results.
What will happen in a two-node solution with circular replication as described at http://www.onlamp.com/pub/a/onlamp/2006/04/20/advanced-mysql-replication.html is that the update is copied to the other node while the local update is overwritten.
This is a flaw that has to be considered, and the right way to resolve this is probably through the MySQL Cluster.
If you are using SSL and find that you can connect using the command line, yet get 'Access Denied' in the replication logs, check the permissions on your certificates! Mine turned out to be readable by root, but not by the mysql user that the replication runs as.
Here is a video tutorial for setting up replication that shows what happens in the event of the master server failing http://www.codefutures.com/mysql-replication-howto
Here's a step by step simple quick and dirty tutorial on how to setup replication in just 5 mysql command lines and editing of the /etc/mysql/my.cnf file on both the master and the slave.
Basically you just need to setup the server id, create a user with the right privilege and start the replication:
http://blog.bottomlessinc.com/2010/03/setting-up-mysql-replication/
The doc was confusing to me and not in chronological order.
Add your own comment.