MySQL数据库的主从配置(多主对一从)

一、实验环境部署

服务器 192.168.18.42 端口3306  ==》 从服务器 192.168.18.44 端口 3306    
主服务器 192.168.18.43 端口3306  ==》 从服务器 192.168.18.44 端口 3307

##数据库,已经安装MySQL服务,安装部分略。从服务器上的多个mysql实例,请看另一篇帖子《用mysql_multi 实现一台机器跑多台mysql 》

二、部署服务器

1.在两台主服务器上赋予从机权限,有多台丛机,就执行多次(我们这里两台主库使用统一帐号密码)。

mysql> grant replication slave on *.* to 'backup'@'192.168.18.44' identified by '123456';
Query OK, 0 rows affected (0.00 sec)

2.在主服务器上配置my.cnf

vi /etc/my.cnf

server-id = 1
log-bin = mysql-bin  #保证binlog可读
read-only = 0  #主机,读写都可以
#binlog-do-db = test   #需要备份数据,多个写多行,不写全部都备份
binlog-ignore-db = mysql #不需要备份的数据库,多个写多行

编辑后重启数据库 # service mysqld restart

3.配置从库服务器的my.cnf

vi /etc/my.cnf

[mysqld_multi]
mysqld = /mysql/bin/mysqld_safe
mysqladmin = /mysql/bin/mysqladmin

[mysqld1]
port    = 3306
socket  = /tmp/mysql3306.sock
pid-file = /data/mysql/data1/mysql3306.pid
datadir = /data/mysql/data1
skip-name-resolve
log-bin = mysql-bin-3306
log_slave_updates
expire_logs_days = 7
log-error = /data/mysql/data1/mysql3306.err
log_slow_queries = mysql3306-slow.log
long_query_time = 3
query_cache_size = 64M
query_cache_limit = 2M
slave-net-timeout = 10
server-id = 2                     #server id 不要与主库的重复
master-host = 192.168.18.42        #对应主库的 ip地址
master-user = backup               # slave 帐号
master-password = 123456           # 密码
master-port = 3306                 #主库端口
replicate-ignore-db=mysql           #跳过不备份的库
master-info-file = master.1842.info
master-connect-retry = 10
relay-log = relay-bin-1842          #中继日志
relay-log-index = relay-bin-1842
relay-log-info-file = relay-log-1842.info
default-character-set=gbk
innodb_data_home_dir = /data/mysql/data1
innodb_data_file_path = ibdata1:50M:autoextend
innodb_log_group_home_dir = /data/mysql/data1
innodb_buffer_pool_size = 3072M
innodb_file_per_table
innodb_open_files = 800
#innodb_flush_method = O_DIRECT
innodb_flush_method = O_DSYNC
skip-locking
key_buffer = 32M
max_allowed_packet = 16M
table_cache = 1024
sort_buffer_size = 8M
net_buffer_length = 8M
read_buffer_size = 2M
read_rnd_buffer_size = 8M
myisam_sort_buffer_size = 32M
max_connections = 100
read_only
wait_timeout=288000
interactive_timeout=288000
log-bin-trust-function-creators=1
replicate-ignore-db = test
replicate-ignore-table = mysql.columns_priv
replicate-ignore-table = mysql.host
replicate-ignore-table = mysql.db
replicate-ignore-table = mysql.procs_priv
replicate-ignore-table = mysql.tables_priv
replicate-ignore-table = mysql.user



[mysqld2]
port    = 3307
socket  = /tmp/mysql3307.sock
pid-file = /data/mysql/data2/mysql3307.pid
datadir = /data/mysql/data2
skip-name-resolve
log-bin = mysql-bin-3307
log_slave_updates
expire_logs_days = 7
log-error = /data/mysql/data1/mysql3307.err
log_slow_queries = mysql3307-slow.log
long_query_time = 3
query_cache_size = 64M
query_cache_limit = 2M
slave-net-timeout = 10
server-id = 2                     #server id 不要与主库的重复
master-host = 192.168.18.43        #对应主库的 ip地址
master-user = backup               # slave 帐号
master-password = 123456           # 密码
master-port = 3306                 #主库端口
replicate-ignore-db=mysql           #跳过不备份的库
master-info-file = master.1843.info
master-connect-retry = 10
relay-log = relay-bin-1843
relay-log-index = relay-bin-1843
relay-log-info-file = relay-log-1843.info
default-character-set=gbk
innodb_data_home_dir = /data/mysql/data2
innodb_data_file_path = ibdata1:50M:autoextend
innodb_log_group_home_dir = /data/mysql/data2
innodb_buffer_pool_size = 3072M
innodb_file_per_table
innodb_open_files = 800
#innodb_flush_method = O_DIRECT
innodb_flush_method = O_DSYNC
skip-locking
key_buffer = 32M
max_allowed_packet = 16M
table_cache = 1024
sort_buffer_size = 8M
net_buffer_length = 8M
read_buffer_size = 2M
read_rnd_buffer_size = 8M
myisam_sort_buffer_size = 32M
max_connections = 100
read_only
wait_timeout=288000
interactive_timeout=288000
log-bin-trust-function-creators=1
replicate-ignore-db = test
replicate-ignore-table = mysql.columns_priv
replicate-ignore-table = mysql.host
replicate-ignore-table = mysql.db
replicate-ignore-table = mysql.procs_priv
replicate-ignore-table = mysql.tables_priv
replicate-ignore-table = mysql.user

