From 5dee4a99d9bb30e5dfd5168384f8805047e403e4 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Fri, 26 Apr 2019 17:55:12 -0700 Subject: [PATCH] MDEV-19324 Wrong results from query, using brackets with ORDER BY ..LIMIT If a select query was of the form (SELECT ... ORDER BY ...) LIMIT ... then in most cases it returned incorrect result. It happened because SELECT ... ORDER BY ... was wrapped into a select with materialized derived table: SELECT ... ORDER BY ... => SELECT * FROM (SELECT ... ORDER BY ...) dt. Yet for any materialized derived table ORDER BY without LIMIT is ignored. This patch resolves the problem by the conversion (SELECT ... ORDER BY ...) LIMIT ... => SELECT ... ORDER BY ... LIMIT ... at the parser stage. Similarly ((SELECT ... UNION ...) ORDER BY ...) LIMIT ... is converted to (SELECT ... UNION ...) ORDER BY ... LIMIT ... This conversion optimizes execution of the query because the result of (SELECT ... UNION ...) ORDER BY ... is not materialized into a temporary table anymore. --- mysql-test/main/brackets.result | 150 ++++++++++++++++++++++++++++++++ mysql-test/main/brackets.test | 33 +++++++ sql/sql_lex.cc | 13 ++- 3 files changed, 194 insertions(+), 2 deletions(-) diff --git a/mysql-test/main/brackets.result b/mysql-test/main/brackets.result index e789cdeff76..3cf3468320f 100644 --- a/mysql-test/main/brackets.result +++ b/mysql-test/main/brackets.result @@ -243,4 +243,154 @@ a a 1 DROP TABLE t1,t2; +# +# MDEV-19324: ((SELECT ...) ORDER BY col ) LIMIT n +# +create table t1 (a int); +insert into t1 values (10),(20),(30); +select a from t1 order by a desc limit 1; +a +30 +explain extended select a from t1 order by a desc limit 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using filesort +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` order by `test`.`t1`.`a` desc limit 1 +explain format=json select a from t1 order by a desc limit 1; +EXPLAIN +{ + "query_block": { + "select_id": 1, + "read_sorted_file": { + "filesort": { + "sort_key": "t1.a desc", + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 3, + "filtered": 100 + } + } + } + } +} +(select a from t1 order by a desc) limit 1; +a +30 +explain extended (select a from t1 order by a desc) limit 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using filesort +Warnings: +Note 1003 (select `test`.`t1`.`a` AS `a` from `test`.`t1` order by `test`.`t1`.`a` desc limit 1) +explain format=json (select a from t1 order by a desc) limit 1; +EXPLAIN +{ + "query_block": { + "select_id": 1, + "read_sorted_file": { + "filesort": { + "sort_key": "t1.a desc", + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 3, + "filtered": 100 + } + } + } + } +} +(select a from t1 where a=20 union select a from t1) order by a desc limit 1; +a +30 +explain extended (select a from t1 where a=20 union select a from t1) order by a desc limit 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using where +2 UNION t1 ALL NULL NULL NULL NULL 3 100.00 +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL Using filesort +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` = 20 union /* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` order by `a` desc limit 1 +explain format=json (select a from t1 where a=20 union select a from t1) order by a desc limit 1; +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 3, + "filtered": 100, + "attached_condition": "t1.a = 20" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 3, + "filtered": 100 + } + } + } + ] + } + } +} +((select a from t1 where a=20 union select a from t1) order by a desc) limit 1; +a +30 +explain extended ((select a from t1 where a=20 union select a from t1) order by a desc) limit 1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using where +2 UNION t1 ALL NULL NULL NULL NULL 3 100.00 +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL Using filesort +Warnings: +Note 1003 (/* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` = 20) union /* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` order by `a` desc limit 1 +explain format=json ((select a from t1 where a=20 union select a from t1) order by a desc) limit 1; +EXPLAIN +{ + "query_block": { + "union_result": { + "table_name": "", + "access_type": "ALL", + "query_specifications": [ + { + "query_block": { + "select_id": 1, + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 3, + "filtered": 100, + "attached_condition": "t1.a = 20" + } + } + }, + { + "query_block": { + "select_id": 2, + "operation": "UNION", + "table": { + "table_name": "t1", + "access_type": "ALL", + "rows": 3, + "filtered": 100 + } + } + } + ] + } + } +} +drop table t1; # End of 10.4 tests diff --git a/mysql-test/main/brackets.test b/mysql-test/main/brackets.test index 0eaa3bfc0a2..54f7d2714a1 100644 --- a/mysql-test/main/brackets.test +++ b/mysql-test/main/brackets.test @@ -106,5 +106,38 @@ INSERT INTO t2 VALUES (4),(5),(6),(7); DROP TABLE t1,t2; +--echo # +--echo # MDEV-19324: ((SELECT ...) ORDER BY col ) LIMIT n +--echo # + +create table t1 (a int); +insert into t1 values (10),(20),(30); + +let $q1= +select a from t1 order by a desc limit 1; +eval $q1; +eval explain extended $q1; +eval explain format=json $q1; + +let $q2= +(select a from t1 order by a desc) limit 1; +eval $q2; +eval explain extended $q2; +eval explain format=json $q2; + +let $q1= +(select a from t1 where a=20 union select a from t1) order by a desc limit 1; +eval $q1; +eval explain extended $q1; +eval explain format=json $q1; + +let $q2= +((select a from t1 where a=20 union select a from t1) order by a desc) limit 1; +eval $q2; +eval explain extended $q2; +eval explain format=json $q2; + +drop table t1; + --echo # End of 10.4 tests diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 4a69e0bd1c7..66ac69fcc46 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -9129,7 +9129,13 @@ SELECT_LEX *LEX::parsed_select(SELECT_LEX *sel, Lex_order_limit_lock * l) l->set_to(unit->fake_select_lex); else { - sel= wrap_unit_into_derived(unit); + if (!l->order_list && !unit->fake_select_lex->explicit_limit) + { + sel= unit->fake_select_lex; + l->order_list= &sel->order_list; + } + else + sel= wrap_unit_into_derived(unit); if (!sel) return NULL; l->set_to(sel); @@ -9144,7 +9150,10 @@ SELECT_LEX *LEX::parsed_select(SELECT_LEX *sel, Lex_order_limit_lock * l) SELECT_LEX_UNIT *unit= create_unit(sel); if (!unit) return NULL; - sel= wrap_unit_into_derived(unit); + if (!l->order_list && !sel->explicit_limit) + l->order_list= &sel->order_list; + else + sel= wrap_unit_into_derived(unit); if (!sel) return NULL; l->set_to(sel);