Flush all the tables and block write statements by executing a
FLUSH TABLES WITH READ LOCK
statement:
mysql> FLUSH TABLES WITH READ LOCK;
For InnoDB
tables, note that FLUSH
TABLES WITH READ LOCK
also blocks
COMMIT
operations. When you have acquired a
global read lock, you can start a filesystem snapshot of your
InnoDB
tables. Internally (inside the
InnoDB
storage engine) the snapshot won't
be consistent (because the InnoDB
caches
are not flushed), but this is not a cause for concern, because
InnoDB
resolves this at startup and
delivers a consistent result. This means that
InnoDB
can perform crash recovery when
started on this snapshot, without corruption. However, there
is no way to stop the MySQL server while insuring a consistent
snapshot of your InnoDB
tables.
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;
If you are using InnoDB
tables, ideally you
should use the InnoDB
Hot
Backup tool, which 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. Hot Backup is an
additional non-free (commercial) tool that is not included in
the standard MySQL distribution. See the
InnoDB
Hot Backup home
page at https://www.innodb.com/manual.php for
detailed information.
Without the Hot Backup tool, the quickest
way to take a binary snapshot of InnoDB
tables is to shut down the master server and copy the
InnoDB
data files, log files, and table
format files (.frm
files). To record the
current log file name and offset, you should issue the
following statements before you shut down the server:
mysql> FLUSH TABLES WITH READ LOCK;
mysql> SHOW MASTER STATUS;
Then record the log name and the offset from the output of
SHOW MASTER STATUS
as was shown earlier.
After recording the log name and the offset, shut down the
server without unlocking the tables to
make sure that the server goes down with the snapshot
corresponding to the current log file and offset:
shell> mysqladmin -u root shutdown
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.
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
is set to 1 if you have not defined
master-host
; otherwise it is set to 2. Note
that in the case of server-id
omission, a
master refuses connections from all slaves, and a slave
refuses to connect to a master. Thus, omitting
server-id
is good only for backup with a
binary log.