Fixed mdev-14879 Lost rows for query using recursive CTE
with recursive reference in subquery If a recursive CTE uses a subquery with recursive reference then the virtual function reset() must be called after each iteration performed at the execution of the CTE.
This commit is contained in:
parent
075f61a1d4
commit
7d201d7b30
@ -2972,3 +2972,81 @@ WHERE 1 = 1
|
|||||||
) K, t3;
|
) K, t3;
|
||||||
C P i
|
C P i
|
||||||
drop table t1,t2,t3;
|
drop table t1,t2,t3;
|
||||||
|
#
|
||||||
|
# mdev-14879: subquery with recursive reference in WHERE of CTE
|
||||||
|
#
|
||||||
|
create table flights
|
||||||
|
(departure varchar(32),
|
||||||
|
arrival varchar(32),
|
||||||
|
carrier varchar(20),
|
||||||
|
flight_number char(7));
|
||||||
|
insert into flights values
|
||||||
|
('Seattle', 'Frankfurt', 'Lufthansa', 'LH 491'),
|
||||||
|
('Seattle', 'Chicago', 'American', 'AA 2573'),
|
||||||
|
('Seattle', 'Los Angeles', 'Alaska Air', 'AS 410'),
|
||||||
|
('Chicago', 'New York', 'American', 'AA 375'),
|
||||||
|
('Chicago', 'Montreal', 'Air Canada', 'AC 3053'),
|
||||||
|
('Los Angeles', 'New York', 'Delta', 'DL 1197'),
|
||||||
|
('Moscow', 'Tokyo', 'Aeroflot', 'SU 264'),
|
||||||
|
('New York', 'Paris', 'Air France', 'AF 23'),
|
||||||
|
('Frankfurt', 'Moscow', 'Lufthansa', 'LH 1444'),
|
||||||
|
('Tokyo', 'Seattle', 'ANA', 'NH 178'),
|
||||||
|
('Los Angeles', 'Tokyo', 'ANA', 'NH 175'),
|
||||||
|
('Moscow', 'Los Angeles', 'Aeroflot', 'SU 106'),
|
||||||
|
('Montreal', 'Paris', 'Air Canada', 'AC 870'),
|
||||||
|
('Cairo', 'Paris', 'Air France', 'AF 503'),
|
||||||
|
('New York', 'Seattle', 'American', 'AA 45'),
|
||||||
|
('Paris', 'Chicago', 'Air France', 'AF 6734');
|
||||||
|
with recursive destinations (city) as
|
||||||
|
( select a.arrival from flights a where a.departure='Cairo'
|
||||||
|
union
|
||||||
|
select b.arrival from destinations r, flights b where r.city=b.departure)
|
||||||
|
select * from destinations;
|
||||||
|
city
|
||||||
|
Paris
|
||||||
|
Chicago
|
||||||
|
New York
|
||||||
|
Montreal
|
||||||
|
Seattle
|
||||||
|
Frankfurt
|
||||||
|
Los Angeles
|
||||||
|
Moscow
|
||||||
|
Tokyo
|
||||||
|
set standard_compliant_cte=0;
|
||||||
|
with recursive destinations (city, legs) as
|
||||||
|
(
|
||||||
|
select a.arrival, 1 from flights a where a.departure='Cairo'
|
||||||
|
union
|
||||||
|
select b.arrival, r.legs + 1 from destinations r, flights b
|
||||||
|
where r.city=b.departure and b.arrival not in (select city from destinations)
|
||||||
|
)
|
||||||
|
select * from destinations;
|
||||||
|
city legs
|
||||||
|
Paris 1
|
||||||
|
Chicago 2
|
||||||
|
New York 3
|
||||||
|
Montreal 3
|
||||||
|
Seattle 4
|
||||||
|
Frankfurt 5
|
||||||
|
Los Angeles 5
|
||||||
|
Moscow 6
|
||||||
|
Tokyo 6
|
||||||
|
explain extended with recursive destinations (city, legs) as
|
||||||
|
(
|
||||||
|
select a.arrival, 1 from flights a where a.departure='Cairo'
|
||||||
|
union
|
||||||
|
select b.arrival, r.legs + 1 from destinations r, flights b
|
||||||
|
where r.city=b.departure and b.arrival not in (select city from destinations)
|
||||||
|
)
|
||||||
|
select * from destinations;
|
||||||
|
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||||
|
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 16 100.00
|
||||||
|
2 DERIVED a ALL NULL NULL NULL NULL 16 100.00 Using where
|
||||||
|
3 RECURSIVE UNION b ALL NULL NULL NULL NULL 16 100.00 Using where
|
||||||
|
3 RECURSIVE UNION <derived2> ref key0 key0 35 test.b.departure 2 100.00
|
||||||
|
4 DEPENDENT SUBQUERY <derived2> ALL NULL NULL NULL NULL 16 100.00 Using where
|
||||||
|
NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL NULL
|
||||||
|
Warnings:
|
||||||
|
Note 1003 with recursive destinations as (select `test`.`a`.`arrival` AS `city`,1 AS `legs` from `test`.`flights` `a` where `test`.`a`.`departure` = 'Cairo' union select `test`.`b`.`arrival` AS `arrival`,`r`.`legs` + 1 AS `r.legs + 1` from `destinations` `r` join `test`.`flights` `b` where `r`.`city` = `test`.`b`.`departure` and !<in_optimizer>(`test`.`b`.`arrival`,<exists>(select `destinations`.`city` from `destinations` where trigcond(`test`.`b`.`arrival` = `destinations`.`city` or `destinations`.`city` is null) having trigcond(`destinations`.`city` is null))))select `destinations`.`city` AS `city`,`destinations`.`legs` AS `legs` from `destinations`
|
||||||
|
set standard_compliant_cte=default;
|
||||||
|
drop table flights;
|
||||||
|
@ -2032,3 +2032,56 @@ FROM
|
|||||||
) K, t3;
|
) K, t3;
|
||||||
|
|
||||||
drop table t1,t2,t3;
|
drop table t1,t2,t3;
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # mdev-14879: subquery with recursive reference in WHERE of CTE
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
create table flights
|
||||||
|
(departure varchar(32),
|
||||||
|
arrival varchar(32),
|
||||||
|
carrier varchar(20),
|
||||||
|
flight_number char(7));
|
||||||
|
|
||||||
|
insert into flights values
|
||||||
|
('Seattle', 'Frankfurt', 'Lufthansa', 'LH 491'),
|
||||||
|
('Seattle', 'Chicago', 'American', 'AA 2573'),
|
||||||
|
('Seattle', 'Los Angeles', 'Alaska Air', 'AS 410'),
|
||||||
|
('Chicago', 'New York', 'American', 'AA 375'),
|
||||||
|
('Chicago', 'Montreal', 'Air Canada', 'AC 3053'),
|
||||||
|
('Los Angeles', 'New York', 'Delta', 'DL 1197'),
|
||||||
|
('Moscow', 'Tokyo', 'Aeroflot', 'SU 264'),
|
||||||
|
('New York', 'Paris', 'Air France', 'AF 23'),
|
||||||
|
('Frankfurt', 'Moscow', 'Lufthansa', 'LH 1444'),
|
||||||
|
('Tokyo', 'Seattle', 'ANA', 'NH 178'),
|
||||||
|
('Los Angeles', 'Tokyo', 'ANA', 'NH 175'),
|
||||||
|
('Moscow', 'Los Angeles', 'Aeroflot', 'SU 106'),
|
||||||
|
('Montreal', 'Paris', 'Air Canada', 'AC 870'),
|
||||||
|
('Cairo', 'Paris', 'Air France', 'AF 503'),
|
||||||
|
('New York', 'Seattle', 'American', 'AA 45'),
|
||||||
|
('Paris', 'Chicago', 'Air France', 'AF 6734');
|
||||||
|
|
||||||
|
with recursive destinations (city) as
|
||||||
|
( select a.arrival from flights a where a.departure='Cairo'
|
||||||
|
union
|
||||||
|
select b.arrival from destinations r, flights b where r.city=b.departure)
|
||||||
|
select * from destinations;
|
||||||
|
|
||||||
|
set standard_compliant_cte=0;
|
||||||
|
|
||||||
|
let $q=
|
||||||
|
with recursive destinations (city, legs) as
|
||||||
|
(
|
||||||
|
select a.arrival, 1 from flights a where a.departure='Cairo'
|
||||||
|
union
|
||||||
|
select b.arrival, r.legs + 1 from destinations r, flights b
|
||||||
|
where r.city=b.departure and b.arrival not in (select city from destinations)
|
||||||
|
)
|
||||||
|
select * from destinations;
|
||||||
|
|
||||||
|
eval $q;
|
||||||
|
eval explain extended $q;
|
||||||
|
|
||||||
|
set standard_compliant_cte=default;
|
||||||
|
|
||||||
|
drop table flights;
|
||||||
|
@ -1284,6 +1284,7 @@ bool st_select_lex_unit::exec_recursive()
|
|||||||
sq;
|
sq;
|
||||||
sq= sq->next_with_rec_ref)
|
sq= sq->next_with_rec_ref)
|
||||||
{
|
{
|
||||||
|
sq->reset();
|
||||||
sq->engine->force_reexecution();
|
sq->engine->force_reexecution();
|
||||||
}
|
}
|
||||||
|
|
||||||
|
Loading…
x
Reference in New Issue
Block a user