searchusermenu
  • 发布文章
  • 消息中心
点赞
收藏
评论
分享
原创

MySQL锁源头定位

2024-10-24 09:13:06
4
0

天翼云数据管理服务已支持MySQL MDL锁、行锁及死锁的自动化分析及源头定位

MDL锁源头定位

--查看所有MDL锁的会话
SELECT OBJECT_TYPE,
       OBJECT_SCHEMA,
       OBJECT_NAME,
       LOCK_TYPE,
       LOCK_STATUS,
       THREAD_ID,
       PROCESSLIST_ID,
       PROCESSLIST_INFO
FROM performance_schema.metadata_locks
INNER JOIN performance_schema.threads ON THREAD_ID = OWNER_THREAD_ID
WHERE PROCESSLIST_ID <> CONNECTION_ID();

--查看MDL锁源头
SELECT 
    locked_schema,
    locked_table,
    locked_type,
    waiting_processlist_id,
    waiting_age,
    waiting_query,
    waiting_state,
    blocking_processlist_id,
    blocking_age,
    SUBSTRING_INDEX(sql_text, 'transaction_begin;', - 1) AS blocking_query,
    sql_kill_blocking_connection
FROM
    (SELECT 
        b.OWNER_THREAD_ID AS granted_thread_id,
            a.OBJECT_SCHEMA AS locked_schema,
            a.OBJECT_NAME AS locked_table,
            CASE
                WHEN
                    (a.OBJECT_NAME IS NULL
                        AND b.OBJECT_NAME IS NULL)
                THEN
                    'Schema Metadata Lock'
                ELSE 'Table Metadata Lock'
            END locked_type,
            c.PROCESSLIST_ID AS waiting_processlist_id,
            c.PROCESSLIST_TIME AS waiting_age,
            c.PROCESSLIST_INFO AS waiting_query,
            c.PROCESSLIST_STATE AS waiting_state,
            d.PROCESSLIST_ID AS blocking_processlist_id,
            d.PROCESSLIST_TIME AS blocking_age,
            d.PROCESSLIST_INFO AS blocking_query,
            CONCAT('KILL ', d.PROCESSLIST_ID) AS sql_kill_blocking_connection
    FROM
        performance_schema.metadata_locks a
    JOIN performance_schema.metadata_locks b ON a.OBJECT_SCHEMA = b.OBJECT_SCHEMA
        AND ((a.OBJECT_NAME = b.OBJECT_NAME)
        OR (a.OBJECT_NAME IS NULL
        AND b.OBJECT_NAME IS NULL))
        AND a.lock_status = 'PENDING'
        AND b.lock_status = 'GRANTED'
        AND a.OWNER_THREAD_ID <> b.OWNER_THREAD_ID
        AND a.lock_type = 'EXCLUSIVE'
    JOIN performance_schema.threads c ON a.OWNER_THREAD_ID = c.THREAD_ID
    JOIN performance_schema.threads d ON b.OWNER_THREAD_ID = d.THREAD_ID) t1,
    (SELECT 
        thread_id,
            GROUP_CONCAT(CASE
                WHEN EVENT_NAME = 'statement/sql/begin' THEN 'transaction_begin'
                ELSE sql_text
            END
                ORDER BY event_id
                SEPARATOR ';') AS sql_text
    FROM
        performance_schema.events_statements_history
    GROUP BY thread_id) t2
WHERE
    t1.granted_thread_id = t2.thread_id\G

行锁源头定位

--输出行锁源事务的信息
SELECT distinct b.trx_id blocking_trx_id,
                b.trx_mysql_thread_id source_lock_thread_id,
                SUBSTRING(p. HOST, 1, INSTR(p. HOST, ':') - 1) blocking_host,
                SUBSTRING(p. HOST, INSTR(p. HOST, ':') + 1) blocking_port,
                IF(p.COMMAND = 'Sleep', p.TIME, 0) idel_in_trx,
                b.trx_query blocking_query,
                t2.sql_text blocking_trx_sql,
                concat('kill ',b.trx_mysql_thread_id,';') source_lock_kill_cmd
  FROM information_schema.INNODB_TRX b
  LEFT JOIN information_schema. PROCESSLIST p
    ON p.ID = b.trx_mysql_thread_id
  JOIN (SELECT BLOCKING_ENGINE_TRANSACTION_ID -- 查找最源头的trx_id
      FROM performance_schema.data_lock_waits ilw
     WHERE BLOCKING_ENGINE_TRANSACTION_ID NOT IN
           (SELECT REQUESTING_ENGINE_TRANSACTION_ID
              FROM performance_schema.data_lock_waits)) c
