Fixed MDEV-14883 Usage of EXCEPT and INTERSECT in recursive CTE

is not supported

Allowed to use recursive references in derived tables.
As a result usage of recursive references in operands of
INTERSECT / EXCEPT is now supported.
This commit is contained in:
Igor Babaev 2018-02-22 10:08:49 -08:00
parent 988ec800ed
commit 907b236112
9 changed files with 464 additions and 22 deletions

View File

@ -3105,3 +3105,236 @@ SELECT * FROM cte;
5
2
3
#
# MDEV-14883: recursive references in operands of INTERSECT / EXCEPT
#
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', 'Amsterdam', 'KLM', 'KL 6032'),
('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'),
('New York', 'London', 'British Airways', 'BA 1511'),
('London', 'Moscow', 'British Airways', 'BA 233'),
('Moscow', 'Tokyo', 'Aeroflot', 'SU 264'),
('Moscow', 'Dubai', 'Emirates', 'EK 2421'),
('Dubai', 'Tokyo', 'Emirates', 'EK 318'),
('Dubai', 'Bangkok', 'Emirates', 'EK 2142'),
('Beijing', 'Bangkok', 'Air China', 'CA 757'),
('Beijing', 'Tokyo', 'Air China', 'CA 6653'),
('Moscow', 'Bangkok', 'Aeroflot', 'SU 270'),
('New York', 'Reykjavik', 'Icelandair', 'FL 416'),
('New York', 'Paris', 'Air France', 'AF 23'),
('Amsterdam', 'Moscow', 'KLM', 'KL 903'),
('Frankfurt', 'Dubai', 'Lufthansa', 'LH 630'),
('Frankfurt', 'Moscow', 'Lufthansa', 'LH 1444'),
('Reykjavik', 'London', 'British Airways', 'BA 2229'),
('Frankfurt', 'Beijing', 'Air China', 'CA 966'),
('Tokyo', 'Seattle', 'ANA', 'NH 178'),
('Los Angeles', 'Tokyo', 'ANA', 'NH 175'),
('Moscow', 'Los Angeles', 'Aeroflot', 'SU 106'),
('Montreal', 'Paris', 'Air Canada', 'AC 870'),
('London', 'Delhi', 'British Airways', 'BA 143'),
('Delhi', 'Bangkok', 'Air India', 'AI 306'),
('Delhi', 'Dubai', 'Air India', 'AI 995'),
('Dubai', 'Cairo', 'Emirates', 'EK 927'),
('Cairo', 'Paris', 'Air France', 'AF 503'),
('Amsterdam', 'New York', 'Delta', 'DL 47'),
('New York', 'Seattle', 'American', 'AA 45'),
('Paris', 'Chicago', 'Air France', 'AF 6734');
create table distances
(city1 varchar(32),
city2 varchar(32),
dist int);
insert into distances values
('Seattle', 'Frankfurt', 5080),
('Seattle', 'Amsterdam', 4859),
('Seattle', 'Chicago', 1733),
('Seattle', 'Los Angeles', 960),
('Chicago', 'New York', 712),
('Chicago', 'Montreal', 746),
('Los Angeles', 'New York', 2446),
('New York', 'London', 3459),
('London', 'Moscow', 1554),
('Moscow', 'Tokyo', 4647),
('Moscow', 'Dubai', 2298),
('Dubai', 'Tokyo', 4929),
('Dubai', 'Bangkok', 3050),
('Beijing', 'Bangkok', 2046),
('Beijing', 'Tokyo', 1301),
('Moscow', 'Bangkok', 4390),
('New York', 'Reykjavik', 2613),
('New York', 'Paris', 3625),
('Amsterdam', 'Moscow', 1334),
('Frankfurt', 'Dubai', 3003),
('Frankfurt', 'Moscow', 1256),
('Reykjavik', 'London', 1173),
('Frankfurt', 'Beijing', 4836),
('Tokyo', 'Seattle', 4783),
('Los Angeles', 'Tokyo', 5479),
('Moscow', 'Los Angeles', 6071),
('Moscow', 'Reykjavik', 2052),
('Montreal', 'Paris', 3425),
('London', 'Delhi', 4159),
('London', 'Paris', 214),
('Delhi', 'Bangkok', 1810),
('Delhi', 'Dubai', 1369),
('Delhi', 'Beijing', 2350),
('Dubai', 'Cairo', 1501),
('Cairo', 'Paris', 1992),
('Amsterdam', 'New York', 3643),
('New York', 'Seattle', 2402),
('Paris', 'Chicago', 4136),
('Paris', 'Los Angeles', 5647);
with recursive destinations (city) as
(
select a.arrival from flights a where a.departure = 'Seattle'
union
select b.arrival from destinations r, flights b where r.city = b.departure
)
select * from destinations;
city
Frankfurt
Amsterdam
Chicago
Los Angeles
New York
Montreal
Moscow
Dubai
Beijing
Tokyo
London
Bangkok
Reykjavik
Paris
Seattle
Cairo
Delhi
with recursive destinations (city) as
(
select a.arrival from flights a, distances d
where a.departure = 'Seattle' and
a.departure = d.city1 and a.arrival = d.city2 and
d.dist < 4000
union
select b.arrival from destinations r, flights b, distances d
where r.city = b.departure and
b.departure = d.city1 and b.arrival = d.city2 and
d.dist < 4000
)
select * from destinations;
city
Chicago
Los Angeles
New York
Montreal
London
Reykjavik
Paris
Seattle
Moscow
Dubai
Bangkok
Cairo
set standard_compliant_cte=0;
with recursive legs_to_destinations
(departure, arrival, dist, leg_no, acc_mileage) as
(
select a.departure, a.arrival, d.dist, 1, d.dist
from flights a, distances d
where a.departure = 'Seattle' and
a.departure = d.city1 and a.arrival = d.city2 and
d.dist < 4000
union all
select b.departure, b.arrival, d.dist, r.leg_no + 1, r.acc_mileage + d.dist
from legs_to_destinations r, flights b, distances d
where r.arrival = b.departure and
b.departure = d.city1 and b.arrival = d.city2 and
d.dist < 4000 and
b.arrival not in (select arrival from legs_to_destinations)
)
select * from legs_to_destinations;
departure arrival dist leg_no acc_mileage
Seattle Chicago 1733 1 1733
Seattle Los Angeles 960 1 960
Chicago New York 712 2 2445
Chicago Montreal 746 2 2479
Los Angeles New York 2446 2 3406
New York London 3459 3 6865
New York London 3459 3 5904
New York Reykjavik 2613 3 6019
New York Reykjavik 2613 3 5058
New York Paris 3625 3 7031
New York Paris 3625 3 6070
Montreal Paris 3425 3 5904
New York Seattle 2402 3 5808
New York Seattle 2402 3 4847
London Moscow 1554 4 7458
London Moscow 1554 4 8419
Moscow Dubai 2298 5 10717
Moscow Dubai 2298 5 9756
Dubai Bangkok 3050 6 12806
Dubai Bangkok 3050 6 13767
Dubai Cairo 1501 6 11257
Dubai Cairo 1501 6 12218
set standard_compliant_cte=default;
with recursive destinations (city) as
(
select a.arrival from flights a, distances d
where a.departure = 'Seattle' and
a.departure = d.city1 and a.arrival = d.city2 and
d.dist < 4000
union
select b.arrival from destinations r, flights b
where r.city = b.departure
intersect
select city2 from destinations s, distances d
where s.city = d.city1 and d.dist < 4000
)
select * from destinations;
city
Chicago
Los Angeles
New York
Montreal
London
Reykjavik
Paris
Seattle
Moscow
Dubai
Bangkok
Cairo
with recursive destinations (city) as
(
select a.arrival from flights a where a.departure = 'Seattle'
union
select * from
(
select b.arrival from destinations r, flights b
where r.city = b.departure
except
select arrival from flights
where arrival in
('New York', 'London', 'Moscow', 'Dubai', 'Cairo', 'Tokyo')
) t
)
select * from destinations;
city
Frankfurt
Amsterdam
Chicago
Los Angeles
Montreal
Beijing
Bangkok
Paris
drop table flights, distances;

