From 9ac235ab7ddaefb2191a03d3e9cb025d584e3c36 Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Mon, 29 Aug 2016 22:45:17 -0700 Subject: [PATCH] mdev-9864: cleanup, re-factoring. Added comments. Added reaction for exceeding maximum number of elements in with clause. Added a test case to check this reaction. Added a test case where the specification of a recursive table uses two non-recursive with tables. --- mysql-test/r/cte_nonrecursive.result | 3 + mysql-test/r/cte_recursive.result | 122 ++++++++++++++++++++++----- mysql-test/t/cte_nonrecursive.test | 14 +++ mysql-test/t/cte_recursive.test | 117 +++++++++++++++++++++---- sql/share/errmsg-utf8.txt | 2 + sql/sql_class.h | 3 + sql/sql_cte.cc | 32 +++++++ sql/sql_cte.h | 12 +-- sql/sql_derived.cc | 90 +++++++++++++------- sql/sql_union.cc | 25 +++++- 10 files changed, 341 insertions(+), 79 deletions(-) diff --git a/mysql-test/r/cte_nonrecursive.result b/mysql-test/r/cte_nonrecursive.result index 7481f26591f..c9552f662a1 100644 --- a/mysql-test/r/cte_nonrecursive.result +++ b/mysql-test/r/cte_nonrecursive.result @@ -797,6 +797,9 @@ select t1.b from t2,t1 where t1.a = t2.c; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t2 ALL NULL NULL NULL NULL 4 1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join) +# too many with elements in with clause +with s65 as (select * from t1), s64 as (select * from t1) , s63 as (select * from t1) , s62 as (select * from t1) , s61 as (select * from t1) , s60 as (select * from t1) , s59 as (select * from t1) , s58 as (select * from t1) , s57 as (select * from t1) , s56 as (select * from t1) , s55 as (select * from t1) , s54 as (select * from t1) , s53 as (select * from t1) , s52 as (select * from t1) , s51 as (select * from t1) , s50 as (select * from t1) , s49 as (select * from t1) , s48 as (select * from t1) , s47 as (select * from t1) , s46 as (select * from t1) , s45 as (select * from t1) , s44 as (select * from t1) , s43 as (select * from t1) , s42 as (select * from t1) , s41 as (select * from t1) , s40 as (select * from t1) , s39 as (select * from t1) , s38 as (select * from t1) , s37 as (select * from t1) , s36 as (select * from t1) , s35 as (select * from t1) , s34 as (select * from t1) , s33 as (select * from t1) , s32 as (select * from t1) , s31 as (select * from t1) , s30 as (select * from t1) , s29 as (select * from t1) , s28 as (select * from t1) , s27 as (select * from t1) , s26 as (select * from t1) , s25 as (select * from t1) , s24 as (select * from t1) , s23 as (select * from t1) , s22 as (select * from t1) , s21 as (select * from t1) , s20 as (select * from t1) , s19 as (select * from t1) , s18 as (select * from t1) , s17 as (select * from t1) , s16 as (select * from t1) , s15 as (select * from t1) , s14 as (select * from t1) , s13 as (select * from t1) , s12 as (select * from t1) , s11 as (select * from t1) , s10 as (select * from t1) , s9 as (select * from t1) , s8 as (select * from t1) , s7 as (select * from t1) , s6 as (select * from t1) , s5 as (select * from t1) , s4 as (select * from t1) , s3 as (select * from t1) , s2 as (select * from t1) , s1 as (select * from t1) select * from s65; +ERROR HY000: Too many WITH elements in WITH clause drop table t1,t2; # # Bug mdev-9937: View used in the specification of with table diff --git a/mysql-test/r/cte_recursive.result b/mysql-test/r/cte_recursive.result index f6ab5ee5dd7..5769948203e 100644 --- a/mysql-test/r/cte_recursive.result +++ b/mysql-test/r/cte_recursive.result @@ -160,6 +160,8 @@ insert into folks values (6, 'Grandgrandma Martha', '1923-05-17', null, null), (67, 'Cousin Eddie', '1992-02-28', 25, 27), (27, 'Auntie Melinda', '1971-03-29', null, null); +# simple recursion with one anchor and one recursive select +# the anchor is the first select in the specification with recursive ancestors as @@ -182,6 +184,8 @@ id name dob father mother 7 Grandma Sally 1943-08-23 NULL 6 8 Grandpa Ben 1940-10-21 NULL NULL 6 Grandgrandma Martha 1923-05-17 NULL NULL +# simple recursion with one anchor and one recursive select +# the anchor is the last select in the specification with recursive ancestors as @@ -204,6 +208,8 @@ id name dob father mother 7 Grandma Sally 1943-08-23 NULL 6 8 Grandpa Ben 1940-10-21 NULL NULL 6 Grandgrandma Martha 1923-05-17 NULL NULL +# simple recursion with one anchor and one recursive select +# the anchor is the first select in the specification with recursive ancestors as @@ -224,29 +230,7 @@ id name dob father mother 7 Grandma Sally 1943-08-23 NULL 6 8 Grandpa Ben 1940-10-21 NULL NULL 6 Grandgrandma Martha 1923-05-17 NULL NULL -with recursive -ancestors -as -( -select * -from folks -where name = 'Me' or name='Sister Amy' - union -select p.* -from folks as p, ancestors as a -where p.id = a.father or p.id = a.mother -) -select * from ancestors; -id name dob father mother -100 Me 2000-01-01 20 30 -98 Sister Amy 2001-06-20 20 30 -20 Dad 1970-02-02 10 9 -30 Mom 1975-03-03 8 7 -10 Grandpa Bill 1940-04-05 NULL NULL -9 Grandma Ann 1941-10-15 NULL NULL -7 Grandma Sally 1943-08-23 NULL 6 -8 Grandpa Ben 1940-10-21 NULL NULL -6 Grandgrandma Martha 1923-05-17 NULL NULL +# two recursive definition, one uses another with recursive prev_gen as @@ -282,6 +266,50 @@ Grandma Ann 1941-10-15 Grandma Sally 1943-08-23 Grandpa Ben 1940-10-21 Grandgrandma Martha 1923-05-17 +# recursive definition with two attached non-recursive +with recursive +ancestors(id,name,dob) +as +( +with +father(child_id,id,name,dob) +as +( +select folks.id, f.id, f.name, f.dob +from folks, folks f +where folks.father=f.id +), +mother(child_id,id,name,dob) +as +( +select folks.id, m.id, m.name, m.dob +from folks, folks m +where folks.mother=m.id +) +select folks.id, folks.name, folks.dob +from folks +where name='Me' + union +select f.id, f.name, f.dob +from ancestors a, father f +where f.child_id=a.id +union +select m.id, m.name, m.dob +from ancestors a, mother m +where m.child_id=a.id +) +select ancestors.name, ancestors.dob from ancestors; +name dob +Me 2000-01-01 +Dad 1970-02-02 +Mom 1975-03-03 +Grandpa Bill 1940-04-05 +Grandpa Ben 1940-10-21 +Grandma Ann 1941-10-15 +Grandma Sally 1943-08-23 +Grandgrandma Martha 1923-05-17 +# simple recursion with one anchor and one recursive select +# the anchor is the first select in the specification with recursive descendants as @@ -300,6 +328,8 @@ id name dob father mother 20 Dad 1970-02-02 10 9 100 Me 2000-01-01 20 30 98 Sister Amy 2001-06-20 20 30 +# simple recursion with one anchor and one recursive select +# the anchor is the first select in the specification with recursive descendants as @@ -320,6 +350,7 @@ id name dob father mother 100 Me 2000-01-01 20 30 98 Sister Amy 2001-06-20 20 30 67 Cousin Eddie 1992-02-28 25 27 +# simple recursive table used three times in the main query with recursive ancestors as @@ -340,6 +371,7 @@ id name dob father mother id name dob father mother 20 Dad 1970-02-02 10 9 30 Mom 1975-03-03 8 7 10 Grandpa Bill 1940-04-05 NULL NULL 9 Grandma Ann 1941-10-15 NULL NULL 8 Grandpa Ben 1940-10-21 NULL NULL 7 Grandma Sally 1943-08-23 NULL 6 +# simple recursive table used three times in the main query with ancestor_couples(husband, h_dob, wife, w_dob) as @@ -366,6 +398,7 @@ husband h_dob wife w_dob Dad 1970-02-02 Mom 1975-03-03 Grandpa Bill 1940-04-05 Grandma Ann 1941-10-15 Grandpa Ben 1940-10-21 Grandma Sally 1943-08-23 +# simple recursion with two selects in recursive part with recursive ancestors as @@ -392,6 +425,7 @@ id name dob father mother 9 Grandma Ann 1941-10-15 NULL NULL 7 Grandma Sally 1943-08-23 NULL 6 6 Grandgrandma Martha 1923-05-17 NULL NULL +# mutual recursion with renaming with recursive ancestor_couples(h_id, h_name, h_dob, h_father, h_mother, w_id, w_name, w_dob, w_father, w_mother) @@ -421,6 +455,7 @@ h_name h_dob w_name w_dob Dad 1970-02-02 Mom 1975-03-03 Grandpa Bill 1940-04-05 Grandma Ann 1941-10-15 Grandpa Ben 1940-10-21 Grandma Sally 1943-08-23 +# mutual recursion with union all with recursive ancestor_couples(h_id, h_name, h_dob, h_father, h_mother, w_id, w_name, w_dob, w_father, w_mother) @@ -450,6 +485,37 @@ h_name h_dob w_name w_dob Dad 1970-02-02 Mom 1975-03-03 Grandpa Bill 1940-04-05 Grandma Ann 1941-10-15 Grandpa Ben 1940-10-21 Grandma Sally 1943-08-23 +# mutual recursion with renaming +with recursive +ancestor_couples(h_id, h_name, h_dob, h_father, h_mother, +w_id, w_name, w_dob, w_father, w_mother) +as +( +select h.*, w.* +from folks h, folks w, coupled_ancestors a +where a.father = h.id AND a.mother = w.id +union +select h.*, w.* +from folks v, folks h, folks w +where v.name = 'Me' and +(v.father = h.id AND v.mother= w.id) +), +coupled_ancestors (id, name, dob, father, mother) +as +( +select h_id, h_name, h_dob, h_father, h_mother +from ancestor_couples +union +select w_id, w_name, w_dob, w_father, w_mother +from ancestor_couples +) +select h_name, h_dob, w_name, w_dob +from ancestor_couples; +h_name h_dob w_name w_dob +Dad 1970-02-02 Mom 1975-03-03 +Grandpa Bill 1940-04-05 Grandma Ann 1941-10-15 +Grandpa Ben 1940-10-21 Grandma Sally 1943-08-23 +# mutual recursion with union all with recursive ancestor_couples(h_id, h_name, h_dob, h_father, h_mother, w_id, w_name, w_dob, w_father, w_mother) @@ -478,6 +544,7 @@ h_name h_dob w_name w_dob Dad 1970-02-02 Mom 1975-03-03 Grandpa Bill 1940-04-05 Grandma Ann 1941-10-15 Grandpa Ben 1940-10-21 Grandma Sally 1943-08-23 +# mutual recursion with one select in the first definition with recursive ancestor_couple_ids(h_id, w_id) as @@ -507,6 +574,7 @@ h_id w_id 20 30 10 9 8 7 +# join of a mutually recursive table with base tables with recursive ancestor_couple_ids(h_id, w_id) as @@ -537,6 +605,7 @@ name dob name dob Dad 1970-02-02 Mom 1975-03-03 Grandpa Bill 1940-04-05 Grandma Ann 1941-10-15 Grandpa Ben 1940-10-21 Grandma Sally 1943-08-23 +# join of two mutually recursive tables with recursive ancestor_couple_ids(h_id, w_id) as @@ -607,6 +676,7 @@ NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL 2 UNCACHEABLE SUBQUERY ALL NULL NULL NULL NULL 12 100.00 Using where Warnings: Note 1003 with recursive ancestor_couple_ids as (select `a`.`father` AS `h_id`,`a`.`mother` AS `w_id` from `coupled_ancestors` `a` where ((`a`.`father` is not null) and (`a`.`mother` is not null)))coupled_ancestors as (select `test`.`folks`.`id` AS `id`,`test`.`folks`.`name` AS `name`,`test`.`folks`.`dob` AS `dob`,`test`.`folks`.`father` AS `father`,`test`.`folks`.`mother` AS `mother` from `test`.`folks` where (`test`.`folks`.`name` = 'Me') union all select `test`.`p`.`id` AS `id`,`test`.`p`.`name` AS `name`,`test`.`p`.`dob` AS `dob`,`test`.`p`.`father` AS `father`,`test`.`p`.`mother` AS `mother` from `test`.`folks` `p` join `ancestor_couple_ids` `fa` where (`test`.`p`.`id` = `fa`.`h_id`) union all select `test`.`p`.`id` AS `id`,`test`.`p`.`name` AS `name`,`test`.`p`.`dob` AS `dob`,`test`.`p`.`father` AS `father`,`test`.`p`.`mother` AS `mother` from `test`.`folks` `p` join `ancestor_couple_ids` `ma` where (`test`.`p`.`id` = `ma`.`w_id`)), select `h`.`name` AS `name`,`h`.`dob` AS `dob`,`w`.`name` AS `name`,`w`.`dob` AS `dob` from `ancestor_couple_ids` `c` join `coupled_ancestors` `h` join `coupled_ancestors` `w` where ((`h`.`id` = `c`.`h_id`) and (`w`.`id` = `c`.`w_id`)) +# simple mutual recursion with recursive ancestor_couple_ids(h_id, w_id) as @@ -640,6 +710,7 @@ NULL NULL NULL NULL NULL 6 NULL NULL +# join of two mutually recursive tables with recursive ancestor_couple_ids(h_id, w_id) as @@ -669,6 +740,7 @@ name dob name dob Dad 1970-02-02 Mom 1975-03-03 Grandpa Bill 1940-04-05 Grandma Ann 1941-10-15 Grandpa Ben 1940-10-21 Grandma Sally 1943-08-23 +# execution of prepared query using a recursive table prepare stmt1 from " with recursive ancestors @@ -705,6 +777,7 @@ id name dob father mother 8 Grandpa Ben 1940-10-21 NULL NULL 6 Grandgrandma Martha 1923-05-17 NULL NULL deallocate prepare stmt1; +# view using a recursive table create view v1 as with recursive ancestors @@ -786,6 +859,7 @@ id select_type table type possible_keys key key_len ref rows filtered Extra NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL Warnings: Note 1003 with recursive ancestors as (select `test`.`folks`.`id` AS `id`,`test`.`folks`.`name` AS `name`,`test`.`folks`.`dob` AS `dob`,`test`.`folks`.`father` AS `father`,`test`.`folks`.`mother` AS `mother` from `test`.`folks` where ((`test`.`folks`.`name` = 'Me') and (`test`.`folks`.`dob` = DATE'2000-01-01')) union select `p`.`id` AS `id`,`p`.`name` AS `name`,`p`.`dob` AS `dob`,`p`.`father` AS `father`,`p`.`mother` AS `mother` from `test`.`folks` `p` join `ancestors` `a` where ((`a`.`father` = `p`.`id`) or (`a`.`mother` = `p`.`id`)))select `ancestors`.`id` AS `id`,`ancestors`.`name` AS `name`,`ancestors`.`dob` AS `dob`,`ancestors`.`father` AS `father`,`ancestors`.`mother` AS `mother` from `ancestors` +# recursive spec with two anchor selects and two recursive ones with recursive ancestor_ids (id) as @@ -813,6 +887,7 @@ id name dob father mother 7 Grandma Sally 1943-08-23 NULL 6 8 Grandpa Ben 1940-10-21 NULL NULL 6 Grandgrandma Martha 1923-05-17 NULL NULL +# recursive spec using union all with recursive ancestors as @@ -1115,6 +1190,7 @@ generation name 2 Grandma Ann 2 Grandma Sally 2 Grandpa Ben +# query with recursive tables using key access alter table folks add primary key (id); explain with recursive diff --git a/mysql-test/t/cte_nonrecursive.test b/mysql-test/t/cte_nonrecursive.test index eb6677e7f75..414b1c27687 100644 --- a/mysql-test/t/cte_nonrecursive.test +++ b/mysql-test/t/cte_nonrecursive.test @@ -469,6 +469,20 @@ explain with t as (select a, count(*) from t1 where b >= 'c' group by a) select t1.b from t2,t1 where t1.a = t2.c; +--echo # too many with elements in with clause +let $m= 65; +let $i= $m; +dec $i; +let $q= with s$m as (select * from t1); +while ($i) +{ + let $q= $q, s$i as (select * from t1) ; + dec $i; + } +let $q= $q select * from s$m; +--ERROR ER_TOO_MANY_DEFINITIONS_IN_WITH_CLAUSE +eval $q; + drop table t1,t2; --echo # diff --git a/mysql-test/t/cte_recursive.test b/mysql-test/t/cte_recursive.test index 98fe159e174..d795ea81b23 100644 --- a/mysql-test/t/cte_recursive.test +++ b/mysql-test/t/cte_recursive.test @@ -156,7 +156,8 @@ insert into folks values (67, 'Cousin Eddie', '1992-02-28', 25, 27), (27, 'Auntie Melinda', '1971-03-29', null, null); - +--echo # simple recursion with one anchor and one recursive select +--echo # the anchor is the first select in the specification with recursive ancestors as @@ -171,6 +172,8 @@ as ) select * from ancestors; +--echo # simple recursion with one anchor and one recursive select +--echo # the anchor is the last select in the specification with recursive ancestors as @@ -185,6 +188,8 @@ as ) select * from ancestors; +--echo # simple recursion with one anchor and one recursive select +--echo # the anchor is the first select in the specification with recursive ancestors as @@ -199,20 +204,8 @@ as ) select * from ancestors; -with recursive -ancestors -as -( - select * - from folks - where name = 'Me' or name='Sister Amy' - union - select p.* - from folks as p, ancestors as a - where p.id = a.father or p.id = a.mother -) -select * from ancestors; +--echo # two recursive definition, one uses another with recursive prev_gen as @@ -240,7 +233,45 @@ as ) select ancestors.name, ancestors.dob from ancestors; +--echo # recursive definition with two attached non-recursive +with recursive +ancestors(id,name,dob) +as +( + with + father(child_id,id,name,dob) + as + ( + select folks.id, f.id, f.name, f.dob + from folks, folks f + where folks.father=f.id + + ), + mother(child_id,id,name,dob) + as + ( + select folks.id, m.id, m.name, m.dob + from folks, folks m + where folks.mother=m.id + + ) + select folks.id, folks.name, folks.dob + from folks + where name='Me' + union + select f.id, f.name, f.dob + from ancestors a, father f + where f.child_id=a.id + union + select m.id, m.name, m.dob + from ancestors a, mother m + where m.child_id=a.id + +) +select ancestors.name, ancestors.dob from ancestors; +--echo # simple recursion with one anchor and one recursive select +--echo # the anchor is the first select in the specification with recursive descendants as @@ -255,6 +286,8 @@ as ) select * from descendants; +--echo # simple recursion with one anchor and one recursive select +--echo # the anchor is the first select in the specification with recursive descendants as @@ -270,6 +303,7 @@ as select * from descendants; +--echo # simple recursive table used three times in the main query with recursive ancestors as @@ -287,6 +321,8 @@ select * where exists (select * from ancestors a where a.father=t1.id AND a.mother=t2.id); + +--echo # simple recursive table used three times in the main query with ancestor_couples(husband, h_dob, wife, w_dob) as @@ -310,6 +346,8 @@ select t1.name, t1.dob, t2.name, t2.dob ) select * from ancestor_couples; + +--echo # simple recursion with two selects in recursive part with recursive ancestors as @@ -328,6 +366,8 @@ as ) select * from ancestors; + +--echo # mutual recursion with renaming with recursive ancestor_couples(h_id, h_name, h_dob, h_father, h_mother, w_id, w_name, w_dob, w_father, w_mother) @@ -355,6 +395,7 @@ select h_name, h_dob, w_name, w_dob from ancestor_couples; +--echo # mutual recursion with union all with recursive ancestor_couples(h_id, h_name, h_dob, h_father, h_mother, w_id, w_name, w_dob, w_father, w_mother) @@ -382,6 +423,35 @@ select h_name, h_dob, w_name, w_dob from ancestor_couples; +--echo # mutual recursion with renaming +with recursive +ancestor_couples(h_id, h_name, h_dob, h_father, h_mother, + w_id, w_name, w_dob, w_father, w_mother) +as +( + select h.*, w.* + from folks h, folks w, coupled_ancestors a + where a.father = h.id AND a.mother = w.id + union + select h.*, w.* + from folks v, folks h, folks w + where v.name = 'Me' and + (v.father = h.id AND v.mother= w.id) +), +coupled_ancestors (id, name, dob, father, mother) +as +( + select h_id, h_name, h_dob, h_father, h_mother + from ancestor_couples + union + select w_id, w_name, w_dob, w_father, w_mother + from ancestor_couples +) +select h_name, h_dob, w_name, w_dob + from ancestor_couples; + + +--echo # mutual recursion with union all with recursive ancestor_couples(h_id, h_name, h_dob, h_father, h_mother, w_id, w_name, w_dob, w_father, w_mother) @@ -407,7 +477,7 @@ as select h_name, h_dob, w_name, w_dob from ancestor_couples; - +--echo # mutual recursion with one select in the first definition with recursive ancestor_couple_ids(h_id, w_id) as @@ -434,6 +504,8 @@ as select * from ancestor_couple_ids; + +--echo # join of a mutually recursive table with base tables with recursive ancestor_couple_ids(h_id, w_id) as @@ -462,6 +534,7 @@ select h.name, h.dob, w.name, w.dob where c.h_id = h.id and c.w_id= w.id; +--echo # join of two mutually recursive tables with recursive ancestor_couple_ids(h_id, w_id) as @@ -517,6 +590,8 @@ select h.name, h.dob, w.name, w.dob from ancestor_couple_ids c, coupled_ancestors h, coupled_ancestors w where c.h_id = h.id and c.w_id= w.id; + +--echo # simple mutual recursion with recursive ancestor_couple_ids(h_id, w_id) as @@ -543,6 +618,7 @@ select * from ancestor_couple_ids; +--echo # join of two mutually recursive tables with recursive ancestor_couple_ids(h_id, w_id) as @@ -570,6 +646,7 @@ select h.name, h.dob, w.name, w.dob where c.h_id = h.id and c.w_id= w.id; +--echo # execution of prepared query using a recursive table prepare stmt1 from " with recursive ancestors @@ -592,6 +669,7 @@ execute stmt1; deallocate prepare stmt1; +--echo # view using a recursive table create view v1 as with recursive ancestors @@ -636,6 +714,7 @@ select * from v2; drop view v1,v2; + explain extended with recursive ancestors @@ -652,6 +731,7 @@ as select * from ancestors; +--echo # recursive spec with two anchor selects and two recursive ones with recursive ancestor_ids (id) as @@ -672,6 +752,8 @@ as ) select * from ancestors; + +--echo # recursive spec using union all with recursive ancestors as @@ -691,8 +773,6 @@ as select * from ancestors; - - --ERROR ER_NOT_STANDARDS_COMPLIANT_RECURSIVE with recursive ancestor_ids (id, generation) @@ -937,6 +1017,8 @@ as ) select * from ancestors; +--echo # query with recursive tables using key access + alter table folks add primary key (id); explain @@ -958,6 +1040,7 @@ as ) select * from ancestors; + with recursive ancestors as diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index e1db12d2544..1dce05af943 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7150,6 +7150,8 @@ ER_BAD_COMMAND_IN_MULTI ukr "Команда '%s' не дозволена для COM_MULTI" ER_WITH_COL_WRONG_LIST eng "WITH column list and SELECT field list have different column counts" +ER_TOO_MANY_DEFINITIONS_IN_WITH_CLAUSE + eng "Too many WITH elements in WITH clause" ER_DUP_QUERY_NAME eng "Duplicate query name in WITH clause" ER_RECURSIVE_WITHOUT_ANCHORS diff --git a/sql/sql_class.h b/sql/sql_class.h index be263a6b902..99a5403ff04 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -4681,8 +4681,11 @@ public: class select_union_recursive :public select_union { public: + /* The temporary table with the new records generated by one iterative step */ TABLE *incr_table; + /* One of tables from the list rec_tables (determined dynamically) */ TABLE *first_rec_table_to_update; + /* The temporary tables used for recursive table references */ List rec_tables; select_union_recursive(THD *thd_arg): diff --git a/sql/sql_cte.cc b/sql/sql_cte.cc index 82958333f65..fa18de0f49f 100644 --- a/sql/sql_cte.cc +++ b/sql/sql_cte.cc @@ -6,6 +6,38 @@ #include "sql_select.h" +/** + @brief + Add a new element to this with clause + + @param elem The with element to add to this with clause + + @details + The method adds the with element 'elem' to the elements + in this with clause. The method reports an error if + the number of the added element exceeds the value + of the constant max_number_of_elements_in_with_clause. + + @retval + true if an error is reported + false otherwise +*/ + +bool With_clause::add_with_element(With_element *elem) +{ + if (with_list.elements == max_number_of_elements_in_with_clause) + { + my_error(ER_TOO_MANY_DEFINITIONS_IN_WITH_CLAUSE, MYF(0)); + return true; + } + elem->owner= this; + elem->number= with_list.elements; + elem->spec->with_element= elem; + with_list.link_in_list(elem, &elem->next); + return false; +} + + /** @brief Check dependencies between tables defined in a list of with clauses diff --git a/sql/sql_cte.h b/sql/sql_cte.h index 20164174214..94fad561b0d 100644 --- a/sql/sql_cte.h +++ b/sql/sql_cte.h @@ -210,6 +210,8 @@ public: friend class With_clause; }; +const uint max_number_of_elements_in_with_clause= sizeof(table_map)*8; + /** @class With_clause @brief Set of with_elements @@ -270,15 +272,7 @@ public: with_recursive(recursive_fl) { } - /* Add a new element to the current with clause */ - bool add_with_element(With_element *elem) - { - elem->owner= this; - elem->number= with_list.elements; - elem->spec->with_element= elem; - with_list.link_in_list(elem, &elem->next); - return false; - } + bool add_with_element(With_element *elem); /* Add this with clause to the list of with clauses used in the statement */ void add_to_list(With_clause ** &last_next) diff --git a/sql/sql_derived.cc b/sql/sql_derived.cc index 33befdd4639..6297cc6eb84 100644 --- a/sql/sql_derived.cc +++ b/sql/sql_derived.cc @@ -644,16 +644,21 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) if (unit->prepared && derived->is_recursive_with_table() && !derived->table) { + /* + Here 'derived' is either a non-recursive table reference to a recursive + with table or a recursive table reference to a recursvive table whose + specification has been already prepared (a secondary recursive table + reference. + */ if (!(derived->derived_result= new (thd->mem_root) select_union(thd))) DBUG_RETURN(TRUE); // out of memory thd->create_tmp_table_for_derived= TRUE; - if (!derived->table) - res= derived->derived_result->create_result_table( - thd, &unit->types, FALSE, - (first_select->options | - thd->variables.option_bits | - TMP_TABLE_ALL_COLUMNS), - derived->alias, FALSE, FALSE); + res= derived->derived_result->create_result_table( + thd, &unit->types, FALSE, + (first_select->options | + thd->variables.option_bits | + TMP_TABLE_ALL_COLUMNS), + derived->alias, FALSE, FALSE); thd->create_tmp_table_for_derived= FALSE; if (!res && !derived->table) @@ -662,6 +667,7 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) derived->table= derived->derived_result->table; if (derived->is_with_table_recursive_reference()) { + /* Here 'derived" is a secondary recursive table reference */ unit->with_element->rec_result->rec_tables.push_back(derived->table); } } @@ -685,7 +691,12 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) (!derived->with->with_anchor && !derived->with->is_with_prepared_anchor())) { - // Prepare underlying views/DT first. + /* + Prepare underlying views/DT first unless 'derived' is a recursive + table reference and either the anchors from the specification of + 'derived' has been already prepared or there no anchor in this + specification + */ if ((res= sl->handle_derived(lex, DT_PREPARE))) goto exit; } @@ -922,30 +933,41 @@ bool mysql_derived_create(THD *thd, LEX *lex, TABLE_LIST *derived) } +/** + @brief + Fill the recursive with table + + @param thd The thread handle + + @details + The method is called only for recursive with tables. + The method executes the recursive part of the specification + of this with table until no more rows are added to the table + or the number of the performed iteration reaches the allowed + maximum. + + @retval + false on success + true on failure +*/ + bool TABLE_LIST::fill_recursive(THD *thd) { bool rc= false; st_select_lex_unit *unit= get_unit(); - if (is_with_table_recursive_reference()) + rc= with->instantiate_tmp_tables(); + while (!rc && !with->all_are_stabilized()) { + if (with->level > thd->variables.max_recursive_iterations) + break; + with->prepare_for_next_iteration(); rc= unit->exec_recursive(); } - else + if (!rc) { - rc= with->instantiate_tmp_tables(); - while (!rc && !with->all_are_stabilized()) - { - if (with->level > thd->variables.max_recursive_iterations) - break; - with->prepare_for_next_iteration(); - rc= unit->exec_recursive(); - } - if (!rc) - { - TABLE *src= with->rec_result->table; - rc =src->insert_all_rows_into(thd, table, true); - } - } + TABLE *src= with->rec_result->table; + rc =src->insert_all_rows_into(thd, table, true); + } return rc; } @@ -960,9 +982,10 @@ bool TABLE_LIST::fill_recursive(THD *thd) @details Execute subquery of given 'derived' table/view and fill the result - table. After result table is filled, if this is not the EXPLAIN statement, - the entire unit / node is deleted. unit is deleted if UNION is used - for derived table and node is deleted is it is a simple SELECT. + table. After result table is filled, if this is not the EXPLAIN statement + and the table is not specified with a recursion the entire unit / node + is deleted. unit is deleted if UNION is used for derived table and node + is deleted is it is a simple SELECT. 'lex' is unused and 'thd' is passed as an argument to an underlying function. @note @@ -986,13 +1009,21 @@ bool mysql_derived_fill(THD *thd, LEX *lex, TABLE_LIST *derived) DBUG_RETURN(FALSE); /*check that table creation passed without problems. */ DBUG_ASSERT(derived->table && derived->table->is_created()); - SELECT_LEX *first_select= unit->first_select(); select_union *derived_result= derived->derived_result; SELECT_LEX *save_current_select= lex->current_select; if (derived_is_recursive) { - res= derived->fill_recursive(thd); + if (derived->is_with_table_recursive_reference()) + { + /* Here only one iteration step is performed */ + res= unit->exec_recursive(); + } + else + { + /* In this case all iteration are performed */ + res= derived->fill_recursive(thd); + } } else if (unit->is_union()) { @@ -1001,6 +1032,7 @@ bool mysql_derived_fill(THD *thd, LEX *lex, TABLE_LIST *derived) } else { + SELECT_LEX *first_select= unit->first_select(); unit->set_limit(unit->global_parameters()); if (unit->select_limit_cnt == HA_POS_ERROR) first_select->options&= ~OPTION_FOUND_ROWS; diff --git a/sql/sql_union.cc b/sql/sql_union.cc index 185d79ec77a..40f01a4db38 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -100,6 +100,7 @@ int select_union::send_data(List &values) return 0; } + int select_union_recursive::send_data(List &values) { int rc= select_union::send_data(values); @@ -1166,7 +1167,29 @@ err: } -// One step of recursive execution +/** + @brief + Execute the union of the specification of a recursive with table + + @details + The method is performed only for the units that are specifications + if recursive with table T. If the specification contains an anchor + part then the first call of this method executes only this part + while the following calls execute the recursive part. If there are + no anchors each call executes the whole unit. + Before the excution the method cleans up the temporary table + to where the new rows of the recursive table are sent. + After the execution the unit these rows are copied to the + temporary tables created for recursive references of T. + If the specification if T is restricted (standards compliant) + then these temporary tables are cleaned up before new rows + are copied into them. + + @retval + false on success + true on failure +*/ + bool st_select_lex_unit::exec_recursive() { st_select_lex *lex_select_save= thd->lex->current_select;