Skip to content

Commit

Permalink
Bug#32855925 SELECT #2 WILL BE DISPLAYED TWICE WHEN WE EXPLAIN THE SQL
Browse files Browse the repository at this point in the history
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
  • Loading branch information
Jan Wedvik committed Sep 25, 2023
1 parent 42557a1 commit de131d1
Show file tree
Hide file tree
Showing 6 changed files with 185 additions and 15 deletions.
70 changes: 70 additions & 0 deletions mysql-test/r/explain_json_hypergraph.result
Original file line number Diff line number Diff line change
Expand Up @@ -963,3 +963,73 @@ EXPLAIN
Warnings:
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
DROP TABLE t1;
#
# Bug#34569685 No explain output for subquery
#
CREATE TABLE t1 (a INT PRIMARY KEY, b INT);
ANALYZE TABLE t1;
Table Op Msg_type Msg_text
test.t1 analyze status OK
EXPLAIN FORMAT=TREE SELECT LAST_VALUE((SELECT x1.a FROM t1))
OVER (PARTITION BY b) FROM t1 x1;
EXPLAIN
-> Window aggregate with buffering: last_value(`(select #2)`) OVER (PARTITION BY x1.b ) (...)
-> Sort: x1.b (...)
-> Table scan on x1 (...)
-> Select #2 (subquery in projection; dependent)
-> Table scan on t1 (...)

