├── README.md ├── mysql_tuning.py └── mysql_tuning_v3.py /README.md: -------------------------------------------------------------------------------- 1 | #### 该程序可以方便DBA的日常SQL调优工作。其原理是将优化相关的信息,一次性提交给DBA,可快速定位问题。 2 | 3 | ### 1.准备条件 4 | #### 模块 5 | - 模块 - MySQLDB(适用于旧版本) 6 | - 模块 - pymysql(使用于v3版本) 7 | - 模块 - sqlparse 8 | - 模块 - prettytable 9 | 10 | #### 版本 11 | - Python版本 >= 2.6, mysql_tuning.py 12 | - Python版本 =3.x,mysql_tuning_v3.py 13 | 14 | #### 授权 15 | grant all on *.* to testuser@'localhost' identified by 'testpwd'; 16 | 17 | #### 参数 18 | 在5.7版本中,需要打开show_compatibility_56参数。 19 | set global show_compatibility_56=on; 20 | 21 | 需要开放导出文件权限。 22 | 23 | set secure_file_priv=''; 24 | 25 | ### 2.调用方法 26 | - python 2.x用法 27 | 28 | python mysql_tuning.py -p tuning_sql.ini -s 'select d.dname ,e.empno from big_dep...' 29 | 30 | - python 3.x用法 31 | 32 | python mysql_tuning_v3.py -p tuning_sql.ini -s 'select d.dname ,e.empno from big_dep...' 33 | 34 | #### 参数说明 35 | -p 指定配置文件名称,文件格式及含义参加下面说明。 36 | -s 指定SQL语句。 37 | #### 配置文件 38 | 文本格式,共分两节信息。分别是[database]描述数据库连接信息,[option]运行配置信息。 39 | 40 | [database] 41 | server_ip = 127.0.0.1 42 | server_port = 3306 43 | db_user = testuser 44 | db_pwd = testpwd 45 | db_name = test 46 | [option] 47 | sys_parm = ON //是否显示系统参数 48 | sql_plan = ON //是否显示执行计划 49 | obj_stat = ON //是否显示相关对象(表、索引)统计信息 50 | ses_status = ON //是否显示运行前后状态信息(激活后会真实执行SQL) 51 | sql_profile = ON //是否显示PROFILE跟踪信息(激活后会真实执行SQL) 52 | opt_trace = ON //是否开启optimizer trace(激活后会真实执行SQL) 53 | ### 3.输出说明 54 | #### 标题部分 55 | 包含运行数据库的地址信息及数据版本信息。 56 | 57 | ===== BASIC INFORMATION ===== 58 | +-----------+-------------+-----------+---------+------------+ 59 | | server_ip | server_port | user_name | db_name | db_version | 60 | +-----------+-------------+-----------+---------+------------+ 61 | | localhost | 3501 | testuser | test | 5.7.12 | 62 | +-----------+-------------+-----------+---------+------------+ 63 | #### 原始SQL 64 | 用户执行输入的SQL,这部分主要是为了后续对比重写SQL时使用。 65 | 66 | ===== ORIGINAL SQL TEXT ===== 67 | SELECT d.dname, 68 | e.empno 69 | FROM big_dept d, 70 | big_emp e 71 | WHERE d.deptno=e.deptno LIMIT 10 72 | #### 系统级参数 73 | 脚本选择显示了部分与SQL性能相关的参数。 74 | 75 | ===== SYSTEM PARAMETER ===== 76 | +-------------------------+-----------------+ 77 | | parameter_name | value | 78 | +-------------------------+-----------------+ 79 | | binlog_cache_size | 1.0 M | 80 | | bulk_insert_buffer_size | 64.0 M | 81 | | join_buffer_size | 8.0 M | 82 | | key_buffer_size | 256.0 M | 83 | | key_cache_block_size | 1.0 K | 84 | | max_binlog_cache_size | 17179869183.0 G | 85 | | max_binlog_size | 1.0 G | 86 | | max_join_size | 17179869183.0 G | 87 | | query_cache_size | 0 B | 88 | | query_prealloc_size | 8.0 K | 89 | | range_alloc_block_size | 4.0 K | 90 | | read_buffer_size | 2.0 M | 91 | | read_rnd_buffer_size | 8.0 M | 92 | | sort_buffer_size | 2.0 M | 93 | | thread_cache_size | 20 B | 94 | | tmp_table_size | 1.0 G | 95 | +-------------------------+-----------------+ 96 | 97 | #### 优化器开关 98 | 99 | ===== OPTIMIZER SWITCH ===== 100 | +-------------------------------------+-------+ 101 | | switch_name | value | 102 | +-------------------------------------+-------+ 103 | | index_merge | on | 104 | | index_merge_union | on | 105 | | index_merge_sort_union | on | 106 | | index_merge_intersection | on | 107 | | engine_condition_pushdown | on | 108 | | index_condition_pushdown | on | 109 | | mrr | on | 110 | | mrr_cost_based | on | 111 | | block_nested_loop | on | 112 | | batched_key_access | off | 113 | | materialization | on | 114 | | semijoin | on | 115 | | loosescan | on | 116 | | firstmatch | on | 117 | | duplicateweedout | on | 118 | | subquery_materialization_cost_based | on | 119 | | use_index_extensions | on | 120 | | condition_fanout_filter | on | 121 | | derived_merge | on | 122 | +-------------------------------------+-------+ 123 | 124 | #### 执行计划 125 | 就是调用explain extended的输出结果。如果结果过长,可能出现显示串行的问题(暂时未解决)。 126 | 127 | ===== SQL PLAN ===== 128 | +----+-------------+-------+------------+-------+---------------+----------------+---------+---------------+------+----------+-------------+ 129 | | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra | 130 | +----+-------------+-------+------------+-------+---------------+----------------+---------+---------------+------+----------+-------------+ 131 | | 1 | SIMPLE | d | None | index | PRIMARY | idx_dept_dname | 17 | None | 1000 | 100.0 | Using index | 132 | | 1 | SIMPLE | e | None | ref | fk_deptno | fk_deptno | 5 | test.d.deptno | 996 | 100.0 | Using index | 133 | +----+-------------+-------+------------+-------+---------------+----------------+---------+---------------+------+----------+-------------+ 134 | 135 | #### 优化器改写后的SQL 136 | 通过这里可判断优化器是否对SQL进行了某种优化(例如子查询的处理)。 137 | 138 | ===== OPTIMIZER REWRITE SQL ===== 139 | SELECT `test`.`d`.`dname` AS `dname`, 140 | `test`.`e`.`empno` AS `empno` 141 | FROM `test`.`big_dept` `d` 142 | JOIN `test`.`big_emp` `e` 143 | WHERE (`test`.`e`.`deptno` = `test`.`d`.`deptno`) LIMIT 10 144 | #### 统计信息 145 | 相关对象的统计信息(表、索引)。在SQL语句中所有涉及到的表及其索引的统计信息都会在这里显示出来。 146 | 147 | ===== OBJECT STATISTICS ===== 148 | +------------+--------+---------+------------+---------+----------+---------+----------+ 149 | | table_name | engine | format | table_rows | avg_row | total_mb | data_mb | index_mb | 150 | +------------+--------+---------+------------+---------+----------+---------+----------+ 151 | | big_dept | InnoDB | Dynamic | 1000 | 81 | 0.08 | 0.08 | 0.00 | 152 | +------------+--------+---------+------------+---------+----------+---------+----------+ 153 | +----------------+------------+--------------+-------------+-----------+-------------+----------+------------+ 154 | | index_name | non_unique | seq_in_index | column_name | collation | cardinality | nullable | index_type | 155 | +----------------+------------+--------------+-------------+-----------+-------------+----------+------------+ 156 | | idx_dept_dname | 1 | 1 | dname | A | 1000 | YES | BTREE | 157 | | PRIMARY | 0 | 1 | deptno | A | 1000 | | BTREE | 158 | +----------------+------------+--------------+-------------+-----------+-------------+----------+------------+ 159 | +------------+--------+---------+------------+---------+----------+---------+----------+---------------------+---------------------+ 160 | | table_name | engine | format | table_rows | avg_row | total_mb | data_mb | index_mb | create_time | last_analyzed | 161 | +------------+--------+---------+------------+---------+----------+---------+----------+---------------------+---------------------+ 162 | | big_emp | InnoDB | Dynamic | 996293 | 62 | 110.17 | 59.58 | 50.59 | 2016-11-22 01:26:35 | 2017-01-13 01:18:55 | 163 | +------------+--------+---------+------------+---------+----------+---------+----------+---------------------+---------------------+ 164 | +------------+------------+--------------+-------------+-----------+-------------+----------+------------+ 165 | | index_name | non_unique | seq_in_index | column_name | collation | cardinality | nullable | index_type | 166 | +------------+------------+--------------+-------------+-----------+-------------+----------+------------+ 167 | | fk_deptno | 1 | 1 | deptno | A | 1000 | YES | BTREE | 168 | | idx_sal | 1 | 1 | sal | A | 10145 | YES | BTREE | 169 | | PRIMARY | 0 | 1 | empno | A | 996293 | | BTREE | 170 | +------------+------------+--------------+-------------+-----------+-------------+----------+------------+ 171 | +------------+---------------------+--------------+------------+-------------+-----------------------------------+ 172 | | index_name | last_analyzed | stat_name | stat_value | sample_size | stat_description | 173 | +------------+---------------------+--------------+------------+-------------+-----------------------------------+ 174 | | PRIMARY | 2017-01-13 01:18:55 | n_diff_pfx01 | 996293 | 20 | empno | 175 | | PRIMARY | 2017-01-13 01:18:55 | n_leaf_pages | 3781 | None | Number of leaf pages in the index | 176 | | PRIMARY | 2017-01-13 01:18:55 | size | 3813 | None | Number of pages in the index | 177 | | fk_deptno | 2017-01-13 01:18:55 | n_diff_pfx01 | 1000 | 20 | deptno | 178 | | fk_deptno | 2017-01-13 01:18:55 | n_diff_pfx02 | 1050373 | 20 | deptno,empno | 179 | | fk_deptno | 2017-01-13 01:18:55 | n_leaf_pages | 1311 | None | Number of leaf pages in the index | 180 | | fk_deptno | 2017-01-13 01:18:55 | size | 1507 | None | Number of pages in the index | 181 | | idx_sal | 2017-01-13 01:18:55 | n_diff_pfx01 | 10001 | 20 | sal | 182 | | idx_sal | 2017-01-13 01:18:55 | n_diff_pfx02 | 1047187 | 20 | sal,empno | 183 | | idx_sal | 2017-01-13 01:18:55 | n_leaf_pages | 1373 | None | Number of leaf pages in the index | 184 | | idx_sal | 2017-01-13 01:18:55 | size | 1731 | None | Number of pages in the index | 185 | +------------+---------------------+--------------+------------+-------------+-----------------------------------+ 186 | #### 运行状态信息 187 | 在会话级别对比了执行前后的状态(SHOW STATUS),并将出现变化的部分显示出来。需要注意的是,因为收集状态数据是采用SELECT方式,会造成个别指标的误差(例如Com_select)。 188 | 189 | ===== SESSION STATUS (DIFFERENT) ===== 190 | +----------------------------------+-----------+---------------+---------------+ 191 | | status_name | before | after | diff | 192 | +----------------------------------+-----------+---------------+---------------+ 193 | | Bytes_received | 515 | 812 | 297.0 | 194 | | Bytes_sent | 661 | 12002 | 11341.0 | 195 | | Com_select | 2 | 4 | 2.0 | 196 | | Com_show_warnings | 2 | 3 | 1.0 | 197 | | Created_tmp_tables | 2 | 3 | 1.0 | 198 | | Handler_commit | 0 | 1 | 1.0 | 199 | | Handler_external_lock | 0 | 4 | 4.0 | 200 | | Handler_read_first | 0 | 1 | 1.0 | 201 | | Handler_read_key | 0 | 2 | 2.0 | 202 | | Handler_read_next | 0 | 9 | 9.0 | 203 | | Handler_read_rnd | 0 | 380 | 380.0 | 204 | | Handler_read_rnd_next | 6 | 387 | 381.0 | 205 | | Handler_write | 193 | 573 | 380.0 | 206 | | Innodb_buffer_pool_bytes_data | 43204608 | 43270144 | 65536.0 | 207 | | Innodb_buffer_pool_pages_data | 2637 | 2641 | 4.0 | 208 | | Innodb_buffer_pool_pages_free | 30115 | 30111 | -4.0 | 209 | | Innodb_buffer_pool_read_requests | 26779348 | 26779357 | 9.0 | 210 | | Innodb_buffer_pool_reads | 2565 | 2569 | 4.0 | 211 | | Innodb_data_read | 42095104 | 42160640 | 65536.0 | 212 | | Innodb_data_reads | 2595 | 2600 | 5.0 | 213 | | Innodb_num_open_files | 23 | 24 | 1.0 | 214 | | Innodb_pages_read | 2564 | 2568 | 4.0 | 215 | | Innodb_rows_read | 54637053 | 54637064 | 11.0 | 216 | | Last_query_cost | 10.499000 | 201556.132981 | 201545.633981 | 217 | | Last_query_partial_plans | 1 | 3 | 2.0 | 218 | | Open_tables | 54 | 56 | 2.0 | 219 | | Opened_tables | 0 | 2 | 2.0 | 220 | | Queries | 2734384 | 2734387 | 3.0 | 221 | | Questions | 6 | 9 | 3.0 | 222 | | Select_scan | 2 | 4 | 2.0 | 223 | | Sort_rows | 0 | 380 | 380.0 | 224 | | Sort_scan | 0 | 1 | 1.0 | 225 | | Table_open_cache_misses | 0 | 2 | 2.0 | 226 | +----------------------------------+-----------+---------------+---------------+ 227 | 228 | #### PROFILE详细信息 229 | 调用SHOW PROFILE得到的详细信息。 230 | 231 | ===== SQL PROFILING(DETAIL)===== 232 | +----------------+----------+----------+----------+-------+--------+-------+-------+--------+--------+-------+ 233 | | state | duration | cpu_user | cpu_sys | bk_in | bk_out | msg_s | msg_r | p_f_ma | p_f_mi | swaps | 234 | +----------------+----------+----------+----------+-------+--------+-------+-------+--------+--------+-------+ 235 | | starting | 0.000079 | 0.000000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 236 | | query end | 0.000006 | 0.000000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 237 | | closing tables | 0.000004 | 0.000000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 238 | | freeing items | 0.000010 | 0.000000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 239 | | cleaning up | 0.000073 | 0.000000 | 0.000000 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 240 | +----------------+----------+----------+----------+-------+--------+-------+-------+--------+--------+-------+ 241 | bk_in: block_ops_in 242 | bk_out: block_ops_out 243 | msg_s: message sent 244 | msg_r: message received 245 | p_f_ma: page_faults_major 246 | p_f_mi: page_faults_minor 247 | 248 | #### PROFILE汇总信息 249 | 根据PROFILE的资源消耗情况,显示不同阶段消耗对比情况(TOP N),直观显示"瓶颈"所在。 250 | 251 | ===== SQL PROFILING(SUMMARY)===== 252 | +----------------+----------+-------+-------+--------------+ 253 | | state | total_r | pct_r | calls | r/call | 254 | +----------------+----------+-------+-------+--------------+ 255 | | starting | 0.000079 | 45.93 | 1 | 0.0000790000 | 256 | | cleaning up | 0.000073 | 42.44 | 1 | 0.0000730000 | 257 | | freeing items | 0.000010 | 5.81 | 1 | 0.0000100000 | 258 | | query end | 0.000006 | 3.49 | 1 | 0.0000060000 | 259 | | closing tables | 0.000004 | 2.33 | 1 | 0.0000040000 | 260 | +----------------+----------+-------+-------+--------------+ 261 | 262 | #### OPTIMIZER TRACE FILE 263 | OPTIMIZER TRACE生成的文件 264 | 265 | #### 执行时长 266 | 实际执行时长。 267 | 268 | ===== EXECUTE TIME ===== 269 | 0 day 0 hour 0 minute 0 second 162 microsecond 270 | -------------------------------------------------------------------------------- /mysql_tuning.py: -------------------------------------------------------------------------------- 1 | #!/usr/local/bin/python 2 | import datetime 3 | import getopt 4 | import sys 5 | import pprint 6 | from warnings import filterwarnings 7 | import MySQLdb 8 | import ConfigParser 9 | import sqlparse 10 | import string 11 | from sqlparse.sql import IdentifierList, Identifier 12 | from sqlparse.tokens import Keyword, DML 13 | from prettytable import PrettyTable 14 | 15 | filterwarnings('ignore', category = MySQLdb.Warning) 16 | 17 | SYS_PARM_FILTER = ( 18 | 'BINLOG_CACHE_SIZE', 19 | 'BULK_INSERT_BUFFER_SIZE', 20 | 'HAVE_PARTITION_ENGINE', 21 | 'HAVE_QUERY_CACHE', 22 | 'INTERACTIVE_TIMEOUT', 23 | 'JOIN_BUFFER_SIZE', 24 | 'KEY_BUFFER_SIZE', 25 | 'KEY_CACHE_AGE_THRESHOLD', 26 | 'KEY_CACHE_BLOCK_SIZE', 27 | 'KEY_CACHE_DIVISION_LIMIT', 28 | 'LARGE_PAGES', 29 | 'LOCKED_IN_MEMORY', 30 | 'LONG_QUERY_TIME', 31 | 'MAX_ALLOWED_PACKET', 32 | 'MAX_BINLOG_CACHE_SIZE', 33 | 'MAX_BINLOG_SIZE', 34 | 'MAX_CONNECT_ERRORS', 35 | 'MAX_CONNECTIONS', 36 | 'MAX_JOIN_SIZE', 37 | 'MAX_LENGTH_FOR_SORT_DATA', 38 | 'MAX_SEEKS_FOR_KEY', 39 | 'MAX_SORT_LENGTH', 40 | 'MAX_TMP_TABLES', 41 | 'MAX_USER_CONNECTIONS', 42 | 'OPTIMIZER_PRUNE_LEVEL', 43 | 'OPTIMIZER_SEARCH_DEPTH', 44 | 'QUERY_CACHE_SIZE', 45 | 'QUERY_CACHE_TYPE', 46 | 'QUERY_PREALLOC_SIZE', 47 | 'RANGE_ALLOC_BLOCK_SIZE', 48 | 'READ_BUFFER_SIZE', 49 | 'READ_RND_BUFFER_SIZE', 50 | 'SORT_BUFFER_SIZE', 51 | 'SQL_MODE', 52 | 'TABLE_CACHE', 53 | 'THREAD_CACHE_SIZE', 54 | 'TMP_TABLE_SIZE', 55 | 'WAIT_TIMEOUT' 56 | ) 57 | 58 | def print_table(p_title_list,p_data_list,p_align=[]): 59 | x = PrettyTable(p_title_list) 60 | x.padding_width = 1 61 | for i in range(0,len(p_align)): 62 | if p_align[i] == "l": 63 | x.align[p_title_list[i]] = "l" 64 | elif p_align[i] == "r": 65 | x.align[p_title_list[i]] = "r" 66 | else: 67 | pass 68 | 69 | for rec in p_data_list: 70 | if type(rec)!='list': 71 | rec = list(rec) 72 | x.add_row(rec) 73 | print x 74 | 75 | def is_subselect(parsed): 76 | if not parsed.is_group(): 77 | return False 78 | for item in parsed.tokens: 79 | if item.ttype is DML and item.value.upper() == 'SELECT': 80 | return True 81 | return False 82 | 83 | def extract_from_part(parsed): 84 | from_seen = False 85 | for item in parsed.tokens: 86 | #print item.ttype,item.value 87 | if from_seen: 88 | if is_subselect(item): 89 | for x in extract_from_part(item): 90 | yield x 91 | elif item.ttype is Keyword: 92 | raise StopIteration 93 | else: 94 | yield item 95 | elif item.ttype is Keyword and item.value.upper() == 'FROM': 96 | from_seen = True 97 | 98 | def extract_table_identifiers(token_stream): 99 | for item in token_stream: 100 | if isinstance(item, IdentifierList): 101 | for identifier in item.get_identifiers(): 102 | yield identifier.get_real_name() 103 | elif isinstance(item, Identifier): 104 | yield item.get_real_name() 105 | # It's a bug to check for Keyword here, but in the example 106 | # above some tables names are identified as keywords... 107 | elif item.ttype is Keyword: 108 | yield item.value 109 | 110 | def extract_tables(p_sqltext): 111 | stream = extract_from_part(sqlparse.parse(p_sqltext)[0]) 112 | return list(extract_table_identifiers(stream)) 113 | 114 | def f_find_in_list(myList,value): 115 | try: 116 | for v in range(0,len(myList)): 117 | if value==myList[v]: 118 | return 1 119 | return 0 120 | except: 121 | return 0 122 | 123 | def f_get_parm(p_dbinfo): 124 | conn = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 125 | cursor = conn.cursor() 126 | cursor.execute("select lower(variable_name),variable_value from INFORMATION_SCHEMA.GLOBAL_VARIABLES where upper(variable_name) in ('"+"','".join(list(SYS_PARM_FILTER))+"') order by variable_name") 127 | records = cursor.fetchall() 128 | cursor.close() 129 | conn.close() 130 | return records 131 | 132 | def f_print_parm(p_parm_result): 133 | print "\033[1;31;40m%s\033[0m" % "===== SYSTEM PARAMETER =====" 134 | v_data = [] 135 | for i in range(0,len(p_parm_result)): 136 | if 'size' in p_parm_result[i][0]: 137 | if string.atoi(p_parm_result[i][1])>=1024*1024*1024: 138 | v_data.append([p_parm_result[i][0],str(round(string.atoi(p_parm_result[i][1])/1024/1024/1024,2))+' G']) 139 | elif string.atoi(p_parm_result[i][1])>=1024*1024: 140 | v_data.append([p_parm_result[i][0],str(round(string.atoi(p_parm_result[i][1])/1024/1024,2))+' M']) 141 | elif string.atoi(p_parm_result[i][1])>=1024: 142 | v_data.append([p_parm_result[i][0],str(round(string.atoi(p_parm_result[i][1])/1024,2))+' K']) 143 | else: 144 | v_data.append([p_parm_result[i][0],p_parm_result[i][1]+' B']) 145 | else: 146 | pass 147 | print_table(['parameter_name','value'],v_data,['l','r']) 148 | print 149 | 150 | def f_get_optimizer_switch(p_dbinfo): 151 | conn = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 152 | cursor = conn.cursor() 153 | cursor.execute("select variable_value from INFORMATION_SCHEMA.GLOBAL_VARIABLES where upper(variable_name)='OPTIMIZER_SWITCH'") 154 | records = cursor.fetchall() 155 | cursor.close() 156 | conn.close() 157 | result = [] 158 | for o in str(records[0][0]).split(','): 159 | result.append([o.split('=')[0],o.split('=')[1]]) 160 | return result 161 | 162 | def f_print_optimizer_switch(p_optimizer_switch_result): 163 | print "\033[1;31;40m%s\033[0m" % "===== OPTIMIZER SWITCH =====" 164 | print_table(['switch_name','value'],p_optimizer_switch_result,['l','r']) 165 | print 166 | 167 | def f_exec_sql(p_dbinfo,p_sqltext,p_option): 168 | results={} 169 | conn = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 170 | cursor = conn.cursor() 171 | 172 | if f_find_in_list(p_option,'PROFILING'): 173 | cursor.execute("set profiling=1") 174 | cursor.execute("select ifnull(max(query_id),0) from INFORMATION_SCHEMA.PROFILING") 175 | records = cursor.fetchall() 176 | query_id=records[0][0] +2 #skip next sql 177 | 178 | if f_find_in_list(p_option,'STATUS'): 179 | #cursor.execute("select concat(upper(left(variable_name,1)),substring(lower(variable_name),2,(length(variable_name)-1))) var_name,variable_value var_value from INFORMATION_SCHEMA.SESSION_STATUS where variable_name in('"+"','".join(tuple(SES_STATUS_ITEM))+"') order by 1") 180 | cursor.execute("select concat(upper(left(variable_name,1)),substring(lower(variable_name),2,(length(variable_name)-1))) var_name,variable_value var_value from INFORMATION_SCHEMA.SESSION_STATUS order by 1") 181 | records = cursor.fetchall() 182 | results['BEFORE_STATUS']=dict(records) 183 | 184 | cursor.execute(p_sqltext) 185 | 186 | if f_find_in_list(p_option,'STATUS'): 187 | cursor.execute("select concat(upper(left(variable_name,1)),substring(lower(variable_name),2,(length(variable_name)-1))) var_name,variable_value var_value from INFORMATION_SCHEMA.SESSION_STATUS order by 1") 188 | records = cursor.fetchall() 189 | results['AFTER_STATUS']=dict(records) 190 | 191 | if f_find_in_list(p_option,'PROFILING'): 192 | cursor.execute("select STATE,DURATION,CPU_USER,CPU_SYSTEM,BLOCK_OPS_IN,BLOCK_OPS_OUT ,MESSAGES_SENT ,MESSAGES_RECEIVED ,PAGE_FAULTS_MAJOR ,PAGE_FAULTS_MINOR ,SWAPS from INFORMATION_SCHEMA.PROFILING where query_id="+str(query_id)+" order by seq") 193 | records = cursor.fetchall() 194 | results['PROFILING_DETAIL']=records 195 | 196 | cursor.execute("SELECT STATE,SUM(DURATION) AS Total_R,ROUND(100*SUM(DURATION)/(SELECT SUM(DURATION) FROM INFORMATION_SCHEMA.PROFILING WHERE QUERY_ID="+str(query_id)+"),2) AS Pct_R,COUNT(*) AS Calls,SUM(DURATION)/COUNT(*) AS R_Call FROM INFORMATION_SCHEMA.PROFILING WHERE QUERY_ID="+str(query_id)+" GROUP BY STATE ORDER BY Total_R DESC") 197 | records = cursor.fetchall() 198 | results['PROFILING_SUMMARY']=records 199 | 200 | cursor.close() 201 | conn.close() 202 | return results 203 | 204 | def f_calc_status(p_before_status,p_after_status): 205 | results = [] 206 | for key in sorted(p_before_status.keys()): 207 | if p_before_status[key]<>p_after_status[key]: 208 | results.append([key,p_before_status[key],p_after_status[key],str(float(p_after_status[key])-float(p_before_status[key]))]) 209 | return results 210 | 211 | def f_print_status(p_status_data): 212 | print "\033[1;31;40m%s\033[0m" % "===== SESSION STATUS (DIFFERENT) =====" 213 | print_table(['status_name','before','after','diff'],p_status_data,['l','r','r','r']) 214 | print 215 | 216 | def f_print_time(p_starttime,p_endtime): 217 | print "\033[1;31;40m%s\033[0m" % "===== EXECUTE TIME =====" 218 | print timediff(p_starttime,p_endtime) 219 | print 220 | 221 | def f_print_profiling(p_profiling_detail,p_profiling_summary): 222 | print "\033[1;31;40m%s\033[0m" % "===== SQL PROFILING(DETAIL)=====" 223 | print_table(['state','duration','cpu_user','cpu_sys','bk_in','bk_out','msg_s','msg_r','p_f_ma','p_f_mi','swaps'],p_profiling_detail,['l','r','r','r','r','r','r','r','r','r','r']) 224 | print 'bk_in: block_ops_in' 225 | print 'bk_out: block_ops_out' 226 | print 'msg_s: message sent' 227 | print 'msg_r: message received' 228 | print 'p_f_ma: page_faults_major' 229 | print 'p_f_mi: page_faults_minor' 230 | print 231 | 232 | print "\033[1;31;40m%s\033[0m" % "===== SQL PROFILING(SUMMARY)=====" 233 | print_table(['state','total_r','pct_r','calls','r/call'],p_profiling_summary,['l','r','r','r','r']) 234 | print 235 | 236 | def f_get_sqlplan(p_dbinfo,p_sqltext): 237 | results={} 238 | 239 | db = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 240 | cursor = db.cursor() 241 | cursor.execute("explain extended "+p_sqltext) 242 | records = cursor.fetchall() 243 | results['SQLPLAN']=records 244 | cursor.execute("show warnings") 245 | records = cursor.fetchall() 246 | results['WARNING']=records 247 | cursor.close() 248 | db.close() 249 | return results 250 | 251 | def f_null(p_value): 252 | if not p_value: 253 | return '' 254 | 255 | def f_print_sqlplan(p_sqlplan,p_warning,p_mysql_version): 256 | plan_title=('id','select_type','table','type','possible_keys','key','key_len','ref','rows','filtered','Extra') 257 | 258 | print "\033[1;31;40m%s\033[0m" % "===== SQL PLAN =====" 259 | 260 | if p_mysql_version.split('.')[1] == '7': #5.7 261 | print_table(['id','select_type','table','partitions','type','possible_keys','key','key_len','ref','rows','filtered','Extra'],p_sqlplan,['r','l','l','l','l','l','l','l','l','r','r','l']) 262 | else: 263 | print_table(['id','select_type','table','type','possible_keys','key','key_len','ref','rows','filtered','Extra'],p_sqlplan,['r','l','l','l','l','l','l','l','r','r','l']) 264 | print 265 | 266 | print "\033[1;31;40m%s\033[0m" % "===== OPTIMIZER REWRITE SQL =====" 267 | for row in p_warning: 268 | print sqlparse.format(row[2],reindent=True, keyword_case='upper',strip_comments=True) 269 | print 270 | 271 | def f_get_table(p_dbinfo,p_sqltext): 272 | r_tables=[] 273 | db = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 274 | cursor = db.cursor() 275 | cursor.execute("explain "+p_sqltext) 276 | rows = cursor.fetchall () 277 | for row in rows: 278 | table_name = row[2] 279 | if '<' in table_name: 280 | continue 281 | if len(r_tables)==0: 282 | r_tables.append(table_name) 283 | elif f_find_in_list(r_tables,table_name) == -1: 284 | r_tables.append(table_name) 285 | cursor.close() 286 | db.close() 287 | return r_tables 288 | 289 | def f_get_tableinfo(p_dbinfo,p_tablename): 290 | db = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 291 | cursor = db.cursor() 292 | #cursor.execute("select table_name,engine,row_format as format,table_rows,avg_row_length as avg_row,round((data_length+index_length)/1024/1024,2) as total_mb,round((data_length)/1024/1024,2) as data_mb,round((index_length)/1024/1024,2) as index_mb from information_schema.tables where table_schema='"+p_dbinfo[4]+"' and table_name='"+p_tablename+"'") 293 | cursor.execute("select a.table_name,a.engine,a.row_format as format,a.table_rows,a.avg_row_length as avg_row,round((a.data_length+a.index_length)/1024/1024,2) as total_mb,round((a.data_length)/1024/1024,2) as data_mb,round((a.index_length)/1024/1024,2) as index_mb,a.create_time,b.last_update last_analyzed from information_schema.tables a ,mysql.innodb_table_stats b where a.table_schema=b.database_name and a.table_name=b.table_name and a.table_schema='"+p_dbinfo[4]+"' and a.table_name='"+p_tablename+"'") 294 | records = cursor.fetchall () 295 | cursor.close() 296 | db.close() 297 | return records 298 | 299 | def f_print_tableinfo(p_table_stat): 300 | print_table(['table_name','engine','format','table_rows','avg_row','total_mb','data_mb','index_mb','create_time','last_analyzed'],p_table_stat,['l','l','l','r','r','r','r','r','c','c']) 301 | 302 | def f_get_indexinfo(p_dbinfo,p_tablename): 303 | db = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 304 | cursor = db.cursor() 305 | cursor.execute("select index_name,non_unique,seq_in_index,column_name,collation,cardinality,nullable,index_type from information_schema.statistics where table_schema='"+p_dbinfo[4]+"' and table_name='"+p_tablename+"' order by 1,3") 306 | records = cursor.fetchall () 307 | cursor.close() 308 | db.close() 309 | return records 310 | 311 | def f_print_indexinfo(p_index_info): 312 | if len(p_index_info)>0: 313 | print_table(['index_name','non_unique','seq_in_index','column_name','collation','cardinality','nullable','index_type'],p_index_info,['l','r','r','l','','r','r','l']) 314 | 315 | def f_get_indexstat(p_dbinfo,p_tablename): 316 | db = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 317 | cursor = db.cursor() 318 | cursor.execute("select index_name,last_update last_analyzed,stat_name,stat_value,sample_size,stat_description from mysql.innodb_index_stats a where database_name='"+p_dbinfo[4]+"' and table_name='"+p_tablename+"' order by index_name,stat_name") 319 | records = cursor.fetchall () 320 | cursor.close() 321 | db.close() 322 | return records 323 | 324 | def f_print_indexstat(p_index_stat): 325 | if len(p_index_stat)>0: 326 | print_table(['index_name','last_analyzed','stat_name','stat_value','sample_size','stat_description'],p_index_stat,['l','c','l','r','r','l']) 327 | 328 | def f_get_mysql_version(p_dbinfo): 329 | db = MySQLdb.connect(host=p_dbinfo[0], port=string.atoi(p_dbinfo[1]),user=p_dbinfo[2], passwd=p_dbinfo[3],db=p_dbinfo[4]) 330 | cursor = db.cursor() 331 | cursor.execute("select @@version") 332 | records = cursor.fetchall () 333 | cursor.close() 334 | db.close() 335 | return records[0][0] 336 | 337 | def f_print_title(p_dbinfo,p_mysql_version,p_sqltext): 338 | print 339 | print '*'*100 340 | print '*','MySQL SQL Tuning Tools v2.0 (by hanfeng)'.center(96),'*' 341 | print '*'*100 342 | print 343 | 344 | print "\033[1;31;40m%s\033[0m" % "===== BASIC INFORMATION =====" 345 | print_table(['server_ip','server_port','user_name','db_name','db_version'],[[p_dbinfo[0],p_dbinfo[1],p_dbinfo[2],p_dbinfo[4],p_mysql_version]]) 346 | print 347 | 348 | print "\033[1;31;40m%s\033[0m" % "===== ORIGINAL SQL TEXT =====" 349 | print sqlparse.format(p_sqltext,reindent=True, keyword_case='upper') 350 | print 351 | 352 | def timediff(timestart, timestop): 353 | t = (timestop-timestart) 354 | time_day = t.days 355 | s_time = t.seconds 356 | ms_time = t.microseconds / 1000000 357 | usedtime = int(s_time + ms_time) 358 | time_hour = usedtime / 60 / 60 359 | time_minute = (usedtime - time_hour * 3600 ) / 60 360 | time_second = usedtime - time_hour * 3600 - time_minute * 60 361 | time_micsecond = (t.microseconds - t.microseconds / 1000000) / 1000 362 | 363 | retstr = "%d day %d hour %d minute %d second %d microsecond " %(time_day, time_hour, time_minute, time_second, time_micsecond) 364 | return retstr 365 | 366 | if __name__=="__main__": 367 | dbinfo=["","","","",""] #dbhost,dbport,dbuser,dbpwd,dbname 368 | sqltext="" 369 | option=[] 370 | config_file="" 371 | mysql_version="" 372 | 373 | opts, args = getopt.getopt(sys.argv[1:], "p:s:") 374 | for o,v in opts: 375 | if o == "-p": 376 | config_file = v 377 | elif o == "-s": 378 | sqltext = v 379 | 380 | config = ConfigParser.ConfigParser() 381 | config.readfp(open(config_file,"rb")) 382 | dbinfo[0] = config.get("database","server_ip") 383 | dbinfo[1] = config.get("database","server_port") 384 | dbinfo[2] = config.get("database","db_user") 385 | dbinfo[3] = config.get("database","db_pwd") 386 | dbinfo[4] = config.get("database","db_name") 387 | 388 | mysql_version = f_get_mysql_version(dbinfo).split('-')[0] 389 | 390 | f_print_title(dbinfo,mysql_version,sqltext) 391 | 392 | if config.get("option","sys_parm")=='ON': 393 | parm_result = f_get_parm(dbinfo) 394 | optimizer_switch_result = f_get_optimizer_switch(dbinfo) 395 | f_print_parm(parm_result) 396 | f_print_optimizer_switch(optimizer_switch_result) 397 | 398 | if config.get("option","sql_plan")=='ON': 399 | sqlplan_result = f_get_sqlplan(dbinfo,sqltext) 400 | f_print_sqlplan(sqlplan_result['SQLPLAN'],sqlplan_result['WARNING'],mysql_version) 401 | 402 | if config.get("option","obj_stat")=='ON': 403 | print "\033[1;31;40m%s\033[0m" % "===== OBJECT STATISTICS =====" 404 | for table_name in extract_tables(sqltext): 405 | f_print_tableinfo(f_get_tableinfo(dbinfo,table_name)) 406 | f_print_indexinfo(f_get_indexinfo(dbinfo,table_name)) 407 | f_print_indexstat(f_get_indexstat(dbinfo,table_name)) 408 | print 409 | 410 | if config.get("option","ses_status")=='ON': 411 | option.append('STATUS') 412 | 413 | if config.get("option","sql_profile")=='ON': 414 | option.append('PROFILING') 415 | 416 | if config.get("option","ses_status")=='ON' or config.get("option","sql_profile")=='ON': 417 | starttime = datetime.datetime.now() 418 | exec_result = f_exec_sql(dbinfo,sqltext,option) 419 | endtime = datetime.datetime.now() 420 | 421 | if config.get("option","ses_status")=='ON': 422 | f_print_status(f_calc_status(exec_result['BEFORE_STATUS'],exec_result['AFTER_STATUS'])) 423 | 424 | if config.get("option","sql_profile")=='ON': 425 | f_print_profiling(exec_result['PROFILING_DETAIL'],exec_result['PROFILING_SUMMARY']) 426 | 427 | f_print_time(starttime,endtime) -------------------------------------------------------------------------------- /mysql_tuning_v3.py: -------------------------------------------------------------------------------- 1 | #!/usr/local/bin/python 2 | import datetime 3 | import getopt 4 | import sys 5 | import re 6 | from warnings import filterwarnings 7 | import pymysql 8 | import configparser 9 | import sqlparse 10 | from sqlparse.sql import IdentifierList, Identifier 11 | from sqlparse.tokens import Keyword, DML,Token 12 | from prettytable import PrettyTable 13 | 14 | filterwarnings('ignore',category=pymysql.Warning) 15 | 16 | SYS_PARM_FILTER = ( 17 | 'BINLOG_CACHE_SIZE', 18 | 'BULK_INSERT_BUFFER_SIZE', 19 | 'HAVE_PARTITION_ENGINE', 20 | 'HAVE_QUERY_CACHE', 21 | 'INTERACTIVE_TIMEOUT', 22 | 'JOIN_BUFFER_SIZE', 23 | 'KEY_BUFFER_SIZE', 24 | 'KEY_CACHE_AGE_THRESHOLD', 25 | 'KEY_CACHE_BLOCK_SIZE', 26 | 'KEY_CACHE_DIVISION_LIMIT', 27 | 'LARGE_PAGES', 28 | 'LOCKED_IN_MEMORY', 29 | 'LONG_QUERY_TIME', 30 | 'MAX_ALLOWED_PACKET', 31 | 'MAX_BINLOG_CACHE_SIZE', 32 | 'MAX_BINLOG_SIZE', 33 | 'MAX_CONNECT_ERRORS', 34 | 'MAX_CONNECTIONS', 35 | 'MAX_JOIN_SIZE', 36 | 'MAX_LENGTH_FOR_SORT_DATA', 37 | 'MAX_SEEKS_FOR_KEY', 38 | 'MAX_SORT_LENGTH', 39 | 'MAX_TMP_TABLES', 40 | 'MAX_USER_CONNECTIONS', 41 | 'OPTIMIZER_PRUNE_LEVEL', 42 | 'OPTIMIZER_SEARCH_DEPTH', 43 | 'QUERY_CACHE_SIZE', 44 | 'QUERY_CACHE_TYPE', 45 | 'QUERY_PREALLOC_SIZE', 46 | 'RANGE_ALLOC_BLOCK_SIZE', 47 | 'READ_BUFFER_SIZE', 48 | 'READ_RND_BUFFER_SIZE', 49 | 'SORT_BUFFER_SIZE', 50 | 'SQL_MODE', 51 | 'TABLE_CACHE', 52 | 'THREAD_CACHE_SIZE', 53 | 'TMP_TABLE_SIZE', 54 | 'WAIT_TIMEOUT' 55 | ) 56 | 57 | def print_table(p_title_list, p_data_list, p_align=[]): 58 | x = PrettyTable(p_title_list) 59 | x.padding_width = 1 60 | for i in range(0, len(p_align)): 61 | if p_align[i] == "l": 62 | x.align[p_title_list[i]] = "l" 63 | elif p_align[i] == "r": 64 | x.align[p_title_list[i]] = "r" 65 | else: 66 | pass 67 | 68 | for rec in p_data_list: 69 | if type(rec) != 'list': 70 | rec = list(rec) 71 | x.add_row(rec) 72 | print(x) 73 | 74 | 75 | def is_subselect(parsed): 76 | if not parsed.is_group: 77 | return False 78 | for item in parsed.tokens: 79 | if item.ttype is DML and item.value.upper() == 'SELECT': 80 | return True 81 | return False 82 | 83 | def extract_from_part(parsed): 84 | from_seen = False 85 | for item in parsed.tokens: 86 | # print(item.ttype,item.value) 87 | if from_seen: 88 | if item.ttype is not Token.Text.Whitespace: 89 | if is_subselect(item): 90 | for x in extract_from_part(item): 91 | yield x 92 | elif item.ttype is Keyword: 93 | raise StopIteration 94 | else: 95 | yield item 96 | elif item.ttype is Keyword and item.value.upper() == 'FROM': 97 | from_seen = True 98 | 99 | def extract_table_identifiers(token_stream): 100 | for item in token_stream: 101 | if isinstance(item, IdentifierList): 102 | for identifier in item.get_identifiers(): 103 | yield identifier.get_real_name() 104 | elif isinstance(item, Identifier): 105 | yield item.get_real_name() 106 | # It's a bug to check for Keyword here, but in the example 107 | # above some tables names are identified as keywords... 108 | elif item.ttype is Keyword: 109 | yield item.value 110 | 111 | 112 | def extract_tables(p_sqltext): 113 | stream = extract_from_part(sqlparse.parse(p_sqltext)[0]) 114 | return list(extract_table_identifiers(stream)) 115 | 116 | 117 | def f_find_in_list(myList, value): 118 | try: 119 | for v in range(0, len(myList)): 120 | if value == myList[v]: 121 | return 1 122 | return 0 123 | except: 124 | return 0 125 | 126 | 127 | def f_get_parm(p_dbinfo): 128 | conn = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 129 | database=p_dbinfo[4]) 130 | cursor = conn.cursor() 131 | cursor.execute( 132 | "select lower(variable_name),variable_value from INFORMATION_SCHEMA.GLOBAL_VARIABLES where upper(variable_name) in ('" + "','".join( 133 | list(SYS_PARM_FILTER)) + "') order by variable_name") 134 | records = cursor.fetchall() 135 | cursor.close() 136 | conn.close() 137 | return records 138 | 139 | 140 | def f_print_parm(p_parm_result): 141 | print("\033[1;31;40m%s\033[0m" % "===== SYSTEM PARAMETER =====") 142 | v_data = [] 143 | for i in range(0, len(p_parm_result)): 144 | if 'size' in p_parm_result[i][0]: 145 | if int(p_parm_result[i][1]) >= 1024 * 1024 * 1024: 146 | v_data.append( 147 | [p_parm_result[i][0], str(round(int(p_parm_result[i][1]) / 1024 / 1024 / 1024, 2)) + ' G']) 148 | elif int(p_parm_result[i][1]) >= 1024 * 1024: 149 | v_data.append( 150 | [p_parm_result[i][0], str(round(int(p_parm_result[i][1]) / 1024 / 1024, 2)) + ' M']) 151 | elif int(p_parm_result[i][1]) >= 1024: 152 | v_data.append([p_parm_result[i][0], str(round(int(p_parm_result[i][1]) / 1024, 2)) + ' K']) 153 | else: 154 | v_data.append([p_parm_result[i][0], p_parm_result[i][1] + ' B']) 155 | else: 156 | pass 157 | print_table(['parameter_name', 'value'], v_data, ['l', 'r']) 158 | print 159 | 160 | 161 | def f_get_optimizer_switch(p_dbinfo): 162 | conn = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 163 | database=p_dbinfo[4]) 164 | cursor = conn.cursor() 165 | cursor.execute( 166 | "select variable_value from INFORMATION_SCHEMA.GLOBAL_VARIABLES where upper(variable_name)='OPTIMIZER_SWITCH'") 167 | records = cursor.fetchall() 168 | cursor.close() 169 | conn.close() 170 | result = [] 171 | for o in str(records[0][0]).split(','): 172 | result.append([o.split('=')[0], o.split('=')[1]]) 173 | return result 174 | 175 | 176 | def f_get_datadir(p_dbinfo): 177 | conn = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 178 | database=p_dbinfo[4]) 179 | cursor = conn.cursor() 180 | cursor.execute( 181 | "select variable_value from INFORMATION_SCHEMA.GLOBAL_VARIABLES where upper(variable_name)='DATADIR'") 182 | records = cursor.fetchall() 183 | result= records[0][0]+p_dbinfo[4] 184 | cursor.close() 185 | conn.close() 186 | return result 187 | 188 | def f_print_optimizer_switch(p_optimizer_switch_result): 189 | print("\033[1;31;40m%s\033[0m" % "===== OPTIMIZER SWITCH =====") 190 | print_table(['switch_name', 'value'], p_optimizer_switch_result, ['l', 'r']) 191 | print 192 | 193 | 194 | def f_exec_sql(p_dbinfo, p_sqltext, p_option): 195 | results = {} 196 | conn = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 197 | database=p_dbinfo[4]) 198 | cursor = conn.cursor() 199 | 200 | if f_find_in_list(p_option, 'OPT_TRACE'): 201 | cursor.execute("set session optimizer_trace='enabled=on'") 202 | cursor.execute("set optimizer_trace_max_mem_size=1000000") 203 | cursor.execute("set optimizer_trace_limit=10") 204 | cursor.execute("set optimizer_trace_offset=-10") 205 | # cursor.execute("set end_markers_in_json=on") 206 | 207 | if f_find_in_list(p_option, 'PROFILING'): 208 | cursor.execute("set profiling=1") 209 | cursor.execute("select ifnull(max(query_id),0) from INFORMATION_SCHEMA.PROFILING") 210 | records = cursor.fetchall() 211 | query_id = records[0][0] + 2 #skip next sql 212 | 213 | if f_find_in_list(p_option, 'STATUS'): 214 | cursor.execute( 215 | "select concat(upper(left(variable_name,1)),substring(lower(variable_name),2,(length(variable_name)-1))) var_name,variable_value var_value from INFORMATION_SCHEMA.SESSION_STATUS order by 1") 216 | records = cursor.fetchall() 217 | results['BEFORE_STATUS'] = dict(records) 218 | 219 | cursor.execute(p_sqltext) 220 | 221 | if f_find_in_list(p_option, 'STATUS'): 222 | cursor.execute( 223 | "select concat(upper(left(variable_name,1)),substring(lower(variable_name),2,(length(variable_name)-1))) var_name,variable_value var_value from INFORMATION_SCHEMA.SESSION_STATUS order by 1") 224 | records = cursor.fetchall() 225 | results['AFTER_STATUS'] = dict(records) 226 | 227 | if f_find_in_list(p_option, 'PROFILING'): 228 | cursor.execute( 229 | "select STATE,DURATION,CPU_USER,CPU_SYSTEM,BLOCK_OPS_IN,BLOCK_OPS_OUT ,MESSAGES_SENT ,MESSAGES_RECEIVED ,PAGE_FAULTS_MAJOR ,PAGE_FAULTS_MINOR ,SWAPS from INFORMATION_SCHEMA.PROFILING where query_id=" + str( 230 | query_id) + " order by seq") 231 | records = cursor.fetchall() 232 | results['PROFILING_DETAIL'] = records 233 | 234 | cursor.execute( 235 | "SELECT STATE,SUM(DURATION) AS Total_R,ROUND(100*SUM(DURATION)/(SELECT SUM(DURATION) FROM INFORMATION_SCHEMA.PROFILING WHERE QUERY_ID=" + str( 236 | query_id) + "),2) AS Pct_R,COUNT(*) AS Calls,SUM(DURATION)/COUNT(*) AS R_Call FROM INFORMATION_SCHEMA.PROFILING WHERE QUERY_ID=" + str( 237 | query_id) + " GROUP BY STATE ORDER BY Total_R DESC") 238 | records = cursor.fetchall() 239 | results['PROFILING_SUMMARY'] = records 240 | 241 | if f_find_in_list(p_option, 'OPT_TRACE'): 242 | if sys.platform=="win32" or sys.platform=="win64": 243 | break_char="\\" 244 | else: 245 | break_char="\/" 246 | 247 | dumpfile="optimizer_trace_"+ re.sub(r'[\-\:\.]','',datetime.datetime.now().isoformat())+".json" 248 | cursor.execute("SELECT TRACE INTO DUMPFILE '"+dumpfile+"' FROM INFORMATION_SCHEMA.OPTIMIZER_TRACE WHERE QUERY='"+p_sqltext+"';") 249 | results['OPT_TRACE'] = f_get_datadir(p_dbinfo)+break_char+dumpfile 250 | 251 | cursor.close() 252 | conn.close() 253 | return results 254 | 255 | 256 | def f_calc_status(p_before_status, p_after_status): 257 | results = [] 258 | for key in sorted(p_before_status.keys()): 259 | if p_before_status[key] != p_after_status[key]: 260 | results.append([key, p_before_status[key], p_after_status[key], 261 | str(float(p_after_status[key]) - float(p_before_status[key]))]) 262 | return results 263 | 264 | 265 | def f_print_status(p_status_data): 266 | print("\033[1;31;40m%s\033[0m" % "===== SESSION STATUS (DIFFERENT) =====") 267 | print_table(['status_name', 'before', 'after', 'diff'], p_status_data, ['l', 'r', 'r', 'r']) 268 | print 269 | 270 | 271 | def f_print_time(p_starttime, p_endtime): 272 | print("\033[1;31;40m%s\033[0m" % "===== EXECUTE TIME =====") 273 | print(timediff(p_starttime, p_endtime)) 274 | print 275 | 276 | 277 | def f_print_profiling(p_profiling_detail, p_profiling_summary): 278 | print("\033[1;31;40m%s\033[0m" % "===== SQL PROFILING(DETAIL)=====") 279 | print_table( 280 | ['state', 'duration', 'cpu_user', 'cpu_sys', 'bk_in', 'bk_out', 'msg_s', 'msg_r', 'p_f_ma', 'p_f_mi', 'swaps'], 281 | p_profiling_detail, ['l', 'r', 'r', 'r', 'r', 'r', 'r', 'r', 'r', 'r', 'r']) 282 | print('bk_in: block_ops_in') 283 | print('bk_out: block_ops_out') 284 | print('msg_s: message sent') 285 | print('msg_r: message received') 286 | print('p_f_ma: page_faults_major') 287 | print('p_f_mi: page_faults_minor') 288 | print 289 | 290 | print("\033[1;31;40m%s\033[0m" % "===== SQL PROFILING(SUMMARY)=====") 291 | print_table(['state', 'total_r', 'pct_r', 'calls', 'r/call'], p_profiling_summary, ['l', 'r', 'r', 'r', 'r']) 292 | print 293 | 294 | def f_print_optimizer_trace(p_trace_file): 295 | print("\033[1;31;40m%s\033[0m" % "===== OPTIMIZER TRACE FILE =====") 296 | print(p_trace_file) 297 | print 298 | 299 | def f_get_sqlplan(p_dbinfo, p_sqltext): 300 | results = {} 301 | 302 | db = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 303 | database = p_dbinfo[4]) 304 | cursor = db.cursor() 305 | cursor.execute("explain extended " + p_sqltext) 306 | records = cursor.fetchall() 307 | results['SQLPLAN'] = records 308 | cursor.execute("show warnings") 309 | records = cursor.fetchall() 310 | results['WARNING'] = records 311 | cursor.close() 312 | db.close() 313 | return results 314 | 315 | 316 | def f_null(p_value): 317 | if not p_value: 318 | return '' 319 | 320 | 321 | def f_print_sqlplan(p_sqlplan, p_warning, p_mysql_version): 322 | plan_title = ( 323 | 'id', 'select_type', 'table', 'type', 'possible_keys', 'key', 'key_len', 'ref', 'rows', 'filtered', 'Extra') 324 | 325 | print("\033[1;31;40m%s\033[0m" % "===== SQL PLAN =====") 326 | 327 | if p_mysql_version.split('.')[1] == '7': #5.7 328 | print_table( 329 | ['id', 'select_type', 'table', 'partitions', 'type', 'possible_keys', 'key', 'key_len', 'ref', 'rows', 330 | 'filtered', 'Extra'], p_sqlplan, ['r', 'l', 'l', 'l', 'l', 'l', 'l', 'l', 'l', 'r', 'r', 'l']) 331 | else: 332 | print_table(['id', 'select_type', 'table', 'type', 'possible_keys', 'key', 'key_len', 'ref', 'rows', 'filtered', 333 | 'Extra'], p_sqlplan, ['r', 'l', 'l', 'l', 'l', 'l', 'l', 'l', 'r', 'r', 'l']) 334 | print 335 | 336 | print("\033[1;31;40m%s\033[0m" % "===== OPTIMIZER REWRITE SQL =====") 337 | for row in p_warning: 338 | print(sqlparse.format(row[2], reindent=True, keyword_case='upper', strip_comments=True)) 339 | print 340 | 341 | 342 | def f_get_table(p_dbinfo, p_sqltext): 343 | r_tables = [] 344 | db = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 345 | database=p_dbinfo[4]) 346 | cursor = db.cursor() 347 | cursor.execute("explain " + p_sqltext) 348 | rows = cursor.fetchall() 349 | for row in rows: 350 | table_name = row[2] 351 | if '<' in table_name: 352 | continue 353 | if len(r_tables) == 0: 354 | r_tables.append(table_name) 355 | elif f_find_in_list(r_tables, table_name) == -1: 356 | r_tables.append(table_name) 357 | cursor.close() 358 | db.close() 359 | return r_tables 360 | 361 | 362 | def f_get_tableinfo(p_dbinfo, p_tablename): 363 | db = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 364 | database=p_dbinfo[4]) 365 | cursor = db.cursor() 366 | #cursor.execute("select table_name,engine,row_format as format,table_rows,avg_row_length as avg_row,round((data_length+index_length)/1024/1024,2) as total_mb,round((data_length)/1024/1024,2) as data_mb,round((index_length)/1024/1024,2) as index_mb from information_schema.tables where table_schema='"+p_dbinfo[4]+"' and table_name='"+p_tablename+"'") 367 | cursor.execute( 368 | "select a.table_name,a.engine,a.row_format as format,a.table_rows,a.avg_row_length as avg_row,round((a.data_length+a.index_length)/1024/1024,2) as total_mb,round((a.data_length)/1024/1024,2) as data_mb,round((a.index_length)/1024/1024,2) as index_mb,a.create_time,b.last_update last_analyzed from information_schema.tables a ,mysql.innodb_table_stats b where a.table_schema=b.database_name and a.table_name=b.table_name and a.table_schema='" + 369 | p_dbinfo[4] + "' and a.table_name='" + p_tablename + "'") 370 | records = cursor.fetchall() 371 | cursor.close() 372 | db.close() 373 | return records 374 | 375 | 376 | def f_print_tableinfo(p_table_stat): 377 | print_table( 378 | ['table_name', 'engine', 'format', 'table_rows', 'avg_row', 'total_mb', 'data_mb', 'index_mb', 'create_time', 379 | 'last_analyzed'], p_table_stat, ['l', 'l', 'l', 'r', 'r', 'r', 'r', 'r', 'c', 'c']) 380 | 381 | 382 | def f_get_indexinfo(p_dbinfo, p_tablename): 383 | db = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 384 | database=p_dbinfo[4]) 385 | cursor = db.cursor() 386 | cursor.execute( 387 | "select index_name,non_unique,seq_in_index,column_name,collation,cardinality,nullable,index_type from information_schema.statistics where table_schema='" + 388 | p_dbinfo[4] + "' and table_name='" + p_tablename + "' order by 1,3") 389 | records = cursor.fetchall() 390 | cursor.close() 391 | db.close() 392 | return records 393 | 394 | 395 | def f_print_indexinfo(p_index_info): 396 | if len(p_index_info) > 0: 397 | print_table(['index_name', 'non_unique', 'seq_in_index', 'column_name', 'collation', 'cardinality', 'nullable', 398 | 'index_type'], p_index_info, ['l', 'r', 'r', 'l', '', 'r', 'r', 'l']) 399 | 400 | 401 | def f_get_indexstat(p_dbinfo, p_tablename): 402 | db = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 403 | database=p_dbinfo[4]) 404 | cursor = db.cursor() 405 | cursor.execute( 406 | "select index_name,last_update last_analyzed,stat_name,stat_value,sample_size,stat_description from mysql.innodb_index_stats a where database_name='" + 407 | p_dbinfo[4] + "' and table_name='" + p_tablename + "' order by index_name,stat_name") 408 | records = cursor.fetchall() 409 | cursor.close() 410 | db.close() 411 | return records 412 | 413 | 414 | def f_print_indexstat(p_index_stat): 415 | if len(p_index_stat) > 0: 416 | print_table(['index_name', 'last_analyzed', 'stat_name', 'stat_value', 'sample_size', 'stat_description'], 417 | p_index_stat, ['l', 'c', 'l', 'r', 'r', 'l']) 418 | 419 | 420 | def f_get_mysql_version(p_dbinfo): 421 | db = pymysql.connect(host=p_dbinfo[0], port=int(p_dbinfo[1]), user=p_dbinfo[2], password=p_dbinfo[3], 422 | database=p_dbinfo[4]) 423 | cursor = db.cursor() 424 | cursor.execute("select @@version") 425 | records = cursor.fetchall() 426 | cursor.close() 427 | db.close() 428 | return records[0][0] 429 | 430 | def f_print_title(p_dbinfo, p_mysql_version, p_sqltext): 431 | print 432 | print('*' * 100) 433 | print('*', 'MySQL SQL Tuning Tools v2.0 (by hanfeng)'.center(96), '*') 434 | print('*' * 100) 435 | print 436 | 437 | print("\033[1;31;40m%s\033[0m" % "===== BASIC INFORMATION =====") 438 | print_table(['server_ip', 'server_port', 'user_name', 'db_name', 'db_version'], 439 | [[p_dbinfo[0], p_dbinfo[1], p_dbinfo[2], p_dbinfo[4], p_mysql_version]]) 440 | print 441 | 442 | print("\033[1;31;40m%s\033[0m" % "===== ORIGINAL SQL TEXT =====") 443 | print(sqlparse.format(p_sqltext, reindent=True, keyword_case='upper')) 444 | print 445 | 446 | 447 | def timediff(timestart, timestop): 448 | t = (timestop - timestart) 449 | time_day = t.days 450 | s_time = t.seconds 451 | ms_time = t.microseconds / 1000000 452 | usedtime = int(s_time + ms_time) 453 | time_hour = usedtime / 60 / 60 454 | time_minute = (usedtime - time_hour * 3600 ) / 60 455 | time_second = usedtime - time_hour * 3600 - time_minute * 60 456 | time_micsecond = (t.microseconds - t.microseconds / 1000000) / 1000 457 | 458 | retstr = "%d day %d hour %d minute %d second %d microsecond " % ( 459 | time_day, time_hour, time_minute, time_second, time_micsecond) 460 | return retstr 461 | 462 | 463 | if __name__ == "__main__": 464 | dbinfo = ["", "", "", "", ""] #dbhost,dbport,dbuser,dbpwd,dbname 465 | sqltext = "" 466 | option = [] 467 | config_file = "" 468 | mysql_version = "" 469 | 470 | opts, args = getopt.getopt(sys.argv[1:], "p:s:") 471 | for o, v in opts: 472 | if o == "-p": 473 | config_file = v 474 | elif o == "-s": 475 | sqltext = v 476 | 477 | config = configparser.ConfigParser() 478 | config.read(config_file) 479 | 480 | dbinfo[0] = config.get("database", "server_ip") 481 | dbinfo[1] = config.get("database", "server_port") 482 | dbinfo[2] = config.get("database", "db_user") 483 | dbinfo[3] = config.get("database", "db_pwd") 484 | dbinfo[4] = config.get("database", "db_name") 485 | 486 | mysql_version = f_get_mysql_version(dbinfo).split('-')[0] 487 | 488 | f_print_title(dbinfo, mysql_version, sqltext) 489 | 490 | if config.get("option", "sys_parm") == 'ON': 491 | parm_result = f_get_parm(dbinfo) 492 | optimizer_switch_result = f_get_optimizer_switch(dbinfo) 493 | f_print_parm(parm_result) 494 | f_print_optimizer_switch(optimizer_switch_result) 495 | 496 | if config.get("option", "sql_plan") == 'ON': 497 | sqlplan_result = f_get_sqlplan(dbinfo, sqltext) 498 | f_print_sqlplan(sqlplan_result['SQLPLAN'], sqlplan_result['WARNING'], mysql_version) 499 | 500 | if config.get("option", "obj_stat") == 'ON': 501 | print("\033[1;31;40m%s\033[0m" % "===== OBJECT STATISTICS =====") 502 | for table_name in extract_tables(sqltext): 503 | f_print_tableinfo(f_get_tableinfo(dbinfo, table_name)) 504 | f_print_indexinfo(f_get_indexinfo(dbinfo, table_name)) 505 | f_print_indexstat(f_get_indexstat(dbinfo, table_name)) 506 | print 507 | 508 | if config.get("option", "ses_status") == 'ON': 509 | option.append('STATUS') 510 | 511 | if config.get("option", "sql_profile") == 'ON': 512 | option.append('PROFILING') 513 | 514 | if config.get("option", "opt_trace") == 'ON': 515 | option.append('OPT_TRACE') 516 | 517 | if config.get("option", "ses_status") == 'ON' or config.get("option", "sql_profile") == 'ON' or config.get("option", "opt_trace") == 'ON': 518 | starttime = datetime.datetime.now() 519 | exec_result = f_exec_sql(dbinfo, sqltext, option) 520 | endtime = datetime.datetime.now() 521 | 522 | if config.get("option", "ses_status") == 'ON': 523 | f_print_status(f_calc_status(exec_result['BEFORE_STATUS'], exec_result['AFTER_STATUS'])) 524 | 525 | if config.get("option", "sql_profile") == 'ON': 526 | f_print_profiling(exec_result['PROFILING_DETAIL'], exec_result['PROFILING_SUMMARY']) 527 | 528 | if config.get("option", "opt_trace") == 'ON': 529 | f_print_optimizer_trace(exec_result['OPT_TRACE']) 530 | 531 | f_print_time(starttime, endtime) 532 | --------------------------------------------------------------------------------