权限管理及数据备份与恢复

**作者:行癫(盗版必究)** ------ ## 一:权限管理 #### 1.权限级别 ​ Global level:系统级,所有库,所有表的权限 ​ Database level:某个数据库中的所有表的权限 ​ Table level:库中的某个表的权限 ​ Column level:表中的某个字段的权限 ​ procs level:某个存储过程的权限 ​ proxies level:代理服务器的权限 #### 2.查看权限记录表 ​ 因为超级管理员默认已经设置;所以直接查询权限即可 ##### Global level ``` mysql> select * from mysql.user\G *************************** 1. row *************************** Host: localhost User: root Select_priv: Y Insert_priv: Y Update_priv: Y Delete_priv: Y Create_priv: Y Drop_priv: Y Reload_priv: Y Shutdown_priv: Y Process_priv: Y File_priv: Y Grant_priv: Y References_priv: Y Index_priv: Y Alter_priv: Y Show_db_priv: Y Super_priv: Y Create_tmp_table_priv: Y Lock_tables_priv: Y Execute_priv: Y Repl_slave_priv: Y Repl_client_priv: Y Create_view_priv: Y Show_view_priv: Y Create_routine_priv: Y Alter_routine_priv: Y Create_user_priv: Y Event_priv: Y Trigger_priv: Y Create_tablespace_priv: Y ssl_type: ssl_cipher: x509_issuer: x509_subject: max_questions: 0 max_updates: 0 max_connections: 0 max_user_connections: 0 plugin: mysql_native_password authentication_string: *B1DD4ADE47888D9AEC4D705C85230F1B52D2A817 password_expired: N password_last_changed: 2022-09-25 14:44:38 password_lifetime: NULL account_locked: N ``` 字段介绍: ```shell 用户字段:root 权限字段:Select_priv 安全字段:*B1DD4ADE47888D9AEC4D705C85230F1B52D2A817 Select_priv:查询权限 Insert_priv:插入权限 Update_priv:更新权限 Delete_priv:删除权限 ...... ``` ##### Database level ```shell mysql> select * from mysql.db\G; *************************** 1. row *************************** Host: localhost Db: performance_schema User: mysql.session Select_priv: Y Insert_priv: N Update_priv: N Delete_priv: N Create_priv: N Drop_priv: N Grant_priv: N References_priv: N Index_priv: N Alter_priv: N Create_tmp_table_priv: N Lock_tables_priv: N Create_view_priv: N Show_view_priv: N Create_routine_priv: N Alter_routine_priv: N Execute_priv: N Event_priv: N Trigger_priv: N ``` 测试库权限: ```shell mysql> create database t1; Query OK, 1 row affected (0.00 sec) mysql> grant all on t1.* to 't1'@'localhost' identified by 'QianFeng@123'; Query OK, 0 rows affected, 1 warning (0.00 sec) ``` 查看: ``` mysql> select * from mysql.db\G *************************** 3. row *************************** Host: localhost Db: t1 User: t1 Select_priv: Y Insert_priv: Y Update_priv: Y Delete_priv: Y Create_priv: Y Drop_priv: Y Grant_priv: N References_priv: Y Index_priv: Y Alter_priv: Y Create_tmp_table_priv: Y Lock_tables_priv: Y Create_view_priv: Y Show_view_priv: Y Create_routine_priv: Y Alter_routine_priv: Y Execute_priv: Y Event_priv: Y Trigger_priv: Y 3 rows in set (0.00 sec) ``` 验证: ```shell [root@xingdian ~]# mysql -u t1 -pQianFeng@123 mysql: [Warning] Using a password on the command line interface can be insecure. Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 4 Server version: 5.7.39-log MySQL Community Server (GPL) Copyright (c) 2000, 2022, Oracle and/or its affiliates. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> show databases; +--------------------+ | Database | +--------------------+ | information_schema | | t1 | +--------------------+ 2 rows in set (0.00 sec) ``` ##### Table level ```shell mysql> select * from mysql.tables_priv\G; *************************** 1. row *************************** Host: localhost Db: mysql User: mysql.session Table_name: user Grantor: boot@connecting host Timestamp: 0000-00-00 00:00:00 Table_priv: Select Column_priv: *************************** 2. row *************************** Host: localhost Db: sys User: mysql.sys Table_name: sys_config Grantor: root@localhost Timestamp: 2022-09-25 14:40:58 Table_priv: Select Column_priv: 2 rows in set (0.00 sec) ``` 创建库表验证: ```shell mysql> create database t2; Query OK, 1 row affected (0.00 sec) mysql> use t2; Database changed mysql> create table u1(id int); Query OK, 0 rows affected (0.01 sec) mysql> insert into u1 values (1); Query OK, 1 row affected (0.01 sec) mysql> grant all on t2.u1 to 't2'@'localhost' identified by 'QianFeng@123'; Query OK, 0 rows affected, 1 warning (0.00 sec) mysql> create table u2(id int); Query OK, 0 rows affected (0.01 sec) mysql> show tables; +--------------+ | Tables_in_t2 | +--------------+ | u1 | | u2 | +--------------+ 2 rows in set (0.00 sec) ``` 权限查看: ```shell mysql> select * from mysql.tables_priv\G; *************************** 3. row *************************** Host: localhost Db: t2 User: t2 Table_name: u1 Grantor: root@localhost Timestamp: 0000-00-00 00:00:00 Table_priv: Select,Insert,Update,Delete,Create,Drop,References,Index,Alter,Create View,Show view,Trigger Column_priv: 3 rows in set (0.00 sec) ``` 验证:(登录t2账户,看到u1表,看不到u2代表权限成功) ```shell [root@xingdian ~]# mysql -u t2 -pQianFeng@123 mysql: [Warning] Using a password on the command line interface can be insecure. Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 6 Server version: 5.7.39-log MySQL Community Server (GPL) Copyright (c) 2000, 2022, Oracle and/or its affiliates. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> show databases; +--------------------+ | Database | +--------------------+ | information_schema | | t2 | +--------------------+ 2 rows in set (0.00 sec) mysql> use t2; Reading table information for completion of table and column names You can turn off this feature to get a quicker startup with -A Database changed mysql> show tables; +--------------+ | Tables_in_t2 | +--------------+ | u1 | +--------------+ 1 row in set (0.00 sec) ``` ##### Column level ```shell [root@xingdian ~]# mysql -uroot -pQianFeng@123 mysql: [Warning] Using a password on the command line interface can be insecure. Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 7 Server version: 5.7.39-log MySQL Community Server (GPL) Copyright (c) 2000, 2022, Oracle and/or its affiliates. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> select * from mysql.columns_priv\G; Empty set (0.00 sec) mysql> insert into mysql.columns_priv(host,db,user,table_name,column_name,column_priv) values('%','t2','t2','u1','id','select'); Query OK, 1 row affected (0.00 sec) mysql> select * from mysql.columns_priv\G; *************************** 1. row *************************** Host: % Db: t2 User: t2 Table_name: u1 Column_name: id Timestamp: 2022-09-25 15:34:05 Column_priv: Select 1 row in set (0.00 sec) ``` 注意: ​ 前提是有库,有表,有权限 ## 二:用户管理 #### 1.登录和退出 ```shell [root@xingdian ~]# mysql -h 192.168.18.160 -P 30042 -u root -pmysql -e "show databases;" [root@xingdian ~]# mysql -h 192.168.18.160 -P 30042 -u root -pmysql mysql -e "show tables;" -h 指定主机名 【默认为localhost】 -P MySQL服务器端口 【默认3306】 -u 指定用户名 【默认root】 -p 指定登录密码 【默认为空密码】 此处mysql为指定登录的数据库 -e 接SQL语句 (在脚本中使用) ``` #### 2.创建用户 方式一: ```shell mysql> create user xingdian; ERROR 1819 (HY000): Your password does not satisfy the current policy requirements 注意: 该报错是因为密码强度问题,取消密码强度即可创建用户 mysql> create user xingdian@'%' identified by 'QianFeng@123'; Query OK, 0 rows affected (0.00 sec) ``` 方式二: ```shell mysql> grant all on *.* to 'diange'@'localhost' identified by 'QianFeng@123'; Query OK, 0 rows affected, 1 warning (0.00 sec) ``` 注意: ​ 该方式采用授权的方式 ​ ALL 所有权限 select 单独某一个权限(多个权限用逗号隔开) ```shell mysql> grant select on *.* to 'dianye'@'localhost' identified by 'QianFeng@123'; Query OK, 0 rows affected, 1 warning (0.00 sec) ``` ```shell *.* 所有的库所有的表 也可以单独某一个库某一个表 ``` ```shell xingdian@localhost 用户有则授权无则创建 localhost % 10.19.40.% 10.19.40.11 ``` #### 3.删除用户 方式一: ```shell MySQL [(none)]> Drop user xingdian@'%'; Query OK, 0 rows affected (0.00 sec) ``` 方法二: ```shell MySQL [(none)]> delete from mysql.user where user='diandian' AND Host='%'; Query OK, 1 row affected (0.00 sec) ``` #### 4.修改密码 方式一: ```shell [root@xingdian ~]# mysqladmin -uroot -p'123' password 'new_password' //123为旧密码 ``` 方式二: ```shell MySQL [(none)]> update mysql.user set authentication_string=password(123456) where user='diange' And Host='%'; ``` 注意: ​ 刷新授权表后生效:flush privileges 自己设置自己密码: ```shell MySQL [(none)]> set password='123'; Query OK, 0 rows affected (0.00 sec) ``` root用户修改其他用户密码: 方法一: ```shell mysql> SET PASSWORD FOR user3@'localhost'='new_password'; ``` 方法二: ```shell UPDATE mysql.user SET authentication_string=password('new_password') WHERE user='user3' AND host='localhost'; ``` #### 5.查看密码策略 ```shell mysql> SHOW VARIABLES LIKE 'validate_password%'; +--------------------------------------+--------+ | Variable_name | Value | +--------------------------------------+--------+ | validate_password_check_user_name | OFF | | validate_password_dictionary_file | | | validate_password_length | 8 | | validate_password_mixed_case_count | 1 | | validate_password_number_count | 1 | | validate_password_policy | MEDIUM | | validate_password_special_char_count | 1 | +--------------------------------------+--------+ 7 rows in set (0.00 sec) ``` 参数解释: ​ validate_password_dictionary_file 指定密码验证的文件路径 ​ validate_password_length 密码最小长度 ​ validate_password_mixed_case_count 密码至少要包含的小写字母个数和大写字母个数 ​ validate_password_number_count 密码至少要包含的数字个数 ​ validate_password_policy 密码强度检查等级,对应等级为:0/LOW、1/MEDIUM、2/STRONG,默认为1 ​ 0/LOW:只检查长度 ​ 1/MEDIUM:检查长度、数字、大小写、特殊字符 ​ 2/STRONG:检查长度、数字、大小写、特殊字符字典文件 ​ validate_password_special_char_count密码至少要包含的特殊字符数 修改密码策略: ```shell mysql> SHOW VARIABLES LIKE 'validate_password%'; +--------------------------------------+--------+ | Variable_name | Value | +--------------------------------------+--------+ | validate_password_check_user_name | OFF | | validate_password_dictionary_file | | | validate_password_length | 8 | | validate_password_mixed_case_count | 1 | | validate_password_number_count | 1 | | validate_password_policy | MEDIUM | | validate_password_special_char_count | 1 | +--------------------------------------+--------+ 7 rows in set (0.00 sec) mysql> set global validate_password_length=4; Query OK, 0 rows affected (0.00 sec) mysql> SHOW VARIABLES LIKE 'validate_password%'; +--------------------------------------+--------+ | Variable_name | Value | +--------------------------------------+--------+ | validate_password_check_user_name | OFF | | validate_password_dictionary_file | | | validate_password_length | 4 | | validate_password_mixed_case_count | 1 | | validate_password_number_count | 1 | | validate_password_policy | MEDIUM | | validate_password_special_char_count | 1 | +--------------------------------------+--------+ 7 rows in set (0.00 sec) ``` 关闭密码策略: ``` 修改配置文件,添加以下参数: validate_password=off ``` ## 三:数据备份及恢复 #### 1.概述 ​ 所有备份数据都应放在非数据库本地,而且建议有多份副本 备份: 能够防止由于机械故障以及人为误操作带来的数据丢失,例如将数据库文件保存在了其它地方 冗余: 数据有多份冗余,但不等备份,只能防止机械故障还来的数据丢失,例如主备模式、数据库集群 备份考虑的因素: ​ 数据的一致性 ​ 服务的可用性 分类: ​ 逻辑备份 ​ 备份的是建表、建库、插入等操作所执行SQL语句;适用于中小型数据库,效率相对较低(mysqldump) ​ 物理备份 ​ 直接复制数据库文件,适用于大型数据库环境,不受存储引擎的限制,但不能恢复到不同的MySQL版本(tar、xtrabackup) 备份方式分类: ​ 完全备份 ​ 备份所有数据 ​ 增量备份 ​ 每次备份上一次备份到现在产生的新数据 image-20220925184632820 ​ 差异备份 ​ 只备份跟完整备份不一样的 #### 2.tar备份 ​ 注意:备份期间,服务不可用 备份过程:完全物理备份 ​ 停止数据库 ```shell [root@xingdian ~]# systemctl stop mysqld ``` ​ tar备份数据 ```shell [root@xingdian ~]# mkdir /backup [root@xingdian ~]# cd /var/lib/mysql [root@xingdian ~]# tar -zcvf /backup/`date +%F`-mysql-all.tar.gz ./* ``` ​ 启动数据库(备份完成后启动数据库,继续为其他服务提供服务) ```shell [root@xingdian ~]# systemctl start mysqld ``` 恢复过程:模拟数据丢失,恢复数据 ​ 停止数据库 ```shell [root@xingdian ~]# systemctl stop mysqld ``` ​ 清理环境 ```shell [root@xingdian ~]# rm -rf /var/lib/mysql/* ``` ​ 导入备份数据 ```shell [root@xingdian ~]# tar -xvf /backup/2019-08-20-mysql-all.tar.gz -C /usr/lib/mysql [root@xingdian ~]# chown mysql.mysql /var/lib/mysql/* -R ``` ​ 启动数据库(恢复后验证数据是否恢复成功) ```shell [root@xingdian ~]# systemctl start mysqld ``` #### 3.xtrabackup备份 简介: ​ percona-xtrabackup是开源免费的支持MySQL 数据库热备份的软件;能对InnoDB和XtraDB存储引擎的数据库非阻塞地备份;它不暂停服务创建Innodb热备份;为mysql做增量备份;在mysql服务器之间做在线表迁移;使创建replication更加容易;备份mysql而不增加服务器的负载 ![image-20220925185829126](https://xingdian-image.oss-cn-beijing.aliyuncs.com/xingdian-image/image-20220925185829126.png) 安装软件: ```shell [root@xingdian ~]# yum install https://repo.percona.com/yum/percona-release-latest.noarch.rpm -y [root@xingdian ~]# yum install percona-xtrabackup-24 -y ``` ##### 完整备份 ​ 创建备份目录: ```shell [root@xingdian ~]# mkdir -p /xtrabackup/full/ ``` ​ 备份: ```shell [root@xingdian ~]# innobackupex --user=root --password='QianFeng@123' /xtrabackup/full/ ``` ​ 查看备份数据: ```shell [root@xingdian ~]# ls /xtrabackup/full/ 2022-09-25_19-40-47 ``` ​ 模拟数据丢失数据恢复:(以下操作模拟数据丢失) 丢失前数据库中的数据: ```shell [root@xingdian ~]# mysql -u root -pQianFeng@123 mysql: [Warning] Using a password on the command line interface can be insecure. Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 7 Server version: 5.7.39 MySQL Community Server (GPL) Copyright (c) 2000, 2022, Oracle and/or its affiliates. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> show databases; +--------------------+ | Database | +--------------------+ | information_schema | | mysql | | performance_schema | | sys | | t1 | +--------------------+ 5 rows in set (0.00 sec) ``` 数据丢失: ```shell [root@xingdian ~]# systemctl stop mysqld [root@xingdian ~]# rm -rf /var/lib/mysql/* [root@xingdian ~]# rm -rf /var/log/mysqld.log [root@xingdian ~]# rm -rf /var/log/mysql-slow/slow.log (有则删除,无则不需要操作) ``` ​ 恢复前的验证: ```shell [root@xingdian ~]# innobackupex --apply-log /xtrabackup/full/2022-09-25_19-40-47/ ``` ​ 恢复之前需要确认配置文件内有数据库目录指定,不然xtrabackup不知道恢复到哪里 ```shell [root@xingdian ~]# cat /etc/my.cnf datadir=/var/lib/mysql ``` ​ 恢复数据: ```shell [root@xingdian ~]# innobackupex --copy-back /xtrabackup/full/2022-09-25_19-40-47/ ``` ​ 修改权限: ```shell [root@xingdian ~]# chown mysql.mysql /var/lib/mysql -R ``` ​ 启动服务: ```shell [root@xingdian ~]# systemctl start mysqld ``` ​ 验证: ```shell [root@xingdian ~]# mysql -u root -pQianFeng@123 mysql: [Warning] Using a password on the command line interface can be insecure. Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 2 Server version: 5.7.39 MySQL Community Server (GPL) Copyright (c) 2000, 2022, Oracle and/or its affiliates. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> show databases; +--------------------+ | Database | +--------------------+ | information_schema | | mysql | | performance_schema | | sys | | t1 | +--------------------+ 5 rows in set (0.00 sec) ``` ##### 增量备份 原理:每次备份上一次备份到现在产生的新数据 注意:在进行增量备份前先进行完整备份 案例:周一进行全备,周二到周天进行增量备份 ​ 完整备份:(周一) ```shell [root@xingdian ~]# innobackupex --user=root --password='QianFeng@123' /xtrabackup/full ``` ​ 创建增量备份存放数据目录: ```shell [root@xingdian ~]# mkdir /xtrabackup/zeng -p ``` ​ 模拟数据增加(略) ​ 第一次增量备份:(周二) ```shell [root@xingdian ~]# innobackupex --user=root --password='QianFeng@123' --incremental /xtrabackup/zeng/ --incremental-basedir=/xtrabackup/full/2022-09-25_19-40-47/ 第一次增量备份的数据: [root@xingdian ~]# ls /xtrabackup/zeng/ 2022-09-25_19-56-00 ``` ​ 模拟数据增加(略) ​ 第二次增量备份:(周三) ```shell [root@xingdian ~]# innobackupex --user=root --password='QianFeng@123' --incremental /xtrabackup/zeng/ --incremental-basedir=/xtrabackup/zeng/2022-09-25_19-56-00/ 第二次增量备份的数据: [root@xingdian ~]# ls /xtrabackup/zeng/ 2022-09-25_19-56-00 2022-09-25_19-58-12 ``` ​ 后面的增量备份重复上面的操作(略) 增量备份数据恢复流程:(需要模拟数据的丢失) ​ 停止数据库: ```shell [root@xingdian ~]# systemctl stop mysqld ``` ​ 删除数据: ```shell [root@xingdian ~]# rm -rf /var/lib/mysql/* [root@xingdian ~]# rm -rf /var/log/mysqld.log 其他数据根据实际情况删除 ``` ​ 依次重演回滚: ```shell 全备回滚: [root@xingdian ~]# innobackupex --apply-log --redo-only /xtrabackup/full/2022-09-25_19-40-47/ 第一次增量回滚: [root@xingdian ~]# innobackupex --apply-log --redo-only /xtrabackup/full/2022-09-25_19-40-47/ --incremental-dir=/xtrabackup/zeng/2022-09-25_19-56-00/ 第二次增量回滚: [root@xingdian ~]# innobackupex --apply-log --redo-only /xtrabackup/full/2022-09-25_19-40-47/ --incremental-dir=/xtrabackup/zeng/2022-09-25_19-58-12/ 根据实际增量备份的次数回滚,可以想恢复到那个时间节点就回滚到那个时间节点,所有的回滚都给全备 ``` ​ 恢复数据: ```shell [root@xingdian ~]# innobackupex --copy-back /xtrabackup/full/2022-09-25_19-40-47/ ``` ​ 修改权限: ```shell [root@xingdian ~]# chown mysql.mysql /var/lib/mysql -R ``` ​ 启动数据库: ```shell [root@xingdian ~]# systemctl start mysqld ``` ​ 验证: ```shell [root@xingdian ~]# mysql -u root -pQianFeng@123 mysql: [Warning] Using a password on the command line interface can be insecure. Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 2 Server version: 5.7.39 MySQL Community Server (GPL) Copyright (c) 2000, 2022, Oracle and/or its affiliates. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> show databases; +--------------------+ | Database | +--------------------+ | information_schema | | mysql | | performance_schema | | sys | | t1 | | t2 | | t3 | +--------------------+ ``` ##### 差异备份 原理:只备份跟完整备份不一样的 注意:在进行增量备份前先进行完整备份 案例:周一进行全备,周二到周天进行差异备份 ​ 完整备份:(周一) ```shell [root@xingdian ~]# mkdir -p /xtrabackup/full [root@xingdian ~]# innobackupex --user=root --password=QianFeng@123 /xtrabackup/full ``` ​ 模拟数据增加(略) ​ 第一次差异备份:(周二) ```shell [root@xingdian ~]# mkdir -p /xtrabackup/jian [root@xingdian ~]# innobackupex --user=root --password=QianFeng@123 --incremental /xtrabackup/jian --incremental-basedir=/xtrabackup/full/2022-09-25_20-10-52/ 查看第一次差异备份的数据: [root@xingdian ~]# ls /xtrabackup/jian/ 2022-09-25_20-12-55 ``` ​ 模拟数据增加(略) ​ 第二次差异备份:(周三) ```shell [root@xingdian ~]# innobackupex --user=root --password=QianFeng@123 --incremental /xtrabackup/jian --incremental-basedir=/xtrabackup/full/2022-09-25_20-10-52/ 查看第二次差异备份的数据: [root@xingdian ~]# ls /xtrabackup/jian/ 2022-09-25_20-12-55 2022-09-25_20-14-32 注意:后面的差异备份跟之前一样,根据需求可以继续差异备份 ``` 差异备份恢复流程:(模拟数据丢失) ​ 停止数据库: ```shell [root@xingdian ~]# systemctl stop mysqld ``` ​ 删除数据: ```shell [root@xingdian ~]# rm -rf /var/lib/mysql/* [root@xingdian ~]# rm -rf /var/log/mysqld.log ``` ​ 重演数据回滚: ```shell 完整备份回滚: [root@xingdian ~]# innobackupex --apply-log --redo-only /xtrabackup/full/2022-09-25_20-10-52/ 差异备份回滚(根据差异备份的原理,如果恢复所有数据只需要将最后依次差异回滚) [root@xingdian ~]# innobackupex --apply-log --redo-only /xtrabackup/full/2022-09-25_20-10-52/ --incremental-dir=/xtrabackup/jian/2022-09-25_20-14-32/ ``` ​ 恢复数据: ```shell [root@xingdian ~]# innobackupex --copy-back /xtrabackup/full/2022-09-25_20-10-52/ ``` ​ 修改权限: ```shell [root@xingdian ~]# chown mysql.mysql /var/lib/mysql -R ``` ​ 启动数据库: ```shell [root@xingdian ~]# systemctl start mysqld ``` ​ 数据验证: ```shell [root@xingdian ~]# mysql -u root -pQianFeng@123 mysql: [Warning] Using a password on the command line interface can be insecure. Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 2 Server version: 5.7.39 MySQL Community Server (GPL) Copyright (c) 2000, 2022, Oracle and/or its affiliates. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> show databases; +--------------------+ | Database | +--------------------+ | information_schema | | k1 | | k2 | | mysql | | performance_schema | | sys | +--------------------+ 9 rows in set (0.00 sec) ``` #### 4.mysqldump备份 备份表:(前提有库有表) ```shell [root@xingdian ~]# mysqldump -u root -pQianFeng@123 k1 t1 > /t1.sql ``` 恢复表:(恢复之前模拟数据丢失) ```shell [root@xingdian ~]# mysql -u root -pQianFeng@123 k1 < /t1.sql mysql: [Warning] Using a password on the command line interface can be insecure. ``` 验证: ```shell [root@xingdian ~]# mysql -u root -pQianFeng@123 -e "use k1;show tables" mysql: [Warning] Using a password on the command line interface can be insecure. +--------------+ | Tables_in_k1 | +--------------+ | t1 | +--------------+ ``` 备份一个库: ```shell [root@xingdian ~]# mysqldump -u root -pQianFeng@123 k1 > /k1.sql ``` 备份多个库: ```shell [root@xingdian ~]# mysqldump -u root -pQianFeng@123 -B k1 k2 > /kall.sql ``` 备份所有库: ```shell [root@xingdian ~]# mysqldump -u root -pQianFeng@123 -A > /all.sql ``` 数据恢复: ​ 为保证数据一致性,应在恢复数据之前停止数据库对外的服务,停止binlog日志 ​ binlog使用binlog日志恢复数据时也会产生binlog日志(如果开启的话,需要关闭) ```shell mysql> set sql_log_bin=0; Query OK, 0 rows affected (0.00 sec) ``` ​ 模拟数据丢失(略) ```shell [root@xingdian ~]# mysql -u root -pQianFeng@123 -D k1 < /k1.sql mysql: [Warning] Using a password on the command line interface can be insecure. ERROR 1049 (42000): Unknown database 'k1' 出现该错误是因为在恢复的时候需要有库的存在 [root@xingdian ~]# mysql -u root -pQianFeng@123 -e "create database k1" [root@xingdian ~]# mysql -u root -pQianFeng@123 -D k1 < /k1.sql [root@xingdian ~]# mysql -u root -pQianFeng@123 -e "create database k1" [root@xingdian ~]# mysql -u root -pQianFeng@123 -e "create database k2" [root@xingdian ~]# mysql -u root -pQianFeng@123 -D k1 k2 < /kall.sql 或者 mysql> source /k1.sql ``` 验证: ```shell [root@xingdian ~]# mysql -u root -pQianFeng@123 -e "use k1; show tables;" mysql: [Warning] Using a password on the command line interface can be insecure. +--------------+ | Tables_in_k1 | +--------------+ | t1 | +--------------+ [root@xingdian ~]# mysql -u root -pQianFeng@123 -e "use k2; show tables;" mysql: [Warning] Using a password on the command line interface can be insecure. +--------------+ | Tables_in_k2 | +--------------+ | t1 | +--------------+ ``` #### 5.binlog日志备份 原理:日志方法备份恢复数据 日志默认存储位置: ​ rpm : /var/lib/mysql ​ 编译: 安装目录的var下 产生日志: ​ 方式一:编译安装 ```shell [root@xingdian ~]# mysqld_safe --log-bin --user=mysql --server-id=1 & 查看binlog日志 [root@xingdian ~]# mysqlbinlog slave2-bin.000001 -v --base64-output=decode-rows 时间点 : 141126 14:04:49 位置点 : at 106 ``` ​ 方式二:rpm安装(永久) ```shell [root@xingdian ~]# vim /etc/my.cnf log-bin=mylog server-id=1 //做主从复制使用 [root@xingdian ~]# systemctl restart mysqld 查看: [root@xingdian ~]# ls /var/lib/mysql auto.cnf client-key.pem ib_logfile1 mysql private_key.pem sys ca-key.pem ib_buffer_pool ibtmp1 mysql.sock public_key.pem xingdian-bin.index ca.pem ibdata1 mylog.000001 mysql.sock.lock server-cert.pem xtrabackup_info client-cert.pem ib_logfile0 mylog.index [root@xingdian ~]# mysqlbinlog /var/lib/mysql/mylog.000001 -v --base64-output=decode-rows /*!50530 SET @@SESSION.PSEUDO_SLAVE_MODE=1*/; /*!50003 SET @OLD_COMPLETION_TYPE=@@COMPLETION_TYPE,COMPLETION_TYPE=0*/; DELIMITER /*!*/; # at 4 #220925 21:12:47 server id 1 end_log_pos 123 CRC32 0x52358645 Start: binlog v 4, server v 5.7.39-log created 220925 21:12:47 at startup # Warning: this binlog is either in use or was not closed properly. ROLLBACK/*!*/; # at 123 #220925 21:12:47 server id 1 end_log_pos 154 CRC32 0xa84d8536 Previous-GTIDs # [empty] # at 154 #220925 21:13:38 server id 1 end_log_pos 219 CRC32 0xc2b00431 Anonymous_GTID last_committed=0 sequence_number=1 rbr_only=no SET @@SESSION.GTID_NEXT= 'ANONYMOUS'/*!*/; # at 219 #220925 21:13:38 server id 1 end_log_pos 307 CRC32 0x635401a5 Query thread_id=2 exec_time=0 error_code=0 SET TIMESTAMP=1664111618/*!*/; SET @@session.pseudo_thread_id=2/*!*/; SET @@session.foreign_key_checks=1, @@session.sql_auto_is_null=0, @@session.unique_checks=1, @@session.autocommit=1/*!*/; SET @@session.sql_mode=1436549152/*!*/; SET @@session.auto_increment_increment=1, @@session.auto_increment_offset=1/*!*/; /*!\C utf8 *//*!*/; SET @@session.character_set_client=33,@@session.collation_connection=33,@@session.collation_server=8/*!*/; SET @@session.lc_time_names=0/*!*/; SET @@session.collation_database=DEFAULT/*!*/; create database t1 /*!*/; SET @@SESSION.GTID_NEXT= 'AUTOMATIC' /* added by mysqlbinlog */ /*!*/; DELIMITER ; # End of log file /*!50003 SET COMPLETION_TYPE=@OLD_COMPLETION_TYPE*/; /*!50530 SET @@SESSION.PSEUDO_SLAVE_MODE=0*/; 方法二: mysql> show binlog events in "mylog.000001"; +--------------+-----+----------------+-----------+-------------+---------------------------------------+ | Log_name | Pos | Event_type | Server_id | End_log_pos | Info | +--------------+-----+----------------+-----------+-------------+---------------------------------------+ | mylog.000001 | 4 | Format_desc | 1 | 123 | Server ver: 5.7.39-log, Binlog ver: 4 | | mylog.000001 | 123 | Previous_gtids | 1 | 154 | | | mylog.000001 | 154 | Anonymous_Gtid | 1 | 219 | SET @@SESSION.GTID_NEXT= 'ANONYMOUS' | | mylog.000001 | 219 | Query | 1 | 307 | create database t1 | +--------------+-----+----------------+-----------+-------------+---------------------------------------+ 4 rows in set (0.00 sec) 默认查看第一个 mysql> show binlog events; +--------------+-----+----------------+-----------+-------------+---------------------------------------+ | Log_name | Pos | Event_type | Server_id | End_log_pos | Info | +--------------+-----+----------------+-----------+-------------+---------------------------------------+ | mylog.000001 | 4 | Format_desc | 1 | 123 | Server ver: 5.7.39-log, Binlog ver: 4 | | mylog.000001 | 123 | Previous_gtids | 1 | 154 | | | mylog.000001 | 154 | Anonymous_Gtid | 1 | 219 | SET @@SESSION.GTID_NEXT= 'ANONYMOUS' | | mylog.000001 | 219 | Query | 1 | 307 | create database t1 | +--------------+-----+----------------+-----------+-------------+---------------------------------------+ 4 rows in set (0.00 sec) ``` 数据恢复: ​ 根据时间点恢复数据: ```shell [root@xingdian ~]# mysqlbinlog --start-datetime='2022-9-25 21:12:47' --stop-datetime='2022-9-25 21:16:55' /var/lib/mysql/mylog.000001 | mysql -u root -pQianFeng@123 ``` ​ 根据位置点恢复数据: ```shell mysql> show binlog events; +--------------+-----+----------------+-----------+-------------+---------------------------------------+ | Log_name | Pos | Event_type | Server_id | End_log_pos | Info | +--------------+-----+----------------+-----------+-------------+---------------------------------------+ | mylog.000001 | 4 | Format_desc | 1 | 123 | Server ver: 5.7.39-log, Binlog ver: 4 | | mylog.000001 | 123 | Previous_gtids | 1 | 154 | | | mylog.000001 | 154 | Anonymous_Gtid | 1 | 219 | SET @@SESSION.GTID_NEXT= 'ANONYMOUS' | | mylog.000001 | 219 | Query | 1 | 307 | create database t1 | | mylog.000001 | 307 | Anonymous_Gtid | 1 | 372 | SET @@SESSION.GTID_NEXT= 'ANONYMOUS' | | mylog.000001 | 372 | Query | 1 | 453 | drop database t1 | | mylog.000001 | 453 | Anonymous_Gtid | 1 | 518 | SET @@SESSION.GTID_NEXT= 'ANONYMOUS' | | mylog.000001 | 518 | Query | 1 | 606 | create database t1 | | mylog.000001 | 606 | Anonymous_Gtid | 1 | 671 | SET @@SESSION.GTID_NEXT= 'ANONYMOUS' | | mylog.000001 | 671 | Query | 1 | 752 | drop database t1 | +--------------+-----+----------------+-----------+-------------+---------------------------------------+ [root@xingdian ~]# mysqlbinlog --start-position 219 --stop-position 307 /var/lib/mysql/mylog.000001 | mysql -u root -pQianFeng@123 ```