Skip to content

Instantly share code, notes, and snippets.

@mdcallag
Last active November 5, 2020 21:24
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save mdcallag/cf62a30505dc80de5911371e7b2a8954 to your computer and use it in GitHub Desktop.
Save mdcallag/cf62a30505dc80de5911371e7b2a8954 to your computer and use it in GitHub Desktop.
explain
SELECT * FROM tags, LATERAL (SELECT * FROM cpu WHERE cpu.tags_id = tags.id ORDER BY time DESC LIMIT 1) as lp ORDER by tags.hostname, lp.time DESC
Query takes 84+ seconds, examines 300 rows?
# Time: 2020-11-05T20:12:25.702338Z
# User@Host: root[root] @ localhost [] Id: 41
# Query_time: 84.049762 Lock_time: 0.000119 Rows_sent: 100 Rows_examined: 300
SET timestamp=1604607061;
SELECT * FROM tags, LATERAL (SELECT * FROM cpu WHERE cpu.tags_id = tags.id ORDER BY time DESC LIMIT 1) as lp ORDER by tags.hostname, lp.time DESC;
The slow plan == 60+ seconds
EXPLAIN: -> Sort: tags.hostname, lp.`time` DESC
-> Stream results (cost=1062.02 rows=100)
-> Nested loop inner join (cost=1062.02 rows=100)
-> Invalidate materialized tables (row from tags) (cost=11.00 rows=100)
-> Index scan on tags using uniq1 (cost=11.00 rows=100)
-> Table scan on lp (cost=10.41 rows=2)
-> Materialize (invalidate on row from tags) (cost=788.32 rows=1)
-> Limit: 1 row(s) (cost=788.32 rows=1)
-> Sort: `cpu`.`time` DESC, limit input to 1 row(s) per chunk (cost=788.32 rows=743)
-> Index lookup on cpu using six (tags_id=tags.id)
The fast plan == < 1 second
EXPLAIN: -> Sort: tags.hostname, lp.`time` DESC
-> Stream results (cost=65666.35 rows=100)
-> Nested loop inner join (cost=65666.35 rows=100)
-> Invalidate materialized tables (row from tags) (cost=10.25 rows=100)
-> Index scan on tags using uniq1 (cost=10.25 rows=100)
-> Table scan on lp (cost=656.46 rows=2)
-> Materialize (invalidate on row from tags) (cost=10.00 rows=1)
-> Limit: 1 row(s) (cost=10.00 rows=1)
-> Filter: (`cpu`.tags_id = tags.id) (cost=10.00 rows=10)
-> Index scan on cpu using PRIMARY (cost=10.00 rows=100)
Fast plan via hint = < 1 second
explain format=tree SELECT * FROM tags, LATERAL (SELECT /*+ index(cpu PRIMARY) */ * FROM cpu WHERE cpu.tags_id = tags.id ORDER BY time DESC LIMIT 1) as lp ORDER by tags.hostname, lp.time DESC
| -> Sort: tags.hostname, lp.`time` DESC
-> Stream results (cost=8408800.70 rows=10)
-> Nested loop inner join (cost=8408800.70 rows=10)
-> Invalidate materialized tables (row from tags) (cost=11.00 rows=100)
-> Index scan on tags using uniq1 (cost=11.00 rows=100)
-> Table scan on lp (cost=84087.89 rows=2)
-> Materialize (invalidate on row from tags) (cost=0.25 rows=0)
-> Limit: 1 row(s) (cost=0.25 rows=0)
-> Filter: (`cpu`.tags_id = tags.id) (cost=0.25 rows=0)
-> Index scan on cpu using PRIMARY (reverse) (cost=0.25 rows=1)
The tables:
| cpu | CREATE TABLE `cpu` (
`time` timestamp NOT NULL,
`tags_id` bigint NOT NULL,
`additional_tags` varchar(256) DEFAULT NULL,
`usage_user` double NOT NULL,
`usage_system` double NOT NULL,
`usage_idle` double NOT NULL,
`usage_nice` double NOT NULL,
`usage_iowait` double NOT NULL,
`usage_irq` double NOT NULL,
`usage_softirq` double NOT NULL,
`usage_steal` double NOT NULL,
`usage_guest` double NOT NULL,
`usage_guest_nice` double DEFAULT NULL,
PRIMARY KEY (`time` DESC,`tags_id`),
KEY `six` (`tags_id`,`time` DESC)
) ENGINE=InnoDB DEFAULT CHARSET=latin1
| tags | CREATE TABLE `tags` (
`id` bigint NOT NULL,
`hostname` varchar(256) DEFAULT NULL,
`region` varchar(256) DEFAULT NULL,
`datacenter` varchar(256) DEFAULT NULL,
`rack` varchar(256) DEFAULT NULL,
`os` varchar(256) DEFAULT NULL,
`arch` varchar(256) DEFAULT NULL,
`team` varchar(256) DEFAULT NULL,
`service` varchar(256) DEFAULT NULL,
`service_version` varchar(256) DEFAULT NULL,
`service_environment` varchar(256) DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `uniq1` (`hostname`,`region`,`datacenter`,`rack`,`os`,`arch`,`team`,`service`,`service_version`,`service_environment`),
KEY `xhost` (`hostname`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1 |
show table status
--------------
*************************** 1. row ***************************
Name: cpu
Engine: InnoDB
Version: 10
Row_format: Dynamic
Rows: 25125052
Avg_row_length: 208
Data_length: 5249171456
Max_data_length: 0
Index_length: 667942912
Data_free: 4194304
Auto_increment: NULL
Create_time: 2020-11-05 12:21:10
Update_time: 2020-11-04 20:30:54
Check_time: NULL
Collation: latin1_swedish_ci
Checksum: NULL
Create_options:
Comment:
*************************** 2. row ***************************
Name: tags
Engine: InnoDB
Version: 10
Row_format: Dynamic
Rows: 100
Avg_row_length: 163
Data_length: 16384
Max_data_length: 0
Index_length: 32768
Data_free: 0
Auto_increment: NULL
Create_time: 2020-11-04 20:14:06
Update_time: 2020-11-04 20:14:06
Check_time: NULL
Collation: latin1_swedish_ci
Checksum: NULL
Create_options:
Comment:
2 rows in set (0.02 sec)
| explain format=tree SELECT * FROM tags, LATERAL (SELECT * FROM cpu WHERE cpu.tags_id = tags.id ORDER BY time DESC LIMIT 1) as lp ORDER by tags.hostname, lp.time DESC | {
"steps": [
{
"join_preparation": {
"select#": 1,
"steps": [
{
"join_preparation": {
"select#": 2,
"steps": [
{
"expanded_query": "/* select#2 */ select `cpu`.`time` AS `time`,`cpu`.`tags_id` AS `tags_id`,`cpu`.`additional_tags` AS `additional_tags`,`cpu`.`usage_user` AS `usage_user`,`cpu`.`usage_system` AS `usage_system`,`cpu`.`usage_idle` AS `usage_idle`,`cpu`.`usage_nice` AS `usage_nice`,`cpu`.`usage_iowait` AS `usage_iowait`,`cpu`.`usage_irq` AS `usage_irq`,`cpu`.`usage_softirq` AS `usage_softirq`,`cpu`.`usage_steal` AS `usage_steal`,`cpu`.`usage_guest` AS `usage_guest`,`cpu`.`usage_guest_nice` AS `usage_guest_nice` from `cpu` where (`cpu`.`tags_id` = `tags`.`id`) order by `cpu`.`time` desc limit 1"
}
]
}
},
{
"derived": {
"table": " `lp`",
"select#": 2,
"materialized": true
}
},
{
"expanded_query": "/* select#1 */ select `tags`.`id` AS `id`,`tags`.`hostname` AS `hostname`,`tags`.`region` AS `region`,`tags`.`datacenter` AS `datacenter`,`tags`.`rack` AS `rack`,`tags`.`os` AS `os`,`tags`.`arch` AS `arch`,`tags`.`team` AS `team`,`tags`.`service` AS `service`,`tags`.`service_version` AS `service_version`,`tags`.`service_environment` AS `service_environment`,`lp`.`time` AS `time`,`lp`.`tags_id` AS `tags_id`,`lp`.`additional_tags` AS `additional_tags`,`lp`.`usage_user` AS `usage_user`,`lp`.`usage_system` AS `usage_system`,`lp`.`usage_idle` AS `usage_idle`,`lp`.`usage_nice` AS `usage_nice`,`lp`.`usage_iowait` AS `usage_iowait`,`lp`.`usage_irq` AS `usage_irq`,`lp`.`usage_softirq` AS `usage_softirq`,`lp`.`usage_steal` AS `usage_steal`,`lp`.`usage_guest` AS `usage_guest`,`lp`.`usage_guest_nice` AS `usage_guest_nice` from `tags` join lateral (/* select#2 */ select `cpu`.`time` AS `time`,`cpu`.`tags_id` AS `tags_id`,`cpu`.`additional_tags` AS `additional_tags`,`cpu`.`usage_user` AS `usage_user`,`cpu`.`usage_system` AS `usage_system`,`cpu`.`usage_idle` AS `usage_idle`,`cpu`.`usage_nice` AS `usage_nice`,`cpu`.`usage_iowait` AS `usage_iowait`,`cpu`.`usage_irq` AS `usage_irq`,`cpu`.`usage_softirq` AS `usage_softirq`,`cpu`.`usage_steal` AS `usage_steal`,`cpu`.`usage_guest` AS `usage_guest`,`cpu`.`usage_guest_nice` AS `usage_guest_nice` from `cpu` where (`cpu`.`tags_id` = `tags`.`id`) order by `cpu`.`time` desc limit 1) `lp` order by `tags`.`hostname`,`lp`.`time` desc"
}
]
}
},
{
"join_optimization": {
"select#": 1,
"steps": [
{
"join_optimization": {
"select#": 2,
"steps": [
{
"condition_processing": {
"condition": "WHERE",
"original_condition": "(`cpu`.`tags_id` = `tags`.`id`)",
"steps": [
{
"transformation": "equality_propagation",
"resulting_condition": "(`cpu`.`tags_id` = `tags`.`id`)"
},
{
"transformation": "constant_propagation",
"resulting_condition": "(`cpu`.`tags_id` = `tags`.`id`)"
},
{
"transformation": "trivial_condition_removal",
"resulting_condition": "(`cpu`.`tags_id` = `tags`.`id`)"
}
]
}
},
{
"substitute_generated_columns": {
}
},
{
"table_dependencies": [
{
"table": "`cpu`",
"row_may_be_null": false,
"map_bit": 0,
"depends_on_map_bits": [
]
}
]
},
{
"ref_optimizer_key_uses": [
{
"table": "`cpu`",
"field": "tags_id",
"equals": "`tags`.`id`",
"null_rejecting": true
}
]
},
{
"rows_estimation": [
{
"table": "`cpu`",
"table_scan": {
"rows": 24017445,
"cost": 203710
}
}
]
},
{
"considered_execution_plans": [
{
"plan_prefix": [
],
"table": "`cpu`",
"best_access_path": {
"considered_access_paths": [
{
"access_type": "ref",
"index": "six",
"rows": 1023.5,
"cost": 1125.9,
"chosen": true
},
{
"access_type": "scan",
"cost": 2.61e6,
"rows": 24017445,
"chosen": false,
"cause": "cost"
}
]
},
"condition_filtering_pct": 100,
"rows_for_plan": 1023.5,
"cost_for_plan": 1125.9,
"chosen": true
}
]
},
{
"attaching_conditions_to_tables": {
"original_condition": "(`cpu`.`tags_id` = `tags`.`id`)",
"attached_conditions_computation": [
],
"attached_conditions_summary": [
{
"table": "`cpu`",
"attached": "(`cpu`.`tags_id` = `tags`.`id`)"
}
]
}
},
{
"optimizing_distinct_group_by_order_by": {
"simplifying_order_by": {
"original_clause": "`cpu`.`time` desc",
"items": [
{
"item": "`cpu`.`time`"
}
],
"resulting_clause_is_simple": true,
"resulting_clause": "`cpu`.`time` desc"
}
}
},
{
"reconsidering_access_paths_for_index_ordering": {
"clause": "ORDER BY",
"steps": [
],
"index_order_summary": {
"table": "`cpu`",
"index_provides_order": false,
"order_direction": "undefined",
"index": "six",
"plan_changed": false
}
}
},
{
"finalizing_table_conditions": [
{
"table": "`cpu`",
"original_table_condition": "(`cpu`.`tags_id` = `tags`.`id`)",
"final_table_condition ": null
}
]
},
{
"refine_plan": [
{
"table": "`cpu`"
}
]
},
{
"considering_tmp_tables": [
{
"adding_sort_to_table": "cpu"
}
]
}
]
}
},
{
"substitute_generated_columns": {
}
},
{
"table_dependencies": [
{
"table": "`tags`",
"row_may_be_null": false,
"map_bit": 0,
"depends_on_map_bits": [
]
},
{
"table": " `lp`",
"row_may_be_null": false,
"map_bit": 1,
"depends_on_map_bits": [
0
]
}
]
},
{
"rows_estimation": [
{
"table": "`tags`",
"table_scan": {
"rows": 100,
"cost": 1
}
},
{
"table": " `lp`",
"table_scan": {
"rows": 2,
"cost": 2.525
}
}
]
},
{
"considered_execution_plans": [
{
"plan_prefix": [
],
"table": "`tags`",
"best_access_path": {
"considered_access_paths": [
{
"rows_to_scan": 100,
"filtering_effect": [
],
"final_filtering_effect": 1,
"access_type": "scan",
"resulting_rows": 100,
"cost": 11,
"chosen": true
}
]
},
"condition_filtering_pct": 100,
"rows_for_plan": 100,
"cost_for_plan": 11,
"rest_of_plan": [
{
"plan_prefix": [
"`tags`"
],
"table": " `lp`",
"best_access_path": {
"considered_access_paths": [
{
"lateral_materialization": {
"cost_for_one_run_of_inner_query": 1125.9,
"cost_for_writing_to_tmp_table": 0.2,
"count_of_runs": 100,
"total_cost": 112609,
"cost_per_read": 1126.1
}
},
{
"rows_to_scan": 2,
"access_type": "scan",
"resulting_rows": 2,
"cost": 272.5,
"chosen": true
}
]
},
"condition_filtering_pct": 100,
"rows_for_plan": 200,
"cost_for_plan": 1409.6,
"chosen": true
}
]
}
]
},
{
"attaching_conditions_to_tables": {
"original_condition": null,
"attached_conditions_computation": [
],
"attached_conditions_summary": [
{
"table": "`tags`",
"attached": null
},
{
"table": " `lp`",
"attached": null
}
]
}
},
{
"optimizing_distinct_group_by_order_by": {
"simplifying_order_by": {
"original_clause": "`tags`.`hostname`,`lp`.`time` desc",
"items": [
{
"item": "`tags`.`hostname`"
},
{
"item": "`lp`.`time`"
}
],
"resulting_clause_is_simple": false,
"resulting_clause": "`tags`.`hostname`,`lp`.`time` desc"
}
}
},
{
"finalizing_table_conditions": [
]
},
{
"refine_plan": [
{
"table": "`tags`"
},
{
"table": " `lp`",
"rematerialized_for_each_row_of": "tags"
}
]
},
{
"considering_tmp_tables": [
{
"adding_tmp_table_in_plan_at_position": 2,
"write_method": "write_all_rows"
},
{
"adding_sort_to_table": ""
}
]
}
]
}
}
]
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment