侯体宗的博客
  • 首页
  • Hyperf版
  • beego仿版
  • 人生(杂谈)
  • 技术
  • 关于我
  • 更多分类
    • 文件下载
    • 文字修仙
    • 中国象棋ai
    • 群聊
    • 九宫格抽奖
    • 拼图
    • 消消乐
    • 相册

分析Mysql表读写、索引等操作的sql语句效率优化问题

数据库  /  管理员 发布于 6年前   163

上次我们说到mysql的一些sql查询方面的优化,包括查看explain执行计划,分析索引等等。今天我们分享一些 分析mysql表读写、索引等等操作的sql语句。

闲话不多说,直接上代码:

反映表的读写压力

SELECT file_name AS file,    count_read,    sum_number_of_bytes_read AS total_read,    count_write,    sum_number_of_bytes_write AS total_written,    (sum_number_of_bytes_read + sum_number_of_bytes_write) AS total FROM performance_schema.file_summary_by_instanceORDER BY sum_number_of_bytes_read+ sum_number_of_bytes_write DESC;

反映文件的延迟

SELECT (file_name) AS file,    count_star AS total,    CONCAT(ROUND(sum_timer_wait / 3600000000000000, 2), 'h') AS total_latency,    count_read,    CONCAT(ROUND(sum_timer_read / 1000000000000, 2), 's') AS read_latency,    count_write,    CONCAT(ROUND(sum_timer_write / 3600000000000000, 2), 'h')AS write_latency FROM performance_schema.file_summary_by_instanceORDER BY sum_timer_wait DESC;

table 的读写延迟

SELECT object_schema AS table_schema,       object_name AS table_name,       count_star AS total,       CONCAT(ROUND(sum_timer_wait / 3600000000000000, 2), 'h') as total_latency,       CONCAT(ROUND((sum_timer_wait / count_star) / 1000000, 2), 'us') AS avg_latency,       CONCAT(ROUND(max_timer_wait / 1000000000, 2), 'ms') AS max_latency FROM performance_schema.objects_summary_global_by_type    ORDER BY sum_timer_wait DESC;

查看表操作频度

SELECT object_schema AS table_schema,      object_name AS table_name,      count_star AS rows_io_total,      count_read AS rows_read,      count_write AS rows_write,      count_fetch AS rows_fetchs,      count_insert AS rows_inserts,      count_update AS rows_updates,      count_delete AS rows_deletes,       CONCAT(ROUND(sum_timer_fetch / 3600000000000000, 2), 'h') AS fetch_latency,       CONCAT(ROUND(sum_timer_insert / 3600000000000000, 2), 'h') AS insert_latency,       CONCAT(ROUND(sum_timer_update / 3600000000000000, 2), 'h') AS update_latency,       CONCAT(ROUND(sum_timer_delete / 3600000000000000, 2), 'h') AS delete_latency   FROM performance_schema.table_io_waits_summary_by_table    ORDER BY sum_timer_wait DESC ;

索引状况

SELECT OBJECT_SCHEMA AS table_schema,        OBJECT_NAME AS table_name,        INDEX_NAME as index_name,        COUNT_FETCH AS rows_fetched,        CONCAT(ROUND(SUM_TIMER_FETCH / 3600000000000000, 2), 'h') AS select_latency,        COUNT_INSERT AS rows_inserted,        CONCAT(ROUND(SUM_TIMER_INSERT / 3600000000000000, 2), 'h') AS insert_latency,        COUNT_UPDATE AS rows_updated,        CONCAT(ROUND(SUM_TIMER_UPDATE / 3600000000000000, 2), 'h') AS update_latency,        COUNT_DELETE AS rows_deleted,        CONCAT(ROUND(SUM_TIMER_DELETE / 3600000000000000, 2), 'h')AS delete_latencyFROM performance_schema.table_io_waits_summary_by_index_usageWHERE index_name IS NOT NULLORDER BY sum_timer_wait DESC;

全表扫描情况

SELECT object_schema,    object_name,    count_read AS rows_full_scanned FROM performance_schema.table_io_waits_summary_by_index_usageWHERE index_name IS NULL  AND count_read > 0ORDER BY count_read DESC;

没有使用的index

SELECT object_schema,    object_name,    index_name  FROM performance_schema.table_io_waits_summary_by_index_usage WHERE index_name IS NOT NULL  AND count_star = 0  AND object_schema not in ('mysql','v_monitor')  AND index_name <> 'PRIMARY' ORDER BY object_schema, object_name;

糟糕的sql问题摘要

