Skip to content

Commit 3b07831

Browse files
author
Guilhem Bichot
committed
Bug#26556025 ASSERTION `!SELECT_LEX->IS_RECURSIVE() || !TMP_TABLES' FAILED.
With SQL_BUFFER_RESULT = 1 any recursive CTE would cause a server exit, with the debug binary. Because such setting makes need_tmp_before_win be true which forces the creation of a tmp table in JOIN::make_tmp_tables_info(), and the recursive query block shouldn't use such table as it introduces a layer of buffering which "cuts the recycling of rows". Fix: refined the setting of need_tmp_before_win; the CTE already uses a tmp table anyway. Also rewrote the conditions to an equivalent but hopefully easier block of code. Added minimal test for bug in with_recursive_bugs.test. Added a few tests in with_recursive.inc (their result is not influenced by the code fix; but as they relate to clauses which create tmp tables, I wanted to have coverage).
1 parent 67a9b82 commit 3b07831

File tree

5 files changed

+158
-30
lines changed

5 files changed

+158
-30
lines changed

mysql-test/include/with_recursive.inc

Lines changed: 16 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -78,6 +78,17 @@ with recursive qn as
7878
select max(a) from qn)
7979
select * from qn;
8080

81+
--echo # No GROUP BY
82+
with recursive qn as
83+
(select 1 as a from dual group by a union all
84+
select a+1 from qn where a<3)
85+
select * from qn;
86+
--error ER_CTE_RECURSIVE_FORBIDS_AGGREGATION
87+
with recursive qn as
88+
(select 1 as a from dual union all
89+
select a from qn group by a)
90+
select * from qn;
91+
8192
--echo # No subquery referencing a QN
8293
--error ER_CTE_RECURSIVE_REQUIRES_SINGLE_REFERENCE
8394
with recursive qn as (
@@ -106,13 +117,17 @@ select 1 as a from dual union all
106117
select 1 from qn
107118
order by a)
108119
select * from qn;
109-
110120
--echo # No matter if global, or attached to one recursive member.
111121
--error ER_NOT_SUPPORTED_YET
112122
with recursive qn as (
113123
select 1 as a from dual union all
114124
(select 1 from qn order by a))
115125
select * from qn;
126+
--echo # Allowed on non-recursive query block (though pointless)
127+
with recursive qn as (
128+
(select 1 as a from dual order by a) union all
129+
select a+1 from qn where a<3)
130+
select * from qn;
116131

117132
--echo # no LIMIT as it's not pushed down to UNION members
118133
--error ER_NOT_SUPPORTED_YET

mysql-test/r/with_recursive.result

