使用Docker快速搭建MySQL主从复制环境
2016-10-13
MySQL常见复制模式 #
MySQL的常见复制模式(假设有DB1,DB2,DB3三个MySQL实例):
- 主从复制 DB1 -> DB2
- 主主复制 DB1 <- -> DB2
- 链式复制 DB1 -> DB2 -> DB3
- 环形复制 DB1 -> DB2 -> DB3 -> DB1
生产环境常见主从复制,这是最稳健的一种方式;为了切换方便也可选择主主模式,但要注意主主复制必须确保在任何时刻只有一个数据库是master写入状态,否则可能导致数据异常。 链式和环形复制在生产环境很少使用,主要的缺点是随着节点的增加整个复制系统的稳健性会下降。
对于各种复制模式,主从复制是基础。本文记录自己使用Docker快速搭建MySQL主从复制环境的过程,用于平时的学习和试验。
主从配置文件 #
master配置文件/home/mysql/etc/master/master.cnf
1[mysqld]
2server_id = 1
3
4character-set-server=utf8mb4
5collation-server=utf8mb4_unicode_ci
6default-storage-engine=INNODB
7
8#Optimize omit
9
10sql_mode=NO_ENGINE_SUBSTITUTION,STRICT_TRANS_TABLES
11
12log-bin = /var/lib/mysql/binlog
13log_bin_trust_function_creators=1
14binlog_format = ROW
15expire_logs_days = 99
16sync_binlog = 0
17
18slow-query-log=1
19slow-query-log-file=/var/log/mysql/slow-queries.log
20long_query_time = 3
21log-queries-not-using-indexes
slave配置文件/home/mysql/etc/slave/slave.cnf
1[mysqld]
2server_id = 2
3
4character-set-server=utf8mb4
5collation-server=utf8mb4_unicode_ci
6default-storage-engine=INNODB
7
8#Optimize omit
9
10sql_mode=NO_ENGINE_SUBSTITUTION,STRICT_TRANS_TABLES
11
12log-bin = /var/lib/mysql/binlog
13log_bin_trust_function_creators=1
14binlog_format = ROW
15expire_logs_days = 99
16sync_binlog = 0
17
18relay_log=slave-relay-bin
19log-slave-updates=1
20slave-skip-errors=all
21
22slow-query-log=1
23slow-query-log-file=/var/log/mysql/slow-queries.log
24long_query_time = 3
25log-queries-not-using-indexes
启动容器,配置主从复制 #
创建数据目录:
1mkdir -p /home/mysql/data/master
2mkdir -p /home/mysql/data/slave
3
4MASTER_DIR=/home/mysql/data/master
5SLAVE_DIR=/home/mysql/data/slave
启动MySQL容器:
1docker run --name mysql-master \
2-v /home/mysql/etc/master:/etc/mysql/conf.d \
3-v /home/mysql/data/master:/var/lib/mysql \
4-e MYSQL_ROOT_PASSWORD=root \
5-d \
6mysql:5.7
7
8
9docker run --name mysql-slave \
10-v /home/mysql/etc/slave:/etc/mysql/conf.d \
11-v /home/mysql/data/slave:/var/lib/mysql \
12-e MYSQL_ROOT_PASSWORD=root \
13--link mysql-master:master \
14-d mysql:5.7
Master上创建复制用户:
1docker exec -it mysql-master mysql -p
2
3CREATE USER 'repl'@'%' IDENTIFIED BY 'repl';
4GRANT REPLICATION SLAVE ON *.* TO 'repl'@'%';
查看Master节点 Binlog状态:
1show master status\G
2*************************** 1. row ***************************
3 File: binlog.000008
4 Position: 595
5 Binlog_Do_DB:
6 Binlog_Ignore_DB:
7Executed_Gtid_Set:
81 row in set (0.00 sec)
在Slave节点上配置复制:
1docker exec -it mysql-slave mysql -p
2
3CHANGE MASTER TO \
4MASTER_HOST='master',\
5MASTER_PORT=3306,\
6MASTER_USER='repl',\
7MASTER_PASSWORD='repl',\
8MASTER_LOG_FILE='binlog.000008',\
9MASTER_LOG_POS=595;
10
11start slave;
查看Salve状态:
1show slave status\G
2*************************** 1. row ***************************
3 Slave_IO_State: Waiting for master to send event
4 Master_Host: master
5 Master_User: repl
6 Master_Port: 3306
7 Connect_Retry: 60
8 Master_Log_File: binlog.000008
9 Read_Master_Log_Pos: 595
10 Relay_Log_File: slave-relay-bin.000002
11 Relay_Log_Pos: 317
12 Relay_Master_Log_File: binlog.000008
13 Slave_IO_Running: Yes
14 Slave_SQL_Running: Yes
15 Replicate_Do_DB:
16 Replicate_Ignore_DB:
17 Replicate_Do_Table:
18 Replicate_Ignore_Table:
19 Replicate_Wild_Do_Table:
20 Replicate_Wild_Ignore_Table:
21 Last_Errno: 0
22 Last_Error:
23 Skip_Counter: 0
24 Exec_Master_Log_Pos: 595
25 Relay_Log_Space: 524
26 Until_Condition: None
27 Until_Log_File:
28 Until_Log_Pos: 0
29 Master_SSL_Allowed: No
30 Master_SSL_CA_File:
31 Master_SSL_CA_Path:
32 Master_SSL_Cert:
33 Master_SSL_Cipher:
34 Master_SSL_Key:
35 Seconds_Behind_Master: 0
36Master_SSL_Verify_Server_Cert: No
37 Last_IO_Errno: 0
38 Last_IO_Error:
39 Last_SQL_Errno: 0
40 Last_SQL_Error:
41 Replicate_Ignore_Server_Ids:
42 Master_Server_Id: 1
43 Master_UUID: 7a5a452f-fca9-11e6-be18-0242ac110002
44 Master_Info_File: /var/lib/mysql/master.info
45 SQL_Delay: 0
46 SQL_Remaining_Delay: NULL
47 Slave_SQL_Running_State: Slave has read all relay log; waiting for more updates
48 Master_Retry_Count: 86400
49 Master_Bind:
50 Last_IO_Error_Timestamp:
51 Last_SQL_Error_Timestamp:
52 Master_SSL_Crl:
53 Master_SSL_Crlpath:
54 Retrieved_Gtid_Set:
55 Executed_Gtid_Set:
56 Auto_Position: 0
57 Replicate_Rewrite_DB:
58 Channel_Name:
59 Master_TLS_Version:
601 row in set (0.00 sec)