MySQL性能调优实战指南:系统级优化与监控策略
Orion K Lv6

MySQL性能调优是一个系统性工程,涉及硬件配置、系统参数、数据库配置等多个层面。本文将从实战角度详细介绍MySQL性能调优的方法和技巧。

性能分析基础

1. 性能指标监控

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
-- 查看MySQL运行状态
SHOW STATUS;

-- 关键性能指标
SHOW STATUS LIKE 'Connections';
SHOW STATUS LIKE 'Threads_connected';
SHOW STATUS LIKE 'Threads_running';
SHOW STATUS LIKE 'Queries';
SHOW STATUS LIKE 'Questions';
SHOW STATUS LIKE 'Slow_queries';

-- 查看缓冲池状态
SHOW STATUS LIKE 'Innodb_buffer_pool%';

-- 查看锁等待统计
SHOW STATUS LIKE 'Innodb_row_lock%';

-- 查看临时表使用情况
SHOW STATUS LIKE 'Created_tmp%';

-- 查看排序操作统计
SHOW STATUS LIKE 'Sort%';

-- 查看表扫描统计
SHOW STATUS LIKE 'Select_scan';
SHOW STATUS LIKE 'Select_full_join';

2. 性能瓶颈识别

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
-- 使用 Performance Schema 分析性能
-- 启用性能监控
UPDATE performance_schema.setup_instruments
SET ENABLED = 'YES', TIMED = 'YES'
WHERE NAME LIKE '%statement/%' OR NAME LIKE '%stage/%';

UPDATE performance_schema.setup_consumers
SET ENABLED = 'YES'
WHERE NAME LIKE '%events_statements%' OR NAME LIKE '%events_stages%';

-- 查看最耗时的SQL语句
SELECT
DIGEST_TEXT,
COUNT_STAR as exec_count,
AVG_TIMER_WAIT/1000000000 as avg_time_sec,
SUM_TIMER_WAIT/1000000000 as total_time_sec,
AVG_ROWS_EXAMINED,
AVG_ROWS_SENT
FROM performance_schema.events_statements_summary_by_digest
ORDER BY SUM_TIMER_WAIT DESC
LIMIT 10;

-- 查看IO等待最多的表
SELECT
OBJECT_SCHEMA,
OBJECT_NAME,
COUNT_READ,
COUNT_WRITE,
SUM_TIMER_READ/1000000000 as read_time_sec,
SUM_TIMER_WRITE/1000000000 as write_time_sec
FROM performance_schema.table_io_waits_summary_by_table
WHERE OBJECT_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema')
ORDER BY SUM_TIMER_READ + SUM_TIMER_WRITE DESC
LIMIT 10;

-- 查看锁等待情况
SELECT
OBJECT_SCHEMA,
OBJECT_NAME,
COUNT_STAR,
SUM_TIMER_WAIT/1000000000 as wait_time_sec,
AVG_TIMER_WAIT/1000000000 as avg_wait_sec
FROM performance_schema.table_lock_waits_summary_by_table
WHERE COUNT_STAR > 0
ORDER BY SUM_TIMER_WAIT DESC;

硬件和系统优化

1. 硬件配置建议

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
#!/bin/bash
# 系统硬件信息检查脚本

echo "=== MySQL服务器硬件配置检查 ==="

# CPU信息
echo "CPU信息:"
lscpu | grep -E "CPU\(s\)|Model name|CPU MHz"

# 内存信息
echo -e "\n内存信息:"
free -h
echo "建议: MySQL服务器内存应为数据库大小的1.5-2倍"

# 磁盘信息
echo -e "\n磁盘信息:"
df -h
lsblk

# 磁盘IO性能测试
echo -e "\n磁盘IO性能测试:"
echo "随机读测试:"
fio --name=random-read --ioengine=libaio --iodepth=16 --rw=randread --bs=4k --direct=1 --size=1G --numjobs=1 --runtime=60 --group_reporting

