├── Performance_Schema_Memory_Footprint.md ├── README.md ├── Statistic Analysis-1551728872954.json ├── check_max_int.sh ├── collectdata.sh ├── get_history_long.sh ├── load_data.sh ├── restoreToDev.sh └── split /Performance_Schema_Memory_Footprint.md: -------------------------------------------------------------------------------- 1 | # **Performance Schema / Memory Footprint** 2 | 3 | Table of Contents 4 | ================= 5 | 6 | * [Performance Schema / Memory Footprint](#performance-schema--memory-footprint) 7 | * [Performance Schema in a nutshell](#performance-schema-in-a-nutshell) 8 | * [P_S memory footprint](#p_s-memory-footprint) 9 | * [What's currently available in 5.6?](#whats-currently-available-in-56) 10 | * [Limitations of fixed memalloc](#limitations-of-fixed-memalloc) 11 | * [What's new in 5.7?](#whats-new-in-57) 12 | * [How to set memory allocation?](#how-to-set-memory-allocation) 13 | * [How auto-sized values are calculated?](#how-auto-sized-values-are-calculated) 14 | * [How much memory the Performance Schema is using?](#how-much-memory-the-performance-schema-is-using) 15 | * [P_S Memory metrics](#p_s-memory-metrics) 16 | * [Memory tables](#memory-tables) 17 | * [Memory instruments](#memory-instruments) 18 | * [Using Sys Schema](#using-sys-schema) 19 | * [memory_by_host_by_current_bytes](#memory_by_host_by_current_bytes) 20 | * [memory_by_thread_by_current_bytes](#memory_by_thread_by_current_bytes) 21 | * [memory_by_user_by_current_bytes](#memory_by_user_by_current_bytes) 22 | * [memory_global_by_current_bytes](#memory_global_by_current_bytes) 23 | * [memory_global_total](#memory_global_total) 24 | * [More info](#more-info) 25 | 26 | ## Performance Schema in a nutshell 27 | 28 | Performance Schema is a mechanism to collect and report run time statistics for running MySQL server. These statistics are stored-in and fetched-from internal memory buffers. 29 | 30 | ## P_S memory footprint 31 | 32 | How much memory does P_S uses by just itself. 33 | 34 | ### What's currently available in 5.6? 35 | 36 | In MySQL 5.6, memory for these buffers is allocated during MySQL server startup with either user specified configuration values or with default values that autosize. Once the server has started, the size of the buffers is fixed and performance_schema does not do any additional memory allocation or freeing during execution. 37 | 38 | #### Limitations of fixed memalloc 39 | 40 | - Significant amount of allocated buffer is left unused if less instances of instrument are encountered. 41 | - Amount allocated is not sufficient and performance_schema starts loosing further statistics if more instances of instrument are encountered. 42 | 43 | ### What's new in 5.7? 44 | 45 | In MySQL 5.7 memory allocation for Performance Schema buffers doesn’t happen at server start-up but is instead based on the actual runtime requirement. 46 | 47 | As of MySQL 5.7.6, the memory model allocates less memory by default under most circumstances: 48 | 49 | - May allocate memory at server startup 50 | 51 | - May allocate additional memory during server operation 52 | 53 | - Never free memory during server operation (although it might be recycled) 54 | 55 | - Free all memory used at shutdown 56 | 57 | Consumption scales with server load. Memory used depends on the load actually seen, not the load estimated or explicitly configured for. 58 | 59 | #### How to set memory allocation? 60 | 61 | For the server variables (which control buffer size), you can now specify: 62 | 63 | | Value | Description | 64 | | ----- | ---------------------------------------- | 65 | | 0 | To tell P_S not to collect stats thus no allocation for this buffer. | 66 | | N | To tell P_S to collect stats for maximum N instance only. Memory allocation happens as and when need arises. And this allocation continues until space for max (N here) instances is allocated. | 67 | | -1 | To tell P_S take your own decision for maximum limit. As above, memory is allocated as and when need arises. This allocation continues until space for max (decided by P_S here) instances is allocated. | 68 | 69 | With -1, as the Performance Schema collects data, memory is allocated in the corresponding buffer. The buffer size is unbounded, and may grow with the load. 70 | 71 | With N, once the buffer size reaches N, no more memory is allocated. Data collected by the Performance Schema for this buffer is lost, and any corresponding “lost instance” counters are incremented. 72 | 73 | Lost instances can be tracked on the server status: 74 | 75 | ```mysql 76 | mysql> pager head 77 | PAGER set to 'head' 78 | mysql> show status like '%lost'; 79 | +-----------------------------------------------+-------+ 80 | | Variable_name | Value | 81 | +-----------------------------------------------+-------+ 82 | | Performance_schema_accounts_lost | 0 | 83 | | Performance_schema_cond_classes_lost | 0 | 84 | | Performance_schema_cond_instances_lost | 0 | 85 | | Performance_schema_digest_lost | 0 | 86 | | Performance_schema_file_classes_lost | 0 | 87 | | Performance_schema_file_handles_lost | 0 | 88 | | Performance_schema_file_instances_lost | 0 | 89 | 30 rows in set (0.00 sec) 90 | ``` 91 | 92 | Variables that can be autosized/autoscaled, are set to -1 by default: 93 | 94 | ```mysql 95 | mysql> show variables where variable_name like "performance_schema%" and variable_value=-1; 96 | +------------------------------------------------------+-------+ 97 | | Variable_name | Value | 98 | +------------------------------------------------------+-------+ 99 | | performance_schema_accounts_size | -1 | 100 | | performance_schema_hosts_size | -1 | 101 | | performance_schema_max_cond_instances | -1 | 102 | | performance_schema_max_file_instances | -1 | 103 | | performance_schema_max_index_stat | -1 | 104 | | performance_schema_max_metadata_locks | -1 | 105 | | performance_schema_max_mutex_instances | -1 | 106 | | performance_schema_max_prepared_statements_instances | -1 | 107 | | performance_schema_max_program_instances | -1 | 108 | | performance_schema_max_rwlock_instances | -1 | 109 | | performance_schema_max_socket_instances | -1 | 110 | | performance_schema_max_table_handles | -1 | 111 | | performance_schema_max_table_instances | -1 | 112 | | performance_schema_max_table_lock_stat | -1 | 113 | | performance_schema_max_thread_instances | -1 | 114 | | performance_schema_setup_actors_size | -1 | 115 | | performance_schema_setup_objects_size | -1 | 116 | | performance_schema_users_size | -1 | 117 | +------------------------------------------------------+-------+ 118 | 18 rows in set, 1 warning (0.01 sec) 119 | ``` 120 | 121 | You can also check https://dev.mysql.com/doc/refman/5.7/en/performance-schema-system-variables.html and find out which variables are autosized or autoscaled 122 | 123 | What's the difference: 124 | 125 | - **auto-sized:** Based on estimated server load/configuration, value of this variable would be determined by performance schema during startup. 126 | - **auto-scaled:** Based on actual runtime requirement, memory is allocated for buffers controlled by these variables. 127 | 128 | #### How auto-sized values are calculated? 129 | 130 | For each **autosized** parameter that is not set at server startup (or is set to −1), the Performance Schema determines how to set its value based on the value of the following system values, which are considered as “hints” about how you have configured your MySQL server: 131 | 132 | > max_connections 133 | > open_files_limit 134 | > table_definition_cache 135 | > table_open_cache 136 | 137 | #### How much memory the Performance Schema is using? 138 | 139 | The Performance Schema allocates memory internally and associates each buffer with a dedicated instrument so that memory consumption can be traced to individual buffers. 140 | 141 | Instruments named with the prefix memory/performance_schema/ expose how much memory is allocated for these internal buffers. 142 | 143 | The buffers are global to the server, so the instruments are displayed only in the **memory_summary_global_by_event_name** table, and not in other memory_summary_by_xxx_by_event_name tables. 144 | 145 | Use this query: 146 | 147 | ```mysql 148 | SELECT 149 | * 150 | FROM 151 | performance_schema.memory_summary_global_by_event_name 152 | WHERE EVENT_NAME LIKE 'memory/performance_schema/%'; 153 | ``` 154 | 155 | ```mysql 156 | *************************** 1. row *************************** 157 | EVENT_NAME: memory/performance_schema/file_instances 158 | COUNT_ALLOC: 1 159 | COUNT_FREE: 0 160 | SUM_NUMBER_OF_BYTES_ALLOC: 720896 161 | SUM_NUMBER_OF_BYTES_FREE: 0 162 | LOW_COUNT_USED: 0 163 | CURRENT_COUNT_USED: 1 164 | HIGH_COUNT_USED: 1 165 | LOW_NUMBER_OF_BYTES_USED: 0 166 | CURRENT_NUMBER_OF_BYTES_USED: 720896 167 | HIGH_NUMBER_OF_BYTES_USED: 720896 168 | ``` 169 | 170 | For details about the fields, please see https://dev.mysql.com/doc/refman/5.7/en/memory-summary-tables.html 171 | 172 | You can also use the **SHOW ENGINE PERFORMANCE_SCHEMA STATUS** command to inspect the internal operation of the Performance Schema code: 173 | 174 | ```mysql 175 | mysql> pager grep "\.memory" | less 176 | PAGER set to 'grep "\.memory" | less' 177 | mysql> show engine performance_schema status; 178 | | performance_schema | events_waits_history.memory | 450560 | 179 | | performance_schema | events_waits_history_long.memory | 176000 | 180 | | performance_schema | (pfs_mutex_class).memory | 51200 | 181 | | performance_schema | (pfs_rwlock_class).memory | 12800 | 182 | | performance_schema | (pfs_cond_class).memory | 20480 | 183 | | performance_schema | (pfs_thread_class).memory | 9600 | 184 | | performance_schema | (pfs_file_class).memory | 25600 | 185 | | performance_schema | mutex_instances.memory | 0 | 186 | | performance_schema | rwlock_instances.memory | 0 | 187 | | performance_schema | cond_instances.memory | 0 | 188 | | performance_schema | threads.memory | 950272 | 189 | | performance_schema | file_instances.memory | 720896 | 190 | | performance_schema | (pfs_file_handle).memory | 262144 | 191 | | performance_schema | events_waits_summary_by_thread_by_event_name.memory | 3473408 | 192 | | performance_schema | (pfs_table_share).memory | 1048576 | 193 | | performance_schema | (pfs_table).memory | 0 | 194 | | performance_schema | setup_actors.memory | 40960 | 195 | | performance_schema | setup_objects.memory | 57344 | 196 | | performance_schema | (pfs_account).memory | 90112 | 197 | | performance_schema | events_waits_summary_by_account_by_event_name.memory | 1736704 | 198 | | performance_schema | events_waits_summary_by_user_by_event_name.memory | 1736704 | 199 | | performance_schema | events_waits_summary_by_host_by_event_name.memory | 1736704 | 200 | | performance_schema | (pfs_user).memory | 81920 | 201 | | performance_schema | (pfs_host).memory | 73728 | 202 | | performance_schema | (pfs_stage_class).memory | 38400 | 203 | | performance_schema | events_stages_history.memory | 266240 | 204 | | performance_schema | events_stages_history_long.memory | 104000 | 205 | | performance_schema | events_stages_summary_by_thread_by_event_name.memory | 1228800 | 206 | | performance_schema | events_stages_summary_global_by_event_name.memory | 4800 | 207 | | performance_schema | events_stages_summary_by_account_by_event_name.memory | 614400 | 208 | | performance_schema | events_stages_summary_by_user_by_event_name.memory | 614400 | 209 | | performance_schema | events_stages_summary_by_host_by_event_name.memory | 614400 | 210 | | performance_schema | (pfs_statement_class).memory | 38592 | 211 | | performance_schema | events_statements_history.memory | 3665920 | 212 | | performance_schema | events_statements_history_long.memory | 1432000 | 213 | | performance_schema | events_statements_summary_by_thread_by_event_name.memory | 9467904 | 214 | | performance_schema | events_statements_summary_global_by_event_name.memory | 36984 | 215 | | performance_schema | events_statements_summary_by_account_by_event_name.memory | 4733952 | 216 | | performance_schema | events_statements_summary_by_user_by_event_name.memory | 4733952 | 217 | | performance_schema | events_statements_summary_by_host_by_event_name.memory | 4733952 | 218 | | performance_schema | events_statements_current.memory | 3665920 | 219 | | performance_schema | (pfs_socket_class).memory | 3200 | 220 | | performance_schema | socket_instances.memory | 0 | 221 | | performance_schema | events_statements_summary_by_digest.memory | 2560000 | 222 | | performance_schema | events_statements_summary_by_program.memory | 0 | 223 | | performance_schema | session_connect_attrs.memory | 131072 | 224 | | performance_schema | prepared_statements_instances.memory | 0 | 225 | | performance_schema | (pfs_memory_class).memory | 76800 | 226 | | performance_schema | memory_summary_by_thread_by_event_name.memory | 7372800 | 227 | | performance_schema | memory_summary_global_by_event_name.memory | 28800 | 228 | | performance_schema | memory_summary_by_account_by_event_name.memory | 3686400 | 229 | | performance_schema | memory_summary_by_user_by_event_name.memory | 3686400 | 230 | | performance_schema | memory_summary_by_host_by_event_name.memory | 3686400 | 231 | | performance_schema | metadata_locks.memory | 0 | 232 | | performance_schema | events_transactions_history.memory | 880640 | 233 | | performance_schema | events_transactions_history_long.memory | 344000 | 234 | | performance_schema | events_transactions_summary_by_thread_by_event_name.memory | 22528 | 235 | | performance_schema | events_transactions_summary_by_account_by_event_name.memory | 11264 | 236 | | performance_schema | events_transactions_summary_by_user_by_event_name.memory | 11264 | 237 | | performance_schema | events_transactions_summary_by_host_by_event_name.memory | 11264 | 238 | | performance_schema | table_lock_waits_summary_by_table.memory | 0 | 239 | | performance_schema | table_io_waits_summary_by_index_usage.memory | 352256 | 240 | | performance_schema | (history_long_statements_digest_token_array).memory | 1024000 | 241 | | performance_schema | (history_statements_digest_token_array).memory | 2621440 | 242 | | performance_schema | (current_statements_digest_token_array).memory | 2621440 | 243 | | performance_schema | (history_long_statements_text_array).memory | 1024000 | 244 | | performance_schema | (history_statements_text_array).memory | 2621440 | 245 | | performance_schema | (current_statements_text_array).memory | 2621440 | 246 | | performance_schema | (statements_digest_token_array).memory | 5120000 | 247 | | performance_schema | performance_schema.memory | 89269176 | 248 | ``` 249 | 250 | Name values consist of two parts, which name an internal buffer and a buffer attribute, respectively. Interpret buffer names as follows: 251 | 252 | - An internal buffer that is not exposed as a table is named within parentheses. Examples: (pfs_cond_class).size, (pfs_mutex_class).memory. 253 | 254 | - An internal buffer that is exposed as a table in the performance_schema database is named after the table, without parentheses. Examples: events_waits_history.size, mutex_instances.count. 255 | 256 | - A value that applies to the Performance Schema as a whole begins with performance_schema. Example: performance_schema.memory. 257 | 258 | Buffer attributes have these meanings: 259 | 260 | - **size** is the size of the internal record used by the implementation, such as the size of a row in a table. size values cannot be changed. 261 | 262 | - **count** is the number of internal records, such as the number of rows in a table. count values can be changed using Performance Schema configuration options. 263 | 264 | - For a table, **tbl_name**.memory is the product of size and count. For the Performance Schema as a whole, performance_schema.memory is the sum of all the memory used (the sum of all other memory values). 265 | 266 | ## P_S Memory metrics 267 | 268 | ### Memory tables 269 | 270 | 5 tables (5.7.11-4 Percona Server (GPL), Release '4', Revision '5c940e1'): 271 | 272 | ```mysql 273 | mysql> show tables like '%memory%'; 274 | +-----------------------------------------+ 275 | | Tables_in_performance_schema (%memory%) | 276 | +-----------------------------------------+ 277 | | memory_summary_by_account_by_event_name | 278 | | memory_summary_by_host_by_event_name | 279 | | memory_summary_by_thread_by_event_name | 280 | | memory_summary_by_user_by_event_name | 281 | | memory_summary_global_by_event_name | 282 | +-----------------------------------------+ 283 | 5 rows in set (0.00 sec) 284 | ``` 285 | 286 | ### Memory instruments 287 | 288 | 391 memory instruments (5.7.11-4 Percona Server (GPL), Release '4', Revision '5c940e1') 289 | 290 | ```mysql 291 | mysql> select substring_index(name,'/',2), count(*) from performance_schema.setup_instruments where name like 'memory%' group by 1 with rollup; 292 | +-----------------------------+----------+ 293 | | substring_index(name,'/',2) | count(*) | 294 | +-----------------------------+----------+ 295 | | memory/archive | 2 | 296 | | memory/blackhole | 1 | 297 | | memory/client | 7 | 298 | | memory/csv | 5 | 299 | | memory/innodb | 92 | 300 | | memory/keyring | 1 | 301 | | memory/memory | 5 | 302 | | memory/myisam | 21 | 303 | | memory/myisammrg | 2 | 304 | | memory/mysys | 21 | 305 | | memory/partition | 3 | 306 | | memory/performance_schema | 70 | 307 | | memory/sql | 157 | 308 | | memory/vio | 4 | 309 | | NULL | 391 | 310 | +-----------------------------+----------+ 311 | 15 rows in set (0.00 sec) 312 | ``` 313 | 314 | Let's enable all the consumers: 315 | 316 | ```mysql 317 | mysql> update setup_consumers set enabled = 'yes' ; 318 | Query OK, 10 rows affected (0.00 sec) 319 | Rows matched: 15 Changed: 10 Warnings: 0 320 | ``` 321 | 322 | By default, only 70 memory instruments are enabled: 323 | 324 | ```Mysql 325 | mysql> select count(*) from setup_instruments where name like 'memory%' and enabled = 'yes'; 326 | +----------+ 327 | | count(*) | 328 | +----------+ 329 | | 70 | 330 | +----------+ 331 | 1 row in set (0.00 sec) 332 | ``` 333 | 334 | Let's enable the rest of them (321): 335 | 336 | ```mysql 337 | mysql> update setup_instruments set enabled = 'yes' where name like 'memory%'; 338 | Query OK, 321 rows affected (0.00 sec) 339 | Rows matched: 391 Changed: 321 Warnings: 0 340 | ``` 341 | 342 | Now, to get the statistics, we could just query the **p_s.memory_%** tables OR we could use the **Sys Schema!** 343 | 344 | ## Using Sys Schema 345 | 346 | Sys Schema comes by default in 5.7 and have 5 views related to **Memory:** 347 | 348 | - memory_by_host_by_current_bytes 349 | - memory_by_thread_by_current_bytes 350 | - memory_by_user_by_current_bytes 351 | - memory_global_by_current_bytes 352 | - memory_global_total 353 | 354 | #### memory_by_host_by_current_bytes 355 | 356 | Summarizes memory use by host using the 5.7 Performance Schema instrumentation. When the host found is NULL, it is assumed to be a local "background" thread. 357 | 358 | ```mysql 359 | mysql> select * from memory_by_host_by_current_bytes; 360 | +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 361 | | host | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | 362 | +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 363 | | localhost | 833 | 1.56 MiB | 1.92 KiB | 805.47 KiB | 1.72 GiB | 364 | | background | 52 | 24.14 KiB | 475 bytes | 16.02 KiB | 3.88 MiB | 365 | +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 366 | 2 rows in set (0.00 sec) 367 | ``` 368 | 369 | It's based on the table **performance_schema.memory_summary_by_host_by_event_name** 370 | 371 | https://dev.mysql.com/doc/refman/5.7/en/sys-memory-by-host-by-current-bytes.html 372 | 373 | #### memory_by_thread_by_current_bytes 374 | 375 | Summarizes memory use by threads using the 5.7 Performance Schema instrumentation. 376 | 377 | ```mysql 378 | mysql> select * from sys.memory_by_thread_by_current_bytes limit 10; 379 | +-----------+----------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 380 | | thread_id | user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | 381 | +-----------+----------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 382 | | 29 | root@localhost | 517 | 1.46 MiB | 2.89 KiB | 805.47 KiB | 226.81 MiB | 383 | | 40 | root@localhost | 13 | 22.84 KiB | 1.76 KiB | 16.01 KiB | 25.48 MiB | 384 | | 38 | root@localhost | 12 | 22.49 KiB | 1.87 KiB | 16.01 KiB | 25.50 MiB | 385 | | 39 | root@localhost | 12 | 22.49 KiB | 1.87 KiB | 16.01 KiB | 24.00 MiB | 386 | | 37 | root@localhost | 11 | 22.15 KiB | 2.01 KiB | 16.01 KiB | 23.92 MiB | 387 | | 25 | innodb/dict_stats_thread | 30 | 5.00 KiB | 171 bytes | 4.47 KiB | 1.71 MiB | 388 | | 3 | innodb/io_write_thread | 0 | 0 bytes | 0 bytes | 0 bytes | 0 bytes | 389 | | 4 | innodb/io_write_thread | 0 | 0 bytes | 0 bytes | 0 bytes | 0 bytes | 390 | | 5 | innodb/io_write_thread | 0 | 0 bytes | 0 bytes | 0 bytes | 0 bytes | 391 | | 6 | innodb/page_cleaner_thread | 0 | 0 bytes | 0 bytes | 0 bytes | 3.48 KiB | 392 | +-----------+----------------------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 393 | 10 rows in set (0.10 sec) 394 | ``` 395 | 396 | Based on the tables **performance_schema.memory_summary_by_thread_by_event_name** and **performance_schema.threads.** 397 | 398 | https://dev.mysql.com/doc/refman/5.7/en/sys-memory-by-thread-by-current-bytes.html 399 | 400 | #### memory_by_user_by_current_bytes 401 | 402 | Summarizes memory use by user using the 5.7 Performance Schema instrumentation. 403 | 404 | ```mysql 405 | mysql> select * from memory_by_user_by_current_bytes; 406 | +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 407 | | user | current_count_used | current_allocated | current_avg_alloc | current_max_alloc | total_allocated | 408 | +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 409 | | root | 835 | 1.57 MiB | 1.92 KiB | 805.47 KiB | 2.41 GiB | 410 | | background | 66 | 26.45 KiB | 410 bytes | 16.02 KiB | 7.00 MiB | 411 | +------------+--------------------+-------------------+-------------------+-------------------+-----------------+ 412 | 2 rows in set (0.01 sec) 413 | ``` 414 | 415 | Based on the table **performance_schema.memory_summary_by_user_by_event_name** 416 | 417 | https://dev.mysql.com/doc/refman/5.7/en/sys-memory-by-user-by-current-bytes.html 418 | 419 | #### memory_global_by_current_bytes 420 | 421 | Shows the current memory usage within the server globally broken down by allocation type. 422 | 423 | Example of all the memory allocated by sql instruments: 424 | 425 | ```mysql 426 | mysql> select * from memory_global_by_current_bytes where event_name like 'memory/sql%'; 427 | +---------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ 428 | | event_name | current_count | current_alloc | current_avg_alloc | high_count | high_alloc | high_avg_alloc | 429 | +---------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ 430 | | memory/sql/sp_head::main_mem_root | 73 | 805.47 KiB | 11.03 KiB | 83 | 885.31 KiB | 10.67 KiB | 431 | | memory/sql/TABLE_SHARE::mem_root | 312 | 581.69 KiB | 1.86 KiB | 315 | 584.89 KiB | 1.86 KiB | 432 | | memory/sql/TABLE | 221 | 294.98 KiB | 1.33 KiB | 231 | 604.67 KiB | 2.62 KiB | 433 | | memory/sql/Filesort_buffer::sort_keys | 1 | 255.90 KiB | 255.90 KiB | 1 | 255.90 KiB | 255.90 KiB | 434 | | memory/sql/String::value | 16 | 64.11 KiB | 4.01 KiB | 30 | 130.88 KiB | 4.36 KiB | 435 | | memory/sql/thd::main_mem_root | 6 | 63.75 KiB | 10.62 KiB | 74 | 4.64 MiB | 64.24 KiB | 436 | | memory/sql/THD::sp_cache | 1 | 7.98 KiB | 7.98 KiB | 1 | 7.98 KiB | 7.98 KiB | 437 | | memory/sql/THD::variables | 4 | 512 bytes | 128 bytes | 4 | 512 bytes | 128 bytes | 438 | | memory/sql/TABLE::sort_io_cache | 1 | 280 bytes | 280 bytes | 1 | 280 bytes | 280 bytes | 439 | | memory/sql/acl_cache | 4 | 209 bytes | 52 bytes | 4 | 209 bytes | 52 bytes | 440 | | memory/sql/MYSQL_LOCK | 5 | 176 bytes | 35 bytes | 5 | 200 bytes | 40 bytes | 441 | | memory/sql/dboptions_hash | 1 | 48 bytes | 48 bytes | 1 | 48 bytes | 48 bytes | 442 | | memory/sql/THD::db | 5 | 36 bytes | 7 bytes | 5 | 36 bytes | 7 bytes | 443 | +---------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ 444 | 13 rows in set (0.00 sec) 445 | ``` 446 | 447 | And for InnoDB: 448 | 449 | ```mysql 450 | mysql> select * from memory_global_by_current_bytes where event_name like 'memory/innodb%'; 451 | +-------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ 452 | | event_name | current_count | current_alloc | current_avg_alloc | high_count | high_alloc | high_avg_alloc | 453 | +-------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ 454 | | memory/innodb/mem0mem | 56 | 82.06 KiB | 1.47 KiB | 148 | 348.85 KiB | 2.36 KiB | 455 | | memory/innodb/trx0undo | 202 | 69.44 KiB | 352 bytes | 202 | 69.44 KiB | 352 bytes | 456 | | memory/innodb/ha_innodb | 14 | 5.06 KiB | 370 bytes | 15 | 5.96 KiB | 407 bytes | 457 | | memory/innodb/os0event | 14 | 1.86 KiB | 136 bytes | 27 | 3.59 KiB | 136 bytes | 458 | | memory/innodb/fil0fil | 2 | 632 bytes | 316 bytes | 10 | 4.06 MiB | 416.09 KiB | 459 | | memory/innodb/dict0dict | 3 | 384 bytes | 128 bytes | 7 | 1.08 KiB | 157 bytes | 460 | | memory/innodb/std | 6 | 296 bytes | 49 bytes | 22 | 385.73 KiB | 17.53 KiB | 461 | | memory/innodb/read0read | 1 | 280 bytes | 280 bytes | 1 | 280 bytes | 280 bytes | 462 | | memory/innodb/trx_sys_t::rw_trx_ids | 1 | 88 bytes | 88 bytes | 2 | 144 bytes | 72 bytes | 463 | +-------------------------------------+---------------+---------------+-------------------+------------+------------+----------------+ 464 | 9 rows in set (0.01 sec) 465 | ``` 466 | 467 | This view is based on the table **performance_schema.memory_summary_global_by_event_name** 468 | 469 | https://dev.mysql.com/doc/refman/5.7/en/sys-memory-global-by-current-bytes.html 470 | 471 | #### memory_global_total 472 | 473 | Shows the total memory usage within the server globally. And by globally, it means by "event instrumented" 474 | 475 | ``` 476 | mysql> select * from memory_global_total; 477 | +-----------------+ 478 | | total_allocated | 479 | +-----------------+ 480 | | 96.91 MiB | 481 | +-----------------+ 482 | 1 row in set (0.01 sec) 483 | ``` 484 | 485 | Based on the **performance_schema.memory_summary_global_by_event_name** table. 486 | 487 | https://dev.mysql.com/doc/refman/5.7/en/sys-memory-global-total.html 488 | 489 | ## More info 490 | 491 | - http://mysqlserverteam.com/new-in-mysql-5-7-performance-schema-scalable-memory-allocation/ 492 | - https://dev.mysql.com/doc/refman/5.7/en/performance-schema-memory-model.html 493 | - https://dev.mysql.com/doc/refman/5.7/en/memory-summary-tables.html 494 | - https://dev.mysql.com/doc/refman/5.7/en/show-engine.html 495 | - https://dev.mysql.com/doc/refman/5.7/en/performance-schema-startup-configuration.html 496 | 497 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # MySQL Tools 2 | 3 | Collection of scripts that enhance another MySQL tools :) 4 | 5 | ## Load Data 6 | The load_data.sh is a bash code script that allows you to: 7 | 8 | * Load data in **Parallel** by a number of user-defined threads 9 | * Protect against **Performance** degradation. The script checks on each iteration for the status variable *Threads_running* and the current *Checkpoint age* in order to keep thing under a defined threshold. 10 | * Load data in small transactions. 11 | 12 | ### Requirements: 13 | * This script acts as a wrapper around the [pt-fifo-split](http://www.percona.com/doc/percona-toolkit/2.2/pt-fifo-split.html "pt-fifo-split") tool from the Percona Toolkit. You will need to have this tool in your server. 14 | * The "split" tool from linux [Coreutils](http://www.gnu.org/software/coreutils/ "Coreutils"), version 8.8 or greater is needed. You can use the one that i have in this repo: 15 | [split](https://github.com/nethalo/mysql-tools/blob/master/split "Split") 16 | Or compile one yourself. The reason for this is that the script uses the **--number** parameter 17 | 18 | ### Settings 19 | 20 | This values can be modified to suit better your needs. 21 | 22 | * **readonly max_running_threads=10** After this value, the script will pause the data load and will resume after the value of Threads_running is lower than the one defined. You will need to check it by running in your mysql: `SHOW STATUS LIKE 'Threads_running';` in order to find out a good value for your server 23 | * **readonly checkpoint_threshold_pct=70** The script will run only if the checkpoint age (Amount of transactions still in InnoDB Log File but not on the tablespace) is below 70% of total available size 24 | * **readonly fifoLines=1000** The number of lines that pt-fifo-split will use per read. 25 | * **readonly CHUNKS=8** The number of **Parallel** running threads. This shouldn't be more than the available CPU cores. 26 | 27 | Also: 28 | 29 | * **user=root** The MySQL user that the script will use to connect to the database. 30 | The script relies that the password is defined in a .my.cnf file under the home directory of the linux user. 31 | Example, if the user is root: 32 | 33 | ``` 34 | File name: /root/.my.cnf 35 | File permission: chown 644 /root/.my.cnf 36 | File contents: 37 | [client] 38 | user=root 39 | password=p@$$w0rd 40 | ``` 41 | * **database=sakila** The database name where the destination table exists. 42 | 43 | ### Run 44 | To run the script you only need to execute this line: 45 | 46 | ``` 47 | ./load_data.sh "/path/to/the/file" 48 | ``` 49 | 50 | Right now, the script can only load non-extended INSERT files, which means, files with this kind of inserts: 51 | ``` 52 | INSERT INTO `actor` VALUES (1,'PENELOPE','GUINESS','2006-02-15 02:34:33'); 53 | INSERT INTO `actor` VALUES (2,'NICK','WAHLBERG','2006-02-15 02:34:33'); 54 | INSERT INTO `actor` VALUES (3,'ED','CHASE','2006-02-15 02:34:33'); 55 | INSERT INTO `actor` VALUES (4,'JENNIFER','DAVIS','2006-02-15 02:34:33'); 56 | ``` 57 | 58 | Coming soon, "LOAD DATA" types 59 | -------------------------------------------------------------------------------- /Statistic Analysis-1551728872954.json: -------------------------------------------------------------------------------- 1 | { 2 | "__inputs": [ 3 | { 4 | "name": "DS_PROMETHEUS", 5 | "label": "Prometheus", 6 | "description": "", 7 | "type": "datasource", 8 | "pluginId": "prometheus", 9 | "pluginName": "Prometheus" 10 | } 11 | ], 12 | "__requires": [ 13 | { 14 | "type": "grafana", 15 | "id": "grafana", 16 | "name": "Grafana", 17 | "version": "5.1.3" 18 | }, 19 | { 20 | "type": "panel", 21 | "id": "graph", 22 | "name": "Graph", 23 | "version": "5.0.0" 24 | }, 25 | { 26 | "type": "datasource", 27 | "id": "prometheus", 28 | "name": "Prometheus", 29 | "version": "5.0.0" 30 | }, 31 | { 32 | "type": "panel", 33 | "id": "singlestat", 34 | "name": "Singlestat", 35 | "version": "5.0.0" 36 | } 37 | ], 38 | "annotations": { 39 | "list": [ 40 | { 41 | "builtIn": 1, 42 | "datasource": "-- Grafana --", 43 | "enable": true, 44 | "hide": false, 45 | "iconColor": "#e0752d", 46 | "limit": 100, 47 | "name": "PMM Annotations", 48 | "showIn": 0, 49 | "tags": [ 50 | "pmm_annotation" 51 | ], 52 | "type": "tags" 53 | } 54 | ] 55 | }, 56 | "editable": true, 57 | "gnetId": null, 58 | "graphTooltip": 1, 59 | "id": null, 60 | "iteration": 1551709446897, 61 | "links": [ 62 | { 63 | "icon": "dashboard", 64 | "includeVars": true, 65 | "keepTime": true, 66 | "tags": [ 67 | "QAN" 68 | ], 69 | "targetBlank": false, 70 | "title": "Query Analytics", 71 | "type": "link", 72 | "url": "/graph/dashboard/db/_pmm-query-analytics" 73 | }, 74 | { 75 | "asDropdown": true, 76 | "includeVars": true, 77 | "keepTime": true, 78 | "tags": [ 79 | "OS" 80 | ], 81 | "targetBlank": false, 82 | "title": "OS", 83 | "type": "dashboards" 84 | }, 85 | { 86 | "asDropdown": true, 87 | "includeVars": true, 88 | "keepTime": true, 89 | "tags": [ 90 | "MySQL" 91 | ], 92 | "targetBlank": false, 93 | "title": "MySQL", 94 | "type": "dashboards" 95 | }, 96 | { 97 | "asDropdown": true, 98 | "includeVars": true, 99 | "keepTime": true, 100 | "tags": [ 101 | "MongoDB" 102 | ], 103 | "targetBlank": false, 104 | "title": "MongoDB", 105 | "type": "dashboards" 106 | }, 107 | { 108 | "asDropdown": true, 109 | "includeVars": true, 110 | "keepTime": true, 111 | "tags": [ 112 | "HA" 113 | ], 114 | "targetBlank": false, 115 | "title": "HA", 116 | "type": "dashboards" 117 | }, 118 | { 119 | "asDropdown": true, 120 | "includeVars": true, 121 | "keepTime": true, 122 | "tags": [ 123 | "Cloud" 124 | ], 125 | "targetBlank": false, 126 | "title": "Cloud", 127 | "type": "dashboards" 128 | }, 129 | { 130 | "asDropdown": true, 131 | "includeVars": true, 132 | "keepTime": true, 133 | "tags": [ 134 | "Insight" 135 | ], 136 | "targetBlank": false, 137 | "title": "Insight", 138 | "type": "dashboards" 139 | }, 140 | { 141 | "asDropdown": true, 142 | "includeVars": true, 143 | "keepTime": true, 144 | "tags": [ 145 | "PMM" 146 | ], 147 | "targetBlank": false, 148 | "title": "PMM", 149 | "type": "dashboards" 150 | } 151 | ], 152 | "panels": [ 153 | { 154 | "cacheTimeout": null, 155 | "colorBackground": false, 156 | "colorValue": true, 157 | "colors": [ 158 | "rgba(245, 54, 54, 0.9)", 159 | "rgba(237, 129, 40, 0.89)", 160 | "rgba(50, 172, 45, 0.97)" 161 | ], 162 | "datasource": "${DS_PROMETHEUS}", 163 | "decimals": 1, 164 | "editable": true, 165 | "error": false, 166 | "format": "s", 167 | "gauge": { 168 | "maxValue": 100, 169 | "minValue": 0, 170 | "show": false, 171 | "thresholdLabels": false, 172 | "thresholdMarkers": true 173 | }, 174 | "gridPos": { 175 | "h": 4, 176 | "w": 6, 177 | "x": 0, 178 | "y": 0 179 | }, 180 | "height": "125px", 181 | "id": 19, 182 | "interval": "$interval", 183 | "links": [], 184 | "mappingType": 1, 185 | "mappingTypes": [ 186 | { 187 | "name": "value to text", 188 | "value": 1 189 | }, 190 | { 191 | "name": "range to text", 192 | "value": 2 193 | } 194 | ], 195 | "maxDataPoints": 100, 196 | "nullPointMode": "connected", 197 | "nullText": null, 198 | "postfix": "s", 199 | "postfixFontSize": "80%", 200 | "prefix": "", 201 | "prefixFontSize": "80%", 202 | "rangeMaps": [ 203 | { 204 | "from": "null", 205 | "text": "N/A", 206 | "to": "null" 207 | } 208 | ], 209 | "sparkline": { 210 | "fillColor": "rgba(31, 118, 189, 0.18)", 211 | "full": false, 212 | "lineColor": "rgb(31, 120, 193)", 213 | "show": false 214 | }, 215 | "tableColumn": "", 216 | "targets": [ 217 | { 218 | "calculatedInterval": "10m", 219 | "datasourceErrors": {}, 220 | "errors": {}, 221 | "expr": "(node_time{instance=\"$host\"} - node_boot_time{instance=\"$host\"}) or (time() - node_boot_time{instance=\"$host\"})", 222 | "format": "time_series", 223 | "hide": false, 224 | "interval": "5m", 225 | "intervalFactor": 1, 226 | "legendFormat": "", 227 | "metric": "", 228 | "refId": "A", 229 | "step": 300 230 | } 231 | ], 232 | "thresholds": "300,3600", 233 | "title": "System Uptime", 234 | "transparent": false, 235 | "type": "singlestat", 236 | "valueFontSize": "80%", 237 | "valueMaps": [], 238 | "valueName": "current" 239 | }, 240 | { 241 | "cacheTimeout": null, 242 | "colorBackground": false, 243 | "colorValue": false, 244 | "colors": [ 245 | "rgba(245, 54, 54, 0.9)", 246 | "rgba(237, 129, 40, 0.89)", 247 | "rgba(50, 172, 45, 0.97)" 248 | ], 249 | "datasource": "${DS_PROMETHEUS}", 250 | "editable": true, 251 | "error": false, 252 | "format": "none", 253 | "gauge": { 254 | "maxValue": 100, 255 | "minValue": 0, 256 | "show": false, 257 | "thresholdLabels": false, 258 | "thresholdMarkers": true 259 | }, 260 | "gridPos": { 261 | "h": 4, 262 | "w": 6, 263 | "x": 6, 264 | "y": 0 265 | }, 266 | "height": "125px", 267 | "id": 25, 268 | "interval": "$interval", 269 | "links": [], 270 | "mappingType": 1, 271 | "mappingTypes": [ 272 | { 273 | "name": "value to text", 274 | "value": 1 275 | }, 276 | { 277 | "name": "range to text", 278 | "value": 2 279 | } 280 | ], 281 | "maxDataPoints": 100, 282 | "nullPointMode": "connected", 283 | "nullText": null, 284 | "postfix": "", 285 | "postfixFontSize": "50%", 286 | "prefix": "", 287 | "prefixFontSize": "80%", 288 | "rangeMaps": [ 289 | { 290 | "from": "null", 291 | "text": "N/A", 292 | "to": "null" 293 | } 294 | ], 295 | "sparkline": { 296 | "fillColor": "rgba(31, 118, 189, 0.18)", 297 | "full": false, 298 | "lineColor": "rgb(31, 120, 193)", 299 | "show": false 300 | }, 301 | "tableColumn": "", 302 | "targets": [ 303 | { 304 | "expr": "count(node_cpu{mode=\"user\", instance=\"$host\"}) or count(rdsosmetrics_General_numVCPUs)", 305 | "format": "time_series", 306 | "interval": "5m", 307 | "intervalFactor": 1, 308 | "refId": "A", 309 | "step": 300 310 | } 311 | ], 312 | "thresholds": "", 313 | "title": "Virtual CPUs", 314 | "type": "singlestat", 315 | "valueFontSize": "80%", 316 | "valueMaps": [ 317 | { 318 | "op": "=", 319 | "text": "N/A", 320 | "value": "null" 321 | } 322 | ], 323 | "valueName": "current" 324 | }, 325 | { 326 | "cacheTimeout": null, 327 | "colorBackground": false, 328 | "colorValue": false, 329 | "colors": [ 330 | "rgba(245, 54, 54, 0.9)", 331 | "rgba(237, 129, 40, 0.89)", 332 | "rgba(50, 172, 45, 0.97)" 333 | ], 334 | "datasource": "${DS_PROMETHEUS}", 335 | "decimals": 2, 336 | "editable": true, 337 | "error": false, 338 | "format": "bytes", 339 | "gauge": { 340 | "maxValue": 100, 341 | "minValue": 0, 342 | "show": false, 343 | "thresholdLabels": false, 344 | "thresholdMarkers": true 345 | }, 346 | "gridPos": { 347 | "h": 4, 348 | "w": 6, 349 | "x": 12, 350 | "y": 0 351 | }, 352 | "height": "125px", 353 | "id": 26, 354 | "interval": "$interval", 355 | "links": [], 356 | "mappingType": 1, 357 | "mappingTypes": [ 358 | { 359 | "name": "value to text", 360 | "value": 1 361 | }, 362 | { 363 | "name": "range to text", 364 | "value": 2 365 | } 366 | ], 367 | "maxDataPoints": 100, 368 | "nullPointMode": "connected", 369 | "nullText": null, 370 | "postfix": "", 371 | "postfixFontSize": "50%", 372 | "prefix": "", 373 | "prefixFontSize": "80%", 374 | "rangeMaps": [ 375 | { 376 | "from": "null", 377 | "text": "N/A", 378 | "to": "null" 379 | } 380 | ], 381 | "sparkline": { 382 | "fillColor": "rgba(31, 118, 189, 0.18)", 383 | "full": false, 384 | "lineColor": "rgb(31, 120, 193)", 385 | "show": false 386 | }, 387 | "tableColumn": "", 388 | "targets": [ 389 | { 390 | "expr": "node_memory_MemTotal{instance=\"$host\"}", 391 | "interval": "5m", 392 | "intervalFactor": 1, 393 | "refId": "A", 394 | "step": 300 395 | } 396 | ], 397 | "thresholds": "", 398 | "title": "RAM", 399 | "type": "singlestat", 400 | "valueFontSize": "80%", 401 | "valueMaps": [ 402 | { 403 | "op": "=", 404 | "text": "N/A", 405 | "value": "null" 406 | } 407 | ], 408 | "valueName": "current" 409 | }, 410 | { 411 | "cacheTimeout": null, 412 | "colorBackground": false, 413 | "colorValue": true, 414 | "colors": [ 415 | "rgba(50, 172, 45, 0.97)", 416 | "rgba(237, 129, 40, 0.89)", 417 | "rgba(245, 54, 54, 0.9)" 418 | ], 419 | "datasource": "${DS_PROMETHEUS}", 420 | "decimals": 0, 421 | "editable": true, 422 | "error": false, 423 | "format": "percent", 424 | "gauge": { 425 | "maxValue": 100, 426 | "minValue": 0, 427 | "show": false, 428 | "thresholdLabels": false, 429 | "thresholdMarkers": true 430 | }, 431 | "gridPos": { 432 | "h": 4, 433 | "w": 6, 434 | "x": 18, 435 | "y": 0 436 | }, 437 | "height": "125px", 438 | "id": 9, 439 | "interval": "$interval", 440 | "links": [], 441 | "mappingType": 1, 442 | "mappingTypes": [ 443 | { 444 | "name": "value to text", 445 | "value": 1 446 | }, 447 | { 448 | "name": "range to text", 449 | "value": 2 450 | } 451 | ], 452 | "maxDataPoints": 100, 453 | "nullPointMode": "connected", 454 | "nullText": null, 455 | "postfix": "", 456 | "postfixFontSize": "50%", 457 | "prefix": "", 458 | "prefixFontSize": "80%", 459 | "rangeMaps": [ 460 | { 461 | "from": "null", 462 | "text": "N/A", 463 | "to": "null" 464 | } 465 | ], 466 | "sparkline": { 467 | "fillColor": "rgba(31, 118, 189, 0.18)", 468 | "full": true, 469 | "lineColor": "rgb(31, 120, 193)", 470 | "show": true 471 | }, 472 | "tableColumn": "", 473 | "targets": [ 474 | { 475 | "calculatedInterval": "10m", 476 | "datasourceErrors": {}, 477 | "errors": {}, 478 | "expr": "(node_memory_MemAvailable{instance=\"$host\"} or (node_memory_MemFree{instance=\"$host\"} + node_memory_Buffers{instance=\"$host\"} + node_memory_Cached{instance=\"$host\"})) / node_memory_MemTotal{instance=\"$host\"} * 100", 479 | "interval": "5m", 480 | "intervalFactor": 1, 481 | "legendFormat": "", 482 | "metric": "node_mem", 483 | "refId": "A", 484 | "step": 300 485 | } 486 | ], 487 | "thresholds": "90,95", 488 | "title": "Memory Available", 489 | "transparent": false, 490 | "type": "singlestat", 491 | "valueFontSize": "80%", 492 | "valueMaps": [], 493 | "valueName": "current" 494 | }, 495 | { 496 | "aliasColors": { 497 | "Avg Row Lock Wait Time": "#BF1B00" 498 | }, 499 | "bars": false, 500 | "dashLength": 10, 501 | "dashes": false, 502 | "datasource": "${DS_PROMETHEUS}", 503 | "decimals": 2, 504 | "description": "**InnoDB Row Lock Time**\n\nWhen data is locked, then that means that another ***session can NOT update that data until the lock*** is released (which unlocks the data and allows other users to update that data). Locks are usually released by either a ROLLBACK or COMMIT SQL statement.\n\nInnoDB implements standard row-level locking where there are two types of locks, [shared (S) locks](https://dev.mysql.com/doc/refman/5.7/en/glossary.html#glos_shared_lock) and [exclusive (X) locks](https://dev.mysql.com/doc/refman/5.7/en/glossary.html#glos_exclusive_lock).\n\n* A [shared (S) lock](https://dev.mysql.com/doc/refman/5.7/en/glossary.html#glos_shared_lock) permits the transaction that holds the lock to read a row.\n* An [exclusive (X) lock](https://dev.mysql.com/doc/refman/5.7/en/glossary.html#glos_exclusive_lock) permits the transaction that holds the lock to update or delete a row.\n\n_Average Row Lock Wait Time_ is the row lock wait time divided by the number of row locks.\\\n_Row Lock Waits_ are how many times a transaction waited on a row lock per second.\\\n_Row Lock Wait Load_ is a rolling 5 minute average of Row Lock Waits.", 505 | "editable": true, 506 | "error": false, 507 | "fill": 1, 508 | "grid": { 509 | "leftLogBase": 1, 510 | "leftMax": null, 511 | "leftMin": 0, 512 | "rightLogBase": 1, 513 | "rightMax": null, 514 | "rightMin": 0 515 | }, 516 | "gridPos": { 517 | "h": 12, 518 | "w": 24, 519 | "x": 0, 520 | "y": 4 521 | }, 522 | "id": 18, 523 | "legend": { 524 | "alignAsTable": true, 525 | "avg": true, 526 | "current": false, 527 | "max": true, 528 | "min": true, 529 | "rightSide": false, 530 | "show": true, 531 | "sort": "avg", 532 | "sortDesc": true, 533 | "total": false, 534 | "values": true 535 | }, 536 | "lines": false, 537 | "linewidth": 2, 538 | "links": [ 539 | { 540 | "dashboard": "https://dev.mysql.com/doc/refman/5.7/en/innodb-locking.html", 541 | "targetBlank": true, 542 | "title": "InnoDB Locking", 543 | "type": "absolute", 544 | "url": "https://dev.mysql.com/doc/refman/5.7/en/innodb-locking.html" 545 | } 546 | ], 547 | "nullPointMode": "null", 548 | "percentage": false, 549 | "pointradius": 1, 550 | "points": true, 551 | "renderer": "flot", 552 | "seriesOverrides": [ 553 | { 554 | "alias": "Avg Row Lock Wait Time", 555 | "yaxis": 2 556 | } 557 | ], 558 | "spaceLength": 10, 559 | "stack": false, 560 | "steppedLine": true, 561 | "targets": [ 562 | { 563 | "calculatedInterval": "2m", 564 | "datasourceErrors": {}, 565 | "errors": {}, 566 | "expr": "rate(mysql_global_status_innodb_row_lock_waits{instance=\"$host\"}[$interval]) or irate(mysql_global_status_innodb_row_lock_waits{instance=\"$host\"}[5m])", 567 | "format": "time_series", 568 | "interval": "$interval", 569 | "intervalFactor": 1, 570 | "legendFormat": "Row Lock Waits", 571 | "metric": "", 572 | "refId": "B", 573 | "step": 300 574 | }, 575 | { 576 | "expr": "rate(mysql_global_status_innodb_row_lock_time{instance=\"$host\"}[$interval])/1000 or irate(mysql_global_status_innodb_row_lock_time{instance=\"$host\"}[5m])/1000", 577 | "format": "time_series", 578 | "interval": "$interval", 579 | "intervalFactor": 1, 580 | "legendFormat": "Row Lock Wait Load", 581 | "metric": "", 582 | "refId": "A", 583 | "step": 300 584 | }, 585 | { 586 | "expr": "rate(mysql_global_status_innodb_row_lock_time{instance=\"$host\"}[$interval])/rate(mysql_global_status_innodb_row_lock_waits{instance=\"$host\"}[$interval]) or irate(mysql_global_status_innodb_row_lock_time{instance=\"$host\"}[5m])/irate(mysql_global_status_innodb_row_lock_waits{instance=\"$host\"}[5m])", 587 | "format": "time_series", 588 | "interval": "$interval", 589 | "intervalFactor": 1, 590 | "legendFormat": "Avg Row Lock Wait Time", 591 | "refId": "C", 592 | "step": 300 593 | } 594 | ], 595 | "thresholds": [], 596 | "timeFrom": null, 597 | "timeShift": null, 598 | "title": "InnoDB Row Lock Time", 599 | "tooltip": { 600 | "msResolution": false, 601 | "shared": true, 602 | "sort": 0, 603 | "value_type": "individual" 604 | }, 605 | "type": "graph", 606 | "x-axis": true, 607 | "xaxis": { 608 | "buckets": null, 609 | "mode": "time", 610 | "name": null, 611 | "show": true, 612 | "values": [] 613 | }, 614 | "y-axis": true, 615 | "y_formats": [ 616 | "short", 617 | "ms" 618 | ], 619 | "yaxes": [ 620 | { 621 | "format": "short", 622 | "label": null, 623 | "logBase": 1, 624 | "max": null, 625 | "min": 0, 626 | "show": true 627 | }, 628 | { 629 | "format": "ms", 630 | "label": null, 631 | "logBase": 1, 632 | "max": null, 633 | "min": 0, 634 | "show": true 635 | } 636 | ], 637 | "yaxis": { 638 | "align": false, 639 | "alignLevel": null 640 | } 641 | }, 642 | { 643 | "aliasColors": {}, 644 | "bars": false, 645 | "dashLength": 10, 646 | "dashes": false, 647 | "datasource": "${DS_PROMETHEUS}", 648 | "decimals": 2, 649 | "description": "**MySQL Handlers**\n\nHandler statistics are internal statistics on how MySQL is selecting, updating, inserting, and modifying rows, tables, and indexes.\n\nThis is in fact the layer between the Storage Engine and MySQL.\n\n* `read_rnd_next` is incremented when the server performs a full table scan and this is a counter you don't really want to see with a high value.\n* `read_key` is incremented when a read is done with an index.\n* `read_next` is incremented when the storage engine is asked to 'read the next index entry'. A high value means a lot of index scans are being done.", 650 | "editable": true, 651 | "error": false, 652 | "fill": 2, 653 | "grid": {}, 654 | "gridPos": { 655 | "h": 11, 656 | "w": 24, 657 | "x": 0, 658 | "y": 16 659 | }, 660 | "id": 6, 661 | "legend": { 662 | "alignAsTable": true, 663 | "avg": true, 664 | "current": false, 665 | "hideZero": true, 666 | "max": true, 667 | "min": true, 668 | "rightSide": true, 669 | "show": true, 670 | "sort": "avg", 671 | "sortDesc": true, 672 | "total": false, 673 | "values": true 674 | }, 675 | "lines": true, 676 | "linewidth": 2, 677 | "links": [], 678 | "nullPointMode": "null", 679 | "percentage": false, 680 | "pointradius": 5, 681 | "points": false, 682 | "renderer": "flot", 683 | "seriesOverrides": [], 684 | "spaceLength": 10, 685 | "stack": false, 686 | "steppedLine": false, 687 | "targets": [ 688 | { 689 | "calculatedInterval": "2m", 690 | "datasourceErrors": {}, 691 | "errors": {}, 692 | "expr": "rate(mysql_global_status_handlers_total{instance=\"$host\", handler!~\"commit|rollback|savepoint.*|prepare\"}[$interval]) or irate(mysql_global_status_handlers_total{instance=\"$host\", handler!~\"commit|rollback|savepoint.*|prepare\"}[5m])", 693 | "format": "time_series", 694 | "interval": "$interval", 695 | "intervalFactor": 1, 696 | "legendFormat": "{{ handler }}", 697 | "metric": "", 698 | "refId": "J", 699 | "step": 20 700 | } 701 | ], 702 | "thresholds": [], 703 | "timeFrom": null, 704 | "timeShift": null, 705 | "title": "MySQL Handlers", 706 | "tooltip": { 707 | "msResolution": false, 708 | "shared": true, 709 | "sort": 0, 710 | "value_type": "individual" 711 | }, 712 | "type": "graph", 713 | "xaxis": { 714 | "buckets": null, 715 | "mode": "time", 716 | "name": null, 717 | "show": true, 718 | "values": [] 719 | }, 720 | "yaxes": [ 721 | { 722 | "format": "short", 723 | "logBase": 1, 724 | "max": null, 725 | "min": 0, 726 | "show": true 727 | }, 728 | { 729 | "format": "short", 730 | "logBase": 1, 731 | "max": null, 732 | "min": 0, 733 | "show": true 734 | } 735 | ], 736 | "yaxis": { 737 | "align": false, 738 | "alignLevel": null 739 | } 740 | }, 741 | { 742 | "aliasColors": {}, 743 | "bars": false, 744 | "dashLength": 10, 745 | "dashes": false, 746 | "datasource": "${DS_PROMETHEUS}", 747 | "decimals": 2, 748 | "description": "**MySQL Sorts**\n\nDue to a query's structure, order, or other requirements, MySQL sorts the rows before returning them. For example, if a table is ordered 1 to 10 but you want the results reversed, MySQL then has to sort the rows to return 10 to 1.\n\nThis graph also shows when sorts had to scan a whole table or a given range of a table in order to return the results and which could not have been sorted via an index.", 749 | "editable": true, 750 | "error": false, 751 | "fill": 2, 752 | "grid": {}, 753 | "gridPos": { 754 | "h": 15, 755 | "w": 24, 756 | "x": 0, 757 | "y": 27 758 | }, 759 | "id": 29, 760 | "legend": { 761 | "alignAsTable": true, 762 | "avg": true, 763 | "current": false, 764 | "hideZero": true, 765 | "max": true, 766 | "min": true, 767 | "rightSide": false, 768 | "show": true, 769 | "sort": "avg", 770 | "sortDesc": true, 771 | "total": false, 772 | "values": true 773 | }, 774 | "lines": true, 775 | "linewidth": 2, 776 | "links": [], 777 | "nullPointMode": "null", 778 | "percentage": false, 779 | "pointradius": 5, 780 | "points": false, 781 | "renderer": "flot", 782 | "seriesOverrides": [], 783 | "spaceLength": 10, 784 | "stack": false, 785 | "steppedLine": false, 786 | "targets": [ 787 | { 788 | "calculatedInterval": "2m", 789 | "datasourceErrors": {}, 790 | "errors": {}, 791 | "expr": "rate(mysql_global_status_sort_rows{instance=\"$host\"}[$interval]) or irate(mysql_global_status_sort_rows{instance=\"$host\"}[5m])", 792 | "format": "time_series", 793 | "interval": "$interval", 794 | "intervalFactor": 1, 795 | "legendFormat": "Sort Rows", 796 | "metric": "", 797 | "refId": "A", 798 | "step": 20 799 | }, 800 | { 801 | "calculatedInterval": "2m", 802 | "datasourceErrors": {}, 803 | "errors": {}, 804 | "expr": "rate(mysql_global_status_sort_range{instance=\"$host\"}[$interval]) or irate(mysql_global_status_sort_range{instance=\"$host\"}[5m])", 805 | "format": "time_series", 806 | "interval": "$interval", 807 | "intervalFactor": 1, 808 | "legendFormat": "Sort Range", 809 | "metric": "", 810 | "refId": "B", 811 | "step": 20 812 | }, 813 | { 814 | "calculatedInterval": "2m", 815 | "datasourceErrors": {}, 816 | "errors": {}, 817 | "expr": "rate(mysql_global_status_sort_merge_passes{instance=\"$host\"}[$interval]) or irate(mysql_global_status_sort_merge_passes{instance=\"$host\"}[5m])", 818 | "format": "time_series", 819 | "interval": "$interval", 820 | "intervalFactor": 1, 821 | "legendFormat": "Sort Merge Passes", 822 | "metric": "", 823 | "refId": "C", 824 | "step": 20 825 | }, 826 | { 827 | "calculatedInterval": "2m", 828 | "datasourceErrors": {}, 829 | "errors": {}, 830 | "expr": "rate(mysql_global_status_sort_scan{instance=\"$host\"}[$interval]) or irate(mysql_global_status_sort_scan{instance=\"$host\"}[5m])", 831 | "format": "time_series", 832 | "interval": "$interval", 833 | "intervalFactor": 1, 834 | "legendFormat": "Sort Scan", 835 | "metric": "", 836 | "refId": "D", 837 | "step": 20 838 | } 839 | ], 840 | "thresholds": [], 841 | "timeFrom": null, 842 | "timeShift": null, 843 | "title": "MySQL Sorts", 844 | "tooltip": { 845 | "msResolution": false, 846 | "shared": true, 847 | "sort": 0, 848 | "value_type": "individual" 849 | }, 850 | "type": "graph", 851 | "xaxis": { 852 | "buckets": null, 853 | "mode": "time", 854 | "name": null, 855 | "show": true, 856 | "values": [] 857 | }, 858 | "yaxes": [ 859 | { 860 | "format": "short", 861 | "logBase": 1, 862 | "max": null, 863 | "min": 0, 864 | "show": true 865 | }, 866 | { 867 | "format": "short", 868 | "logBase": 1, 869 | "max": null, 870 | "min": 0, 871 | "show": true 872 | } 873 | ], 874 | "yaxis": { 875 | "align": false, 876 | "alignLevel": null 877 | } 878 | }, 879 | { 880 | "aliasColors": {}, 881 | "bars": false, 882 | "dashLength": 10, 883 | "dashes": false, 884 | "datasource": "${DS_PROMETHEUS}", 885 | "decimals": 2, 886 | "editable": true, 887 | "error": false, 888 | "fill": 2, 889 | "grid": {}, 890 | "gridPos": { 891 | "h": 12, 892 | "w": 24, 893 | "x": 0, 894 | "y": 42 895 | }, 896 | "id": 2, 897 | "legend": { 898 | "alignAsTable": true, 899 | "avg": true, 900 | "current": false, 901 | "max": true, 902 | "min": true, 903 | "rightSide": false, 904 | "show": true, 905 | "sort": "avg", 906 | "sortDesc": true, 907 | "total": false, 908 | "values": true 909 | }, 910 | "lines": true, 911 | "linewidth": 2, 912 | "links": [], 913 | "nullPointMode": "null", 914 | "percentage": false, 915 | "pointradius": 5, 916 | "points": false, 917 | "renderer": "flot", 918 | "seriesOverrides": [], 919 | "spaceLength": 10, 920 | "stack": false, 921 | "steppedLine": false, 922 | "targets": [ 923 | { 924 | "calculatedInterval": "2m", 925 | "datasourceErrors": {}, 926 | "errors": {}, 927 | "expr": "rate(mysql_global_status_created_tmp_tables{instance=\"$host\"}[$interval]) or irate(mysql_global_status_created_tmp_tables{instance=\"$host\"}[5m])", 928 | "interval": "$interval", 929 | "intervalFactor": 1, 930 | "legendFormat": "Created Tmp Tables", 931 | "metric": "", 932 | "refId": "A", 933 | "step": 20 934 | }, 935 | { 936 | "calculatedInterval": "2m", 937 | "datasourceErrors": {}, 938 | "errors": {}, 939 | "expr": "rate(mysql_global_status_created_tmp_disk_tables{instance=\"$host\"}[$interval]) or irate(mysql_global_status_created_tmp_disk_tables{instance=\"$host\"}[5m])", 940 | "interval": "$interval", 941 | "intervalFactor": 1, 942 | "legendFormat": "Created Tmp Disk Tables", 943 | "metric": "", 944 | "refId": "B", 945 | "step": 20 946 | }, 947 | { 948 | "calculatedInterval": "2m", 949 | "datasourceErrors": {}, 950 | "errors": {}, 951 | "expr": "rate(mysql_global_status_created_tmp_files{instance=\"$host\"}[$interval]) or irate(mysql_global_status_created_tmp_files{instance=\"$host\"}[5m])", 952 | "interval": "$interval", 953 | "intervalFactor": 1, 954 | "legendFormat": "Created Tmp Files", 955 | "metric": "", 956 | "refId": "C", 957 | "step": 20 958 | } 959 | ], 960 | "thresholds": [], 961 | "timeFrom": null, 962 | "timeShift": null, 963 | "title": "MySQL Temporary Objects", 964 | "tooltip": { 965 | "msResolution": false, 966 | "shared": true, 967 | "sort": 0, 968 | "value_type": "individual" 969 | }, 970 | "type": "graph", 971 | "xaxis": { 972 | "buckets": null, 973 | "mode": "time", 974 | "name": null, 975 | "show": true, 976 | "values": [] 977 | }, 978 | "yaxes": [ 979 | { 980 | "format": "short", 981 | "logBase": 1, 982 | "max": null, 983 | "min": 0, 984 | "show": true 985 | }, 986 | { 987 | "format": "short", 988 | "logBase": 1, 989 | "max": null, 990 | "min": 0, 991 | "show": true 992 | } 993 | ], 994 | "yaxis": { 995 | "align": false, 996 | "alignLevel": null 997 | } 998 | }, 999 | { 1000 | "aliasColors": {}, 1001 | "bars": false, 1002 | "dashLength": 10, 1003 | "dashes": false, 1004 | "datasource": "${DS_PROMETHEUS}", 1005 | "decimals": 1, 1006 | "editable": true, 1007 | "error": false, 1008 | "fill": 1, 1009 | "grid": { 1010 | "leftLogBase": 1, 1011 | "leftMax": null, 1012 | "leftMin": 0, 1013 | "rightLogBase": 1, 1014 | "rightMax": null, 1015 | "rightMin": 0 1016 | }, 1017 | "gridPos": { 1018 | "h": 9, 1019 | "w": 24, 1020 | "x": 0, 1021 | "y": 54 1022 | }, 1023 | "id": 36, 1024 | "legend": { 1025 | "alignAsTable": true, 1026 | "avg": true, 1027 | "current": false, 1028 | "max": true, 1029 | "min": true, 1030 | "rightSide": false, 1031 | "show": true, 1032 | "sort": "avg", 1033 | "sortDesc": true, 1034 | "total": false, 1035 | "values": true 1036 | }, 1037 | "lines": true, 1038 | "linewidth": 2, 1039 | "links": [], 1040 | "nullPointMode": "null", 1041 | "percentage": false, 1042 | "pointradius": 1, 1043 | "points": false, 1044 | "renderer": "flot", 1045 | "seriesOverrides": [ 1046 | { 1047 | "alias": "InnoDB Log Buffer Size", 1048 | "yaxis": 2 1049 | } 1050 | ], 1051 | "spaceLength": 10, 1052 | "stack": false, 1053 | "steppedLine": false, 1054 | "targets": [ 1055 | { 1056 | "calculatedInterval": "2m", 1057 | "datasourceErrors": {}, 1058 | "errors": {}, 1059 | "expr": "mysql_global_variables_innodb_log_buffer_size{instance=\"$host\"}", 1060 | "format": "time_series", 1061 | "hide": false, 1062 | "instant": false, 1063 | "interval": "$interval", 1064 | "intervalFactor": 1, 1065 | "legendFormat": "InnoDB Log Buffer Size", 1066 | "metric": "", 1067 | "refId": "B", 1068 | "step": 300 1069 | }, 1070 | { 1071 | "expr": "mysql_global_status_innodb_log_waits{instance=\"$host\"}", 1072 | "format": "time_series", 1073 | "instant": false, 1074 | "interval": "$interval", 1075 | "intervalFactor": 1, 1076 | "legendFormat": "InnoDB Log Waits", 1077 | "metric": "", 1078 | "refId": "A", 1079 | "step": 300 1080 | } 1081 | ], 1082 | "thresholds": [], 1083 | "timeFrom": null, 1084 | "timeShift": null, 1085 | "title": "InnoDB Log Buffer", 1086 | "tooltip": { 1087 | "msResolution": false, 1088 | "shared": true, 1089 | "sort": 0, 1090 | "value_type": "individual" 1091 | }, 1092 | "type": "graph", 1093 | "x-axis": true, 1094 | "xaxis": { 1095 | "buckets": null, 1096 | "mode": "time", 1097 | "name": null, 1098 | "show": true, 1099 | "values": [] 1100 | }, 1101 | "y-axis": true, 1102 | "y_formats": [ 1103 | "bytes", 1104 | "short" 1105 | ], 1106 | "yaxes": [ 1107 | { 1108 | "format": "short", 1109 | "label": null, 1110 | "logBase": 1, 1111 | "max": null, 1112 | "min": 0, 1113 | "show": true 1114 | }, 1115 | { 1116 | "decimals": null, 1117 | "format": "decbytes", 1118 | "label": null, 1119 | "logBase": 1, 1120 | "max": null, 1121 | "min": "0", 1122 | "show": true 1123 | } 1124 | ], 1125 | "yaxis": { 1126 | "align": false, 1127 | "alignLevel": null 1128 | } 1129 | }, 1130 | { 1131 | "aliasColors": { 1132 | "Max Checkpoint Age": "#BF1B00", 1133 | "Uncheckpointed Bytes": "#E0752D" 1134 | }, 1135 | "bars": false, 1136 | "dashLength": 10, 1137 | "dashes": false, 1138 | "datasource": "${DS_PROMETHEUS}", 1139 | "decimals": 2, 1140 | "description": "**InnoDB Checkpoint Age**\n\nThe maximum checkpoint age is determined by the total length of all transaction log files (`innodb_log_file_size`).\n\nWhen the checkpoint age reaches the maximum checkpoint age, blocks are flushed syncronously. The rules of the thumb is to keep one hour of traffic in those logs and let the checkpointing perform its work as smooth as possible. If you don't do this, InnoDB will do synchronous flushing at the worst possible time, ie when you are busiest.", 1141 | "editable": true, 1142 | "error": false, 1143 | "fill": 2, 1144 | "grid": {}, 1145 | "gridPos": { 1146 | "h": 9, 1147 | "w": 24, 1148 | "x": 0, 1149 | "y": 63 1150 | }, 1151 | "id": 38, 1152 | "legend": { 1153 | "alignAsTable": true, 1154 | "avg": true, 1155 | "current": false, 1156 | "max": true, 1157 | "min": true, 1158 | "rightSide": false, 1159 | "show": true, 1160 | "sortDesc": false, 1161 | "total": false, 1162 | "values": true 1163 | }, 1164 | "lines": true, 1165 | "linewidth": 2, 1166 | "links": [], 1167 | "nullPointMode": "null", 1168 | "percentage": false, 1169 | "pointradius": 5, 1170 | "points": false, 1171 | "renderer": "flot", 1172 | "seriesOverrides": [ 1173 | { 1174 | "alias": "Max Checkpoint Age", 1175 | "color": "#BF1B00", 1176 | "fill": 0 1177 | } 1178 | ], 1179 | "spaceLength": 10, 1180 | "stack": false, 1181 | "steppedLine": false, 1182 | "targets": [ 1183 | { 1184 | "calculatedInterval": "2m", 1185 | "datasourceErrors": {}, 1186 | "errors": {}, 1187 | "expr": "mysql_global_status_innodb_checkpoint_age{instance=\"$host\"}", 1188 | "format": "time_series", 1189 | "interval": "$interval", 1190 | "intervalFactor": 1, 1191 | "legendFormat": "Uncheckpointed Bytes", 1192 | "metric": "", 1193 | "refId": "A", 1194 | "step": 300 1195 | }, 1196 | { 1197 | "calculatedInterval": "2m", 1198 | "datasourceErrors": {}, 1199 | "errors": {}, 1200 | "expr": "mysql_global_status_innodb_checkpoint_max_age{instance=\"$host\"}", 1201 | "format": "time_series", 1202 | "interval": "$interval", 1203 | "intervalFactor": 1, 1204 | "legendFormat": "Max Checkpoint Age", 1205 | "metric": "", 1206 | "refId": "B", 1207 | "step": 300 1208 | } 1209 | ], 1210 | "thresholds": [], 1211 | "timeFrom": null, 1212 | "timeShift": null, 1213 | "title": "InnoDB Checkpoint Age", 1214 | "tooltip": { 1215 | "msResolution": false, 1216 | "shared": true, 1217 | "sort": 0, 1218 | "value_type": "individual" 1219 | }, 1220 | "type": "graph", 1221 | "xaxis": { 1222 | "buckets": null, 1223 | "mode": "time", 1224 | "name": null, 1225 | "show": true, 1226 | "values": [] 1227 | }, 1228 | "yaxes": [ 1229 | { 1230 | "format": "bytes", 1231 | "logBase": 1, 1232 | "max": null, 1233 | "min": 0, 1234 | "show": true 1235 | }, 1236 | { 1237 | "format": "bytes", 1238 | "logBase": 1, 1239 | "max": null, 1240 | "min": 0, 1241 | "show": true 1242 | } 1243 | ], 1244 | "yaxis": { 1245 | "align": false, 1246 | "alignLevel": null 1247 | } 1248 | }, 1249 | { 1250 | "aliasColors": {}, 1251 | "bars": false, 1252 | "dashLength": 10, 1253 | "dashes": false, 1254 | "datasource": "${DS_PROMETHEUS}", 1255 | "fill": 0, 1256 | "gridPos": { 1257 | "h": 14, 1258 | "w": 24, 1259 | "x": 0, 1260 | "y": 72 1261 | }, 1262 | "id": 46, 1263 | "legend": { 1264 | "alignAsTable": true, 1265 | "avg": true, 1266 | "current": false, 1267 | "max": true, 1268 | "min": true, 1269 | "rightSide": false, 1270 | "show": true, 1271 | "sideWidth": 0, 1272 | "sort": "avg", 1273 | "sortDesc": true, 1274 | "total": false, 1275 | "values": true 1276 | }, 1277 | "lines": true, 1278 | "linewidth": 2, 1279 | "links": [], 1280 | "nullPointMode": "null", 1281 | "percentage": false, 1282 | "pointradius": 0.5, 1283 | "points": false, 1284 | "renderer": "flot", 1285 | "seriesOverrides": [ 1286 | { 1287 | "alias": "/Timer Wait/i", 1288 | "yaxis": 2 1289 | } 1290 | ], 1291 | "spaceLength": 10, 1292 | "stack": false, 1293 | "steppedLine": false, 1294 | "targets": [ 1295 | { 1296 | "expr": "topk(5, label_replace(rate(mysql_global_status_innodb_mutex_COUNT_STAR{instance=\"$host\"}[$interval]), \"mutex\", \"$2\", \"EVENT_NAME\", \"(.*)/(.*)\" ) or label_replace(irate(mysql_global_status_innodb_mutex_COUNT_STAR{instance=\"$host\"}[5m]), \"mutex\", \"$2\", \"EVENT_NAME\", \"(.*)/(.*)\" ))", 1297 | "format": "time_series", 1298 | "interval": "$interval", 1299 | "intervalFactor": 1, 1300 | "legendFormat": "{{ mutex }} calls", 1301 | "refId": "A" 1302 | }, 1303 | { 1304 | "expr": "topk(5, label_replace(rate(mysql_global_status_innodb_mutex_SUM_TIMER_WAIT{instance=\"$host\"}[$interval]), \"mutex\", \"$2\", \"EVENT_NAME\", \"(.*)/(.*)\" ) or label_replace(irate(mysql_global_status_innodb_mutex_SUM_TIMER_WAIT{instance=\"$host\"}[5m]), \"mutex\", \"$2\", \"EVENT_NAME\", \"(.*)/(.*)\" ))", 1305 | "format": "time_series", 1306 | "interval": "$interval", 1307 | "intervalFactor": 1, 1308 | "legendFormat": "{{ mutex }} timer wait", 1309 | "refId": "B" 1310 | } 1311 | ], 1312 | "thresholds": [], 1313 | "timeFrom": null, 1314 | "timeShift": null, 1315 | "title": "InnoDB Mutex", 1316 | "tooltip": { 1317 | "shared": true, 1318 | "sort": 2, 1319 | "value_type": "individual" 1320 | }, 1321 | "transparent": false, 1322 | "type": "graph", 1323 | "xaxis": { 1324 | "buckets": null, 1325 | "mode": "time", 1326 | "name": null, 1327 | "show": true, 1328 | "values": [] 1329 | }, 1330 | "yaxes": [ 1331 | { 1332 | "format": "short", 1333 | "label": "", 1334 | "logBase": 1, 1335 | "max": null, 1336 | "min": null, 1337 | "show": true 1338 | }, 1339 | { 1340 | "decimals": null, 1341 | "format": "ns", 1342 | "label": "", 1343 | "logBase": 1, 1344 | "max": null, 1345 | "min": "0", 1346 | "show": true 1347 | } 1348 | ], 1349 | "yaxis": { 1350 | "align": false, 1351 | "alignLevel": null 1352 | } 1353 | }, 1354 | { 1355 | "aliasColors": {}, 1356 | "bars": false, 1357 | "dashLength": 10, 1358 | "dashes": false, 1359 | "datasource": "${DS_PROMETHEUS}", 1360 | "decimals": null, 1361 | "editable": true, 1362 | "error": false, 1363 | "fill": 2, 1364 | "grid": {}, 1365 | "gridPos": { 1366 | "h": 15, 1367 | "w": 24, 1368 | "x": 0, 1369 | "y": 86 1370 | }, 1371 | "id": 30, 1372 | "legend": { 1373 | "alignAsTable": true, 1374 | "avg": true, 1375 | "current": false, 1376 | "hideEmpty": false, 1377 | "max": true, 1378 | "min": true, 1379 | "rightSide": false, 1380 | "show": true, 1381 | "sort": "avg", 1382 | "sortDesc": true, 1383 | "total": false, 1384 | "values": true 1385 | }, 1386 | "lines": true, 1387 | "linewidth": 2, 1388 | "links": [], 1389 | "nullPointMode": "null", 1390 | "percentage": false, 1391 | "pointradius": 5, 1392 | "points": false, 1393 | "renderer": "flot", 1394 | "seriesOverrides": [ 1395 | { 1396 | "alias": "Swap Used", 1397 | "yaxis": 2 1398 | }, 1399 | { 1400 | "alias": "Swap Free", 1401 | "yaxis": 2 1402 | } 1403 | ], 1404 | "spaceLength": 10, 1405 | "stack": false, 1406 | "steppedLine": false, 1407 | "targets": [ 1408 | { 1409 | "calculatedInterval": "2s", 1410 | "datasourceErrors": {}, 1411 | "errors": {}, 1412 | "expr": "rate(node_vmstat_pswpin{instance=\"$host\"}[$interval]) * 4096 or irate(node_vmstat_pswpin{instance=\"$host\"}[5m]) * 4096", 1413 | "format": "time_series", 1414 | "interval": "$interval", 1415 | "intervalFactor": 1, 1416 | "legendFormat": "Swap In (Reads)", 1417 | "metric": "", 1418 | "refId": "A", 1419 | "step": 300, 1420 | "target": "" 1421 | }, 1422 | { 1423 | "calculatedInterval": "2s", 1424 | "datasourceErrors": {}, 1425 | "errors": {}, 1426 | "expr": "rate(node_vmstat_pswpout{instance=\"$host\"}[$interval]) * 4096 or irate(node_vmstat_pswpout{instance=\"$host\"}[5m]) * 4096", 1427 | "format": "time_series", 1428 | "interval": "$interval", 1429 | "intervalFactor": 1, 1430 | "legendFormat": "Swap Out (Writes)", 1431 | "metric": "", 1432 | "refId": "B", 1433 | "step": 300, 1434 | "target": "" 1435 | }, 1436 | { 1437 | "expr": "node_memory_SwapTotal{instance=\"$host\"} - node_memory_SwapFree{instance=\"$host\"}", 1438 | "format": "time_series", 1439 | "intervalFactor": 1, 1440 | "legendFormat": "Swap Used", 1441 | "refId": "C" 1442 | }, 1443 | { 1444 | "expr": "node_memory_SwapFree{instance=\"$host\"}", 1445 | "format": "time_series", 1446 | "intervalFactor": 1, 1447 | "legendFormat": "Swap Free", 1448 | "refId": "D" 1449 | } 1450 | ], 1451 | "thresholds": [], 1452 | "timeFrom": null, 1453 | "timeShift": null, 1454 | "title": "Swap Activity", 1455 | "tooltip": { 1456 | "msResolution": false, 1457 | "shared": true, 1458 | "sort": 0, 1459 | "value_type": "individual" 1460 | }, 1461 | "transparent": false, 1462 | "type": "graph", 1463 | "xaxis": { 1464 | "buckets": null, 1465 | "mode": "time", 1466 | "name": null, 1467 | "show": true, 1468 | "values": [] 1469 | }, 1470 | "yaxes": [ 1471 | { 1472 | "format": "Bps", 1473 | "label": "", 1474 | "logBase": 1, 1475 | "max": null, 1476 | "min": 0, 1477 | "show": true 1478 | }, 1479 | { 1480 | "format": "bytes", 1481 | "logBase": 1, 1482 | "max": null, 1483 | "min": 0, 1484 | "show": true 1485 | } 1486 | ], 1487 | "yaxis": { 1488 | "align": false, 1489 | "alignLevel": null 1490 | } 1491 | }, 1492 | { 1493 | "aliasColors": {}, 1494 | "bars": false, 1495 | "dashLength": 10, 1496 | "dashes": false, 1497 | "datasource": "${DS_PROMETHEUS}", 1498 | "decimals": 2, 1499 | "editable": true, 1500 | "error": false, 1501 | "fill": 2, 1502 | "grid": {}, 1503 | "gridPos": { 1504 | "h": 8, 1505 | "w": 24, 1506 | "x": 0, 1507 | "y": 101 1508 | }, 1509 | "height": "250px", 1510 | "id": 40, 1511 | "legend": { 1512 | "alignAsTable": false, 1513 | "avg": true, 1514 | "current": false, 1515 | "hideEmpty": true, 1516 | "hideZero": true, 1517 | "max": false, 1518 | "min": false, 1519 | "rightSide": false, 1520 | "show": true, 1521 | "total": false, 1522 | "values": true 1523 | }, 1524 | "lines": false, 1525 | "linewidth": 2, 1526 | "links": [], 1527 | "nullPointMode": "null", 1528 | "percentage": false, 1529 | "pointradius": 1, 1530 | "points": true, 1531 | "renderer": "flot", 1532 | "seriesOverrides": [], 1533 | "spaceLength": 10, 1534 | "stack": false, 1535 | "steppedLine": false, 1536 | "targets": [ 1537 | { 1538 | "calculatedInterval": "2m", 1539 | "datasourceErrors": {}, 1540 | "errors": {}, 1541 | "expr": "sum((rate(node_disk_read_time_ms{device!~\"dm-.+\", instance=\"$host\"}[$interval]) / rate(node_disk_reads_completed{device!~\"dm-.+\", instance=\"$host\"}[$interval])) or (irate(node_disk_read_time_ms{device!~\"dm-.+\", instance=\"$host\"}[5m]) / irate(node_disk_reads_completed{device!~\"dm-.+\", instance=\"$host\"}[5m]))\nor avg_over_time(aws_rds_read_latency_average{instance=\"$host\"}[$interval]) or avg_over_time(aws_rds_read_latency_average{instance=\"$host\"}[5m]))", 1542 | "format": "time_series", 1543 | "interval": "$interval", 1544 | "intervalFactor": 1, 1545 | "legendFormat": "Read", 1546 | "metric": "", 1547 | "refId": "A", 1548 | "step": 20, 1549 | "target": "" 1550 | }, 1551 | { 1552 | "calculatedInterval": "2m", 1553 | "datasourceErrors": {}, 1554 | "errors": {}, 1555 | "expr": "sum((rate(node_disk_write_time_ms{device!~\"dm-.+\", instance=\"$host\"}[$interval]) / rate(node_disk_writes_completed{device!~\"dm-.+\", instance=\"$host\"}[$interval])) or (irate(node_disk_write_time_ms{device!~\"dm-.+\", instance=\"$host\"}[5m]) / irate(node_disk_writes_completed{device!~\"dm-.+\", instance=\"$host\"}[5m])) or \navg_over_time(aws_rds_write_latency_average{instance=\"$host\"}[$interval]) or avg_over_time(aws_rds_write_latency_average{instance=\"$host\"}[5m]))", 1556 | "format": "time_series", 1557 | "interval": "$interval", 1558 | "intervalFactor": 1, 1559 | "legendFormat": "Write", 1560 | "metric": "", 1561 | "refId": "B", 1562 | "step": 20, 1563 | "target": "" 1564 | } 1565 | ], 1566 | "thresholds": [], 1567 | "timeFrom": null, 1568 | "timeShift": null, 1569 | "title": "Disk Latency", 1570 | "tooltip": { 1571 | "msResolution": false, 1572 | "shared": true, 1573 | "sort": 0, 1574 | "value_type": "individual" 1575 | }, 1576 | "transparent": false, 1577 | "type": "graph", 1578 | "xaxis": { 1579 | "buckets": null, 1580 | "mode": "time", 1581 | "name": null, 1582 | "show": true, 1583 | "values": [] 1584 | }, 1585 | "yaxes": [ 1586 | { 1587 | "format": "ms", 1588 | "label": "", 1589 | "logBase": 2, 1590 | "max": null, 1591 | "min": null, 1592 | "show": true 1593 | }, 1594 | { 1595 | "format": "ms", 1596 | "label": "", 1597 | "logBase": 1, 1598 | "max": null, 1599 | "min": 0, 1600 | "show": true 1601 | } 1602 | ], 1603 | "yaxis": { 1604 | "align": false, 1605 | "alignLevel": null 1606 | } 1607 | }, 1608 | { 1609 | "aliasColors": {}, 1610 | "bars": false, 1611 | "dashLength": 10, 1612 | "dashes": false, 1613 | "datasource": "${DS_PROMETHEUS}", 1614 | "decimals": 2, 1615 | "description": "Shows amount of physical IOs (reads and writes) different devices are serving. Spikes in number of IOs served often corresponds to performance problems due to IO subsystem overload.", 1616 | "editable": true, 1617 | "error": false, 1618 | "fill": 2, 1619 | "grid": {}, 1620 | "gridPos": { 1621 | "h": 8, 1622 | "w": 24, 1623 | "x": 0, 1624 | "y": 109 1625 | }, 1626 | "id": 44, 1627 | "legend": { 1628 | "alignAsTable": true, 1629 | "avg": true, 1630 | "current": false, 1631 | "hideEmpty": false, 1632 | "hideZero": true, 1633 | "max": true, 1634 | "min": true, 1635 | "rightSide": true, 1636 | "show": true, 1637 | "sort": null, 1638 | "sortDesc": null, 1639 | "total": false, 1640 | "values": true 1641 | }, 1642 | "lines": true, 1643 | "linewidth": 2, 1644 | "links": [], 1645 | "nullPointMode": "null", 1646 | "percentage": false, 1647 | "pointradius": 1, 1648 | "points": false, 1649 | "renderer": "flot", 1650 | "seriesOverrides": [], 1651 | "spaceLength": 10, 1652 | "stack": false, 1653 | "steppedLine": false, 1654 | "targets": [ 1655 | { 1656 | "calculatedInterval": "2m", 1657 | "datasourceErrors": {}, 1658 | "errors": {}, 1659 | "expr": "rate(node_disk_reads_completed{device=~\"$device\", instance=\"$host\"}[$interval]) or irate(node_disk_reads_completed{device=~\"$device\", instance=\"$host\"}[5m])", 1660 | "format": "time_series", 1661 | "interval": "$interval", 1662 | "intervalFactor": 1, 1663 | "legendFormat": "Read: {{ device }}", 1664 | "metric": "", 1665 | "refId": "A", 1666 | "step": 300, 1667 | "target": "" 1668 | }, 1669 | { 1670 | "calculatedInterval": "2m", 1671 | "datasourceErrors": {}, 1672 | "errors": {}, 1673 | "expr": "rate(node_disk_writes_completed{device=~\"$device\", instance=\"$host\"}[$interval]) or irate(node_disk_writes_completed{device=~\"$device\", instance=\"$host\"}[5m])", 1674 | "format": "time_series", 1675 | "interval": "$interval", 1676 | "intervalFactor": 1, 1677 | "legendFormat": "Write: {{ device }}", 1678 | "metric": "", 1679 | "refId": "B", 1680 | "step": 300, 1681 | "target": "" 1682 | } 1683 | ], 1684 | "thresholds": [], 1685 | "timeFrom": null, 1686 | "timeShift": null, 1687 | "title": "Disk Operations", 1688 | "tooltip": { 1689 | "msResolution": false, 1690 | "shared": true, 1691 | "sort": 0, 1692 | "value_type": "individual" 1693 | }, 1694 | "transparent": false, 1695 | "type": "graph", 1696 | "xaxis": { 1697 | "buckets": null, 1698 | "mode": "time", 1699 | "name": null, 1700 | "show": true, 1701 | "values": [] 1702 | }, 1703 | "yaxes": [ 1704 | { 1705 | "format": "iops", 1706 | "label": "", 1707 | "logBase": 1, 1708 | "max": null, 1709 | "min": 0, 1710 | "show": true 1711 | }, 1712 | { 1713 | "format": "short", 1714 | "label": "", 1715 | "logBase": 1, 1716 | "max": null, 1717 | "min": 0, 1718 | "show": true 1719 | } 1720 | ], 1721 | "yaxis": { 1722 | "align": false, 1723 | "alignLevel": null 1724 | } 1725 | }, 1726 | { 1727 | "aliasColors": { 1728 | "Allocated": "#E0752D", 1729 | "CPU Load": "#64B0C8", 1730 | "IO Load ": "#EA6460", 1731 | "Limit": "#1F78C1", 1732 | "Normalized CPU Load": "#6ED0E0" 1733 | }, 1734 | "bars": false, 1735 | "dashLength": 10, 1736 | "dashes": false, 1737 | "datasource": "${DS_PROMETHEUS}", 1738 | "decimals": 2, 1739 | "editable": true, 1740 | "error": false, 1741 | "fill": 2, 1742 | "grid": {}, 1743 | "gridPos": { 1744 | "h": 10, 1745 | "w": 24, 1746 | "x": 0, 1747 | "y": 117 1748 | }, 1749 | "id": 33, 1750 | "legend": { 1751 | "alignAsTable": true, 1752 | "avg": true, 1753 | "current": false, 1754 | "hideEmpty": false, 1755 | "max": true, 1756 | "min": true, 1757 | "rightSide": false, 1758 | "show": true, 1759 | "sortDesc": true, 1760 | "total": false, 1761 | "values": true 1762 | }, 1763 | "lines": true, 1764 | "linewidth": 2, 1765 | "links": [], 1766 | "nullPointMode": "null", 1767 | "percentage": false, 1768 | "pointradius": 5, 1769 | "points": false, 1770 | "renderer": "flot", 1771 | "seriesOverrides": [], 1772 | "spaceLength": 10, 1773 | "stack": false, 1774 | "steppedLine": false, 1775 | "targets": [ 1776 | { 1777 | "calculatedInterval": "2s", 1778 | "datasourceErrors": {}, 1779 | "errors": {}, 1780 | "expr": "(avg_over_time(node_procs_running{instance=\"$host\"}[$interval])-1) / scalar(count(node_cpu{mode=\"user\", instance=\"$host\"})) or (avg_over_time(node_procs_running{instance=\"$host\"}[5m])-1) / scalar(count(node_cpu{mode=\"user\", instance=\"$host\"}))", 1781 | "format": "time_series", 1782 | "hide": false, 1783 | "interval": "$interval", 1784 | "intervalFactor": 1, 1785 | "legendFormat": "Normalized CPU Load", 1786 | "metric": "", 1787 | "refId": "B", 1788 | "step": 300, 1789 | "target": "" 1790 | }, 1791 | { 1792 | "calculatedInterval": "2s", 1793 | "datasourceErrors": {}, 1794 | "errors": {}, 1795 | "expr": "avg_over_time(node_procs_blocked{instance=\"$host\"}[$interval]) or avg_over_time(node_procs_blocked{instance=\"$host\"}[5m])", 1796 | "format": "time_series", 1797 | "interval": "$interval", 1798 | "intervalFactor": 1, 1799 | "legendFormat": "IO Load ", 1800 | "metric": "", 1801 | "refId": "A", 1802 | "step": 300, 1803 | "target": "" 1804 | } 1805 | ], 1806 | "thresholds": [], 1807 | "timeFrom": null, 1808 | "timeShift": null, 1809 | "title": "Saturation Metrics", 1810 | "tooltip": { 1811 | "msResolution": false, 1812 | "shared": true, 1813 | "sort": 0, 1814 | "value_type": "individual" 1815 | }, 1816 | "transparent": false, 1817 | "type": "graph", 1818 | "xaxis": { 1819 | "buckets": null, 1820 | "mode": "time", 1821 | "name": null, 1822 | "show": true, 1823 | "values": [] 1824 | }, 1825 | "yaxes": [ 1826 | { 1827 | "format": "short", 1828 | "label": "", 1829 | "logBase": 1, 1830 | "max": null, 1831 | "min": 0, 1832 | "show": true 1833 | }, 1834 | { 1835 | "format": "short", 1836 | "logBase": 1, 1837 | "max": null, 1838 | "min": 0, 1839 | "show": true 1840 | } 1841 | ], 1842 | "yaxis": { 1843 | "align": false, 1844 | "alignLevel": null 1845 | } 1846 | }, 1847 | { 1848 | "aliasColors": {}, 1849 | "bars": false, 1850 | "dashLength": 10, 1851 | "dashes": false, 1852 | "datasource": "${DS_PROMETHEUS}", 1853 | "decimals": 2, 1854 | "description": "**Innodb Transactions** \n\nInnoDB is an MVCC storage engine, which means you can start a transaction and continue to see a consistent snapshot \neven as the data changes. This is implemented by keeping old versions of rows as they are modified.\n\nThe InnoDB History List is the undo logs which are used to store these modifications. They are a fundamental part of InnoDB’s transactional architecture.\n\nIf history length is rising regularly, do not let open connections linger for a long period as this can affect the performance of InnoDB considerably. It is also a good idea to look for long running queries in PMM's Query Analytics.", 1855 | "editable": true, 1856 | "error": false, 1857 | "fill": 2, 1858 | "grid": {}, 1859 | "gridPos": { 1860 | "h": 9, 1861 | "w": 24, 1862 | "x": 0, 1863 | "y": 127 1864 | }, 1865 | "id": 20, 1866 | "legend": { 1867 | "alignAsTable": true, 1868 | "avg": true, 1869 | "current": false, 1870 | "hideZero": true, 1871 | "max": true, 1872 | "min": true, 1873 | "rightSide": false, 1874 | "show": true, 1875 | "sort": "avg", 1876 | "sortDesc": true, 1877 | "total": false, 1878 | "values": true 1879 | }, 1880 | "lines": true, 1881 | "linewidth": 2, 1882 | "links": [ 1883 | { 1884 | "dashUri": "db/_pmm-query-analytics", 1885 | "dashboard": "_PMM Query Analytics", 1886 | "title": "Query Analytics", 1887 | "type": "dashboard" 1888 | } 1889 | ], 1890 | "nullPointMode": "null", 1891 | "percentage": false, 1892 | "pointradius": 5, 1893 | "points": false, 1894 | "renderer": "flot", 1895 | "seriesOverrides": [ 1896 | { 1897 | "alias": "InnoDB Transactions", 1898 | "yaxis": 2 1899 | } 1900 | ], 1901 | "spaceLength": 10, 1902 | "stack": false, 1903 | "steppedLine": false, 1904 | "targets": [ 1905 | { 1906 | "calculatedInterval": "2m", 1907 | "datasourceErrors": {}, 1908 | "errors": {}, 1909 | "expr": "(max_over_time(mysql_global_status_innodb_history_list_length{instance=\"$host\"}[$interval]) or \nmax_over_time(mysql_global_status_innodb_history_list_length{instance=\"$host\"}[5m])) or \n(max_over_time(mysql_info_schema_innodb_metrics_transaction_trx_rseg_history_len{instance=\"$host\"}[$interval]) or \nmax_over_time(mysql_info_schema_innodb_metrics_transaction_trx_rseg_history_len{instance=\"$host\"}[5m]))", 1910 | "format": "time_series", 1911 | "interval": "$interval", 1912 | "intervalFactor": 1, 1913 | "legendFormat": "History Length", 1914 | "metric": "", 1915 | "refId": "B", 1916 | "step": 300 1917 | }, 1918 | { 1919 | "calculatedInterval": "2m", 1920 | "datasourceErrors": {}, 1921 | "errors": {}, 1922 | "expr": "rate(mysql_global_status_innodb_max_trx_id{instance=\"$host\"}[$interval]) or irate(mysql_global_status_innodb_max_trx_id{instance=\"$host\"}[5m])", 1923 | "format": "time_series", 1924 | "hide": false, 1925 | "interval": "$interval", 1926 | "intervalFactor": 1, 1927 | "legendFormat": "InnoDB Transactions", 1928 | "metric": "", 1929 | "refId": "A", 1930 | "step": 300 1931 | } 1932 | ], 1933 | "thresholds": [], 1934 | "timeFrom": null, 1935 | "timeShift": null, 1936 | "title": "InnoDB History Length + Transactions", 1937 | "tooltip": { 1938 | "msResolution": false, 1939 | "shared": true, 1940 | "sort": 0, 1941 | "value_type": "individual" 1942 | }, 1943 | "type": "graph", 1944 | "xaxis": { 1945 | "buckets": null, 1946 | "mode": "time", 1947 | "name": null, 1948 | "show": true, 1949 | "values": [] 1950 | }, 1951 | "yaxes": [ 1952 | { 1953 | "format": "short", 1954 | "logBase": 1, 1955 | "max": null, 1956 | "min": 0, 1957 | "show": true 1958 | }, 1959 | { 1960 | "format": "short", 1961 | "logBase": 1, 1962 | "max": null, 1963 | "min": 0, 1964 | "show": true 1965 | } 1966 | ], 1967 | "yaxis": { 1968 | "align": false, 1969 | "alignLevel": null 1970 | } 1971 | }, 1972 | { 1973 | "aliasColors": {}, 1974 | "bars": false, 1975 | "dashLength": 10, 1976 | "dashes": false, 1977 | "datasource": "${DS_PROMETHEUS}", 1978 | "decimals": 2, 1979 | "editable": true, 1980 | "error": false, 1981 | "fill": 2, 1982 | "grid": {}, 1983 | "gridPos": { 1984 | "h": 12, 1985 | "w": 24, 1986 | "x": 0, 1987 | "y": 136 1988 | }, 1989 | "id": 34, 1990 | "legend": { 1991 | "alignAsTable": true, 1992 | "avg": true, 1993 | "current": false, 1994 | "max": true, 1995 | "min": true, 1996 | "rightSide": false, 1997 | "show": true, 1998 | "sort": "avg", 1999 | "sortDesc": true, 2000 | "total": false, 2001 | "values": true 2002 | }, 2003 | "lines": true, 2004 | "linewidth": 2, 2005 | "links": [], 2006 | "nullPointMode": "null", 2007 | "percentage": false, 2008 | "pointradius": 5, 2009 | "points": false, 2010 | "renderer": "flot", 2011 | "seriesOverrides": [ 2012 | { 2013 | "alias": "Disk Reads", 2014 | "yaxis": 2 2015 | } 2016 | ], 2017 | "spaceLength": 10, 2018 | "stack": false, 2019 | "steppedLine": false, 2020 | "targets": [ 2021 | { 2022 | "calculatedInterval": "2m", 2023 | "datasourceErrors": {}, 2024 | "errors": {}, 2025 | "expr": "rate(mysql_global_status_innodb_buffer_pool_reads{instance=\"$host\"}[$interval]) or irate(mysql_global_status_innodb_buffer_pool_reads{instance=\"$host\"}[5m]) ", 2026 | "format": "time_series", 2027 | "interval": "$interval", 2028 | "intervalFactor": 1, 2029 | "legendFormat": "Disk Reads", 2030 | "metric": "", 2031 | "refId": "C", 2032 | "step": 300 2033 | }, 2034 | { 2035 | "calculatedInterval": "2m", 2036 | "datasourceErrors": {}, 2037 | "errors": {}, 2038 | "expr": "rate(mysql_global_status_innodb_buffer_pool_read_requests{instance=\"$host\"}[$interval]) or irate(mysql_global_status_innodb_buffer_pool_read_requests{instance=\"$host\"}[5m])", 2039 | "format": "time_series", 2040 | "interval": "$interval", 2041 | "intervalFactor": 1, 2042 | "legendFormat": "Read Requests", 2043 | "metric": "", 2044 | "refId": "A", 2045 | "step": 300 2046 | }, 2047 | { 2048 | "calculatedInterval": "2m", 2049 | "datasourceErrors": {}, 2050 | "errors": {}, 2051 | "expr": "rate(mysql_global_status_innodb_buffer_pool_write_requests{instance=\"$host\"}[$interval]) or irate(mysql_global_status_innodb_buffer_pool_write_requests{instance=\"$host\"}[5m])", 2052 | "format": "time_series", 2053 | "interval": "$interval", 2054 | "intervalFactor": 1, 2055 | "legendFormat": "Write Requests", 2056 | "metric": "", 2057 | "refId": "B", 2058 | "step": 300 2059 | } 2060 | ], 2061 | "thresholds": [], 2062 | "timeFrom": null, 2063 | "timeShift": null, 2064 | "title": "InnoDB Buffer Pool Requests", 2065 | "tooltip": { 2066 | "msResolution": true, 2067 | "shared": true, 2068 | "sort": 0, 2069 | "value_type": "individual" 2070 | }, 2071 | "type": "graph", 2072 | "xaxis": { 2073 | "buckets": null, 2074 | "mode": "time", 2075 | "name": null, 2076 | "show": true, 2077 | "values": [] 2078 | }, 2079 | "yaxes": [ 2080 | { 2081 | "format": "short", 2082 | "logBase": 1, 2083 | "max": null, 2084 | "min": 0, 2085 | "show": true 2086 | }, 2087 | { 2088 | "format": "short", 2089 | "logBase": 1, 2090 | "max": null, 2091 | "min": 0, 2092 | "show": true 2093 | } 2094 | ], 2095 | "yaxis": { 2096 | "align": false, 2097 | "alignLevel": null 2098 | } 2099 | }, 2100 | { 2101 | "aliasColors": {}, 2102 | "bars": false, 2103 | "dashLength": 10, 2104 | "dashes": false, 2105 | "datasource": "${DS_PROMETHEUS}", 2106 | "decimals": 2, 2107 | "description": "**Top Command Counters**\n\nThe Com_{{xxx}} statement counter variables indicate the number of times each xxx statement has been executed. There is one status variable for each type of statement. For example, Com_delete and Com_update count [``DELETE``](https://dev.mysql.com/doc/refman/5.7/en/delete.html) and [``UPDATE``](https://dev.mysql.com/doc/refman/5.7/en/update.html) statements, respectively. Com_delete_multi and Com_update_multi are similar but apply to [``DELETE``](https://dev.mysql.com/doc/refman/5.7/en/delete.html) and [``UPDATE``](https://dev.mysql.com/doc/refman/5.7/en/update.html) statements that use multiple-table syntax.", 2108 | "editable": true, 2109 | "error": false, 2110 | "fill": 2, 2111 | "grid": {}, 2112 | "gridPos": { 2113 | "h": 9, 2114 | "w": 24, 2115 | "x": 0, 2116 | "y": 148 2117 | }, 2118 | "id": 42, 2119 | "legend": { 2120 | "alignAsTable": true, 2121 | "avg": true, 2122 | "current": false, 2123 | "hideEmpty": false, 2124 | "hideZero": false, 2125 | "max": true, 2126 | "min": true, 2127 | "rightSide": true, 2128 | "show": true, 2129 | "sort": "avg", 2130 | "sortDesc": true, 2131 | "total": false, 2132 | "values": true 2133 | }, 2134 | "lines": true, 2135 | "linewidth": 2, 2136 | "links": [ 2137 | { 2138 | "title": "Server Status Variables (Com_xxx)", 2139 | "type": "absolute", 2140 | "url": "https://dev.mysql.com/doc/refman/5.7/en/server-status-variables.html#statvar_Com_xxx" 2141 | } 2142 | ], 2143 | "nullPointMode": "null", 2144 | "percentage": false, 2145 | "pointradius": 5, 2146 | "points": false, 2147 | "renderer": "flot", 2148 | "seriesOverrides": [], 2149 | "spaceLength": 10, 2150 | "stack": false, 2151 | "steppedLine": false, 2152 | "targets": [ 2153 | { 2154 | "calculatedInterval": "2m", 2155 | "datasourceErrors": {}, 2156 | "errors": {}, 2157 | "expr": "topk(10, rate(mysql_global_status_commands_total{instance=\"$host\"}[$interval])>0) or topk(10, irate(mysql_global_status_commands_total{instance=\"$host\"}[5m])>0)", 2158 | "format": "time_series", 2159 | "hide": false, 2160 | "interval": "$interval", 2161 | "intervalFactor": 1, 2162 | "legendFormat": "Com_{{ command }}", 2163 | "metric": "", 2164 | "refId": "B", 2165 | "step": 20 2166 | } 2167 | ], 2168 | "thresholds": [], 2169 | "timeFrom": null, 2170 | "timeShift": null, 2171 | "title": "Top Command Counters", 2172 | "tooltip": { 2173 | "msResolution": false, 2174 | "shared": true, 2175 | "sort": 0, 2176 | "value_type": "individual" 2177 | }, 2178 | "type": "graph", 2179 | "xaxis": { 2180 | "buckets": null, 2181 | "mode": "time", 2182 | "name": null, 2183 | "show": true, 2184 | "values": [] 2185 | }, 2186 | "yaxes": [ 2187 | { 2188 | "format": "short", 2189 | "logBase": 1, 2190 | "max": null, 2191 | "min": 0, 2192 | "show": true 2193 | }, 2194 | { 2195 | "format": "short", 2196 | "logBase": 1, 2197 | "max": null, 2198 | "min": 0, 2199 | "show": true 2200 | } 2201 | ], 2202 | "yaxis": { 2203 | "align": false, 2204 | "alignLevel": null 2205 | } 2206 | }, 2207 | { 2208 | "aliasColors": {}, 2209 | "bars": false, 2210 | "dashLength": 10, 2211 | "dashes": false, 2212 | "datasource": "${DS_PROMETHEUS}", 2213 | "decimals": 2, 2214 | "description": "**MySQL Active Threads**\n\nThreads Connected is the number of open connections, while Threads Running is the number of threads not sleeping.", 2215 | "editable": true, 2216 | "error": false, 2217 | "fill": 2, 2218 | "grid": {}, 2219 | "gridPos": { 2220 | "h": 12, 2221 | "w": 24, 2222 | "x": 0, 2223 | "y": 157 2224 | }, 2225 | "id": 24, 2226 | "legend": { 2227 | "alignAsTable": true, 2228 | "avg": true, 2229 | "current": true, 2230 | "max": true, 2231 | "min": true, 2232 | "rightSide": false, 2233 | "show": true, 2234 | "sortDesc": true, 2235 | "total": false, 2236 | "values": true 2237 | }, 2238 | "lines": true, 2239 | "linewidth": 2, 2240 | "links": [], 2241 | "nullPointMode": "null", 2242 | "percentage": false, 2243 | "pointradius": 5, 2244 | "points": false, 2245 | "renderer": "flot", 2246 | "seriesOverrides": [ 2247 | { 2248 | "alias": "Peak Threads Running", 2249 | "color": "#E24D42", 2250 | "lines": false, 2251 | "pointradius": 1, 2252 | "points": true 2253 | }, 2254 | { 2255 | "alias": "Peak Threads Connected", 2256 | "color": "#1F78C1" 2257 | }, 2258 | { 2259 | "alias": "Avg Threads Running", 2260 | "color": "#EAB839" 2261 | } 2262 | ], 2263 | "spaceLength": 10, 2264 | "stack": false, 2265 | "steppedLine": false, 2266 | "targets": [ 2267 | { 2268 | "calculatedInterval": "2m", 2269 | "datasourceErrors": {}, 2270 | "errors": {}, 2271 | "expr": "max_over_time(mysql_global_status_threads_connected{instance=\"$host\"}[$interval]) or\nmax_over_time(mysql_global_status_threads_connected{instance=\"$host\"}[5m])", 2272 | "format": "time_series", 2273 | "hide": false, 2274 | "interval": "$interval", 2275 | "intervalFactor": 1, 2276 | "legendFormat": "Peak Threads Connected", 2277 | "metric": "", 2278 | "refId": "A", 2279 | "step": 20 2280 | }, 2281 | { 2282 | "calculatedInterval": "2m", 2283 | "datasourceErrors": {}, 2284 | "errors": {}, 2285 | "expr": "max_over_time(mysql_global_status_threads_running{instance=\"$host\"}[$interval]) or\nmax_over_time(mysql_global_status_threads_running{instance=\"$host\"}[5m])", 2286 | "format": "time_series", 2287 | "interval": "$interval", 2288 | "intervalFactor": 1, 2289 | "legendFormat": "Peak Threads Running", 2290 | "metric": "", 2291 | "refId": "B", 2292 | "step": 20 2293 | }, 2294 | { 2295 | "expr": "avg_over_time(mysql_global_status_threads_running{instance=\"$host\"}[$interval]) or \navg_over_time(mysql_global_status_threads_running{instance=\"$host\"}[5m])", 2296 | "format": "time_series", 2297 | "interval": "$interval", 2298 | "intervalFactor": 1, 2299 | "legendFormat": "Avg Threads Running", 2300 | "refId": "C", 2301 | "step": 20 2302 | } 2303 | ], 2304 | "thresholds": [], 2305 | "timeFrom": null, 2306 | "timeShift": null, 2307 | "title": "Thread Activity", 2308 | "tooltip": { 2309 | "msResolution": false, 2310 | "shared": true, 2311 | "sort": 0, 2312 | "value_type": "individual" 2313 | }, 2314 | "type": "graph", 2315 | "xaxis": { 2316 | "buckets": null, 2317 | "mode": "time", 2318 | "name": null, 2319 | "show": true, 2320 | "values": [ 2321 | "total" 2322 | ] 2323 | }, 2324 | "yaxes": [ 2325 | { 2326 | "format": "short", 2327 | "label": "Threads", 2328 | "logBase": 1, 2329 | "max": null, 2330 | "min": 0, 2331 | "show": true 2332 | }, 2333 | { 2334 | "format": "short", 2335 | "label": "", 2336 | "logBase": 1, 2337 | "max": null, 2338 | "min": 0, 2339 | "show": false 2340 | } 2341 | ], 2342 | "yaxis": { 2343 | "align": false, 2344 | "alignLevel": null 2345 | } 2346 | }, 2347 | { 2348 | "aliasColors": {}, 2349 | "bars": false, 2350 | "dashLength": 10, 2351 | "dashes": false, 2352 | "datasource": "${DS_PROMETHEUS}", 2353 | "decimals": 2, 2354 | "description": "**MySQL Table Open Cache Status**\n\nThe recommendation is to set the `table_open_cache_instances` to a loose correlation to virtual CPUs, keeping in mind that more instances means the cache is split more times. If you have a cache set to 500 but it has 10 instances, each cache will only have 50 cached.\n\nThe `table_definition_cache` and `table_open_cache` can be left as default as they are auto-sized MySQL 5.6 and above (ie: do not set them to any value).", 2355 | "editable": true, 2356 | "error": false, 2357 | "fill": 2, 2358 | "grid": {}, 2359 | "gridPos": { 2360 | "h": 17, 2361 | "w": 24, 2362 | "x": 0, 2363 | "y": 169 2364 | }, 2365 | "id": 22, 2366 | "legend": { 2367 | "alignAsTable": true, 2368 | "avg": true, 2369 | "current": false, 2370 | "max": true, 2371 | "min": true, 2372 | "rightSide": false, 2373 | "show": true, 2374 | "sort": "avg", 2375 | "sortDesc": true, 2376 | "total": false, 2377 | "values": true 2378 | }, 2379 | "lines": true, 2380 | "linewidth": 2, 2381 | "links": [ 2382 | { 2383 | "title": "Server Status Variables (table_open_cache)", 2384 | "type": "absolute", 2385 | "url": "http://dev.mysql.com/doc/refman/5.6/en/server-system-variables.html#sysvar_table_open_cache" 2386 | } 2387 | ], 2388 | "nullPointMode": "null", 2389 | "percentage": false, 2390 | "pointradius": 5, 2391 | "points": false, 2392 | "renderer": "flot", 2393 | "seriesOverrides": [ 2394 | { 2395 | "alias": "Table Open Cache Hit Ratio", 2396 | "yaxis": 2 2397 | } 2398 | ], 2399 | "spaceLength": 10, 2400 | "stack": false, 2401 | "steppedLine": false, 2402 | "targets": [ 2403 | { 2404 | "calculatedInterval": "2m", 2405 | "datasourceErrors": {}, 2406 | "errors": {}, 2407 | "expr": "rate(mysql_global_status_opened_tables{instance=\"$host\"}[$interval]) or irate(mysql_global_status_opened_tables{instance=\"$host\"}[5m])", 2408 | "format": "time_series", 2409 | "interval": "$interval", 2410 | "intervalFactor": 1, 2411 | "legendFormat": "Openings", 2412 | "metric": "", 2413 | "refId": "A", 2414 | "step": 20 2415 | }, 2416 | { 2417 | "expr": "rate(mysql_global_status_table_open_cache_hits{instance=\"$host\"}[$interval]) or irate(mysql_global_status_table_open_cache_hits{instance=\"$host\"}[5m])", 2418 | "format": "time_series", 2419 | "interval": "$interval", 2420 | "intervalFactor": 1, 2421 | "legendFormat": "Hits", 2422 | "refId": "B", 2423 | "step": 20 2424 | }, 2425 | { 2426 | "expr": "rate(mysql_global_status_table_open_cache_misses{instance=\"$host\"}[$interval]) or irate(mysql_global_status_table_open_cache_misses{instance=\"$host\"}[5m])", 2427 | "format": "time_series", 2428 | "interval": "$interval", 2429 | "intervalFactor": 1, 2430 | "legendFormat": "Misses", 2431 | "refId": "C", 2432 | "step": 20 2433 | }, 2434 | { 2435 | "expr": "rate(mysql_global_status_table_open_cache_overflows{instance=\"$host\"}[$interval]) or irate(mysql_global_status_table_open_cache_overflows{instance=\"$host\"}[5m])", 2436 | "format": "time_series", 2437 | "interval": "$interval", 2438 | "intervalFactor": 1, 2439 | "legendFormat": "Misses due to Overflows", 2440 | "refId": "D", 2441 | "step": 20 2442 | }, 2443 | { 2444 | "expr": "(rate(mysql_global_status_table_open_cache_hits{instance=\"$host\"}[$interval]) or irate(mysql_global_status_table_open_cache_hits{instance=\"$host\"}[5m]))/((rate(mysql_global_status_table_open_cache_hits{instance=\"$host\"}[$interval]) or irate(mysql_global_status_table_open_cache_hits{instance=\"$host\"}[5m]))+(rate(mysql_global_status_table_open_cache_misses{instance=\"$host\"}[$interval]) or irate(mysql_global_status_table_open_cache_misses{instance=\"$host\"}[5m])))", 2445 | "format": "time_series", 2446 | "interval": "$interval", 2447 | "intervalFactor": 1, 2448 | "legendFormat": "Table Open Cache Hit Ratio", 2449 | "refId": "E", 2450 | "step": 20 2451 | } 2452 | ], 2453 | "thresholds": [], 2454 | "timeFrom": null, 2455 | "timeShift": null, 2456 | "title": "MySQL Table Open Cache Status", 2457 | "tooltip": { 2458 | "msResolution": false, 2459 | "shared": true, 2460 | "sort": 0, 2461 | "value_type": "individual" 2462 | }, 2463 | "type": "graph", 2464 | "xaxis": { 2465 | "buckets": null, 2466 | "mode": "time", 2467 | "name": null, 2468 | "show": true, 2469 | "values": [] 2470 | }, 2471 | "yaxes": [ 2472 | { 2473 | "format": "short", 2474 | "logBase": 1, 2475 | "max": null, 2476 | "min": 0, 2477 | "show": true 2478 | }, 2479 | { 2480 | "format": "percentunit", 2481 | "logBase": 1, 2482 | "max": null, 2483 | "min": 0, 2484 | "show": true 2485 | } 2486 | ], 2487 | "yaxis": { 2488 | "align": false, 2489 | "alignLevel": null 2490 | } 2491 | } 2492 | ], 2493 | "refresh": false, 2494 | "schemaVersion": 16, 2495 | "style": "dark", 2496 | "tags": [ 2497 | "OS", 2498 | "Percona" 2499 | ], 2500 | "templating": { 2501 | "list": [ 2502 | { 2503 | "allFormat": "glob", 2504 | "auto": true, 2505 | "auto_count": 200, 2506 | "auto_min": "1s", 2507 | "current": { 2508 | "text": "1s", 2509 | "value": "1s" 2510 | }, 2511 | "datasource": "Prometheus", 2512 | "hide": 0, 2513 | "includeAll": false, 2514 | "label": "Interval", 2515 | "multi": false, 2516 | "multiFormat": "glob", 2517 | "name": "interval", 2518 | "options": [ 2519 | { 2520 | "selected": false, 2521 | "text": "auto", 2522 | "value": "$__auto_interval_interval" 2523 | }, 2524 | { 2525 | "selected": true, 2526 | "text": "1s", 2527 | "value": "1s" 2528 | }, 2529 | { 2530 | "selected": false, 2531 | "text": "5s", 2532 | "value": "5s" 2533 | }, 2534 | { 2535 | "selected": false, 2536 | "text": "1m", 2537 | "value": "1m" 2538 | }, 2539 | { 2540 | "selected": false, 2541 | "text": "5m", 2542 | "value": "5m" 2543 | }, 2544 | { 2545 | "selected": false, 2546 | "text": "1h", 2547 | "value": "1h" 2548 | }, 2549 | { 2550 | "selected": false, 2551 | "text": "6h", 2552 | "value": "6h" 2553 | }, 2554 | { 2555 | "selected": false, 2556 | "text": "1d", 2557 | "value": "1d" 2558 | } 2559 | ], 2560 | "query": "1s,5s,1m,5m,1h,6h,1d", 2561 | "refresh": 2, 2562 | "type": "interval" 2563 | }, 2564 | { 2565 | "allFormat": "glob", 2566 | "allValue": null, 2567 | "current": {}, 2568 | "datasource": "${DS_PROMETHEUS}", 2569 | "hide": 0, 2570 | "includeAll": false, 2571 | "label": "Host", 2572 | "multi": false, 2573 | "multiFormat": "regex values", 2574 | "name": "host", 2575 | "options": [], 2576 | "query": "label_values(mysql_up, instance)", 2577 | "refresh": 1, 2578 | "refresh_on_load": false, 2579 | "regex": "", 2580 | "sort": 1, 2581 | "tagValuesQuery": "instance", 2582 | "tags": [], 2583 | "tagsQuery": "up", 2584 | "type": "query", 2585 | "useTags": false 2586 | }, 2587 | { 2588 | "allValue": null, 2589 | "current": {}, 2590 | "datasource": "${DS_PROMETHEUS}", 2591 | "hide": 0, 2592 | "includeAll": true, 2593 | "label": "Device", 2594 | "multi": true, 2595 | "name": "device", 2596 | "options": [], 2597 | "query": "label_values(node_disk_reads_completed{instance=\"$host\", device!~\"dm-.+\"}, device)", 2598 | "refresh": 1, 2599 | "regex": "", 2600 | "sort": 1, 2601 | "tagValuesQuery": "", 2602 | "tags": [], 2603 | "tagsQuery": "", 2604 | "type": "query", 2605 | "useTags": false 2606 | } 2607 | ] 2608 | }, 2609 | "time": { 2610 | "from": "now-6h", 2611 | "to": "now" 2612 | }, 2613 | "timepicker": { 2614 | "collapse": false, 2615 | "enable": true, 2616 | "hidden": false, 2617 | "notice": false, 2618 | "now": true, 2619 | "refresh_intervals": [ 2620 | "5s", 2621 | "10s", 2622 | "30s", 2623 | "1m", 2624 | "5m", 2625 | "15m", 2626 | "30m", 2627 | "1h", 2628 | "2h", 2629 | "1d" 2630 | ], 2631 | "status": "Stable", 2632 | "time_options": [ 2633 | "5m", 2634 | "15m", 2635 | "1h", 2636 | "6h", 2637 | "12h", 2638 | "24h", 2639 | "2d", 2640 | "7d", 2641 | "30d" 2642 | ], 2643 | "type": "timepicker" 2644 | }, 2645 | "timezone": "browser", 2646 | "title": "Statistic Analysis", 2647 | "uid": "Sfdh-iXmz", 2648 | "version": 9 2649 | } -------------------------------------------------------------------------------- /check_max_int.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # Daniel Guzman Burgos 4 | # daniel.guzman.burgos@percona.com 5 | # 6 | 7 | readonly tinyint=127 8 | readonly tinyint_unsigned=255 9 | readonly smallint=32767 10 | readonly smallint_unsigned=65535 11 | readonly mediumint=8388607 12 | readonly mediumint_unsigned=16777215 13 | readonly int=2147483647 14 | readonly int_unsigned=4294967295 15 | readonly bigint=9223372036854775807 16 | readonly bigint_unsigned=18446744073709551615 17 | 18 | # critical percentage 19 | readonly threshold=90 20 | 21 | tempDbFile="/tmp/dbs.txt" 22 | 23 | function destructor () { 24 | rm -f $tempDbFile 25 | } 26 | 27 | #trap destructor EXIT INT TERM 28 | 29 | function getLimitValue() { 30 | limitvalue_tinyint=$(echo "scale=0; $tinyint * $threshold/100" | bc) 31 | limitvalue_tinyint_unsigned=$(echo "scale=0; $tinyint_unsigned * $threshold/100" | bc) 32 | limitvalue_smallint=$(echo "scale=0; $smallint * $threshold/100" | bc) 33 | limitvalue_smallint_unsigned=$(echo "scale=0; $smallint_unsigned * $threshold/100" | bc) 34 | limitvalue_mediumint=$(echo "scale=0; $mediumint * $threshold/100" | bc) 35 | limitvalue_mediumint_unsigned=$(echo "scale=0; $mediumint_unsigned * $threshold/100" | bc) 36 | limitvalue_int=$(echo "scale=0; $int * $threshold/100" | bc) 37 | limitvalue_int_unsigned=$(echo "scale=0; $int_unsigned * $threshold/100" | bc) 38 | } 39 | 40 | function noIS () { 41 | mysql -A -N -e"show databases" | egrep -vi "information_schema|mysql|performance_schema" > $tempDbFile 42 | 43 | for k in $(cat $tempDbFile); do 44 | for j in $(mysql -N -e"show tables from $k"); do 45 | 46 | fieldData="" 47 | fieldData=$(mysql -A -N -e"show create table ${k}.${j}\G" | grep -i auto_increment | head -n1) 48 | if [[ "$fieldData" == "" || "$fieldData" == "NULL" ]]; then 49 | continue 50 | fi 51 | 52 | fieldName=$(echo $fieldData | awk '{print $1}') 53 | inttype=$(echo $fieldData | awk '{print $2}' | awk -F\( '{print $1}') 54 | 55 | if [[ $fieldData == *"unsigned"* ]]; then 56 | inttype=${inttype}_unsigned 57 | fi 58 | 59 | i="SELECT MAX($fieldName) FROM \`${k}\`.\`${j}\`;" 60 | out=$(mysql -N -e"$i") 61 | value=$(echo $out | awk '{print $1}') 62 | 63 | #Table empty 64 | if [ "$value" == "NULL" ]; then 65 | continue; 66 | fi 67 | 68 | chechIntMax 69 | 70 | done 71 | done 72 | } 73 | 74 | function withIS () { 75 | QUERY="SELECT 76 | CONCAT(\"SELECT MAX(\`\",COLUMN_NAME,\"\`), '\",COLUMN_TYPE,\"' FROM \`\",COLUMNS.TABLE_SCHEMA,\"\`.\`\",TABLE_NAME,\"\`;\") 77 | FROM 78 | INFORMATION_SCHEMA.COLUMNS 79 | INNER JOIN INFORMATION_SCHEMA.TABLES using(TABLE_NAME) 80 | WHERE TABLES.ENGINE IN ('innodb','myisam') 81 | AND COLUMNS.EXTRA = 'auto_increment';" 82 | 83 | IFS=' 84 | ' 85 | 86 | for i in $(mysql -N -e"$QUERY"); do 87 | out=$(mysql -N -e"$i") 88 | value=$(echo $out | awk '{print $1}') 89 | inttype=$(echo $out | awk '{print $2}' | awk -F\( '{print $1}') 90 | 91 | #Table empty 92 | if [ "$value" == "NULL" ]; then 93 | continue; 94 | fi 95 | 96 | # Unsigned used 97 | if [[ $out == *"unsigned"* ]]; then 98 | inttype=${inttype}_unsigned 99 | fi 100 | 101 | chechIntMax 102 | 103 | done 104 | 105 | } 106 | 107 | function chechIntMax () { 108 | maxvalue=$(eval echo \$$inttype) 109 | 110 | # Bigint unsigned is already the biggest value so no need to check 111 | if [[ "$inttype" == "bigint_unsigned" || "$inttype" == "bigint" ]]; then 112 | #Bigint signed is verified by the amount of digits in the max value 113 | if [ "$inttype" == "bigint" ]; then 114 | digits=$(echo ${#value}) 115 | if [ $digits -gt 17 ]; then 116 | echo "AUTO INC value ($value) close to exhaustion (Max Value: $maxvalue) $i" 117 | fi 118 | fi; 119 | continue; 120 | fi 121 | 122 | limitvalue=$(eval echo "limitvalue_$inttype") 123 | limitvalue=$(eval echo \$$limitvalue) 124 | 125 | if [ $value -gt $limitvalue ]; then 126 | echo "AUTO INC value ($value) close to exhaustion (Max Value: $maxvalue) $i" 127 | fi 128 | } 129 | 130 | getLimitValue 131 | 132 | if [[ "$1" == "I_S" || "$1" == "i_s" ]]; then 133 | withIS 134 | else 135 | noIS 136 | fi 137 | -------------------------------------------------------------------------------- /collectdata.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | query="set session group_concat_max_len=2048; select concat(digest_text,'dash', round(sum_timer_wait/ 1000000000000, 6),'\n') from performance_schema.events_statements_summary_by_digest order by sum_timer_wait desc limit 20;" 3 | IFS=" 4 | " 5 | for i in $(mysql -Nr -e"$query"); do 6 | digest=$(echo ${i%%dash*}) 7 | digest=${digest%%,*} 8 | digest=$(echo $digest | tr -d "\`") 9 | digest=$(echo $digest | tr " " "_") 10 | digest=$(echo $digest | tr -d "?") 11 | digest=$(echo $digest | tr "." "-") 12 | digest=$(echo $digest | tr "(" "_") 13 | digest=$(echo $digest | tr ")" "_") 14 | value=$(echo ${i##*dash}) 15 | echo "mysql.rds.$digest $value $(date +%s)" | nc -w 1 localhost 2003 16 | done 17 | -------------------------------------------------------------------------------- /get_history_long.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | clear 4 | counter=0 5 | SLOW_LOG_CUSTOM=/root/log.out 6 | rm -f $SLOW_LOG_CUSTOM 7 | 8 | while true; do 9 | 10 | THREADS=$(mysql -N -e"SELECT t.thread_id FROM performance_schema.events_statements_history inner join performance_schema.threads t where t.PROCESSLIST_ID != connection_id() group by thread_id;") 11 | if [ $counter -eq 0 ]; then 12 | for k in $(echo $THREADS); do 13 | OLD_EVENT[$k]=0 14 | done 15 | fi 16 | counter=1 17 | 18 | for i in $(echo $THREADS); do 19 | MAX_EVENT=$(mysql -N -e"SELECT IFNULL(max(event_id),0) FROM performance_schema.events_statements_history where thread_id = "$i) 20 | if [[ ! ${OLD_EVENT[$i]} ]]; then OLD_EVENT[$i]=0; fi 21 | if [ $MAX_EVENT -gt ${OLD_EVENT[$i]} ]; then 22 | SQL="SELECT CONCAT_WS( 23 | '','# Time: ', date_format(CURDATE(),'%y%m%d'),' ',TIME_FORMAT(NOW(6),'%H:%i:%s.%f'),'\n' 24 | ,'# User@Host: ',t.PROCESSLIST_USER,'[',t.PROCESSLIST_USER,'] @ ',PROCESSLIST_HOST,' [] Id: ',t.PROCESSLIST_ID,'\n' 25 | ,'# Schema: ',CURRENT_SCHEMA,' Last_errno: ',MYSQL_ERRNO,' ','\n' 26 | ,'# Query_time: ',ROUND(s.TIMER_WAIT / 1000000000000, 6),' Lock_time: ',ROUND(s.LOCK_TIME / 1000000000000, 6),' Rows_sent: ',ROWS_SENT,' Rows_examined: ',ROWS_EXAMINED,' Rows_affected: ',ROWS_AFFECTED,'\n' 27 | ,'# Tmp_tables: ',CREATED_TMP_TABLES,' Tmp_disk_tables: ',CREATED_TMP_DISK_TABLES,' ','\n' 28 | ,'# Full_scan: ',IF(SELECT_SCAN=0,'No','Yes'),' Full_join: ',IF(SELECT_FULL_JOIN=0,'No','Yes'),' Tmp_table: ',IF(CREATED_TMP_TABLES=0,'No','Yes'),' Tmp_table_on_disk: ',IF(CREATED_TMP_DISK_TABLES=0,'No','Yes'),'\n' 29 | , t.PROCESSLIST_INFO,';') FROM performance_schema.events_statements_history_long s inner join performance_schema.threads t using (thread_id) WHERE t.thread_id = "$i" AND EVENT_ID BETWEEN "${OLD_EVENT[$i]}" AND "$MAX_EVENT" ORDER BY TIMER_END desc;" 30 | #echo $SQL 31 | mysql -Nr -e"$SQL" >> $SLOW_LOG_CUSTOM 32 | unset OLD_EVENT[$i] 33 | OLD_EVENT[$i]=$(echo $MAX_EVENT) 34 | fi 35 | done 36 | done 37 | -------------------------------------------------------------------------------- /load_data.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # Load data to MySQL in a controlled way 4 | # Daniel Guzman Burgos 5 | # daniel.guzman.burgos@percona.com 6 | 7 | set -o pipefail 8 | 9 | readonly max_running_threads=10; 10 | readonly checkpoint_threshold_pct=70 11 | readonly fifoLines=1000 12 | readonly CHUNKS=8 13 | 14 | user=root 15 | database=sakila 16 | 17 | function destructor () { 18 | mysql -u$user -e"SET GLOBAL innodb_old_blocks_time = 0" 19 | } 20 | 21 | trap destructor INT TERM EXIT 22 | 23 | function getLogFileSize () { 24 | local SIZE=$(mysql -N -e"show variables like 'innodb_log_file_size'" | awk '{print $2}') 25 | local GROUP=$(mysql -N -e"show variables like 'innodb_log_files_in_group'" | awk '{print $2}') 26 | totalBytes=$(($SIZE*$GROUP)) 27 | } 28 | 29 | function getCheckPct () { 30 | chkckpointLimit=$(echo "${checkpoint_threshold_pct}/100*${totalBytes}" | bc -l | awk -F. '{print $1}') 31 | } 32 | 33 | function checkThreads () { 34 | local currentThreadsRunning=$(mysql -N -e"show global status like 'Threads_running'" | awk '{print $2}') 35 | while [ $currentThreadsRunning -gt $max_running_threads ]; do 36 | echo "Waiting until Threads_running go back to lower than $max_running_threads. Currently: $currentThreadsRunning ...."; 37 | sleep 1 38 | local currentThreadsRunning=$(mysql -N -e"show global status like 'Threads_running'" | awk '{print $2}') 39 | done 40 | } 41 | 42 | function monitorCheckpoint () { 43 | local currentCheckpoint=$(mysql -N -e"show status like 'Innodb_checkpoint_age'" | awk '{print $2}') 44 | while [ $currentCheckpoint -gt $chkckpointLimit ]; do 45 | echo "Waiting until checkpoint age becomes lower than $chkckpointLimit bytes. Currently $currentCheckpoint ...." 46 | sleep 1 47 | local currentCheckpoint=$(mysql -N -e"show status like 'Innodb_checkpoint_age'" | awk '{print $2}') 48 | done 49 | } 50 | 51 | function loadData () { 52 | 53 | if [ -z "$1" ]; then 54 | echo "Error: No file specified: ./load_data.sh \"/path/to/file\"" 55 | exit 1 56 | fi 57 | 58 | fifoFile=/tmp/dani_$2 59 | 60 | /usr/bin/pt-fifo-split --force --fifo $fifoFile --lines $fifoLines "$1" & 61 | sleep 1; 62 | 63 | mysql -u$user -e"SET GLOBAL innodb_old_blocks_time = 1000" 64 | while [ -p "$fifoFile" ]; do 65 | echo "Loading data from part $1 using fifo $fifoFile ..." 66 | cat $fifoFile | mysql -u$user $database 2>&1 67 | checkThreads 68 | monitorCheckpoint 69 | done 70 | mysql -u$user -e"SET GLOBAL innodb_old_blocks_time = 0" 71 | 72 | trap - INT TERM EXIT 73 | } 74 | 75 | function loadDataParallel () { 76 | 77 | clear 78 | 79 | if [ -z "$1" ]; then 80 | echo "Error: No file specified: ./load_data.sh \"/path/to/file\"" 81 | exit 1 82 | fi 83 | 84 | echo "Start to load data in parallel" 85 | 86 | DATAFILE=$1 87 | SPLITTED=/tmp/filepart 88 | 89 | local TTL=1 90 | local WATCHDOG_TIME=$((3600*$TTL)) 91 | 92 | /usr/bin/split --number=l/$CHUNKS --numeric-suffixes --suffix-length=1 $DATAFILE $SPLITTED 93 | mysql -u$user -e"SET GLOBAL innodb_old_blocks_time = 1000" 94 | 95 | for d in $(seq $CHUNKS) ; do 96 | echo "Launching $0 --single-load ${SPLITTED}$(($d-1)) $d" 97 | $0 --single-load "${SPLITTED}$(($d-1))" "$d" & 98 | pid[$d]=$! 99 | done 100 | 101 | WATCHDOG_INIT=$(date +%s) 102 | while [ "${#pid[@]}" -ne 0 ]; do 103 | count=0 104 | for p in $(echo ${pid[@]}); do 105 | kill -0 $p > /dev/null 2>&1 106 | if [ $? -ne 0 ]; then 107 | pid=(${pid[@]:0:$count} ${pid[@]:$(($count + 1))}) 108 | fi 109 | count=$(($count+1)) 110 | done 111 | 112 | WATCHDOG_NOW=$(date +%s) 113 | UPTIME=$(($WATCHDOG_NOW-$WATCHDOG_INIT)) 114 | 115 | if [ $UPTIME -ge $WATCHDOG_TIME ]; then 116 | echo "Timeout. ${TTL} hours running. Load data interrupted" 117 | exit 1 118 | fi 119 | 120 | sleep 1 121 | done 122 | 123 | } 124 | 125 | getLogFileSize 126 | getCheckPct 127 | checkThreads 128 | monitorCheckpoint 129 | 130 | if [ $1 == "--single-load" ]; then 131 | loadData "$2" "$3" 132 | exit 133 | fi 134 | 135 | loadDataParallel "$1" 136 | -------------------------------------------------------------------------------- /restoreToDev.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # Restore backups made with Percona XtraBackup tool 4 | # Daniel Guzman Burgos 5 | # 6 | 7 | clear 8 | 9 | set -o pipefail 10 | 11 | # Initial values 12 | 13 | lockFile="/var/lock/xtrabackup.lock" 14 | errorFile="/var/log/mysql/xtrabackup.err" 15 | logFile="/var/log/mysql/xtrabackup.log" 16 | mysqlUser=root 17 | mysqlPort=3306 18 | backupPath="${backupPath-"/root/backups/"}" 19 | restorePath="/var/lib/datadir" 20 | email="daniel.guzman.burgos@percona.com" 21 | 22 | # Function definitions 23 | 24 | function sendAlert () { 25 | if [ -e "$errorFile" ] 26 | then 27 | alertMsg=$(cat $errorFile) 28 | echo -e "${alertMsg}" | mailx -s "[$HOSTNAME] ALERT XtraBackup backup" "${email}" 29 | fi 30 | } 31 | 32 | function destructor () { 33 | sendAlert 34 | rm -f "$lockFile" "$errorFile" 35 | } 36 | 37 | # Setting TRAP in order to capture SIG and cleanup things 38 | trap destructor EXIT INT TERM 39 | 40 | function logInfo (){ 41 | echo "[$(date +%y%m%d-%H:%M:%S)] $1" >> $logFile 42 | } 43 | 44 | function verifyExecution () { 45 | local exitCode="$1" 46 | local mustDie=${3-:"false"} 47 | if [ $exitCode -ne "0" ] 48 | then 49 | msg="[ERROR] Failed execution. ${2}" 50 | echo "$msg" >> ${errorFile} 51 | logInfo "${msg}" 52 | if [ "$mustDie" == "true" ]; then 53 | exit 1 54 | else 55 | return 1 56 | fi 57 | fi 58 | return 0 59 | } 60 | 61 | function setLockFile () { 62 | if [ -e "$lockFile" ]; then 63 | trap - EXIT INT TERM 64 | verifyExecution "1" "Script already running. $lockFile exists" 65 | sendAlert 66 | rm -f "$errorFile" 67 | exit 2 68 | else 69 | touch "$lockFile" 70 | fi 71 | } 72 | 73 | function verifyXtrabackup () { 74 | which xtrabackup &> /dev/null 75 | verifyExecution "$?" "Cannot find xtrabackup tool" true 76 | logInfo "[OK] Found 'xtrabackup' bin" 77 | 78 | which innobackupex &> /dev/null 79 | verifyExecution "$?" "Cannot find innobackupex tool" true 80 | logInfo "[OK] Found 'innobackupex' bin" 81 | } 82 | 83 | function verifyMysqlBin () { 84 | which mysql &> /dev/null 85 | verifyExecution "$?" "Cannot find mysql bin" true 86 | logInfo "[OK] Found 'mysql' bin" 87 | } 88 | 89 | function verifyQpress () { 90 | which qpress &> /dev/null 91 | verifyExecution "$?" "Cannot find qpress tool" true 92 | logInfo "[OK] Found 'qpress' bin" 93 | } 94 | 95 | function verifySpace () { 96 | 97 | isCompress=0 98 | isCompact=0 99 | 100 | spaceOnDisk=$(df -P ${restorePath} | tail -1 | awk '{print $4*1024}') 101 | verifyExecution "$?" "Cannot find space available on disk $restorePath" true 102 | backupSize=$(du -sb $backupPath | awk '{print $1}') 103 | verifyExecution "$?" "Cannot find backup size for $backupPath" true 104 | type=$(file -bi $backupPath/xtrabackup_info* | head -n1) 105 | verifyExecution "$?" "Cannot find file $backupPath/xtrabackup_info. No way to find if is compressed or not. Space available might not be enough. Run at your own risk!" 106 | if [[ $type != *"text"* ]]; then 107 | verifyQpress 108 | logInfo "Compressed backup" 109 | backupSize=$(($backupSize*43)) 110 | isCompress=1 111 | fi 112 | out=$(cat $backupPath/xtrabackup_checkpoints | grep full-backuped) 113 | verifyExecution "$?" "Backup is not full backup." true 114 | out=$(cat $backupPath/xtrabackup_checkpoints | grep compact | grep 1) 115 | if [ $? -eq 0 ]; then 116 | logInfo "Compact backup" 117 | backupSize=$( printf "%.0f" $(echo $backupSize*1.02 | bc)) 118 | isCompact=1 119 | else 120 | logInfo "Regular full backup (not compressed, not compact)" 121 | fi 122 | 123 | percent=$(printf "%.0f" $(echo $spaceOnDisk*0.9 | bc)) 124 | if [ $backupSize -gt $percent ]; then 125 | verifyExecution "1" "Not enough space in disk for restore." true 126 | fi 127 | logInfo "Space available for restore." 128 | } 129 | 130 | function verifyBackupAvailable () { 131 | out=$(find $backupPath -maxdepth 1 -type f | grep xtrabackup_info) 132 | verifyExecution "$?" "Backup doesn't exists. $out" true 133 | logInfo "[OK] Found backup in $backupPath" 134 | } 135 | 136 | function verifyMemory () { 137 | memoryAvailable=$(free -b | grep Mem | awk '{print $4+$7}') 138 | percent=$(printf "%.0f" $(echo $memoryAvailable*0.8 | bc)) 139 | if [ $percent -lt 536870912 ]; then 140 | verifyExecution "1" "Not enough memory available to fire up a mysql instance" true 141 | fi 142 | logInfo "Memory available for restore" 143 | } 144 | 145 | function restoreBackup (){ 146 | 147 | logInfo "Enter restore backup function" 148 | mkdir -p $restorePath &> /dev/null 149 | rm -rf $restorePath/* &> /dev/null 150 | logInfo "Created directory $restorePath" 151 | restoreCommand="innobackupex --apply-log " 152 | 153 | if [ $isCompress -eq 1 ]; then 154 | logInfo "Backup compressed. Start to decompress: innobackupex --decompress $backupPath" 155 | out=$(innobackupex --decompress $backupPath 2>&1) 156 | verifyExecution "$?" "Failure while decompressing the backup. $out" true 157 | logInfo "Backup decompressed" 158 | elif [ $isCompact -eq 1 ]; then 159 | logIngo "Backup compact. Adding --rebuild-indexes parameter" 160 | restoreCommand="$restoreCommand --rebuild-indexes " 161 | fi 162 | 163 | logInfo "Preparing backup: $restoreCommand $backupPath" 164 | out=$($restoreCommand $backupPath 2>&1) 165 | verifyExecution "$?" "Failure while preparing backup. $out" true 166 | logInfo "Backup prepared" 167 | 168 | logInfo "Copy files to datadir: $restorePath" 169 | out=$(cp -R $backupPath/* $restorePath/ 2>&1) 170 | verifyExecution "$?" "Cannot copy files to $restorePath. $out" true 171 | logInfo "Files copied to datadir $restorePath" 172 | 173 | logInfo "Change owner of files to mysql" 174 | chown -R mysql:mysql $restorePath/ 175 | logInfo "Datadir owned by mysql (chown -R mysql:mysql $restorePath)/" 176 | } 177 | 178 | function verifyPortFree () { 179 | out=$(netstat -tpa | grep 3310) 180 | if [ $? -eq 0 ]; then 181 | verifyExecution "1" "Port 3310 busy. Shutdown stalled mysql instance in port 3310 and retry" true 182 | fi 183 | logInfo "Port 3310 available" 184 | } 185 | 186 | function launchMysql () { 187 | 188 | logInfo "Launching small instance of MySQL" 189 | sed -i '/innodb_fast_checksum/d' $restorePath/backup-my.cnf 190 | 191 | out=$($(which mysqld) --defaults-file=${restorePath}/backup-my.cnf --basedir=/usr --datadir=$restorePath --plugin-dir /usr/lib/mysql/plugin --user=mysql --log-error=${restorePath}/error.log --pid-file=${restorePath}/mysqld.pid --explicit_defaults_for_timestamp=true --socket=${restorePath}/mysqld.sock --port=3310 2>&1 &) 192 | verifyExecution "$?" "Cannot launch MySQL instance. $out. More info: ${restorePath}/error.log" true 193 | logInfo "MySQL instance launched: $(which mysqld) --defaults-file=${restorePath}/backup-my.cnf --basedir=/usr --datadir=$restorePath --plugin-dir /usr/lib/mysql/plugin --user=mysql --log-error=${restorePath}/error.log --pid-file=${restorePath}/mysqld.pid --explicit_defaults_for_timestamp=true --socket=${restorePath}/mysqld.sock --port=3310 2>&1" 194 | } 195 | 196 | function verify () { 197 | verifyXtrabackup 198 | verifyMysqlBin 199 | verifyBackupAvailable 200 | verifySpace 201 | verifyMemory 202 | } 203 | 204 | function sanitize () { 205 | echo "Here is where the magic happens" 206 | } 207 | 208 | function logicalBackup () { 209 | echo "Do the mysqldump" 210 | } 211 | 212 | function shutdownMysql () { 213 | sleep 10 #temporal 214 | mysqladmin --socket=${restorePath}/mysqld.sock shutdown 215 | logInfo "MySQL instance shutdown." 216 | } 217 | 218 | if [ -z "$1" ]; then 219 | msg="Backup path wasn't provided. Default path ($backupPath) will be used and most recent backup restored" 220 | logInfo "$msg" 221 | backupPath=$(find $backupPath -maxdepth 1 -type d | sort -nr | head -n1) 222 | logInfo "$backupPath will be restored" 223 | else 224 | backupPath=$(echo "$1") 225 | if [ ! -e $backupPath ]; then 226 | msg="$backupPath is not a file!" 227 | verifyExecution "1" "$msg" true 228 | echo $msg 229 | exit 1 230 | fi 231 | fi 232 | 233 | setLockFile 234 | verify 235 | restoreBackup 236 | launchMysql 237 | sanitize 238 | logicalBackup 239 | shutdownMysql 240 | -------------------------------------------------------------------------------- /split: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/nethalo/mysql-tools/8fec82fd4152137ff48ec477cb0891f573135976/split --------------------------------------------------------------------------------