ON c.BLOCKING_ENGINE_TRANSACTION_ID = b.trx_id
join performance_schema.threads t1 ON b.trx_mysql_thread_id = t1.PROCESSLIST_ID 
join     (SELECT 
        thread_id,
            GROUP_CONCAT(CASE
                WHEN EVENT_NAME = 'statement/sql/begin' THEN 'transaction_begin'
                ELSE sql_text
            END
                ORDER BY event_id
                SEPARATOR ';') AS sql_text
    FROM
        performance_schema.events_statements_history
    GROUP BY thread_id) t2 on t1.thread_id=t2.thread_id\G

--输出行锁源事务和被直接阻塞事务的信息(不包含链式间接阻塞)
SELECT distinct b.trx_id blocking_trx_id,
                b.trx_mysql_thread_id source_lock_thread_id,
                SUBSTRING(p. HOST, 1, INSTR(p. HOST, ':') - 1) blocking_host,
                SUBSTRING(p. HOST, INSTR(p. HOST, ':') + 1) blocking_port,
                IF(p.COMMAND = 'Sleep', p.TIME, 0) idel_in_trx,
                b.trx_query blocking_query,
                t2.sql_text blocking_trx_sql,
                r.trx_id waiting_trx_id,
                r.trx_mysql_thread_id waiting_thread,
                TIMESTAMPDIFF(SECOND, r.trx_wait_started, CURRENT_TIMESTAMP) wait_time,
                r.trx_query waiting_query,
                l.LOCK_DATA waiting_table_lock
  FROM performance_schema.data_locks l
  LEFT JOIN performance_schema.data_lock_waits w
    ON w.REQUESTING_ENGINE_LOCK_ID = l.ENGINE_LOCK_ID
  LEFT JOIN information_schema.INNODB_TRX b
    ON b.trx_id = w.BLOCKING_ENGINE_TRANSACTION_ID
  LEFT JOIN information_schema.INNODB_TRX r
    ON r.trx_id = w.REQUESTING_ENGINE_TRANSACTION_ID
  LEFT JOIN information_schema. PROCESSLIST p
    ON p.ID = b.trx_mysql_thread_id
  JOIN (SELECT BLOCKING_ENGINE_TRANSACTION_ID -- 查找最源头的trx_id
      FROM performance_schema.data_lock_waits ilw
     WHERE BLOCKING_ENGINE_TRANSACTION_ID NOT IN
           (SELECT REQUESTING_ENGINE_TRANSACTION_ID
              FROM performance_schema.data_lock_waits)) c
ON c.BLOCKING_ENGINE_TRANSACTION_ID = b.trx_id 
join performance_schema.threads t1 ON b.trx_mysql_thread_id = t1.PROCESSLIST_ID 
join     (SELECT 
        thread_id,
            GROUP_CONCAT(CASE
                WHEN EVENT_NAME = 'statement/sql/begin' THEN 'transaction_begin'
                ELSE sql_text
            END
                ORDER BY event_id
                SEPARATOR ';') AS sql_text
    FROM
        performance_schema.events_statements_history
    GROUP BY thread_id) t2 on t1.thread_id=t2.thread_id
 ORDER BY wait_time DESC\G

--输出行锁源事务和被阻塞事务的信息(包含链式间接阻塞)
SELECT distinct b.trx_id blocking_trx_id,
                b.trx_mysql_thread_id source_lock_thread_id,
                SUBSTRING(p. HOST, 1, INSTR(p. HOST, ':') - 1) blocking_host,
                SUBSTRING(p. HOST, INSTR(p. HOST, ':') + 1) blocking_port,
                IF(p.COMMAND = 'Sleep', p.TIME, 0) idel_in_trx,
                b.trx_query blocking_current_query,
                t2.sql_text blocking_trx_query,
                r.trx_id waiting_trx_id,
                r.trx_mysql_thread_id waiting_thread,
                TIMESTAMPDIFF(SECOND, r.trx_wait_started, CURRENT_TIMESTAMP) wait_time,
                r.trx_query waiting_query,
                l.LOCK_DATA waiting_table_lock
  FROM performance_schema.data_locks l
  LEFT JOIN performance_schema.data_lock_waits w
    ON w.REQUESTING_ENGINE_LOCK_ID = l.ENGINE_LOCK_ID
  LEFT JOIN information_schema.INNODB_TRX b
    ON b.trx_id = w.BLOCKING_ENGINE_TRANSACTION_ID
  LEFT JOIN information_schema.INNODB_TRX r
    ON r.trx_id = w.REQUESTING_ENGINE_TRANSACTION_ID
  LEFT JOIN information_schema. PROCESSLIST p
    ON p.ID = b.trx_mysql_thread_id