echo "随机写测试:"
fio --name=random-write --ioengine=libaio --iodepth=16 --rw=randwrite --bs=4k --direct=1 --size=1G --numjobs=1 --runtime=60 --group_reporting

# 网络信息
echo -e "\n网络信息:"
ip addr show
ss -tuln | grep 3306

echo -e "\n硬件优化建议:"
echo "1. CPU: 推荐使用多核心处理器,MySQL 8.0对多核支持更好"
echo "2. 内存: 足够的内存用于InnoDB缓冲池,建议至少8GB"
echo "3. 存储: 使用SSD存储,特别是数据目录和日志目录"
echo "4. 网络: 千兆网络,低延迟连接"

2. 操作系统优化

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
#!/bin/bash
# Linux系统优化脚本

echo "=== MySQL系统优化配置 ==="

# 1. 内核参数优化
cat >> /etc/sysctl.conf << EOF
# MySQL优化参数
vm.swappiness = 1
vm.dirty_ratio = 15
vm.dirty_background_ratio = 5
net.core.somaxconn = 65535
net.core.netdev_max_backlog = 5000
net.ipv4.tcp_max_syn_backlog = 65535
net.ipv4.tcp_fin_timeout = 10
net.ipv4.tcp_tw_reuse = 1
net.ipv4.tcp_tw_recycle = 1
fs.file-max = 6815744
EOF

# 应用内核参数
sysctl -p

# 2. 文件描述符限制
cat >> /etc/security/limits.conf << EOF
mysql soft nofile 65535
mysql hard nofile 65535
mysql soft nproc 65535
mysql hard nproc 65535
EOF

# 3. 磁盘调度器优化
echo "检查磁盘调度器:"
for disk in $(lsblk -d -o name | grep -v NAME); do
echo "$disk: $(cat /sys/block/$disk/queue/scheduler)"
# 对于SSD,推荐使用noop或deadline
echo noop > /sys/block/$disk/queue/scheduler
done

# 4. 透明大页禁用
echo never > /sys/kernel/mm/transparent_hugepage/enabled
echo never > /sys/kernel/mm/transparent_hugepage/defrag

# 5. CPU频率调节器
echo performance > /sys/devices/system/cpu/cpu*/cpufreq/scaling_governor

echo "系统优化完成,建议重启系统使所有配置生效"

MySQL配置优化

1. InnoDB存储引擎优化

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
# my.cnf InnoDB优化配置
[mysqld]
# 基础配置
default_storage_engine = InnoDB
innodb_file_per_table = 1

# 缓冲池配置 (最重要的参数)
# 建议设置为系统内存的70-80%
innodb_buffer_pool_size = 8G
innodb_buffer_pool_instances = 8
innodb_buffer_pool_chunk_size = 128M

# 日志配置
innodb_log_file_size = 1G
innodb_log_files_in_group = 2
innodb_log_buffer_size = 64M
innodb_flush_log_at_trx_commit = 1

# 刷新配置
innodb_flush_method = O_DIRECT
innodb_flush_neighbors = 0 # SSD设置为0,HDD设置为1

# IO配置
innodb_io_capacity = 2000 # SSD: 2000-20000, HDD: 200
innodb_io_capacity_max = 4000
innodb_read_io_threads = 8
innodb_write_io_threads = 8

# 锁配置
innodb_lock_wait_timeout = 50
innodb_deadlock_detect = 1

# 其他优化
innodb_adaptive_hash_index = 1
innodb_change_buffering = all
innodb_old_blocks_time = 1000
innodb_stats_on_metadata = 0

# MySQL 8.0+ 特定配置
innodb_dedicated_server = 1 # 自动配置InnoDB参数
innodb_redo_log_capacity = 2G # MySQL 8.0.30+

