当前位置:   article > 正文

MySQL 8.0从库某些情况下记录重放的CREATE TABLE、DROP TABLE语句到慢日志(slow log)

MySQL 8.0从库某些情况下记录重放的CREATE TABLE、DROP TABLE语句到慢日志(slow log)

问题描述

主从复制采用 binlog 的行模式时,如果从库启用 slow_query_log、log_slow_replica_statements 且从库重放 CREATE TABLE、DROP TABLE 时因特殊情况(比如被从库其他 SQL 占用 MDL 锁)执行耗时较长,会被从库记录到慢日志(slow log),而 ALTER TABLE 却不会被记录到慢日志。

ALTER TABLE 等管理语句是否会记录到慢日志,受参数 slow_query_log、log_slow_admin_statements 控制。

本文基于 MySQL 8.0.30 版本。

复现步骤

1. 搭建主从复制

主(master)、从(replica)my.cnf 中启用 binlog 的行模式:

binlog_format=ROW # 行模式

2. 从库动态设置配置参数

  1. set global long_query_time=0.0001;
  2. # 当然,除了这种方法,还有另一种方法:
  3. # 主库执行DROP TABLE db1.tbl 语句之前,在从库先用事务阻塞住 DROP TABLE db1.tbl 的重放(会处于 Waiting for table metadata lock 状态):
  4. # begin; select count(*) from db1.tbl for update;
  5. # 等待几秒后(大于long_query_time的配置即可),再 commit
  6. set global slow_query_log=on;
  7. set global log_slow_replica_statements=on;
  8. mysql> show variables like '%slow%';
  9. +-----------------------------+----------------------------------------------------------+
  10. | Variable_name | Value |
  11. +-----------------------------+----------------------------------------------------------+
  12. | log_slow_admin_statements | OFF |
  13. | log_slow_extra | OFF |
  14. | log_slow_replica_statements | ON |
  15. | log_slow_slave_statements | ON |
  16. | slow_launch_time | 2 |
  17. | slow_query_log | ON |
  18. | slow_query_log_file | /home/wslu/work/mysql/mysql80-data/s1-slave1/vm-slow.log |
  19. +-----------------------------+----------------------------------------------------------+
  20. 7 rows in set (0.01 sec)

3. 主库执行 SQL 语句

  1. CREATE TABLE db1.tbl(a int, b int);
  2. DROP TABLE db1.tbl;

4. 查看从库慢日志

查看从库slow_query_log_file参数指定的慢日志文件,其中出现 DROP TABLE 语句:

  1. # Time: 2023-11-30T09:36:32.202303+08:00
  2. # User@Host: skip-grants user[] @ [] Id: 41
  3. # Query_time: 0.060373 Lock_time: 0.000143 Rows_sent: 0 Rows_examined: 0
  4. SET timestamp=1701308185;
  5. CREATE TABLE `tbl` (
  6. `my_row_id` bigint unsigned NOT NULL AUTO_INCREMENT /*!80023 INVISIBLE */,
  7. `a` int DEFAULT NULL,
  8. `b` int DEFAULT NULL,
  9. PRIMARY KEY (`my_row_id`)
  10. );
  11. # Time: 2023-11-30T09:36:37.768072+08:00
  12. # User@Host: skip-grants user[] @ [] Id: 41
  13. # Query_time: 0.025328 Lock_time: 0.000089 Rows_sent: 0 Rows_examined: 0
  14. SET timestamp=1701308197;
  15. DROP TABLE `tbl` /* generated by server */;

初步分析

这与官方对 log_slow_slave_statements 参数的描述不符

When the slow query log is enabled, log_slow_replica_statements enables logging for queries that have taken more than long_query_time seconds to execute on the replica. Note that if row-based replication is in use (binlog_format=ROW), log_slow_replica_statements has no effect. Queries are only added to the replica's slow query log when they are logged in statement format in the binary log, that is, when binlog_format=STATEMENT is set, or when binlog_format=MIXED is set and the statement is logged in statement format. Slow queries that are logged in row format when binlog_format=MIXED is set, or that are logged when binlog_format=ROW is set, are not added to the replica's slow query log, even if log_slow_replica_statements is enabled.

