pull/632/head
Mr Chen 5 months ago
parent 6874de5cda
commit 7e2c192d40
  1. 93
      plugins/data_query/sql_mysql.py
  2. 137
      plugins/data_query/static/js/app.js

@ -404,6 +404,88 @@ class nosqlMySQLCtr():
my_instance.execute(cmd)
return mw.returnData(True, '执行成功!')
def getTableInfo(self, args):
from decimal import Decimal
sid = args['sid']
my_instance = self.getInstanceBySid(sid).conn()
if my_instance is False:
return mw.returnData(False,'无法链接')
my_instance.execute("SET sql_mode=(SELECT REPLACE(@@sql_mode,'ONLY_FULL_GROUP_BY',''))")
data = my_instance.query(
"""
SELECT t.TABLE_SCHEMA as TABLE_SCHEMA, t.TABLE_NAME as TABLE_NAME, t.ENGINE as ENGINE,
IFNULL(t.DATA_LENGTH/1024/1024/1024, 0) as DATA_LENGTH,
IFNULL(t.INDEX_LENGTH/1024/1024/1024, 0) as INDEX_LENGTH,
IFNULL((DATA_LENGTH+INDEX_LENGTH)/1024/1024/1024, 0) AS TOTAL_LENGTH,
c.column_name AS COLUMN_NAME, c.data_type AS DATA_TYPE, c.COLUMN_TYPE AS COLUMN_TYPE,
t.AUTO_INCREMENT AS AUTO_INCREMENT, locate('unsigned', c.COLUMN_TYPE) = 0 AS IS_SIGNED
FROM information_schema.TABLES t
JOIN information_schema.COLUMNS c ON t.TABLE_SCHEMA = c.TABLE_SCHEMA AND t.table_name=c.table_name
WHERE t.TABLE_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema', 'sys')
GROUP BY TABLE_NAME
ORDER BY TOTAL_LENGTH DESC, AUTO_INCREMENT DESC;
"""
)
for i in range(len(data)):
row = data[i]
data[i]['DATA_LENGTH'] = round(row['DATA_LENGTH'] or 0, 2)
data[i]['INDEX_LENGTH'] = round(row['INDEX_LENGTH'] or 0, 2)
data[i]['TOTAL_LENGTH'] = round(row['TOTAL_LENGTH'] or 0, 2)
AUTO_INCREMENT = row['AUTO_INCREMENT']
DATA_TYPE = row['DATA_TYPE']
IS_SIGNED = row['IS_SIGNED']
RESIDUAL_AUTO_INCREMENT = 0
if AUTO_INCREMENT is not None:
if DATA_TYPE == 'tinyint':
if IS_SIGNED == 0:
RESIDUAL_AUTO_INCREMENT = int(255 - AUTO_INCREMENT)
if IS_SIGNED == 1:
RESIDUAL_AUTO_INCREMENT = int(127 - AUTO_INCREMENT)
if DATA_TYPE == 'smallint':
if IS_SIGNED == 0:
RESIDUAL_AUTO_INCREMENT = int(65535 - AUTO_INCREMENT)
if IS_SIGNED == 1:
RESIDUAL_AUTO_INCREMENT = int(32767 - AUTO_INCREMENT)
if DATA_TYPE == 'int':
if IS_SIGNED == 0:
RESIDUAL_AUTO_INCREMENT = int(4294967295 - AUTO_INCREMENT)
if IS_SIGNED == 1:
RESIDUAL_AUTO_INCREMENT = int(2147483647 - AUTO_INCREMENT)
if DATA_TYPE == 'bigint':
if IS_SIGNED == 0:
RESIDUAL_AUTO_INCREMENT = Decimal("18446744073709551615") - Decimal(AUTO_INCREMENT)
if IS_SIGNED == 1:
RESIDUAL_AUTO_INCREMENT = Decimal("9223372036854775807") - Decimal(AUTO_INCREMENT)
else:
RESIDUAL_AUTO_INCREMENT = "主键非自增"
data[i]['RESIDUAL_AUTO_INCREMENT'] = RESIDUAL_AUTO_INCREMENT
return mw.returnData(True, 'ok', data)
# 查看应用端IP连接数总和
def getConnCount(self, args):
sid = args['sid']
my_instance = self.getInstanceBySid(sid).conn()
if my_instance is False:
return mw.returnData(False,'无法链接')
data = my_instance.query(
"SELECT user,db,substring_index(HOST,':',1) AS Client_IP,count(1) AS count FROM information_schema.PROCESSLIST "
"GROUP BY user,db,substring_index(HOST,':',1) ORDER BY COUNT(1) DESC"
)
# data2 = my_instance.query("SELECT USER, COUNT(*) as nums FROM information_schema.PROCESSLIST GROUP BY USER ORDER BY COUNT(*) DESC")
# print(data)
# print(data2)
return mw.returnData(True, 'ok', data)
# ---------------------------------- run ----------------------------------
# 获取 mysql 列表
def get_db_list(args):
@ -446,13 +528,20 @@ def get_redundant_indexes(args):
t = nosqlMySQLCtr()
return t.getRedundantIndexes(args)
# 查看重复或冗余的索引
# 删除重复或冗余的索引
def redundant_indexes_cmd(args):
t = nosqlMySQLCtr()
return t.redundantIndexesCmd(args)
# 统计库里每个表的大小
def get_table_info(args):
t = nosqlMySQLCtr()
return t.getTableInfo(args)
# 查看应用端IP连接数总和
def get_conn_count(args):
t = nosqlMySQLCtr()
return t.getConnCount(args)
# 测试