2. 查询缓存和连接优化

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
# 连接和缓存配置
[mysqld]
# 连接配置
max_connections = 1000
max_connect_errors = 100000
connect_timeout = 10
interactive_timeout = 28800
wait_timeout = 28800
thread_cache_size = 64
back_log = 512

# 查询缓存 (MySQL 5.7, MySQL 8.0已移除)
# query_cache_type = 1
# query_cache_size = 256M
# query_cache_limit = 2M

# 临时表配置
tmp_table_size = 256M
max_heap_table_size = 256M

# 排序和分组缓冲区
sort_buffer_size = 2M
read_buffer_size = 1M
read_rnd_buffer_size = 2M
join_buffer_size = 2M

# 批量插入缓冲区
bulk_insert_buffer_size = 64M

# 表缓存
table_open_cache = 4000
table_definition_cache = 2000

# 二进制日志配置
log_bin = mysql-bin
binlog_format = ROW
sync_binlog = 1
expire_logs_days = 7
max_binlog_size = 1G

3. 动态配置调整

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
-- 运行时动态调整参数
-- 注意:这些设置重启后会丢失,需要写入my.cnf永久保存

-- InnoDB缓冲池相关
SET GLOBAL innodb_buffer_pool_size = 8589934592; -- 8GB
-- MySQL 8.0支持在线调整缓冲池大小

-- 连接相关
SET GLOBAL max_connections = 1000;
SET GLOBAL thread_cache_size = 64;

-- 超时相关
SET GLOBAL wait_timeout = 28800;
SET GLOBAL interactive_timeout = 28800;

-- 临时表相关
SET GLOBAL tmp_table_size = 268435456; -- 256MB
SET GLOBAL max_heap_table_size = 268435456;

-- 查看当前配置
SHOW VARIABLES LIKE 'innodb_buffer_pool_size';
SHOW VARIABLES LIKE 'max_connections';
SHOW VARIABLES LIKE 'thread_cache_size';

-- 查看配置是否生效
SHOW STATUS LIKE 'Innodb_buffer_pool_pages_total';
SHOW STATUS LIKE 'Threads_cached';
SHOW STATUS LIKE 'Threads_created';

性能监控和分析

1. 实时性能监控

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
#!/usr/bin/env python3
import pymysql
import time
import json
from datetime import datetime

class MySQLPerformanceMonitor:
def __init__(self, db_config):
self.db_config = db_config
self.baseline_metrics = {}

def get_connection(self):
return pymysql.connect(**self.db_config)

def get_status_variables(self, pattern=None):
"""获取状态变量"""
conn = self.get_connection()
try:
with conn.cursor(pymysql.cursors.DictCursor) as cursor:
if pattern:
cursor.execute(f"SHOW STATUS LIKE '{pattern}'")
else:
cursor.execute("SHOW STATUS")
return {row['Variable_name']: row['Value'] for row in cursor.fetchall()}
finally:
conn.close()

def get_key_metrics(self):
"""获取关键性能指标"""
status = self.get_status_variables()

# 转换数值类型
numeric_keys = [
'Connections', 'Threads_connected', 'Threads_running',
'Queries', 'Questions', 'Slow_queries',
'Innodb_buffer_pool_read_requests', 'Innodb_buffer_pool_reads',
'Innodb_rows_read', 'Innodb_rows_inserted', 'Innodb_rows_updated', 'Innodb_rows_deleted',
'Created_tmp_tables', 'Created_tmp_disk_tables',
'Sort_rows', 'Sort_scan', 'Sort_range'
]

metrics = {}
for key in numeric_keys:
if key in status:
try:
metrics[key] = int(status[key])
except ValueError:
metrics[key] = 0

# 计算缓冲池命中率
if metrics.get('Innodb_buffer_pool_read_requests', 0) > 0:
hit_rate = (1 - metrics.get('Innodb_buffer_pool_reads', 0) /
metrics['Innodb_buffer_pool_read_requests']) * 100
metrics['Buffer_pool_hit_rate'] = round(hit_rate, 2)