join performance_schema.threads t1 ON b.trx_mysql_thread_id = t1.PROCESSLIST_ID 
join     (SELECT 
        thread_id,
            GROUP_CONCAT(CASE
                WHEN EVENT_NAME = 'statement/sql/begin' THEN 'transaction_begin'
                ELSE sql_text
            END
                ORDER BY event_id
                SEPARATOR ';') AS sql_text
    FROM
        performance_schema.events_statements_history
    GROUP BY thread_id) t2 on t1.thread_id=t2.thread_id
 ORDER BY wait_time DESC\G

查询锁信息需开启的performance_schema参数配置

--查询已开启的innodb监控度量
SELECT name, subsystem, status FROM INFORMATION_SCHEMA.INNODB_METRICS where status = 'enabled' ORDER BY NAME;

--查询已开启的性能记录项
select NAME from performance_schema.setup_instruments WHERE ENABLED = 'YES' and TIMED = 'YES';

--8.0
--performance_schema及innodb monitor参数配置
#performance_schema
performance_schema = 1
#performance_schema_instrument = '%memory%=on'
#performance_schema_instrument = '%lock%=on'

--5.7
--performance_schema及innodb monitor参数配置
#performance_schema
performance_schema = 1
performance_schema_instrument = '%memory%=on'
performance_schema_instrument = '%lock%=on'

--SQL保留长度增加
performance_schema_consumer_events_statements_history_long = ON
max_digest_length = 16384
performance_schema_max_digest_length = 16384
performance_schema_max_sql_text_length = 16384

#innodb monitor
innodb_monitor_enable="module_innodb"
innodb_monitor_enable="module_server"
innodb_monitor_enable="module_dml"
innodb_monitor_enable="module_ddl"
innodb_monitor_enable="module_trx"
innodb_monitor_enable="module_os"
innodb_monitor_enable="module_purge"
innodb_monitor_enable="module_log"
innodb_monitor_enable="module_buffer"
innodb_monitor_enable="module_index"
innodb_monitor_enable="module_ibuf_system"
innodb_monitor_enable="module_buffer_page"
innodb_monitor_enable="module_adaptive_hash"
innodb_monitor_enable="module_lock"


--8.0参数配置示例
#
[client]
port    = 33306
socket  = /data/mysql/tmp/mysql.sock

[mysql]
prompt="\u@cnabdabvdc00-205-46 \R:\m:\s [\d]> "
no-auto-rehash

[mysqldump]
quick
max_allowed_packet = 512M

[mysqld]
server_id = 20546
read_only = 1
super_read_only = on
event_scheduler = off
skip-slave-start
user    = mysql
port    = 33306
basedir = /data/app/mysql
datadir = /data/mysql/datafile
socket  = /data/mysql/tmp/mysql.sock
tmpdir = /data/mysql/tmp
pid-file = 20546.pid
character-set-server = utf8mb4
skip_name_resolve = 1
default_authentication_plugin = mysql_native_password
default_time_zone = "+8:00"

performance_schema_consumer_events_statements_history_long = ON
max_digest_length = 16384
performance_schema_max_digest_length = 16384
performance_schema_max_sql_text_length = 16384
sql_require_primary_key=1
open_files_limit    = 65535
back_log = 1024
max_connections = 3000
max_connect_errors = 1000000
table_open_cache = 1024
table_definition_cache = 1024
table_open_cache_instances = 64
thread_stack = 512K
external-locking = FALSE
max_allowed_packet = 32M
sort_buffer_size = 4M
join_buffer_size = 4M
thread_cache_size = 768
interactive_timeout = 600
wait_timeout = 600
tmp_table_size = 32M
max_heap_table_size = 32M
slow_query_log = 1
log_timestamps = SYSTEM
slow_query_log_file = /data/mysql/logs/slow.log
log-error = /data/mysql/logs/error.log
long_query_time = 1
log_queries_not_using_indexes =1
log_throttle_queries_not_using_indexes = 60
min_examined_row_limit = 100
log_slow_admin_statements = 1
log_slow_slave_statements = 1
log-bin = /data/mysql/binlog/binlog
sync_binlog = 1
#sync_relay_log=1
binlog_cache_size = 8M
max_binlog_cache_size = 2G
max_binlog_size = 1G
lower_case_table_names = 1
#expire_logs_days = 7