Lines changed: 46 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -76,6 +76,20 @@ with recursive qn as
7676
select max(a) from qn)
7777
select * from qn;
7878
ERROR HY000: Recursive Common Table Expression 'qn' can contain neither aggregation nor window functions in recursive query block
79+
# No GROUP BY
80+
with recursive qn as
81+
(select 1 as a from dual group by a union all
82+
select a+1 from qn where a<3)
83+
select * from qn;
84+
a
85+
1
86+
2
87+
3
88+
with recursive qn as
89+
(select 1 as a from dual union all
90+
select a from qn group by a)
91+
select * from qn;
92+
ERROR HY000: Recursive Common Table Expression 'qn' can contain neither aggregation nor window functions in recursive query block
7993
# No subquery referencing a QN
8094
with recursive qn as (
8195
select 1 from dual union all
@@ -107,6 +121,15 @@ select 1 as a from dual union all
107121
(select 1 from qn order by a))
108122
select * from qn;
109123
ERROR 42000: This version of MySQL doesn't yet support 'ORDER BY / LIMIT / SELECT DISTINCT in recursive query block of Common Table Expression'
124+
# Allowed on non-recursive query block (though pointless)
125+
with recursive qn as (
126+
(select 1 as a from dual order by a) union all
127+
select a+1 from qn where a<3)
128+
select * from qn;
129+
a
130+
1
131+
2
132+
3
110133
# no LIMIT as it's not pushed down to UNION members
111134
with recursive qn as (
112135
select 1 as a from dual union all
@@ -1362,6 +1385,20 @@ with recursive qn as
13621385
select max(a) from qn)
13631386
select * from qn;
13641387
ERROR HY000: Recursive Common Table Expression 'qn' can contain neither aggregation nor window functions in recursive query block
1388+
# No GROUP BY
1389+
with recursive qn as
1390+
(select 1 as a from dual group by a union all
1391+
select a+1 from qn where a<3)
1392+
select * from qn;
1393+
a
1394+
1
1395+
2
1396+
3
1397+
with recursive qn as
1398+
(select 1 as a from dual union all
1399+
select a from qn group by a)
1400+
select * from qn;
1401+
ERROR HY000: Recursive Common Table Expression 'qn' can contain neither aggregation nor window functions in recursive query block
13651402
# No subquery referencing a QN
13661403
with recursive qn as (
13671404
select 1 from dual union all
@@ -1393,6 +1430,15 @@ select 1 as a from dual union all
13931430
(select 1 from qn order by a))
13941431
select * from qn;
13951432
ERROR 42000: This version of MySQL doesn't yet support 'ORDER BY / LIMIT / SELECT DISTINCT in recursive query block of Common Table Expression'
1433+
# Allowed on non-recursive query block (though pointless)
1434+
with recursive qn as (
1435+
(select 1 as a from dual order by a) union all
1436+
select a+1 from qn where a<3)
1437+
select * from qn;
1438+
a
1439+
1
1440+
2
1441+
3
13961442
# no LIMIT as it's not pushed down to UNION members
13971443
with recursive qn as (
13981444
select 1 as a from dual union all

mysql-test/r/with_recursive_bugs.result

Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -158,3 +158,22 @@ SELECT cte.field1 FROM cte
158158
SELECT * FROM cte;
159159
field1
160160
DROP TABLE BB,C,D;
161+
#
162+
# Bug#26556025 ASSERTION `!SELECT_LEX->IS_RECURSIVE() || !TMP_TABLES' FAILED.
163+
#
164+
SET SQL_BUFFER_RESULT = 1;
165+
WITH RECURSIVE cte AS
166+
(SELECT 1 AS n UNION SELECT n+1 FROM cte WHERE n<3)
167+
SELECT * FROM cte;
168+
n
169+
1
170+
2
171+
3
172+
WITH RECURSIVE cte AS
173+
(SELECT 1 AS n UNION ALL SELECT n+1 FROM cte WHERE n<3)
174+
SELECT * FROM cte;
175+
n
176+
1
177+
2
178+
3
179+
SET SQL_BUFFER_RESULT = DEFAULT;

mysql-test/t/with_recursive_bugs.test

Lines changed: 16 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -177,3 +177,19 @@ SELECT cte.field1 FROM cte
177177
SELECT * FROM cte;
178178

179179
DROP TABLE BB,C,D;
180+
181+
--echo #
182+
--echo # Bug#26556025 ASSERTION `!SELECT_LEX->IS_RECURSIVE() || !TMP_TABLES' FAILED.
183+
--echo #
184+
185+
SET SQL_BUFFER_RESULT = 1;
186+
187+
WITH RECURSIVE cte AS
188+
(SELECT 1 AS n UNION SELECT n+1 FROM cte WHERE n<3)
189+
SELECT * FROM cte;
190+
191+
WITH RECURSIVE cte AS
192+
(SELECT 1 AS n UNION ALL SELECT n+1 FROM cte WHERE n<3)
193+
SELECT * FROM cte;
194+
195+
SET SQL_BUFFER_RESULT = DEFAULT;

sql/sql_optimizer.cc

Lines changed: 61 additions & 29 deletions
Original file line numberDiff line numberDiff line change
@@ -200,7 +200,7 @@ int
200200
JOIN::optimize()
201201
{
202202
uint no_jbuf_after= UINT_MAX;
203-
const bool no_w= m_windows.elements == 0;
203+
const bool has_windows= m_windows.elements != 0;
204204

205205
DBUG_ENTER("JOIN::optimize");
206206
DBUG_ASSERT(select_lex->leaf_table_count == 0 ||
@@ -707,35 +707,67 @@ JOIN::optimize()
707707

708708
/*
709709
Check if we need to create a temporary table prior to any windowing.
710-
This has to be done if all tables are not already read (const tables)
711-
and one of the following conditions holds:
712-
- We are using DISTINCT (simple distinct's have already been optimized away)
713-
and we have no windows
714-
- We are using an ORDER BY and no windows, or GROUP BY on fields not in the
715-
first table
716-
- We are using different ORDER BY and GROUP BY orders and we have no windows
717-
- The user wants us to buffer the result and we have no windowing
718-
(if we do, we make a final windowing step temporary table,
719-
cf computation of Temp_table_param::m_window_short_circuit)
720-
- We have windowing and the first window requires sorting
721-
When the WITH ROLLUP modifier is present, we cannot skip temporary table
722-
creation for the DISTINCT clause just because there are only const tables.
710+
711+
(1) If there is ROLLUP, which happens before DISTINCT, windowing and ORDER BY,
712+
any of those clauses needs the result of ROLLUP in a tmp table.
713+
We needn't test ORDER BY in the condition as it's forbidden with ROLLUP.
714+
715+
Rows which ROLLUP adds to the result are visible only to DISTINCT,
716+
windowing and ORDER BY which we handled above. So for the rest of
717+
conditions ((2), etc), we can do as if there were no ROLLUP.
718+
719+
(2) If all tables are constant, the query's result is guaranteed to have 0
720+
or 1 row only, so all SQL clauses discussed below (DISTINCT, ORDER BY,
721+
GROUP BY, windowing, SQL_BUFFER_RESULT) are useless and need no tmp
722+
table.
723+
724+
(3) If there is GROUP BY which isn't resolved by using an index or sorting
725+
the first table, we need a tmp table to compute the grouped rows.
726+
GROUP BY happens before windowing; so it is a pre-windowing tmp
727+
table.
728+
729+
(4) (5) If there is DISTINCT, or ORDER BY which isn't resolved by using an
730+
index or sorting the first table, those clauses need an input tmp table.
731+
If we have windowing, as those clauses are used after windowing, they can
732+
use the last window's tmp table.
733+
734+
(6) If there are different ORDER BY and GROUP BY orders, ORDER BY needs an
735+
input tmp table, so it's like (5).
736+
737+
(7) If the user wants us to buffer the result, we need a tmp table. But
738+
windowing creates one anyway, and so does the materialization of a derived
739+
table.
740+
741+
See also the computation of Temp_table_param::m_window_short_circuit,
742+
where we make sure to create a tmp table if the clauses above want one.
743+
744+
(8) If the first windowing step needs sorting, filesort() will be used; it
745+
can sort one table but not a join of tables, so we need a tmp table
746+
then. If GROUP BY was optimized away, the pre-windowing result is 0 or 1
747+
row so doesn't need sorting.
723748
*/
724-
need_tmp_before_win=
725-
((!plan_is_const() &&
726-
(((select_distinct && no_w) ||
727-
(order && !simple_order && no_w) ||
728-
(group_list && !simple_group)) ||
729-
(group_list && order && no_w) ||
730-
(select_lex->active_options() & OPTION_BUFFER_RESULT && no_w))) ||
731-
/*
732-
If the first window step needs sorting, we need a tmp file,
733-
but only if there's more than one non-const table in join.
734-
*/
735-
(!no_w && (primary_tables - const_tables) > 1 &&
736-
m_windows[0]->needs_sorting() &&
737-
!group_optimized_away) ||
738-
(rollup.state != ROLLUP::STATE_NONE && select_distinct));
749+
750+
if (rollup.state != ROLLUP::STATE_NONE && // (1)
751+
(select_distinct
752+
/* the fix for bug#26497353 will enable this: || has_windows*/))
753+
need_tmp_before_win= true;
754+
755+
if (!plan_is_const()) // (2)
756+
{
757+
if ((group_list && !simple_group) || // (3)
758+
(!has_windows &&
759+
(select_distinct || // (4)
760+
(order && !simple_order) || // (5)
761+
(group_list && order))) || // (6)
762+
((select_lex->active_options() & OPTION_BUFFER_RESULT) &&
763+
!has_windows &&
764+
!(unit->derived_table &&
765+
unit->derived_table->uses_materialization())) || // (7)
766+
(has_windows && (primary_tables - const_tables) > 1 && // (8)
767+
m_windows[0]->needs_sorting() &&
768+
!group_optimized_away))
769+
need_tmp_before_win= true;
770+
}
739771

740772
DBUG_EXECUTE("info", TEST_join(this););
741773

0 commit comments

Comments
 (0)