# 计算临时表磁盘使用率
if metrics.get('Created_tmp_tables', 0) > 0:
disk_tmp_rate = (metrics.get('Created_tmp_disk_tables', 0) /
metrics['Created_tmp_tables']) * 100
metrics['Tmp_disk_table_rate'] = round(disk_tmp_rate, 2)

return metrics

def calculate_rates(self, current_metrics, previous_metrics, time_diff):
"""计算速率指标"""
rates = {}
rate_keys = ['Connections', 'Queries', 'Questions', 'Slow_queries']

for key in rate_keys:
if key in current_metrics and key in previous_metrics:
rate = (current_metrics[key] - previous_metrics[key]) / time_diff
rates[f'{key}_per_sec'] = round(rate, 2)

return rates

def analyze_performance(self, metrics):
"""分析性能并给出建议"""
issues = []
recommendations = []

# 缓冲池命中率检查
hit_rate = metrics.get('Buffer_pool_hit_rate', 0)
if hit_rate < 95:
issues.append(f"InnoDB缓冲池命中率过低: {hit_rate}%")
recommendations.append("考虑增加innodb_buffer_pool_size")

# 临时表磁盘使用率检查
tmp_disk_rate = metrics.get('Tmp_disk_table_rate', 0)
if tmp_disk_rate > 25:
issues.append(f"临时表磁盘使用率过高: {tmp_disk_rate}%")
recommendations.append("考虑增加tmp_table_size和max_heap_table_size")

# 连接数检查
threads_connected = metrics.get('Threads_connected', 0)
if threads_connected > 800: # 假设max_connections=1000
issues.append(f"连接数过高: {threads_connected}")
recommendations.append("检查连接池配置和应用连接管理")

# 慢查询检查
slow_queries = metrics.get('Slow_queries', 0)
if slow_queries > 100:
issues.append(f"慢查询数量: {slow_queries}")
recommendations.append("分析慢查询日志,优化SQL语句")

return {
'issues': issues,
'recommendations': recommendations
}

def monitor_loop(self, interval=60):
"""监控循环"""
previous_metrics = None
previous_time = None

while True:
try:
current_time = time.time()
current_metrics = self.get_key_metrics()

print(f"\n=== MySQL性能监控 {datetime.now().strftime('%Y-%m-%d %H:%M:%S')} ===")

# 显示当前指标
print("当前状态:")
print(f" 连接数: {current_metrics.get('Threads_connected', 0)}")
print(f" 运行线程: {current_metrics.get('Threads_running', 0)}")
print(f" 缓冲池命中率: {current_metrics.get('Buffer_pool_hit_rate', 0)}%")
print(f" 临时表磁盘率: {current_metrics.get('Tmp_disk_table_rate', 0)}%")

# 计算速率指标
if previous_metrics and previous_time:
time_diff = current_time - previous_time
rates = self.calculate_rates(current_metrics, previous_metrics, time_diff)

print("速率指标:")
for key, value in rates.items():
print(f" {key}: {value}")

# 性能分析
analysis = self.analyze_performance(current_metrics)

if analysis['issues']:
print("\n⚠️ 发现的问题:")
for issue in analysis['issues']:
print(f" - {issue}")

if analysis['recommendations']:
print("\n💡 优化建议:")
for rec in analysis['recommendations']:
print(f" - {rec}")

previous_metrics = current_metrics
previous_time = current_time

time.sleep(interval)

except KeyboardInterrupt:
print("\n监控已停止")
break
except Exception as e:
print(f"监控错误: {e}")
time.sleep(interval)

# 使用示例
if __name__ == "__main__":
db_config = {
'host': 'localhost',
'user': 'monitor_user',
'password': 'monitor_pass',
'charset': 'utf8mb4'
}

monitor = MySQLPerformanceMonitor(db_config)
monitor.monitor_loop(30) # 每30秒监控一次