@ -485,6 +485,133 @@ function mysqlCommonFuncRedundantIndexes(){
});
}
function mysqlCommonFuncTableInfo(){
function renderSQL(){
var sid = mysqlGetSid();
myPostCBN('get_table_info',{'sid':sid} ,function(rdata){
var data = rdata.data;
if (data['status']){
var items = data.data;
var tbody = '';
for (var i = 0; i < items.length; i++) {
var t = '<tr>';
t += '<td>'+items[i]['TABLE_SCHEMA']+'</td>';
t += '<td>'+items[i]['TABLE_NAME']+'</td>';
t += '<td>'+items[i]['ENGINE']+'</td>';
t += '<td>'+items[i]['DATA_LENGTH']+'</td>';
t += '<td>'+items[i]['INDEX_LENGTH']+'</td>';
t += '<td>'+items[i]['TOTAL_LENGTH']+'</td>';
t += '<td>'+items[i]['COLUMN_NAME']+'</td>';
t += '<td>'+items[i]['COLUMN_TYPE']+'</td>';
t += '<td>'+items[i]['AUTO_INCREMENT']+'</td>';
t += '<td>'+items[i]['RESIDUAL_AUTO_INCREMENT']+'</td>';
t += '</tr>';
tbody += t;
}
$('#mysql_data_id tbody').html(tbody);
} else {
layer.msg(data.msg,{icon:2});
}
});
}
layer.open({
type: 1,
title: "统计库里每个表的大小",
area: ['1200px', '400px'],
closeBtn: 1,
shadeClose: false,
content: '<div class="bt-form pd20 divtable taskdivtable">\
<table class="table table-hover" id="mysql_data_id">\
<thead>\
<th style="width:100px;">库名</th>\
<th style="width:50px;">表名</th>\
<th style="width:80px;">储存引擎</th>\
<th style="width:150px;">数据大小(GB)</th>\
<th style="width:130px;">索引大小(GB)</th>\
<th style="width:100px;">总计(GB)</th>\
<th style="width:150px;">主键自增字段</th>\
<th style="width:200px;">主键字段属性</th>\
<th style="width:150px;">主键自增当前</th>\
<th style="width:150px;">主键自增剩余</th>\
</thead>\
<tbody></tbody>\
</table>\
</div>',
success:function(i,l){
renderSQL();
}
});
}
function mysqlCommonFuncConnCount(){
function renderSQL(){
var sid = mysqlGetSid();
myPostCBN('get_conn_count',{'sid':sid} ,function(rdata){
var data = rdata.data;
if (data['status']){
var items = data.data;
var tbody = '';
for (var i = 0; i < items.length; i++) {
var t = '<tr>';
t += '<td>'+items[i]['user']+'</td>';
t += '<td>'+items[i]['db']+'</td>';
t += '<td>'+items[i]['Client_IP']+'</td>';
t += '<td>'+items[i]['count']+'</td>';
t += '</tr>';
tbody += t;
}
$('#app_ip_list tbody').html(tbody);
} else {
layer.msg(data.msg,{icon:2});
}
});
}
var sql_timer = null;
layer.open({
type: 1,
title: "查看应用端IP连接数总和",
area: ['700px', '420px'],
closeBtn: 1,
shadeClose: false,
content: '<div class="bt-form pd20 divtable taskdivtable">\
<div class="mr20 pull-left" style="border-right: 1px solid #ccc; padding-right: 20px;">\
<div class="ss-text pull-left">\
<em>实时监控</em>\
<div class="ssh-item">\
<input class="btswitch btswitch-ios" id="app_ip_monitoring" type="checkbox">\
<label id="app_ip_label" class="btswitch-btn" for="app_ip_monitoring"></label>\
</div>\
</div>\
</div>\
<hr />\
<table class="table table-hover" id="app_ip_list">\
<thead>\
<th style="width:160px;">连接用户</th>\
<th style="width:50px;">数据库名</th>\
<th style="width:50px;">应用端IP</th>\
<th style="width:50px;">数量</th>\
</thead>\
<tbody></tbody>\
</table>\
</div>',
success:function(i,l){
renderSQL();
$('#app_ip_label').click(function(){
sql_timer = setInterval(function(){
var t = $('#app_ip_monitoring').is(':checked');
if (t){
renderSQL();
} else{
clearInterval(sql_timer);
}
}, 3000);
});
}
});
}
function mysqlCommonFunc(){
$('#mysql_common').unbind('click').click(function(){
layer.open({
@ -497,6 +624,8 @@ function mysqlCommonFunc(){
<button style="margin-bottom: 8px;" id="mysql_top_nsql" type="button" class="btn btn-default btn-sm">查询执行次数最频繁的前N条SQL语句</button>\
<button style="margin-bottom: 8px;" id="mysql_net_stat" type="button" class="btn btn-default btn-sm">MySQL服务器的QPS/TPS/网络带宽指标</button>\
<button style="margin-bottom: 8px;" id="mysql_redundant_indexes" type="button" class="btn btn-default btn-sm">查看重复或冗余的索引</button>\
<button style="margin-bottom: 8px;" id="mysql_table_info" type="button" class="btn btn-default btn-sm">统计库里每个表的大小</button>\
<button style="margin-bottom: 8px;" id="mysql_conn_count" type="button" class="btn btn-default btn-sm">查看应用端IP连接数总和</button>\
</div>',
success:function(i,l){
$('#mysql_top_nsql').click(function(){
@ -510,6 +639,14 @@ function mysqlCommonFunc(){
$('#mysql_redundant_indexes').click(function(){
mysqlCommonFuncRedundantIndexes();
});
$('#mysql_table_info').click(function(){
mysqlCommonFuncTableInfo();
});
$('#mysql_conn_count').click(function(){
mysqlCommonFuncConnCount();
});
}
});
});

Loading…
Cancel
Save