Skip to content

Commit de131d1

Browse files
author
Jan Wedvik
committed
Bug#32855925 SELECT #2 WILL BE DISPLAYED TWICE WHEN WE EXPLAIN THE SQL
If the argument to a window function contains a subquery, the access path of that subquery would be printed twice when doing 'EXPLAIN FORMAT=TREE'. When using the Hypergraph optimizer, the subquery path was not printed at all, whether using FORMAT=TREE or FORMAT=JSON. This commit fixes this by ensuring that we ignore duplicate paths, and (for Hypergraph) by traversing the structures needed to find the relevant Item_subselect objects. Change-Id: I2abedcf690294f98ce169b74e53f042f46c47a45
1 parent 42557a1 commit de131d1

File tree

6 files changed

+185
-15
lines changed

6 files changed

+185
-15
lines changed

mysql-test/r/explain_json_hypergraph.result

Lines changed: 70 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -963,3 +963,73 @@ EXPLAIN
963963
Warnings:
964964
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
965965
DROP TABLE t1;
966+
#
967+
# Bug#34569685 No explain output for subquery
968+
#
969+
CREATE TABLE t1 (a INT PRIMARY KEY, b INT);
970+
ANALYZE TABLE t1;
971+
Table Op Msg_type Msg_text
972+
test.t1 analyze status OK
973+
EXPLAIN FORMAT=TREE SELECT LAST_VALUE((SELECT x1.a FROM t1))
974+
OVER (PARTITION BY b) FROM t1 x1;
975+
EXPLAIN
976+
-> Window aggregate with buffering: last_value(`(select #2)`) OVER (PARTITION BY x1.b ) (...)
977+
-> Sort: x1.b (...)
978+
-> Table scan on x1 (...)
979+
-> Select #2 (subquery in projection; dependent)
980+
-> Table scan on t1 (...)
981+
982+
Warnings:
983+
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
984+
EXPLAIN FORMAT=JSON SELECT LAST_VALUE((SELECT x1.a FROM t1))
985+
OVER (PARTITION BY b) FROM t1 x1;
986+
EXPLAIN
987+
{
988+
"query": "/* select#1 */ select last_value(`(select #2)`) OVER (PARTITION BY `test`.`x1`.`b` ) AS `LAST_VALUE((SELECT x1.a FROM t1))\nOVER (PARTITION BY b)` from `test`.`t1` `x1`",
989+
"inputs": [
990+
{
991+
"inputs": [
992+
{
993+
"operation": "Table scan on x1",
994+
"table_name": "x1",
995+
"access_type": "table",
996+
"estimated_rows": 1.0,
997+
"estimated_total_cost": 0.25,
998+
"estimated_first_row_cost": 0.25
999+
}
1000+
],
1001+
"operation": "Sort: x1.b",
1002+
"access_type": "sort",
1003+
"sort_fields": [
1004+
"x1.b"
1005+
],
1006+
"estimated_rows": 1.0,
1007+
"estimated_total_cost": 0.35,
1008+
"estimated_first_row_cost": 0.35
1009+
},
1010+
{
1011+
"heading": "Select #2 (subquery in projection; dependent)",
1012+
"subquery": true,
1013+
"dependent": true,
1014+
"operation": "Table scan on t1",
1015+
"table_name": "t1",
1016+
"access_type": "table",
1017+
"estimated_rows": 1.0,
1018+
"subquery_location": "projection",
1019+
"estimated_total_cost": 0.25,
1020+
"estimated_first_row_cost": 0.25
1021+
}
1022+
],
1023+
"buffering": true,
1024+
"functions": [
1025+
"last_value(`(select #2)`) OVER (PARTITION BY x1.b ) "
1026+
],
1027+
"operation": "Window aggregate with buffering: last_value(`(select #2)`) OVER (PARTITION BY x1.b ) ",
1028+
"access_type": "window",
1029+
"estimated_rows": 1.0,
1030+
"estimated_total_cost": 0.44999999999999996,
1031+
"estimated_first_row_cost": 0.44999999999999996
1032+
}
1033+
Warnings:
1034+
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
1035+
DROP TABLE t1;