2. 慢查询分析

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
#!/bin/bash
# 慢查询日志分析脚本

SLOW_LOG="/var/log/mysql/slow.log"
REPORT_FILE="/tmp/slow_query_report.txt"

echo "=== MySQL慢查询分析报告 ===" > $REPORT_FILE
echo "生成时间: $(date)" >> $REPORT_FILE
echo "" >> $REPORT_FILE

# 检查慢查询日志是否存在
if [ ! -f "$SLOW_LOG" ]; then
echo "慢查询日志文件不存在: $SLOW_LOG"
exit 1
fi

# 使用mysqldumpslow分析
echo "=== 最耗时的10个查询 ===" >> $REPORT_FILE
mysqldumpslow -s t -t 10 $SLOW_LOG >> $REPORT_FILE

echo "" >> $REPORT_FILE
echo "=== 执行次数最多的10个查询 ===" >> $REPORT_FILE
mysqldumpslow -s c -t 10 $SLOW_LOG >> $REPORT_FILE

echo "" >> $REPORT_FILE
echo "=== 平均执行时间最长的10个查询 ===" >> $REPORT_FILE
mysqldumpslow -s at -t 10 $SLOW_LOG >> $REPORT_FILE

# 如果安装了pt-query-digest
if command -v pt-query-digest >/dev/null 2>&1; then
echo "" >> $REPORT_FILE
echo "=== pt-query-digest详细分析 ===" >> $REPORT_FILE
pt-query-digest $SLOW_LOG >> $REPORT_FILE
fi

echo "慢查询分析报告已生成: $REPORT_FILE"

# 显示报告摘要
echo ""
echo "=== 慢查询统计摘要 ==="
echo "慢查询总数: $(grep -c "Query_time" $SLOW_LOG)"
echo "涉及的数据库: $(grep "use " $SLOW_LOG | sort | uniq -c)"
echo "最常见的查询类型: $(grep -o "^# Query_time: [0-9.]*" $SLOW_LOG | wc -l) 个慢查询"

性能测试和基准

1. sysbench性能测试

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
#!/bin/bash
# MySQL性能基准测试脚本

DB_HOST="localhost"
DB_PORT="3306"
DB_USER="test_user"
DB_PASS="test_pass"
DB_NAME="sbtest"
TABLE_SIZE=100000
THREADS=16
TEST_TIME=300

echo "=== MySQL性能基准测试 ==="

# 1. 准备测试数据
echo "准备测试数据..."
sysbench oltp_read_write \
--mysql-host=$DB_HOST \
--mysql-port=$DB_PORT \
--mysql-user=$DB_USER \
--mysql-password=$DB_PASS \
--mysql-db=$DB_NAME \
--tables=10 \
--table-size=$TABLE_SIZE \
prepare

# 2. 只读测试
echo "执行只读性能测试..."
sysbench oltp_read_only \
--mysql-host=$DB_HOST \
--mysql-port=$DB_PORT \
--mysql-user=$DB_USER \
--mysql-password=$DB_PASS \
--mysql-db=$DB_NAME \
--tables=10 \
--table-size=$TABLE_SIZE \
--threads=$THREADS \
--time=$TEST_TIME \
--report-interval=10 \
run > readonly_test_result.txt

# 3. 只写测试
echo "执行只写性能测试..."
sysbench oltp_write_only \
--mysql-host=$DB_HOST \
--mysql-port=$DB_PORT \
--mysql-user=$DB_USER \
--mysql-password=$DB_PASS \
--mysql-db=$DB_NAME \
--tables=10 \
--table-size=$TABLE_SIZE \
--threads=$THREADS \
--time=$TEST_TIME \
--report-interval=10 \
run > writeonly_test_result.txt