master_info_repository = TABLE
relay_log_info_repository = TABLE
gtid_mode = on
enforce_gtid_consistency = 1
log_slave_updates = on
slave-rows-search-algorithms = 'INDEX_SCAN,HASH_SCAN'
binlog_format = row
binlog_checksum = NONE
relay_log_recovery = 1
relay-log-purge = 1
key_buffer_size = 32M
read_buffer_size = 8M
read_rnd_buffer_size = 4M
bulk_insert_buffer_size = 64M
myisam_sort_buffer_size = 128M
myisam_max_sort_file_size = 10G
myisam_repair_threads = 1
lock_wait_timeout = 3600
explicit_defaults_for_timestamp = 1
innodb_thread_concurrency = 0
#innodb_sync_spin_loops = 100
#innodb_spin_wait_delay = 30

transaction_isolation = READ-COMMITTED
#innodb_additional_mem_pool_size = 16M
innodb_buffer_pool_size = 7933M
innodb_buffer_pool_instances = 4
innodb_buffer_pool_load_at_startup = 1
innodb_buffer_pool_dump_at_shutdown = 1
innodb_data_file_path = ibdata1:1G:autoextend
innodb_flush_log_at_trx_commit = 1
innodb_log_buffer_size = 32M
innodb_log_file_size = 2G
innodb_log_files_in_group = 3
innodb_max_undo_log_size = 4G
innodb_undo_directory = /data/mysql/datafile/undolog

innodb_io_capacity = 4000
innodb_io_capacity_max = 8000
innodb_flush_sync = 0
innodb_flush_neighbors = 0
innodb_write_io_threads = 8
innodb_read_io_threads = 8
innodb_purge_threads = 4
innodb_page_cleaners = 4
innodb_open_files = 65535
innodb_max_dirty_pages_pct = 75
innodb_flush_method = O_DIRECT
innodb_lru_scan_depth = 4000
innodb_checksum_algorithm = crc32
innodb_lock_wait_timeout = 10
innodb_rollback_on_timeout = 1
innodb_print_all_deadlocks = 1
innodb_file_per_table = 1
innodb_online_alter_log_max_size = 4G
innodb_stats_on_metadata = 0
innodb_undo_log_truncate = 1


# some var for MySQL 8
log_error_verbosity = 3
innodb_print_ddl_logs = 1
binlog_expire_logs_seconds = 604800
#innodb_dedicated_server = 0
sql_require_primary_key = 1

innodb_status_file = 1
innodb_status_output = 0
innodb_status_output_locks = 1

innodb_sort_buffer_size = 67108864
innodb_autoinc_lock_mode = 1

#performance_schema
performance_schema = 1
#performance_schema_instrument = '%memory%=on'
#performance_schema_instrument = '%lock%=on'

#innodb monitor
innodb_monitor_enable="module_innodb"
innodb_monitor_enable="module_server"
innodb_monitor_enable="module_dml"
innodb_monitor_enable="module_ddl"
innodb_monitor_enable="module_trx"
innodb_monitor_enable="module_os"
innodb_monitor_enable="module_purge"
innodb_monitor_enable="module_log"
innodb_monitor_enable="module_buffer"
innodb_monitor_enable="module_index"
innodb_monitor_enable="module_ibuf_system"
innodb_monitor_enable="module_buffer_page"
innodb_monitor_enable="module_adaptive_hash"
innodb_monitor_enable="module_lock"


# parallel replacate
binlog_transaction_dependency_tracking=writeset
transaction_write_set_extraction=XXHASH64
slave_parallel_type="LOGICAL_CLOCK"
slave_parallel_workers=16
slave_preserve_commit_order=on
slave_checkpoint_period=2
slave_checkpoint_group=256

#MGR
plugin_load_add='group_replication.so'
loose-group_replication_group_name="aaaaaaaa-aaaa-aaaa-aaaa-aaaaaaaaaaaa"
loose-group_replication_start_on_boot=off
loose-group_replication_local_address= "1.1.1.1:333061"
loose-group_replication_group_seeds= "1.1.1.1:333061,1.1.1.2:333061,1.1.1.3:333061"
loose-group_replication_ip_whitelist= "1.1.1.1,1.1.1.2,1.1.1.3"
loose-group_replication_member_weight=50
loose-group_replication_bootstrap_group=off
loose-group_replication_unreachable_majority_timeout=5
loose-group_replication_compression_threshold=131072
#loose-group_replication_transaction_size_limit=2097152
loose-group_replication_communication_max_message_size=10485760
loose-group_replication_flow_control_mode='DISABLED'
0条评论
作者已关闭评论
孙****文
2文章数
0粉丝数
孙****文
2 文章 | 0 粉丝
孙****文
2文章数
0粉丝数
孙****文
2 文章 | 0 粉丝
原创

