-
Notifications
You must be signed in to change notification settings - Fork 20
/
Copy pathmysql_watcher.py
1336 lines (1215 loc) · 77.3 KB
/
mysql_watcher.py
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
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
#!/usr/local/bin/python
# coding: utf-8
# MySQL Watcher V1.2.0
# trouble shoot MySQL performance
# Copyright (C) 2017-2017 Kinghow - Kinghow@hotmail.com
# Git repository available at https://github.com/kinghows/MySQL_Watcher
import getopt
import sys
import MySQLdb
import ConfigParser
import math
import time
import os
import prettytable
import psutil
import platform
import glob
import re
from collections import OrderedDict
from collections import namedtuple
from warnings import filterwarnings
filterwarnings('ignore', category = MySQLdb.Warning)
tab1="="
tab2="*"
linesize=104
SYS_PARM_FILTER = (
'autocommit',
'binlog_cache_size',
'bulk_insert_buffer_size',
'character_set_server',
'tx_isolation',
'tx_read_only',
'sql_mode',
# connection #
'interactive_timeout',
'wait_timeout',
'lock_wait_timeout',
'skip_name_resolve',
'max_connections',
'max_connect_errors',
# table cache performance settings
'table_open_cache',
'table_definition_cache',
'table_open_cache_instances',
# performance settings
'have_query_cache',
'join_buffer_size',
'key_buffer_size',
'key_cache_age_threshold',
'key_cache_block_size',
'key_cache_division_limit',
'large_pages',
'locked_in_memory',
'long_query_time',
'max_allowed_packet',
'max_binlog_size',
'max_length_for_sort_data',
'max_sort_length',
'max_tmp_tables',
'max_user_connections',
'optimizer_prune_level',
'optimizer_search_depth',
'query_cache_size',
'query_cache_type',
'query_prealloc_size',
'range_alloc_block_size',
# session memory settings #
'read_buffer_size',
'read_rnd_buffer_size',
'sort_buffer_size',
'tmp_table_size',
'join_buffer_size',
'thread_cache_size',
# log settings #
'log_error',
'slow_query_log',
'slow_query_log_file',
'log_queries_not_using_indexes',
'log_slow_admin_statements',
'log_slow_slave_statements',
'log_throttle_queries_not_using_indexes',
'expire_logs_days',
'long_query_time',
'min_examined_row_limit',
'binlog-rows-query-log-events',
'log-bin-trust-function-creators',
'expire-logs-days',
'log-slave-updates',
# innodb settings #
'innodb_page_size',
'innodb_buffer_pool_size',
'innodb_buffer_pool_instances',
'innodb_buffer_pool_chunk_size',
'innodb_buffer_pool_load_at_startup',
'innodb_buffer_pool_dump_at_shutdown',
'innodb_lru_scan_depth',
'innodb_lock_wait_timeout',
'innodb_io_capacity',
'innodb_io_capacity_max',
'innodb_flush_method',
'innodb_file_format',
'innodb_file_format_max',
'innodb_undo_logs',
'innodb_undo_tablespaces',
'innodb_flush_neighbors',
'innodb_log_file_size',
'innodb_log_files_in_group',
'innodb_log_buffer_size',
'innodb_purge_threads',
'innodb_large_prefix',
'innodb_thread_concurrency',
'innodb_print_all_deadlocks',
'innodb_strict_mode',
'innodb_sort_buffer_size',
'innodb_write_io_threads',
'innodb_read_io_threads',
'innodb_file_per_table',
'innodb_stats_persistent_sample_pages',
'innodb_autoinc_lock_mode',
'innodb_online_alter_log_max_size',
'innodb_open_files',
# replication settings #
'master_info_repository',
'relay_log_info_repository',
'sync_binlog',
'gtid_mode',
'enforce_gtid_consistency',
'log_slave_updates',
'binlog_format',
'binlog_rows_query_log_events',
'relay_log',
'relay_log_recovery',
'slave_skip_errors',
'slave-rows-search-algorithms',
# semi sync replication settings #
'plugin_load',
'rpl_semi_sync_master_enabled',
'rpl_semi_sync_master_timeout',
'rpl_semi_sync_slave_enabled',
# password plugin #
'validate_password_policy',
'validate-password',
# metalock performance settings
'metadata_locks_hash_instances',
# new innodb settings #
'loose_innodb_numa_interleave',
'innodb_buffer_pool_dump_pct',
'innodb_page_cleaners',
'innodb_undo_log_truncate',
'innodb_max_undo_log_size',
'innodb_purge_rseg_truncate_frequency',
# new replication settings #
'slave-parallel-type',
'slave-parallel-workers',
'slave_preserve_commit_order',
'slave_transaction_retries',
# other change settings #
'binlog_gtid_simple_recovery',
'log_timestamps',
'show_compatibility_56'
)
def f_get_conn(dbinfo):
try:
conn = MySQLdb.connect(host=dbinfo[0],user=dbinfo[1],passwd=dbinfo[2],db=dbinfo[3],port=int(dbinfo[4]))
return conn
except MySQLdb.Error, e:
print "Error %d: %s" % (e.args[0], e.args[1])
sys.exit(1)
def f_get_query_value(conn, query):
cursor = conn.cursor()
getNum = cursor.execute(query)
if getNum > 0:
result = cursor.fetchone()
else:
result = ['0']
cursor.close()
return result[0]
def f_get_query_record(conn, query):
cursor = conn.cursor()
cursor.execute(query)
records = cursor.fetchall()
cursor.close()
return records
def f_print_title(title):
print
print ((linesize-4)/2 - int(len(title) / 2)) * tab1, title, ((linesize-4)/2+1 - int(len(title) / 2)) * tab1
print
def f_print_table_body(rows, style,tab):
for row in rows:
k = 0
for col in row:
k += 1
print tab,
if style[k].split(',')[2] == 'l':
print str(col).ljust(int(style[k].split(',')[1])),
elif style[k].split(',')[2] == 'r':
print str(col).rjust(int(style[k].split(',')[1])),
else:
print str(col).center(int(style[k].split(',')[1])),
print tab
def f_print_table_txt(rows, title, style):
field_names = []
f_print_title(title)
table = prettytable.PrettyTable()
for k in style.keys():
field_names.append(style[k].split(',')[0])
table.field_names = field_names
for k in style.keys():
table.align[style[k].split(',')[0]] = style[k].split(',')[1]
for row in rows:
table.add_row(row)
print table
def f_print_table_html(rows, title, style):
print """<p /><h3 class="awr"><a class="awr" name="99999"></a>""" + title + "</h3><p />"
print """<table border="1">"""
print """<tr>""",
for k in style.keys():
v = style[k]
print """<th class="awrbg">""",
print v.split(',')[0],
print """</th>""",
print """</tr>"""
linenum = 0
for row in rows:
k = 0
linenum += 1
print "<tr>",
if linenum % 2 == 0:
classs='awrc'
else:
classs='awrnc'
for col in row:
k += 1
if style[k].split(',')[1] == 'r':
print """<td align="right" class='"""+classs+"'>"+str(col)+"</td>",
else:
print """<td class='"""+classs+"'>"+str(col)+"</td>",
print "</tr>"
print """</table>
<br /><a class="awr" href="#top">Back to Top</a>
<p />
<p />
"""
def f_print_table(rows,title,style,save_as):
if save_as == "txt":
f_print_table_txt(rows, title, style)
elif save_as == "html":
f_print_table_html(rows, title, style)
def f_print_query_table(conn, title, query, style,save_as):
rows = f_get_query_record(conn, query)
f_print_table(rows,title,style,save_as)
def f_is_sys_schema_exist(conn):
query = "SHOW DATABASES"
rows = f_get_query_record(conn, query)
exist=False
for row in rows:
if row[0]=='sys':
exist = True
break
return exist
def f_print_optimizer_switch(conn,save_as,perfor_or_infor):
title = "Optimizer Switch"
style = {1: 'switch_name,l', 2: 'value,r'}
rows =[]
query="select variable_value from "+perfor_or_infor+".global_variables where variable_name='optimizer_switch'"
recode = f_get_query_record(conn, query)
for col in recode[0][0].split(','):
rows.append([col.split('=')[0],col.split('=')[1]])
f_print_table(rows, title, style,save_as)
def f_print_log_error(conn,perfor_or_infor,save_as):
title = "Log file Statistics"
style = {1: 'start & shutdown:,l'}
rows =[]
WarnLog = 0
ErrLog = 0
query = "SELECT variable_value FROM " + perfor_or_infor + ".global_variables where variable_name ='log_error'"
filename = f_get_query_value(conn, query)
if os.path.exists(filename):
with open(filename, 'r') as f:
for line in f:
if ('ready for connections' in line or 'Shutdown completed' in line):
rows.append([line])
if ('Warning' in line):
WarnLog += 1
if ('error' in line):
ErrLog += 1
else:
rows.append([filename + " not exists"])
rows.append(['Warning & Error Statistics:'])
rows.append([filename + ' contains ' + str(WarnLog) + ' warning(s).'])
rows.append([filename + ' contains ' + str(ErrLog) + ' error(s).'])
f_print_table(rows, title, style,save_as)
def f_print_caption(dbinfo,mysql_version,save_as):
if save_as == "txt":
print tab2 * linesize
print tab2, 'MySQL Watcher V1.2.0'.center(linesize - 4), tab2
print tab2, 'Kinghow@hotmail.com'.center(linesize - 4), tab2
print tab2, 'https://github.com/kinghows/MySQL_Watcher'.center(linesize - 4), tab2
print tab2 * linesize
elif save_as == "html":
print """
<html><head><title>MySQL Watcher V1.2.0 Kinghow@hotmail.com https://github.com/kinghows/MySQL_Watcher </title>
<style type=\"text/css\">
body.awr {font:bold 10pt Arial,Helvetica,Geneva,sans-serif;color:black; background:White;}
pre.awr {font:8pt Courier;color:black; background:White;}
h1.awr {font:bold 20pt Arial,Helvetica,Geneva,sans-serif;color:#336699;background-color:White;border-bottom:1px solid #cccc99;margin-top:0pt; margin-bottom:0pt;padding:0px 0px 0px 0px;}
h2.awr {font:bold 18pt Arial,Helvetica,Geneva,sans-serif;color:#336699;background-color:White;margin-top:4pt; margin-bottom:0pt;}
h3.awr {font:bold 16pt Arial,Helvetica,Geneva,sans-serif;color:#336699;background-color:White;margin-top:4pt; margin-bottom:0pt;}
li.awr {font: 8pt Arial,Helvetica,Geneva,sans-serif; color:black; background:White;}
th.awrnobg {font:bold 8pt Arial,Helvetica,Geneva,sans-serif; color:black; background:White;padding-left:4px; padding-right:4px;padding-bottom:2px}
th.awrbg {font:bold 8pt Arial,Helvetica,Geneva,sans-serif; color:White; background:#0066CC;padding-left:4px; padding-right:4px;padding-bottom:2px}
td.awrnc {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:White;vertical-align:top;}
td.awrc {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:#FFFFCC; vertical-align:top;}
td.awrnclb {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:White;vertical-align:top;border-left: thin solid black;}
td.awrncbb {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:White;vertical-align:top;border-left: thin solid black;border-right: thin solid black;}
td.awrncrb {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:White;vertical-align:top;border-right: thin solid black;}
td.awrcrb {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:#FFFFCC; vertical-align:top;border-right: thin solid black;}
td.awrclb {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:#FFFFCC; vertical-align:top;border-left: thin solid black;}
td.awrcbb {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:#FFFFCC; vertical-align:top;border-left: thin solid black;border-right: thin solid black;}
a.awr {font:bold 8pt Arial,Helvetica,sans-serif;color:#663300; vertical-align:top;margin-top:0pt; margin-bottom:0pt;}
td.awrnct {font:8pt Arial,Helvetica,Geneva,sans-serif;border-top: thin solid black;color:black;background:White;vertical-align:top;}
td.awrct {font:8pt Arial,Helvetica,Geneva,sans-serif;border-top: thin solid black;color:black;background:#FFFFCC; vertical-align:top;}
td.awrnclbt {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:White;vertical-align:top;border-top: thin solid black;border-left: thin solid black;}
td.awrncbbt {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:White;vertical-align:top;border-left: thin solid black;border-right: thin solid black;border-top: thin solid black;}
td.awrncrbt {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:White;vertical-align:top;border-top: thin solid black;border-right: thin solid black;}
td.awrcrbt {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:#FFFFCC; vertical-align:top;border-top: thin solid black;border-right: thin solid black;}
td.awrclbt {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:#FFFFCC; vertical-align:top;border-top: thin solid black;border-left: thin solid black;}
td.awrcbbt {font:8pt Arial,Helvetica,Geneva,sans-serif;color:black;background:#FFFFCC; vertical-align:top;border-top: thin solid black;border-left: thin solid black;border-right: thin solid black;}
table.tdiff { border_collapse: collapse; }
</style></head><body class="awr">
<h1 class="awr">
WORKLOAD REPOSITORY report for
</h1>
"""
title = "Basic Information"
style = {1: 'host,c', 2: 'user,c', 3: 'db,c', 4: 'mysql version,c'}
rows = [[dbinfo[0], dbinfo[1], dbinfo[3], mysql_version]]
f_print_table(rows, title, style,save_as)
def f_print_ending(save_as):
if save_as == "txt":
f_print_title('--@-- End --@--')
elif save_as == "html":
print """
<p />
End of Report
</body></html>
"""
def size(device):
nr_sectors = open(device+'/size').read().rstrip('\n')
sect_size = open(device+'/queue/hw_sector_size').read().rstrip('\n')
return (float(nr_sectors)*float(sect_size))/(1024.0*1024.0*1024.0)
def f_print_linux_info(save_as):
title = "Linux info"
style = {1: 'Linux,l',2: 'Info,l'}
rows =[]
#version
rows.append(["Version",platform.uname()[0]+' '+platform.uname()[2]+' '+platform.uname()[4]])
#cpu
cpu_count = 0
with open('/proc/cpuinfo') as f:
for line in f:
if line.strip():
if line.rstrip('\n').startswith('model name'):
model_name = line.rstrip('\n').split(':')[1]
cpu_count +=1
rows.append(["CPU",model_name + ' X '+str(cpu_count)])
#mem
meminfo = OrderedDict()
with open('/proc/meminfo') as f:
for line in f:
meminfo[line.split(':')[0]] = line.split(':')[1].strip()
rows.append(["Memory",'Total: {0}'.format(meminfo['MemTotal'])+' Free: {0}'.format(meminfo['MemFree'])])
#net
with open('/proc/net/dev') as f:
net_dump = f.readlines()
device_data = {}
data = namedtuple('data', ['rx', 'tx'])
for line in net_dump[2:]:
line = line.split(':')
if line[0].strip() != 'lo':
device_data[line[0].strip()] = data(float(line[1].split()[0]) / (1024.0 * 1024.0),
float(line[1].split()[8]) / (1024.0 * 1024.0))
for dev in device_data.keys():
rows.append(["Net",'{0}: {1} MiB {2} MiB'.format(dev, device_data[dev].rx, device_data[dev].tx)])
#Device
dev_pattern = ['sd.*', 'mmcblk*']
for device in glob.glob('/sys/block/*'):
for pattern in dev_pattern:
if re.compile(pattern).match(os.path.basename(device)):
rows.append(["Device",'{0}, Size: {1} GiB'.format(device, size(device))])
#process
pids = []
for subdir in os.listdir('/proc'):
if subdir.isdigit():
pids.append(subdir)
rows.append(["Processes",'Total number of running : {0}'.format(len(pids))])
f_print_table(rows, title, style,save_as)
def f_print_filesystem_info(save_as):
title = "Filesystem info"
style = {1: 'Filesystem,l',2: 'Size,r',3: 'Used,r',4: 'Avail,r',5: 'Use %,r',6: ' Mounted on,l'}
rows =[]
file_info = []
j = 0
for line in os.popen('df -h').readlines():
for eachList in line.strip().split():
file_info.append(eachList)
j +=1
i = 6
while i<j-6:
rows.append([file_info[i+1],file_info[i+2],file_info[i+3],file_info[i+4],file_info[i+5],file_info[i+6]])
i += 6
f_print_table(rows, title, style,save_as)
def f_print_linux_status(save_as):
###获取参数###################################################################
#scputimes(user=, nice, system, idle, iowait, irq, softirq,steal, guest, guest_nice)
cpu_times = psutil.cpu_times()
#scpustats(ctx_switches, interrupts, soft_interrupts, syscalls)
#cpu_stats = psutil.cpu_stats()
# svmem(total , available, percent, used , free, active, inactive, buffers, cached, shared)
mem = psutil.virtual_memory()
# sswap(total, used, free, percent, sin, sout)
swap = psutil.swap_memory()
#sdiskusage(total, used, free, percent)
#disk_usage = psutil.disk_usage('/')
#sdiskio(read_count, write_count, read_bytes, write_bytes, read_time, write_time)
#disk_io_counters = psutil.disk_io_counters()
#snetio(bytes_sent, bytes_recv, packets_sent, packets_recv, errin, errout, dropin, dropout)
#net = psutil.net_io_counters()
#load
try:
load = os.getloadavg()
except (OSError, AttributeError):
stats = {}
else:
stats = {'min1': load[0], 'min5': load[1], 'min15': load[2]}
#Uptime = datetime.datetime.fromtimestamp(psutil.boot_time()).strftime("%Y-%m-%d %H:%M:%S")
###打印参数###################################################################
style1 = {1: ' ,6,l', 2: ' ,10,r',3: ' ,6,l', 4: ' ,10,r',5: ' ,6,l', 6: ' ,6,r',7: ' ,8,l',8: ' ,6,r',9: ' ,6,l', 10: ' ,6,r',11: ' ,6,l', 12: ' ,5,r',}
style = {1: ' ,l', 2: ' ,r',3: ' ,l', 4: ' ,r',5: ' ,l', 6: ' ,r',7: ' ,l',8: ' ,r',9: ' ,l', 10: ' ,r',11: ' ,l', 12: ' ,r',}
rows=[
["CPU", str(psutil.cpu_percent(interval=1))+'%',"nice", cpu_times.nice,"MEM", str(mem.percent) + '%',"active", str(mem.active/1024/1024) + 'M',"SWAP", str(swap.percent)+'%',"LOAD", str(psutil.cpu_count())+'core'],
["user", cpu_times.user,"irq", cpu_times.irq,"total", str(mem.total/1024/1024)+'M',"inactive", str(mem.inactive/1024/1024) + 'M',"total", str(swap.total/1024/1024) + 'M',"1 min", stats["min1"]],
["system", cpu_times.system,"iowait", cpu_times.iowait,"used", str(mem.used/1024/1024)+'M',"buffers", str(mem.buffers/1024/1024) + 'M',"used", str(swap.used/1024/1024) + 'M',"5 min", stats["min5"]],
["idle", cpu_times.idle,"steal", cpu_times.steal,"free", str(mem.free/1024/1024) + 'M',"cached", str(mem.cached/1024/1024) + 'M',"free", str(swap.free/1024/1024) + 'M',"15 min", stats["min15"]]
]
title = "Linux Overview"
if save_as == "txt":
f_print_title(title)
f_print_table_body(rows, style1,' ')
elif save_as == "html":
f_print_table_html(rows, title, style)
def f_print_host_memory_topN(topN,save_as):
ps_result = list()
for proc in psutil.process_iter():
ps_result.append({'name': proc.name(), 'pid': proc.pid, 'cpu_percent': proc.cpu_percent(),
'memory_percent': proc.memory_percent()})
rows = []
for i, item in enumerate(sorted(ps_result, key=lambda x: x['memory_percent'], reverse=True)):
if i >= topN:
break
rows.append([i + 1, item['name'], item['pid'], format(item['memory_percent'] / 100, '.2%')])
style = {1: 'No,r', 2: 'Name,l',3: 'Pid,r', 4: 'Memory percent,r'}
title = "Host memory top"+str(topN)
f_print_table(rows, title, style, save_as)
def f_sec2dhms(sec):
day = 24*60*60
hour = 60*60
min = 60
if sec <60:
return "%ds"%math.ceil(sec)
elif sec > day:
days = divmod(sec,day)
return "%dd%s"%(int(days[0]),f_sec2dhms(days[1]))
elif sec > hour:
hours = divmod(sec,hour)
return '%dh%s'%(int(hours[0]),f_sec2dhms(hours[1]))
else:
mins = divmod(sec,min)
return "%dm%ds"%(int(mins[0]),math.ceil(mins[1]))
def f_get_mysql_status(conn):
query = "SHOW GLOBAL STATUS"
rows = f_get_query_record(conn, query)
mysqlstatus = dict(rows)
return mysqlstatus
def f_print_mysql_status(conn,perfor_or_infor,interval,save_as):
###获取参数###################################################################
mysqlstatus1 = f_get_mysql_status(conn)
time.sleep(interval)
mysqlstatus2 = f_get_mysql_status(conn)
# 执行查询的总次数
Questions1 = long(mysqlstatus1["Questions"])
Questions2 = long(mysqlstatus2["Questions"])
# 服务器已经运行的时间(以秒为单位)
Uptime2 = long(mysqlstatus2["Uptime"])
Com_commit1 = long(mysqlstatus1["Com_commit"])
Com_commit2 = long(mysqlstatus2["Com_commit"])
Com_rollback1 = long(mysqlstatus1["Com_rollback"])
Com_rollback2 = long(mysqlstatus2["Com_rollback"])
# 从硬盘读取键的数据块的次数。如果Key_reads较大,则Key_buffer_size值可能太小。
# 可以用Key_reads/Key_read_requests计算缓存损失率
#Key_reads1 = long(mysqlstatus1["Key_reads"])
#Key_reads2 = long(mysqlstatus2["Key_reads"])
# 从缓存读键的数据块的请求数
#Key_read_requests1 = long(mysqlstatus1["Key_read_requests"])
#Key_read_requests2 = long(mysqlstatus2["Key_read_requests"])
# 向硬盘写入将键的数据块的物理写操作的次数
#Key_writes1 = long(mysqlstatus1["Key_writes"])
#Key_writes2 = long(mysqlstatus2["Key_writes"])
# 将键的数据块写入缓存的请求数
#Key_write_requests1 = long(mysqlstatus1["Key_write_requests"])
#Key_write_requests2 = long(mysqlstatus2["Key_write_requests"])
# 不能满足InnoDB必须单页读取的缓冲池中的逻辑读数量。
Innodb_buffer_pool_reads1 = long(mysqlstatus1["Innodb_buffer_pool_reads"])
Innodb_buffer_pool_reads2 = long(mysqlstatus2["Innodb_buffer_pool_reads"])
# InnoDB已经完成的逻辑读请求数
Innodb_buffer_pool_read_requests1 = long(mysqlstatus1["Innodb_buffer_pool_read_requests"])
Innodb_buffer_pool_read_requests2 = long(mysqlstatus2["Innodb_buffer_pool_read_requests"])
# 当前打开的表的数量
Open_tables1 = long(mysqlstatus2["Open_tables"])-long(mysqlstatus1["Open_tables"])
Open_tables2 = long(mysqlstatus2["Open_tables"])
# 已经打开的表的数量。如果Opened_tables较大,table_cache 值可能太小
Opened_tables1 = long(mysqlstatus2["Opened_tables"])-long(mysqlstatus1["Opened_tables"])
Opened_tables2 = long(mysqlstatus2["Opened_tables"])
# 创建用来处理连接的线程数。如果Threads_created较大,你可能要
# 增加thread_cache_size值。缓存访问率的计算方法Threads_created/Connections
Threads_created1 = long(mysqlstatus1["Threads_created"])
Threads_created2 = long(mysqlstatus2["Threads_created"])
# 试图连接到(不管是否成功)MySQL服务器的连接数。缓存访问率的计算方法Threads_created/Connections
Connections1 = long(mysqlstatus1["Connections"])
Connections2 = long(mysqlstatus2["Connections"])
Threads_connected1 = str(long(mysqlstatus2["Threads_connected"])-long(mysqlstatus1["Threads_connected"]))
Threads_connected2 = mysqlstatus2["Threads_connected"]
Aborted_connects1 = str(long(mysqlstatus2["Aborted_connects"])-long(mysqlstatus1["Aborted_connects"]))
Aborted_connects2 = mysqlstatus2["Aborted_connects"]
# Com_select/s:平均每秒select语句执行次数
# Com_insert/s:平均每秒insert语句执行次数
# Com_update/s:平均每秒update语句执行次数
# Com_delete/s:平均每秒delete语句执行次数
Com_select1 = long(mysqlstatus1["Com_select"])
Com_select2 = long(mysqlstatus2["Com_select"])
Com_insert1 = long(mysqlstatus1["Com_insert"])
Com_insert2 = long(mysqlstatus2["Com_insert"])
Com_update1 = long(mysqlstatus1["Com_update"])
Com_update2 = long(mysqlstatus2["Com_update"])
Com_delete1 = long(mysqlstatus1["Com_delete"])
Com_delete2 = long(mysqlstatus2["Com_delete"])
Com_replace1 = long(mysqlstatus1["Com_replace"])
Com_replace2 = long(mysqlstatus2["Com_replace"])
# 不能立即获得的表的锁的次数。如果该值较高,并且有性能问题,你应首先优化查询,然后拆分表或使用复制。
#Table_locks_waited1 = long(mysqlstatus1["Table_locks_waited"])
#Table_locks_waited2 = long(mysqlstatus2["Table_locks_waited"])
# 立即获得的表的锁的次数
#Table_locks_immediate1 = long(mysqlstatus1["Table_locks_immediate"])
#Table_locks_immediate2 = long(mysqlstatus2["Table_locks_immediate"])
# 服务器执行语句时自动创建的内存中的临时表的数量。如果Created_tmp_disk_tables较大,
# 你可能要增加tmp_table_size值使临时 表基于内存而不基于硬盘
Created_tmp_tables1 = long(mysqlstatus1["Created_tmp_tables"])
Created_tmp_tables2 = long(mysqlstatus2["Created_tmp_tables"])
# 服务器执行语句时在硬盘上自动创建的临时表的数量
Created_tmp_disk_tables1 = long(mysqlstatus1["Created_tmp_disk_tables"])
Created_tmp_disk_tables2 = long(mysqlstatus2["Created_tmp_disk_tables"])
# 查询时间超过long_query_time秒的查询的个数 缓慢查询个数
Slow_queries1 = long(mysqlstatus1["Slow_queries"])
Slow_queries2 = long(mysqlstatus2["Slow_queries"])
# 没有主键(key)联合(Join)的执行。该值可能是零。这是捕获开发错误的好方法,因为一些这样的查询可能降低系统的性能。
Select_full_join1 = long(mysqlstatus1["Select_full_join"])
Select_full_join2 = long(mysqlstatus2["Select_full_join"])
# Percentage of full table scans
Handler_read_rnd_next1 = long(mysqlstatus1["Handler_read_rnd_next"])
Handler_read_rnd_next2 = long(mysqlstatus2["Handler_read_rnd_next"])
Handler_read_rnd1 = long(mysqlstatus1["Handler_read_rnd"])
Handler_read_rnd2 = long(mysqlstatus2["Handler_read_rnd"])
Handler_read_first1 = long(mysqlstatus1["Handler_read_first"])
Handler_read_first2 = long(mysqlstatus2["Handler_read_first"])
Handler_read_next1 = long(mysqlstatus1["Handler_read_next"])
Handler_read_next2 = long(mysqlstatus2["Handler_read_next"])
Handler_read_key1 = long(mysqlstatus1["Handler_read_key"])
Handler_read_key2 = long(mysqlstatus2["Handler_read_key"])
Handler_read_prev1 = long(mysqlstatus1["Handler_read_prev"])
Handler_read_prev2 = long(mysqlstatus2["Handler_read_prev"])
# 缓冲池利用率
Innodb_buffer_pool_pages_total1 = long(mysqlstatus1["Innodb_buffer_pool_pages_total"])
Innodb_buffer_pool_pages_total2 = long(mysqlstatus2["Innodb_buffer_pool_pages_total"])
Innodb_buffer_pool_pages_free1 = long(mysqlstatus1["Innodb_buffer_pool_pages_free"])
Innodb_buffer_pool_pages_free2 = long(mysqlstatus2["Innodb_buffer_pool_pages_free"])
###计算参数###################################################################
Uptimes1 = str(interval) + "s"
Uptimes2 = f_sec2dhms(Uptime2)
# QPS = Questions / Seconds
QPS1 = str(round((Questions2-Questions1) * 1.0 / interval, 2))+' ('+str(Questions2-Questions1)+'/'+str(interval)+')'
QPS2 = str(round(Questions2* 1.0 / Uptime2, 2))+' ('+str(Questions2)+'/'+str(Uptime2)+')'
TPS1 = str(round((Com_commit2 + Com_rollback2-Com_commit1 - Com_rollback1) * 1.0 / interval, 2))+' (('+str(Com_commit2 -Com_commit1)+'+'+str(Com_rollback2- Com_rollback1)+')/'+str(interval)+')'
TPS2 = str(round((Com_commit2 + Com_rollback2)* 1.0 / Uptime2, 2))+' (('+str(Com_commit2)+'+'+str(Com_rollback2)+')/'+str(Uptime2)+')'
Read1 = Com_select2 -Com_select1
Read2 = Com_select2
ReadS1 = str(round(Read1 * 1.0 / interval, 2))+' ('+str(Read1)+'/'+str(interval)+')'
ReadS2 = str(round(Read2* 1.0 / Uptime2, 2))+' ('+str(Read2)+'/'+str(Uptime2)+')'
Write1 = Com_insert2 + Com_update2 + Com_delete2 + Com_replace2-Com_insert1 - Com_update1 - Com_delete1 - Com_replace1
Write2 = Com_insert2 + Com_update2 + Com_delete2 + Com_replace2
WriteS1 = str(round(Write1 * 1.0 / interval, 2))+' ('+str(Write1)+'/'+str(interval)+')'
WriteS2 = str(round(Write2* 1.0 / Uptime2, 2))+' ('+str(Write2)+'/'+str(Uptime2)+')'
# Read/Write Ratio
if Write1<>0:
rwr1 = str(round(Read1 * 1.0 / Write1,2))+' ('+str(Read1)+'/'+str(Write1)+')'
else:
rwr1 ='0.0%'
if Write2<>0:
rwr2 = str(round(Read2 * 1.0 / Write2,2))+' ('+str(Read2)+'/'+str(Write2)+')'
else:
rwr2 ='0.0%'
Slow_queries_per_second1 = str(round((Slow_queries2-Slow_queries1) * 1.0 / interval, 2))+' ('+str(Slow_queries2-Slow_queries1)+'/'+str(interval)+')'
Slow_queries_per_second2 = str(round(Slow_queries2 * 1.0 / Uptime2, 2))+' ('+str(Slow_queries2)+'/'+str(Uptime2)+')'
#Slow_queries / Questions
SQ1 = str(round(((Slow_queries2-Slow_queries1) * 1.0 / (Questions2-Questions1)) * 100, 2)) + "%"+' ('+str(Slow_queries2-Slow_queries1)+'/'+str(Questions2-Questions1)+')'
SQ2 = str(round((Slow_queries2 * 1.0 / Questions2) * 100, 2)) + "%"+' ('+str(Slow_queries2)+'/'+str(Questions2)+')'
if (Connections2-Connections1) <> 0:
Thread_cache_hits1 = str(round((1 - (Threads_created2-Threads_created1)* 1.0 / (Connections2-Connections1)) * 100, 2)) + "%"
else:
Thread_cache_hits1 = '0.0%'
Thread_cache_hits2 = str(round((1 - Threads_created2 * 1.0 / Connections2) * 100, 2)) + "%"
if (Innodb_buffer_pool_read_requests2-Innodb_buffer_pool_read_requests1) <> 0:
Innodb_buffer_read_hits1 = str(round((1 - (Innodb_buffer_pool_reads2-Innodb_buffer_pool_reads1) * 1.0 / (Innodb_buffer_pool_read_requests2-Innodb_buffer_pool_read_requests1)) * 100, 2)) + "%"+ "%"+' (1-'+str(Innodb_buffer_pool_reads2-Innodb_buffer_pool_reads1)+'/'+str(Innodb_buffer_pool_read_requests2-Innodb_buffer_pool_read_requests1)+')'
else:
Innodb_buffer_read_hits1 = '0.0%'
Innodb_buffer_read_hits2 = str(round((1 - Innodb_buffer_pool_reads2* 1.0 / Innodb_buffer_pool_read_requests2) * 100, 2)) + "%"+' (1-'+str(Innodb_buffer_pool_reads2)+'/'+str(Innodb_buffer_pool_read_requests2)+')'
Innodb_buffer_pool_utilization1 = str(round((Innodb_buffer_pool_pages_total1 - Innodb_buffer_pool_pages_free1) * 1.0 / Innodb_buffer_pool_pages_total1 * 100,2)) + "%"+' ('+str(Innodb_buffer_pool_pages_total1 - Innodb_buffer_pool_pages_free1)+'/'+str(Innodb_buffer_pool_pages_total1)+')'
Innodb_buffer_pool_utilization2 = str(round((Innodb_buffer_pool_pages_total2 - Innodb_buffer_pool_pages_free2) * 1.0 / Innodb_buffer_pool_pages_total2 * 100,2)) + "%"+' ('+str(Innodb_buffer_pool_pages_total2 - Innodb_buffer_pool_pages_free2)+'/'+str(Innodb_buffer_pool_pages_total2)+')'
"""
if (Key_read_requests2-Key_read_requests1) <> 0:
Key_buffer_read_hits1 = str(round((1 - (Key_reads2-Key_reads1) * 1.0 / (Key_read_requests2-Key_read_requests1)) * 100, 2)) + "%"
else:
Key_buffer_read_hits1 = '0.0%'
if Key_read_requests2 <> 0:
Key_buffer_read_hits2 = str(round((1 - Key_reads2* 1.0 / Key_read_requests2) * 100, 2)) + "%"
else:
Key_buffer_read_hits2 = '0.0%'
if (Key_write_requests2-Key_write_requests1)<>0:
Key_buffer_write_hits1 = str(round((1 - (Key_writes2-Key_writes1)* 1.0 / (Key_write_requests2-Key_write_requests1)) * 100, 2)) + "%"
else:
Key_buffer_write_hits1 = '0.0%'
if Key_write_requests2<>0:
Key_buffer_write_hits2 = str(round((1 - Key_writes2* 1.0 / Key_write_requests2) * 100, 2)) + "%"
else:
Key_buffer_write_hits2 = '0.0%'
"""
if (Select_full_join2-Select_full_join1) > 0:
Select_full_join_per_second1 = str(round((Select_full_join2-Select_full_join1) * 1.0 / interval, 2))+' ('+str(Select_full_join2-Select_full_join1)+'/'+str(interval)+')'
else:
Select_full_join_per_second1 = '0.0%'
Select_full_join_per_second2 = str(round(Select_full_join2 * 1.0 / Uptime2, 2))+' ('+str(Select_full_join2)+'/'+str(Uptime2)+')'
if (Com_select2-Com_select1) > 0:
full_select_in_all_select1 = str(round(((Select_full_join2-Select_full_join1) * 1.0 / (Com_select2-Com_select1)) * 100, 2)) + "%"+' ('+str(Select_full_join2-Select_full_join1)+'/'+str(Com_select2-Com_select1)+')'
else:
full_select_in_all_select1 = '0.0%'
full_select_in_all_select2 = str(round((Select_full_join2 * 1.0 / Com_select2) * 100, 2)) + "%"+' ('+str(Select_full_join2)+'/'+str(Com_select2)+')'
#((Handler_read_rnd_next + Handler_read_rnd) / (Handler_read_rnd_next + Handler_read_rnd + Handler_read_first + Handler_read_next + Handler_read_key + Handler_read_prev)).
if (Handler_read_rnd_next2 -Handler_read_rnd_next1+ Handler_read_rnd2-Handler_read_rnd1 + Handler_read_first2 -Handler_read_first1+ Handler_read_next2-Handler_read_next1 + Handler_read_key2-Handler_read_key1 + Handler_read_prev2-Handler_read_prev1) > 0:
full_table_scans1=str(round((Handler_read_rnd_next2 + Handler_read_rnd2-Handler_read_rnd_next1 - Handler_read_rnd1)* 1.0 / (Handler_read_rnd_next2 -Handler_read_rnd_next1+ Handler_read_rnd2-Handler_read_rnd1 + Handler_read_first2 -Handler_read_first1+ Handler_read_next2-Handler_read_next1 + Handler_read_key2-Handler_read_key2 + Handler_read_prev2-Handler_read_prev1)* 100, 2)) + "%"
else:
full_table_scans1 = '0.0%'
full_table_scans2=str(round((Handler_read_rnd_next2 + Handler_read_rnd2)* 1.0 / (Handler_read_rnd_next2 + Handler_read_rnd2 + Handler_read_first2 + Handler_read_next2 + Handler_read_key2 + Handler_read_prev2)* 100, 2)) + "%"
"""
if (Table_locks_immediate2-Table_locks_immediate1) > 0:
lock_contention1 = str(round(((Table_locks_waited2-Table_locks_waited1) * 1.00 / (Table_locks_immediate2-Table_locks_immediate1)) * 100, 2)) + "%"
else:
lock_contention1 = '0.0%'
lock_contention2 = str(round((Table_locks_waited2 * 1.00 / Table_locks_immediate2) * 100, 2)) + "%"
"""
if (Created_tmp_tables2-Created_tmp_tables1) > 0:
Temp_tables_to_disk1 = str(round(((Created_tmp_disk_tables2-Created_tmp_disk_tables1) * 1.0 / (Created_tmp_tables2-Created_tmp_tables1)) * 100, 2)) + "%"+' ('+str(Created_tmp_disk_tables2-Created_tmp_disk_tables1)+'/'+str(Created_tmp_tables2-Created_tmp_tables1)+')'
else:
Temp_tables_to_disk1 = '0.0%'
Temp_tables_to_disk2 = str(round((Created_tmp_disk_tables2 * 1.0 / Created_tmp_tables2) * 100, 2)) + "%"+' ('+str(Created_tmp_disk_tables2)+'/'+str(Created_tmp_tables2)+')'
###打印参数###################################################################
title = "MySQL Overview"
style = {1: 'Key,l', 2: 'In '+Uptimes1+',r', 3: 'Total,r'}
rows=[
["Uptimes",Uptimes1,Uptimes2],
["QPS (Questions / Seconds)", QPS1, QPS2],
["TPS ((Commit + Rollback)/ Seconds)", TPS1, TPS2],
["Reads per second", ReadS1, ReadS2],
["Writes per second", WriteS1, WriteS2],
["Read/Writes", rwr1,rwr2],
["Slow queries per second", Slow_queries_per_second1, Slow_queries_per_second2],
["Slow_queries/Questions", SQ1,SQ2],
["Threads connected", Threads_connected1, Threads_connected2],
["Aborted connects", Aborted_connects1, Aborted_connects2],
["Thread cache hits (>90%)", Thread_cache_hits1, Thread_cache_hits2],
["Innodb buffer hits(96% - 99%)", Innodb_buffer_read_hits1,Innodb_buffer_read_hits2],
["Innodb buffer pool utilization", Innodb_buffer_pool_utilization1,Innodb_buffer_pool_utilization2],
#["Key buffer read hits(99.3% - 99.9%)",str(Key_buffer_read_hits1), str(Key_buffer_read_hits2)],
#["Key buffer write hits(99.3% - 99.9%)", str(Key_buffer_write_hits1), str(Key_buffer_write_hits2)],
["Select full join per second", Select_full_join_per_second1, Select_full_join_per_second2],
["full select in all select", full_select_in_all_select1, full_select_in_all_select2],
["full table scans", full_table_scans1, full_table_scans2],
#["MyISAM Lock waiting ratio", lock_contention1, lock_contention2],
["Current open tables", str(Open_tables1), str(Open_tables2)],
["Accumulative open tables", str(Opened_tables1), str(Opened_tables2)],
["Temp tables to disk(<10%)", Temp_tables_to_disk1, Temp_tables_to_disk2]
]
f_print_table(rows, title, style,save_as)
if __name__=="__main__":
dbinfo=["127.0.0.1","root","","mysql",3306] #host,user,passwd,db,port
config_file="dbset.ini"
mysql_version=""
option = []
save_as = "txt"
opts, args = getopt.getopt(sys.argv[1:], "p:s:")
for o,v in opts:
if o == "-p":
config_file = v
elif o == "-s":
save_as = v
config = ConfigParser.ConfigParser()
config.readfp(open(config_file,"rb"))
dbinfo[0] = config.get("database","host")
dbinfo[1] = config.get("database","user")
dbinfo[2] = config.get("database","passwd")
dbinfo[3] = config.get("database","db")
dbinfo[4] = config.get("database", "port")
interval = long(config.get("option", "interval"))
conn = f_get_conn(dbinfo)
query ="select @@version"
mysql_version = f_get_query_value(conn, query)
f_print_caption(dbinfo,mysql_version,save_as)
if "5.6" in mysql_version:
perfor_or_infor = "information_schema"
else:
perfor_or_infor = "performance_schema"
sys_schema_exist = f_is_sys_schema_exist(conn)
if config.get("option","linux_info")=='ON':
f_print_linux_info(save_as)
if config.get("option","filesystem_info")=='ON':
f_print_filesystem_info(save_as)
if config.get("option","linux_overview")=='ON':
f_print_linux_status(save_as)
if config.get("option","host_memory_topN")<>'OFF':
topN=int(config.get("option","host_memory_topN"))
f_print_host_memory_topN(topN,save_as)
if config.get("option","mysql_overview")=='ON':
f_print_mysql_status(conn,perfor_or_infor,interval,save_as)
if config.get("option","sys_parm")=='ON':
title = "System Parameter "
query = "SELECT variable_name,IF(INSTR(variable_name,'size'), \
CASE \
WHEN variable_value>=1024*1024*1024*1024*1024 THEN CONCAT(variable_value/1024/1024/1024/1024/1024,'P') \
WHEN variable_value>=1024*1024*1024*1024 THEN CONCAT(variable_value/1024/1024/1024/1024,'T') \
WHEN variable_value>=1024*1024*1024 THEN CONCAT(variable_value/1024/1024/1024,'G') \
WHEN variable_value>=1024*1024 THEN CONCAT(variable_value/1024/1024,'M') \
WHEN variable_value>=1024 THEN CONCAT(variable_value/1024,'K') \
ELSE variable_value END , \
variable_value) \
FROM "+perfor_or_infor+".global_variables \
where variable_name in ('" + "','".join(list(SYS_PARM_FILTER)) + "')"
style = {1: 'parameter_name,l', 2: 'value,r'}
f_print_query_table(conn, title, query, style,save_as)
f_print_optimizer_switch(conn,save_as,perfor_or_infor)
if config.get("option","log_error_statistics")=='ON':
f_print_log_error(conn,perfor_or_infor,save_as)
if config.get ( "option", "replication" ) == 'ON':
title = "Replication"
query = """SELECT USER,HOST,command,CONCAT(FLOOR(TIME/86400),'d',FLOOR(TIME/3600)%24,'h',FLOOR(TIME/60)%60,'m',TIME%60,'s') TIMES,state
FROM information_schema.processlist WHERE COMMAND = 'Binlog Dump' OR COMMAND = 'Binlog Dump GTID'"""
style = {1: 'USER,l', 2: 'HOST,l', 3: 'command,l', 4: 'TIMES,r', 5: 'state,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "connect_count" ) == 'ON':
title = "Connect Count"
query = """SELECT SUBSTRING_INDEX(HOST,':',1) HOSTS,USER,db,command,COUNT(*),SUM(TIME)
FROM information_schema.processlist
WHERE Command !='' AND DB !='information_schema'
GROUP BY HOSTS,USER,db,command"""
style = {1: 'HOSTS,l', 2: 'USER,l', 3: 'db,l', 4: 'command,l', 5: 'COUNT(*),r', 6: 'SUM(TIME),r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "avg_query_time" ) == 'ON' and not ("5.6" in mysql_version):
title = "Avg Query Time"
query = """SELECT schema_name,SUM(count_star) COUNT, ROUND((SUM(sum_timer_wait)/SUM(count_star))/1000000) avg_microsec
FROM performance_schema.events_statements_summary_by_digest
WHERE schema_name IS NOT NULL
GROUP BY schema_name"""
style = {1: 'schema_name,l', 2: 'COUNT,r', 3: 'avg_microsec,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "slow_query_topN" ) <> 'OFF' and sys_schema_exist:
topN = int(config.get("option", "slow_query_topN"))
title = "Slow Query Top"+str(topN)
query = "SELECT QUERY,db,exec_count,total_latency,max_latency,avg_latency FROM sys.statements_with_runtimes_in_95th_percentile LIMIT "+str(topN)
style = {1: 'QUERY,l', 2: 'db,r', 3: 'exec_count,r', 4: 'total_latency,r', 5: 'max_latency,r', 6: 'avg_latency,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "err_sql_count" ) == 'ON' and ("5.7" in mysql_version):
title = "Err Sql Count"
query = """SELECT schema_name,SUM(sum_errors) err_count
FROM performance_schema.events_statements_summary_by_digest
WHERE sum_errors > 0
GROUP BY schema_name"""
style = {1: 'schema_name,l', 2: 'err_count,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "err_sql_topN" ) <> 'OFF' and sys_schema_exist:
topN = int(config.get("option", "err_sql_topN"))
title = "Err SQL Top"+str(topN)
query = "SELECT QUERY,db,exec_count,ERRORS FROM sys.statements_with_errors_or_warnings ORDER BY ERRORS DESC LIMIT "+str(topN)
style = {1: 'QUERY,l', 2: 'db,r', 3: 'exec_count,r', 4: 'ERRORS,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "query_analysis_topN" ) <> 'OFF' and sys_schema_exist:
topN = int(config.get("option", "query_analysis_topN"))
title = "query analysis top"+str(topN)
query = """SELECT QUERY,full_scan,exec_count,total_latency,lock_latency,rows_sent_avg,rows_examined_avg,
tmp_tables,tmp_disk_tables,rows_sorted,last_seen
FROM sys.statement_analysis
where db='""" + dbinfo[3] + "' ORDER BY total_latency DESC LIMIT "+str(topN)
style = {1: 'QUERY,l', 2: 'fscan,l', 3: 'ex_cot,r', 4: 'total_ltc,r', 5:'lock_ltc,r', 6: 'rw_st_avg,r',
7: 'rw_exm_avg,9,r',8: 'tmp_table,9,r',9: 'tp_dk_tab,9,r',10: 'rows_sort,9,r',11: 'last_seen,19,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "query_full_table_scans_topN" ) <> 'OFF' and sys_schema_exist:
topN = int(config.get("option", "query_full_table_scans_topN"))
title = "query full table scans top"+str(topN)
query = """SELECT QUERY,exec_count,total_latency,no_index_used_count,no_good_index_used_count,no_index_used_pct,rows_sent_avg,rows_examined_avg,last_seen
FROM sys.statements_with_full_table_scans
where db='""" + dbinfo[3] + "' ORDER BY total_latency DESC LIMIT "+str(topN)
style = {1: 'QUERY,l', 2: 'ex_cot,r', 3: 'total_ltc,r', 4:'no_idx_use,r', 5: 'n_g_idx_use,r',6: 'n_i_u_pct,r',
7: 'rw_st_avg,r',8: 'rw_exm_avg,r',9: 'last_seen,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "query_sorting_topN" ) <> 'OFF' and sys_schema_exist:
topN = int(config.get("option", "query_sorting_topN"))
title = "query sorting top"+str(topN)
query = """SELECT QUERY,exec_count,total_latency,sort_merge_passes,avg_sort_merges,sorts_using_scans,sort_using_range,
rows_sorted,avg_rows_sorted,last_seen
FROM sys.statements_with_sorting
where db='""" + dbinfo[3] + "' ORDER BY avg_rows_sorted DESC LIMIT "+str(topN)
style = {1: 'QUERY,l', 2: 'ex_cot,r', 3: 'total_ltc,r', 4:'st_mg_ps,r', 5: 'avg_st_mg,r',6: 'st_us_scan,r',
7: 'st_us_rag,r',8: 'rows_sort,r',9: 'avg_rw_st,r',10: 'last_seen,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "query_with_temp_tables_topN" ) <> 'OFF' and sys_schema_exist:
topN = int(config.get("option", "query_with_temp_tables_topN"))
title = "query with temp tables top"+str(topN)
query = """SELECT QUERY,exec_count,total_latency,memory_tmp_tables,disk_tmp_tables,avg_tmp_tables_per_query,tmp_tables_to_disk_pct,last_seen
FROM sys.statements_with_temp_tables
where db='""" + dbinfo[3] + "' ORDER BY avg_tmp_tables_per_query DESC LIMIT "+str(topN)
style = {1: 'QUERY,l', 2: 'ex_cot,r', 3: 'total_ltc,r', 4:'mem_tmp_tab,r', 5: 'dsk_tmp_tab,r',6: 'avg_tt_per_qry,r',
7: 'tt_to_dk_pct,r',8:'last_seen,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "database_size" ) == 'ON':
title = "Database Size"
query = """SELECT table_schema,
CONCAT(ROUND(SUM(data_length)/(1024*1024),2),'MB') AS 'Table Size',
CONCAT(ROUND(SUM(index_length)/(1024*1024),2),'MB') AS 'Index Size' ,
CONCAT(ROUND(SUM(data_length)/(1024*1024),2) + ROUND(SUM(index_length)/(1024*1024),2),'MB') AS 'DB Size'
FROM information_schema.tables GROUP BY table_schema
UNION
SELECT '*** all ***' table_schema,
CONCAT(ROUND(SUM(data_length)/(1024*1024),2),'MB') AS 'Table Size',
CONCAT(ROUND(SUM(index_length)/(1024*1024),2),'MB') AS 'Index Size' ,
CONCAT(ROUND(SUM(data_length)/(1024*1024),2) + ROUND(SUM(index_length)/(1024*1024),2),'MB') AS 'DB Size'
FROM information_schema.tables"""
style = {1: 'table_schema,l', 2: 'Table Size,r', 3: 'Index Size,r', 4: 'DB Size,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get("option","object_count")=='ON':
title = "Object Count"
query = "SELECT information_schema.routines.ROUTINE_TYPE AS object_type, COUNT(0) AS COUNT FROM information_schema.routines \
WHERE information_schema.routines.ROUTINE_SCHEMA='" + dbinfo[3] + "' GROUP BY information_schema.routines.ROUTINE_TYPE UNION \
SELECT information_schema.tables.TABLE_TYPE AS object_type, COUNT(0) AS COUNT FROM information_schema.tables \
WHERE information_schema.tables.TABLE_SCHEMA='" + dbinfo[3] + "' GROUP BY information_schema.tables.TABLE_TYPE UNION \
SELECT CONCAT('INDEX (',information_schema.statistics.INDEX_TYPE,')') AS object_type,COUNT(0) AS COUNT FROM information_schema.statistics \
WHERE information_schema.statistics.TABLE_SCHEMA='" + dbinfo[3] + "' GROUP BY information_schema.statistics.INDEX_TYPE UNION \
SELECT 'TRIGGER' AS `TRIGGER`,COUNT(0) AS COUNT FROM information_schema.triggers \
WHERE information_schema.triggers.TRIGGER_SCHEMA='" + dbinfo[3] + "' UNION \
SELECT 'EVENT' AS object_type, COUNT(0) AS COUNT FROM information_schema.events \
WHERE information_schema.events.EVENT_SCHEMA='" + dbinfo[3] + "'"
style = {1:'object_type,l',2: 'COUNT,r'}
if save_as == "txt":
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "table_info" ) == 'ON':
title = "Table Info"
query = """select table_name,engine,row_format as format,table_rows,avg_row_length as avg_row,
round((data_length)/1024/1024,2) as data_mb,
round((index_length)/1024/1024,2) as index_mb,
round((data_length+index_length)/1024/1024,2) as total_mb
from information_schema.tables
where table_schema='""" + dbinfo[3] + "'"
style = {1: 'table_name,l', 2: 'engine,l', 3: 'format,l', 4: 'table_rows,r', 5: 'avg_row,r',
6: 'data_mb,r', 7: 'index_mb,r', 8: 'total_mb,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get ( "option", "index_info" ) == 'ON':
title = "Index Info"
query = """select index_name,non_unique,seq_in_index,column_name,collation,cardinality,nullable,index_type
from information_schema.statistics
where table_schema='""" + dbinfo[3] + "'"
style = {1: 'index_name,l', 2: 'non_unique,l', 3: 'seq_in_index,l', 4: 'column_name,l',
5: 'collation,r', 6: 'cardinality,r', 7: 'nullable,r', 8: 'index_type,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get("option", "schema_index_statistics") == 'ON' and sys_schema_exist:
title = "schema_index_statistics"
query = """SELECT table_name,index_name ,rows_selected,select_latency,rows_inserted,insert_latency,rows_updated,
update_latency,rows_deleted,delete_latency
FROM sys.schema_index_statistics where table_schema='""" + dbinfo[3] + "' ORDER BY table_name"
style = {1: 'table_name,l', 2: 'index_name,l', 3: 'rows_selected,r', 4: 'select_latency,r',5: 'rows_inserted,r',
6: 'insert_latency,r', 7: 'rows_updated,r', 8: 'update_latency,r', 9: 'rows_deleted,r',10: 'delete_latency,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get("option", "schema_table_statistics") == 'ON' and sys_schema_exist:
title = "schema_table_statistics"
query = """SELECT table_name,total_latency ,rows_fetched,fetch_latency,rows_inserted,insert_latency,rows_updated,
update_latency,rows_deleted,delete_latency,io_read_requests,io_read,io_read_latency,io_write_requests,
io_write,io_write_latency,io_misc_requests,io_misc_latency
FROM sys.schema_table_statistics where table_schema='""" + dbinfo[3] + "' ORDER BY table_name"
style = {1: 'table_name,l', 2: 'tal_ltc,r', 3: 'rw_ftc,r', 4: 'ftc_ltc,r',
5: 'rw_ins,r', 6: 'ins_ltc,r', 7: 'rw_upd,r', 8: 'upd_ltc,r',
9: 'rw_del,r', 10: 'del_ltc,r', 11: 'io_rd_rq,r', 12: 'io_read,r',
13: 'io_rd_ltc,r', 14: 'io_wt_rq,r', 15: 'io_write,r',16: 'io_wt_ltc,r',
17: 'io_ms_rq,r',18: 'io_ms_ltc,r'}
f_print_query_table(conn, title, query, style,save_as)
if config.get("option", "schema_table_statistics_with_buffer") == 'ON' and sys_schema_exist:
title = "schema_table_statistics_with_buffer"
query = """SELECT table_name,innodb_buffer_allocated,innodb_buffer_data,innodb_buffer_free,innodb_buffer_pages,
innodb_buffer_pages_hashed,innodb_buffer_pages_old,innodb_buffer_rows_cached
FROM sys.schema_table_statistics_with_buffer where table_schema='""" + dbinfo[3] + "' ORDER BY table_name"
style = {1: 'table_name,l', 2: 'indb_buf_alc,r', 3: 'indb_buf_data,r', 4: 'indb_buf_free,r', 5: 'indb_buf_page,r',
6: 'indb_buf_page_hash,r', 7: 'indb_buf_page_old,r', 8: 'indb_buf_rw_cach,r'}
f_print_query_table(conn, title, query, style, save_as)