Warnings:
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
EXPLAIN FORMAT=JSON SELECT LAST_VALUE((SELECT x1.a FROM t1))
OVER (PARTITION BY b) FROM t1 x1;
EXPLAIN
{
"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`",
"inputs": [
{
"inputs": [
{
"operation": "Table scan on x1",
"table_name": "x1",
"access_type": "table",
"estimated_rows": 1.0,
"estimated_total_cost": 0.25,
"estimated_first_row_cost": 0.25
}
],
"operation": "Sort: x1.b",
"access_type": "sort",
"sort_fields": [
"x1.b"
],
"estimated_rows": 1.0,
"estimated_total_cost": 0.35,
"estimated_first_row_cost": 0.35
},
{
"heading": "Select #2 (subquery in projection; dependent)",
"subquery": true,
"dependent": true,
"operation": "Table scan on t1",
"table_name": "t1",
"access_type": "table",
"estimated_rows": 1.0,
"subquery_location": "projection",
"estimated_total_cost": 0.25,
"estimated_first_row_cost": 0.25
}
],
"buffering": true,
"functions": [
"last_value(`(select #2)`) OVER (PARTITION BY x1.b ) "
],
"operation": "Window aggregate with buffering: last_value(`(select #2)`) OVER (PARTITION BY x1.b ) ",
"access_type": "window",
"estimated_rows": 1.0,
"estimated_total_cost": 0.44999999999999996,
"estimated_first_row_cost": 0.44999999999999996
}
Warnings:
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
DROP TABLE t1;
19 changes: 19 additions & 0 deletions mysql-test/r/explain_tree.result
Original file line number Diff line number Diff line change
Expand Up @@ -1299,3 +1299,22 @@ EXPLAIN
Warnings:
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
DROP TABLE t1;
#
# Bug#34569685 No explain output for subquery
#
CREATE TABLE t1 (a INT PRIMARY KEY, b INT);
ANALYZE TABLE t1;
Table Op Msg_type Msg_text
test.t1 analyze status OK
EXPLAIN FORMAT=TREE SELECT LAST_VALUE((SELECT x1.a FROM t1))
OVER (PARTITION BY b) FROM t1 x1;
EXPLAIN
-> Window aggregate with buffering: last_value((select #2)) OVER (PARTITION BY x1.b )
-> Sort: x1.b (...)
-> Table scan on x1 (...)
-> Select #2 (subquery in projection; dependent)
-> Covering index scan on t1 using PRIMARY (...)

Warnings:
Note 1276 Field or reference 'test.x1.a' of SELECT #2 was resolved in SELECT #1
DROP TABLE t1;
3 changes: 0 additions & 3 deletions mysql-test/r/explain_tree_hypergraph.result
Original file line number Diff line number Diff line change
Expand Up @@ -97,9 +97,6 @@ EXPLAIN
-> Select #2 (subquery in condition; uncacheable)
-> Aggregate: max((x2.a + rand(0))) (cost=1.25..1.25 rows=1)
-> Table scan on x2 (cost=0.025..0.25 rows=10)
-> Select #2 (subquery in projection; uncacheable)
-> Aggregate: max((x2.a + rand(0))) (cost=1.25..1.25 rows=1)
-> Table scan on x2 (cost=0.025..0.25 rows=10)

DROP TABLE num,t1;
#
Expand Down
20 changes: 20 additions & 0 deletions mysql-test/t/explain_json_hypergraph.test
Original file line number Diff line number Diff line change
Expand Up @@ -193,3 +193,23 @@ SELECT * FROM t1 x1 JOIN t1 x2 ON x2.a<
--eval EXPLAIN FORMAT=JSON $query

DROP TABLE t1;


--echo #
--echo # Bug#34569685 No explain output for subquery
--echo #

CREATE TABLE t1 (a INT PRIMARY KEY, b INT);

ANALYZE TABLE t1;

let $query =
SELECT LAST_VALUE((SELECT x1.a FROM t1))
OVER (PARTITION BY b) FROM t1 x1;

--replace_regex $elide_costs_and_rows
--eval EXPLAIN FORMAT=TREE $query

--eval EXPLAIN FORMAT=JSON $query

DROP TABLE t1;
14 changes: 14 additions & 0 deletions mysql-test/t/explain_tree.test
Original file line number Diff line number Diff line change
Expand Up @@ -763,3 +763,17 @@ SELECT * FROM t1 x1 LEFT JOIN t1 x2 ON x2.a<
(SELECT MIN(x3.a) FROM t1 x3 WHERE x1.a=x3.a);

DROP TABLE t1;

--echo #
--echo # Bug#34569685 No explain output for subquery
--echo #

CREATE TABLE t1 (a INT PRIMARY KEY, b INT);

ANALYZE TABLE t1;

--replace_regex $elide_costs_and_rows
EXPLAIN FORMAT=TREE SELECT LAST_VALUE((SELECT x1.a FROM t1))
OVER (PARTITION BY b) FROM t1 x1;

DROP TABLE t1;
74 changes: 62 additions & 12 deletions sql/join_optimizer/explain_access_path.cc
Original file line number Diff line number Diff line change
Expand Up @@ -255,26 +255,49 @@ static bool AddSubqueryPaths(const Item *item_arg, const char *source_text,

qe->finalize(current_thd);
AccessPath *path;

if (qe->root_access_path() != nullptr) {
path = qe->root_access_path();
} else {
path = qe->item->root_access_path();
}
Json_object *child_obj = new (std::nothrow) Json_object();
if (child_obj == nullptr) return true;
// Populate the subquery-specific json fields.

bool error = false;
error |= AddMemberToObject<Json_boolean>(child_obj, "subquery", true);
error |= AddMemberToObject<Json_string>(child_obj, "subquery_location",
source_text);
if (query_block->is_dependent())
error |= AddMemberToObject<Json_boolean>(child_obj, "dependent", true);
if (query_block->is_cacheable())
error |= AddMemberToObject<Json_boolean>(child_obj, "cacheable", true);

children->push_back({path, description, query_block->join, child_obj});
// Add 'path' if not present in 'children' already.
if (std::none_of(children->cbegin(), children->cend(),
[path](const ExplainChild &existing) {
return existing.path == path;
})) {
char description[256];
if (query_block->is_dependent()) {
snprintf(description, sizeof(description),
"Select #%d (subquery in %s; dependent)",
query_block->select_number, source_text);
} else if (!query_block->is_cacheable()) {
snprintf(description, sizeof(description),
"Select #%d (subquery in %s; uncacheable)",
query_block->select_number, source_text);
} else {
snprintf(description, sizeof(description),
"Select #%d (subquery in %s; run only once)",
query_block->select_number, source_text);
}
Json_object *child_obj = new (std::nothrow) Json_object();
if (child_obj == nullptr) return true;
// Populate the subquery-specific json fields.
error |= AddMemberToObject<Json_boolean>(child_obj, "subquery", true);
error |= AddMemberToObject<Json_string>(child_obj, "subquery_location",
source_text);
if (query_block->is_dependent())
error |= AddMemberToObject<Json_boolean>(child_obj, "dependent", true);
if (query_block->is_cacheable())
error |= AddMemberToObject<Json_boolean>(child_obj, "cacheable", true);

children->push_back({path, description, query_block->join, child_obj});
}

return error != 0;
return error;
};

return WalkItem(item_arg, enum_walk::POSTFIX, add_subqueries);
Expand Down Expand Up @@ -1517,6 +1540,15 @@ static std::unique_ptr<Json_object> SetObjectMembers(
error |= obj->add_alias("functions", std::move(funcs));
error |= AddMemberToObject<Json_string>(obj, "access_type", "window");
children->push_back({path->window().child});
// temp_table_param may be nullptr for secondary engine,
// see ExplainWindowForExternalExecutor in hypergraph_optimizer-t.cc.
if (path->window().temp_table_param != nullptr) {
for (const Func_ptr &func :
*path->window().temp_table_param->items_to_copy) {
AddSubqueryPaths(func.func(), "projection", children);
}
}

break;
}
case AccessPath::WEEDOUT: {
Expand Down Expand Up @@ -1746,6 +1778,24 @@ static std::unique_ptr<Json_object> ExplainAccessPath(
vector<ExplainChild> children_from_select;
if (GetAccessPathsFromSelectList(join, &children_from_select))
return nullptr;

// Return 'true' if 'children' contains an object with the same 'path'
// as 'sel_child'.
const auto in_children = [&children](const ExplainChild &sel_child) {
return std::any_of(children.cbegin(), children.cend(),
[sel_child](const ExplainChild &child) {
return sel_child.path == child.path;
});
};

// Remove objects from children_from_select where 'children' has
// an object with the same 'path', so that we do not print the same path
// twice.
children_from_select.erase(
std::remove_if(children_from_select.begin(), children_from_select.end(),
in_children),
children_from_select.end());

if (AddChildrenToObject(obj, children_from_select, join,
/*is_root_of_join*/ true,
"inputs_from_select_list"))
Expand Down

0 comments on commit de131d1

Please sign in to comment.