SELECT (DIGEST_TEXT) AS query,    SCHEMA_NAME AS db,    IF(SUM_NO_GOOD_INDEX_USED > 0 OR SUM_NO_INDEX_USED > 0, '*', '') AS full_scan,    COUNT_STAR AS exec_count,    SUM_ERRORS AS err_count,    SUM_WARNINGS AS warn_count,    (SUM_TIMER_WAIT) AS total_latency,    (MAX_TIMER_WAIT) AS max_latency,    (AVG_TIMER_WAIT) AS avg_latency,    (SUM_LOCK_TIME) AS lock_latency,    format(SUM_ROWS_SENT,0) AS rows_sent,    ROUND(IFNULL(SUM_ROWS_SENT / NULLIF(COUNT_STAR, 0), 0)) AS rows_sent_avg,    SUM_ROWS_EXAMINED AS rows_examined,    ROUND(IFNULL(SUM_ROWS_EXAMINED / NULLIF(COUNT_STAR, 0), 0)) AS rows_examined_avg,    SUM_CREATED_TMP_TABLES AS tmp_tables,    SUM_CREATED_TMP_DISK_TABLES AS tmp_disk_tables,    SUM_SORT_ROWS AS rows_sorted,    SUM_SORT_MERGE_PASSES AS sort_merge_passes,    DIGEST AS digest,    FIRST_SEEN AS first_seen,    LAST_SEEN as last_seen  FROM performance_schema.events_statements_summary_by_digest dwhere dORDER BY SUM_TIMER_WAIT DESClimit 20;

掌握这些sql,你能轻松知道你的库那些表存在问题,然后考虑怎么去优化。   

总结

以上就是这篇文章的全部内容了,希望本文的内容对大家的学习或者工作具有一定的参考学习价值,谢谢大家对的支持。如果你想了解更多相关内容请查看下面相关链接


  • 上一条:
    Mysql:The user specified as a definer (&#39;xxx@&#39;%&#39;) does not exist的解决方案
    下一条:
    Mysql查询正在执行的事务以及等待锁的操作方式
  • 昵称:

    邮箱:

    0条评论 (评论内容有缓存机制,请悉知!)
    最新最热
    • 分类目录
    • 人生(杂谈)
    • 技术
    • linux
    • Java
    • php
    • 框架(架构)
    • 前端
    • ThinkPHP
    • 数据库
    • 微信(小程序)
    • Laravel
    • Redis
    • Docker
    • Go
    • swoole
    • Windows
    • Python
    • 苹果(mac/ios)
    • 相关文章
    • 分库分表的目的、优缺点及具体实现方式介绍(0个评论)
    • DevDB - 在 VS 代码中直接访问数据库(0个评论)
    • 在ubuntu系统中实现mysql数据存储目录迁移流程步骤(0个评论)
    • 在mysql中使用存储过程批量新增测试数据流程步骤(0个评论)
    • php+mysql数据库批量根据条件快速更新、连表更新sql实现(0个评论)
    • 近期文章
    • 在go语言中使用api.geonames.org接口实现根据国际邮政编码获取地址信息功能(1个评论)
    • 在go语言中使用github.com/signintech/gopdf实现生成pdf分页文件功能(0个评论)
    • gmail发邮件报错:534 5.7.9 Application-specific password required...解决方案(0个评论)
    • 欧盟关于强迫劳动的规定的官方举报渠道及官方举报网站(0个评论)
    • 在go语言中使用github.com/signintech/gopdf实现生成pdf文件功能(0个评论)
    • Laravel从Accel获得5700万美元A轮融资(0个评论)
    • 在go + gin中gorm实现指定搜索/区间搜索分页列表功能接口实例(0个评论)
    • 在go语言中实现IP/CIDR的ip和netmask互转及IP段形式互转及ip是否存在IP/CIDR(0个评论)
    • PHP 8.4 Alpha 1现已发布!(0个评论)
    • Laravel 11.15版本发布 - Eloquent Builder中添加的泛型(0个评论)
    • 近期评论
    • 122 在

      学历:一种延缓就业设计,生活需求下的权衡之选中评论 工作几年后,报名考研了,到现在还没认真学习备考,迷茫中。作为一名北漂互联网打工人..
    • 123 在

      Clash for Windows作者删库跑路了,github已404中评论 按理说只要你在国内,所有的流量进出都在监控范围内,不管你怎么隐藏也没用,想搞你分..
    • 原梓番博客 在

      在Laravel框架中使用模型Model分表最简单的方法中评论 好久好久都没看友情链接申请了,今天刚看,已经添加。..
    • 博主 在

      佛跳墙vpn软件不会用?上不了网?佛跳墙vpn常见问题以及解决办法中评论 @1111老铁这个不行了,可以看看近期评论的其他文章..
    • 1111 在

      佛跳墙vpn软件不会用?上不了网?佛跳墙vpn常见问题以及解决办法中评论 网站不能打开,博主百忙中能否发个APP下载链接,佛跳墙或极光..
    • 2017-06
    • 2017-08
    • 2017-09
    • 2017-10
    • 2017-11
    • 2018-01
    • 2018-05
    • 2018-10
    • 2018-11
    • 2020-02
    • 2020-03
    • 2020-04
    • 2020-05
    • 2020-06
    • 2020-07
    • 2020-08
    • 2020-09
    • 2021-02
    • 2021-04
    • 2021-07
    • 2021-08
    • 2021-11
    • 2021-12
    • 2022-02
    • 2022-03
    • 2022-05
    • 2022-06
    • 2022-07
    • 2022-08
    • 2022-09
    • 2022-10
    • 2022-11
    • 2022-12
    • 2023-01
    • 2023-03
    • 2023-04
    • 2023-05
    • 2023-07
    • 2023-08
    • 2023-10
    • 2023-11
    • 2023-12
    • 2024-01
    • 2024-03
    Top

    Copyright·© 2019 侯体宗版权所有· 粤ICP备20027696号 PHP交流群

    侯体宗的博客