View File

@ -2138,3 +2138,173 @@ WITH RECURSIVE cte AS
UNION
SELECT @c:=@c+1 FROM cte WHERE @c<3)
SELECT * FROM cte;
--echo #
--echo # MDEV-14883: recursive references in operands of INTERSECT / EXCEPT
--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', 'Amsterdam', 'KLM', 'KL 6032'),
('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'),
('New York', 'London', 'British Airways', 'BA 1511'),
('London', 'Moscow', 'British Airways', 'BA 233'),
('Moscow', 'Tokyo', 'Aeroflot', 'SU 264'),
('Moscow', 'Dubai', 'Emirates', 'EK 2421'),
('Dubai', 'Tokyo', 'Emirates', 'EK 318'),
('Dubai', 'Bangkok', 'Emirates', 'EK 2142'),
('Beijing', 'Bangkok', 'Air China', 'CA 757'),
('Beijing', 'Tokyo', 'Air China', 'CA 6653'),
('Moscow', 'Bangkok', 'Aeroflot', 'SU 270'),
('New York', 'Reykjavik', 'Icelandair', 'FL 416'),
('New York', 'Paris', 'Air France', 'AF 23'),
('Amsterdam', 'Moscow', 'KLM', 'KL 903'),
('Frankfurt', 'Dubai', 'Lufthansa', 'LH 630'),
('Frankfurt', 'Moscow', 'Lufthansa', 'LH 1444'),
('Reykjavik', 'London', 'British Airways', 'BA 2229'),
('Frankfurt', 'Beijing', 'Air China', 'CA 966'),
('Tokyo', 'Seattle', 'ANA', 'NH 178'),
('Los Angeles', 'Tokyo', 'ANA', 'NH 175'),
('Moscow', 'Los Angeles', 'Aeroflot', 'SU 106'),
('Montreal', 'Paris', 'Air Canada', 'AC 870'),
('London', 'Delhi', 'British Airways', 'BA 143'),
('Delhi', 'Bangkok', 'Air India', 'AI 306'),
('Delhi', 'Dubai', 'Air India', 'AI 995'),
('Dubai', 'Cairo', 'Emirates', 'EK 927'),
('Cairo', 'Paris', 'Air France', 'AF 503'),
('Amsterdam', 'New York', 'Delta', 'DL 47'),
('New York', 'Seattle', 'American', 'AA 45'),
('Paris', 'Chicago', 'Air France', 'AF 6734');
create table distances
(city1 varchar(32),
city2 varchar(32),
dist int);
insert into distances values
('Seattle', 'Frankfurt', 5080),
('Seattle', 'Amsterdam', 4859),
('Seattle', 'Chicago', 1733),
('Seattle', 'Los Angeles', 960),
('Chicago', 'New York', 712),
('Chicago', 'Montreal', 746),
('Los Angeles', 'New York', 2446),
('New York', 'London', 3459),
('London', 'Moscow', 1554),
('Moscow', 'Tokyo', 4647),
('Moscow', 'Dubai', 2298),
('Dubai', 'Tokyo', 4929),
('Dubai', 'Bangkok', 3050),
('Beijing', 'Bangkok', 2046),
('Beijing', 'Tokyo', 1301),
('Moscow', 'Bangkok', 4390),
('New York', 'Reykjavik', 2613),
('New York', 'Paris', 3625),
('Amsterdam', 'Moscow', 1334),
('Frankfurt', 'Dubai', 3003),
('Frankfurt', 'Moscow', 1256),
('Reykjavik', 'London', 1173),
('Frankfurt', 'Beijing', 4836),
('Tokyo', 'Seattle', 4783),
('Los Angeles', 'Tokyo', 5479),
('Moscow', 'Los Angeles', 6071),
('Moscow', 'Reykjavik', 2052),
('Montreal', 'Paris', 3425),
('London', 'Delhi', 4159),
('London', 'Paris', 214),
('Delhi', 'Bangkok', 1810),
('Delhi', 'Dubai', 1369),
('Delhi', 'Beijing', 2350),
('Dubai', 'Cairo', 1501),
('Cairo', 'Paris', 1992),
('Amsterdam', 'New York', 3643),
('New York', 'Seattle', 2402),
('Paris', 'Chicago', 4136),
('Paris', 'Los Angeles', 5647);
with recursive destinations (city) as
(
select a.arrival from flights a where a.departure = 'Seattle'
union
select b.arrival from destinations r, flights b where r.city = b.departure
)
select * from destinations;
with recursive destinations (city) as
(
select a.arrival from flights a, distances d
where a.departure = 'Seattle' and
a.departure = d.city1 and a.arrival = d.city2 and
d.dist < 4000
union
select b.arrival from destinations r, flights b, distances d
where r.city = b.departure and
b.departure = d.city1 and b.arrival = d.city2 and
d.dist < 4000
)
select * from destinations;
set standard_compliant_cte=0;
with recursive legs_to_destinations
(departure, arrival, dist, leg_no, acc_mileage) as
(
select a.departure, a.arrival, d.dist, 1, d.dist
from flights a, distances d
where a.departure = 'Seattle' and
a.departure = d.city1 and a.arrival = d.city2 and
d.dist < 4000
union all
select b.departure, b.arrival, d.dist, r.leg_no + 1, r.acc_mileage + d.dist
from legs_to_destinations r, flights b, distances d
where r.arrival = b.departure and
b.departure = d.city1 and b.arrival = d.city2 and
d.dist < 4000 and
b.arrival not in (select arrival from legs_to_destinations)
)
select * from legs_to_destinations;
set standard_compliant_cte=default;
with recursive destinations (city) as
(
select a.arrival from flights a, distances d
where a.departure = 'Seattle' and
a.departure = d.city1 and a.arrival = d.city2 and
d.dist < 4000
union
select b.arrival from destinations r, flights b
where r.city = b.departure
intersect
select city2 from destinations s, distances d
where s.city = d.city1 and d.dist < 4000
)
select * from destinations;
with recursive destinations (city) as
(
select a.arrival from flights a where a.departure = 'Seattle'
union
select * from
(
select b.arrival from destinations r, flights b
where r.city = b.departure
except
select arrival from flights
where arrival in
('New York', 'London', 'Moscow', 'Dubai', 'Cairo', 'Tokyo')
) t
)
select * from destinations;
drop table flights, distances;