MySQL锁源头定位

2024-10-24 09:13:06
4
0

天翼云数据管理服务已支持MySQL MDL锁、行锁及死锁的自动化分析及源头定位

MDL锁源头定位

--查看所有MDL锁的会话
SELECT OBJECT_TYPE,
       OBJECT_SCHEMA,
       OBJECT_NAME,
       LOCK_TYPE,
       LOCK_STATUS,
       THREAD_ID,
       PROCESSLIST_ID,
       PROCESSLIST_INFO
FROM performance_schema.metadata_locks
INNER JOIN performance_schema.threads ON THREAD_ID = OWNER_THREAD_ID
WHERE PROCESSLIST_ID <> CONNECTION_ID();

--查看MDL锁源头
SELECT 
    locked_schema,
    locked_table,
    locked_type,
    waiting_processlist_id,
    waiting_age,
    waiting_query,
    waiting_state,
    blocking_processlist_id,
    blocking_age,
    SUBSTRING_INDEX(sql_text, 'transaction_begin;', - 1) AS blocking_query,
    sql_kill_blocking_connection
FROM
    (SELECT 
        b.OWNER_THREAD_ID AS granted_thread_id,
            a.OBJECT_SCHEMA AS locked_schema,
            a.OBJECT_NAME AS locked_table,
            CASE
                WHEN
                    (a.OBJECT_NAME IS NULL
                        AND b.OBJECT_NAME IS NULL)
                THEN
                    'Schema Metadata Lock'
                ELSE 'Table Metadata Lock'
            END locked_type,
            c.PROCESSLIST_ID AS waiting_processlist_id,
            c.PROCESSLIST_TIME AS waiting_age,
            c.PROCESSLIST_INFO AS waiting_query,
            c.PROCESSLIST_STATE AS waiting_state,
            d.PROCESSLIST_ID AS blocking_processlist_id,
            d.PROCESSLIST_TIME AS blocking_age,
            d.PROCESSLIST_INFO AS blocking_query,
            CONCAT('KILL ', d.PROCESSLIST_ID) AS sql_kill_blocking_connection
    FROM
        performance_schema.metadata_locks a
    JOIN performance_schema.metadata_locks b ON a.OBJECT_SCHEMA = b.OBJECT_SCHEMA
        AND ((a.OBJECT_NAME = b.OBJECT_NAME)
        OR (a.OBJECT_NAME IS NULL
        AND b.OBJECT_NAME IS NULL))
        AND a.lock_status = 'PENDING'
        AND b.lock_status = 'GRANTED'
        AND a.OWNER_THREAD_ID <> b.OWNER_THREAD_ID
        AND a.lock_type = 'EXCLUSIVE'
    JOIN performance_schema.threads c ON a.OWNER_THREAD_ID = c.THREAD_ID
    JOIN performance_schema.threads d ON b.OWNER_THREAD_ID = d.THREAD_ID) t1,
    (SELECT 
        thread_id,
            GROUP_CONCAT(CASE
                WHEN EVENT_NAME = 'statement/sql/begin' THEN 'transaction_begin'
                ELSE sql_text
            END
                ORDER BY event_id
                SEPARATOR ';') AS sql_text
    FROM
        performance_schema.events_statements_history
    GROUP BY thread_id) t2
WHERE
    t1.granted_thread_id = t2.thread_id\G

行锁源头定位

--输出行锁源事务的信息
SELECT distinct b.trx_id blocking_trx_id,
                b.trx_mysql_thread_id source_lock_thread_id,
                SUBSTRING(p. HOST, 1, INSTR(p. HOST, ':') - 1) blocking_host,
                SUBSTRING(p. HOST, INSTR(p. HOST, ':') + 1) blocking_port,
                IF(p.COMMAND = 'Sleep', p.TIME, 0) idel_in_trx,
                b.trx_query blocking_query,
                t2.sql_text blocking_trx_sql,
                concat('kill ',b.trx_mysql_thread_id,';') source_lock_kill_cmd
  FROM information_schema.INNODB_TRX b
  LEFT JOIN information_schema. PROCESSLIST p
    ON p.ID = b.trx_mysql_thread_id
  JOIN (SELECT BLOCKING_ENGINE_TRANSACTION_ID -- 查找最源头的trx_id
      FROM performance_schema.data_lock_waits ilw
     WHERE BLOCKING_ENGINE_TRANSACTION_ID NOT IN
           (SELECT REQUESTING_ENGINE_TRANSACTION_ID
              FROM performance_schema.data_lock_waits)) c