Setting log_slow_replica_statements has no immediate effect. The state of the variable applies on all subsequent START REPLICA statements. Also note that the global setting for long_query_time applies for the lifetime of the SQL thread. If you change that setting, you must stop and restart the replication SQL thread to implement the change there (for example, by issuing STOP REPLICA and START REPLICA statements with the SQL_THREAD option).

按照官方的描述,在 binlog_format 是行模式的情况下,即使启用log_slow_replica_statements 参数,从库重放时也不该产生慢日志。

补充说明

按照上述同样的步骤执行 ALTER TABLE 语句,则不会记录到 slow log

通过阅读手册及自行验证,ALTER TABLE 等管理语句是否记录到从库的 slow log 受参数log_slow_admin_statements控制。

log_slow_admin_statements

Include slow administrative statements in the statements written to the slow query log. Administrative statements include ALTER TABLEANALYZE TABLECHECK TABLECREATE INDEXDROP INDEXOPTIMIZE TABLE, and REPAIR TABLE.

代码解读

函数堆栈:

  1. #0 Query_logger::slow_log_write (this=0xaaaaef99e760 <query_logger>, thd=0xffff3c291be0, query=0xffff34165cb8 "DROP TABLE `tbl` /* generated by server */",
  2. query_length=42, aggregate=false, lock_usec=0, exec_usec=0) at /home/wslu/work/mysql/mac-mysql-server/sql/log.cc:1334
  3. #1 0x0000aaaaead81368 in log_slow_do (thd=0xffff3c291be0) at /home/wslu/work/mysql/mac-mysql-server/sql/log.cc:1643
  4. #2 0x0000aaaaead813a0 in log_slow_statement (thd=0xffff3c291be0) at /home/wslu/work/mysql/mac-mysql-server/sql/log.cc:1660
  5. #3 0x0000aaaaeb9ce438 in Query_log_event::do_apply_event (this=0xffff341ce540, rli=0xffff3402ad80,
  6. query_arg=0xffff34165cb8 "DROP TABLE `tbl` /* generated by server */", q_len_arg=42) at /home/wslu/work/mysql/mac-mysql-server/sql/log_event.cc:4884
  7. #4 0x0000aaaaeb9cc840 in Query_log_event::do_apply_event (this=0xffff341ce540, rli=0xffff3402ad80)
  8. at /home/wslu/work/mysql/mac-mysql-server/sql/log_event.cc:4447
  9. #5 0x0000aaaaeb9f43c4 in Log_event::do_apply_event_worker (this=0xffff341ce540, w=0xffff3402ad80)
  10. at /home/wslu/work/mysql/mac-mysql-server/sql/log_event.cc:1087
  11. #6 0x0000aaaaebacb3a4 in Slave_worker::slave_worker_exec_event (this=0xffff3402ad80, ev=0xffff341ce540)
  12. at /home/wslu/work/mysql/mac-mysql-server/sql/rpl_rli_pdb.cc:1733
  13. #7 0x0000aaaaebacda04 in slave_worker_exec_job_group (worker=0xffff3402ad80, rli=0xaaab2f98d4d0)
  14. at /home/wslu/work/mysql/mac-mysql-server/sql/rpl_rli_pdb.cc:2457
  15. #8 0x0000aaaaebae84d4 in handle_slave_worker (arg=0xffff3402ad80) at /home/wslu/work/mysql/mac-mysql-server/sql/rpl_replica.cc:5913
  16. #9 0x0000aaaaec8356f0 in pfs_spawn_thread (arg=0xffff784dd4e0) at /home/wslu/work/mysql/mac-mysql-server/storage/perfschema/pfs.cc:2942
  17. #10 0x0000ffff928bd5c8 in start_thread (arg=0x0) at ./nptl/pthread_create.c:442
  18. #11 0x0000ffff92925d1c in thread_start () at ../sysdeps/unix/sysv/linux/aarch64/clone.S:79