# 4. 读写混合测试
echo "执行读写混合性能测试..."
sysbench oltp_read_write \
--mysql-host=$DB_HOST \
--mysql-port=$DB_PORT \
--mysql-user=$DB_USER \
--mysql-password=$DB_PASS \
--mysql-db=$DB_NAME \
--tables=10 \
--table-size=$TABLE_SIZE \
--threads=$THREADS \
--time=$TEST_TIME \
--report-interval=10 \
run > readwrite_test_result.txt

# 5. 清理测试数据
echo "清理测试数据..."
sysbench oltp_read_write \
--mysql-host=$DB_HOST \
--mysql-port=$DB_PORT \
--mysql-user=$DB_USER \
--mysql-password=$DB_PASS \
--mysql-db=$DB_NAME \
--tables=10 \
cleanup

# 6. 生成测试报告
echo "=== 性能测试报告 ===" > performance_report.txt
echo "测试时间: $(date)" >> performance_report.txt
echo "测试配置: $THREADS 线程, $TABLE_SIZE 行/表, $TEST_TIME 秒" >> performance_report.txt
echo "" >> performance_report.txt

echo "只读测试结果:" >> performance_report.txt
grep -E "transactions:|queries:|read/write requests:" readonly_test_result.txt >> performance_report.txt
echo "" >> performance_report.txt

echo "只写测试结果:" >> performance_report.txt
grep -E "transactions:|queries:|read/write requests:" writeonly_test_result.txt >> performance_report.txt
echo "" >> performance_report.txt

echo "读写混合测试结果:" >> performance_report.txt
grep -E "transactions:|queries:|read/write requests:" readwrite_test_result.txt >> performance_report.txt

echo "性能测试完成,报告保存在 performance_report.txt"

2. 自定义性能测试

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
#!/usr/bin/env python3
import pymysql
import threading
import time
import random
from concurrent.futures import ThreadPoolExecutor
import statistics

class MySQLBenchmark:
def __init__(self, db_config, num_threads=10):
self.db_config = db_config
self.num_threads = num_threads
self.results = []
self.lock = threading.Lock()

def get_connection(self):
return pymysql.connect(**self.db_config)

def create_test_table(self):
"""创建测试表"""
conn = self.get_connection()
try:
with conn.cursor() as cursor:
cursor.execute("""
CREATE TABLE IF NOT EXISTS benchmark_test (
id INT PRIMARY KEY AUTO_INCREMENT,
name VARCHAR(100) NOT NULL,
value INT NOT NULL,
data TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
INDEX idx_name (name),
INDEX idx_value (value)
) ENGINE=InnoDB
""")

# 插入测试数据
cursor.execute("DELETE FROM benchmark_test")

test_data = []
for i in range(10000):
test_data.append((
f'test_name_{i}',
random.randint(1, 1000),
f'test_data_{i}' * 10
))

cursor.executemany(
"INSERT INTO benchmark_test (name, value, data) VALUES (%s, %s, %s)",
test_data
)
conn.commit()
print("测试表创建完成,插入10000条测试数据")
finally:
conn.close()

def benchmark_select(self, duration=60):
"""SELECT查询基准测试"""
def worker():
conn = self.get_connection()
start_time = time.time()
query_count = 0

try:
while time.time() - start_time < duration:
with conn.cursor() as cursor:
# 随机查询
query_start = time.time()
cursor.execute(
"SELECT * FROM benchmark_test WHERE value = %s LIMIT 10",
(random.randint(1, 1000),)
)
cursor.fetchall()
query_time = time.time() - query_start

with self.lock:
self.results.append(('SELECT', query_time))

query_count += 1
finally:
conn.close()

return query_count

print(f"开始SELECT基准测试 ({duration}秒, {self.num_threads}线程)...")

with ThreadPoolExecutor(max_workers=self.num_threads) as executor:
futures = [executor.submit(worker) for _ in range(self.num_threads)]
total_queries = sum(future.result() for future in futures)

return total_queries