ON c.BLOCKING_ENGINE_TRANSACTION_ID = b.trx_id
join performance_schema.threads t1 ON b.trx_mysql_thread_id = t1.PROCESSLIST_ID 
join     (SELECT 
        thread_id,
            GROUP_CONCAT(CASE
                WHEN EVENT_NAME = 'statement/sql/begin' THEN 'transaction_begin'
                ELSE sql_text
            END
                ORDER BY event_id
                SEPARATOR ';') AS sql_text
    FROM
        performance_schema.events_statements_history
    GROUP BY thread_id) t2 on t1.thread_id=t2.thread_id\G

--输出行锁源事务和被直接阻塞事务的信息(不包含链式间接阻塞)
SELECT distinct b.trx_id blocking_trx_id,
                b.trx_mysql_thread_id source_lock_thread_id,
                SUBSTRING(p. HOST, 1, INSTR(p. HOST, ':') - 1) blocking_host,
                SUBSTRING(p. HOST, INSTR(p. HOST, ':') + 1) blocking_port,
                IF(p.COMMAND = 'Sleep', p.TIME, 0) idel_in_trx,
                b.trx_query blocking_query,
                t2.sql_text blocking_trx_sql,
                r.trx_id waiting_trx_id,
                r.trx_mysql_thread_id waiting_thread,
                TIMESTAMPDIFF(SECOND, r.trx_wait_started, CURRENT_TIMESTAMP) wait_time,
                r.trx_query waiting_query,
                l.LOCK_DATA waiting_table_lock
  FROM performance_schema.data_locks l
  LEFT JOIN performance_schema.data_lock_waits w
    ON w.REQUESTING_ENGINE_LOCK_ID = l.ENGINE_LOCK_ID
  LEFT JOIN information_schema.INNODB_TRX b
    ON b.trx_id = w.BLOCKING_ENGINE_TRANSACTION_ID
  LEFT JOIN information_schema.INNODB_TRX r
    ON r.trx_id = w.REQUESTING_ENGINE_TRANSACTION_ID
  LEFT JOIN information_schema. PROCESSLIST p
    ON p.ID = b.trx_mysql_thread_id
  JOIN (SELECT BLOCKING_ENGINE_TRANSACTION_ID -- 查找最源头的trx_id
      FROM performance_schema.data_lock_waits ilw
     WHERE BLOCKING_ENGINE_TRANSACTION_ID NOT IN
           (SELECT REQUESTING_ENGINE_TRANSACTION_ID
              FROM performance_schema.data_lock_waits)) c
ON c.BLOCKING_ENGINE_TRANSACTION_ID = b.trx_id 
join performance_schema.threads t1 ON b.trx_mysql_thread_id = t1.PROCESSLIST_ID 
join     (SELECT 
        thread_id,
            GROUP_CONCAT(CASE
                WHEN EVENT_NAME = 'statement/sql/begin' THEN 'transaction_begin'
                ELSE sql_text
            END
                ORDER BY event_id
                SEPARATOR ';') AS sql_text
    FROM
        performance_schema.events_statements_history
    GROUP BY thread_id) t2 on t1.thread_id=t2.thread_id
 ORDER BY wait_time DESC\G

--输出行锁源事务和被阻塞事务的信息(包含链式间接阻塞)
SELECT distinct b.trx_id blocking_trx_id,
                b.trx_mysql_thread_id source_lock_thread_id,
                SUBSTRING(p. HOST, 1, INSTR(p. HOST, ':') - 1) blocking_host,
                SUBSTRING(p. HOST, INSTR(p. HOST, ':') + 1) blocking_port,
                IF(p.COMMAND = 'Sleep', p.TIME, 0) idel_in_trx,
                b.trx_query blocking_current_query,
                t2.sql_text blocking_trx_query,
                r.trx_id waiting_trx_id,
                r.trx_mysql_thread_id waiting_thread,
                TIMESTAMPDIFF(SECOND, r.trx_wait_started, CURRENT_TIMESTAMP) wait_time,
                r.trx_query waiting_query,
                l.LOCK_DATA waiting_table_lock
  FROM performance_schema.data_locks l
  LEFT JOIN performance_schema.data_lock_waits w
    ON w.REQUESTING_ENGINE_LOCK_ID = l.ENGINE_LOCK_ID
  LEFT JOIN information_schema.INNODB_TRX b
    ON b.trx_id = w.BLOCKING_ENGINE_TRANSACTION_ID
  LEFT JOIN information_schema.INNODB_TRX r
    ON r.trx_id = w.REQUESTING_ENGINE_TRANSACTION_ID
  LEFT JOIN information_schema. PROCESSLIST p
    ON p.ID = b.trx_mysql_thread_id
