Description:
In certain rare circumstances, the stored procedure optimizer fails to
update jump destinations correctly when jumping to a "no-op" instruction
like "hpop 0" and "cpop 0". These instruction appear with forward jumps,
e.g. LEAVE, and are removed by the optimizer. In the example, at the end
the code is:
| 42 | jump_if_not 50 (p_all@1 and (v_i@3 > 0)) |
| 43 | set v_i@3 (v_i@3 - 1) |
| 44 | jump 14 |
| 45 | jump 46 |
| 46 | stmt 9 "drop temporary table sudoku_work, sud..." |
+-----+-----------------------------------------------------------------------+
Instruction 42 should have the final statement (46) as its destination. (And
instruction 45 is left as a result of the failed optimization.)
The correct code would be:
| 42 | jump_if_not 45 (p_all@1 and (v_i@3 > 0)) |
| 43 | set v_i@3 (v_i@3 - 1) |
| 44 | jump 14 |
| 45 | stmt 9 "drop temporary table sudoku_work, sud..." |
+-----+-----------------------------------------------------------------------+
A simple workaround is possible:
Putting any (harmless) statement before the LEAVE will make the problem go
away. I.e. in the example, change:
if p_all and v_i > 0 then
set v_i = v_i - 1;
else
leave more;
end if;
end;
end loop more;
end;
into:
if p_all and v_i > 0 then
set v_i = v_i - 1;
else
set @dummy = 0; -- Workaround optimizer bug
leave more;
end if;
end;
end loop more;
end;
In this case the code becomes:
| 42 | jump_if_not 45 (p_all@1 and (v_i@3 > 0)) |
| 43 | set v_i@3 (v_i@3 - 1) |
| 44 | jump 14 |
| 45 | stmt 32 "SET @dummy = 0" |
| 46 | jump 47 |
| 47 | stmt 9 "drop temporary table sudoku_work, sud..." |
+-----+-----------------------------------------------------------------------+
which is not perfect, but correct.
How to repeat:
-- A debug build is required for this (to enable "show procedure code ...").
drop procedure if exists sudoku_solve;
delimiter //
create procedure sudoku_solve(p_naive boolean, p_all boolean)
deterministic
modifies sql data
begin
drop temporary table if exists sudoku_work, sudoku_schedule;
create temporary table sudoku_work
(
row smallint not null,
col smallint not null,
dig smallint not null,
cnt smallint,
key using btree (cnt),
key using btree (row),
key using btree (col),
unique key using hash (row,col)
);
create temporary table sudoku_schedule
(
idx int not null auto_increment primary key,
row smallint not null,
col smallint not null
);
call sudoku_init();
if p_naive then
update sudoku_work set cnt = 0 where dig = 0;
else
call sudoku_count();
end if;
insert into sudoku_schedule (row,col)
select row,col from sudoku_work where cnt is not null order by cnt desc;
begin
declare v_scounter bigint default 0;
declare v_i smallint default 1;
declare v_dig smallint;
declare v_schedmax smallint;
select count(*) into v_schedmax from sudoku_schedule;
more:
loop
begin
declare v_tcounter bigint default 0;
sched:
while v_i <= v_schedmax do
begin
declare v_row, v_col smallint;
select row,col into v_row,v_col from sudoku_schedule where v_i = idx;
select dig into v_dig from sudoku_work
where v_row = row and v_col = col;
case v_dig
when 0 then
set v_dig = 1;
update sudoku_work set dig = 1
where v_row = row and v_col = col;
when 9 then
if v_i > 0 then
update sudoku_work set dig = 0
where v_row = row and v_col = col;
set v_i = v_i - 1;
iterate sched;
else
select v_scounter as 'Solutions';
leave more;
end if;
else
set v_dig = v_dig + 1;
update sudoku_work set dig = v_dig
where v_row = row and v_col = col;
end case;
set v_tcounter = v_tcounter + 1;
if not sudoku_digit_ok(v_row, v_col, v_dig) then
iterate sched;
end if;
set v_i = v_i + 1;
end;
end while sched;
select dig from sudoku_work;
select v_tcounter as 'Tests';
set v_scounter = v_scounter + 1;
if p_all and v_i > 0 then
set v_i = v_i - 1;
else
leave more;
end if;
end;
end loop more;
end;
drop temporary table sudoku_work, sudoku_schedule;
end//
delimiter ;
show procedure code sudoku_solve;
drop procedure sudoku_solve;