Skip to content

Commit be04be8

Browse files
author
Dag Wanvik
committed
Bug#36625752 View with ORDER BY misses a row
As pointed out by the bug reporter, premature optimization leads us to lose information about the ORDER BY, so that when the view information is reparsed for use in a SELECT from the view, we see only an empty table and accordingly produce an empty result set. Without the view present, we see a single result row for an implicitly grouped query - as expected. The optimization removed the ORDER BY when resolving the query of the view, since it is redundant in the presence of a single row result set. Normally (when no view is involved) we keep the information that the query is implicitly grouped even though the ORDER BY is been optimized away. This is information lost for the view, hence the bug. Solution: defer the optimization when analyzing the view until we re-resolve it at view use time, i.e. we make sure the ORDER BY in the view's definition isn't optimized away. Change-Id: I22fd3d6a27aba9fb413748234f26667d2b1d9f87
1 parent b29f67b commit be04be8

File tree

4 files changed

+68
-3
lines changed

4 files changed

+68
-3
lines changed

mysql-test/r/group_by.result

Lines changed: 37 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4963,3 +4963,40 @@ SELECT (SELECT f1) FROM t1 GROUP BY f1 HAVING f1 < 1;
49634963
Warnings:
49644964
Warning 1052 Column 'f1' in group statement is ambiguous
49654965
DROP TABLE t1;
4966+
#
4967+
# Bug#36625752 View with ORDER BY misses a row
4968+
#
4969+
CREATE TABLE t1(c0 INT PRIMARY KEY);
4970+
# returns one row as expected
4971+
SELECT 1 FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0));
4972+
1
4973+
1
4974+
CREATE VIEW v AS SELECT 1 FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0));
4975+
# used to return zero rows
4976+
SELECT 1 AS one FROM v;
4977+
one
4978+
1
4979+
SHOW CREATE VIEW v;
4980+
View Create View character_set_client collation_connection
4981+
v CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v` AS select 1 AS `1` from `t1` order by count(0) OVER (PARTITION BY min(`t1`.`c0`) ) utf8mb4 utf8mb4_0900_ai_ci
4982+
DROP VIEW v;
4983+
# returns two rows as expected
4984+
(SELECT 1 AS one FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0)))
4985+
UNION ALL
4986+
(SELECT 1 FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0)));
4987+
one
4988+
1
4989+
1
4990+
CREATE VIEW v AS (SELECT 1 AS one FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0)))
4991+
UNION ALL
4992+
(SELECT 1 FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0)));
4993+
# used to return zero rows
4994+
SELECT v.one AS one FROM v;
4995+
one
4996+
1
4997+
1
4998+
SHOW CREATE VIEW v;
4999+
View Create View character_set_client collation_connection
5000+
v CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v` AS (select 1 AS `one` from `t1` order by count(0) OVER (PARTITION BY min(`t1`.`c0`) ) ) union all (select 1 AS `1` from `t1` order by count(0) OVER (PARTITION BY min(`t1`.`c0`) ) ) utf8mb4 utf8mb4_0900_ai_ci
5001+
DROP VIEW v;
5002+
DROP TABLE t1;

mysql-test/r/parser.result

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2512,7 +2512,7 @@ ERROR 42000: Multiple COLLATE clauses near 'COLLATE ascii_bin
25122512
CREATE VIEW v1 AS (SELECT 1 ORDER BY 1) UNION (SELECT 3 ORDER BY 1) ORDER BY 1;
25132513
SHOW CREATE VIEW v1;
25142514
View Create View character_set_client collation_connection
2515-
v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS select 1 AS `1` union select 3 AS `3` order by `1` utf8mb4 utf8mb4_0900_ai_ci
2515+
v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS (select 1 AS `1` order by '') union (select 3 AS `3` order by '') order by `1` utf8mb4 utf8mb4_0900_ai_ci
25162516
DROP VIEW v1;
25172517
#
25182518
# Bug#29871803: REQUIRED PARENTHESES NO LONGER PRINTED FOR CERTAIN UNION

mysql-test/t/group_by.test

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3638,3 +3638,31 @@ DROP TABLE product;
36383638
CREATE TABLE t1(f1 INTEGER);
36393639
SELECT (SELECT f1) FROM t1 GROUP BY f1 HAVING f1 < 1;
36403640
DROP TABLE t1;
3641+
3642+
--echo #
3643+
--echo # Bug#36625752 View with ORDER BY misses a row
3644+
--echo #
3645+
CREATE TABLE t1(c0 INT PRIMARY KEY);
3646+
let $query =
3647+
SELECT 1 FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0));
3648+
--echo # returns one row as expected
3649+
eval $query;
3650+
eval CREATE VIEW v AS $query;
3651+
--echo # used to return zero rows
3652+
SELECT 1 AS one FROM v;
3653+
SHOW CREATE VIEW v;
3654+
DROP VIEW v;
3655+
3656+
let $query=
3657+
(SELECT 1 AS one FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0)))
3658+
UNION ALL
3659+
(SELECT 1 FROM t1 ORDER BY COUNT(*) OVER (PARTITION BY MIN(t1.c0)));
3660+
--echo # returns two rows as expected
3661+
eval $query;
3662+
eval CREATE VIEW v AS $query;
3663+
--echo # used to return zero rows
3664+
SELECT v.one AS one FROM v;
3665+
SHOW CREATE VIEW v;
3666+
DROP VIEW v;
3667+
3668+
DROP TABLE t1;

sql/sql_resolver.cc

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -4529,7 +4529,7 @@ bool Query_block::check_only_full_group_by(THD *thd) {
45294529
*/
45304530
bool Query_block::setup_order_final(THD *thd) {
45314531
DBUG_TRACE;
4532-
if (is_implicitly_grouped()) {
4532+
if (is_implicitly_grouped() && !parent_lex->is_view_context_analysis()) {
45334533
// Result will contain zero or one row - ordering is redundant
45344534
return empty_order_list(this);
45354535
}
@@ -4538,7 +4538,7 @@ bool Query_block::setup_order_final(THD *thd) {
45384538
std::pair<bool, bool> result =
45394539
master_query_expression()->query_term()->redundant_order_by(this, 0);
45404540
assert(result.first); // that we found the block
4541-
if (result.second) {
4541+
if (result.second && !parent_lex->is_view_context_analysis()) {
45424542
// Part of set operation which requires global ordering may skip local
45434543
// order
45444544
if (empty_order_list(this)) return true;

0 commit comments

Comments
 (0)