# 因为图方便就把参数全部抓出来了 对主从有用的也就标注的几个

4.配置完成后重启大从服务器
[root@localhost data1]# mysqld_multi --config-file=/etc/my.cnf --user=root --password=123456 report 1,2
Reporting MySQL servers
MySQL server from group: mysqld1 is running
MySQL server from group: mysqld2 is running

5.在从库上进行chang master ;
1).在date1上
mysql -uroot -p -S /tmp/mysql3306.sock

mysql> stop slave;
Query OK, 0 rows affected (0.00 sec)

mysql> CHANGE MASTER TO
    -> MASTER_HOST='192.168.18.43',
    -> MASTER_PORT=3306,
    -> MASTER_USER='backup',
    -> MASTER_PASSWORD='123456'
Query OK, 0 rows affected (0.05 sec)

mysql> start slave;
Query OK, 0 rows affected (0.00 sec)

2)。在date2上

mysql -uroot -p -S /tmp/mysql3307.sock

mysql> stop slave;
Query OK, 0 rows affected (0.00 sec)

mysql> CHANGE MASTER TO
    -> MASTER_HOST='192.168.18.42',
    -> MASTER_PORT=3306,
    -> MASTER_USER='backup',
    -> MASTER_PASSWORD='123456'
Query OK, 0 rows affected (0.05 sec)

mysql> start slave;
Query OK, 0 rows affected (0.00 sec)


三、验证:
1.在大从服务器上

  show slave status\G; 

  Slave_IO_Running: Yes
  Slave_SQL_Running: Yes

2.在主库创建数据库(18.43上)

mysql> create database haifengtest;
Query OK, 1 row affected (0.00 sec)

mysql> show databases;
+--------------------+
| Database           |
+--------------------+
| information_schema | 
| haifengtest        | 
| mysql              | 
| test               | 
+--------------------+
4 rows in set (0.00 sec)

从库查看 (mysql3307.sock上)

mysql> show databases;
+--------------------+
| Database           |
+--------------------+
| information_schema | 
| haifengtest        | 
| mysql              | 
| test               | 
+--------------------+
4 rows in set (0.00 sec)

创新互联建站坚持“要么做到,要么别承诺”的工作理念,服务领域包括:成都做网站、网站制作、企业官网、英文网站、手机端网站、网站推广等服务,满足客户于互联网时代的嘉善网站设计、移动媒体设计的需求,帮助企业找到有效的互联网解决方案。努力成为您成熟可靠的网络建设合作伙伴!

四、一种常见的问题。

在show slave status\G;时发现下面的问题,(因为我事先在从上创建了该库)

  Relay_Master_Log_File: mysql-bin.000005
           Slave_IO_Running: Yes
          Slave_SQL_Running: No
            Replicate_Do_DB: 
        Replicate_Ignore_DB: mysql
         Replicate_Do_Table: 
     Replicate_Ignore_Table: 
    Replicate_Wild_Do_Table: 
Replicate_Wild_Ignore_Table: 
                 Last_Errno: 1007
                 Last_Error: Error 'Can't create database 'haifengtest'; database exists' on query. Default database: 'haifengtest'. Query: 'create database haifengtest'

如果Replication在Slave上出现上面错误而停止,一般都期望Slave能忽略这个错误,继续进行同步,而不是重新启动Slave。

这时可以使用 SQL_SLAVE_SKIP_COUNTER

mysql> SET GLOBAL SQL_SLAVE_SKIP_COUNTER = 1;
Query OK, 0 rows affected (0.00 sec)

mysql> start slave;
Query OK, 0 rows affected (0.00 sec)

 

在验证一次

  show slave status\G; 

  Slave_IO_Running: Yes
  Slave_SQL_Running: Yes


当前名称:MySQL数据库的主从配置(多主对一从)
标题网址:http://scyanting.com/article/gjshes.html