From d9b332bd2009cc520534bb9413e2f50c717237aa Mon Sep 17 00:00:00 2001 From: Galina Shalygina Date: Thu, 12 May 2016 23:23:12 +0300 Subject: [PATCH] Made prepared statement, explain and views working with recursuve CTE. --- mysql-test/r/cte_nonrecursive.result | 8 +-- mysql-test/r/cte_recursive.result | 83 ++++++++++++++++++++++++++++ mysql-test/t/cte_recursive.test | 61 ++++++++++++++++++++ sql/sql_cte.cc | 20 +++++-- sql/sql_cte.h | 23 +++++--- sql/sql_select.cc | 4 +- sql/sql_union.cc | 10 +++- sql/sql_view.cc | 10 ++++ 8 files changed, 198 insertions(+), 21 deletions(-) diff --git a/mysql-test/r/cte_nonrecursive.result b/mysql-test/r/cte_nonrecursive.result index 2cc291dcfbc..d81c7c9ed4c 100644 --- a/mysql-test/r/cte_nonrecursive.result +++ b/mysql-test/r/cte_nonrecursive.result @@ -534,7 +534,7 @@ with t as (select a from t1 where b >= 'c') select * from t2,t where t2.c=t.a; show create view v1; View Create View character_set_client collation_connection -v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS WITH t AS (select `t1`.`a` AS `a` from `t1` where (`t1`.`b` >= 'c'))select `t2`.`c` AS `c`,`t`.`a` AS `a` from (`t2` join `t`) where (`t2`.`c` = `t`.`a`) latin1 latin1_swedish_ci +v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS with t as (select `t1`.`a` AS `a` from `t1` where (`t1`.`b` >= 'c'))select `t2`.`c` AS `c`,`t`.`a` AS `a` from (`t2` join `t`) where (`t2`.`c` = `t`.`a`) latin1 latin1_swedish_ci select * from v1; c a 4 4 @@ -552,7 +552,7 @@ with t as (select a, count(*) from t1 where b >= 'c' group by a) select * from t2,t where t2.c=t.a; show create view v2; View Create View character_set_client collation_connection -v2 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v2` AS WITH t AS (select `t1`.`a` AS `a`,count(0) AS `count(*)` from `t1` where (`t1`.`b` >= 'c') group by `t1`.`a`)select `t2`.`c` AS `c`,`t`.`a` AS `a`,`t`.`count(*)` AS `count(*)` from (`t2` join `t`) where (`t2`.`c` = `t`.`a`) latin1 latin1_swedish_ci +v2 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v2` AS with t as (select `t1`.`a` AS `a`,count(0) AS `count(*)` from `t1` where (`t1`.`b` >= 'c') group by `t1`.`a`)select `t2`.`c` AS `c`,`t`.`a` AS `a`,`t`.`count(*)` AS `count(*)` from (`t2` join `t`) where (`t2`.`c` = `t`.`a`) latin1 latin1_swedish_ci select * from v2; c a count(*) 4 4 2 @@ -571,7 +571,7 @@ with t(c) as (select a from t1 where b >= 'c') select * from t r1 where r1.c=4; show create view v3; View Create View character_set_client collation_connection -v3 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v3` AS WITH t AS (select `t1`.`a` AS `c` from `t1` where (`t1`.`b` >= 'c'))select `r1`.`c` AS `c` from `t` `r1` where (`r1`.`c` = 4) latin1 latin1_swedish_ci +v3 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v3` AS with t as (select `t1`.`a` AS `c` from `t1` where (`t1`.`b` >= 'c'))select `r1`.`c` AS `c` from `t` `r1` where (`r1`.`c` = 4) latin1 latin1_swedish_ci select * from v3; c 4 @@ -583,7 +583,7 @@ with t(c) as (select a from t1 where b >= 'c') select * from t r1, t r2 where r1.c=r2.c and r2.c=4; show create view v4; View Create View character_set_client collation_connection -v4 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v4` AS WITH t AS (select `t1`.`a` AS `c` from `t1` where (`t1`.`b` >= 'c'))select `r1`.`c` AS `c`,`r2`.`c` AS `d` from (`t` `r1` join `t` `r2`) where ((`r1`.`c` = `r2`.`c`) and (`r2`.`c` = 4)) latin1 latin1_swedish_ci +v4 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v4` AS with t as (select `t1`.`a` AS `c` from `t1` where (`t1`.`b` >= 'c'))select `r1`.`c` AS `c`,`r2`.`c` AS `d` from (`t` `r1` join `t` `r2`) where ((`r1`.`c` = `r2`.`c`) and (`r2`.`c` = 4)) latin1 latin1_swedish_ci select * from v4; c d 4 4 diff --git a/mysql-test/r/cte_recursive.result b/mysql-test/r/cte_recursive.result index 7408bc56e63..77b391d6629 100644 --- a/mysql-test/r/cte_recursive.result +++ b/mysql-test/r/cte_recursive.result @@ -286,4 +286,87 @@ 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 +prepare stmt1 from " +with recursive +ancestors +as +( + select * + from folks + where name = 'Vasya' and dob = '2000-01-01' + union + select p.id, p.name, p.dob, p.father, p.mother + from folks as p, ancestors AS a + where p.id = a.father or p.id = a.mother +) +select * from ancestors; +"; +execute stmt1; +id name dob father mother +100 Vasya 2000-01-01 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 +8 Grandma Sally 1943-08-23 5 6 +6 Grandgrandma Martha 1923-05-17 NULL NULL +execute stmt1; +id name dob father mother +100 Vasya 2000-01-01 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 +8 Grandma Sally 1943-08-23 5 6 +6 Grandgrandma Martha 1923-05-17 NULL NULL +deallocate prepare stmt1; +create view v1 as +with recursive +ancestors +as +( +select * +from folks +where name = 'Vasya' and dob = '2000-01-01' + union +select p.id, p.name, p.dob, p.father, p.mother +from folks as p, ancestors AS a +where p.id = a.father or p.id = a.mother +) +select * from ancestors; +show create view v1; +View Create View character_set_client collation_connection +v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS with recursive ancestors as (select `folks`.`id` AS `id`,`folks`.`name` AS `name`,`folks`.`dob` AS `dob`,`folks`.`father` AS `father`,`folks`.`mother` AS `mother` from `folks` where ((`folks`.`name` = 'Vasya') and (`folks`.`dob` = '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 (`folks` `p` join `ancestors` `a`) where ((`p`.`id` = `a`.`father`) or (`p`.`id` = `a`.`mother`)))select `ancestors`.`id` AS `id`,`ancestors`.`name` AS `name`,`ancestors`.`dob` AS `dob`,`ancestors`.`father` AS `father`,`ancestors`.`mother` AS `mother` from `ancestors` latin1 latin1_swedish_ci +select * from v1; +id name dob father mother +100 Vasya 2000-01-01 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 +8 Grandma Sally 1943-08-23 5 6 +6 Grandgrandma Martha 1923-05-17 NULL NULL +drop view v1; +explain extended +with recursive +ancestors +as +( +select * +from folks +where name = 'Vasya' and dob = '2000-01-01' + union +select p.id, p.name, p.dob, p.father, p.mother +from folks as p, ancestors AS a +where p.id = a.father or p.id = a.mother +) +select * from ancestors; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 132 100.00 +2 SUBQUERY folks ALL NULL NULL NULL NULL 11 100.00 Using where +3 UNCACHEABLE UNION p ALL NULL NULL NULL NULL 11 100.00 +3 UNCACHEABLE UNION ALL NULL NULL NULL NULL 11 100.00 Using where; Using join buffer (flat, BNL join) +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` = 'Vasya') 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` drop table folks; diff --git a/mysql-test/t/cte_recursive.test b/mysql-test/t/cte_recursive.test index a5ad1d66a51..47eae971c6d 100644 --- a/mysql-test/t/cte_recursive.test +++ b/mysql-test/t/cte_recursive.test @@ -237,5 +237,66 @@ as select h_name, h_dob, w_name, w_dob from ancestor_couples; + +prepare stmt1 from " +with recursive +ancestors +as +( + select * + from folks + where name = 'Vasya' and dob = '2000-01-01' + union + select p.id, p.name, p.dob, p.father, p.mother + from folks as p, ancestors AS a + where p.id = a.father or p.id = a.mother +) +select * from ancestors; +"; + +execute stmt1; +execute stmt1; + +deallocate prepare stmt1; + + +create view v1 as +with recursive +ancestors +as +( + select * + from folks + where name = 'Vasya' and dob = '2000-01-01' + union + select p.id, p.name, p.dob, p.father, p.mother + from folks as p, ancestors AS a + where p.id = a.father or p.id = a.mother +) +select * from ancestors; + +show create view v1; + +select * from v1; + +drop view v1; + + +explain extended +with recursive +ancestors +as +( + select * + from folks + where name = 'Vasya' and dob = '2000-01-01' + union + select p.id, p.name, p.dob, p.father, p.mother + from folks as p, ancestors AS a + where p.id = a.father or p.id = a.mother +) +select * from ancestors; + + drop table folks; diff --git a/sql/sql_cte.cc b/sql/sql_cte.cc index 04d53495400..7e60a8d1892 100644 --- a/sql/sql_cte.cc +++ b/sql/sql_cte.cc @@ -731,7 +731,7 @@ bool TABLE_LIST::is_with_table_recursive_reference() bool st_select_lex::check_unrestricted_recursive() { With_element *with_elem= get_with_element(); - if (!with_elem) + if (!with_elem ||!with_elem->is_recursive) return false; table_map unrestricted= 0; table_map encountered= 0; @@ -806,6 +806,18 @@ bool With_element::check_unrestricted_recursive(st_select_lex *sel, } } } + ti.rewind(); + while ((tbl= ti++)) + { + for (TABLE_LIST *tab= tbl; tab; tab= tab->embedding) + { + if (tab->outer_join & (JOIN_TYPE_LEFT | JOIN_TYPE_RIGHT)) + { + unrestricted|= get_elem_map(); + break; + } + } + } return false; } @@ -824,9 +836,9 @@ bool With_element::check_unrestricted_recursive(st_select_lex *sel, void With_clause::print(String *str, enum_query_type query_type) { - str->append(STRING_WITH_LEN("WITH ")); + str->append(STRING_WITH_LEN("with ")); if (with_recursive) - str->append(STRING_WITH_LEN("RECURSIVE ")); + str->append(STRING_WITH_LEN("recursive ")); for (With_element *with_elem= first_elem; with_elem != NULL; with_elem= with_elem->next_elem) @@ -853,7 +865,7 @@ void With_clause::print(String *str, enum_query_type query_type) void With_element::print(String *str, enum_query_type query_type) { str->append(query_name); - str->append(STRING_WITH_LEN(" AS ")); + str->append(STRING_WITH_LEN(" as ")); str->append('('); spec->print(str, query_type); str->append(')'); diff --git a/sql/sql_cte.h b/sql/sql_cte.h index b559be93de5..0312fcd0643 100644 --- a/sql/sql_cte.h +++ b/sql/sql_cte.h @@ -82,9 +82,8 @@ public: uint level; - select_union *partial_result; - select_union *final_result; select_union_recursive *rec_result; + TABLE *result_table; With_element(LEX_STRING *name, @@ -95,9 +94,8 @@ public: references(0), table(NULL), query_name(name), column_list(list), spec(unit), is_recursive(false), with_anchor(false), - partial_result(NULL), final_result(NULL), - rec_result(NULL), result_table(NULL) - { reset();} + level(0), rec_result(NULL), result_table(NULL) + {} bool check_dependencies_in_spec(THD *thd); @@ -147,10 +145,7 @@ public: void mark_as_cleaned(); - void reset() - { - level= 0; - } + void reset_for_exec(); void set_result_table(TABLE *tab) { result_table= tab; } @@ -284,4 +279,14 @@ void With_element::mark_as_cleaned() owner->cleaned|= get_elem_map(); } + +inline +void With_element::reset_for_exec() +{ + level= 0; + owner->with_prepared_anchor&= ~mutually_recursive; + owner->cleaned&= ~get_elem_map(); +} + + #endif /* SQL_CTE_INCLUDED */ diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 0a961b4a53a..71b672b6131 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -816,6 +816,8 @@ JOIN::prepare(TABLE_LIST *tables_init, &hidden_group_fields, &select_lex->select_n_reserved)) DBUG_RETURN(-1); + if (select_lex->check_unrestricted_recursive()) + DBUG_RETURN(-1); /* Resolve the ORDER BY that was skipped, then remove it. */ if (skip_order_by && select_lex != select_lex->master_unit()->global_parameters()) @@ -24491,7 +24493,7 @@ bool mysql_explain_union(THD *thd, SELECT_LEX_UNIT *unit, select_result *result) if (unit->is_union()) { - if (unit->union_needs_tmp_table()) + if (unit->union_needs_tmp_table() && unit->fake_select_lex) { unit->fake_select_lex->select_number= FAKE_SELECT_LEX_ID; // just for initialization unit->fake_select_lex->type= "UNION RESULT"; diff --git a/sql/sql_union.cc b/sql/sql_union.cc index 7345c6f224e..902620aaac1 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -514,6 +514,7 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, with_element->rec_result= new (thd_arg->mem_root) select_union_recursive(thd_arg); union_result= with_element->rec_result; + fake_select_lex= NULL; } if (!(tmp_result= union_result)) goto err; /* purecov: inspected */ @@ -615,7 +616,8 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, TMP_TABLE_ALL_COLUMNS); if (union_result->create_result_table(thd, &types, MY_TEST(union_distinct), - create_options, "", false, + create_options, derived->alias, + false, instantiate_tmp_table, false)) goto err; if (!derived->table) @@ -932,7 +934,7 @@ bool st_select_lex_unit::exec() if (uncacheable || !item || !item->assigned() || describe) { - if (!fake_select_lex) + if (!fake_select_lex && !(with_element && with_element->is_recursive)) union_result->cleanup(); for (SELECT_LEX *sl= select_cursor; sl; sl= sl->next_select()) { @@ -973,7 +975,7 @@ bool st_select_lex_unit::exec() { records_at_start= table->file->stats.records; sl->join->exec(); - if (sl == union_distinct) + if (sl == union_distinct && !(with_element && with_element->is_recursive)) { // This is UNION DISTINCT, so there should be a fake_select_lex DBUG_ASSERT(fake_select_lex != NULL); @@ -1315,6 +1317,8 @@ void st_select_lex_unit::reinit_exec_mechanism() */ field->fixed= 0; } + if (with_element && with_element->is_recursive) + with_element->reset_for_exec(); } #endif } diff --git a/sql/sql_view.cc b/sql/sql_view.cc index b66f678adfc..4fd4fb8dd01 100644 --- a/sql/sql_view.cc +++ b/sql/sql_view.cc @@ -35,6 +35,7 @@ #include "sp_cache.h" #include "datadict.h" // dd_frm_is_view() #include "sql_derived.h" +#include "sql_cte.h" // check_dependencies_in_with_clauses() #define MD5_BUFF_LENGTH 33 @@ -429,6 +430,12 @@ bool mysql_create_view(THD *thd, TABLE_LIST *views, lex->link_first_table_back(view, link_to_local); view->open_type= OT_BASE_ONLY; + if (check_dependencies_in_with_clauses(thd, lex->with_clauses_list)) + { + res= TRUE; + goto err; + } + if (open_temporary_tables(thd, lex->query_tables) || open_and_lock_tables(thd, lex->query_tables, TRUE, 0)) { @@ -1383,6 +1390,9 @@ bool mysql_make_view(THD *thd, TABLE_SHARE *share, TABLE_LIST *table, TABLE_LIST *tbl; Security_context *security_ctx= 0; + if (check_dependencies_in_with_clauses(thd, thd->lex->with_clauses_list)) + goto err; + /* Check rights to run commands (ANALYZE SELECT, EXPLAIN SELECT & SHOW CREATE) which show underlying tables.