mysql-test/r/explain_tree.result

Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1299,3 +1299,22 @@ EXPLAIN
12991299
Warnings:
13001300
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
13011301
DROP TABLE t1;
1302+
#
1303+
# Bug#34569685 No explain output for subquery
1304+
#
1305+
CREATE TABLE t1 (a INT PRIMARY KEY, b INT);
1306+
ANALYZE TABLE t1;
1307+
Table Op Msg_type Msg_text
1308+
test.t1 analyze status OK
1309+
EXPLAIN FORMAT=TREE SELECT LAST_VALUE((SELECT x1.a FROM t1))
1310+
OVER (PARTITION BY b) FROM t1 x1;
1311+
EXPLAIN
1312+
-> Window aggregate with buffering: last_value((select #2)) OVER (PARTITION BY x1.b )
1313+
-> Sort: x1.b (...)
1314+
-> Table scan on x1 (...)
1315+
-> Select #2 (subquery in projection; dependent)
1316+
-> Covering index scan on t1 using PRIMARY (...)
1317+
1318+
Warnings:
1319+
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
1320+
DROP TABLE t1;

mysql-test/r/explain_tree_hypergraph.result

Lines changed: 0 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -97,9 +97,6 @@ EXPLAIN
9797
-> Select #2 (subquery in condition; uncacheable)
9898
-> Aggregate: max((x2.a + rand(0))) (cost=1.25..1.25 rows=1)
9999
-> Table scan on x2 (cost=0.025..0.25 rows=10)
100-
-> Select #2 (subquery in projection; uncacheable)
101-
-> Aggregate: max((x2.a + rand(0))) (cost=1.25..1.25 rows=1)
102-
-> Table scan on x2 (cost=0.025..0.25 rows=10)
103100

104101
DROP TABLE num,t1;
105102
#

mysql-test/t/explain_json_hypergraph.test

Lines changed: 20 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -193,3 +193,23 @@ SELECT * FROM t1 x1 JOIN t1 x2 ON x2.a<
193193
--eval EXPLAIN FORMAT=JSON $query
194194

195195
DROP TABLE t1;
196+
197+
198+
--echo #
199+
--echo # Bug#34569685 No explain output for subquery
200+
--echo #
201+
202+
CREATE TABLE t1 (a INT PRIMARY KEY, b INT);
203+
204+
ANALYZE TABLE t1;
205+
206+
let $query =
207+
SELECT LAST_VALUE((SELECT x1.a FROM t1))
208+
OVER (PARTITION BY b) FROM t1 x1;
209+
210+
--replace_regex $elide_costs_and_rows
211+
--eval EXPLAIN FORMAT=TREE $query
212+
213+
--eval EXPLAIN FORMAT=JSON $query
214+
215+
DROP TABLE t1;

mysql-test/t/explain_tree.test

Lines changed: 14 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -763,3 +763,17 @@ SELECT * FROM t1 x1 LEFT JOIN t1 x2 ON x2.a<
763763
(SELECT MIN(x3.a) FROM t1 x3 WHERE x1.a=x3.a);
764764

765765
DROP TABLE t1;
766+
767+
--echo #
768+
--echo # Bug#34569685 No explain output for subquery
769+
--echo #
770+
771+
CREATE TABLE t1 (a INT PRIMARY KEY, b INT);
772+
773+
ANALYZE TABLE t1;
774+
775+
--replace_regex $elide_costs_and_rows
776+
EXPLAIN FORMAT=TREE SELECT LAST_VALUE((SELECT x1.a FROM t1))
777+
OVER (PARTITION BY b) FROM t1 x1;
778+
779+
DROP TABLE t1;

sql/join_optimizer/explain_access_path.cc

Lines changed: 62 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -255,26 +255,49 @@ static bool AddSubqueryPaths(const Item *item_arg, const char *source_text,
255255

256256
qe->finalize(current_thd);
257257
AccessPath *path;
258+
258259
if (qe->root_access_path() != nullptr) {
259260
path = qe->root_access_path();
260261
} else {
261262
path = qe->item->root_access_path();
262263
}
263-
Json_object *child_obj = new (std::nothrow) Json_object();
264-
if (child_obj == nullptr) return true;
265-
// Populate the subquery-specific json fields.
264+
266265
bool error = false;
267-
error |= AddMemberToObject<Json_boolean>(child_obj, "subquery", true);
268-
error |= AddMemberToObject<Json_string>(child_obj, "subquery_location",
269-
source_text);
270-
if (query_block->is_dependent())
271-
error |= AddMemberToObject<Json_boolean>(child_obj, "dependent", true);
272-
if (query_block->is_cacheable())
273-
error |= AddMemberToObject<Json_boolean>(child_obj, "cacheable", true);
274266

275-
children->push_back({path, description, query_block->join, child_obj});
267+
// Add 'path' if not present in 'children' already.
268+
if (std::none_of(children->cbegin(), children->cend(),
269+
[path](const ExplainChild &existing) {
270+
return existing.path == path;
271+
})) {
272+
char description[256];
273+
if (query_block->is_dependent()) {
274+
snprintf(description, sizeof(description),
275+
"Select #%d (subquery in %s; dependent)",
276+
query_block->select_number, source_text);
277+
} else if (!query_block->is_cacheable()) {
278+
snprintf(description, sizeof(description),
279+
"Select #%d (subquery in %s; uncacheable)",
280+
query_block->select_number, source_text);
281+
} else {
282+
snprintf(description, sizeof(description),
283+
"Select #%d (subquery in %s; run only once)",
284+
query_block->select_number, source_text);
285+
}
286+
Json_object *child_obj = new (std::nothrow) Json_object();
287+
if (child_obj == nullptr) return true;
288+
// Populate the subquery-specific json fields.
289+
error |= AddMemberToObject<Json_boolean>(child_obj, "subquery", true);
290+
error |= AddMemberToObject<Json_string>(child_obj, "subquery_location",
291+
source_text);
292+
if (query_block->is_dependent())
293+
error |= AddMemberToObject<Json_boolean>(child_obj, "dependent", true);
294+
if (query_block->is_cacheable())
295+
error |= AddMemberToObject<Json_boolean>(child_obj, "cacheable", true);
296+
297+
children->push_back({path, description, query_block->join, child_obj});
298+
}
276299

277-
return error != 0;
300+
return error;
278301
};
279302

280303
return WalkItem(item_arg, enum_walk::POSTFIX, add_subqueries);
@@ -1517,6 +1540,15 @@ static std::unique_ptr<Json_object> SetObjectMembers(
15171540
error |= obj->add_alias("functions", std::move(funcs));
15181541
error |= AddMemberToObject<Json_string>(obj, "access_type", "window");
15191542
children->push_back({path->window().child});
1543+
// temp_table_param may be nullptr for secondary engine,
1544+
// see ExplainWindowForExternalExecutor in hypergraph_optimizer-t.cc.
1545+
if (path->window().temp_table_param != nullptr) {
1546+
for (const Func_ptr &func :
1547+
*path->window().temp_table_param->items_to_copy) {
1548+
AddSubqueryPaths(func.func(), "projection", children);
1549+
}
1550+
}
1551+
15201552
break;
15211553
}
15221554
case AccessPath::WEEDOUT: {
@@ -1746,6 +1778,24 @@ static std::unique_ptr<Json_object> ExplainAccessPath(
17461778
vector<ExplainChild> children_from_select;
17471779
if (GetAccessPathsFromSelectList(join, &children_from_select))
17481780
return nullptr;
1781+
1782+
// Return 'true' if 'children' contains an object with the same 'path'
1783+
// as 'sel_child'.
1784+
const auto in_children = [&children](const ExplainChild &sel_child) {
1785+
return std::any_of(children.cbegin(), children.cend(),
1786+
[sel_child](const ExplainChild &child) {
1787+
return sel_child.path == child.path;
1788+
});
1789+
};
1790+
1791+
// Remove objects from children_from_select where 'children' has
1792+
// an object with the same 'path', so that we do not print the same path
1793+
// twice.
1794+
children_from_select.erase(
1795+
std::remove_if(children_from_select.begin(), children_from_select.end(),
1796+
in_children),
1797+
children_from_select.end());
1798+
17491799
if (AddChildrenToObject(obj, children_from_select, join,
17501800
/*is_root_of_join*/ true,
17511801
"inputs_from_select_list"))

0 commit comments

Comments
 (0)