最终会调用Query_logger::slow_log_write函数:

  1. bool Query_logger::slow_log_write(THD *thd, const char *query,
  2. size_t query_length, bool aggregate,
  3. ulonglong lock_usec, ulonglong exec_usec) {
  4. assert(thd->enable_slow_log && opt_slow_log);
  5. if (!(*slow_log_handler_list)) return false;
  6. /* do not log slow queries from replication threads */
  7. if (thd->slave_thread && !opt_log_slow_replica_statements) return false; // ====> 关键位置
  8. /* fill in user_host value: the format is "%s[%s] @ %s [%s]" */
  9. char user_host_buff[MAX_USER_HOST_SIZE + 1];
  10. Security_context *sctx = thd->security_context();
  11. LEX_CSTRING sctx_user = sctx->user();
  12. LEX_CSTRING sctx_host = sctx->host();
  13. LEX_CSTRING sctx_ip = sctx->ip();
  14. size_t user_host_len =
  15. (strxnmov(user_host_buff, MAX_USER_HOST_SIZE, sctx->priv_user().str, "[",
  16. sctx_user.length ? sctx_user.str : "", "] @ ",
  17. sctx_host.length ? sctx_host.str : "", " [",
  18. sctx_ip.length ? sctx_ip.str : "", "]", NullS) -
  19. user_host_buff);
  20. ulonglong current_utime = my_micro_time();
  21. ulonglong query_utime, lock_utime;
  22. if (aggregate) {
  23. query_utime = exec_usec;
  24. lock_utime = lock_usec;
  25. } else if (thd->start_utime) {
  26. query_utime = (current_utime - thd->start_utime);
  27. lock_utime = thd->get_lock_usec();
  28. } else {
  29. query_utime = 0;
  30. lock_utime = 0;
  31. }
  32. bool is_command = false;
  33. if (!query) {
  34. is_command = true;
  35. const std::string &cn = Command_names::str_global(thd->get_command());
  36. query = cn.c_str();
  37. query_length = cn.length();
  38. }
  39. mysql_rwlock_rdlock(&LOCK_logger);
  40. bool error = false;
  41. for (Log_event_handler **current_handler = slow_log_handler_list;
  42. *current_handler;) {
  43. error |= (*current_handler++)
  44. ->log_slow(thd, current_utime,
  45. (thd->start_time.tv_sec * 1000000ULL) +
  46. thd->start_time.tv_usec,
  47. user_host_buff, user_host_len, query_utime,
  48. lock_utime, is_command, query, query_length); // 写慢日志
  49. }
  50. mysql_rwlock_unlock(&LOCK_logger);
  51. return error;
  52. }

结论

我查看了 8.0.31-8.0.35 版本的 change log,其中并无对DROP TABLE相关的 Bug Fix,说明该问题官方尚未修复。

可行的修改思路有两种:

  1. 比较直接的方式是修改Query_logger::slow_log_write函数中的逻辑,添加额外的条件判断(见后文)。
  2. 借鉴参数log_slow_admin_statements的处理逻辑。如果启用log_slow_admin_statements参数且管理语句执行时长大于 long_query_time,则会将其记录到慢日志,最终也会调用到Query_logger::slow_log_write函数;反之,如果未启用该参数,则不会记录管理语句到慢日志。这说明是在中间过程中判断并过滤的,本文不再展开说明。

公司同事向官方提交了 BUG,官方已经确认,其中的 patch 采用的思路 1:

MySQL Bugs: #113251: the slow log in slave is logged ,when binlog_format is row

  1. --- a/sql/log.cc
  2. +++ b/sql/log.cc
  3. @@ -1295,6 +1295,9 @@ bool Query_logger::slow_log_write(THD *t
  4. /* do not log slow queries from replication threads */
  5. if (thd->slave_thread && !opt_log_slow_replica_statements) return false;
  6. + /*when binlog_format=MIXED is set, or that are logged when binlog_format=ROW is set, are not added to the replica's slow query log, even if log_slow_replica_statements is enabled.*/
  7. + if (thd->slave_thread && opt_log_slow_replica_statements && (thd->current_stmt_binlog_format == BINLOG_FORMAT_MIXED ||thd->current_stmt_binlog_format == BINLOG_FORMAT_ROW) ) return false;
  8. +
  9. /* fill in user_host value: the format is "%s[%s] @ %s [%s]" */
  10. char user_host_buff[MAX_USER_HOST_SIZE + 1];
  11. Security_context *sctx = thd->security_context();

声明:本文内容由网友自发贡献,不代表【wpsshop博客】立场,版权归原作者所有,本站不承担相应法律责任。如您发现有侵权的内容,请联系我们。转载请注明出处:https://www.wpsshop.cn/w/繁依Fanyi0/article/detail/534682
推荐阅读
相关标签
  

闽ICP备14008679号