mysql优化实战-基于bugfree的运行参数分析
注:截图及配置来源于生产环境bugfree对应的mysql管理工具phpMyAdmin的状态监控面板
1.created tmp files参数过高
分析:默认16M,观察监控发现临时表创建过多,大于16M了,使用了磁盘,内存有4G,建议10%,这里加大为400M
设定方式与优化准则
可根据如下参数的现状进行判断是否需要优化:
Created_tmp_disk_tables:磁盘中的临时表
Created_tmp_files:内存中的临时文件
Created_tmp_tables:内存中的临时表
Created_tmp_disk_tables表示使用到的磁盘临时表的数量。所以可根据Created_tmp_disk_tables/Created_tmp_tables的比例进行判断:
设定tmp_table_size过高虽然会使得此比例较低,但是也会带来浪费
根据经验设定低于10%较为理想,可根据对性能的要求自行调节和判断
[mysqld]
# 默认值是16M,优化为400M
tmp_table_size=400M
# 默认值是16M,优化为800M
max_heap_table_size=800M
2.Innodb buffer pool reads异常
分析:一般来说命中率(innodb_buffer_pool_size对应的缓存)不会低于99%,有部分数据没有命中缓存而读取了磁盘,4G磁盘优化后给了1024M内,10.24M内都是正常的。
[mysqld]
innodb_buffer_pool_size = 1024M
3.读取参数异常
分析:这个就是注意索引的使用和sql语句的编写,不改sql的前提只能调整索引,本文优化只尝试配置优化,不考虑修改索引
4.表打开个数过多
分析:
观察Opened tables的值在运行时达到了1.1k,比该值默认64大的多,并且还在不断增长.
如果Open_tables的值已经接近table_cache的值,且Opened_tables还在不断变大,则说明mysql正在将缓存的表释放以容纳新的表,此时可能需要加大table_cache的值。对于大多数情况,
比较适合的值:
Open_tables / Opened_tables >= 0.85
Open_tables / table_cache <= 0.95
如果对此参数的把握不是很准,VPS管理百科给出一个很保守的设置建议:把MySQL数据库放在生产环境中试运行一段时间,然后把参数的值调整得比Opened_tables的数值大一些,并且保证在比较高负载的极端条件下依然比Opened_tables略大。
在mysql默认安装情况下,table_cache的值在2G内存以下的机器中的值默认时256到 512,如果机器有4G内存,则默认这个值是2048,但这决意味着机器内存越大,这个值应该越大,因为table_cache加大后,使得mysql对 SQL响应的速度更快了,不可避免的会产生更多的死锁(dead lock),这样反而使得数据库整个一套操作慢了下来,严重影响性能。所以平时维护中还是要根据库的实际情况去作出判断,找到最适合你维护的库的 table_cache值。
因此:由于默认bugfree给的参数是64,和安装版本默认值相差较大,此处调整为建议配置,安装版本4G对应的2048
[mysqld]
table_cache = 2048
5.Sort merge passes
排序算法使用归并的次数
分析:如图描述,该参数异常,应考虑增加sort_buffer_size的值,参考下图,给到该配置1024k
[mysqld]
sort_buffer_size = 1024k
6.key reads异常
分析:
key_buffer_size指定索引缓冲区的大小,它决定索引处理的速度,尤其是索引读的速度。通过检查状态值Key_read_requests和Key_reads,可以知道key_buffer_size设置是否合理。比例key_reads /key_read_requests应该尽可能的低,至少是1:100,1:1000更好(上述状态值可以使用SHOW STATUS LIKE ‘key_read%'获得)。
key_buffer_size只对MyISAM表起作用。即使你不使用MyISAM表,但是内部的临时磁盘表是MyISAM表,也要使用该值。可以使用检查状态值created_tmp_disk_tables得知详情。
对于1G内存的机器,如果不使用MyISAM表,推荐值是16M(8-64M),4G推荐64M
[mysqld]
key_buffer_size = 64M
4G内存配置,mysql5.5.27
# Example MySQL config file for small systems.
#
# This is for a system with little memory (<= 64M) where MySQL is only used
# from time to time and it's important that the mysqld daemon
# doesn't use much resources.
#
# You can copy this file to
# C:/xampp/mysql/bin/my.cnf to set global options,
# mysql-data-dir/my.cnf to set server-specific options (in this
# installation this directory is C:/xampp/mysql/data) or
# ~/.my.cnf to set user-specific options.
#
# In this file, you can use all long options that a program supports.
# If you want to know which options a program supports, run the program
# with the "--help" option.
# The following options will be passed to all MySQL clients
[client]
# password = your_password
port = 3306
socket = "C:/xampp/mysql/mysql.sock"
max_connections=256
# Here follows entries for some specific programs
# The MySQL server
[mysqld]
port= 3306
socket = "C:/xampp/mysql/mysql.sock"
basedir = "C:/xampp/mysql"
tmpdir = "C:/xampp/tmp"
datadir = "C:/xampp/mysql/data"
pid_file = "mysql.pid"
# enable-named-pipe
# 优化,调整成正确的参数,4G推荐64M,key_buffer=16M => key_buffer_size=64M
key_buffer_size = 64M
# 指mysql服务器端和客户端在一次传送数据包的过程当中最大允许的数据包大小,1M => 64M
max_allowed_packet = 64M
# 优化,默认64,调整到2048
table_cache = 2048
# 优化,从512k调整到1024k
sort_buffer_size = 1024K
net_buffer_length = 8K
read_buffer_size = 256K
# 优化,bugfree有order by 操作,这个参数提高随机读取性能
read_rnd_buffer_size = 8M
myisam_sort_buffer_size = 8M
log_error = "mysql_error.log"
# 默认16M,优化后调整为400M,配套参数max_heap_table_size调整为800M
tmp_table_size=400M
max_heap_table_size=800M
# 默认是256K,这里优化到1M,按照200的并发来说,最多占到200M
join_buffer_size=1M
# Change here for bind listening
# bind-address="127.0.0.1"
# bind-address = :: # for ipv6
# Where do all the plugins live
plugin_dir = "C:/xampp/mysql/data/lib/plugin/"
# Don't listen on a TCP/IP port at all. This can be a security enhancement,
# if all processes that need to connect to mysqld run on the same host.
# All interaction with mysqld must be made via Unix sockets or named pipes.
# Note that using this option without enabling named pipes on Windows
# (via the "enable-named-pipe" option) will render mysqld useless!
#
# commented in by lampp security
#skip-networking
skip-federated
# Replication Master Server (default)
# binary logging is required for replication
# log-bin deactivated by default since XAMPP 1.4.11
#log-bin=mysql-bin
# required unique id between 1 and 2^32 - 1
# defaults to 1 if master-host is not set
# but will not function as a master if omitted
server-id = 1
# Replication Slave (comment out master section to use this)
#
# To configure this host as a replication slave, you can choose between
# two methods :
#
# 1) Use the CHANGE MASTER TO command (fully described in our manual) -
# the syntax is:
#
# CHANGE MASTER TO MASTER_HOST=<host>, MASTER_PORT=<port>,
# MASTER_USER=<user>, MASTER_PASSWORD=<password> ;
#
# where you replace <host>, <user>, <password> by quoted strings and
# <port> by the master's port number (3306 by default).
#
# Example:
#
# CHANGE MASTER TO MASTER_HOST='125.564.12.1', MASTER_PORT=3306,
# MASTER_USER='joe', MASTER_PASSWORD='secret';
#
# OR
#
# 2) Set the variables below. However, in case you choose this method, then
# start replication for the first time (even unsuccessfully, for example
# if you mistyped the password in master-password and the slave fails to
# connect), the slave will create a master.info file, and any later
# change in this file to the variables' values below will be ignored and
# overridden by the content of the master.info file, unless you shutdown
# the slave server, delete master.info and restart the slaver server.
# For that reason, you may want to leave the lines below untouched
# (commented) and instead use CHANGE MASTER TO (see above)
#
# required unique id between 2 and 2^32 - 1
# (and different from the master)
# defaults to 2 if master-host is set
# but will not function as a slave if omitted
#server-id = 2
#
# The replication master for this slave - required
#master-host = <hostname>
#
# The username the slave will use for authentication when connecting
# to the master - required
#master-user = <username>
#
# The password the slave will authenticate with when connecting to
# the master - required
#master-password = <password>
#
# The port the master is listening on.
# optional - defaults to 3306
#master-port = <port>
#
# binary logging - not required for slaves, but recommended
#log-bin=mysql-bin
# Point the following paths to different dedicated disks
#tmpdir = "C:/xampp/tmp"
#log-update = /path-to-dedicated-directory/hostname
# Uncomment the following if you are using BDB tables
#bdb_cache_size = 4M
#bdb_max_lock = 10000
# Comment the following if you are using InnoDB tables
#skip-innodb
innodb_data_home_dir = "C:/xampp/mysql/data"
innodb_data_file_path = ibdata1:10M:autoextend;ibdata2:1G:autoextend
innodb_log_group_home_dir = "C:/xampp/mysql/data"
#innodb_log_arch_dir = "C:/xampp/mysql/data"
## You can set .._buffer_pool_size up to 50 - 80 %
## of RAM but beware of setting memory usage too high
# InnoDB使用操作系统的内存分配程序
innodb_use_sys_malloc = 1
# 优化,扩展到1024M
innodb_buffer_pool_size = 1024M
# 优化,恢复默认的8M
innodb_additional_mem_pool_size = 8M
## Set .._log_file_size to 25 % of buffer pool size
# 优化,扩展innodb_log_file_size到buffer_pool_size的25%
innodb_log_file_size = 256M
innodb_log_buffer_size = 300M
# 优化,将默认的1更改为2
# 0代表:log buffer将每秒一次地写入log file中,并且log file的flush(刷到磁盘)操作同时进行。该模式下在事务提交的时候,不会主动触发写入磁盘的操作。
# 1代表:每次事务提交时MySQL都会把log buffer的数据写入log file,并且flush(刷到磁盘)中去,该模式为系统默认(因此会保留每一份redo日志)
# 2代表:每次事务提交时MySQL都会把log buffer的数据写入log file,但是flush(刷到磁盘)操作并不会同时进行。
# 该模式下,MySQL会每秒执行一次 flush(刷到磁盘)操作。
# 该模式速度较快,也比0安全,只有在操作系统崩溃或者系统断电的情况下,上一秒钟所有事务数据才可能丢失。
innodb_flush_log_at_trx_commit = 2
innodb_lock_wait_timeout = 500
# InnoDB内核最大并发线程数为9
innodb_thread_concurrency=9
## UTF 8 Settings
#init-connect=\'SET NAMES utf8\'
#collation_server=utf8_unicode_ci
#character_set_server=utf8
#skip-character-set-client-handshake
#character_sets-dir="C:/xampp/mysql/share/charsets"
[mysqldump]
quick
max_allowed_packet = 16M
[mysql]
no-auto-rehash
# Remove the next comment character if you are not familiar with SQL
#safe-updates
[isamchk]
key_buffer = 20M
sort_buffer_size = 20M
read_buffer = 2M
write_buffer = 2M
[myisamchk]
key_buffer = 20M
sort_buffer_size = 20M
read_buffer = 2M
write_buffer = 2M
[mysqlhotcopy]
interactive-timeout
正文到此结束