View File

@ -1314,32 +1314,29 @@ bool With_element::check_unrestricted_recursive(st_select_lex *sel,
bool st_select_lex::check_subqueries_with_recursive_references()
{
st_select_lex_unit *sl_master= master_unit();
List_iterator<TABLE_LIST> ti(leaf_tables);
TABLE_LIST *tbl;
while ((tbl= ti++))
{
if (!(tbl->is_with_table_recursive_reference() && sl_master->item))
if (!(tbl->is_with_table_recursive_reference()))
continue;
With_element *with_elem= tbl->with;
bool check_embedding_materialized_derived= true;
With_element *rec_elem= tbl->with;
st_select_lex_unit *sl_master;
for (st_select_lex *sl= this; sl; sl= sl_master->outer_select())
{
{
sl_master= sl->master_unit();
if (with_elem->get_owner() == sl_master->with_clause)
check_embedding_materialized_derived= false;
if (check_embedding_materialized_derived && !sl_master->with_element &&
sl_master->derived && sl_master->derived->is_materialized_derived())
if (sl_master->with_element &&
sl_master->with_element->get_owner() == rec_elem->get_owner())
break;
sl->uncacheable|= UNCACHEABLE_DEPENDENT;
sl_master->uncacheable|= UNCACHEABLE_DEPENDENT;
if (sl_master->derived)
sl_master->derived->register_as_derived_with_rec_ref(rec_elem);
if (sl_master->item)
{
my_error(ER_REF_TO_RECURSIVE_WITH_TABLE_IN_DERIVED,
MYF(0), with_elem->query_name->str);
return true;
Item_subselect *subq= (Item_subselect *) (sl_master->item);
subq->register_as_with_rec_ref(rec_elem);
}
if (!sl_master->item)
continue;
Item_subselect *subq= (Item_subselect *) sl_master->item;
subq->with_recursive_reference= true;
subq->register_as_with_rec_ref(tbl->with);
}
}
return false;

View File

@ -146,7 +146,9 @@ public:
select_union_recursive *rec_result;
/* List of Item_subselects containing recursive references to this CTE */
SQL_I_List<Item_subselect> sq_with_rec_ref;
SQL_I_List<Item_subselect> sq_with_rec_ref;
/* List of derived tables containing recursive references to this CTE */
SQL_I_List<TABLE_LIST> derived_with_rec_ref;
With_element(LEX_CSTRING *name,
List <LEX_CSTRING> list,

View File

@ -1010,6 +1010,20 @@ bool mysql_derived_create(THD *thd, LEX *lex, TABLE_LIST *derived)
}
void TABLE_LIST::register_as_derived_with_rec_ref(With_element *rec_elem)
{
rec_elem->derived_with_rec_ref.link_in_list(this, &this->next_with_rec_ref);
is_derived_with_recursive_reference= true;
get_unit()->uncacheable|= UNCACHEABLE_DEPENDENT;
}
bool TABLE_LIST::is_nonrecursive_derived_with_rec_ref()
{
return is_derived_with_recursive_reference;
}
/**
@brief
Fill the recursive with table

View File

@ -12500,7 +12500,8 @@ bool JOIN_TAB::preread_init()
derived, DT_CREATE | DT_FILL))
return TRUE;
if (!(derived->get_unit()->uncacheable & UNCACHEABLE_DEPENDENT))
if (!(derived->get_unit()->uncacheable & UNCACHEABLE_DEPENDENT) ||
derived->is_nonrecursive_derived_with_rec_ref())
preread_init_done= TRUE;
if (select && select->quick)
select->quick->replace_handler(table->file);

View File

@ -1365,7 +1365,15 @@ bool st_select_lex_unit::exec()
DBUG_RETURN(saved_error);
if (union_result)
{
union_result->init();
if (uncacheable & UNCACHEABLE_DEPENDENT &&
union_result->table && union_result->table->is_created())
{
union_result->table->file->ha_delete_all_rows();
union_result->table->file->ha_enable_indexes(HA_KEY_SWITCH_ALL);
}
}
if (uncacheable || !item || !item->assigned() || describe)
{
@ -1663,6 +1671,20 @@ bool st_select_lex_unit::exec_recursive()
for (st_select_lex *sl= start ; sl != end; sl= sl->next_select())
{
if (with_element->level)
{
for (TABLE_LIST *derived= with_element->derived_with_rec_ref.first;
derived;
derived= derived->next_with_rec_ref)
{
if (derived->is_materialized_derived())
{
if (derived->table->is_created())
derived->table->file->ha_delete_all_rows();
derived->table->reginfo.join_tab->preread_init_done= false;
}
}
}
thd->lex->current_select= sl;
if (sl->tvc)
sl->tvc->exec(sl);
@ -1706,7 +1728,7 @@ bool st_select_lex_unit::exec_recursive()
if (!with_element->rec_result->first_rec_table_to_update)
with_element->rec_result->first_rec_table_to_update= rec_table;
if (with_element->level == 1 && rec_table->reginfo.join_tab)
rec_table->reginfo.join_tab->preread_init_done= true;
rec_table->reginfo.join_tab->preread_init_done= true;
}
for (Item_subselect *sq= with_element->sq_with_rec_ref.first;
sq;

View File

@ -8371,7 +8371,6 @@ bool TABLE_LIST::is_with_table()
return derived && derived->with_element;
}
uint TABLE_SHARE::actual_n_key_parts(THD *thd)
{
return use_ext_keys &&

View File

@ -2131,7 +2131,9 @@ inline void init_one_table(const LEX_CSTRING *db_arg,
st_select_lex_unit *derived; /* SELECT_LEX_UNIT of derived table */
With_element *with; /* With element defining this table (if any) */
/* Bitmap of the defining with element */
table_map with_internal_reference_map;
table_map with_internal_reference_map;
TABLE_LIST * next_with_rec_ref;
bool is_derived_with_recursive_reference;
bool block_handle_derived;
ST_SCHEMA_TABLE *schema_table; /* Information_schema table */
st_select_lex *schema_select_lex;
@ -2508,6 +2510,8 @@ inline void init_one_table(const LEX_CSTRING *db_arg,
bool is_with_table();
bool is_recursive_with_table();
bool is_with_table_recursive_reference();
void register_as_derived_with_rec_ref(With_element *rec_elem);
bool is_nonrecursive_derived_with_rec_ref();
bool fill_recursive(THD *thd);
inline void set_view()