join performance_schema.threads t1 ON b.trx_mysql_thread_id = t1.PROCESSLIST_ID 
join     (SELECT 
        thread_id,
            GROUP_CONCAT(CASE
                WHEN EVENT_NAME = 'statement/sql/begin' THEN 'transaction_begin'
                ELSE sql_text
            END
                ORDER BY event_id
                SEPARATOR ';') AS sql_text
    FROM
        performance_schema.events_statements_history
    GROUP BY thread_id) t2 on t1.thread_id=t2.thread_id
 ORDER BY wait_time DESC\G

查询锁信息需开启的performance_schema参数配置

--查询已开启的innodb监控度量
SELECT name, subsystem, status FROM INFORMATION_SCHEMA.INNODB_METRICS where status = 'enabled' ORDER BY NAME;

--查询已开启的性能记录项
select NAME from performance_schema.setup_instruments WHERE ENABLED = 'YES' and TIMED = 'YES';

--8.0
--performance_schema及innodb monitor参数配置
#performance_schema
performance_schema = 1
#performance_schema_instrument = '%memory%=on'
#performance_schema_instrument = '%lock%=on'

--5.7
--performance_schema及innodb monitor参数配置
#performance_schema
performance_schema = 1
performance_schema_instrument = '%memory%=on'
performance_schema_instrument = '%lock%=on'

--SQL保留长度增加
performance_schema_consumer_events_statements_history_long = ON
max_digest_length = 16384
performance_schema_max_digest_length = 16384
performance_schema_max_sql_text_length = 16384

#innodb monitor
innodb_monitor_enable="module_innodb"
innodb_monitor_enable="module_server"
innodb_monitor_enable="module_dml"
innodb_monitor_enable="module_ddl"
innodb_monitor_enable="module_trx"
innodb_monitor_enable="module_os"
innodb_monitor_enable="module_purge"
innodb_monitor_enable="module_log"
innodb_monitor_enable="module_buffer"
innodb_monitor_enable="module_index"
innodb_monitor_enable="module_ibuf_system"
innodb_monitor_enable="module_buffer_page"
innodb_monitor_enable="module_adaptive_hash"
innodb_monitor_enable="module_lock"


--8.0参数配置示例
#
[client]
port    = 33306
socket  = /data/mysql/tmp/mysql.sock

[mysql]
prompt="\u@cnabdabvdc00-205-46 \R:\m:\s [\d]> "
no-auto-rehash

[mysqldump]
quick
max_allowed_packet = 512M

[mysqld]
server_id = 20546
read_only = 1
super_read_only = on
event_scheduler = off
skip-slave-start
user    = mysql
port    = 33306
basedir = /data/app/mysql
datadir = /data/mysql/datafile
socket  = /data/mysql/tmp/mysql.sock
tmpdir = /data/mysql/tmp
pid-file = 20546.pid
character-set-server = utf8mb4
skip_name_resolve = 1
default_authentication_plugin = mysql_native_password
default_time_zone = "+8:00"

performance_schema_consumer_events_statements_history_long = ON
max_digest_length = 16384
performance_schema_max_digest_length = 16384
performance_schema_max_sql_text_length = 16384
sql_require_primary_key=1
open_files_limit    = 65535
back_log = 1024
max_connections = 3000
max_connect_errors = 1000000
table_open_cache = 1024
table_definition_cache = 1024
table_open_cache_instances = 64
thread_stack = 512K
external-locking = FALSE
max_allowed_packet = 32M
sort_buffer_size = 4M
join_buffer_size = 4M
thread_cache_size = 768
interactive_timeout = 600
wait_timeout = 600
tmp_table_size = 32M
max_heap_table_size = 32M
slow_query_log = 1
log_timestamps = SYSTEM
slow_query_log_file = /data/mysql/logs/slow.log
log-error = /data/mysql/logs/error.log
long_query_time = 1
log_queries_not_using_indexes =1
log_throttle_queries_not_using_indexes = 60
min_examined_row_limit = 100
log_slow_admin_statements = 1
log_slow_slave_statements = 1
log-bin = /data/mysql/binlog/binlog
sync_binlog = 1
#sync_relay_log=1
binlog_cache_size = 8M
max_binlog_cache_size = 2G
max_binlog_size = 1G
lower_case_table_names = 1
#expire_logs_days = 7

