long_query_time=1
时(表info的id为主键),出现下面的慢日志,可能会让你吃惊
# Time: 2024-01-28T22:52:24.500491+08:00
# User@Host: root[root] @ [127.0.0.1] Id: 8
# Query_time: 7.760787 Lock_time: 7.757456 Rows_sent: 0 Rows_examined: 0
use apple;
SET
timestamp=;
delete
from info where
id < ;
greatsql> select * from performance_schema.global_variables where variable_name in('slow_query_log','log_output','slow_query_log_file','long_query_time','log_queries_not_using_indexes','log_slow_admin_statements','min_examined_row_limit','log_throttle_queries_not_using_indexes') order
by variable_name;
+----------------------------------------+-------------------------------------+
| VARIABLE_NAME | VARIABLE_VALUE |
+----------------------------------------+-------------------------------------+
| log_output | FILE |
| log_queries_not_using_indexes | OFF |
| log_slow_admin_statements | OFF |
| log_throttle_queries_not_using_indexes | 0 |
| long_query_time | 1.000000 |
| min_examined_row_limit | 0 |
| slow_query_log | ON |
| slow_query_log_file | /root/local/8026/log/slow.log |
+----------------------------------------+-------------------------------------+
8 rows in set (10.49 sec)
slow_query_log
:慢日志开关log_output
:慢日志存储方式,FILE或TABLElong_query_time
:慢日志阈值min_examined_row_limit
:设置慢SQL的最小examined扫描行数,建议设置为0,因为有bug:https://bugs.mysql.com/bug.php?id=110804log_queries_not_using_indexes
:不使用索引的慢查询日志是否记录到索引log_slow_admin_statements
:在写入慢速查询日志的语句中包含慢速管理语句(create index,drop index,alter table,analyze table,check table,optimize table,repair table)
默认是不会记录的log_throttle_queries_not_using_indexes
:用于限制每分钟输出未使用索引的日志数量。每分钟允许记录到slow log的且未使用索引的sql语句次数,配合long_queries_not_using_indexes开启使用。log_slow_slave_statements
:默认OFF,是否开启主从复制中从库的慢查询void
THD::update_slow_query_status()
{
if (my_micro_time() > utime_after_lock + variables.long_query_time)
server_status | = SERVER_QUERY_WAS_SLOW;
}
// my_micro_time() 获取当前系统时间点,单位为微妙
// utime_after_lock 为MDL LOCK和row lock等待时间后的时间点,单位为微妙
// variables.long_query_time 慢日志阈值long_query_time * 1000000 ,单位为微妙
// 等价于:my_micro_time() - utime_after_lock > variables.long_query_time
// 不包含锁等待时间
void
THD::update_slow_query_status()
{
if (my_micro_time() > start_utime + variables.long_query_time)
server_status | = SERVER_QUERY_WAS_SLOW;
}
// 判别标准变成了:(语句执行结束的时间 - 语句开始执行时间) > 慢日志阈值
// my_micro_time() 当前系统时间点,单位为微妙
// start_utime:语句开始执行时间点,单位为微妙
// variables.long_query_time 慢日志阈值long_query_time * 1000000 ,单位为微妙
// 包含锁等待时间
从上面可以看出慢日志的判断标准发生了根本变化
举例说明
greatsql> select * from info;
+----+------+
| id | name |
+----+------+
| 1 | 1 |
| 2 | 2 |
| 5 | 5 |
| 60 | 8 |
| 40 | 11 |
| 20 | 20 |
| 30 | 30 |
+----+------+
7 rows in set (0.05 sec)
greatsql> show
create
table info\G
*************************** 1.
row ***************************
Table: info
Create
Table: CREATE
TABLE
`info` (
`id`
int
NOT
NULL AUTO_INCREMENT,
`name`
int
NOT
NULL,
PRIMARY KEY (`id`),
UNIQUE
KEY
`uk_name` (`name`)
) ENGINE=InnoDB AUTO_INCREMENT=61
DEFAULT
CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
1
row
in
set (0.02 sec)
session1session2begin;
delete from info where id < 10;
delete from info where id < 10;session1等待一段时间超过慢日志阈值long_query_time
rollback;
• 在8.0.26版本中,是不会记录session2中的delete from info where id < 10
• 在8.0.32版本中,会记录session2中的delete from info where id < 10
三、判断是否写入慢日志
void
log_slow_statement(THD *thd,
struct System_status_var *query_start_status)
{
if (log_slow_applicable(thd)) log_slow_do(thd, query_start_status);
}
//----------------------------------------------------------------
bool
log_slow_applicable(THD *thd)
{
DBUG_TRACE;
/*
The following should never be true with our current code base,
but better to keep this here so we don't accidently try to log a
statement in a trigger or stored function
*/
if (unlikely(thd->in_sub_stmt)) return
false; // Don't set time for sub stmt
if (unlikely(thd->killed == THD::KILL_CONNECTION)) return
false;
/*
Do not log administrative statements unless the appropriate option is
set.
*/
if (thd->enable_slow_log && opt_slow_log) {
bool warn_no_index =
((thd->server_status &
(SERVER_QUERY_NO_INDEX_USED | SERVER_QUERY_NO_GOOD_INDEX_USED)) &&
opt_log_queries_not_using_indexes &&
!(sql_command_flags[thd->lex->sql_command] & CF_STATUS_COMMAND));
bool log_this_query =
((thd->server_status & SERVER_QUERY_WAS_SLOW) || warn_no_index) &&
(thd->get_examined_row_count() >=
thd->variables.min_examined_row_limit);
bool suppress_logging = log_throttle_qni.log(thd, warn_no_index);
if (!suppress_logging && log_this_query) return
true;
}
return
false;
}
a. 子查询,返回false b. 被kill,返回false c. 解析出错,返回false d. 执行出错,返回false
按照线上配置
那么在GreatSQL 8.0.26中,是否写入到慢日志中,取决于thd->server_status & SERVER_QUERY_WAS_SLOW
,即SQL执行总耗时-SQL锁等待耗时>1秒(简单说:【不】包含锁等待耗时)。
那么在GreatSQL 8.0.32中,是否写入到慢日志中,取决于thd->server_status & SERVER_QUERY_WAS_SLOW
,即SQL执行总耗时>1秒(简单说:【会】包含锁等待耗时)。
P.S,八怪老师也写过一篇这方面的文章:MySQL:8.0.28及其之后慢查询记录算法的重大变化,推荐也看看。
Enjoy GreatSQL :)