def benchmark_insert(self, duration=60):
"""INSERT基准测试"""
def worker():
conn = self.get_connection()
start_time = time.time()
query_count = 0

try:
while time.time() - start_time < duration:
with conn.cursor() as cursor:
query_start = time.time()
cursor.execute(
"INSERT INTO benchmark_test (name, value, data) VALUES (%s, %s, %s)",
(f'bench_{random.randint(1, 10000)}',
random.randint(1, 1000),
f'benchmark_data_{random.randint(1, 1000)}')
)
conn.commit()
query_time = time.time() - query_start

with self.lock:
self.results.append(('INSERT', query_time))

query_count += 1
finally:
conn.close()

return query_count

print(f"开始INSERT基准测试 ({duration}秒, {self.num_threads}线程)...")

with ThreadPoolExecutor(max_workers=self.num_threads) as executor:
futures = [executor.submit(worker) for _ in range(self.num_threads)]
total_queries = sum(future.result() for future in futures)

return total_queries

def benchmark_update(self, duration=60):
"""UPDATE基准测试"""
def worker():
conn = self.get_connection()
start_time = time.time()
query_count = 0

try:
while time.time() - start_time < duration:
with conn.cursor() as cursor:
query_start = time.time()
cursor.execute(
"UPDATE benchmark_test SET value = %s WHERE id = %s",
(random.randint(1, 1000), random.randint(1, 10000))
)
conn.commit()
query_time = time.time() - query_start

with self.lock:
self.results.append(('UPDATE', query_time))

query_count += 1
finally:
conn.close()

return query_count

print(f"开始UPDATE基准测试 ({duration}秒, {self.num_threads}线程)...")

with ThreadPoolExecutor(max_workers=self.num_threads) as executor:
futures = [executor.submit(worker) for _ in range(self.num_threads)]
total_queries = sum(future.result() for future in futures)

return total_queries

def generate_report(self, test_duration=60):
"""生成性能测试报告"""
print("\n=== MySQL性能基准测试报告 ===")

# 按操作类型分组统计
select_times = [r[1] for r in self.results if r[0] == 'SELECT']
insert_times = [r[1] for r in self.results if r[0] == 'INSERT']
update_times = [r[1] for r in self.results if r[0] == 'UPDATE']

def print_stats(operation, times):
if times:
print(f"\n{operation} 操作统计:")
print(f" 总查询数: {len(times)}")
print(f" QPS: {len(times) / test_duration:.2f}")
print(f" 平均响应时间: {statistics.mean(times)*1000:.2f}ms")
print(f" 中位数响应时间: {statistics.median(times)*1000:.2f}ms")
print(f" 95%响应时间: {sorted(times)[int(len(times)*0.95)]*1000:.2f}ms")
print(f" 最大响应时间: {max(times)*1000:.2f}ms")
print(f" 最小响应时间: {min(times)*1000:.2f}ms")

print_stats('SELECT', select_times)
print_stats('INSERT', insert_times)
print_stats('UPDATE', update_times)

def run_full_benchmark(self, duration=60):
"""运行完整的基准测试"""
self.create_test_table()
self.results = []

