-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathExplain_optimizer_trace.sql
325 lines (295 loc) · 9.4 KB
/
Explain_optimizer_trace.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
/*##########################
# 16.11.2017 by [email protected]
# EXPLAIN How TO
#################################*/
--### let`s look @ explain
use world;
ALTER TABLE Country DROP index p;
EXPLAIN FORMAT=JSON
SELECT * FROM Country WHERE continent='Asia' and population > 5000000\G
##
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "53.80" ##<=== cost
},
"table": {
"table_name": "Country",
"access_type": "ALL", ## <== FULL TABLE Scan
"rows_examined_per_scan": 239, #Accessing all 239 rows in the table
"rows_produced_per_join": 11,
"filtered": "4.76",
"cost_info": {
"read_cost": "51.52",
"eval_cost": "2.28",
"prefix_cost": "53.80",
"data_read_per_join": "2K"
},
"used_columns": [ ## this is the select * ..
"Code",
"Name",
"Continent",
"Region",
"SurfaceArea",
"IndepYear",
"Population",
"LifeExpectancy",
"GNP",
"GNPOld",
"LocalName",
"GovernmentForm",
"HeadOfState",
"Capital",
"Code2"
],
"attached_condition": "((`world`.`country`.`Continent` = 'Asia') and (`world`.`country`.`Population` > 5000000))" ## filter will be applied when reading the rows
}
}
}
--# adding index to population
ALTER TABLE Country ADD INDEX p (population);
EXPLAIN FORMAT=JSON
SELECT * FROM Country WHERE continent='Asia' and population > 5000000;
##
{
"query_block": {
"select_id": 1,
"cost_info": {
"query_cost": "53.80" ##<=== cost
},
"table": {
"table_name": "Country",
"access_type": "ALL", ## the optimizer select FTS but
"possible_keys": [ ## now we have possible_keys with the index p ...
"p" ##
],
"rows_examined_per_scan": 239,
"rows_produced_per_join": 15,
"filtered": "6.46",
"cost_info": {
"read_cost": "50.71",
"eval_cost": "3.09",
"prefix_cost": "53.80",
"data_read_per_join": "3K"
},
"used_columns": [
"Code",
"Name",
"Continent",
"Region",
"SurfaceArea",
"IndepYear",
"Population",
"LifeExpectancy",
"GNP",
"GNPOld",
"LocalName",
"GovernmentForm",
"HeadOfState",
"Capital",
"Code2"
],
"attached_condition": "((`world`.`country`.`Continent` = 'Asia') and (`world`.`country`.`Population` > 5000000))"
}
}
}
/*
#OPTIMIZER_TRACE
# lets enable optimizer trace*/
SET optimizer_trace_offset=-10, optimizer_trace_limit=10;
SET optimizer_trace="enabled=on";
--##run query
SELECT * FROM Country WHERE continent='Asia' and population > 5000000;
--## look @ table
SELECT * FROM information_schema.optimizer_trace;
--#
SET optimizer_trace="enabled=off";
##OPTIMIZER_TRACE showing why the index was not used
{
"steps": [
{
"join_preparation": {
"select#": 1,
"steps": [
{
"expanded_query": "/* select#1 */ select `country`.`Code` AS `Code`,`country`.`Name` AS `Name`,`country`.`Continent` AS `Continent`,`country`.`Region` AS `Region`,`country`.`SurfaceArea` AS `SurfaceArea`,`country`.`IndepYear` AS `IndepYear`,`country`.`Population` AS `Population`,`country`.`LifeExpectancy` AS `LifeExpectancy`,`country`.`GNP` AS `GNP`,`country`.`GNPOld` AS `GNPOld`,`country`.`LocalName` AS `LocalName`,`country`.`GovernmentForm` AS `GovernmentForm`,`country`.`HeadOfState` AS `HeadOfState`,`country`.`Capital` AS `Capital`,`country`.`Code2` AS `Code2` from `country` where ((`country`.`Continent` = 'Asia') and (`country`.`Population` > 5000000))"
}
]
}
},
{
"join_optimization": {
"select#": 1,
"steps": [
{
"condition_processing": {
"condition": "WHERE",
"original_condition": "((`country`.`Continent` = 'Asia') and (`country`.`Population` > 5000000))",
"steps": [
{
"transformation": "equality_propagation",
"resulting_condition": "((`country`.`Population` > 5000000) and multiple equal('Asia', `country`.`Continent`))"
},
{
"transformation": "constant_propagation",
"resulting_condition": "((`country`.`Population` > 5000000) and multiple equal('Asia', `country`.`Continent`))"
},
{
"transformation": "trivial_condition_removal",
"resulting_condition": "((`country`.`Population` > 5000000) and multiple equal('Asia', `country`.`Continent`))"
}
]
}
},
{
"substitute_generated_columns": {
}
},
{
"table_dependencies": [
{
"table": "`country`",
"row_may_be_null": false,
"map_bit": 0,
"depends_on_map_bits": [
]
}
]
},
{
"ref_optimizer_key_uses": [
]
},
{
"rows_estimation": [
{
"table": "`country`",
"range_analysis": {
"table_scan": {
"rows": 239,
"cost": 55.9
},
"potential_range_indexes": [
{
"index": "PRIMARY",
"usable": false,
"cause": "not_applicable"
},
{
"index": "p",
"usable": true,
"key_parts": [
"Population",
"Code"
]
}
],
"setup_range_conditions": [
],
"group_index_range": {
"chosen": false,
"cause": "not_group_by_or_distinct"
},
"analyzing_range_alternatives": {
"range_scan_alternatives": [
{
"index": "p", ## what if i use index ?
"ranges": [
"5000000 < Population"
],
"index_dives_for_eq_ranges": true,
"rowid_ordered": false,
"using_mrr": false,
"index_only": false,
"rows": 108,
"cost": 130.61, ## cost for using index
"chosen": false, ## can not use
"cause": "cost" ### cost to high
}
],
"analyzing_roworder_intersect": {
"usable": false, # Merging indexes is rejected
"cause": "too_few_roworder_scans"
}
}
}
}
]
},
{
"considered_execution_plans": [
{
"plan_prefix": [
],
"table": "`country`",
"best_access_path": {
"considered_access_paths": [
{
"rows_to_scan": 239,
"access_type": "scan",
"resulting_rows": 239,
"cost": 53.8,
"chosen": true
}
]
},
"condition_filtering_pct": 100,
"rows_for_plan": 239,
"cost_for_plan": 53.8,
"chosen": true
}
]
},
{
"attaching_conditions_to_tables": {
"original_condition": "((`country`.`Continent` = 'Asia') and (`country`.`Population` > 5000000))",
"attached_conditions_computation": [
],
"attached_conditions_summary": [
{
"table": "`country`",
"attached": "((`country`.`Continent` = 'Asia') and (`country`.`Population` > 5000000))"
}
]
}
},
{
"refine_plan": [
{
"table": "`country`"
}
]
}
]
}
},
{
"join_execution": {
"select#": 1,
"steps": [
]
}
}
]
}
--##
/*
The optimizer_search_depth variable tells how far into the “future” of each
incomplete plan the optimizer should look to evaluate whether it should be expanded further
If you are unsure of what a reasonable value is for optimizer_search_depth,
this variable can be set to 0 to tell the optimizer to determine the value automatically.
*/
select @@optimizer_search_depth;
--## cost
select * from mysql.server_cost;
--## change cost
--# Increase the cost from 0.2 to 1.0
UPDATE mysql.server_cost SET cost_value=1 WHERE cost_name='row_evaluate_cost';
FLUSH OPTIMIZER_COSTS;
--### in new session
EXPLAIN FORMAT=JSON
SELECT * FROM Country WHERE continent='Asia' and population > 5000000;
--# fix all
UPDATE mysql.server_cost SET cost_value=NULL WHERE cost_name='row_evaluate_cost';
FLUSH OPTIMIZER_COSTS;