标题: mysql+proxysql+replication-manager的主从半同步复制+高可用+读写分离 [打印本页] 作者: 三尺非寒 时间: 2023-4-23 21:50 标题: mysql+proxysql+replication-manager的主从半同步复制+高可用+读写分离 环境:
AlmaLinux release 9.1
MySQL Community Server Ver 8.0.33
Replication Manager v2.2.40 for MariaDB 10.x and MySQL 5.7 Series
ProxySQL version 2.5.1-90-gbedaa6c
主机分配情况:
采用hyper-v创建虚拟机的方式进行的,创建1台模板之后另外3台导入虚拟机复制。
1、安装mysql
mysql8的默认加密插件变为了caching_sha2_password需要修改成mysql_native_password,因为proxysql不支持caching_sha2_password
安装完成后在server01、02、03上创建以下用户
rep-manager供replication-manager使用,repl供主从复制使用
mysql> create user 'rep-manager'@'%' identified by 'your password';
Query OK, 0 rows affected (0.01 sec)
mysql> create user 'repl'@'%' identified by 'your password';
Query OK, 0 rows affected (0.02 sec)
mysql> create user 'proxysql'@'%' identified by 'your password';
Query OK, 0 rows affected (0.02 sec)
mysql> grant process,replication slave,replication client on *.* to 'proxysql'@'%';
Query OK, 0 rows affected (0.01 sec)
mysql> grant select,replication slave,replication client,reload,super on *.* to 'repl'@'%';
Query OK, 0 rows affected, 1 warning (0.01 sec)
mysql> grant all privileges on *.* to 'rep-manager'@'%' with grant option;
mysql> show plugins;<br>+----------------------------------+----------+--------------------+---------------------+---------+<br>| Name | Status | Type | Library | License |<br>+----------------------------------+----------+--------------------+---------------------+---------+<br>| binlog | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| mysql_native_password | ACTIVE | AUTHENTICATION | NULL | GPL |<br>| sha256_password | ACTIVE | AUTHENTICATION | NULL | GPL |<br>| caching_sha2_password | ACTIVE | AUTHENTICATION | NULL | GPL |<br>| sha2_cache_cleaner | ACTIVE | AUDIT | NULL | GPL |<br>| daemon_keyring_proxy_plugin | ACTIVE | DAEMON | NULL | GPL |<br>| CSV | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| MEMORY | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| InnoDB | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| INNODB_TRX | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_CMP | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_CMP_RESET | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_CMPMEM | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_CMPMEM_RESET | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_CMP_PER_INDEX | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_CMP_PER_INDEX_RESET | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_BUFFER_PAGE | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_BUFFER_PAGE_LRU | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_BUFFER_POOL_STATS | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_TEMP_TABLE_INFO | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_METRICS | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_FT_DEFAULT_STOPWORD | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_FT_DELETED | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_FT_BEING_DELETED | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_FT_CONFIG | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_FT_INDEX_CACHE | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_FT_INDEX_TABLE | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_TABLES | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_TABLESTATS | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_INDEXES | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_TABLESPACES | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_COLUMNS | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_VIRTUAL | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_CACHED_INDEXES | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| INNODB_SESSION_TEMP_TABLESPACES | ACTIVE | INFORMATION SCHEMA | NULL | GPL |<br>| MyISAM | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| MRG_MYISAM | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| PERFORMANCE_SCHEMA | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| TempTable | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| ARCHIVE | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| BLACKHOLE | ACTIVE | STORAGE ENGINE | NULL | GPL |<br>| FEDERATED | DISABLED | STORAGE ENGINE | NULL | GPL |<br>| ndbcluster | DISABLED | STORAGE ENGINE | NULL | GPL |<br>| ndbinfo | DISABLED | STORAGE ENGINE | NULL | GPL |<br>| ndb_transid_mysql_connection_map | DISABLED | INFORMATION SCHEMA | NULL | GPL |<br>| ngram | ACTIVE | FTPARSER | NULL | GPL |<br>| mysqlx_cache_cleaner | ACTIVE | AUDIT | NULL | GPL |<br>| mysqlx | ACTIVE | DAEMON | NULL | GPL |<br>| rpl_semi_sync_source | ACTIVE | REPLICATION | semisync_source.so | GPL |<br>| rpl_semi_sync_replica | ACTIVE | REPLICATION | semisync_replica.so | GPL |<br>+----------------------------------+----------+--------------------+---------------------+---------+<br>50 rows in set (0.00 sec)<br>要想永久启用半同步需将配置写入my.cnf看下面的配置即可。<br>在主库上查看是否启用了半同步<br> mysql> show variables like 'rpl_semi%';<br>+---------------------------------------------+------------+<br>| Variable_name | Value |<br>+---------------------------------------------+------------+<br>| rpl_semi_sync_replica_enabled | ON |<br>| rpl_semi_sync_replica_trace_level | 32 |<br>| rpl_semi_sync_source_enabled | ON |<br>| rpl_semi_sync_source_timeout | 10000 |<br>| rpl_semi_sync_source_trace_level | 32 |<br>| rpl_semi_sync_source_wait_for_replica_count | 1 |<br>| rpl_semi_sync_source_wait_no_replica | ON |<br>| rpl_semi_sync_source_wait_point | AFTER_SYNC |<br>+---------------------------------------------+------------+<br>从库上<br>mysql> show variables like 'rpl_semi%';<br>+---------------------------------------------+------------+<br>| Variable_name | Value |<br>+---------------------------------------------+------------+<br>| rpl_semi_sync_replica_enabled | ON |<br>| rpl_semi_sync_replica_trace_level | 32 |<br>| rpl_semi_sync_source_enabled | ON |<br>| rpl_semi_sync_source_timeout | 10000 |<br>| rpl_semi_sync_source_trace_level | 32 |<br>| rpl_semi_sync_source_wait_for_replica_count | 1 |<br>| rpl_semi_sync_source_wait_no_replica | ON |<br>| rpl_semi_sync_source_wait_point | AFTER_SYNC |<br>+---------------------------------------------+------------+<br>8 rows in set (0.01 sec)
复制代码
master主机mysql配置my.cnf如下
# For advice on how to change settings please see<br># http://dev.mysql.com/doc/refman/8.0/en/server-configuration-defaults.html<br><br>[mysqld]<br>#<br># Remove leading # and set to the amount of RAM for the most important data<br># cache in MySQL. Start at 70% of total RAM for dedicated server, else 10%.<br># innodb_buffer_pool_size = 128M<br>#<br># Remove the leading "# " to disable binary logging<br># Binary logging captures changes between backups and is enabled by<br># default. It's default setting is log_bin=binlog<br># disable_log_bin<br>#<br># Remove leading # to set options mainly useful for reporting servers.<br># The server defaults are faster for transactions and fast SELECTs.<br># Adjust sizes as needed, experiment to find the optimal values.<br># join_buffer_size = 128M<br># sort_buffer_size = 2M<br># read_rnd_buffer_size = 2M<br>#<br># Remove leading # to revert to previous value for default_authentication_plugin,<br># this will increase compatibility with older clients. For background, see:<br># https://dev.mysql.com/doc/refman/8.0/en/server-system-variables.html#sysvar_default_authentication_plugin<br># default-authentication-plugin=mysql_native_password<br><br>datadir=/var/lib/mysql<br>socket=/var/lib/mysql/mysql.sock<br><br>log-error=/var/log/mysqld.log<br>pid-file=/var/run/mysqld/mysqld.pid<br><br>default-authentication-plugin=mysql_native_password<br><br>######replication settings######<br>server-id=1001<br>log-bin=mysql-bin<br>binlog_format=row<br><br>binlog-ignore-db=mysql<br>binlog-ignore-db=information_schema<br>binlog-ignore-db=performance_schema<br>binlog-ignore-db=sys<br><br>######gtid#######<br>gtid_mode=on<br>enforce_gtid_consistency=on<br>binlog_gtid_simple_recovery=on<br><br>relay_log_recovery = ON<br>relay-log-index=mysql-relay<br>relay-log=mysql-relay<br><br>loose_rpl_semi_sync_source_enabled = ON<br>loose_rpl_semi_sync_replica_enabled = ON<br><br>log_slow_replica_statements = 1
复制代码
slave主机myql的配置如下:
# For advice on how to change settings please see<br># http://dev.mysql.com/doc/refman/8.0/en/server-configuration-defaults.html<br><br>[mysqld]<br>#<br># Remove leading # and set to the amount of RAM for the most important data<br># cache in MySQL. Start at 70% of total RAM for dedicated server, else 10%.<br># innodb_buffer_pool_size = 128M<br>#<br># Remove the leading "# " to disable binary logging<br># Binary logging captures changes between backups and is enabled by<br># default. It's default setting is log_bin=binlog<br># disable_log_bin<br>#<br># Remove leading # to set options mainly useful for reporting servers.<br># The server defaults are faster for transactions and fast SELECTs.<br># Adjust sizes as needed, experiment to find the optimal values.<br># join_buffer_size = 128M<br># sort_buffer_size = 2M<br># read_rnd_buffer_size = 2M<br>#<br># Remove leading # to revert to previous value for default_authentication_plugin,<br># this will increase compatibility with older clients. For background, see:<br># https://dev.mysql.com/doc/refman/8.0/en/server-system-variables.html#sysvar_default_authentication_plugin<br># default-authentication-plugin=mysql_native_password<br><br>datadir=/var/lib/mysql<br>socket=/var/lib/mysql/mysql.sock<br><br>log-error=/var/log/mysqld.log<br>pid-file=/var/run/mysqld/mysqld.pid<br><br>default-authentication-plugin=mysql_native_password<br><br>######replication settings######<br>server-id=1002<br>log-bin=mysql-bin<br>binlog_format=row<br>log_slave_updates=on<br>relay_log_recovery=1<br><br>binlog-ignore-db=mysql<br>binlog-ignore-db=information_schema<br>binlog-ignore-db=performance_schema<br>binlog-ignore-db=sys<br><br>######gtid#######<br>gtid_mode=on<br>enforce_gtid_consistency=on<br>binlog_gtid_simple_recovery=on<br><br>relay_log_recovery = ON<br>relay-log-index=mysql-relay<br>relay-log=mysql-relay<br><br>loose_rpl_semi_sync_source_enabled = ON<br>loose_rpl_semi_sync_replica_enabled = ON<br><br>log_slow_replica_statements = 1<br><br>read_only = on<br>
mysql> create user appbox@'%' identified by 'Appbox@123';
Query OK, 0 rows affected (0.01 sec)
mysql> create database appboxdb character set utf8mb4;
Query OK, 1 row affected (0.01 sec)
mysql> grant all privileges on appboxdb.* to appbox@'%';
Query OK, 0 rows affected (0.01 sec)
mysql>
复制代码
用Navicat连proxysql
在proxysql中插入读写规则
insert into mysql_query_rules(rule_id,active,match_digest,destination_hostgroup,apply)values(1,1,'^SELECT.*FOR UPDATE$',100,1);
insert into mysql_query_rules(rule_id,active,match_digest,destination_hostgroup,apply)values(2,1,'^SELECT',1000,1);<br>load mysql query rules to runtime;<br>save mysql query rules to disk;
复制代码
bash下进行读写测试
for i in {1..100}; do mysql -uappbox -pAppbox@123 -h server00.mshome.net -P6033 -e 'select @@server_id;' ; sleep 0.5; done