# 运行各种测试
select_queries = self.benchmark_select(duration)
self.benchmark_insert(duration // 3) # 较少的插入测试
self.benchmark_update(duration // 3) # 较少的更新测试

self.generate_report(duration)

# 清理测试表
conn = self.get_connection()
try:
with conn.cursor() as cursor:
cursor.execute("DROP TABLE IF EXISTS benchmark_test")
print("\n测试表已清理")
finally:
conn.close()

# 使用示例
if __name__ == "__main__":
db_config = {
'host': 'localhost',
'user': 'test_user',
'password': 'test_pass',
'database': 'test_db',
'charset': 'utf8mb4'
}

benchmark = MySQLBenchmark(db_config, num_threads=16)
benchmark.run_full_benchmark(120) # 运行2分钟测试

最佳实践总结

1. 性能优化检查清单

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
-- MySQL性能优化检查清单
SELECT
'缓冲池大小' as 检查项,
CONCAT(ROUND(@@innodb_buffer_pool_size/1024/1024/1024, 1), 'GB') as 当前值,
'建议为系统内存的70-80%' as 建议
UNION ALL
SELECT
'缓冲池命中率',
CONCAT(ROUND((1 - (SELECT VARIABLE_VALUE FROM performance_schema.global_status WHERE VARIABLE_NAME = 'Innodb_buffer_pool_reads') /
(SELECT VARIABLE_VALUE FROM performance_schema.global_status WHERE VARIABLE_NAME = 'Innodb_buffer_pool_read_requests')) * 100, 2), '%'),
'应该 > 95%'
UNION ALL
SELECT
'最大连接数',
@@max_connections,
'根据并发需求调整'
UNION ALL
SELECT
'慢查询',
(SELECT VARIABLE_VALUE FROM performance_schema.global_status WHERE VARIABLE_NAME = 'Slow_queries'),
'应该尽可能少'
UNION ALL
SELECT
'临时表磁盘使用率',
CONCAT(ROUND((SELECT VARIABLE_VALUE FROM performance_schema.global_status WHERE VARIABLE_NAME = 'Created_tmp_disk_tables') * 100 /
(SELECT VARIABLE_VALUE FROM performance_schema.global_status WHERE VARIABLE_NAME = 'Created_tmp_tables'), 2), '%'),
'应该 < 25%';

2. 监控告警阈值

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
# 性能监控告警阈值配置
ALERT_THRESHOLDS = {
'buffer_pool_hit_rate': {
'warning': 95,
'critical': 90
},
'tmp_disk_table_rate': {
'warning': 25,
'critical': 50
},
'connection_usage_rate': {
'warning': 80,
'critical': 90
},
'slow_queries_per_hour': {
'warning': 100,
'critical': 500
},
'threads_running': {
'warning': 50,
'critical': 100
},
'innodb_lock_wait_time': {
'warning': 10, # 秒
'critical': 30
}
}

3. 性能优化步骤

  1. 基础监控: 建立性能监控体系
  2. 硬件优化: 确保硬件配置合理
  3. 系统优化: 调整操作系统参数
  4. 配置优化: 调整MySQL配置参数
  5. 查询优化: 优化SQL语句和索引
  6. 架构优化: 考虑读写分离、分库分表
  7. 持续监控: 建立长期监控和告警机制

4. 常见性能问题解决方案

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
# 性能问题诊断脚本
#!/bin/bash

echo "=== MySQL性能问题诊断 ==="

# 1. 检查系统资源使用
echo "1. 系统资源使用情况:"
echo "CPU使用率:"
top -bn1 | grep "Cpu(s)" | awk '{print $2}' | cut -d'%' -f1

echo "内存使用情况:"
free -h

echo "磁盘IO情况:"
iostat -x 1 3

# 2. 检查MySQL进程
echo -e "\n2. MySQL进程状态:"
ps aux | grep mysql

# 3. 检查MySQL连接
echo -e "\n3. MySQL连接状态:"
mysql -e "SHOW PROCESSLIST;" | head -20

# 4. 检查慢查询
echo -e "\n4. 慢查询统计:"
mysql -e "SHOW STATUS LIKE 'Slow_queries';"

# 5. 检查锁等待
echo -e "\n5. 锁等待情况:"
mysql -e "SHOW STATUS LIKE 'Innodb_row_lock%';"

echo -e "\n诊断完成,请根据结果进行相应优化"

通过系统性的性能调优,可以显著提升MySQL数据库的性能表现。记住,性能优化是一个持续的过程,需要根据业务发展和数据增长不断调整优化策略。最重要的是建立完善的监控体系,及时发现和解决性能问题。

本站由 提供部署服务