Skip to content

Commit e1e57a1

Browse files
author
Dag Wanvik
committed
Bug#37074489 stored procedure is producing different results in different attempts
The error occurs also in the recursive CTE query if used in a prepared statement; in the first execution the result is correct, but wrong in subsequent executions. Tracing revealed that the creation of the materialized tmp table during optimization was made using the wrong key, so execution found no row matching its where clause againt the constant in this part of the query: SELECT type, COUNT(*) AS count FROM t WHERE batch_uid = 549285 where t is the recursive cte. The second execution uses index on "type" instead of on "batch_uid" for materialized table "t" (and also wrong index for materialized "tran": "refguid' instead of "batch_uid". This happens because TABLE::s->key_parts is not reset when the tmp table is cleaned up in 'cleanup_tmp_tables'. s->keys is reset to 0, but s->key_parts is not touched. This upsets the logic in TABLE::add_tmp_key, so we end up with the wrong index (the value for s->key_parts ends up one too high in the second execution). Solution: reset TABLE_SHARE::key_parts as well in 'cleanup_tmp_tables'. Change-Id: I556f041f4476817208a6b8beb179ddaa44fd712f
1 parent 9655bb2 commit e1e57a1

File tree

3 files changed

+153
-0
lines changed

3 files changed

+153
-0
lines changed

mysql-test/r/with_recursive_bugs.result

+91
Original file line numberDiff line numberDiff line change
@@ -247,3 +247,94 @@ SELECT 2 FROM cte1 WHERE FALSE
247247
SELECT * FROM cte1;
248248
1
249249
DROP TABLE t1;
250+
#
251+
# Bug#37074489 stored procedure is producing different results in different attempts
252+
# The error also reproduces with prepared statement in 2..n executions
253+
PREPARE p FROM "WITH RECURSIVE
254+
tran(batch_uid, guid, type, trantime, refguid) AS (
255+
SELECT 549285, 'W5PT9A5F3D2WF57', 13, '2023-04-07 09:19:04', NULL
256+
UNION ALL
257+
SELECT 549286, 'W5PTVYU84715VJ7', 13, '2023-04-07 09:31:20', 'W5PT9A5F3D2WF57'
258+
)
259+
,t(init_dataset, batch_uid, guid, type, trantime) AS (
260+
SELECT TRUE AS init_dataset,
261+
batch_uid,
262+
guid,
263+
type,
264+
trantime
265+
FROM tran
266+
WHERE batch_uid = 549285
267+
UNION ALL
268+
SELECT FALSE,
269+
wt.batch_uid,
270+
wt.guid,
271+
wt.type,
272+
wt.trantime
273+
FROM tran wt
274+
JOIN
275+
t ts
276+
ON wt.refguid = ts.guid
277+
WHERE wt.batch_uid != 549285 AND init_dataset
278+
)
279+
SELECT t2.count
280+
FROM t
281+
LEFT JOIN
282+
( SELECT type,
283+
COUNT(*) AS count
284+
FROM t /* t2 */
285+
WHERE batch_uid = 549285
286+
GROUP BY type
287+
) t2 ON t2.type = t.type
288+
";
289+
EXECUTE p;
290+
count
291+
1
292+
1
293+
# This used to yield two NULL rows
294+
EXECUTE p;
295+
count
296+
1
297+
1
298+
DROP PREPARE p;
299+
# Original repro
300+
CREATE PROCEDURE cte_bug() BEGIN WITH RECURSIVE
301+
tran(batch_uid, guid, type, trantime, refguid) AS (
302+
SELECT 549285, 'W5PT9A5F3D2WF57', 13, '2023-04-07 09:19:04', NULL
303+
UNION ALL
304+
SELECT 549286, 'W5PTVYU84715VJ7', 13, '2023-04-07 09:31:20', 'W5PT9A5F3D2WF57'
305+
)
306+
,t(init_dataset, batch_uid, guid, type, trantime) AS (
307+
SELECT TRUE AS init_dataset,
308+
batch_uid,
309+
guid,
310+
type,
311+
trantime
312+
FROM tran
313+
WHERE batch_uid = 549285
314+
UNION ALL
315+
SELECT FALSE,
316+
wt.batch_uid,
317+
wt.guid,
318+
wt.type,
319+
wt.trantime
320+
FROM tran wt
321+
JOIN
322+
t ts
323+
ON wt.refguid = ts.guid
324+
WHERE wt.batch_uid != 549285 AND init_dataset
325+
)
326+
SELECT t2.count
327+
FROM t
328+
LEFT JOIN
329+
( SELECT type,
330+
COUNT(*) AS count
331+
FROM t /* t2 */
332+
WHERE batch_uid = 549285
333+
GROUP BY type
334+
) t2 ON t2.type = t.type
335+
; END $$
336+
CALL cte_bug();
337+
count
338+
1
339+
1
340+
DROP PROCEDURE cte_bug;

mysql-test/t/with_recursive_bugs.test

+60
Original file line numberDiff line numberDiff line change
@@ -264,3 +264,63 @@ WITH RECURSIVE cte1 AS
264264
SELECT * FROM cte1;
265265

266266
DROP TABLE t1;
267+
268+
--echo #
269+
--echo # Bug#37074489 stored procedure is producing different results in different attempts
270+
--echo # The error also reproduces with prepared statement in 2..n executions
271+
272+
let $query =
273+
WITH RECURSIVE
274+
tran(batch_uid, guid, type, trantime, refguid) AS (
275+
SELECT 549285, 'W5PT9A5F3D2WF57', 13, '2023-04-07 09:19:04', NULL
276+
UNION ALL
277+
SELECT 549286, 'W5PTVYU84715VJ7', 13, '2023-04-07 09:31:20', 'W5PT9A5F3D2WF57'
278+
)
279+
,t(init_dataset, batch_uid, guid, type, trantime) AS (
280+
SELECT TRUE AS init_dataset,
281+
batch_uid,
282+
guid,
283+
type,
284+
trantime
285+
FROM tran
286+
WHERE batch_uid = 549285
287+
UNION ALL
288+
SELECT FALSE,
289+
wt.batch_uid,
290+
wt.guid,
291+
wt.type,
292+
wt.trantime
293+
FROM tran wt
294+
JOIN
295+
t ts
296+
ON wt.refguid = ts.guid
297+
WHERE wt.batch_uid != 549285 AND init_dataset
298+
)
299+
SELECT t2.count
300+
FROM t
301+
LEFT JOIN
302+
( SELECT type,
303+
COUNT(*) AS count
304+
FROM t /* t2 */
305+
WHERE batch_uid = 549285
306+
GROUP BY type
307+
) t2 ON t2.type = t.type
308+
;
309+
310+
eval PREPARE p FROM "$query";
311+
312+
EXECUTE p;
313+
--echo # This used to yield two NULL rows
314+
EXECUTE p;
315+
316+
DROP PREPARE p;
317+
318+
--echo # Original repro
319+
DELIMITER $$;
320+
321+
eval CREATE PROCEDURE cte_bug() BEGIN $query; END $$
322+
DELIMITER ;$$
323+
324+
CALL cte_bug();
325+
326+
DROP PROCEDURE cte_bug;

sql/sql_union.cc

+2
Original file line numberDiff line numberDiff line change
@@ -1382,6 +1382,8 @@ static void cleanup_tmp_tables(Table_ref *list) {
13821382
// Clear indexes added during optimization, keep possible unique index
13831383
TABLE *t = tl->table;
13841384
t->s->keys = t->s->is_distinct ? 1 : 0;
1385+
t->s->key_parts =
1386+
t->s->is_distinct ? t->s->key_info[0].user_defined_key_parts : 0;
13851387
t->s->first_unused_tmp_key = 0;
13861388
t->keys_in_use_for_query.clear_all();
13871389
t->keys_in_use_for_group_by.clear_all();

0 commit comments

Comments
 (0)