master_info_repository = TABLE
relay_log_info_repository = TABLE
gtid_mode = on
enforce_gtid_consistency = 1
log_slave_updates = on
slave-rows-search-algorithms = 'INDEX_SCAN,HASH_SCAN'
binlog_format = row
binlog_checksum = NONE
relay_log_recovery = 1
relay-log-purge = 1
key_buffer_size = 32M
read_buffer_size = 8M
read_rnd_buffer_size = 4M
bulk_insert_buffer_size = 64M
myisam_sort_buffer_size = 128M
myisam_max_sort_file_size = 10G
myisam_repair_threads = 1
lock_wait_timeout = 3600
explicit_defaults_for_timestamp = 1
innodb_thread_concurrency = 0
#innodb_sync_spin_loops = 100
#innodb_spin_wait_delay = 30

transaction_isolation = READ-COMMITTED
#innodb_additional_mem_pool_size = 16M
innodb_buffer_pool_size = 7933M
innodb_buffer_pool_instances = 4
innodb_buffer_pool_load_at_startup = 1
innodb_buffer_pool_dump_at_shutdown = 1
innodb_data_file_path = ibdata1:1G:autoextend
innodb_flush_log_at_trx_commit = 1
innodb_log_buffer_size = 32M
innodb_log_file_size = 2G
innodb_log_files_in_group = 3
innodb_max_undo_log_size = 4G
innodb_undo_directory = /data/mysql/datafile/undolog

innodb_io_capacity = 4000
innodb_io_capacity_max = 8000
innodb_flush_sync = 0
innodb_flush_neighbors = 0
innodb_write_io_threads = 8
innodb_read_io_threads = 8
innodb_purge_threads = 4
innodb_page_cleaners = 4
innodb_open_files = 65535
innodb_max_dirty_pages_pct = 75
innodb_flush_method = O_DIRECT
innodb_lru_scan_depth = 4000
innodb_checksum_algorithm = crc32
innodb_lock_wait_timeout = 10
innodb_rollback_on_timeout = 1
innodb_print_all_deadlocks = 1
innodb_file_per_table = 1
innodb_online_alter_log_max_size = 4G
innodb_stats_on_metadata = 0
innodb_undo_log_truncate = 1


# some var for MySQL 8
log_error_verbosity = 3
innodb_print_ddl_logs = 1
binlog_expire_logs_seconds = 604800
#innodb_dedicated_server = 0
sql_require_primary_key = 1

innodb_status_file = 1
innodb_status_output = 0
innodb_status_output_locks = 1

innodb_sort_buffer_size = 67108864
innodb_autoinc_lock_mode = 1

#performance_schema
performance_schema = 1
#performance_schema_instrument = '%memory%=on'
#performance_schema_instrument = '%lock%=on'

#innodb monitor
innodb_monitor_enable="module_innodb"
innodb_monitor_enable="module_server"
innodb_monitor_enable="module_dml"
innodb_monitor_enable="module_ddl"
innodb_monitor_enable="module_trx"
innodb_monitor_enable="module_os"
innodb_monitor_enable="module_purge"
innodb_monitor_enable="module_log"
innodb_monitor_enable="module_buffer"
innodb_monitor_enable="module_index"
innodb_monitor_enable="module_ibuf_system"
innodb_monitor_enable="module_buffer_page"
innodb_monitor_enable="module_adaptive_hash"
innodb_monitor_enable="module_lock"


# parallel replacate
binlog_transaction_dependency_tracking=writeset
transaction_write_set_extraction=XXHASH64
slave_parallel_type="LOGICAL_CLOCK"
slave_parallel_workers=16
slave_preserve_commit_order=on
slave_checkpoint_period=2
slave_checkpoint_group=256

#MGR
plugin_load_add='group_replication.so'
loose-group_replication_group_name="aaaaaaaa-aaaa-aaaa-aaaa-aaaaaaaaaaaa"
loose-group_replication_start_on_boot=off
loose-group_replication_local_address= "1.1.1.1:333061"
loose-group_replication_group_seeds= "1.1.1.1:333061,1.1.1.2:333061,1.1.1.3:333061"
loose-group_replication_ip_whitelist= "1.1.1.1,1.1.1.2,1.1.1.3"
loose-group_replication_member_weight=50
loose-group_replication_bootstrap_group=off
loose-group_replication_unreachable_majority_timeout=5
loose-group_replication_compression_threshold=131072
#loose-group_replication_transaction_size_limit=2097152
loose-group_replication_communication_max_message_size=10485760
loose-group_replication_flow_control_mode='DISABLED'
文章来自个人专栏
MySQL研发运维
2 文章 | 1 订阅
0条评论
作者已关闭评论
作者已关闭评论
0
0