[Commits] 393ad02: MDEV-18511: CTE support for UPDATE and DELETE statements
revision-id: 393ad0215fa4f1833650c801133ae1806cc63ef4 (mariadb-10.5.2-410-g393ad02) parent(s): d34cc6b3fd995ea7f10745d3b8e730053026dca2 author: Igor Babaev committer: Igor Babaev timestamp: 2020-10-01 15:47:26 -0700 message: MDEV-18511: CTE support for UPDATE and DELETE statements MDEV-23552: Merge mergeable derived tables used at the top level of UPDATE statements This is the first preliminary patch for the tasks. The patch introduces the new test files derived_update.test, cte_update.test, view_update.test, derived_update_multi.test, cte_update_multi.test, view_update_multi.test. All these tests + view.test, derived.test, derived_view.test, cte_nonrecursive and cte recursive pass with the patch. The code of the patch is far from being final. --- mysql-test/main/cte_nonrecursive.result | 9 +- mysql-test/main/cte_nonrecursive.test | 2 +- mysql-test/main/cte_update.result | 432 +++++ mysql-test/main/cte_update.test | 221 +++ mysql-test/main/cte_update_multi.result | 2643 ++++++++++++++++++++++++++ mysql-test/main/cte_update_multi.test | 916 +++++++++ mysql-test/main/derived_update.result | 440 +++++ mysql-test/main/derived_update.test | 226 +++ mysql-test/main/derived_update_multi.result | 2529 +++++++++++++++++++++++++ mysql-test/main/derived_update_multi.test | 860 +++++++++ mysql-test/main/view.result | 24 +- mysql-test/main/view.test | 21 +- mysql-test/main/view_update.result | 412 ++++ mysql-test/main/view_update.test | 241 +++ mysql-test/main/view_update_multi.result | 2685 +++++++++++++++++++++++++++ mysql-test/main/view_update_multi.test | 970 ++++++++++ sql/item_subselect.cc | 1 - sql/sp_head.cc | 3 +- sql/sql_base.cc | 55 +- sql/sql_class.h | 13 +- sql/sql_cte.cc | 396 +++- sql/sql_cte.h | 69 +- sql/sql_delete.cc | 13 +- sql/sql_derived.cc | 56 +- sql/sql_insert.cc | 23 +- sql/sql_lex.cc | 18 +- sql/sql_lex.h | 32 +- sql/sql_load.cc | 2 +- sql/sql_parse.cc | 19 +- sql/sql_prepare.cc | 7 +- sql/sql_select.cc | 23 +- sql/sql_show.cc | 2 + sql/sql_tvc.cc | 4 +- sql/sql_update.cc | 151 +- sql/sql_view.cc | 13 +- sql/sql_yacc.yy | 76 +- sql/table.cc | 261 ++- sql/table.h | 37 +- 38 files changed, 13472 insertions(+), 433 deletions(-) diff --git a/mysql-test/main/cte_nonrecursive.result b/mysql-test/main/cte_nonrecursive.result index 6ff33e6..b7bb143 100644 --- a/mysql-test/main/cte_nonrecursive.result +++ b/mysql-test/main/cte_nonrecursive.result @@ -618,7 +618,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(`c`) as (select `test`.`t1`.`a` AS `c` from `test`.`t1` where `test`.`t1`.`b` >= 'c')select `r1`.`c` AS `c`,`r2`.`c` AS `d` from (`t` `r1` join (select `test`.`t1`.`a` AS `c` from `test`.`t1` where `test`.`t1`.`b` >= 'c') `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(`c`) 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 (select `t1`.`a` AS `c` from `t1` where `t1`.`b` >= 'c') `r2`) where `r1`.`c` = `r2`.`c` and `r2`.`c` = 4 latin1 latin1_swedish_ci select * from v4; c d 4 4 @@ -636,7 +636,6 @@ create view v1(a) as with t as (select a from t1 where b >= 'c') select t.a from t2,t where t2.c=t.a; update v1 set a=0 where a > 4; -ERROR HY000: The target table v1 of the UPDATE is not updatable drop view v1; # prepare of a query containing a definition of a with table t prepare stmt1 from " @@ -1021,10 +1020,10 @@ select a from t1; show table status; 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 `s`.`a` AS `a` from (select `test`.`t1`.`a` AS `a` from `test`.`t1`) `s`), r as (select `t`.`a` AS `a` from (`test`.`t2` join `t`) where `test`.`t2`.`b` = `t`.`a`)select `r`.`a` AS `a` from `r` latin1 latin1_swedish_ci +v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS with t as (select `s`.`a` AS `a` from (select `t1`.`a` AS `a` from `t1`) `s`), r as (select `t`.`a` AS `a` from (`t2` join `t`) where `t2`.`b` = `t`.`a`)select `r`.`a` AS `a` from `r` latin1 latin1_swedish_ci 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 `s`.`a` AS `a` from (select `test`.`t1`.`a` AS `a` from `test`.`t1`) `s`), r as (select `t`.`a` AS `a` from (`test`.`t2` join `t`) where `test`.`t2`.`b` = `t`.`a`)select `test`.`t1`.`a` AS `a` from `test`.`t1` latin1 latin1_swedish_ci +v2 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v2` AS with t as (select `s`.`a` AS `a` from (select `t1`.`a` AS `a` from `t1`) `s`), r as (select `t`.`a` AS `a` from (`t2` join `t`) where `t2`.`b` = `t`.`a`)select `t1`.`a` AS `a` from `t1` latin1 latin1_swedish_ci select * from v1; a 2 @@ -1126,7 +1125,7 @@ NULL UNION RESULT <union4,5> ALL NULL NULL NULL NULL NULL NULL NULL UNION RESULT <union11,12> ALL NULL NULL NULL NULL NULL NULL NULL UNION RESULT <union1,6> ALL NULL NULL NULL NULL NULL NULL Warnings: -Note 1003 with cte_e as (with cte_o as (with cte_i as (select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 7)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 3 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 and `test`.`t1`.`a` > 1 union select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 4 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 and `test`.`t1`.`a` > 1)select `cte_e1`.`a` AS `a` from `cte_e` `cte_e1` where `cte_e1`.`a` > 1 union select `cte_e2`.`a` AS `a` from (with cte_o as (with cte_i as (select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 7)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 3 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 union select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 4 and `test`.`t 1`.`a` > 1 and `test`.`t1`.`a` < 7) `cte_e2` +Note 1003 with cte_e as (with cte_o as (with cte_i as (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 7)/* select#3 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1)/* select#4 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 3 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 and `test`.`t1`.`a` > 1 union /* select#5 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 4 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 and `test`.`t1`.`a` > 1)/* select#1 */ select `cte_e1`.`a` AS `a` from `cte_e` `cte_e1` where `cte_e1`.`a` > 1 union /* select#6 */ select `cte_e2`.`a` AS `a` from (with cte_o as (with cte_i as (/* select#9 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 7)/* select#10 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1)/* select#11 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 3 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 union /* select#12 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 4 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7) `cte_e2` drop table t1; # # MDEV-13753: embedded CTE in a VIEW created in prepared statement diff --git a/mysql-test/main/cte_nonrecursive.test b/mysql-test/main/cte_nonrecursive.test index 807e2e0..4fd3cd9 100644 --- a/mysql-test/main/cte_nonrecursive.test +++ b/mysql-test/main/cte_nonrecursive.test @@ -345,7 +345,7 @@ drop view v1,v2,v3,v4; create view v1(a) as with t as (select a from t1 where b >= 'c') select t.a from t2,t where t2.c=t.a; ---error ER_NON_UPDATABLE_TABLE +# --error ER_NON_UPDATABLE_TABLE update v1 set a=0 where a > 4; drop view v1; diff --git a/mysql-test/main/cte_update.result b/mysql-test/main/cte_update.result new file mode 100644 index 0000000..e675781 --- /dev/null +++ b/mysql-test/main/cte_update.result @@ -0,0 +1,432 @@ +create table t1 (a int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4); +# full update of mergeable cte1 +explain with cte1 as (select a from t1) update cte1 set a=10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +with cte1 as (select a from t1) update cte1 set a=10; +select * from t1; +a +10 +10 +10 +10 +10 +explain with cte1 as (select * from t1) update cte1 set a=14; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +with cte1 as (select * from t1) update cte1 set a=14; +select * from t1; +a +14 +14 +14 +14 +14 +# update with limit of mergeable cte1 +explain with cte1 as (select * from t1) update cte1 set cte1.a=18 limit 3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +with cte1 as (select * from t1) update cte1 set cte1.a=18 limit 3; +select * from t1; +a +18 +18 +18 +14 +14 +# partial update of mergeable cte1 +explain with cte1 as (select * from t1) update cte1 set cte1.a=2 where a<18; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte1 as (select * from t1) update cte1 set cte1.a=2 where a<18; +select * from t1; +a +18 +18 +18 +2 +2 +# partial update of mergeable cte1 defined as +# full select from mergeable derived table dt1 +explain with cte1 as (select * from (select * from t1) dt1) +update cte1 set cte1.a=22 where a>16; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte1 as (select * from (select * from t1) dt1) +update cte1 set cte1.a=22 where a>16; +select * from t1; +a +22 +22 +22 +2 +2 +# full update of mergeable cte1 defined as +# partial select from mergeable derived table dt1 +explain with cte1 as (select * from (select * from t1) dt1 where dt1.a > 20) +update cte1 set cte1.a=24; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte1 as (select * from (select * from t1) dt1 where dt1.a > 20) +update cte1 set cte1.a=24; +select * from t1; +a +24 +24 +24 +2 +2 +update t1 set a=26 limit 1; +select * from t1; +a +26 +24 +24 +2 +2 +# partial update of mergeable cte1 defined as +# partial select from mergeable derived table dt1 +explain with cte1 as (select * from (select * from t1) dt1 where dt1.a < 25) +update cte1 set cte1.a=15 where cte1.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte1 as (select * from (select * from t1) dt1 where dt1.a < 25) +update cte1 set cte1.a=15 where cte1.a > 2; +select * from t1; +a +26 +15 +15 +2 +2 +create view v1 as select * from t1; +# partial update of mergeable cte1 defined as +# full select from mergeable view v1 +explain with cte1 as (select * from v1) +update cte1 set cte1.a=17 where cte1.a between 10 and 20; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte1 as (select * from v1) +update cte1 set cte1.a=17 where cte1.a between 10 and 20; +select * from t1; +a +26 +17 +17 +2 +2 +# full update of mergeable cte1 defined as +# partial select from mergeable view v1 +explain with cte1 as (select * from v1 where v1.a > 10) +update cte1 set cte1.a=23; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte1 as (select * from v1 where v1.a > 10) +update cte1 set cte1.a=23; +select * from t1; +a +23 +23 +23 +2 +2 +update t1 set a=28 limit 1; +select * from t1; +a +28 +23 +23 +2 +2 +# partial update of mergeable cte1 defined as +# partial select from mergeable view v1 +explain with cte1 as (select * from v1 where v1.a < 27) +update cte1 set cte1.a=19 where cte1.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte1 as (select * from v1 where v1.a < 27) +update cte1 set cte1.a=19 where cte1.a > 2; +select * from t1; +a +28 +19 +19 +2 +2 +# partial update of mergeable cte2 defined as +# full select from mergeable embedded cte1 +explain with cte2 as (with cte1 as (select * from t1) select * from cte1) +update cte2 set cte2.a=11 where cte2.a between 10 and 20; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte2 as (with cte1 as (select * from t1) select * from cte1) +update cte2 set cte2.a=11 where cte2.a between 10 and 20; +select * from t1; +a +28 +11 +11 +2 +2 +# full update of mergeable cte2 defined as +# partial select from mergeable embedded cte1 +explain with cte2 as (with cte1 as (select * from t1) +select * from cte1 where cte1.a > 10) +update cte2 set cte2.a=21; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte2 as (with cte1 as (select * from t1) +select * from cte1 where cte1.a > 10) +update cte2 set cte2.a=21; +select * from t1; +a +21 +21 +21 +2 +2 +update t1 set a=29 limit 1; +select * from t1; +a +29 +21 +21 +2 +2 +# partial update of mergeable cte2 defined as +# partial select from mergeable embedded cte1 +explain with cte2 as (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 27) +update cte2 set cte2.a=13 where cte2.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +with cte2 as (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 27) +update cte2 set cte2.a=13 where cte2.a > 2; +select * from t1; +a +29 +13 +13 +2 +2 +drop view v1; +delete from t1; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +# partial update of mergeable cte1 defined as +# partial select from mergeable dt2 that uses mergeable dt1 +explain with cte1 as +(select * +from (select * from (select * from t1) dt1 where dt1.a > 1) dt2 +where dt2.a < 8) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 4 and 6; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte1 as +(select * +from (select * from (select * from t1) dt1 where dt1.a > 1) dt2 +where dt2.a < 8) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 4 and 6; +select * from t1; +a +3 +8 +7 +1 +5 +3 +6 +2 +# partial update of mergeable cte2 defined as +# partial select from mergeable dt1 that uses mergeable cte1 +explain with cte2 as +(select * +from (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 8) dt1 +where dt1.a > 1) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 5 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte2 as +(select * +from (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 8) dt1 +where dt1.a > 1) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 5 and 7; +select * from t1; +a +3 +8 +6 +1 +4 +3 +5 +2 +# partial update of mergeable cte1 defined as +# partial select from mergeable dt1 that uses mergeable view v1 +create view v1 as select * from t1; +explain with cte1 as +(select * +from (select * from v1 where v1.a < 8) dt1 +where dt1.a > 2) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 2 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte1 as +(select * +from (select * from v1 where v1.a < 8) dt1 +where dt1.a > 2) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 2 and 5; +select * from t1; +a +4 +8 +6 +1 +5 +4 +6 +2 +drop view v1; +# partial update of mergeable cte2 defined as +# partial select from mergeable cte1 that uses mergeable dt1 +explain with cte2 as +(with cte1 as +(select * from (select * from t1) dt1 where dt1.a > 2) +select * from cte1 where cte1.a < 6) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 4 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte2 as +(with cte1 as +(select * from (select * from t1) dt1 where dt1.a > 2) +select * from cte1 where cte1.a < 6) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 4 and 7; +select * from t1; +a +3 +8 +6 +1 +4 +3 +6 +2 +# partial update of mergeable cte3 defined as +# partial select from mergeable cte2 that uses mergeable cte1 +explain with cte3 as +(with cte2 as +(with cte1 as (select * from t1) +select * from cte1 where cte1.a > 3) +select * from cte2 where cte2.a < 10) +update cte3 set cte3.a=cte3.a+1 where cte3.a between 4 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte3 as +(with cte2 as +(with cte1 as (select * from t1) +select * from cte1 where cte1.a > 3) +select * from cte2 where cte2.a < 10) +update cte3 set cte3.a=cte3.a+1 where cte3.a between 4 and 7; +select * from t1; +a +3 +8 +7 +1 +5 +3 +7 +2 +# partial update of mergeable cte2 defined as +# partial select from mergeable cte1 that uses mergeable v1 +create view v1 as select a from t1; +explain with cte2 as +(with cte1 as +(select * from v1 where v1.a > 1) +select * from cte1 where cte1.a < 7) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 2 and 4; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte2 as +(with cte1 as +(select * from v1 where v1.a > 1) +select * from cte1 where cte1.a < 7) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 2 and 4; +select * from t1; +a +2 +8 +7 +1 +5 +2 +7 +1 +drop view v1; +# partial update of mergeable cte1 defined as +# partial select from mergeable v1 that uses mergeable dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a > 2; +explain with cte1 as (select * from v1 where v1.a < 6) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 4 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte1 as (select * from v1 where v1.a < 6) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 4 and 5; +select * from t1; +a +2 +8 +7 +1 +6 +2 +7 +1 +drop view v1; +# partial update of mergeable cte2 defined as +# partial select from mergeable v1 that uses mergeable cte1 +create view v1 as +with cte1 as (select * from t1) select * from cte1 where cte1.a > 1; +explain with cte2 as (select * from v1 where v1.a < 6) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 2 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte2 as (select * from v1 where v1.a < 6) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 2 and 5; +select * from t1; +a +1 +8 +7 +1 +6 +1 +7 +1 +drop view v1; +# partial update of mergeable cte1 defined as +# partial select from mergeable v2 that uses mergeable v1 +create view v1 as select a from t1; +create view v2 as select * from v1 where v1.a > 3; +explain with cte1 as (select * from v2 where v2.a < 8) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 5 and 10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +with cte1 as (select * from v2 where v2.a < 8) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 5 and 10; +select * from t1; +a +1 +8 +8 +1 +7 +1 +8 +1 +drop view v2; +drop view v1; +drop table t1; diff --git a/mysql-test/main/cte_update.test b/mysql-test/main/cte_update.test new file mode 100644 index 0000000..a6db27d --- /dev/null +++ b/mysql-test/main/cte_update.test @@ -0,0 +1,221 @@ +create table t1 (a int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4); +--echo # full update of mergeable cte1 +let $q= +with cte1 as (select a from t1) update cte1 set a=10; +eval explain $q; +eval $q; +select * from t1; +let $q= +with cte1 as (select * from t1) update cte1 set a=14; +eval explain $q; +eval $q; +select * from t1; +--echo # update with limit of mergeable cte1 +let $q= +with cte1 as (select * from t1) update cte1 set cte1.a=18 limit 3; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable cte1 +let $q= +with cte1 as (select * from t1) update cte1 set cte1.a=2 where a<18; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable cte1 defined as +--echo # full select from mergeable derived table dt1 +let $q= +with cte1 as (select * from (select * from t1) dt1) + update cte1 set cte1.a=22 where a>16; +eval explain $q; +eval $q; +select * from t1; +--echo # full update of mergeable cte1 defined as +--echo # partial select from mergeable derived table dt1 +let $q= +with cte1 as (select * from (select * from t1) dt1 where dt1.a > 20) + update cte1 set cte1.a=24; +eval explain $q; +eval $q; +select * from t1; +update t1 set a=26 limit 1; +select * from t1; +--echo # partial update of mergeable cte1 defined as +--echo # partial select from mergeable derived table dt1 +let $q= +with cte1 as (select * from (select * from t1) dt1 where dt1.a < 25) + update cte1 set cte1.a=15 where cte1.a > 2; +eval explain $q; +eval $q; +select * from t1; + +create view v1 as select * from t1; + +--echo # partial update of mergeable cte1 defined as +--echo # full select from mergeable view v1 +let $q= +with cte1 as (select * from v1) + update cte1 set cte1.a=17 where cte1.a between 10 and 20; +eval explain $q; +eval $q; +select * from t1; +--echo # full update of mergeable cte1 defined as +--echo # partial select from mergeable view v1 +let $q= +with cte1 as (select * from v1 where v1.a > 10) + update cte1 set cte1.a=23; +eval explain $q; +eval $q; +select * from t1; +update t1 set a=28 limit 1; +select * from t1; +--echo # partial update of mergeable cte1 defined as +--echo # partial select from mergeable view v1 +let $q= +with cte1 as (select * from v1 where v1.a < 27) + update cte1 set cte1.a=19 where cte1.a > 2; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable cte2 defined as +--echo # full select from mergeable embedded cte1 +let $q= +with cte2 as (with cte1 as (select * from t1) select * from cte1) + update cte2 set cte2.a=11 where cte2.a between 10 and 20; +eval explain $q; +eval $q; +select * from t1; +--echo # full update of mergeable cte2 defined as +--echo # partial select from mergeable embedded cte1 +let $q= +with cte2 as (with cte1 as (select * from t1) + select * from cte1 where cte1.a > 10) + update cte2 set cte2.a=21; +eval explain $q; +eval $q; +select * from t1; +update t1 set a=29 limit 1; +select * from t1; +--echo # partial update of mergeable cte2 defined as +--echo # partial select from mergeable embedded cte1 +let $q= +with cte2 as (with cte1 as (select * from t1) + select * from cte1 where cte1.a < 27) + update cte2 set cte2.a=13 where cte2.a > 2; +eval explain $q; +eval $q; +select * from t1; + +drop view v1; + +delete from t1; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); + +--echo # partial update of mergeable cte1 defined as +--echo # partial select from mergeable dt2 that uses mergeable dt1 +let $q= +with cte1 as + (select * + from (select * from (select * from t1) dt1 where dt1.a > 1) dt2 + where dt2.a < 8) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 4 and 6; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable cte2 defined as +--echo # partial select from mergeable dt1 that uses mergeable cte1 +let $q= +with cte2 as + (select * + from (with cte1 as (select * from t1) + select * from cte1 where cte1.a < 8) dt1 + where dt1.a > 1) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 5 and 7; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable cte1 defined as +--echo # partial select from mergeable dt1 that uses mergeable view v1 +create view v1 as select * from t1; +let $q= +with cte1 as + (select * + from (select * from v1 where v1.a < 8) dt1 + where dt1.a > 2) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 2 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable cte2 defined as +--echo # partial select from mergeable cte1 that uses mergeable dt1 +let $q= +with cte2 as + (with cte1 as + (select * from (select * from t1) dt1 where dt1.a > 2) + select * from cte1 where cte1.a < 6) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 4 and 7; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable cte3 defined as +--echo # partial select from mergeable cte2 that uses mergeable cte1 +let $q= +with cte3 as + (with cte2 as + (with cte1 as (select * from t1) + select * from cte1 where cte1.a > 3) +select * from cte2 where cte2.a < 10) +update cte3 set cte3.a=cte3.a+1 where cte3.a between 4 and 7; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable cte2 defined as +--echo # partial select from mergeable cte1 that uses mergeable v1 +create view v1 as select a from t1; +let $q= +with cte2 as + (with cte1 as + (select * from v1 where v1.a > 1) + select * from cte1 where cte1.a < 7) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 2 and 4; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable cte1 defined as +--echo # partial select from mergeable v1 that uses mergeable dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a > 2; +let $q= +with cte1 as (select * from v1 where v1.a < 6) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 4 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable cte2 defined as +--echo # partial select from mergeable v1 that uses mergeable cte1 +create view v1 as + with cte1 as (select * from t1) select * from cte1 where cte1.a > 1; +let $q= +with cte2 as (select * from v1 where v1.a < 6) +update cte2 set cte2.a=cte2.a-1 where cte2.a between 2 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable cte1 defined as +--echo # partial select from mergeable v2 that uses mergeable v1 +create view v1 as select a from t1; +create view v2 as select * from v1 where v1.a > 3; +let $q= +with cte1 as (select * from v2 where v2.a < 8) +update cte1 set cte1.a=cte1.a+1 where cte1.a between 5 and 10; +eval explain $q; +eval $q; +select * from t1; +drop view v2; +drop view v1; + +drop table t1; diff --git a/mysql-test/main/cte_update_multi.result b/mysql-test/main/cte_update_multi.result new file mode 100644 index 0000000..c7af6d3 --- /dev/null +++ b/mysql-test/main/cte_update_multi.result @@ -0,0 +1,2643 @@ +create table t1 (a int) engine=myisam; +create table t2 (b int) engine=myisam; +create table t3 (c int, d int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable cte1 +# and mergeable derived table dt1 +explain with cte1 as (select a from t1 where a > 1) +select * from cte1, (select b from t2 where b < 6) as dt1 +where cte1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +with cte1 as (select a from t1 where a > 1) +select * from cte1, (select b from t2 where b < 6) as dt1 +where cte1.a=dt1.b; +a b +5 5 +3 3 +3 3 +2 2 +2 2 +4 4 +explain with cte1 as (select a from t1 where a > 1) +update cte1, (select b from t2 where b < 6) as dt1 +set a=a+1, b=b+1 where cte1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte1 as (select a from t1 where a > 1) +update cte1, (select b from t2 where b < 6) as dt1 +set a=a+1, b=b+1 where cte1.a=dt1.b; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +6 +10 +4 +9 +3 +3 +5 +6 +1 +# multi-table update of mergeable cte1 +# and mergeable cte2 +explain with +cte1 as (select a from t1 where a > 1), +cte2 as (select * from t2 where b < 9) +select * from cte1, cte2 where cte1.a=cte2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +with +cte1 as (select a from t1 where a > 1), +cte2 as (select * from t2 where b < 9) +select * from cte1, cte2 where cte1.a=cte2.b; +a b +6 6 +4 4 +4 4 +3 3 +3 3 +5 5 +6 6 +explain with +cte1 as (select a from t1 where a > 1), +cte2 as (select * from t2 where b < 9) +update cte1, cte2 +set cte1.a=cte1.a-1, cte2.b=cte2.b-1 where cte1.a=cte2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with +cte1 as (select a from t1 where a > 1), +cte2 as (select * from t2 where b < 9) +update cte1, cte2 +set cte1.a=cte1.a-1, cte2.b=cte2.b-1 where cte1.a=cte2.b; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +5 +1 +# multi-table update of mergeable cte1 +# and mergeable view v1 +create view v1 as select * from t2 where b < 5; +explain with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b; +a b +3 3 +3 3 +2 2 +2 2 +4 4 +explain with cte1 as (select a from t1 where a > 1) +update cte1, v1 +set cte1.a=cte1.a+2, v1.b=v1.b+2 where cte1.a=v1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte1 as (select a from t1 where a > 1) +update cte1, v1 +set cte1.a=cte1.a+2, v1.b=v1.b+2 where cte1.a=v1.b; +select * from t1; +a +5 +8 +7 +1 +6 +5 +5 +4 +select * from t2; +b +5 +10 +5 +9 +4 +4 +6 +5 +1 +drop view v1; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable cte1 +# and non-mergeable derived table dt1 +explain with cte1 as (select a from t1 where a > 1) +select * from cte1, (select b from t2 where b < 6 group by b) as dt1 +where cte1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select a from t1 where a > 1) +select * from cte1, (select b from t2 where b < 6 group by b) as dt1 +where cte1.a=dt1.b; +a b +3 3 +4 4 +3 3 +5 5 +2 2 +explain with cte1 as (select a from t1 where a > 1) +update cte1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where cte1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select a from t1 where a > 1) +update cte1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where cte1.a=dt1.b; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable cte1 +# and non-mergeable cte2 +explain with cte1 as (select a from t1 where a > 1), +cte2 as (select * from t2 where b < 9 group by b) +select * from cte1, cte2 where cte1.a=cte2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select a from t1 where a > 1), +cte2 as (select * from t2 where b < 9 group by b) +select * from cte1, cte2 where cte1.a=cte2.b; +a b +4 4 +5 5 +4 4 +6 6 +3 3 +explain with cte1 as (select a from t1 where a > 1), +cte2 as (select * from t2 where b < 9 group by b) +update cte1, cte2 +set cte1.a=cte1.a-1 where cte1.a=cte2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select a from t1 where a > 1), +cte2 as (select * from t2 where b < 9 group by b) +update cte1, cte2 +set cte1.a=cte1.a-1 where cte1.a=cte2.b; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable cte1 +# and non-mergeable view v1 +create view v1 as select * from t2 where b < 5 group by b; +explain with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b; +a b +3 3 +4 4 +3 3 +2 2 +explain with cte1 as (select a from t1 where a > 1) +update cte1, v1 +set cte1.a=cte1.a+2 where cte1.a=v1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select a from t1 where a > 1) +update cte1, v1 +set cte1.a=cte1.a+2 where cte1.a=v1.b; +select * from t1; +a +5 +8 +7 +1 +6 +5 +5 +4 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +# update of mergeable cte1 specified as join of +# mergeable derived table dt1 and mergeable derived table dt2 +explain with cte1 as +(select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +where dt1.a=dt2.b) +update cte1 +set cte1.a=cte1.a+1, cte1.b=cte1.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte1 as +(select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +where dt1.a=dt2.b) +update cte1 +set cte1.a=cte1.a+1, cte1.b=cte1.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +6 +10 +4 +9 +3 +3 +5 +6 +1 +# update of mergeable cte2 specified as join of +# mergeable derived table dt1 and mergeable cte1 +explain with cte2 as +(with cte1 as (select b from t2 where b < 9) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1, cte2.b=cte2.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte2 as +(with cte1 as (select b from t2 where b < 9) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1, cte2.b=cte2.b-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +5 +1 +# update of mergeable cte1 specified as join of +# mergeable derived table dt1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +explain with cte1 as +(select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b) +update cte1 +set cte1.a=cte1.a+1, cte1.b=cte1.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte1 as +(select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b) +update cte1 +set cte1.a=cte1.a+1, cte1.b=cte1.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +4 +9 +3 +3 +5 +5 +1 +drop view v1; +# update of mergeable cte3 specified as join of +# mergeable cte1 and mergeable cte2 +explain with cte3 as +(with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6) +select * from cte1, cte2 where cte1.a=cte2.b) +update cte3 +set cte3.a=cte3.a-1, cte3.b=cte3.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte3 as +(with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6) +select * from cte1, cte2 where cte1.a=cte2.b) +update cte3 +set cte3.a=cte3.a-1, cte3.b=cte3.b-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +4 +10 +3 +9 +2 +2 +4 +4 +1 +# update of mergeable cte2 specified as join of +# mergeable cte1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +explain with cte2 as +(with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b) +update cte2 +set cte2.a=cte2.a+1, cte2.b=cte2.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte2 as +(with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b) +update cte2 +set cte2.a=cte2.a+1, cte2.b=cte2.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +4 +9 +3 +3 +5 +5 +1 +drop view v1; +# update of mergeable cte1 specified as join of +# mergeable view v1 and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5; +explain with cte1 as +(select * from v1, v2 where v1.a=v2.b) +update cte1 +set cte1.a=cte1.a-1, cte1.b=cte1.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte1 as +(select * from v1, v2 where v1.a=v2.b) +update cte1 +set cte1.a=cte1.a-1, cte1.b=cte1.b-1; +select * from t1; +a +3 +8 +7 +1 +5 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +5 +5 +1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +# update of mergeable cte1 specified as join of +# mergeable derived table dt1 and non-mergeable derived table dt2 +explain with cte1 as +(select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +where dt1.a=dt2.b) +update cte1 +set cte1.a=cte1.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as +(select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +where dt1.a=dt2.b) +update cte1 +set cte1.a=cte1.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# update of mergeable cte2 specified as join of +# mergeable derived table dt1 and non-mergeable cte1 +explain with cte2 as +(with cte1 as (select b from t2 where b < 9 group by b) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte2 as +(with cte1 as (select b from t2 where b < 9 group by b) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# update of mergeable cte1 specified as join of +# mergeable derived table dt1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 5 group by b; +explain with cte1 as +(select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b) +update cte1 +set cte1.a=cte1.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as +(select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b) +update cte1 +set cte1.a=cte1.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable cte2 specified as join of +# mergeable cte1 and non-mergeable dt1 +explain with cte2 as +(with cte1 as (select a from t1 where a > 1) +select * from +cte1, (select b from t2 where b < 7 group by b) dt1 +where cte1.a=dt1.b) +update cte2 +set cte2.a=cte2.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte2 as +(with cte1 as (select a from t1 where a > 1) +select * from +cte1, (select b from t2 where b < 7 group by b) dt1 +where cte1.a=dt1.b) +update cte2 +set cte2.a=cte2.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# update of mergeable cte3 specified as join of +# mergeable cte1 and non-mergeable cte2 +explain with cte3 as +(with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6 group by b) +select * from cte1, cte2 where cte1.a=cte2.b) +update cte3 +set cte3.a=cte3.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte3 as +(with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6 group by b) +select * from cte1, cte2 where cte1.a=cte2.b) +update cte3 +set cte3.a=cte3.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# update of mergeable cte2 specified as join of +# mergeable cte1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 7 group by b; +explain with cte2 as +(with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b) +update cte2 +set cte2.a=cte2.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte2 as +(with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b) +update cte2 +set cte2.a=cte2.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable cte1 specified as join of +# mergeable view v1 and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +explain with cte1 as +(select * from +v1, (select b from t2 where b < 6 group by b) dt1 +where v1.a=dt1.b) +update cte1 +set cte1.a=cte1.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as +(select * from +v1, (select b from t2 where b < 6 group by b) dt1 +where v1.a=dt1.b) +update cte1 +set cte1.a=cte1.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable cte2 specified as join of +# mergeable view v1 and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +explain with cte2 as +(with cte1 as (select b from t2 where b < 7 group by b) +select * from v1, cte1 where v1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte2 as +(with cte1 as (select b from t2 where b < 7 group by b) +select * from v1, cte1 where v1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable cte1 specified as join of +# mergeable view v1 and non-mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5 group by b; +explain with cte1 as +(select * from v1, v2 where v1.a=v2.b) +update cte1 +set cte1.a=cte1.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as +(select * from v1, v2 where v1.a=v2.b) +update cte1 +set cte1.a=cte1.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable cte1, +# mergeable derived table dt1 and mergeable derived table dt2 +explain with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 5) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where cte1.a=dt1.b and dt1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 5) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where cte1.a=dt1.b and dt1.b=dt2.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with cte1 as (select * from t1 where t1.a > 2) +update +cte1, +(select * from t2 where t2.b < 5) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set cte1.a=cte1.a+1, dt1.b=dt1.b+1, dt2.c=dt2.c-dt2.d1 +where cte1.a=dt1.b and dt1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select * from t1 where t1.a > 2) +update +cte1, +(select * from t2 where t2.b < 5) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set cte1.a=cte1.a+1, dt1.b=dt1.b+1, dt2.c=dt2.c-dt2.d1 +where cte1.a=dt1.b and dt1.b=dt2.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +# update of join of mergeable cte1, +# mergeable derived table dt1 and mergeable cte2 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 10) dt1, +cte2 +where cte1.a=dt1.b and dt1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 10) dt1, +cte2 +where cte1.a=dt1.b and dt1.b=cte2.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +(select * from t2 where t2.b < 10) dt1, +cte2 +set cte1.a=cte1.a-1, dt1.b=dt1.b-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=dt1.b and dt1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +(select * from t2 where t2.b < 10) dt1, +cte2 +set cte1.a=cte1.a-1, dt1.b=dt1.b-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=dt1.b and dt1.b=cte2.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +# update of join of mergeable cte1, +# mergeable derived table dt1 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 5) dt1, +v1 +where cte1.a=dt1.b and dt1.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 5) dt1, +v1 +where cte1.a=dt1.b and dt1.b=v1.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain with cte1 as (select * from t1 where t1.a < 3) +update +cte1, +(select * from t2 where t2.b < 5) dt1, +v1 +set cte1.a=cte1.a+1, dt1.b=dt1.b+1, v1.c=v1.c+v1.d1 +where cte1.a=dt1.b and dt1.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select * from t1 where t1.a < 3) +update +cte1, +(select * from t2 where t2.b < 5) dt1, +v1 +set cte1.a=cte1.a+1, dt1.b=dt1.b+1, v1.c=v1.c+v1.d1 +where cte1.a=dt1.b and dt1.b=v1.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable cte1, +# mergeable cte2 and mergeable derived table dt1 +explain with +cte1 as (select * from t1 where t1.a > 2), +cte2 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +cte1, +cte2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=cte2.b and cte2.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with +cte1 as (select * from t1 where t1.a > 2), +cte2 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +cte1, +cte2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=cte2.b and cte2.b=dt1.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with +cte1 as (select * from t1 where t1.a > 2), +cte2 as (select * from t2 where t2.b < 5) +update +cte1, +cte2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, cte2.b=cte2.b+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=cte2.b and cte2.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with +cte1 as (select * from t1 where t1.a > 2), +cte2 as (select * from t2 where t2.b < 5) +update +cte1, +cte2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, cte2.b=cte2.b+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=cte2.b and cte2.b=dt1.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +# update of join of mergeable cte1, +# mergeable cte2 and mergeable cte3 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select * from t2 where t2.b < 10), +cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +cte2, +cte3 +where cte1.a=cte2.b and cte2.b=cte3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select * from t2 where t2.b < 10), +cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +cte2, +cte3 +where cte1.a=cte2.b and cte2.b=cte3.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select * from t2 where t2.b < 10), +cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +cte2, +cte3 +set cte1.a=cte1.a-1, cte2.b=cte2.b-1, cte3.c=cte3.c+cte3.d1 +where cte1.a=cte2.b and cte2.b=cte3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select * from t2 where t2.b < 10), +cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +cte2, +cte3 +set cte1.a=cte1.a-1, cte2.b=cte2.b-1, cte3.c=cte3.c+cte3.d1 +where cte1.a=cte2.b and cte2.b=cte3.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +# update of join of mergeable cte1, +# mergeable cte2 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with +cte1 as (select * from t1 where t1.a < 3), +cte2 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +cte1, +cte2, +v1 +where cte1.a=cte2.b and cte2.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with +cte1 as (select * from t1 where t1.a < 3), +cte2 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +cte1, +cte2, +v1 +where cte1.a=cte2.b and cte2.b=v1.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain with +cte1 as (select * from t1 where t1.a < 3), +cte2 as (select * from t2 where t2.b < 5) +update +cte1, +cte2, +v1 +set cte1.a=cte1.a+1, cte2.b=cte2.b+1, v1.c=v1.c+v1.d1 +where cte1.a=cte2.b and cte2.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with +cte1 as (select * from t1 where t1.a < 3), +cte2 as (select * from t2 where t2.b < 5) +update +cte1, +cte2, +v1 +set cte1.a=cte1.a+1, cte2.b=cte2.b+1, v1.c=v1.c+v1.d1 +where cte1.a=cte2.b and cte2.b=v1.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable cte1, +# mergeable view v1 and mergeable derived table dt1 +create view v1 as (select * from t2 where t2.b < 5); +explain with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from +cte1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=v1.b and v1.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from +cte1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=v1.b and v1.b=dt1.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with cte1 as (select * from t1 where t1.a > 2) +update +cte1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, v1.b=v1.b+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=v1.b and v1.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select * from t1 where t1.a > 2) +update +cte1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, v1.b=v1.b+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=v1.b and v1.b=dt1.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +# update of join of mergeable cte1, +# mergeable view v1 and mergeable cte2 +create view v1 as select * from t2 where t2.b < 10; +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +v1, +cte2 +where cte1.a=v1.b and v1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +v1, +cte2 +where cte1.a=v1.b and v1.b=cte2.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +v1, +cte2 +set cte1.a=cte1.a-1, v1.b=v1.b-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=v1.b and v1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +v1, +cte2 +set cte1.a=cte1.a-1, v1.b=v1.b-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=v1.b and v1.b=cte2.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +# update of join of mergeable cte1, +# mergeable view v1 and mergeable view v2 +create view v1 as select * from t2 where t2.b < 5; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +cte1, +v1, +v2 +where cte1.a=v1.b and v1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +cte1, +v1, +v2 +where cte1.a=v1.b and v1.b=v2.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain with cte1 as (select * from t1 where t1.a < 3) +update +cte1, +v1, +v2 +set cte1.a=cte1.a+1, v1.b=v1.b+1, v2.c=v2.c+v2.d1 +where cte1.a=v1.b and v1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select * from t1 where t1.a < 3) +update +cte1, +v1, +v2 +set cte1.a=cte1.a+1, v1.b=v1.b+1, v2.c=v2.c+v2.d1 +where cte1.a=v1.b and v1.b=v2.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable cte1, +# non-mergeable derived table dt1 and mergeable derived table dt2 +explain with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 5 group by b) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where cte1.a=dt1.b and dt1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 5 group by b) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where cte1.a=dt1.b and dt1.b=dt2.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with cte1 as (select * from t1 where t1.a > 2) +update +cte1, +(select * from t2 where t2.b < 5 group by b) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set cte1.a=cte1.a+1, dt2.c=dt2.c-dt2.d1 +where cte1.a=dt1.b and dt1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a > 2) +update +cte1, +(select * from t2 where t2.b < 5 group by b) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set cte1.a=cte1.a+1, dt2.c=dt2.c-dt2.d1 +where cte1.a=dt1.b and dt1.b=dt2.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +# update of join of mergeable cte1, +# non-mergeable derived table dt1 and mergeable cte2 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 10 group by b) dt1, +cte2 +where cte1.a=dt1.b and dt1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 10 group by b) dt1, +cte2 +where cte1.a=dt1.b and dt1.b=cte2.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +(select * from t2 where t2.b < 10 group by b) dt1, +cte2 +set cte1.a=cte1.a-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=dt1.b and dt1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +(select * from t2 where t2.b < 10 group by b) dt1, +cte2 +set cte1.a=cte1.a-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=dt1.b and dt1.b=cte2.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +# update of join of mergeable cte1, +# non-mergeable derived table dt1 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 5 group by b) dt1, +v1 +where cte1.a=dt1.b and dt1.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +cte1, +(select * from t2 where t2.b < 5 group by b) dt1, +v1 +where cte1.a=dt1.b and dt1.b=v1.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain with cte1 as (select * from t1 where t1.a < 3) +update +cte1, +(select * from t2 where t2.b < 5 group by b) dt1, +v1 +set cte1.a=cte1.a+1, v1.c=v1.c+v1.d1 +where cte1.a=dt1.b and dt1.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a < 3) +update +cte1, +(select * from t2 where t2.b < 5 group by b) dt1, +v1 +set cte1.a=cte1.a+1, v1.c=v1.c+v1.d1 +where cte1.a=dt1.b and dt1.b=v1.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable cte1, +# non-mergeable cte2 and mergeable derived table dt1 +explain with +cte1 as (select * from t1 where t1.a > 2), +cte2 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +cte1, +cte2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=cte2.b and cte2.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a > 2), +cte2 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +cte1, +cte2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=cte2.b and cte2.b=dt1.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with +cte1 as (select * from t1 where t1.a > 2), +cte2 as (select * from t2 where t2.b < 5 group by b) +update +cte1, +cte2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=cte2.b and cte2.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a > 2), +cte2 as (select * from t2 where t2.b < 5 group by b) +update +cte1, +cte2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=cte2.b and cte2.b=dt1.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +# update of join of mergeable cte1, +# non-mergeable cte2 and mergeable cte3 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select * from t2 where t2.b < 10 group by b), +cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +cte2, +cte3 +where cte1.a=cte2.b and cte2.b=cte3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select * from t2 where t2.b < 10 group by b), +cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +cte2, +cte3 +where cte1.a=cte2.b and cte2.b=cte3.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select * from t2 where t2.b < 10 group by b), +cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +cte2, +cte3 +set cte1.a=cte1.a-1, cte3.c=cte3.c+cte3.d1 +where cte1.a=cte2.b and cte2.b=cte3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select * from t2 where t2.b < 10 group by b), +cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +cte2, +cte3 +set cte1.a=cte1.a-1, cte3.c=cte3.c+cte3.d1 +where cte1.a=cte2.b and cte2.b=cte3.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +# update of join of mergeable cte1, +# non-mergeable cte2 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with +cte1 as (select * from t1 where t1.a < 3), +cte2 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +cte1, +cte2, +v1 +where cte1.a=cte2.b and cte2.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a < 3), +cte2 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +cte1, +cte2, +v1 +where cte1.a=cte2.b and cte2.b=v1.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain with +cte1 as (select * from t1 where t1.a < 3), +cte2 as (select * from t2 where t2.b < 5 group by b) +update +cte1, +cte2, +v1 +set cte1.a=cte1.a+1, v1.c=v1.c+v1.d1 +where cte1.a=cte2.b and cte2.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a < 3), +cte2 as (select * from t2 where t2.b < 5 group by b) +update +cte1, +cte2, +v1 +set cte1.a=cte1.a+1, v1.c=v1.c+v1.d1 +where cte1.a=cte2.b and cte2.b=v1.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable cte1, +# non-mergeable view v1 and mergeable derived table dt1 +create view v1 as (select * from t2 where t2.b < 5 group by b); +explain with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from +cte1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=v1.b and v1.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from +cte1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=v1.b and v1.b=dt1.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with cte1 as (select * from t1 where t1.a > 2) +update +cte1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=v1.b and v1.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a > 2) +update +cte1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=v1.b and v1.b=dt1.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +# update of join of mergeable cte1, +# non-mergeable view v1 and mergeable cte2 +create view v1 as select * from t2 where t2.b < 10 group by b; +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +v1, +cte2 +where cte1.a=v1.b and v1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +cte1, +v1, +cte2 +where cte1.a=v1.b and v1.b=cte2.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +v1, +cte2 +set cte1.a=cte1.a-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=v1.b and v1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t1 where t1.a > 5), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +cte1, +v1, +cte2 +set cte1.a=cte1.a-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=v1.b and v1.b=cte2.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +# update of join of mergeable cte1, +# non-mergeable view v1 and mergeable view v2 +create view v1 as select * from t2 where t2.b < 5 group by b; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +cte1, +v1, +v2 +where cte1.a=v1.b and v1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +cte1, +v1, +v2 +where cte1.a=v1.b and v1.b=v2.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain with cte1 as (select * from t1 where t1.a < 3) +update +cte1, +v1, +v2 +set cte1.a=cte1.a+1, v2.c=v2.c+v2.d1 +where cte1.a=v1.b and v1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a < 3) +update +cte1, +v1, +v2 +set cte1.a=cte1.a+1, v2.c=v2.c+v2.d1 +where cte1.a=v1.b and v1.b=v2.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +drop table t1,t2,t3; diff --git a/mysql-test/main/cte_update_multi.test b/mysql-test/main/cte_update_multi.test new file mode 100644 index 0000000..77527bc --- /dev/null +++ b/mysql-test/main/cte_update_multi.test @@ -0,0 +1,916 @@ +create table t1 (a int) engine=myisam; +create table t2 (b int) engine=myisam; +create table t3 (c int, d int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +select * from t1; +select * from t2; +--echo # multi-table update of mergeable cte1 +--echo # and mergeable derived table dt1 +let $qs= +with cte1 as (select a from t1 where a > 1) +select * from cte1, (select b from t2 where b < 6) as dt1 +where cte1.a=dt1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select a from t1 where a > 1) +update cte1, (select b from t2 where b < 6) as dt1 +set a=a+1, b=b+1 where cte1.a=dt1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # multi-table update of mergeable cte1 +--echo # and mergeable cte2 +let $qs= +with + cte1 as (select a from t1 where a > 1), + cte2 as (select * from t2 where b < 9) +select * from cte1, cte2 where cte1.a=cte2.b; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select a from t1 where a > 1), + cte2 as (select * from t2 where b < 9) +update cte1, cte2 +set cte1.a=cte1.a-1, cte2.b=cte2.b-1 where cte1.a=cte2.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # multi-table update of mergeable cte1 +--echo # and mergeable view v1 +create view v1 as select * from t2 where b < 5; +let $qs= +with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select a from t1 where a > 1) +update cte1, v1 +set cte1.a=cte1.a+2, v1.b=v1.b+2 where cte1.a=v1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +select * from t1; +select * from t2; +--echo # multi-table update of mergeable cte1 +--echo # and non-mergeable derived table dt1 +let $qs= +with cte1 as (select a from t1 where a > 1) +select * from cte1, (select b from t2 where b < 6 group by b) as dt1 +where cte1.a=dt1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select a from t1 where a > 1) +update cte1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where cte1.a=dt1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # multi-table update of mergeable cte1 +--echo # and non-mergeable cte2 +let $qs= +with cte1 as (select a from t1 where a > 1), + cte2 as (select * from t2 where b < 9 group by b) +select * from cte1, cte2 where cte1.a=cte2.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select a from t1 where a > 1), + cte2 as (select * from t2 where b < 9 group by b) +update cte1, cte2 +set cte1.a=cte1.a-1 where cte1.a=cte2.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # multi-table update of mergeable cte1 +--echo # and non-mergeable view v1 +create view v1 as select * from t2 where b < 5 group by b; +let $qs= +with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select a from t1 where a > 1) +update cte1, v1 +set cte1.a=cte1.a+2 where cte1.a=v1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +--echo # update of mergeable cte1 specified as join of +--echo # mergeable derived table dt1 and mergeable derived table dt2 +let $qu= +with cte1 as + (select * from + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6) as dt2 + where dt1.a=dt2.b) +update cte1 +set cte1.a=cte1.a+1, cte1.b=cte1.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable cte2 specified as join of +--echo # mergeable derived table dt1 and mergeable cte1 +let $qu= +with cte2 as + (with cte1 as (select b from t2 where b < 9) + select * from + (select a from t1 where a > 1) as dt1, cte1 + where dt1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1, cte2.b=cte2.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable cte1 specified as join of +--echo # mergeable derived table dt1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +let $qu= +with cte1 as + (select * from + (select a from t1 where a > 1) as dt1, v1 + where dt1.a=v1.b) +update cte1 +set cte1.a=cte1.a+1, cte1.b=cte1.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable cte3 specified as join of +--echo # mergeable cte1 and mergeable cte2 +let $qu= +with cte3 as + (with cte1 as (select a from t1 where a > 1), + cte2 as (select b from t2 where b < 6) + select * from cte1, cte2 where cte1.a=cte2.b) +update cte3 +set cte3.a=cte3.a-1, cte3.b=cte3.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable cte2 specified as join of +--echo # mergeable cte1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +let $qu= +with cte2 as + (with cte1 as (select a from t1 where a > 1) + select * from cte1, v1 where cte1.a=v1.b) +update cte2 +set cte2.a=cte2.a+1, cte2.b=cte2.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable cte1 specified as join of +--echo # mergeable view v1 and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5; +let $qu= +with cte1 as + (select * from v1, v2 where v1.a=v2.b) +update cte1 +set cte1.a=cte1.a-1, cte1.b=cte1.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +--echo # update of mergeable cte1 specified as join of +--echo # mergeable derived table dt1 and non-mergeable derived table dt2 +let $qu= +with cte1 as + (select * from + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6 group by b) as dt2 + where dt1.a=dt2.b) +update cte1 +set cte1.a=cte1.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable cte2 specified as join of +--echo # mergeable derived table dt1 and non-mergeable cte1 +let $qu= +with cte2 as + (with cte1 as (select b from t2 where b < 9 group by b) + select * from + (select a from t1 where a > 1) as dt1, cte1 + where dt1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable cte1 specified as join of +--echo # mergeable derived table dt1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 5 group by b; +let $qu= +with cte1 as + (select * from + (select a from t1 where a > 1) as dt1, v1 + where dt1.a=v1.b) +update cte1 +set cte1.a=cte1.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable cte2 specified as join of +--echo # mergeable cte1 and non-mergeable dt1 +let $qu= +with cte2 as + (with cte1 as (select a from t1 where a > 1) + select * from + cte1, (select b from t2 where b < 7 group by b) dt1 + where cte1.a=dt1.b) +update cte2 +set cte2.a=cte2.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable cte3 specified as join of +--echo # mergeable cte1 and non-mergeable cte2 +let $qu= +with cte3 as + (with cte1 as (select a from t1 where a > 1), + cte2 as (select b from t2 where b < 6 group by b) + select * from cte1, cte2 where cte1.a=cte2.b) +update cte3 +set cte3.a=cte3.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable cte2 specified as join of +--echo # mergeable cte1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 7 group by b; +let $qu= +with cte2 as + (with cte1 as (select a from t1 where a > 1) + select * from cte1, v1 where cte1.a=v1.b) +update cte2 +set cte2.a=cte2.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable cte1 specified as join of +--echo # mergeable view v1 and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +let $qu= +with cte1 as + (select * from + v1, (select b from t2 where b < 6 group by b) dt1 + where v1.a=dt1.b) +update cte1 +set cte1.a=cte1.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable cte2 specified as join of +--echo # mergeable view v1 and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +let $qu= +with cte2 as + (with cte1 as (select b from t2 where b < 7 group by b) + select * from v1, cte1 where v1.a=cte1.b) +update cte2 +set cte2.a=cte2.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable cte1 specified as join of +--echo # mergeable view v1 and non-mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5 group by b; +let $qu= +with cte1 as + (select * from v1, v2 where v1.a=v2.b) +update cte1 +set cte1.a=cte1.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # mergeable derived table dt1 and mergeable derived table dt2 +let $qs= +with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from + cte1, + (select * from t2 where t2.b < 5) dt1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where cte1.a=dt1.b and dt1.b=dt2.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t1 where t1.a > 2) +update + cte1, + (select * from t2 where t2.b < 5) dt1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set cte1.a=cte1.a+1, dt1.b=dt1.b+1, dt2.c=dt2.c-dt2.d1 +where cte1.a=dt1.b and dt1.b=dt2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # mergeable derived table dt1 and mergeable cte2 +let $qs= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + cte1, + (select * from t2 where t2.b < 10) dt1, + cte2 +where cte1.a=dt1.b and dt1.b=cte2.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + cte1, + (select * from t2 where t2.b < 10) dt1, + cte2 +set cte1.a=cte1.a-1, dt1.b=dt1.b-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=dt1.b and dt1.b=cte2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # mergeable derived table dt1 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from + cte1, + (select * from t2 where t2.b < 5) dt1, + v1 +where cte1.a=dt1.b and dt1.b=v1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t1 where t1.a < 3) +update + cte1, + (select * from t2 where t2.b < 5) dt1, + v1 +set cte1.a=cte1.a+1, dt1.b=dt1.b+1, v1.c=v1.c+v1.d1 +where cte1.a=dt1.b and dt1.b=v1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable cte1, +--echo # mergeable cte2 and mergeable derived table dt1 +let $qs= +with + cte1 as (select * from t1 where t1.a > 2), + cte2 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from + cte1, + cte2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=cte2.b and cte2.b=dt1.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a > 2), + cte2 as (select * from t2 where t2.b < 5) +update + cte1, + cte2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, cte2.b=cte2.b+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=cte2.b and cte2.b=dt1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # mergeable cte2 and mergeable cte3 +let $qs= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select * from t2 where t2.b < 10), + cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + cte1, + cte2, + cte3 +where cte1.a=cte2.b and cte2.b=cte3.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select * from t2 where t2.b < 10), + cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + cte1, + cte2, + cte3 +set cte1.a=cte1.a-1, cte2.b=cte2.b-1, cte3.c=cte3.c+cte3.d1 +where cte1.a=cte2.b and cte2.b=cte3.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # mergeable cte2 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with + cte1 as (select * from t1 where t1.a < 3), + cte2 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from + cte1, + cte2, + v1 +where cte1.a=cte2.b and cte2.b=v1.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a < 3), + cte2 as (select * from t2 where t2.b < 5) +update + cte1, + cte2, + v1 +set cte1.a=cte1.a+1, cte2.b=cte2.b+1, v1.c=v1.c+v1.d1 +where cte1.a=cte2.b and cte2.b=v1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable cte1, +--echo # mergeable view v1 and mergeable derived table dt1 +create view v1 as (select * from t2 where t2.b < 5); +let $qs= +with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from + cte1, + v1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=v1.b and v1.b=dt1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t1 where t1.a > 2) +update + cte1, + v1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, v1.b=v1.b+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=v1.b and v1.b=dt1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable cte1, +--echo # mergeable view v1 and mergeable cte2 +create view v1 as select * from t2 where t2.b < 10; +let $qs= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + cte1, + v1, + cte2 +where cte1.a=v1.b and v1.b=cte2.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + cte1, + v1, + cte2 +set cte1.a=cte1.a-1, v1.b=v1.b-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=v1.b and v1.b=cte2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable cte1, +--echo # mergeable view v1 and mergeable view v2 +create view v1 as select * from t2 where t2.b < 5; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from + cte1, + v1, + v2 +where cte1.a=v1.b and v1.b=v2.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t1 where t1.a < 3) +update + cte1, + v1, + v2 +set cte1.a=cte1.a+1, v1.b=v1.b+1, v2.c=v2.c+v2.d1 +where cte1.a=v1.b and v1.b=v2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable cte1, +--echo # non-mergeable derived table dt1 and mergeable derived table dt2 +let $qs= +with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from + cte1, + (select * from t2 where t2.b < 5 group by b) dt1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where cte1.a=dt1.b and dt1.b=dt2.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t1 where t1.a > 2) +update + cte1, + (select * from t2 where t2.b < 5 group by b) dt1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set cte1.a=cte1.a+1, dt2.c=dt2.c-dt2.d1 +where cte1.a=dt1.b and dt1.b=dt2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # non-mergeable derived table dt1 and mergeable cte2 +let $qs= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + cte1, + (select * from t2 where t2.b < 10 group by b) dt1, + cte2 +where cte1.a=dt1.b and dt1.b=cte2.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + cte1, + (select * from t2 where t2.b < 10 group by b) dt1, + cte2 +set cte1.a=cte1.a-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=dt1.b and dt1.b=cte2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # non-mergeable derived table dt1 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from + cte1, + (select * from t2 where t2.b < 5 group by b) dt1, + v1 +where cte1.a=dt1.b and dt1.b=v1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t1 where t1.a < 3) +update + cte1, + (select * from t2 where t2.b < 5 group by b) dt1, + v1 +set cte1.a=cte1.a+1, v1.c=v1.c+v1.d1 +where cte1.a=dt1.b and dt1.b=v1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable cte1, +--echo # non-mergeable cte2 and mergeable derived table dt1 +let $qs= +with + cte1 as (select * from t1 where t1.a > 2), + cte2 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from + cte1, + cte2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=cte2.b and cte2.b=dt1.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a > 2), + cte2 as (select * from t2 where t2.b < 5 group by b) +update + cte1, + cte2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=cte2.b and cte2.b=dt1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # non-mergeable cte2 and mergeable cte3 +let $qs= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select * from t2 where t2.b < 10 group by b), + cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + cte1, + cte2, + cte3 +where cte1.a=cte2.b and cte2.b=cte3.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select * from t2 where t2.b < 10 group by b), + cte3 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + cte1, + cte2, + cte3 +set cte1.a=cte1.a-1, cte3.c=cte3.c+cte3.d1 +where cte1.a=cte2.b and cte2.b=cte3.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable cte1, +--echo # non-mergeable cte2 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with + cte1 as (select * from t1 where t1.a < 3), + cte2 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from + cte1, + cte2, + v1 +where cte1.a=cte2.b and cte2.b=v1.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a < 3), + cte2 as (select * from t2 where t2.b < 5 group by b) +update + cte1, + cte2, + v1 +set cte1.a=cte1.a+1, v1.c=v1.c+v1.d1 +where cte1.a=cte2.b and cte2.b=v1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable cte1, +--echo # non-mergeable view v1 and mergeable derived table dt1 +create view v1 as (select * from t2 where t2.b < 5 group by b); +let $qs= +with cte1 as (select * from t1 where t1.a > 2) +select a,b,c,d1 from + cte1, + v1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where cte1.a=v1.b and v1.b=dt1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t1 where t1.a > 2) +update + cte1, + v1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set cte1.a=cte1.a+1, dt1.c=dt1.c-dt1.d1 +where cte1.a=v1.b and v1.b=dt1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable cte1, +--echo # non-mergeable view v1 and mergeable cte2 +create view v1 as select * from t2 where t2.b < 10 group by b; +let $qs= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + cte1, + v1, + cte2 +where cte1.a=v1.b and v1.b=cte2.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t1 where t1.a > 5), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + cte1, + v1, + cte2 +set cte1.a=cte1.a-1, cte2.c=cte2.c+cte2.d1 +where cte1.a=v1.b and v1.b=cte2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable cte1, +--echo # non-mergeable view v1 and mergeable view v2 +create view v1 as select * from t2 where t2.b < 5 group by b; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from + cte1, + v1, + v2 +where cte1.a=v1.b and v1.b=v2.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t1 where t1.a < 3) +update + cte1, + v1, + v2 +set cte1.a=cte1.a+1, v2.c=v2.c+v2.d1 +where cte1.a=v1.b and v1.b=v2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; + +drop table t1,t2,t3; diff --git a/mysql-test/main/derived_update.result b/mysql-test/main/derived_update.result new file mode 100644 index 0000000..676cb7c --- /dev/null +++ b/mysql-test/main/derived_update.result @@ -0,0 +1,440 @@ +create table t1 (a int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4); +# full update of mergeable derived table dt1 +explain update (select a from t1) as dt1 set a=10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +update (select a from t1) as dt1 set a=10; +select * from t1; +a +10 +10 +10 +10 +10 +explain update (select * from t1) as dt1 set a=14; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +update (select * from t1) as dt1 set a=14; +select * from t1; +a +14 +14 +14 +14 +14 +# update with limit of mergeable dt1 +explain update (select * from t1) as dt1 set dt1.a=18 limit 3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +update (select * from t1) as dt1 set dt1.a=18 limit 3; +select * from t1; +a +18 +18 +18 +14 +14 +# partial update of mergeable dt1 +explain update (select * from t1) as dt1 set dt1.a=2 where a < 18; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (select * from t1) as dt1 set dt1.a=2 where a < 18; +select * from t1; +a +18 +18 +18 +2 +2 +# partial update of mergeable dt2 defined as +# full select from mergeable derived table dt1 +explain update (select * from (select * from t1) as d1t) as dt2 +set dt2.a=22 where a > 16; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (select * from (select * from t1) as d1t) as dt2 +set dt2.a=22 where a > 16; +select * from t1; +a +22 +22 +22 +2 +2 +# full update of mergeable dt2 defined as +# partial select from mergeable derived table dt1 +explain update (select * from (select * from t1) as dt1 where dt1.a > 20) as dt2 +set dt2.a=24; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (select * from (select * from t1) as dt1 where dt1.a > 20) as dt2 +set dt2.a=24; +select * from t1; +a +24 +24 +24 +2 +2 +update t1 set a=26 limit 1; +select * from t1; +a +26 +24 +24 +2 +2 +# partial update of mergeable dt2 defined as +# partial select from mergeable derived table dt1 +explain update (select * from (select * from t1) as dt1 where dt1.a < 25) as dt2 +set dt2.a=15 where dt2.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (select * from (select * from t1) as dt1 where dt1.a < 25) as dt2 +set dt2.a=15 where dt2.a > 2; +select * from t1; +a +26 +15 +15 +2 +2 +create view v1 as select * from t1; +# partial update of mergeable dt1 defined as +# full select from mergeable view v1 +explain update (select * from v1) dt1 +set dt1.a=17 where dt1.a between 10 and 20; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (select * from v1) dt1 +set dt1.a=17 where dt1.a between 10 and 20; +select * from t1; +a +26 +17 +17 +2 +2 +# full update of mergeable dt1 defined as +# partial select from mergeable view v1 +explain update (select * from v1 where v1.a > 10) as dt1 +set dt1.a=23; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (select * from v1 where v1.a > 10) as dt1 +set dt1.a=23; +select * from t1; +a +23 +23 +23 +2 +2 +update t1 set a=28 limit 1; +select * from t1; +a +28 +23 +23 +2 +2 +# partial update of mergeable dt1 defined as +# partial select from mergeable view v1 +explain update (select * from v1 where v1.a < 27) as dt1 +set dt1.a=19 where dt1.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (select * from v1 where v1.a < 27) as dt1 +set dt1.a=19 where dt1.a > 2; +select * from t1; +a +28 +19 +19 +2 +2 +# partial update of mergeable dt1 defined as +# full select from mergeable embedded cte1 +explain update (with cte1 as (select * from t1) select * from cte1) dt1 +set dt1.a=11 where dt1.a between 10 and 20; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (with cte1 as (select * from t1) select * from cte1) dt1 +set dt1.a=11 where dt1.a between 10 and 20; +select * from t1; +a +28 +11 +11 +2 +2 +# full update of mergeable dt1 defined as +# partial select from mergeable embedded cte1 +explain update (with cte1 as (select * from t1) +select * from cte1 where cte1.a > 10) dt1 +set dt1.a=21; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (with cte1 as (select * from t1) +select * from cte1 where cte1.a > 10) dt1 +set dt1.a=21; +select * from t1; +a +21 +21 +21 +2 +2 +update t1 set a=29 limit 1; +select * from t1; +a +29 +21 +21 +2 +2 +# partial update of mergeable cte2 defined as +# partial select from mergeable embedded cte1 +explain update (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 27) dt1 +set dt1.a=13 where dt1.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 27) dt1 +set dt1.a=13 where dt1.a > 2; +select * from t1; +a +29 +13 +13 +2 +2 +drop view v1; +delete from t1; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +# partial update of mergeable dt3 defined as +# partial select from mergeable dt2 that uses mergeable dt1 +explain update (select * +from (select * +from (select * from t1) dt1 where dt1.a > 1) dt2 +where dt2.a < 8) dt3 +set dt3.a=dt3.a+1 +where dt3.a between 4 and 6; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (select * +from (select * +from (select * from t1) dt1 where dt1.a > 1) dt2 +where dt2.a < 8) dt3 +set dt3.a=dt3.a+1 +where dt3.a between 4 and 6; +select * from t1; +a +3 +8 +7 +1 +5 +3 +6 +2 +# partial update of mergeable dt2 defined as +# partial select from mergeable dt1 that uses mergeable cte1 +explain update (select * +from (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 8) dt1 +where dt1.a > 1) dt2 +set dt2.a=dt2.a-1 +where dt2.a between 5 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (select * +from (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 8) dt1 +where dt1.a > 1) dt2 +set dt2.a=dt2.a-1 +where dt2.a between 5 and 7; +select * from t1; +a +3 +8 +6 +1 +4 +3 +5 +2 +# partial update of mergeable dt2 defined as +# partial select from mergeable dt1 that uses mergeable view v1 +create view v1 as select * from t1; +explain update (select * +from (select * from v1 where v1.a < 8) dt1 +where dt1.a > 2) dt2 +set dt2.a=dt2.a+1 +where dt2.a between 2 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (select * +from (select * from v1 where v1.a < 8) dt1 +where dt1.a > 2) dt2 +set dt2.a=dt2.a+1 +where dt2.a between 2 and 5; +select * from t1; +a +4 +8 +6 +1 +5 +4 +6 +2 +drop view v1; +# partial update of mergeable dt2 defined as +# partial select from mergeable cte1 that uses mergeable dt1 +explain update (with cte1 as +(select * from (select * from t1) dt1 where dt1.a > 2) +select * from cte1 where cte1.a < 6) dt2 +set dt2.a=dt2.a-1 +where dt2.a between 4 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (with cte1 as +(select * from (select * from t1) dt1 where dt1.a > 2) +select * from cte1 where cte1.a < 6) dt2 +set dt2.a=dt2.a-1 +where dt2.a between 4 and 7; +select * from t1; +a +3 +8 +6 +1 +4 +3 +6 +2 +# partial update of mergeable dt1 defined as +# partial select from mergeable cte2 that uses mergeable cte1 +explain update (with cte2 as +(with cte1 as (select * from t1) +select * from cte1 where cte1.a > 3) +select * from cte2 where cte2.a < 10) dt1 +set dt1.a=dt1.a+1 +where dt1.a between 4 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (with cte2 as +(with cte1 as (select * from t1) +select * from cte1 where cte1.a > 3) +select * from cte2 where cte2.a < 10) dt1 +set dt1.a=dt1.a+1 +where dt1.a between 4 and 7; +select * from t1; +a +3 +8 +7 +1 +5 +3 +7 +2 +# partial update of mergeable dt1 defined as +# partial select from mergeable cte1 that uses mergeable v1 +create view v1 as select a from t1; +explain update (with cte1 as +(select * from v1 where v1.a > 1) +select * from cte1 where cte1.a < 7) dt1 +set dt1.a=dt1.a-1 +where dt1.a between 2 and 4; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (with cte1 as +(select * from v1 where v1.a > 1) +select * from cte1 where cte1.a < 7) dt1 +set dt1.a=dt1.a-1 +where dt1.a between 2 and 4; +select * from t1; +a +2 +8 +7 +1 +5 +2 +7 +1 +drop view v1; +# partial update of mergeable dt2 defined as +# partial select from mergeable v1 that uses mergeable dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a > 2; +explain update (select * from v1 where v1.a < 6) dt2 +set dt2.a=dt2.a+1 +where dt2.a between 4 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (select * from v1 where v1.a < 6) dt2 +set dt2.a=dt2.a+1 +where dt2.a between 4 and 5; +select * from t1; +a +2 +8 +7 +1 +6 +2 +7 +1 +drop view v1; +# partial update of mergeable dt1 defined as +# partial select from mergeable v1 that uses mergeable cte1 +create view v1 as +with cte1 as (select * from t1) select * from cte1 where cte1.a > 1; +explain update (select * from v1 where v1.a < 6) dt1 +set dt1.a=dt1.a-1 +where dt1.a between 2 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (select * from v1 where v1.a < 6) dt1 +set dt1.a=dt1.a-1 +where dt1.a between 2 and 5; +select * from t1; +a +1 +8 +7 +1 +6 +1 +7 +1 +drop view v1; +# partial update of mergeable dt1 defined as +# partial select from mergeable v2 that uses mergeable v1 +create view v1 as select a from t1; +create view v2 as select * from v1 where v1.a > 3; +explain update (select * from v2 where v2.a < 8) dt1 +set dt1.a=dt1.a+1 +where dt1.a between 5 and 10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update (select * from v2 where v2.a < 8) dt1 +set dt1.a=dt1.a+1 +where dt1.a between 5 and 10; +select * from t1; +a +1 +8 +8 +1 +7 +1 +8 +1 +drop view v2; +drop view v1; +drop table t1; diff --git a/mysql-test/main/derived_update.test b/mysql-test/main/derived_update.test new file mode 100644 index 0000000..58984d0 --- /dev/null +++ b/mysql-test/main/derived_update.test @@ -0,0 +1,226 @@ +create table t1 (a int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4); + +--echo # full update of mergeable derived table dt1 +let $q= +update (select a from t1) as dt1 set a=10; +eval explain $q; +eval $q; +select * from t1; +let $q= +update (select * from t1) as dt1 set a=14; +eval explain $q; +eval $q; +select * from t1; +--echo # update with limit of mergeable dt1 +let $q= +update (select * from t1) as dt1 set dt1.a=18 limit 3; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable dt1 +let $q= +update (select * from t1) as dt1 set dt1.a=2 where a < 18; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable dt2 defined as +--echo # full select from mergeable derived table dt1 +let $q= +update (select * from (select * from t1) as d1t) as dt2 + set dt2.a=22 where a > 16; +eval explain $q; +eval $q; +select * from t1; +--echo # full update of mergeable dt2 defined as +--echo # partial select from mergeable derived table dt1 +let $q= +update (select * from (select * from t1) as dt1 where dt1.a > 20) as dt2 + set dt2.a=24; +eval explain $q; +eval $q; +select * from t1; +update t1 set a=26 limit 1; +select * from t1; +--echo # partial update of mergeable dt2 defined as +--echo # partial select from mergeable derived table dt1 +let $q= +update (select * from (select * from t1) as dt1 where dt1.a < 25) as dt2 + set dt2.a=15 where dt2.a > 2; +eval explain $q; +eval $q; +select * from t1; + +create view v1 as select * from t1; + +--echo # partial update of mergeable dt1 defined as +--echo # full select from mergeable view v1 +let $q= +update (select * from v1) dt1 + set dt1.a=17 where dt1.a between 10 and 20; +eval explain $q; +eval $q; +select * from t1; +--echo # full update of mergeable dt1 defined as +--echo # partial select from mergeable view v1 +let $q= +update (select * from v1 where v1.a > 10) as dt1 + set dt1.a=23; +eval explain $q; +eval $q; +select * from t1; +update t1 set a=28 limit 1; +select * from t1; +--echo # partial update of mergeable dt1 defined as +--echo # partial select from mergeable view v1 +let $q= +update (select * from v1 where v1.a < 27) as dt1 + set dt1.a=19 where dt1.a > 2; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable dt1 defined as +--echo # full select from mergeable embedded cte1 +let $q= +update (with cte1 as (select * from t1) select * from cte1) dt1 + set dt1.a=11 where dt1.a between 10 and 20; +eval explain $q; +eval $q; +select * from t1; +--echo # full update of mergeable dt1 defined as +--echo # partial select from mergeable embedded cte1 +let $q= +update (with cte1 as (select * from t1) + select * from cte1 where cte1.a > 10) dt1 + set dt1.a=21; +eval explain $q; +eval $q; +select * from t1; +update t1 set a=29 limit 1; +select * from t1; +--echo # partial update of mergeable cte2 defined as +--echo # partial select from mergeable embedded cte1 +let $q= +update (with cte1 as (select * from t1) + select * from cte1 where cte1.a < 27) dt1 + set dt1.a=13 where dt1.a > 2; +eval explain $q; +eval $q; +select * from t1; + +drop view v1; + +delete from t1; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); + +--echo # partial update of mergeable dt3 defined as +--echo # partial select from mergeable dt2 that uses mergeable dt1 +let $q= +update (select * + from (select * + from (select * from t1) dt1 where dt1.a > 1) dt2 + where dt2.a < 8) dt3 +set dt3.a=dt3.a+1 +where dt3.a between 4 and 6; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable dt2 defined as +--echo # partial select from mergeable dt1 that uses mergeable cte1 +let $q= +update (select * + from (with cte1 as (select * from t1) + select * from cte1 where cte1.a < 8) dt1 + where dt1.a > 1) dt2 +set dt2.a=dt2.a-1 +where dt2.a between 5 and 7; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable dt2 defined as +--echo # partial select from mergeable dt1 that uses mergeable view v1 +create view v1 as select * from t1; +let $q= +update (select * + from (select * from v1 where v1.a < 8) dt1 + where dt1.a > 2) dt2 +set dt2.a=dt2.a+1 +where dt2.a between 2 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable dt2 defined as +--echo # partial select from mergeable cte1 that uses mergeable dt1 +let $q= +update (with cte1 as + (select * from (select * from t1) dt1 where dt1.a > 2) + select * from cte1 where cte1.a < 6) dt2 +set dt2.a=dt2.a-1 +where dt2.a between 4 and 7; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable dt1 defined as +--echo # partial select from mergeable cte2 that uses mergeable cte1 +let $q= +update (with cte2 as + (with cte1 as (select * from t1) + select * from cte1 where cte1.a > 3) + select * from cte2 where cte2.a < 10) dt1 +set dt1.a=dt1.a+1 +where dt1.a between 4 and 7; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable dt1 defined as +--echo # partial select from mergeable cte1 that uses mergeable v1 +create view v1 as select a from t1; +let $q= +update (with cte1 as + (select * from v1 where v1.a > 1) + select * from cte1 where cte1.a < 7) dt1 +set dt1.a=dt1.a-1 +where dt1.a between 2 and 4; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable dt2 defined as +--echo # partial select from mergeable v1 that uses mergeable dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a > 2; +let $q= +update (select * from v1 where v1.a < 6) dt2 +set dt2.a=dt2.a+1 +where dt2.a between 4 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable dt1 defined as +--echo # partial select from mergeable v1 that uses mergeable cte1 +create view v1 as + with cte1 as (select * from t1) select * from cte1 where cte1.a > 1; +let $q= +update (select * from v1 where v1.a < 6) dt1 +set dt1.a=dt1.a-1 +where dt1.a between 2 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable dt1 defined as +--echo # partial select from mergeable v2 that uses mergeable v1 +create view v1 as select a from t1; +create view v2 as select * from v1 where v1.a > 3; +let $q= +update (select * from v2 where v2.a < 8) dt1 +set dt1.a=dt1.a+1 +where dt1.a between 5 and 10; +eval explain $q; +eval $q; +select * from t1; +drop view v2; +drop view v1; + +drop table t1; diff --git a/mysql-test/main/derived_update_multi.result b/mysql-test/main/derived_update_multi.result new file mode 100644 index 0000000..3369854 --- /dev/null +++ b/mysql-test/main/derived_update_multi.result @@ -0,0 +1,2529 @@ +create table t1 (a int) engine=myisam; +create table t2 (b int) engine=myisam; +create table t3 (c int, d int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable derived table dt1 +# and mergeable derived table dt2 +explain select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +where dt1.a=dt2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +where dt1.a=dt2.b; +a b +5 5 +3 3 +3 3 +2 2 +2 2 +4 4 +explain update +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +set a=a+1, b=b+1 where dt1.a=dt2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +set a=a+1, b=b+1 where dt1.a=dt2.b; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +6 +10 +4 +9 +3 +3 +5 +6 +1 +# multi-table update of mergeable derived table dt1 +# and mergeable cte1 +explain with cte1 as (select * from t2 where b < 9) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +with cte1 as (select * from t2 where b < 9) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b; +a b +6 6 +4 4 +4 4 +3 3 +3 3 +5 5 +6 6 +explain with cte1 as (select * from t2 where b < 9) +update +(select a from t1 where a > 1) as dt1, cte1 +set dt1.a=dt1.a-1, cte1.b=cte1.b-1 where dt1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte1 as (select * from t2 where b < 9) +update +(select a from t1 where a > 1) as dt1, cte1 +set dt1.a=dt1.a-1, cte1.b=cte1.b-1 where dt1.a=cte1.b; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +5 +1 +# multi-table update of mergeable derived table dt1 +# and mergeable view v1 +create view v1 as select * from t2 where b < 5; +explain select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b; +a b +3 3 +3 3 +2 2 +2 2 +4 4 +explain update +(select a from t1 where a > 1) as dt1, v1 +set dt1.a=dt1.a+2, v1.b=v1.b+2 where dt1.a=v1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update +(select a from t1 where a > 1) as dt1, v1 +set dt1.a=dt1.a+2, v1.b=v1.b+2 where dt1.a=v1.b; +select * from t1; +a +5 +8 +7 +1 +6 +5 +5 +4 +select * from t2; +b +5 +10 +5 +9 +4 +4 +6 +5 +1 +drop view v1; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable derived table dt1 +# and non-mergeable derived table dt2 +explain select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +where dt1.a=dt2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +where dt1.a=dt2.b; +a b +3 3 +4 4 +3 3 +5 5 +2 2 +explain update +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +set a=a+1 where dt1.a=dt2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +set a=a+1 where dt1.a=dt2.b; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable derived table dt1 +# and non-mergeable cte1 +explain with cte1 as (select * from t2 where b < 9 group by b) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where b < 9 group by b) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b; +a b +4 4 +5 5 +4 4 +6 6 +3 3 +explain with cte1 as (select * from t2 where b < 9 group by b) +update +(select a from t1 where a > 1) as dt1, cte1 +set dt1.a=dt1.a-1 where dt1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where b < 9 group by b) +update +(select a from t1 where a > 1) as dt1, cte1 +set dt1.a=dt1.a-1 where dt1.a=cte1.b; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable derived table dt1 +# and non-mergeable view v1 +create view v1 as select * from t2 where b < 5 group by b; +explain select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b; +a b +3 3 +4 4 +3 3 +2 2 +explain update +(select a from t1 where a > 1) as dt1, v1 +set dt1.a=dt1.a+2 where dt1.a=v1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select a from t1 where a > 1) as dt1, v1 +set dt1.a=dt1.a+2 where dt1.a=v1.b; +select * from t1; +a +5 +8 +7 +1 +6 +5 +5 +4 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +# update of mergeable derived table dt3 specified as join of +# mergeable derived table dt1 and mergeable derived table dt2 +explain update +(select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +where dt1.a=dt2.b) dt3 +set dt3.a=dt3.a+1, dt3.b=dt3.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update +(select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +where dt1.a=dt2.b) dt3 +set dt3.a=dt3.a+1, dt3.b=dt3.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +6 +10 +4 +9 +3 +3 +5 +6 +1 +# update of mergeable derived table dt2 specified as join of +# mergeable derived table dt1 and mergeable cte1 +explain update +(with cte1 as (select b from t2 where b < 9) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b) dt2 +set dt2.a=dt2.a-1, dt2.b=dt2.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update +(with cte1 as (select b from t2 where b < 9) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b) dt2 +set dt2.a=dt2.a-1, dt2.b=dt2.b-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +5 +1 +# update of mergeable derived table dt2 specified as join of +# mergeable derived table dt1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +explain update +(select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b) dt2 +set dt2.a=dt2.a+1, dt2.b=dt2.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update +(select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b) dt2 +set dt2.a=dt2.a+1, dt2.b=dt2.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +4 +9 +3 +3 +5 +5 +1 +drop view v1; +# update of mergeable derived table dt1 specified as join of +# mergeable cte1 and mergeable cte2 +explain update +(with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6) +select * from cte1, cte2 where cte1.a=cte2.b) dt1 +set dt1.a=dt1.a-1, dt1.b=dt1.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update +(with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6) +select * from cte1, cte2 where cte1.a=cte2.b) dt1 +set dt1.a=dt1.a-1, dt1.b=dt1.b-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +4 +10 +3 +9 +2 +2 +4 +4 +1 +# update of mergeable derived table dt1 specified as join of +# mergeable cte1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +explain update +(with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b) dt1 +set dt1.a=dt1.a+1, dt1.b=dt1.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update +(with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b) dt1 +set dt1.a=dt1.a+1, dt1.b=dt1.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +4 +9 +3 +3 +5 +5 +1 +drop view v1; +# update of mergeable derived table dt1 specified as join of +# mergeable view v1 and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5; +explain update +(select * from v1, v2 where v1.a=v2.b) dt1 +set dt1.a=dt1.a-1, dt1.b=dt1.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update +(select * from v1, v2 where v1.a=v2.b) dt1 +set dt1.a=dt1.a-1, dt1.b=dt1.b-1; +select * from t1; +a +3 +8 +7 +1 +5 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +5 +5 +1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +# update of mergeable derived table dt3 specified as join of +# mergeable derived table dt1 and non-mergeable derived table dt2 +explain update +(select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +where dt1.a=dt2.b) dt3 +set dt3.a=dt3.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +where dt1.a=dt2.b) dt3 +set dt3.a=dt3.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# update of mergeable derived table dt2 specified as join of +# mergeable derived table dt1 and non-mergeable cte1 +explain update +(with cte1 as (select b from t2 where b < 9 group by b) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b) dt2 +set dt2.a=dt2.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(with cte1 as (select b from t2 where b < 9 group by b) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b) dt2 +set dt2.a=dt2.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# update of mergeable derived table dt2 specified as join of +# mergeable derived table dt1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 5 group by b; +explain update +(select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b) dt2 +set dt2.a=dt2.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b) dt2 +set dt2.a=dt2.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable derived table dt2 specified as join of +# mergeable cte1 and non-mergeable derived table dt1 +explain update +(with cte1 as (select a from t1 where a > 1) +select * from +cte1, (select b from t2 where b < 7 group by b) dt1 +where cte1.a=dt1.b) dt2 +set dt2.a=dt2.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(with cte1 as (select a from t1 where a > 1) +select * from +cte1, (select b from t2 where b < 7 group by b) dt1 +where cte1.a=dt1.b) dt2 +set dt2.a=dt2.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# update of mergeable derived table dt1 specified as join of +# mergeable cte1 and non-mergeable cte2 +explain update +(with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6 group by b) +select * from cte1, cte2 where cte1.a=cte2.b) dt1 +set dt1.a=dt1.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6 group by b) +select * from cte1, cte2 where cte1.a=cte2.b) dt1 +set dt1.a=dt1.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# update of mergeable derived table dt1 specified as join of +# mergeable cte1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 7 group by b; +explain update +(with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b) dt1 +set dt1.a=dt1.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b) dt1 +set dt1.a=dt1.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable derived table dt2 specified as join of +# mergeable view v1 and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +explain update +(select * from +v1, (select b from t2 where b < 6 group by b) dt1 +where v1.a=dt1.b) dt2 +set dt2.a=dt2.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select * from +v1, (select b from t2 where b < 6 group by b) dt1 +where v1.a=dt1.b) dt2 +set dt2.a=dt2.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable derived table dt1 specified as join of +# mergeable view v1 and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +explain with cte1 as (select b from t2 where b < 7 group by b) +update +(select * from v1, cte1 where v1.a=cte1.b) dt1 +set dt1.a=dt1.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select b from t2 where b < 7 group by b) +update +(select * from v1, cte1 where v1.a=cte1.b) dt1 +set dt1.a=dt1.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable derived table dt1 specified as join of +# mergeable view v1 and non-mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5 group by b; +explain update +(select * from v1, v2 where v1.a=v2.b) dt1 +set dt1.a=dt1.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select * from v1, v2 where v1.a=v2.b) dt1 +set dt1.a=dt1.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# mergeable derived table dt2 and mergeable derived table dt3 +explain select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +(select * from t2 where t2.b < 5) dt2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt3 +where dt1.a=dt2.b and dt2.b=dt3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +(select * from t2 where t2.b < 5) dt2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt3 +where dt1.a=dt2.b and dt2.b=dt3.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain update +(select * from t1 where t1.a > 2) dt1, +(select * from t2 where t2.b < 5) dt2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt3 +set dt1.a=dt1.a+1, dt2.b=dt2.b+1, dt3.c=dt3.c-dt3.d1 +where dt1.a=dt2.b and dt2.b=dt3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +update +(select * from t1 where t1.a > 2) dt1, +(select * from t2 where t2.b < 5) dt2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt3 +set dt1.a=dt1.a+1, dt2.b=dt2.b+1, dt3.c=dt3.c-dt3.d1 +where dt1.a=dt2.b and dt2.b=dt3.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# mergeable derived table dt2 and mergeable cte1 +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +(select * from t2 where t2.b < 10) dt2, +cte1 +where dt1.a=dt2.b and dt2.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +(select * from t2 where t2.b < 10) dt2, +cte1 +where dt1.a=dt2.b and dt2.b=cte1.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +(select * from t2 where t2.b < 10) dt2, +cte1 +set dt1.a=dt1.a-1, dt2.b=dt2.b-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=dt2.b and dt2.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +(select * from t2 where t2.b < 10) dt2, +cte1 +set dt1.a=dt1.a-1, dt2.b=dt2.b-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=dt2.b and dt2.b=cte1.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +# update of join of mergeable derived table dt1, +# mergeable derived table dt2 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +(select * from t2 where t2.b < 5) dt2, +v1 +where dt1.a=dt2.b and dt2.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +(select * from t2 where t2.b < 5) dt2, +v1 +where dt1.a=dt2.b and dt2.b=v1.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain update +(select * from t1 where t1.a < 3) dt1, +(select * from t2 where t2.b < 5) dt2, +v1 +set dt1.a=dt1.a+1, dt2.b=dt2.b+1, v1.c=v1.c+v1.d1 +where dt1.a=dt2.b and dt2.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +update +(select * from t1 where t1.a < 3) dt1, +(select * from t2 where t2.b < 5) dt2, +v1 +set dt1.a=dt1.a+1, dt2.b=dt2.b+1, v1.c=v1.c+v1.d1 +where dt1.a=dt2.b and dt2.b=v1.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# mergeable cte1 and mergeable derived table dt2 +explain with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=cte1.b and cte1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=cte1.b and cte1.b=dt2.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with cte1 as (select * from t2 where t2.b < 5) +update +(select * from t1 where t1.a > 2) dt1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, cte1.b=cte1.b+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=cte1.b and cte1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select * from t2 where t2.b < 5) +update +(select * from t1 where t1.a > 2) dt1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, cte1.b=cte1.b+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=cte1.b and cte1.b=dt2.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# mergeable cte1 and mergeable cte2 +explain with +cte1 as (select * from t2 where t2.b < 10), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +cte1, +cte2 +where dt1.a=cte1.b and cte1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with +cte1 as (select * from t2 where t2.b < 10), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +cte1, +cte2 +where dt1.a=cte1.b and cte1.b=cte2.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t2 where t2.b < 10), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +cte1, +cte2 +set dt1.a=dt1.a-1, cte1.b=cte1.b-1, cte2.c=cte2.c+cte2.d1 +where dt1.a=cte1.b and cte1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with +cte1 as (select * from t2 where t2.b < 10), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +cte1, +cte2 +set dt1.a=dt1.a-1, cte1.b=cte1.b-1, cte2.c=cte2.c+cte2.d1 +where dt1.a=cte1.b and cte1.b=cte2.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +# update of join of mergeable derived table dt1, +# mergeable cte1 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +cte1, +v1 +where dt1.a=cte1.b and cte1.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +cte1, +v1 +where dt1.a=cte1.b and cte1.b=v1.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain with cte1 as (select * from t2 where t2.b < 5) +update +(select * from t1 where t1.a < 3) dt1, +cte1, +v1 +set dt1.a=dt1.a+1, cte1.b=cte1.b+1, v1.c=v1.c+v1.d1 +where dt1.a=cte1.b and cte1.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select * from t2 where t2.b < 5) +update +(select * from t1 where t1.a < 3) dt1, +cte1, +v1 +set dt1.a=dt1.a+1, cte1.b=cte1.b+1, v1.c=v1.c+v1.d1 +where dt1.a=cte1.b and cte1.b=v1.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# mergeable view v1 and mergeable derived table dt2 +create view v1 as (select * from t2 where t2.b < 5); +explain select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=v1.b and v1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=v1.b and v1.b=dt2.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain update +(select * from t1 where t1.a > 2) dt1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, v1.b=v1.b+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=v1.b and v1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +update +(select * from t1 where t1.a > 2) dt1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, v1.b=v1.b+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=v1.b and v1.b=dt2.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +# update of join of mergeable derived table dt1, +# mergeable view v1 and mergeable cte1 +create view v1 as select * from t2 where t2.b < 10; +explain with +cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +v1, +cte1 +where dt1.a=v1.b and v1.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with +cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +v1, +cte1 +where dt1.a=v1.b and v1.b=cte1.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +v1, +cte1 +set dt1.a=dt1.a-1, v1.b=v1.b-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=v1.b and v1.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with +cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +v1, +cte1 +set dt1.a=dt1.a-1, v1.b=v1.b-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=v1.b and v1.b=cte1.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +# update of join of mergeable derived table dt1, +# mergeable view v1 and mergeable view v2 +create view v1 as select * from t2 where t2.b < 5; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +v1, +v2 +where dt1.a=v1.b and v1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +v1, +v2 +where dt1.a=v1.b and v1.b=v2.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain update +(select * from t1 where t1.a < 3) dt1, +v1, +v2 +set dt1.a=dt1.a+1, v1.b=v1.b+1, v2.c=v2.c+v2.d1 +where dt1.a=v1.b and v1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +update +(select * from t1 where t1.a < 3) dt1, +v1, +v2 +set dt1.a=dt1.a+1, v1.b=v1.b+1, v2.c=v2.c+v2.d1 +where dt1.a=v1.b and v1.b=v2.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# non-mergeable derived table dt2 and mergeable derived table dt3 +explain select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +(select * from t2 where t2.b < 5 group by b) dt2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt3 +where dt1.a=dt2.b and dt2.b=dt3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +(select * from t2 where t2.b < 5 group by b) dt2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt3 +where dt1.a=dt2.b and dt2.b=dt3.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain update +(select * from t1 where t1.a > 2) dt1, +(select * from t2 where t2.b < 5 group by b) dt2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt3 +set dt1.a=dt1.a+1, dt3.c=dt3.c-dt3.d1 +where dt1.a=dt2.b and dt2.b=dt3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select * from t1 where t1.a > 2) dt1, +(select * from t2 where t2.b < 5 group by b) dt2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt3 +set dt1.a=dt1.a+1, dt3.c=dt3.c-dt3.d1 +where dt1.a=dt2.b and dt2.b=dt3.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# non-mergeable derived table dt2 and mergeable cte1 +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +(select * from t2 where t2.b < 10 group by b) dt2, +cte1 +where dt1.a=dt2.b and dt2.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +(select * from t2 where t2.b < 10 group by b) dt2, +cte1 +where dt1.a=dt2.b and dt2.b=cte1.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +(select * from t2 where t2.b < 10 group by b) dt2, +cte1 +set dt1.a=dt1.a-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=dt2.b and dt2.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +(select * from t2 where t2.b < 10 group by b) dt2, +cte1 +set dt1.a=dt1.a-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=dt2.b and dt2.b=cte1.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +# update of join of mergeable derived table dt1, +# non-mergeable derived table dt2 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +(select * from t2 where t2.b < 5 group by b) dt2, +v1 +where dt1.a=dt2.b and dt2.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +(select * from t2 where t2.b < 5 group by b) dt2, +v1 +where dt1.a=dt2.b and dt2.b=v1.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain update +(select * from t1 where t1.a < 3) dt1, +(select * from t2 where t2.b < 5 group by b) dt2, +v1 +set dt1.a=dt1.a+1, v1.c=v1.c+v1.d1 +where dt1.a=dt2.b and dt2.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select * from t1 where t1.a < 3) dt1, +(select * from t2 where t2.b < 5 group by b) dt2, +v1 +set dt1.a=dt1.a+1, v1.c=v1.c+v1.d1 +where dt1.a=dt2.b and dt2.b=v1.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# non-mergeable cte1 and mergeable derived table dt2 +explain with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=cte1.b and cte1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=cte1.b and cte1.b=dt2.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with cte1 as (select * from t2 where t2.b < 5 group by b) +update +(select * from t1 where t1.a > 2) dt1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=cte1.b and cte1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where t2.b < 5 group by b) +update +(select * from t1 where t1.a > 2) dt1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=cte1.b and cte1.b=dt2.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# non-mergeable cte1 and mergeable cte2 +explain with +cte1 as (select * from t2 where t2.b < 10 group by b), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +cte1, +cte2 +where dt1.a=cte1.b and cte1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t2 where t2.b < 10 group by b), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +cte1, +cte2 +where dt1.a=cte1.b and cte1.b=cte2.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t2 where t2.b < 10 group by b), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +cte1, +cte2 +set dt1.a=dt1.a-1, cte2.c=cte2.c+cte2.d1 +where dt1.a=cte1.b and cte1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t2 where t2.b < 10 group by b), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +cte1, +cte2 +set dt1.a=dt1.a-1, cte2.c=cte2.c+cte2.d1 +where dt1.a=cte1.b and cte1.b=cte2.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +# update of join of mergeable derived table dt1, +# non-mergeable cte1 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +cte1, +v1 +where dt1.a=cte1.b and cte1.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +cte1, +v1 +where dt1.a=cte1.b and cte1.b=v1.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain with cte1 as (select * from t2 where t2.b < 5 group by b) +update +(select * from t1 where t1.a < 3) dt1, +cte1, +v1 +set dt1.a=dt1.a+1, v1.c=v1.c+v1.d1 +where dt1.a=cte1.b and cte1.b=v1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where t2.b < 5 group by b) +update +(select * from t1 where t1.a < 3) dt1, +cte1, +v1 +set dt1.a=dt1.a+1, v1.c=v1.c+v1.d1 +where dt1.a=cte1.b and cte1.b=v1.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable derived table dt1, +# non-mergeable view v1 and mergeable derived table dt2 +create view v1 as (select * from t2 where t2.b < 5 group by b); +explain select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=v1.b and v1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select a,b,c,d1 from +(select * from t1 where t1.a > 2) dt1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=v1.b and v1.b=dt2.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain update +(select * from t1 where t1.a > 2) dt1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=v1.b and v1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select * from t1 where t1.a > 2) dt1, +v1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=v1.b and v1.b=dt2.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +# update of join of mergeable derived table dt1, +# non-mergeable view v1 and mergeable cte1 +create view v1 as select * from t2 where t2.b < 10 group by b; +explain with +cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +v1, +cte1 +where dt1.a=v1.b and v1.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +(select * from t1 where t1.a > 5) dt1, +v1, +cte1 +where dt1.a=v1.b and v1.b=cte1.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +v1, +cte1 +set dt1.a=dt1.a-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=v1.b and v1.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +(select * from t1 where t1.a > 5) dt1, +v1, +cte1 +set dt1.a=dt1.a-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=v1.b and v1.b=cte1.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +# update of join of mergeable derived table dt1, +# non-mergeable view v1 and mergeable view v2 +create view v1 as select * from t2 where t2.b < 5 group by b; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +v1, +v2 +where dt1.a=v1.b and v1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select a,b,c,d1 from +(select * from t1 where t1.a < 3) dt1, +v1, +v2 +where dt1.a=v1.b and v1.b=v2.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain update +(select * from t1 where t1.a < 3) dt1, +v1, +v2 +set dt1.a=dt1.a+1, v2.c=v2.c+v2.d1 +where dt1.a=v1.b and v1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +(select * from t1 where t1.a < 3) dt1, +v1, +v2 +set dt1.a=dt1.a+1, v2.c=v2.c+v2.d1 +where dt1.a=v1.b and v1.b=v2.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +drop table t1,t2,t3; diff --git a/mysql-test/main/derived_update_multi.test b/mysql-test/main/derived_update_multi.test new file mode 100644 index 0000000..7db0848 --- /dev/null +++ b/mysql-test/main/derived_update_multi.test @@ -0,0 +1,860 @@ +create table t1 (a int) engine=myisam; +create table t2 (b int) engine=myisam; +create table t3 (c int, d int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +select * from t1; +select * from t2; +--echo # multi-table update of mergeable derived table dt1 +--echo # and mergeable derived table dt2 +let $qs= +select * from + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6) as dt2 +where dt1.a=dt2.b; +eval explain $qs; +eval $qs; +let $qu= +update + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6) as dt2 +set a=a+1, b=b+1 where dt1.a=dt2.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # multi-table update of mergeable derived table dt1 +--echo # and mergeable cte1 +let $qs= +with cte1 as (select * from t2 where b < 9) +select * from + (select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where b < 9) +update +(select a from t1 where a > 1) as dt1, cte1 +set dt1.a=dt1.a-1, cte1.b=cte1.b-1 where dt1.a=cte1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # multi-table update of mergeable derived table dt1 +--echo # and mergeable view v1 +create view v1 as select * from t2 where b < 5; +let $qs= +select * from + (select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b; +eval explain $qs; +eval $qs; +let $qu= +update +(select a from t1 where a > 1) as dt1, v1 +set dt1.a=dt1.a+2, v1.b=v1.b+2 where dt1.a=v1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +select * from t1; +select * from t2; +--echo # multi-table update of mergeable derived table dt1 +--echo # and non-mergeable derived table dt2 +let $qs= +select * from + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6 group by b) as dt2 +where dt1.a=dt2.b; +eval explain $qs; +eval $qs; +let $qu= +update + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6 group by b) as dt2 +set a=a+1 where dt1.a=dt2.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # multi-table update of mergeable derived table dt1 +--echo # and non-mergeable cte1 +let $qs= +with cte1 as (select * from t2 where b < 9 group by b) +select * from + (select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where b < 9 group by b) +update +(select a from t1 where a > 1) as dt1, cte1 +set dt1.a=dt1.a-1 where dt1.a=cte1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # multi-table update of mergeable derived table dt1 +--echo # and non-mergeable view v1 +create view v1 as select * from t2 where b < 5 group by b; +let $qs= +select * from + (select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b; +eval explain $qs; +eval $qs; +let $qu= +update +(select a from t1 where a > 1) as dt1, v1 +set dt1.a=dt1.a+2 where dt1.a=v1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +--echo # update of mergeable derived table dt3 specified as join of +--echo # mergeable derived table dt1 and mergeable derived table dt2 +let $qu= +update + (select * from + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6) as dt2 + where dt1.a=dt2.b) dt3 +set dt3.a=dt3.a+1, dt3.b=dt3.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable derived table dt2 specified as join of +--echo # mergeable derived table dt1 and mergeable cte1 +let $qu= +update + (with cte1 as (select b from t2 where b < 9) + select * from + (select a from t1 where a > 1) as dt1, cte1 + where dt1.a=cte1.b) dt2 +set dt2.a=dt2.a-1, dt2.b=dt2.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable derived table dt2 specified as join of +--echo # mergeable derived table dt1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +let $qu= +update + (select * from + (select a from t1 where a > 1) as dt1, v1 + where dt1.a=v1.b) dt2 +set dt2.a=dt2.a+1, dt2.b=dt2.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable derived table dt1 specified as join of +--echo # mergeable cte1 and mergeable cte2 +let $qu= +update + (with cte1 as (select a from t1 where a > 1), + cte2 as (select b from t2 where b < 6) + select * from cte1, cte2 where cte1.a=cte2.b) dt1 +set dt1.a=dt1.a-1, dt1.b=dt1.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable derived table dt1 specified as join of +--echo # mergeable cte1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +let $qu= +update + (with cte1 as (select a from t1 where a > 1) + select * from cte1, v1 where cte1.a=v1.b) dt1 +set dt1.a=dt1.a+1, dt1.b=dt1.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable derived table dt1 specified as join of +--echo # mergeable view v1 and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5; +let $qu= +update + (select * from v1, v2 where v1.a=v2.b) dt1 +set dt1.a=dt1.a-1, dt1.b=dt1.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +--echo # update of mergeable derived table dt3 specified as join of +--echo # mergeable derived table dt1 and non-mergeable derived table dt2 +let $qu= +update + (select * from + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6 group by b) as dt2 + where dt1.a=dt2.b) dt3 +set dt3.a=dt3.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable derived table dt2 specified as join of +--echo # mergeable derived table dt1 and non-mergeable cte1 +let $qu= +update + (with cte1 as (select b from t2 where b < 9 group by b) + select * from + (select a from t1 where a > 1) as dt1, cte1 + where dt1.a=cte1.b) dt2 +set dt2.a=dt2.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable derived table dt2 specified as join of +--echo # mergeable derived table dt1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 5 group by b; +let $qu= +update + (select * from + (select a from t1 where a > 1) as dt1, v1 + where dt1.a=v1.b) dt2 +set dt2.a=dt2.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable derived table dt2 specified as join of +--echo # mergeable cte1 and non-mergeable derived table dt1 +let $qu= +update + (with cte1 as (select a from t1 where a > 1) + select * from + cte1, (select b from t2 where b < 7 group by b) dt1 + where cte1.a=dt1.b) dt2 +set dt2.a=dt2.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable derived table dt1 specified as join of +--echo # mergeable cte1 and non-mergeable cte2 +let $qu= +update + (with cte1 as (select a from t1 where a > 1), + cte2 as (select b from t2 where b < 6 group by b) + select * from cte1, cte2 where cte1.a=cte2.b) dt1 +set dt1.a=dt1.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +--echo # update of mergeable derived table dt1 specified as join of +--echo # mergeable cte1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 7 group by b; +let $qu= +update + (with cte1 as (select a from t1 where a > 1) + select * from cte1, v1 where cte1.a=v1.b) dt1 +set dt1.a=dt1.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable derived table dt2 specified as join of +--echo # mergeable view v1 and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +let $qu= +update + (select * from + v1, (select b from t2 where b < 6 group by b) dt1 + where v1.a=dt1.b) dt2 +set dt2.a=dt2.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable derived table dt1 specified as join of +--echo # mergeable view v1 and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +let $qu= +with cte1 as (select b from t2 where b < 7 group by b) +update + (select * from v1, cte1 where v1.a=cte1.b) dt1 +set dt1.a=dt1.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable derived table dt1 specified as join of +--echo # mergeable view v1 and non-mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5 group by b; +let $qu= +update + (select * from v1, v2 where v1.a=v2.b) dt1 +set dt1.a=dt1.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable derived table dt1, +--echo # mergeable derived table dt2 and mergeable derived table dt3 +let $qs= +select a,b,c,d1 from + (select * from t1 where t1.a > 2) dt1, + (select * from t2 where t2.b < 5) dt2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt3 +where dt1.a=dt2.b and dt2.b=dt3.c; +eval explain $qs; +eval $qs; +let $qu= +update + (select * from t1 where t1.a > 2) dt1, + (select * from t2 where t2.b < 5) dt2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt3 +set dt1.a=dt1.a+1, dt2.b=dt2.b+1, dt3.c=dt3.c-dt3.d1 +where dt1.a=dt2.b and dt2.b=dt3.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable derived table dt1, +--echo # mergeable derived table dt2 and mergeable cte1 +let $qs= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + (select * from t1 where t1.a > 5) dt1, + (select * from t2 where t2.b < 10) dt2, + cte1 +where dt1.a=dt2.b and dt2.b=cte1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + (select * from t1 where t1.a > 5) dt1, + (select * from t2 where t2.b < 10) dt2, + cte1 +set dt1.a=dt1.a-1, dt2.b=dt2.b-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=dt2.b and dt2.b=cte1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable derived table dt1, +--echo # mergeable derived table dt2 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +select a,b,c,d1 from + (select * from t1 where t1.a < 3) dt1, + (select * from t2 where t2.b < 5) dt2, + v1 +where dt1.a=dt2.b and dt2.b=v1.c; +eval explain $qs; +eval $qs; +let $qu= +update + (select * from t1 where t1.a < 3) dt1, + (select * from t2 where t2.b < 5) dt2, + v1 +set dt1.a=dt1.a+1, dt2.b=dt2.b+1, v1.c=v1.c+v1.d1 +where dt1.a=dt2.b and dt2.b=v1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable derived table dt1, +--echo # mergeable cte1 and mergeable derived table dt2 +let $qs= +with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from + (select * from t1 where t1.a > 2) dt1, + cte1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=cte1.b and cte1.b=dt2.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where t2.b < 5) +update + (select * from t1 where t1.a > 2) dt1, + cte1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, cte1.b=cte1.b+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=cte1.b and cte1.b=dt2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable derived table dt1, +--echo # mergeable cte1 and mergeable cte2 +let $qs= +with + cte1 as (select * from t2 where t2.b < 10), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + (select * from t1 where t1.a > 5) dt1, + cte1, + cte2 +where dt1.a=cte1.b and cte1.b=cte2.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t2 where t2.b < 10), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + (select * from t1 where t1.a > 5) dt1, + cte1, + cte2 +set dt1.a=dt1.a-1, cte1.b=cte1.b-1, cte2.c=cte2.c+cte2.d1 +where dt1.a=cte1.b and cte1.b=cte2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable derived table dt1, +--echo # mergeable cte1 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from + (select * from t1 where t1.a < 3) dt1, + cte1, + v1 +where dt1.a=cte1.b and cte1.b=v1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where t2.b < 5) +update + (select * from t1 where t1.a < 3) dt1, + cte1, + v1 +set dt1.a=dt1.a+1, cte1.b=cte1.b+1, v1.c=v1.c+v1.d1 +where dt1.a=cte1.b and cte1.b=v1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable derived table dt1, +--echo # mergeable view v1 and mergeable derived table dt2 +create view v1 as (select * from t2 where t2.b < 5); +let $qs= +select a,b,c,d1 from + (select * from t1 where t1.a > 2) dt1, + v1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=v1.b and v1.b=dt2.c; +eval explain $qs; +eval $qs; +let $qu= +update + (select * from t1 where t1.a > 2) dt1, + v1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, v1.b=v1.b+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=v1.b and v1.b=dt2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable derived table dt1, +--echo # mergeable view v1 and mergeable cte1 +create view v1 as select * from t2 where t2.b < 10; +let $qs= +with + cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + (select * from t1 where t1.a > 5) dt1, + v1, + cte1 +where dt1.a=v1.b and v1.b=cte1.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + (select * from t1 where t1.a > 5) dt1, + v1, + cte1 +set dt1.a=dt1.a-1, v1.b=v1.b-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=v1.b and v1.b=cte1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable derived table dt1, +--echo # mergeable view v1 and mergeable view v2 +create view v1 as select * from t2 where t2.b < 5; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +select a,b,c,d1 from + (select * from t1 where t1.a < 3) dt1, + v1, + v2 +where dt1.a=v1.b and v1.b=v2.c; +eval explain $qs; +eval $qs; +let $qu= +update + (select * from t1 where t1.a < 3) dt1, + v1, + v2 +set dt1.a=dt1.a+1, v1.b=v1.b+1, v2.c=v2.c+v2.d1 +where dt1.a=v1.b and v1.b=v2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable derived table dt2 and mergeable derived table dt3 +let $qs= +select a,b,c,d1 from + (select * from t1 where t1.a > 2) dt1, + (select * from t2 where t2.b < 5 group by b) dt2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt3 +where dt1.a=dt2.b and dt2.b=dt3.c; +eval explain $qs; +eval $qs; +let $qu= +update + (select * from t1 where t1.a > 2) dt1, + (select * from t2 where t2.b < 5 group by b) dt2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt3 +set dt1.a=dt1.a+1, dt3.c=dt3.c-dt3.d1 +where dt1.a=dt2.b and dt2.b=dt3.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable derived table dt2 and mergeable cte1 +let $qs= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + (select * from t1 where t1.a > 5) dt1, + (select * from t2 where t2.b < 10 group by b) dt2, + cte1 +where dt1.a=dt2.b and dt2.b=cte1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + (select * from t1 where t1.a > 5) dt1, + (select * from t2 where t2.b < 10 group by b) dt2, + cte1 +set dt1.a=dt1.a-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=dt2.b and dt2.b=cte1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable derived table dt2 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +select a,b,c,d1 from + (select * from t1 where t1.a < 3) dt1, + (select * from t2 where t2.b < 5 group by b) dt2, + v1 +where dt1.a=dt2.b and dt2.b=v1.c; +eval explain $qs; +eval $qs; +let $qu= +update + (select * from t1 where t1.a < 3) dt1, + (select * from t2 where t2.b < 5 group by b) dt2, + v1 +set dt1.a=dt1.a+1, v1.c=v1.c+v1.d1 +where dt1.a=dt2.b and dt2.b=v1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable cte1 and mergeable derived table dt2 +let $qs= +with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from + (select * from t1 where t1.a > 2) dt1, + cte1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=cte1.b and cte1.b=dt2.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where t2.b < 5 group by b) +update + (select * from t1 where t1.a > 2) dt1, + cte1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=cte1.b and cte1.b=dt2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable cte1 and mergeable cte2 +let $qs= +with + cte1 as (select * from t2 where t2.b < 10 group by b), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + (select * from t1 where t1.a > 5) dt1, + cte1, + cte2 +where dt1.a=cte1.b and cte1.b=cte2.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t2 where t2.b < 10 group by b), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + (select * from t1 where t1.a > 5) dt1, + cte1, + cte2 +set dt1.a=dt1.a-1, cte2.c=cte2.c+cte2.d1 +where dt1.a=cte1.b and cte1.b=cte2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable cte1 and mergeable view v1 +create view v1 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from + (select * from t1 where t1.a < 3) dt1, + cte1, + v1 +where dt1.a=cte1.b and cte1.b=v1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where t2.b < 5 group by b) +update + (select * from t1 where t1.a < 3) dt1, + cte1, + v1 +set dt1.a=dt1.a+1, v1.c=v1.c+v1.d1 +where dt1.a=cte1.b and cte1.b=v1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable view v1 and mergeable derived table dt2 +create view v1 as (select * from t2 where t2.b < 5 group by b); +let $qs= +select a,b,c,d1 from + (select * from t1 where t1.a > 2) dt1, + v1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where dt1.a=v1.b and v1.b=dt2.c; +eval explain $qs; +eval $qs; +let $qu= +update + (select * from t1 where t1.a > 2) dt1, + v1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set dt1.a=dt1.a+1, dt2.c=dt2.c-dt2.d1 +where dt1.a=v1.b and v1.b=dt2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable view v1 and mergeable cte1 +create view v1 as select * from t2 where t2.b < 10 group by b; +let $qs= +with + cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + (select * from t1 where t1.a > 5) dt1, + v1, + cte1 +where dt1.a=v1.b and v1.b=cte1.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + (select * from t1 where t1.a > 5) dt1, + v1, + cte1 +set dt1.a=dt1.a-1, cte1.c=cte1.c+cte1.d1 +where dt1.a=v1.b and v1.b=cte1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable derived table dt1, +--echo # non-mergeable view v1 and mergeable view v2 +create view v1 as select * from t2 where t2.b < 5 group by b; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +select a,b,c,d1 from + (select * from t1 where t1.a < 3) dt1, + v1, + v2 +where dt1.a=v1.b and v1.b=v2.c; +eval explain $qs; +eval $qs; +let $qu= +update + (select * from t1 where t1.a < 3) dt1, + v1, + v2 +set dt1.a=dt1.a+1, v2.c=v2.c+v2.d1 +where dt1.a=v1.b and v1.b=v2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; + +drop table t1,t2,t3; diff --git a/mysql-test/main/view.result b/mysql-test/main/view.result index 55d95b2..b3a45bf 100644 --- a/mysql-test/main/view.result +++ b/mysql-test/main/view.result @@ -1114,13 +1114,13 @@ ERROR 44000: CHECK OPTION failed `test`.`v2` insert into v3 values (0); ERROR 44000: CHECK OPTION failed `test`.`v3` insert into v2 values (2); +ERROR 44000: CHECK OPTION failed `test`.`v2` insert into v3 values (2); ERROR 44000: CHECK OPTION failed `test`.`v3` select * from t1; a 1 1 -2 drop view v3,v2,v1; drop table t1; create table t1 (a int, primary key (a)); @@ -1955,7 +1955,6 @@ insert into t1 values (19,41,32); create view v1 as select f59, f60 from t1 where f59 in (select f59 from t1); update v1 set f60=2345; -ERROR HY000: The target table v1 of the UPDATE is not updatable drop view v1; drop table t1; create table t1 (s1 int); @@ -6490,56 +6489,47 @@ CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1 insert into v1 values (-300); ERROR HY000: The target table v1 of the INSERT is not insertable-into update v1 set s1=s1+1; -ERROR HY000: The target table v1 of the UPDATE is not updatable drop view v1; CREATE VIEW v1 AS SELECT s1,s2 FROM (SELECT s1 as s2 FROM t1 WHERE s1 < 100) x, t1 WHERE t1.s1=x.s2; select * from v1; s1 s2 1 1 -2 2 3 3 +4 4 -200 -200 insert into v1 (s1) values (-300); update v1 set s1=s1+1; select * from v1; s1 s2 2 2 -3 3 4 4 +5 5 -199 -199 -299 -299 select * from t1; s1 2 -3 4 +5 200 -199 -299 insert into v1(s2) values (-300); ERROR HY000: The target table v1 of the INSERT is not insertable-into update v1 set s2=s2+1; -ERROR HY000: The target table v1 of the UPDATE is not updatable drop view v1; CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM t1 WHERE s1 < 100) AS x; insert into v1 values (-300); ERROR HY000: The target table v1 of the INSERT is not insertable-into update v1 set s1=s1+1; -ERROR HY000: The target table v1 of the UPDATE is not updatable drop view v1; CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1 < 100) as xx WHERE s1>1) AS x; -insert into v1 values (-300); -ERROR HY000: The target table v1 of the INSERT is not insertable-into update v1 set s1=s1+1; -ERROR HY000: The target table v1 of the UPDATE is not updatable create view v2 as select * from v1; -insert into v2 values (-300); -ERROR HY000: The target table v2 of the INSERT is not insertable-into update v2 set s1=s1+1; -ERROR HY000: The target table v2 of the UPDATE is not updatable drop view v1, v2; drop table t1; # @@ -6554,7 +6544,7 @@ INSERT INTO t3 VALUES (1),(8); CREATE VIEW v1 AS SELECT * FROM t1 LEFT JOIN ( SELECT t2.* FROM t2 INNER JOIN t3 ON ( k = j ) ) AS alias1 ON ( i = j ); 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 select `test`.`t1`.`i` AS `i`,`alias1`.`j` AS `j` from (`test`.`t1` left join (select `test`.`t2`.`j` AS `j` from (`test`.`t2` join `test`.`t3` on(`test`.`t3`.`k` = `test`.`t2`.`j`))) `alias1` on(`test`.`t1`.`i` = `alias1`.`j`)) latin1 latin1_swedish_ci +v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS select `t1`.`i` AS `i`,`alias1`.`j` AS `j` from (`t1` left join (select `t2`.`j` AS `j` from (`t2` join `t3` on(`t3`.`k` = `t2`.`j`))) `alias1` on(`t1`.`i` = `alias1`.`j`)) latin1 latin1_swedish_ci SELECT * FROM t1 LEFT JOIN ( SELECT t2.* FROM t2 INNER JOIN t3 ON ( k = j ) ) AS alias1 ON ( i = j ); i j 3 NULL @@ -6637,7 +6627,7 @@ CREATE VIEW v AS SELECT * FROM ( SELECT * FROM t ) sq; DROP TABLE IF EXISTS t; SHOW CREATE VIEW v; View Create View character_set_client collation_connection -v CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v` AS select `sq`.`i` AS `i` from (select `test`.`t`.`i` AS `i` from `test`.`t`) `sq` latin1 latin1_swedish_ci +v CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v` AS select `sq`.`i` AS `i` from (select `test`.`t`.`i` AS `i` from `t`) `sq` latin1 latin1_swedish_ci Warnings: Warning 1356 View 'test.v' references invalid table(s) or column(s) or function(s) or definer/invoker of view lack rights to use them DROP VIEW v; @@ -6712,7 +6702,7 @@ EXECUTE stmt; DEALLOCATE PREPARE stmt; 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 select `testalias`.`testcase` AS `testcase` from (select case when 1 in (select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` < 2) then 1 end AS `testcase`) `testalias` latin1 latin1_swedish_ci +v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS select `testalias`.`testcase` AS `testcase` from (select case when 1 in (select `t1`.`a` from `t1` where `t1`.`a` < 2) then 1 end AS `testcase`) `testalias` latin1 latin1_swedish_ci SELECT * FROM v1; testcase 1 diff --git a/mysql-test/main/view.test b/mysql-test/main/view.test index 1632e61..6df36ff 100644 --- a/mysql-test/main/view.test +++ b/mysql-test/main/view.test @@ -1020,6 +1020,7 @@ insert into v3 values (1); insert into v2 values (0); -- error ER_VIEW_CHECK_FAILED insert into v3 values (0); +-- error ER_VIEW_CHECK_FAILED insert into v2 values (2); -- error ER_VIEW_CHECK_FAILED insert into v3 values (2); @@ -1734,7 +1735,7 @@ create table t1 (f59 int, f60 int, f61 int); insert into t1 values (19,41,32); create view v1 as select f59, f60 from t1 where f59 in (select f59 from t1); --- error ER_NON_UPDATABLE_TABLE +# -- error ER_NON_UPDATABLE_TABLE update v1 set f60=2345; drop view v1; drop table t1; @@ -6192,7 +6193,7 @@ CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1 --error ER_NON_INSERTABLE_TABLE insert into v1 values (-300); ---error ER_NON_UPDATABLE_TABLE +# --error ER_NON_UPDATABLE_TABLE update v1 set s1=s1+1; drop view v1; @@ -6207,7 +6208,7 @@ select * from v1; select * from t1; --error ER_NON_INSERTABLE_TABLE insert into v1(s2) values (-300); ---error ER_NON_UPDATABLE_TABLE +# --error ER_NON_UPDATABLE_TABLE update v1 set s2=s2+1; drop view v1; @@ -6217,7 +6218,7 @@ CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM t1 WHERE s1 --error ER_NON_INSERTABLE_TABLE insert into v1 values (-300); ---error ER_NON_UPDATABLE_TABLE +# --error ER_NON_UPDATABLE_TABLE update v1 set s1=s1+1; drop view v1; @@ -6225,16 +6226,16 @@ drop view v1; CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1 < 100) as xx WHERE s1>1) AS x; ---error ER_NON_INSERTABLE_TABLE -insert into v1 values (-300); ---error ER_NON_UPDATABLE_TABLE +# --error ER_NON_INSERTABLE_TABLE +# insert into v1 values (-300); +# --error ER_NON_UPDATABLE_TABLE update v1 set s1=s1+1; create view v2 as select * from v1; ---error ER_NON_INSERTABLE_TABLE -insert into v2 values (-300); ---error ER_NON_UPDATABLE_TABLE +# --error ER_NON_INSERTABLE_TABLE +# insert into v2 values (-300); +# --error ER_NON_UPDATABLE_TABLE update v2 set s1=s1+1; drop view v1, v2; diff --git a/mysql-test/main/view_update.result b/mysql-test/main/view_update.result new file mode 100644 index 0000000..fd3259f --- /dev/null +++ b/mysql-test/main/view_update.result @@ -0,0 +1,412 @@ +create table t1 (a int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4); +# full update of mergeable view v1 +create view v1 as select * from t1; +explain update v1 set a=10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +update v1 set a=10; +select * from t1; +a +10 +10 +10 +10 +10 +explain update v1 set a=14; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +update v1 set a=14; +select * from t1; +a +14 +14 +14 +14 +14 +# update with limit of mergeable view v1 +explain update v1 set v1.a=18 limit 3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +update v1 set v1.a=18 limit 3; +select * from t1; +a +18 +18 +18 +14 +14 +# partial update of mergeable view v1 +explain update v1 set v1.a=2 where a<18; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v1 set v1.a=2 where a<18; +select * from t1; +a +18 +18 +18 +2 +2 +drop view v1; +# partial update of mergeable v1 defined as +# full select from mergeable derived table dt1 +create view v1 as select * from (select * from t1) dt1; +explain update v1 set v1.a=22 where a>16; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v1 set v1.a=22 where a>16; +select * from t1; +a +22 +22 +22 +2 +2 +drop view v1; +# full update of mergeable v1 defined as +# partial select from mergeable derived table dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a > 20; +explain update v1 set v1.a=24; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v1 set v1.a=24; +select * from t1; +a +24 +24 +24 +2 +2 +drop view v1; +update t1 set a=26 limit 1; +select * from t1; +a +26 +24 +24 +2 +2 +# partial update of mergeable v1 defined as +# partial select from mergeable derived table dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a < 25; +explain update v1 set v1.a=15 where v1.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v1 set v1.a=15 where v1.a > 2; +select * from t1; +a +26 +15 +15 +2 +2 +drop view v1; +create view v1 as select * from t1; +# partial update of mergeable v2 defined as +# full select from mergeable view v1 +create view v2 as select * from v1; +explain update v2 set v2.a=17 where v2.a between 10 and 20; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v2 set v2.a=17 where v2.a between 10 and 20; +select * from t1; +a +26 +17 +17 +2 +2 +drop view v2; +# full update of mergeable v2 defined as +# partial select from mergeable view v1 +create view v2 as select * from v1 where v1.a > 10; +explain update v2 set v2.a=23; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v2 set v2.a=23; +select * from t1; +a +23 +23 +23 +2 +2 +drop view v2; +update t1 set a=28 limit 1; +select * from t1; +a +28 +23 +23 +2 +2 +# partial update of mergeable cte1 defined as +# partial select from mergeable view v1 +create view v2 as select * from v1 where v1.a < 27; +explain update v2 set v2.a=19 where v2.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v2 set v2.a=19 where v2.a > 2; +select * from t1; +a +28 +19 +19 +2 +2 +drop view v2; +drop view v1; +# partial update of mergeable v1 defined as +# full select from mergeable cte1 +create view v1 as with cte1 as (select * from t1) select * from cte1; +explain update v1 set v1.a=11 where v1.a between 10 and 20; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v1 set v1.a=11 where v1.a between 10 and 20; +select * from t1; +a +28 +11 +11 +2 +2 +drop view v1; +# full update of mergeable v1 defined as +# partial select from mergeable cte1 +create view v1 as +with cte1 as (select * from t1)select * from cte1 where cte1.a > 10; +explain update v1 set v1.a=21; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v1 set v1.a=21; +select * from t1; +a +21 +21 +21 +2 +2 +drop view v1; +update t1 set a=29 limit 1; +select * from t1; +a +29 +21 +21 +2 +2 +# partial update of mergeable v1 defined as +# partial select from mergeable embedded cte1 +create view v1 as +with cte1 as (select * from t1) select * from cte1 where cte1.a < 27; +explain update v1 set v1.a=13 where v1.a > 2; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where +update v1 set v1.a=13 where v1.a > 2; +select * from t1; +a +29 +13 +13 +2 +2 +drop view v1; +delete from t1; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +# partial update of mergeable v1 defined as +# partial select from mergeable dt2 that uses mergeable dt1 +create view v1 as +(select * +from (select * from (select * from t1) dt1 where dt1.a > 1) dt2 +where dt2.a < 8); +explain update v1 set v1.a=v1.a+1 where v1.a between 4 and 6; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v1 set v1.a=v1.a+1 where v1.a between 4 and 6; +select * from t1; +a +3 +8 +7 +1 +5 +3 +6 +2 +drop view v1; +# partial update of mergeable v1 defined as +# partial select from mergeable dt1 that uses mergeable cte1 +create view v1 as +(select * +from (with cte1 as (select * from t1) +select * from cte1 where cte1.a < 8) dt1 +where dt1.a > 1); +explain update v1 set v1.a=v1.a-1 where v1.a between 5 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v1 set v1.a=v1.a-1 where v1.a between 5 and 7; +select * from t1; +a +3 +8 +6 +1 +4 +3 +5 +2 +drop view v1; +# partial update of mergeable v2 defined as +# partial select from mergeable dt1 that uses mergeable view v1 +create view v1 as select * from t1; +create view v2 as +select * +from (select * from v1 where v1.a < 8) dt1 +where dt1.a > 2; +explain update v2 set v2.a=v2.a+1 where v2.a between 2 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v2 set v2.a=v2.a+1 where v2.a between 2 and 5; +select * from t1; +a +4 +8 +6 +1 +5 +4 +6 +2 +drop view v2; +drop view v1; +# partial update of mergeable v1 defined as +# partial select from mergeable cte1 that uses mergeable dt1 +create view v1 as +with cte1 as +(select * from (select * from t1) dt1 where dt1.a > 2) +select * from cte1 where cte1.a < 6; +explain update v1 set v1.a=v1.a-1 where v1.a between 4 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v1 set v1.a=v1.a-1 where v1.a between 4 and 7; +select * from t1; +a +3 +8 +6 +1 +4 +3 +6 +2 +drop view v1; +# partial update of mergeable v1 defined as +# partial select from mergeable cte2 that uses mergeable cte1 +create view v1 as +with cte2 as +(with cte1 as (select * from t1) +select * from cte1 where cte1.a > 3) +select * from cte2 where cte2.a < 10; +explain update v1 set v1.a=v1.a+1 where v1.a between 4 and 7; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v1 set v1.a=v1.a+1 where v1.a between 4 and 7; +select * from t1; +a +3 +8 +7 +1 +5 +3 +7 +2 +drop view v1; +# partial update of mergeable v2 defined as +# partial select from mergeable cte1 that uses mergeable v1 +create view v1 as select a from t1; +create view v2 as +with cte1 as +(select * from v1 where v1.a > 1) +select * from cte1 where cte1.a < 7; +explain update v2 set v2.a=v2.a-1 where v2.a between 2 and 4; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v2 set v2.a=v2.a-1 where v2.a between 2 and 4; +select * from t1; +a +2 +8 +7 +1 +5 +2 +7 +1 +drop view v2; +drop view v1; +# partial update of mergeable v2 defined as +# partial select from mergeable v1 that uses mergeable dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a > 2; +create view v2 as select * from v1 where v1.a < 6; +explain update v2 set v2.a=v2.a+1 where v2.a between 4 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v2 set v2.a=v2.a+1 where v2.a between 4 and 5; +select * from t1; +a +2 +8 +7 +1 +6 +2 +7 +1 +drop view v2; +drop view v1; +# partial update of mergeable v2 defined as +# partial select from mergeable v1 that uses mergeable cte1 +create view v1 as +with cte1 as (select * from t1) select * from cte1 where cte1.a > 1; +create view v2 as select * from v1 where v1.a < 6; +explain update v2 set v2.a=v2.a-1 where v2.a between 2 and 5; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v2 set v2.a=v2.a-1 where v2.a between 2 and 5; +select * from t1; +a +1 +8 +7 +1 +6 +1 +7 +1 +drop view v2; +drop view v1; +# partial update of mergeable v3 defined as +# partial select from mergeable v2 that uses mergeable v1 +create view v1 as select a from t1; +create view v2 as select * from v1 where v1.a > 3; +create view v3 as select * from v2 where v2.a < 8; +explain update v3 set v3.a=v3.a+1 where v3.a between 5 and 10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +update v3 set v3.a=v3.a+1 where v3.a between 5 and 10; +select * from t1; +a +1 +8 +8 +1 +7 +1 +8 +1 +drop view v3; +drop view v2; +drop view v1; +drop table t1; diff --git a/mysql-test/main/view_update.test b/mysql-test/main/view_update.test new file mode 100644 index 0000000..dc074fa --- /dev/null +++ b/mysql-test/main/view_update.test @@ -0,0 +1,241 @@ +create table t1 (a int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4); +--echo # full update of mergeable view v1 +create view v1 as select * from t1; +let $q= +update v1 set a=10; +eval explain $q; +eval $q; +select * from t1; +let $q= +update v1 set a=14; +eval explain $q; +eval $q; +select * from t1; +--echo # update with limit of mergeable view v1 +let $q= +update v1 set v1.a=18 limit 3; +eval explain $q; +eval $q; +select * from t1; +--echo # partial update of mergeable view v1 +let $q= +update v1 set v1.a=2 where a<18; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable v1 defined as +--echo # full select from mergeable derived table dt1 +create view v1 as select * from (select * from t1) dt1; +let $q= +update v1 set v1.a=22 where a>16; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # full update of mergeable v1 defined as +--echo # partial select from mergeable derived table dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a > 20; +let $q= +update v1 set v1.a=24; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +update t1 set a=26 limit 1; +select * from t1; +--echo # partial update of mergeable v1 defined as +--echo # partial select from mergeable derived table dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a < 25; +let $q= +update v1 set v1.a=15 where v1.a > 2; +eval explain $q; +eval $q; +select * from t1; +drop view v1; + +create view v1 as select * from t1; + +--echo # partial update of mergeable v2 defined as +--echo # full select from mergeable view v1 +create view v2 as select * from v1; +let $q= +update v2 set v2.a=17 where v2.a between 10 and 20; +eval explain $q; +eval $q; +select * from t1; +drop view v2; +--echo # full update of mergeable v2 defined as +--echo # partial select from mergeable view v1 +create view v2 as select * from v1 where v1.a > 10; +let $q= +update v2 set v2.a=23; +eval explain $q; +eval $q; +select * from t1; +drop view v2; + +update t1 set a=28 limit 1; +select * from t1; +--echo # partial update of mergeable cte1 defined as +--echo # partial select from mergeable view v1 +create view v2 as select * from v1 where v1.a < 27; +let $q= +update v2 set v2.a=19 where v2.a > 2; +eval explain $q; +eval $q; +select * from t1; +drop view v2; +drop view v1; +--echo # partial update of mergeable v1 defined as +--echo # full select from mergeable cte1 +create view v1 as with cte1 as (select * from t1) select * from cte1; +let $q= +update v1 set v1.a=11 where v1.a between 10 and 20; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # full update of mergeable v1 defined as +--echo # partial select from mergeable cte1 +create view v1 as + with cte1 as (select * from t1)select * from cte1 where cte1.a > 10; +let $q= +update v1 set v1.a=21; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +update t1 set a=29 limit 1; +select * from t1; +--echo # partial update of mergeable v1 defined as +--echo # partial select from mergeable embedded cte1 +create view v1 as + with cte1 as (select * from t1) select * from cte1 where cte1.a < 27; +let $q= +update v1 set v1.a=13 where v1.a > 2; +eval explain $q; +eval $q; +select * from t1; +drop view v1; + +delete from t1; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); + +--echo # partial update of mergeable v1 defined as +--echo # partial select from mergeable dt2 that uses mergeable dt1 +create view v1 as + (select * + from (select * from (select * from t1) dt1 where dt1.a > 1) dt2 + where dt2.a < 8); +let $q= +update v1 set v1.a=v1.a+1 where v1.a between 4 and 6; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable v1 defined as +--echo # partial select from mergeable dt1 that uses mergeable cte1 +create view v1 as + (select * + from (with cte1 as (select * from t1) + select * from cte1 where cte1.a < 8) dt1 + where dt1.a > 1); +let $q= +update v1 set v1.a=v1.a-1 where v1.a between 5 and 7; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable v2 defined as +--echo # partial select from mergeable dt1 that uses mergeable view v1 +create view v1 as select * from t1; +create view v2 as + select * + from (select * from v1 where v1.a < 8) dt1 + where dt1.a > 2; +let $q= +update v2 set v2.a=v2.a+1 where v2.a between 2 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v2; +drop view v1; +--echo # partial update of mergeable v1 defined as +--echo # partial select from mergeable cte1 that uses mergeable dt1 +create view v1 as + with cte1 as + (select * from (select * from t1) dt1 where dt1.a > 2) + select * from cte1 where cte1.a < 6; +let $q= +update v1 set v1.a=v1.a-1 where v1.a between 4 and 7; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable v1 defined as +--echo # partial select from mergeable cte2 that uses mergeable cte1 +create view v1 as + with cte2 as + (with cte1 as (select * from t1) + select * from cte1 where cte1.a > 3) + select * from cte2 where cte2.a < 10; +let $q= +update v1 set v1.a=v1.a+1 where v1.a between 4 and 7; +eval explain $q; +eval $q; +select * from t1; +drop view v1; +--echo # partial update of mergeable v2 defined as +--echo # partial select from mergeable cte1 that uses mergeable v1 +create view v1 as select a from t1; +create view v2 as + with cte1 as + (select * from v1 where v1.a > 1) + select * from cte1 where cte1.a < 7; +let $q= +update v2 set v2.a=v2.a-1 where v2.a between 2 and 4; +eval explain $q; +eval $q; +select * from t1; +drop view v2; +drop view v1; +--echo # partial update of mergeable v2 defined as +--echo # partial select from mergeable v1 that uses mergeable dt1 +create view v1 as select * from (select * from t1) dt1 where dt1.a > 2; +create view v2 as select * from v1 where v1.a < 6; +let $q= +update v2 set v2.a=v2.a+1 where v2.a between 4 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v2; +drop view v1; +--echo # partial update of mergeable v2 defined as +--echo # partial select from mergeable v1 that uses mergeable cte1 +create view v1 as + with cte1 as (select * from t1) select * from cte1 where cte1.a > 1; +create view v2 as select * from v1 where v1.a < 6; +let $q= +update v2 set v2.a=v2.a-1 where v2.a between 2 and 5; +eval explain $q; +eval $q; +select * from t1; +drop view v2; +drop view v1; +--echo # partial update of mergeable v3 defined as +--echo # partial select from mergeable v2 that uses mergeable v1 +create view v1 as select a from t1; +create view v2 as select * from v1 where v1.a > 3; +create view v3 as select * from v2 where v2.a < 8; +let $q= +update v3 set v3.a=v3.a+1 where v3.a between 5 and 10; +eval explain $q; +eval $q; +select * from t1; +drop view v3; +drop view v2; +drop view v1; + +drop table t1; diff --git a/mysql-test/main/view_update_multi.result b/mysql-test/main/view_update_multi.result new file mode 100644 index 0000000..834b0e8 --- /dev/null +++ b/mysql-test/main/view_update_multi.result @@ -0,0 +1,2685 @@ +create table t1 (a int) engine=myisam; +create table t2 (b int) engine=myisam; +create table t3 (c int, d int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable view v1 +# and mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +explain select * from v1, (select b from t2 where b < 6) as dt1 +where v1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +select * from v1, (select b from t2 where b < 6) as dt1 +where v1.a=dt1.b; +a b +5 5 +3 3 +3 3 +2 2 +2 2 +4 4 +explain update v1, (select b from t2 where b < 6) as dt1 +set a=a+1, b=b+1 where v1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update v1, (select b from t2 where b < 6) as dt1 +set a=a+1, b=b+1 where v1.a=dt1.b; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +6 +10 +4 +9 +3 +3 +5 +6 +1 +drop view v1; +# multi-table update of mergeable view v1 +# and mergeable cte1 +create view v1 as select a from t1 where a > 1; +explain with cte1 as (select * from t2 where b < 9) +select * from v1, cte1 where v1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +with cte1 as (select * from t2 where b < 9) +select * from v1, cte1 where v1.a=cte1.b; +a b +6 6 +4 4 +4 4 +3 3 +3 3 +5 5 +6 6 +explain with cte1 as (select * from t2 where b < 9) +update v1, cte1 +set v1.a=v1.a-1, cte1.b=cte1.b-1 where v1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +with cte1 as (select * from t2 where b < 9) +update v1, cte1 +set v1.a=v1.a-1, cte1.b=cte1.b-1 where v1.a=cte1.b; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +5 +1 +drop view v1; +# multi-table update of mergeable view v1 +# and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select * from t2 where b < 5; +explain select * from v1, v2 where v1.a=v2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +select * from v1, v2 where v1.a=v2.b; +a b +3 3 +3 3 +2 2 +2 2 +4 4 +explain update v1, v2 +set v1.a=v1.a+2, v2.b=v2.b+2 where v1.a=v2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update v1, v2 +set v1.a=v1.a+2, v2.b=v2.b+2 where v1.a=v2.b; +select * from t1; +a +5 +8 +7 +1 +6 +5 +5 +4 +select * from t2; +b +5 +10 +5 +9 +4 +4 +6 +5 +1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable view v1; +# and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +explain select * from v1, (select b from t2 where b < 6 group by b) as dt1 +where v1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select * from v1, (select b from t2 where b < 6 group by b) as dt1 +where v1.a=dt1.b; +a b +3 3 +4 4 +3 3 +5 5 +2 2 +explain update v1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where v1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where v1.a=dt1.b; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# multi-table update of mergeable view v1 +# and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +explain with cte1 as (select * from t2 where b < 9 group by b) +select * from v1, cte1 where v1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where b < 9 group by b) +select * from v1, cte1 where v1.a=cte1.b; +a b +4 4 +5 5 +4 4 +6 6 +3 3 +explain with cte1 as (select * from t2 where b < 9 group by b) +update v1, cte1 +set v1.a=v1.a-1 where v1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where b < 9 group by b) +update v1, cte1 +set v1.a=v1.a-1 where v1.a=cte1.b; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# multi-table update of mergeable view v1 +# and non-mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select * from t2 where b < 5 group by b; +explain select * from v1, v2 where v1.a=v2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select * from v1, v2 where v1.a=v2.b; +a b +3 3 +4 4 +3 3 +2 2 +explain update v1, v2 +set v1.a=v1.a+2 where v1.a=v2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v1, v2 +set v1.a=v1.a+2 where v1.a=v2.b; +select * from t1; +a +5 +8 +7 +1 +6 +5 +5 +4 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +# update of mergeable view v1 specified as join of +# mergeable derived table dt1 and mergeable derived table dt2 +create view v1 as +select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6) as dt2 +where dt1.a=dt2.b; +explain update v1 +set v1.a=v1.a+1, v1.b=v1.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update v1 +set v1.a=v1.a+1, v1.b=v1.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +6 +10 +4 +9 +3 +3 +5 +6 +1 +drop view v1; +# update of mergeable view v1 specified as join of +# mergeable derived table dt1 and mergeable cte1 +create view v1 as +with cte1 as (select b from t2 where b < 9) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b; +explain update v1 +set v1.a=v1.a-1, v1.b=v1.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update v1 +set v1.a=v1.a-1, v1.b=v1.b-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +5 +1 +drop view v1; +# update of mergeable view v2 specified as join of +# mergeable derived table dt1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +create view v2 as +select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b; +explain update v2 +set v2.a=v2.a+1, v2.b=v2.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update v2 +set v2.a=v2.a+1, v2.b=v2.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +4 +9 +3 +3 +5 +5 +1 +drop view v2; +drop view v1; +# update of mergeable view v1 specified as join of +# mergeable cte1 and mergeable cte2 +create view v1 as +with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6) +select * from cte1, cte2 where cte1.a=cte2.b; +explain update v1 +set v1.a=v1.a-1, v1.b=v1.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update v1 +set v1.a=v1.a-1, v1.b=v1.b-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +4 +10 +3 +9 +2 +2 +4 +4 +1 +drop view v1; +# update of mergeable view v2 specified as join of +# mergeable cte1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +create view v2 as +with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b; +explain update v2 +set v2.a=v2.a+1, v2.b=v2.b+1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update v2 +set v2.a=v2.a+1, v2.b=v2.b+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +4 +9 +3 +3 +5 +5 +1 +drop view v2; +drop view v1; +# update of mergeable view v3 specified as join of +# mergeable view v1 and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5; +create view v3 as select * from v1, v2 where v1.a=v2.b; +explain update v3 +set v3.a=v3.a-1, v3.b=v3.b-1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +update v3 +set v3.a=v3.a-1, v3.b=v3.b-1; +select * from t1; +a +3 +8 +7 +1 +5 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +5 +5 +1 +drop view v3; +drop view v1; +drop view v2; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +# multi-table update of mergeable view v1; +# and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +explain select * from v1, (select b from t2 where b < 6 group by b) as dt1 +where v1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select * from v1, (select b from t2 where b < 6 group by b) as dt1 +where v1.a=dt1.b; +a b +3 3 +4 4 +3 3 +5 5 +2 2 +explain update v1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where v1.a=dt1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where v1.a=dt1.b; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# multi-table update of mergeable view v1 +# and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +explain with cte1 as (select * from t2 where b < 9 group by b) +select * from v1, cte1 where v1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where b < 9 group by b) +select * from v1, cte1 where v1.a=cte1.b; +a b +4 4 +5 5 +4 4 +6 6 +3 3 +explain with cte1 as (select * from t2 where b < 9 group by b) +update v1, cte1 +set v1.a=v1.a-1 where v1.a=cte1.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where b < 9 group by b) +update v1, cte1 +set v1.a=v1.a-1 where v1.a=cte1.b; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# multi-table update of mergeable view v1 +# and non-mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select * from t2 where b < 5 group by b; +explain select * from v1, v2 where v1.a=v2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select * from v1, v2 where v1.a=v2.b; +a b +3 3 +4 4 +3 3 +2 2 +explain update v1, v2 +set v1.a=v1.a+2 where v1.a=v2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v1, v2 +set v1.a=v1.a+2 where v1.a=v2.b; +select * from t1; +a +5 +8 +7 +1 +6 +5 +5 +4 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); +# update of mergeable view v1 specified as join of +# mergeable derived table dt1 and non-mergeable derived table dt2 +create view v1 as +select * from +(select a from t1 where a > 1) as dt1, +(select b from t2 where b < 6 group by b) as dt2 +where dt1.a=dt2.b; +explain update v1 +set v1.a=v1.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v1 +set v1.a=v1.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +6 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable view v1 specified as join of +# mergeable derived table dt1 and non-mergeable cte1 +create view v1 as +with cte1 as (select b from t2 where b < 9 group by b) +select * from +(select a from t1 where a > 1) as dt1, cte1 +where dt1.a=cte1.b; +explain update v1 +set v1.a=v1.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v1 +set v1.a=v1.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable view v2 specified as join of +# mergeable derived table dt1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 5 group by b; +create view v2 as +select * from +(select a from t1 where a > 1) as dt1, v1 +where dt1.a=v1.b; +explain update v2 +set v2.a=v2.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v2 +set v2.a=v2.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v2; +drop view v1; +# update of mergeable view v1 specified as join of +# mergeable cte1 and non-mergeable derived table dt1 +create view v1 as +with cte1 as (select a from t1 where a > 1) +select * from +cte1, (select b from t2 where b < 7 group by b) dt1 +where cte1.a=dt1.b; +explain update v1 +set v1.a=v1.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v1 +set v1.a=v1.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable view v1 specified as join of +# mergeable cte1 and non-mergeable cte2 +create view v1 as +with cte1 as (select a from t1 where a > 1), +cte2 as (select b from t2 where b < 6 group by b) +select * from cte1, cte2 where cte1.a=cte2.b; +explain update v1 +set v1.a=v1.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v1 +set v1.a=v1.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +# update of mergeable view v2 specified as join of +# mergeable cte1 and non mergeable view v1 +create view v1 as select b from t2 where b < 7 group by b; +create view v2 as +with cte1 as (select a from t1 where a > 1) +select * from cte1, v1 where cte1.a=v1.b; +explain update v2 +set v2.a=v2.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v2 +set v2.a=v2.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v2; +drop view v1; +# update of mergeable view v2 specified as join of +# mergeable view v1 and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +create view v2 as +select * from +v1, (select b from t2 where b < 6 group by b) dt1 +where v1.a=dt1.b; +explain update v2 +set v2.a=v2.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v2 +set v2.a=v2.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +drop view v2; +# update of mergeable view v2 specified as join of +# mergeable view v1 and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +create view v2 as +with cte1 as (select b from t2 where b < 7 group by b) +select * from v1, cte1 where v1.a=cte1.b; +explain update v2 +set v2.a=v2.a-1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v2 +set v2.a=v2.a-1; +select * from t1; +a +3 +8 +7 +1 +4 +3 +4 +2 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v1; +drop view v2; +# update of mergeable view v3 specified as join of +# mergeable view v1 and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5 group by b; +create view v3 as select * from v1, v2 where v1.a=v2.b; +explain update v3 +set v3.a=v3.a+1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update v3 +set v3.a=v3.a+1; +select * from t1; +a +4 +8 +7 +1 +5 +4 +5 +3 +select * from t2; +b +5 +10 +3 +9 +2 +2 +4 +6 +1 +drop view v3; +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable view v1, +# mergeable derived table dt1 and mergeable derived table dt2 +create view v1 as select * from t1 where t1.a > 2; +explain select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 5) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where v1.a=dt1.b and dt1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 5) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where v1.a=dt1.b and dt1.b=dt2.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain update +v1, +(select * from t2 where t2.b < 5) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set v1.a=v1.a+1, dt1.b=dt1.b+1, dt2.c=dt2.c-dt2.d1 +where v1.a=dt1.b and dt1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +update +v1, +(select * from t2 where t2.b < 5) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set v1.a=v1.a+1, dt1.b=dt1.b+1, dt2.c=dt2.c-dt2.d1 +where v1.a=dt1.b and dt1.b=dt2.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +# update of join of mergeable view v1, +# mergeable derived table dt1 and mergeable cte1 +create view v1 as select * from t1 where t1.a > 5; +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 10) dt1, +cte1 +where v1.a=dt1.b and dt1.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 10) dt1, +cte1 +where v1.a=dt1.b and dt1.b=cte1.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +(select * from t2 where t2.b < 10) dt1, +cte1 +set v1.a=v1.a-1, dt1.b=dt1.b-1, cte1.c=cte1.c+cte1.d1 +where v1.a=dt1.b and dt1.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +(select * from t2 where t2.b < 10) dt1, +cte1 +set v1.a=v1.a-1, dt1.b=dt1.b-1, cte1.c=cte1.c+cte1.d1 +where v1.a=dt1.b and dt1.b=cte1.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +# update of join of mergeable view v1, +# mergeable derived table dt1 and mergeable view v2 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 5) dt1, +v2 +where v1.a=dt1.b and dt1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 5) dt1, +v2 +where v1.a=dt1.b and dt1.b=v2.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain update +v1, +(select * from t2 where t2.b < 5) dt1, +v2 +set v1.a=v1.a+1, dt1.b=dt1.b+1, v2.c=v2.c+v2.d1 +where v1.a=dt1.b and dt1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +update +v1, +(select * from t2 where t2.b < 5) dt1, +v2 +set v1.a=v1.a+1, dt1.b=dt1.b+1, v2.c=v2.c+v2.d1 +where v1.a=dt1.b and dt1.b=v2.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable v1, +# mergeable cte1 and mergeable derived table dt1 +create view v1 as select * from t1 where t1.a > 2; +explain with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +v1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=cte1.b and cte1.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +v1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=cte1.b and cte1.b=dt1.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with cte1 as (select * from t2 where t2.b < 5) +update +v1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, cte1.b=cte1.b+1, dt1.c=dt1.c-dt1.d1 +where v1.a=cte1.b and cte1.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select * from t2 where t2.b < 5) +update +v1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, cte1.b=cte1.b+1, dt1.c=dt1.c-dt1.d1 +where v1.a=cte1.b and cte1.b=dt1.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +# update of join of mergeable view v1, +# mergeable cte1 and mergeable cte2 +create view v1 as select * from t1 where t1.a > 5; +explain with +cte1 as (select * from t2 where t2.b < 10), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +cte1, +cte2 +where v1.a=cte1.b and cte1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with +cte1 as (select * from t2 where t2.b < 10), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +cte1, +cte2 +where v1.a=cte1.b and cte1.b=cte2.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t2 where t2.b < 10), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +cte1, +cte2 +set v1.a=v1.a-1, cte1.b=cte1.b-1, cte2.c=cte2.c+cte2.d1 +where v1.a=cte1.b and cte1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with +cte1 as (select * from t2 where t2.b < 10), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +cte1, +cte2 +set v1.a=v1.a-1, cte1.b=cte1.b-1, cte2.c=cte2.c+cte2.d1 +where v1.a=cte1.b and cte1.b=cte2.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +# update of join of mergeable view v1, +# mergeable cte1 and mergeable view v2 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +v1, +cte1, +v2 +where v1.a=cte1.b and cte1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from +v1, +cte1, +v2 +where v1.a=cte1.b and cte1.b=v2.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain with cte1 as (select * from t2 where t2.b < 5) +update +v1, +cte1, +v2 +set v1.a=v1.a+1, cte1.b=cte1.b+1, v2.c=v2.c+v2.d1 +where v1.a=cte1.b and cte1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select * from t2 where t2.b < 5) +update +v1, +cte1, +v2 +set v1.a=v1.a+1, cte1.b=cte1.b+1, v2.c=v2.c+v2.d1 +where v1.a=cte1.b and cte1.b=v2.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable view v1, +# mergeable view v2 and mergeable derived table dt1 +create view v1 as select * from t1 where t1.a > 2; +create view v2 as (select * from t2 where t2.b < 5); +explain select a,b,c,d1 from +v1, +v2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=v2.b and v2.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +select a,b,c,d1 from +v1, +v2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=v2.b and v2.b=dt1.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain update +v1, +v2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, v2.b=v2.b+1, dt1.c=dt1.c-dt1.d1 +where v1.a=v2.b and v2.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +update +v1, +v2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, v2.b=v2.b+1, dt1.c=dt1.c-dt1.d1 +where v1.a=v2.b and v2.b=dt1.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +4 +9 +2 +2 +5 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +drop view v2; +# update of join of mergeable view v1, +# mergeable view v2 and mergeable cte1 +create view v1 as select * from t1 where t1.a > 5; +create view v2 as select * from t2 where t2.b < 10; +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +v2, +cte1 +where v1.a=v2.b and v2.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +v2, +cte1 +where v1.a=v2.b and v2.b=cte1.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +v2, +cte1 +set v1.a=v1.a-1, v2.b=v2.b-1, cte1.c=cte1.c+cte1.d1 +where v1.a=v2.b and v2.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +v2, +cte1 +set v1.a=v1.a-1, v2.b=v2.b-1, cte1.c=cte1.c+cte1.d1 +where v1.a=v2.b and v2.b=cte1.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +6 +4 +9 +2 +2 +5 +5 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +drop view v2; +# update of join of mergeable view v1, +# mergeable view v2 and mergeable view v3 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select * from t2 where t2.b < 5; +create view v3 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +v1, +v2, +v3 +where v1.a=v2.b and v2.b=v3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY t2 ALL NULL NULL NULL NULL 9 Using where; Using join buffer (flat, BNL join) +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (incremental, BNL join) +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +v1, +v2, +v3 +where v1.a=v2.b and v2.b=v3.c; +a b c d1 +2 2 2 2 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +2 2 2 2 +explain update +v1, +v2, +v3 +set v1.a=v1.a+1, v2.b=v2.b+1, v3.c=v3.c+v3.d1 +where v1.a=v2.b and v2.b=v3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where +1 SIMPLE t2 ALL NULL NULL NULL NULL 9 Using where +1 SIMPLE t3 ALL NULL NULL NULL NULL 10 Using where +update +v1, +v2, +v3 +set v1.a=v1.a+1, v2.b=v2.b+1, v3.c=v3.c+v3.d1 +where v1.a=v2.b and v2.b=v3.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +6 +4 +9 +3 +3 +5 +5 +2 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +drop view v3; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable view v1, +# non-mergeable derived table dt1 and mergeable derived table dt2 +create view v1 as select * from t1 where t1.a > 2; +explain select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 5 group by b) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where v1.a=dt1.b and dt1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 5 group by b) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where v1.a=dt1.b and dt1.b=dt2.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain update +v1, +(select * from t2 where t2.b < 5 group by b) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set v1.a=v1.a+1, dt2.c=dt2.c-dt2.d1 +where v1.a=dt1.b and dt1.b=dt2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +v1, +(select * from t2 where t2.b < 5 group by b) dt1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set v1.a=v1.a+1, dt2.c=dt2.c-dt2.d1 +where v1.a=dt1.b and dt1.b=dt2.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +# update of join of mergeable view v1, +# non-mergeable derived table dt1 and mergeable cte1 +create view v1 as select * from t1 where t1.a > 5; +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 10 group by b) dt1, +cte1 +where v1.a=dt1.b and dt1.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 10 group by b) dt1, +cte1 +where v1.a=dt1.b and dt1.b=cte1.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +(select * from t2 where t2.b < 10 group by b) dt1, +cte1 +set v1.a=v1.a-1, cte1.c=cte1.c+cte1.d1 +where v1.a=dt1.b and dt1.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +(select * from t2 where t2.b < 10 group by b) dt1, +cte1 +set v1.a=v1.a-1, cte1.c=cte1.c+cte1.d1 +where v1.a=dt1.b and dt1.b=cte1.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +# update of join of mergeable view v1, +# non-mergeable derived table dt1 and mergeable view v2 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 5 group by b) dt1, +v2 +where v1.a=dt1.b and dt1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select a,b,c,d1 from +v1, +(select * from t2 where t2.b < 5 group by b) dt1, +v2 +where v1.a=dt1.b and dt1.b=v2.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain update +v1, +(select * from t2 where t2.b < 5 group by b) dt1, +v2 +set v1.a=v1.a+1, v2.c=v2.c+v2.d1 +where v1.a=dt1.b and dt1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +v1, +(select * from t2 where t2.b < 5 group by b) dt1, +v2 +set v1.a=v1.a+1, v2.c=v2.c+v2.d1 +where v1.a=dt1.b and dt1.b=v2.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable v1, +# non-mergeable cte1 and mergeable derived table dt1 +create view v1 as select * from t1 where t1.a > 2; +explain with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +v1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=cte1.b and cte1.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +v1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=cte1.b and cte1.b=dt1.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain with cte1 as (select * from t2 where t2.b < 5 group by b) +update +v1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, dt1.c=dt1.c-dt1.d1 +where v1.a=cte1.b and cte1.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where t2.b < 5 group by b) +update +v1, +cte1, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, dt1.c=dt1.c-dt1.d1 +where v1.a=cte1.b and cte1.b=dt1.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +# update of join of mergeable view v1, +# non-mergeable cte1 and mergeable cte2 +create view v1 as select * from t1 where t1.a > 5; +explain with +cte1 as (select * from t2 where t2.b < 10 group by b), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +cte1, +cte2 +where v1.a=cte1.b and cte1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t2 where t2.b < 10 group by b), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +cte1, +cte2 +where v1.a=cte1.b and cte1.b=cte2.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with +cte1 as (select * from t2 where t2.b < 10 group by b), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +cte1, +cte2 +set v1.a=v1.a-1, cte2.c=cte2.c+cte2.d1 +where v1.a=cte1.b and cte1.b=cte2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with +cte1 as (select * from t2 where t2.b < 10 group by b), +cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +cte1, +cte2 +set v1.a=v1.a-1, cte2.c=cte2.c+cte2.d1 +where v1.a=cte1.b and cte1.b=cte2.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +# update of join of mergeable view v1, +# non-mergeable cte1 and mergeable view v2 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +v1, +cte1, +v2 +where v1.a=cte1.b and cte1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from +v1, +cte1, +v2 +where v1.a=cte1.b and cte1.b=v2.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain with cte1 as (select * from t2 where t2.b < 5 group by b) +update +v1, +cte1, +v2 +set v1.a=v1.a+1, v2.c=v2.c+v2.d1 +where v1.a=cte1.b and cte1.b=v2.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +2 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t2 where t2.b < 5 group by b) +update +v1, +cte1, +v2 +set v1.a=v1.a+1, v2.c=v2.c+v2.d1 +where v1.a=cte1.b and cte1.b=v2.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +a +3 +6 +7 +1 +4 +3 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +3 1 +2 3 +7 1 +1 1 +4 1 +5 2 +6 1 +# update of join of mergeable view v1, +# non-mergeable view v2 and mergeable derived table dt1 +create view v1 as select * from t1 where t1.a > 2; +create view v2 as (select * from t2 where t2.b < 5 group by b); +explain select a,b,c,d1 from +v1, +v2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=v2.b and v2.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +select a,b,c,d1 from +v1, +v2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=v2.b and v2.b=dt1.c; +a b c d1 +3 3 3 2 +3 3 3 2 +4 4 4 2 +explain update +v1, +v2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, dt1.c=dt1.c-dt1.d1 +where v1.a=v2.b and v2.b=dt1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +v1, +v2, +(select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, dt1.c=dt1.c-dt1.d1 +where v1.a=v2.b and v2.b=dt1.c; +select * from t1; +a +4 +6 +7 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +7 1 +1 1 +2 1 +5 2 +6 1 +drop view v1; +drop view v2; +# update of join of mergeable view v1, +# non-mergeable view v2 and mergeable cte1 +create view v1 as select * from t1 where t1.a > 5; +create view v2 as select * from t2 where t2.b < 10 group by b; +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +v2, +cte1 +where v1.a=v2.b and v2.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from +v1, +v2, +cte1 +where v1.a=v2.b and v2.b=cte1.c; +a b c d1 +7 7 7 2 +6 6 6 2 +explain with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +v2, +cte1 +set v1.a=v1.a-1, cte1.c=cte1.c+cte1.d1 +where v1.a=v2.b and v2.b=cte1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update +v1, +v2, +cte1 +set v1.a=v1.a-1, cte1.c=cte1.c+cte1.d1 +where v1.a=v2.b and v2.b=cte1.c; +select * from t1; +a +4 +5 +6 +1 +5 +4 +5 +2 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +2 1 +1 1 +2 3 +9 1 +1 1 +2 1 +5 2 +8 1 +drop view v1; +drop view v2; +# update of join of mergeable view v1, +# non-mergeable view v2 and mergeable view v3 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select * from t2 where t2.b < 5 group by b; +create view v3 as select c, d+1 as d1 from t3 where t3.d in (1,2); +explain with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +v1, +v2, +v3 +where v1.a=v2.b and v2.b=v3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived4> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +4 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from +v1, +v2, +v3 +where v1.a=v2.b and v2.b=v3.c; +a b c d1 +2 2 2 2 +1 1 1 2 +1 1 1 2 +2 2 2 2 +explain update +v1, +v2, +v3 +set v1.a=v1.a+1, v3.c=v3.c+v3.d1 +where v1.a=v2.b and v2.b=v3.c; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +1 PRIMARY <derived3> ref key0 key0 5 test.t1.a 2 +1 PRIMARY t3 ALL NULL NULL NULL NULL 10 Using where +3 DERIVED t2 ALL NULL NULL NULL NULL 9 Using where; Using temporary; Using filesort +update +v1, +v2, +v3 +set v1.a=v1.a+1, v3.c=v3.c+v3.d1 +where v1.a=v2.b and v2.b=v3.c; +select * from t1; +a +4 +5 +6 +2 +5 +4 +5 +3 +select * from t2; +b +5 +7 +3 +9 +2 +2 +4 +6 +1 +select * from t3; +c d +4 2 +9 3 +4 1 +3 1 +2 3 +9 1 +3 1 +4 1 +5 2 +8 1 +drop view v1; +drop view v2; +drop view v3; +drop table t1,t2,t3; diff --git a/mysql-test/main/view_update_multi.test b/mysql-test/main/view_update_multi.test new file mode 100644 index 0000000..70c97ac --- /dev/null +++ b/mysql-test/main/view_update_multi.test @@ -0,0 +1,970 @@ +create table t1 (a int) engine=myisam; +create table t2 (b int) engine=myisam; +create table t3 (c int, d int) engine=myisam; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +select * from t1; +select * from t2; +--echo # multi-table update of mergeable view v1 +--echo # and mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +let $qs= +select * from v1, (select b from t2 where b < 6) as dt1 +where v1.a=dt1.b; +eval explain $qs; +eval $qs; +let $qu= +update v1, (select b from t2 where b < 6) as dt1 +set a=a+1, b=b+1 where v1.a=dt1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # multi-table update of mergeable view v1 +--echo # and mergeable cte1 +create view v1 as select a from t1 where a > 1; +let $qs= +with cte1 as (select * from t2 where b < 9) +select * from v1, cte1 where v1.a=cte1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where b < 9) +update v1, cte1 +set v1.a=v1.a-1, cte1.b=cte1.b-1 where v1.a=cte1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # multi-table update of mergeable view v1 +--echo # and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select * from t2 where b < 5; +let $qs= +select * from v1, v2 where v1.a=v2.b; +eval explain $qs; +eval $qs; +let $qu= +update v1, v2 +set v1.a=v1.a+2, v2.b=v2.b+2 where v1.a=v2.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +select * from t1; +select * from t2; +--echo # multi-table update of mergeable view v1; +--echo # and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +let $qs= +select * from v1, (select b from t2 where b < 6 group by b) as dt1 +where v1.a=dt1.b; +eval explain $qs; +eval $qs; +let $qu= +update v1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where v1.a=dt1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # multi-table update of mergeable view v1 +--echo # and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +let $qs= +with cte1 as (select * from t2 where b < 9 group by b) +select * from v1, cte1 where v1.a=cte1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where b < 9 group by b) +update v1, cte1 +set v1.a=v1.a-1 where v1.a=cte1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # multi-table update of mergeable view v1 +--echo # and non-mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select * from t2 where b < 5 group by b; +let $qs= +select * from v1, v2 where v1.a=v2.b; +eval explain $qs; +eval $qs; +let $qu= +update v1, v2 +set v1.a=v1.a+2 where v1.a=v2.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +--echo # update of mergeable view v1 specified as join of +--echo # mergeable derived table dt1 and mergeable derived table dt2 +create view v1 as + select * from + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6) as dt2 + where dt1.a=dt2.b; +let $qu= +update v1 +set v1.a=v1.a+1, v1.b=v1.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable view v1 specified as join of +--echo # mergeable derived table dt1 and mergeable cte1 +create view v1 as + with cte1 as (select b from t2 where b < 9) + select * from + (select a from t1 where a > 1) as dt1, cte1 + where dt1.a=cte1.b; +let $qu= +update v1 +set v1.a=v1.a-1, v1.b=v1.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable view v2 specified as join of +--echo # mergeable derived table dt1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +create view v2 as + select * from + (select a from t1 where a > 1) as dt1, v1 + where dt1.a=v1.b; +let $qu= +update v2 +set v2.a=v2.a+1, v2.b=v2.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v2; +drop view v1; +--echo # update of mergeable view v1 specified as join of +--echo # mergeable cte1 and mergeable cte2 +create view v1 as + with cte1 as (select a from t1 where a > 1), + cte2 as (select b from t2 where b < 6) + select * from cte1, cte2 where cte1.a=cte2.b; +let $qu= +update v1 +set v1.a=v1.a-1, v1.b=v1.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable view v2 specified as join of +--echo # mergeable cte1 and mergeable view v1 +create view v1 as select b from t2 where b < 5; +create view v2 as + with cte1 as (select a from t1 where a > 1) + select * from cte1, v1 where cte1.a=v1.b; +let $qu= +update v2 +set v2.a=v2.a+1, v2.b=v2.b+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v2; +drop view v1; +--echo # update of mergeable view v3 specified as join of +--echo # mergeable view v1 and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5; +create view v3 as select * from v1, v2 where v1.a=v2.b; +let $qu= +update v3 +set v3.a=v3.a-1, v3.b=v3.b-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v3; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +select * from t1; +select * from t2; +--echo # multi-table update of mergeable view v1; +--echo # and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +let $qs= +select * from v1, (select b from t2 where b < 6 group by b) as dt1 +where v1.a=dt1.b; +eval explain $qs; +eval $qs; +let $qu= +update v1, (select b from t2 where b < 6 group by b) as dt1 +set a=a+1 where v1.a=dt1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # multi-table update of mergeable view v1 +--echo # and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +let $qs= +with cte1 as (select * from t2 where b < 9 group by b) +select * from v1, cte1 where v1.a=cte1.b; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where b < 9 group by b) +update v1, cte1 +set v1.a=v1.a-1 where v1.a=cte1.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # multi-table update of mergeable view v1 +--echo # and non-mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select * from t2 where b < 5 group by b; +let $qs= +select * from v1, v2 where v1.a=v2.b; +eval explain $qs; +eval $qs; +let $qu= +update v1, v2 +set v1.a=v1.a+2 where v1.a=v2.b; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +insert into t1 values (3), (8), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (10), (3), (9), (2), (2), (4), (6), (1); + +--echo # update of mergeable view v1 specified as join of +--echo # mergeable derived table dt1 and non-mergeable derived table dt2 +create view v1 as + select * from + (select a from t1 where a > 1) as dt1, + (select b from t2 where b < 6 group by b) as dt2 + where dt1.a=dt2.b; +let $qu= +update v1 +set v1.a=v1.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable view v1 specified as join of +--echo # mergeable derived table dt1 and non-mergeable cte1 +create view v1 as + with cte1 as (select b from t2 where b < 9 group by b) + select * from + (select a from t1 where a > 1) as dt1, cte1 + where dt1.a=cte1.b; +let $qu= +update v1 +set v1.a=v1.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable view v2 specified as join of +--echo # mergeable derived table dt1 and non-mergeable view v1 +create view v1 as select b from t2 where b < 5 group by b; +create view v2 as + select * from + (select a from t1 where a > 1) as dt1, v1 + where dt1.a=v1.b; +let $qu= +update v2 +set v2.a=v2.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v2; +drop view v1; +--echo # update of mergeable view v1 specified as join of +--echo # mergeable cte1 and non-mergeable derived table dt1 +create view v1 as + with cte1 as (select a from t1 where a > 1) + select * from + cte1, (select b from t2 where b < 7 group by b) dt1 + where cte1.a=dt1.b; +let $qu= +update v1 +set v1.a=v1.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable view v1 specified as join of +--echo # mergeable cte1 and non-mergeable cte2 +create view v1 as + with cte1 as (select a from t1 where a > 1), + cte2 as (select b from t2 where b < 6 group by b) + select * from cte1, cte2 where cte1.a=cte2.b; +let $qu= +update v1 +set v1.a=v1.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +--echo # update of mergeable view v2 specified as join of +--echo # mergeable cte1 and non mergeable view v1 +create view v1 as select b from t2 where b < 7 group by b; +create view v2 as + with cte1 as (select a from t1 where a > 1) + select * from cte1, v1 where cte1.a=v1.b; +let $qu= +update v2 +set v2.a=v2.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v2; +drop view v1; +--echo # update of mergeable view v2 specified as join of +--echo # mergeable view v1 and non-mergeable derived table dt1 +create view v1 as select a from t1 where a > 1; +create view v2 as + select * from + v1, (select b from t2 where b < 6 group by b) dt1 + where v1.a=dt1.b; +let $qu= +update v2 +set v2.a=v2.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; +--echo # update of mergeable view v2 specified as join of +--echo # mergeable view v1 and non-mergeable cte1 +create view v1 as select a from t1 where a > 1; +create view v2 as + with cte1 as (select b from t2 where b < 7 group by b) + select * from v1, cte1 where v1.a=cte1.b; +let $qu= +update v2 +set v2.a=v2.a-1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v1; +drop view v2; +--echo # update of mergeable view v3 specified as join of +--echo # mergeable view v1 and mergeable view v2 +create view v1 as select a from t1 where a > 1; +create view v2 as select b from t2 where b < 5 group by b; +create view v3 as select * from v1, v2 where v1.a=v2.b; +let $qu= +update v3 +set v3.a=v3.a+1; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +drop view v3; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable view v1, +--echo # mergeable derived table dt1 and mergeable derived table dt2 +create view v1 as select * from t1 where t1.a > 2; +let $qs= +select a,b,c,d1 from + v1, + (select * from t2 where t2.b < 5) dt1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where v1.a=dt1.b and dt1.b=dt2.c; +eval explain $qs; +eval $qs; +let $qu= +update + v1, + (select * from t2 where t2.b < 5) dt1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set v1.a=v1.a+1, dt1.b=dt1.b+1, dt2.c=dt2.c-dt2.d1 +where v1.a=dt1.b and dt1.b=dt2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable view v1, +--echo # mergeable derived table dt1 and mergeable cte1 +create view v1 as select * from t1 where t1.a > 5; +let $qs= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + v1, + (select * from t2 where t2.b < 10) dt1, + cte1 +where v1.a=dt1.b and dt1.b=cte1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + v1, + (select * from t2 where t2.b < 10) dt1, + cte1 +set v1.a=v1.a-1, dt1.b=dt1.b-1, cte1.c=cte1.c+cte1.d1 +where v1.a=dt1.b and dt1.b=cte1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable view v1, +--echo # mergeable derived table dt1 and mergeable view v2 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +select a,b,c,d1 from + v1, + (select * from t2 where t2.b < 5) dt1, + v2 +where v1.a=dt1.b and dt1.b=v2.c; +eval explain $qs; +eval $qs; +let $qu= +update + v1, + (select * from t2 where t2.b < 5) dt1, + v2 +set v1.a=v1.a+1, dt1.b=dt1.b+1, v2.c=v2.c+v2.d1 +where v1.a=dt1.b and dt1.b=v2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable v1, +--echo # mergeable cte1 and mergeable derived table dt1 +create view v1 as select * from t1 where t1.a > 2; +let $qs= +with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from + v1, + cte1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=cte1.b and cte1.b=dt1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where t2.b < 5) +update + v1, + cte1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, cte1.b=cte1.b+1, dt1.c=dt1.c-dt1.d1 +where v1.a=cte1.b and cte1.b=dt1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable view v1, +--echo # mergeable cte1 and mergeable cte2 +create view v1 as select * from t1 where t1.a > 5; +let $qs= +with + cte1 as (select * from t2 where t2.b < 10), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + v1, + cte1, + cte2 +where v1.a=cte1.b and cte1.b=cte2.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t2 where t2.b < 10), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + v1, + cte1, + cte2 +set v1.a=v1.a-1, cte1.b=cte1.b-1, cte2.c=cte2.c+cte2.d1 +where v1.a=cte1.b and cte1.b=cte2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable view v1, +--echo # mergeable cte1 and mergeable view v2 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t2 where t2.b < 5) +select a,b,c,d1 from + v1, + cte1, + v2 +where v1.a=cte1.b and cte1.b=v2.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where t2.b < 5) +update + v1, + cte1, + v2 +set v1.a=v1.a+1, cte1.b=cte1.b+1, v2.c=v2.c+v2.d1 +where v1.a=cte1.b and cte1.b=v2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable view v1, +--echo # mergeable view v2 and mergeable derived table dt1 +create view v1 as select * from t1 where t1.a > 2; +create view v2 as (select * from t2 where t2.b < 5); +let $qs= +select a,b,c,d1 from + v1, + v2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=v2.b and v2.b=dt1.c; +eval explain $qs; +eval $qs; +let $qu= +update + v1, + v2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, v2.b=v2.b+1, dt1.c=dt1.c-dt1.d1 +where v1.a=v2.b and v2.b=dt1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; +--echo # update of join of mergeable view v1, +--echo # mergeable view v2 and mergeable cte1 +create view v1 as select * from t1 where t1.a > 5; +create view v2 as select * from t2 where t2.b < 10; +let $qs= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + v1, + v2, + cte1 +where v1.a=v2.b and v2.b=cte1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + v1, + v2, + cte1 +set v1.a=v1.a-1, v2.b=v2.b-1, cte1.c=cte1.c+cte1.d1 +where v1.a=v2.b and v2.b=cte1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; +--echo # update of join of mergeable view v1, +--echo # mergeable view v2 and mergeable view v3 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select * from t2 where t2.b < 5; +create view v3 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from + v1, + v2, + v3 +where v1.a=v2.b and v2.b=v3.c; +eval explain $qs; +eval $qs; +let $qu= +update + v1, + v2, + v3 +set v1.a=v1.a+1, v2.b=v2.b+1, v3.c=v3.c+v3.d1 +where v1.a=v2.b and v2.b=v3.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; +drop view v3; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; +--echo # update of join of mergeable view v1, +--echo # non-mergeable derived table dt1 and mergeable derived table dt2 +create view v1 as select * from t1 where t1.a > 2; +let $qs= +select a,b,c,d1 from + v1, + (select * from t2 where t2.b < 5 group by b) dt1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +where v1.a=dt1.b and dt1.b=dt2.c; +eval explain $qs; +eval $qs; +let $qu= +update + v1, + (select * from t2 where t2.b < 5 group by b) dt1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt2 +set v1.a=v1.a+1, dt2.c=dt2.c-dt2.d1 +where v1.a=dt1.b and dt1.b=dt2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable view v1, +--echo # non-mergeable derived table dt1 and mergeable cte1 +create view v1 as select * from t1 where t1.a > 5; +let $qs= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + v1, + (select * from t2 where t2.b < 10 group by b) dt1, + cte1 +where v1.a=dt1.b and dt1.b=cte1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + v1, + (select * from t2 where t2.b < 10 group by b) dt1, + cte1 +set v1.a=v1.a-1, cte1.c=cte1.c+cte1.d1 +where v1.a=dt1.b and dt1.b=cte1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable view v1, +--echo # non-mergeable derived table dt1 and mergeable view v2 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +select a,b,c,d1 from + v1, + (select * from t2 where t2.b < 5 group by b) dt1, + v2 +where v1.a=dt1.b and dt1.b=v2.c; +eval explain $qs; +eval $qs; +let $qu= +update + v1, + (select * from t2 where t2.b < 5 group by b) dt1, + v2 +set v1.a=v1.a+1, v2.c=v2.c+v2.d1 +where v1.a=dt1.b and dt1.b=v2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable v1, +--echo # non-mergeable cte1 and mergeable derived table dt1 +create view v1 as select * from t1 where t1.a > 2; +let $qs= +with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from + v1, + cte1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=cte1.b and cte1.b=dt1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where t2.b < 5 group by b) +update + v1, + cte1, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, dt1.c=dt1.c-dt1.d1 +where v1.a=cte1.b and cte1.b=dt1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable view v1, +--echo # non-mergeable cte1 and mergeable cte2 +create view v1 as select * from t1 where t1.a > 5; +let $qs= +with + cte1 as (select * from t2 where t2.b < 10 group by b), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + v1, + cte1, + cte2 +where v1.a=cte1.b and cte1.b=cte2.c; +eval explain $qs; +eval $qs; +let $qu= +with + cte1 as (select * from t2 where t2.b < 10 group by b), + cte2 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + v1, + cte1, + cte2 +set v1.a=v1.a-1, cte2.c=cte2.c+cte2.d1 +where v1.a=cte1.b and cte1.b=cte2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +--echo # update of join of mergeable view v1, +--echo # non-mergeable cte1 and mergeable view v2 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t2 where t2.b < 5 group by b) +select a,b,c,d1 from + v1, + cte1, + v2 +where v1.a=cte1.b and cte1.b=v2.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select * from t2 where t2.b < 5 group by b) +update + v1, + cte1, + v2 +set v1.a=v1.a+1, v2.c=v2.c+v2.d1 +where v1.a=cte1.b and cte1.b=v2.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; + +delete from t1; +delete from t2; +delete from t3; +insert into t1 values (3), (6), (7), (1), (4), (3), (5), (2); +insert into t2 values (5), (7), (3), (9), (2), (2), (4), (6), (1); +insert into t3 values +(4,2), (9,3), (2,1), (3,1), (2,3), (7,1), (1,1), (4,1), (5,2), (6,1); +select * from t1; +select * from t2; +select * from t3; + +--echo # update of join of mergeable view v1, +--echo # non-mergeable view v2 and mergeable derived table dt1 +create view v1 as select * from t1 where t1.a > 2; +create view v2 as (select * from t2 where t2.b < 5 group by b); +let $qs= +select a,b,c,d1 from + v1, + v2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +where v1.a=v2.b and v2.b=dt1.c; +eval explain $qs; +eval $qs; +let $qu= +update + v1, + v2, + (select c, d+1 as d1 from t3 where t3.d = 1) dt1 +set v1.a=v1.a+1, dt1.c=dt1.c-dt1.d1 +where v1.a=v2.b and v2.b=dt1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; +--echo # update of join of mergeable view v1, +--echo # non-mergeable view v2 and mergeable cte1 +create view v1 as select * from t1 where t1.a > 5; +create view v2 as select * from t2 where t2.b < 10 group by b; +let $qs= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +select a,b,c,d1 from + v1, + v2, + cte1 +where v1.a=v2.b and v2.b=cte1.c; +eval explain $qs; +eval $qs; +let $qu= +with cte1 as (select c, d+1 as d1 from t3 where t3.d < 3) +update + v1, + v2, + cte1 +set v1.a=v1.a-1, cte1.c=cte1.c+cte1.d1 +where v1.a=v2.b and v2.b=cte1.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; +--echo # update of join of mergeable view v1, +--echo # non-mergeable view v2 and mergeable view v3 +create view v1 as select * from t1 where t1.a < 3; +create view v2 as select * from t2 where t2.b < 5 group by b; +create view v3 as select c, d+1 as d1 from t3 where t3.d in (1,2); +let $qs= +with cte1 as (select * from t1 where t1.a < 3) +select a,b,c,d1 from + v1, + v2, + v3 +where v1.a=v2.b and v2.b=v3.c; +eval explain $qs; +eval $qs; +let $qu= +update + v1, + v2, + v3 +set v1.a=v1.a+1, v3.c=v3.c+v3.d1 +where v1.a=v2.b and v2.b=v3.c; +eval explain $qu; +eval $qu; +select * from t1; +select * from t2; +select * from t3; +drop view v1; +drop view v2; +drop view v3; + +drop table t1,t2,t3; diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index 23ff906..1cbf837 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -1782,7 +1782,6 @@ longlong Item_in_subselect::val_int() As far as Item_in_subselect called only from Item_in_optimizer this method should not be used */ - DBUG_ASSERT(0); DBUG_ASSERT(fixed == 1); if (forced_const) return value; diff --git a/sql/sp_head.cc b/sql/sp_head.cc index 49c8229..f177966 100644 --- a/sql/sp_head.cc +++ b/sql/sp_head.cc @@ -3484,8 +3484,7 @@ sp_lex_keeper::reset_lex_and_exec_core(THD *thd, uint *nextp, Json_writer_object trace_command(thd); Json_writer_array trace_command_steps(thd, "steps"); if (open_tables) - res= check_dependencies_in_with_clauses(m_lex->with_clauses_list) || - instr->exec_open_and_lock_tables(thd, m_lex->query_tables); + res= instr->exec_open_and_lock_tables(thd, m_lex->query_tables); if (likely(!res)) { diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 090ced5..71b3fa5 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -1183,7 +1183,7 @@ unique_table(THD *thd, TABLE_LIST *table, TABLE_LIST *table_list, { TABLE_LIST *dup; - table= table->find_table_for_update(); + table= table->find_table_for_update(thd); if (table->table && table->table->file->ha_table_flags() & HA_CAN_MULTISTEP_MERGE) @@ -3568,7 +3568,18 @@ open_and_process_table(THD *thd, TABLE_LIST *tables, uint *counter, uint flags, if (tables->derived) { if (!tables->view) + { + if (!tables->is_derived()) + tables->set_derived(); + st_select_lex *sl= tables->derived->first_select(); + if (sl->is_mergeable()) + { + tables->merge_underlying_list= sl->table_list.first; + tables->propagate_properties_for_mergeable_derived(); + tables->where= sl->where; + } goto end; + } /* We restore view's name and database wiped out by derived tables processing and fall back to standard open process in order to @@ -3578,33 +3589,15 @@ open_and_process_table(THD *thd, TABLE_LIST *tables, uint *counter, uint flags, tables->db= tables->view_db; tables->table_name= tables->view_name; } - else if (tables->select_lex) + else if (tables->select_lex) { - /* - Check whether 'tables' refers to a table defined in a with clause. - If so set the reference to the definition in tables->with. - */ - if (!tables->with) - tables->with= tables->select_lex->find_table_def_in_with_clauses(tables); - /* - If 'tables' is defined in a with clause set the pointer to the - specification from its definition in tables->derived. - */ if (tables->with) { - if (tables->is_recursive_with_table() && - !tables->is_with_table_recursive_reference()) - { - tables->with->rec_outer_references++; - With_element *with_elem= tables->with; - while ((with_elem= with_elem->get_next_mutually_recursive()) != - tables->with) - with_elem->rec_outer_references++; - } - if (tables->set_as_with_table(thd, tables->with)) + if (!(tables->derived= tables->with->clone_parsed_spec(thd->lex, tables))) DBUG_RETURN(1); - else - goto end; + tables->derived->first_select()->set_linkage(DERIVED_TABLE_TYPE); + tables->select_lex->add_statistics(tables->derived); + goto end; } } @@ -5168,13 +5161,13 @@ bool open_and_lock_tables(THD *thd, const DDL_options_st &options, /* Don't read statistics tables when opening internal tables */ if (!(flags & MYSQL_OPEN_IGNORE_LOGGING_FORMAT)) (void) read_statistics_for_tables_if_needed(thd, tables); - + if (derived) { if (mysql_handle_derived(thd->lex, DT_INIT)) goto err; if (thd->prepare_derived_at_open && - (mysql_handle_derived(thd->lex, DT_PREPARE))) + (mysql_handle_derived(thd->lex, DT_PREPARE))) goto err; } @@ -6287,8 +6280,7 @@ find_field_in_tables(THD *thd, Item_ident *item, when table_ref->field_translation != NULL. */ if (table_ref->table && !table_ref->view && - (!table_ref->is_merged_derived() || - (!table_ref->is_multitable() && table_ref->merged_for_insert))) + !table_ref->is_merged_derived()) { found= find_field_in_table(thd, table_ref->table, name, length, @@ -8017,7 +8009,7 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name, (table->grant.privilege & SELECT_ACL)) || ((!tables->is_non_derived() && (tables->grant.privilege & SELECT_ACL)))) && - !any_privileges) + !any_privileges) { field_iterator.set(tables); if (check_grant_all_columns(thd, SELECT_ACL, &field_iterator)) @@ -8082,7 +8074,8 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name, temporary table. Thus in this case we can be sure that 'item' is an Item_field. */ - if (any_privileges && !tables->is_with_table() && !tables->is_derived()) + if (any_privileges && !tables->is_with_table() && !tables->is_derived() && + !thd->lex->can_use_merged()) { DBUG_ASSERT((tables->field_translation == NULL && table) || tables->is_natural_join); @@ -8304,7 +8297,7 @@ int setup_conds(THD *thd, TABLE_LIST *tables, List<TABLE_LIST> &leaves, for (table= tables; table; table= table->next_local) { - if (select_lex == thd->lex->first_select_lex() && + if (select_lex != thd->lex->first_select_lex() && select_lex->first_cond_optimization && table->merged_for_insert && table->prepare_where(thd, conds, FALSE)) diff --git a/sql/sql_class.h b/sql/sql_class.h index ed4ebbb..ea0764f 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -4357,14 +4357,11 @@ class THD: public THD_count, /* this must be first */ to resolve all CTE names as we don't need this message to be thrown for any CTE references. */ - if (!lex->with_clauses_list) + if (!lex->with_cte_resolution) { my_message(ER_NO_DB_ERROR, ER(ER_NO_DB_ERROR), MYF(0)); return TRUE; } - /* This will allow to throw an error later for non-CTE references */ - to->str= NULL; - to->length= 0; return FALSE; } @@ -5384,7 +5381,7 @@ class select_result :public select_result_sink virtual void update_used_tables() {} /* this method is called just before the first row of the table can be read */ - virtual void prepare_to_read_rows() {} + virtual void prepare_to_read_rows(THD *thd) {} void remove_offset_limit() { @@ -6595,7 +6592,7 @@ class multi_delete :public select_result_interceptor bool send_eof(); inline ha_rows num_deleted() const { return deleted; } virtual void abort_result_set(); - void prepare_to_read_rows(); + void prepare_to_read_rows(THD *thd); }; @@ -6603,6 +6600,7 @@ class multi_update :public select_result_interceptor { TABLE_LIST *all_tables; /* query/update command tables */ List<TABLE_LIST> *leaves; /* list of leves of join table tree */ + List<TABLE_LIST> updated_leaves; TABLE_LIST *update_tables; TABLE **tmp_tables, *main_table, *table_to_update; TMP_TABLE_PARAM *tmp_table_param; @@ -6640,6 +6638,7 @@ class multi_update :public select_result_interceptor List<Item> *fields, List<Item> *values, enum_duplicates handle_duplicates, bool ignore); ~multi_update(); + bool init(THD *thd); int prepare(List<Item> &list, SELECT_LEX_UNIT *u); int send_data(List<Item> &items); bool initialize_tables (JOIN *join); @@ -6650,7 +6649,7 @@ class multi_update :public select_result_interceptor inline ha_rows num_updated() const { return updated; } virtual void abort_result_set(); void update_used_tables(); - void prepare_to_read_rows(); + void prepare_to_read_rows(THD *thd); }; class my_var_sp; diff --git a/sql/sql_cte.cc b/sql/sql_cte.cc index 5bf9930..1eb4327 100644 --- a/sql/sql_cte.cc +++ b/sql/sql_cte.cc @@ -56,11 +56,43 @@ bool With_clause::add_with_element(With_element *elem) } -void st_select_lex_unit::set_with_clause(With_clause *with_cl) +void With_clause::move_tables_to_end(LEX *lex) +{ + if (tables_start_pos == tables_end_pos || + tables_end_pos == lex->query_tables_last) + return; + TABLE_LIST *first_tbl= *tables_start_pos; + DBUG_ASSERT (first_tbl); + TABLE_LIST *next_tbl= *tables_end_pos; + DBUG_ASSERT(next_tbl); + /* Exclude the tables of the with clause from global list */ + *(next_tbl->prev_global= tables_start_pos)= next_tbl; + /* Attach the tables of the with_clause to the very end of global list */ + *(first_tbl->prev_global= lex->query_tables_last)= first_tbl; + *(lex->query_tables_last= tables_end_pos)= 0; + for (With_element *with_elem= with_list.first; + with_elem; with_elem= with_elem->next) + { + if (with_elem->head->tables_pos.start_pos != tables_start_pos) + break; + with_elem->head->tables_pos.set_start_pos(first_tbl->prev_global); + if (with_elem->head->tables_pos.end_pos != tables_start_pos) + break; + with_elem->head->tables_pos.set_end_pos(first_tbl->prev_global); + } + tables_start_pos= first_tbl->prev_global; + tables_end_pos= lex->query_tables_last; +} + + +void st_select_lex_unit::set_with_clause(LEX *lex, With_clause *with_cl) { with_clause= with_cl; if (with_clause) + { with_clause->set_owner(this); + with_clause->move_tables_to_end(lex); + } } @@ -84,7 +116,8 @@ void st_select_lex_unit::set_with_clause(With_clause *with_cl) true on failure */ -bool check_dependencies_in_with_clauses(With_clause *with_clauses_list) + +bool LEX::check_dependencies_in_with_clauses() { for (With_clause *with_clause= with_clauses_list; with_clause; @@ -100,6 +133,216 @@ bool check_dependencies_in_with_clauses(With_clause *with_clauses_list) } +bool +LEX::resolve_references_to_cte_in_hanging_cte(TABLE_LIST **start_ptr) +{ + for (With_clause *with_clause= with_clauses_list; + with_clause; with_clause= with_clause->next_with_clause) + { + for (With_element *with_elem= with_clause->with_list.first; + with_elem; with_elem= with_elem->next) + { + if (!with_elem->is_referenced()) + { + TABLE_LIST *cte_last_ordered= 0; + TABLE_LIST *first_tbl= + with_elem->spec->first_select()->table_list.first; + TABLE_LIST **with_elem_end_pos= with_elem->head->tables_pos.end_pos; + if (resolve_and_order_references_to_cte(first_tbl, + with_elem_end_pos, + &cte_last_ordered)) + return true; + reorder_table_list(first_tbl, start_ptr); + start_ptr= &cte_last_ordered->next_global; + } + } + } + return false; +} + + +bool LEX::resolve_and_order_references_to_cte(TABLE_LIST *tables, + TABLE_LIST **tables_last, + TABLE_LIST **last_ordered) +{ + TABLE_LIST *with_elem_first_tbl= 0; + TABLE_LIST **with_elem_end_pos= 0; + With_element *with_elem= 0; + bool rc= false; + Query_arena backup; + Query_arena *arena= thd->activate_stmt_arena_if_needed(&backup); + + for (TABLE_LIST *tbl= tables; + tbl != *tables_last; + tbl= tbl->next_global) + { + if (tbl->next_ordered || tbl == *last_ordered) + continue; + if (!*last_ordered) + *last_ordered= tbl; + else + *last_ordered= (*last_ordered)->next_ordered= tbl; + if (!tbl->db.str && !tbl->with) + tbl->with= tbl->select_lex->find_table_def_in_with_clauses(tbl); + if (!tbl->with) + { + if (!tbl->db.str) + { + if (!thd->db.str) + { + my_message(ER_NO_DB_ERROR, ER(ER_NO_DB_ERROR), MYF(0)); + rc= true; + goto err; + } + if (copy_db_to(&tbl->db)) + { + rc= true; + goto err; + } + if (!(tbl->table_options & TL_OPTION_ALIAS)) + MDL_REQUEST_INIT(&tbl->mdl_request, MDL_key::TABLE, tbl->db.str, + tbl->table_name.str, tbl->mdl_type, MDL_TRANSACTION); + if (tbl->is_mdl_request_type_to_be_set) + { + tbl->mdl_request.set_type((tbl->lock_type >= TL_WRITE_ALLOW_WRITE) ? + MDL_SHARED_WRITE : MDL_SHARED_READ); + tbl->is_mdl_request_type_to_be_set= false; + } + } + continue; + } + with_elem= tbl->with; + if (tbl->is_recursive_with_table() && + !tbl->is_with_table_recursive_reference()) + { + tbl->with->rec_outer_references++; + while ((with_elem= with_elem->get_next_mutually_recursive()) != + tbl->with) + with_elem->rec_outer_references++; + } + if (!with_elem->is_used_in_query || with_elem->is_recursive) + { + tbl->derived= with_elem->spec; + if (tbl->derived != tbl->select_lex->master_unit() && + !with_elem->is_recursive && + !tbl->is_with_table_recursive_reference()) + { + tbl->derived->move_as_slave(tbl->select_lex); + } + with_elem->is_used_in_query= true; + } + else + tbl->derived= 0; + tbl->db.str= empty_c_string; + tbl->db.length= 0; + tbl->schema_table= 0; + MDL_REQUEST_INIT(&tbl->mdl_request, MDL_key::TABLE, tbl->db.str, + tbl->table_name.str, tbl->mdl_type, MDL_TRANSACTION); + if (tbl->is_mdl_request_type_to_be_set) + { + tbl->mdl_request.set_type((tbl->lock_type >= TL_WRITE_ALLOW_WRITE) ? + MDL_SHARED_WRITE : MDL_SHARED_READ); + tbl->is_mdl_request_type_to_be_set= false; + } + if (tbl->derived) + { + tbl->derived->first_select()->set_linkage(DERIVED_TABLE_TYPE); + tbl->select_lex->add_statistics(tbl->derived); + } + if (tbl->with->is_recursive && tbl->is_with_table_recursive_reference()) + continue; + with_elem->inc_references(); + if (tbl->derived) + { + with_elem_first_tbl= tbl->derived->first_select()->table_list.first; + with_elem_end_pos= with_elem->head->tables_pos.end_pos; + if (with_elem_first_tbl && + resolve_and_order_references_to_cte(with_elem_first_tbl, + with_elem_end_pos, + last_ordered)) + { + rc= true; + goto err; + } + } + } +err: + if (arena) + thd->restore_active_arena(arena, &backup); + return rc; +} + + +void LEX::reorder_table_list(TABLE_LIST *tables, TABLE_LIST **start_ptr) +{ + TABLE_LIST *next_ordered= 0; + TABLE_LIST **last_chunk_next_ptr= start_ptr; + bool is_first_chunk= true; + for (TABLE_LIST *tbl= tables; tbl; tbl= next_ordered) + { + TABLE_LIST *chunk_first= tbl; + for (next_ordered= tbl->next_ordered; + next_ordered && next_ordered == tbl->next_global; + next_ordered= tbl->next_ordered) + { + tbl= next_ordered; + } + TABLE_LIST *chunk_last= tbl; + if (is_first_chunk && *last_chunk_next_ptr == chunk_first) + { + /* The first chunk is in place */ + } + else + { + TABLE_LIST *next_tbl= tbl->next_global; + + /* Exclude chunk_first..chunk_last from global list */ + if (next_tbl) + *(next_tbl->prev_global= chunk_first->prev_global)= next_tbl; + else + *(query_tables_last= chunk_first->prev_global)= 0; + + next_tbl= *last_chunk_next_ptr; + /* + Include chunk_first..chunk_last before next_tbl if it's not 0 and + at the end of the list otherwise + */ + if (next_tbl) + *(next_tbl->prev_global= &chunk_last->next_global)= next_tbl; + else + *(query_tables_last= &chunk_last->next_global)= 0; + *(chunk_first->prev_global= last_chunk_next_ptr)= chunk_first; + } + last_chunk_next_ptr= &chunk_last->next_global; + is_first_chunk= false; + } +} + + +bool +LEX::check_cte_dependencies_and_resolve_references() +{ + if (check_dependencies_in_with_clauses()) + return true; + if (!with_cte_resolution) + return false; + TABLE_LIST *last_ordered= 0; + TABLE_LIST *first_tbl= query_tables; + if (resolve_and_order_references_to_cte(first_tbl, + query_tables_last, + &last_ordered)) + return true; + reorder_table_list(first_tbl, &query_tables); + TABLE_LIST **start_ptr= last_ordered ? &last_ordered->next_global : + &query_tables; + if (*start_ptr && + resolve_references_to_cte_in_hanging_cte(start_ptr)) + return true; + all_cte_resolved= true; + return false; +} + + /** @brief Check dependencies between tables defined in this with clause @@ -138,10 +381,11 @@ bool With_clause::check_dependencies() elem != with_elem; elem= elem->next) { - if (lex_string_cmp(system_charset_info, with_elem->query_name, - elem->query_name) == 0) + if (lex_string_cmp(system_charset_info, with_elem->get_name(), + elem->get_name()) == 0) { - my_error(ER_DUP_QUERY_NAME, MYF(0), with_elem->query_name->str); + my_error(ER_DUP_QUERY_NAME, MYF(0), + with_elem->get_name_str()); return true; } } @@ -248,11 +492,12 @@ With_element *With_clause::find_table_def(TABLE_LIST *table, with_elem != barrier; with_elem= with_elem->next) { - if (my_strcasecmp(system_charset_info, with_elem->query_name->str, + if (my_strcasecmp(system_charset_info, with_elem->get_name_str(), table->table_name.str) == 0 && !table->is_fqtn) { table->set_derived(); + with_elem->referenced= true; return with_elem; } } @@ -609,7 +854,7 @@ bool With_clause::check_anchors() if (elem == with_elem) { my_error(ER_RECURSIVE_WITHOUT_ANCHORS, MYF(0), - with_elem->query_name->str); + with_elem->get_name_str()); return true; } } @@ -642,7 +887,7 @@ bool With_clause::check_anchors() if (elem->work_dep_map & elem->get_elem_map()) { my_error(ER_UNACCEPTABLE_MUTUAL_RECURSION, MYF(0), - with_elem->query_name->str); + with_elem->get_name_str()); return true; } } @@ -827,14 +1072,17 @@ bool With_element::set_unparsed_spec(THD *thd, NULL - otherwise */ -st_select_lex_unit *With_element::clone_parsed_spec(THD *thd, +st_select_lex_unit *With_element::clone_parsed_spec(LEX *old_lex, TABLE_LIST *with_table) { + THD *thd= old_lex->thd; LEX *lex; st_select_lex_unit *res= NULL; Query_arena backup; Query_arena *arena= thd->activate_stmt_arena_if_needed(&backup); bool has_tmp_tables; + uint i= 0; + if (!(lex= (LEX*) new(thd->mem_root) st_lex_local)) { @@ -842,14 +1090,12 @@ st_select_lex_unit *With_element::clone_parsed_spec(THD *thd, thd->restore_active_arena(arena, &backup); return res; } - LEX *old_lex= thd->lex; thd->lex= lex; bool parse_status= false; Parser_state parser_state; - TABLE_LIST *spec_tables; - TABLE_LIST *spec_tables_tail; st_select_lex *with_select; + st_select_lex *end_sl; char save_end= unparsed_spec.str[unparsed_spec.length]; ((char*) &unparsed_spec.str[unparsed_spec.length])[0]= '\0'; @@ -866,6 +1112,7 @@ st_select_lex_unit *With_element::clone_parsed_spec(THD *thd, lex->spname= old_lex->spname; lex->spcont= old_lex->spcont; lex->sp_chistics= old_lex->sp_chistics; + lex->with_cte_resolution= true; lex->stmt_lex= old_lex; parse_status= parse_sql(thd, &parser_state, 0); @@ -875,48 +1122,63 @@ st_select_lex_unit *With_element::clone_parsed_spec(THD *thd, if (parse_status) goto err; - if (check_dependencies_in_with_clauses(lex->with_clauses_list)) - goto err; - - spec_tables= lex->query_tables; - spec_tables_tail= 0; - has_tmp_tables= thd->has_temporary_tables(); - for (TABLE_LIST *tbl= spec_tables; - tbl; - tbl= tbl->next_global) + if (lex->query_tables) { - if (has_tmp_tables && !tbl->derived && !tbl->schema_table && - thd->open_temporary_table(tbl)) - goto err; - spec_tables_tail= tbl; - } - if (check_table_access(thd, SELECT_ACL, spec_tables, FALSE, UINT_MAX, FALSE)) - goto err; - if (spec_tables) - { - if (with_table->next_global) + head->tables_pos.set_start_pos(&with_table->next_global); + head->tables_pos.set_end_pos(lex->query_tables_last); + TABLE_LIST *next_tbl= with_table->next_global; + if (next_tbl) { - spec_tables_tail->next_global= with_table->next_global; - with_table->next_global->prev_global= &spec_tables_tail->next_global; + *(lex->query_tables->prev_global= next_tbl->prev_global)= + lex->query_tables; + *(next_tbl->prev_global= lex->query_tables_last)= next_tbl; } else { - old_lex->query_tables_last= &spec_tables_tail->next_global; + *(lex->query_tables->prev_global= old_lex->query_tables_last)= + lex->query_tables; + old_lex->query_tables_last= lex->query_tables_last; } - spec_tables->prev_global= &with_table->next_global; - with_table->next_global= spec_tables; } + res= &lex->unit; lex->unit.include_down(with_table->select_lex); - lex->unit.set_slave(with_select); + lex->unit.set_slave(with_select); + end_sl= lex->all_selects_list; + while (end_sl->next_select_in_list()) + end_sl= end_sl->next_select_in_list(); old_lex->all_selects_list= (st_select_lex*) (lex->all_selects_list-> insert_chain_before( (st_select_lex_node **) &(old_lex->all_selects_list), - with_select)); - if (check_dependencies_in_with_clauses(lex->with_clauses_list)) + end_sl)); + if (lex->check_cte_dependencies_and_resolve_references()) + { res= NULL; + goto err; + } + + has_tmp_tables= thd->has_temporary_tables(); + for (TABLE_LIST *tbl= *head->tables_pos.start_pos; + tbl != *head->tables_pos.end_pos; + tbl= tbl->next_global, i++) + { + if (has_tmp_tables && !tbl->derived && !tbl->schema_table && + thd->open_temporary_table(tbl)) + { + res= NULL; + goto err; + } + } + + if (i && check_table_access(thd, SELECT_ACL, *head->tables_pos.start_pos, + FALSE, i, FALSE)) + { + res= NULL; + goto err; + } + lex->sphead= NULL; // in order not to delete lex->sphead lex_end(lex); err: @@ -1128,57 +1390,6 @@ With_element *st_select_lex::find_table_def_in_with_clauses(TABLE_LIST *table) } -/** - @brief - Set the specifying unit in this reference to a with table - - @details - The method assumes that the given element with_elem defines the table T - this table reference refers to. - If this is the first reference to T the method just sets its specification - in the field 'derived' as the unit that yields T. Otherwise the method - first creates a clone specification and sets rather this clone in this field. - - @retval - false on success - true on failure -*/ - -bool TABLE_LIST::set_as_with_table(THD *thd, With_element *with_elem) -{ - if (table) - { - /* - This table was prematurely identified as a temporary table. - We correct it here, but it's not a nice solution in the case - when the temporary table with this name is not used anywhere - else in the query. - */ - thd->mark_tmp_table_as_free_for_reuse(table); - table= 0; - } - with= with_elem; - schema_table= NULL; - if (!with_elem->is_referenced() || with_elem->is_recursive) - { - derived= with_elem->spec; - if (derived != select_lex->master_unit() && - !with_elem->is_recursive && - !is_with_table_recursive_reference()) - { - derived->move_as_slave(select_lex); - } - } - else - { - if(!(derived= with_elem->clone_parsed_spec(thd, this))) - return true; - } - derived->first_select()->set_linkage(DERIVED_TABLE_TYPE); - select_lex->add_statistics(derived); - with_elem->inc_references(); - return false; -} bool TABLE_LIST::is_recursive_with_table() @@ -1280,7 +1491,7 @@ bool st_select_lex::check_unrestricted_recursive(bool only_standard_compliant) if (only_standard_compliant && with_elem->is_unrestricted()) { my_error(ER_NOT_STANDARD_COMPLIANT_RECURSIVE, - MYF(0), with_elem->query_name->str); + MYF(0), with_elem->get_name_str()); return true; } @@ -1497,7 +1708,8 @@ static void list_strlex_print(THD *thd, String *str, List<Lex_ident_sys> *list) void With_element::print(THD *thd, String *str, enum_query_type query_type) { - str->append(query_name); + str->append(get_name()); + if (column_list.elements) { List_iterator_fast<Lex_ident_sys> li(column_list); diff --git a/sql/sql_cte.h b/sql/sql_cte.h index 4c42dd2..0c5ac72 100644 --- a/sql/sql_cte.h +++ b/sql/sql_cte.h @@ -23,6 +23,20 @@ class select_unit; struct st_unit_ctxt_elem; +class With_element_head : public Sql_alloc +{ + LEX_CSTRING *query_name; +public: + TABLE_CHAIN tables_pos; + With_element_head(LEX_CSTRING *name) + : query_name(name) + { + tables_pos.set_start_pos(0); + tables_pos.set_end_pos(0); + } + friend class With_element; +}; + /** @class With_element @@ -85,6 +99,10 @@ class With_element : public Sql_alloc subqueries and specifications of other with elements). */ uint references; + bool referenced; + + bool is_used_in_query; + /* Unparsed specification of the query that specifies this element. It used to build clones of the specification if they are needed. @@ -98,13 +116,10 @@ class With_element : public Sql_alloc /* Return the map where 1 is set only in the position for this element */ table_map get_elem_map() { return (table_map) 1 << number; } - + public: - /* - The name of the table introduced by this with elememt. The name - can be used in FROM lists of the queries in the scope of the element. - */ - LEX_CSTRING *query_name; + With_element_head *head; + /* Optional list of column names to name the columns of the table introduced by this with element. It is used in the case when the names are not @@ -163,18 +178,27 @@ class With_element : public Sql_alloc /* List of derived tables containing recursive references to this CTE */ SQL_I_List<TABLE_LIST> derived_with_rec_ref; - With_element(LEX_CSTRING *name, + With_element(With_element_head *h, List <Lex_ident_sys> list, st_select_lex_unit *unit) : next(NULL), base_dep_map(0), derived_dep_map(0), sq_dep_map(0), work_dep_map(0), mutually_recursive(0), top_level_dep_map(0), sq_rec_ref(NULL), next_mutually_recursive(NULL), references(0), - query_name(name), column_list(list), cycle_list(0), spec(unit), + referenced(false), is_used_in_query(false), + head(h), column_list(list), cycle_list(0), spec(unit), is_recursive(false), rec_outer_references(0), with_anchor(false), level(0), rec_result(NULL) { unit->with_element= this; } + LEX_CSTRING *get_name() { return head->query_name; } + const char *get_name_str() { return get_name()->str; } + + void set_tables_start_pos(TABLE_LIST **pos) + { head->tables_pos.set_start_pos(pos); } + void set_tables_end_pos(TABLE_LIST **pos) + { head->tables_pos.set_end_pos(pos); } + bool check_dependencies_in_spec(); void check_dependencies_in_select(st_select_lex *sl, st_unit_ctxt_elem *ctxt, @@ -196,14 +220,16 @@ class With_element : public Sql_alloc bool check_dependency_on(With_element *with_elem) { return base_dep_map & with_elem->get_elem_map(); } + + TABLE_LIST *find_first_sq_rec_ref_in_select(st_select_lex *sel); bool set_unparsed_spec(THD *thd, const char *spec_start, const char *spec_end, my_ptrdiff_t spec_offset); - st_select_lex_unit *clone_parsed_spec(THD *thd, TABLE_LIST *with_table); + st_select_lex_unit *clone_parsed_spec(LEX *old_lex, TABLE_LIST *with_table); - bool is_referenced() { return references != 0; } + bool is_referenced() { return referenced; } void inc_references() { references++; } @@ -263,6 +289,13 @@ class With_element : public Sql_alloc void set_cycle_list(List<Lex_ident_sys> *cycle_list_arg); friend class With_clause; + + friend + bool LEX::resolve_and_order_references_to_cte(TABLE_LIST *tables, + TABLE_LIST **tables_last, + TABLE_LIST **last_ordered); + friend + bool LEX::resolve_references_to_cte_in_hanging_cte(TABLE_LIST **start_ptr); }; const uint max_number_of_elements_in_with_clause= sizeof(table_map)*8; @@ -294,6 +327,10 @@ class With_clause : public Sql_alloc in the current statement */ With_clause *next_with_clause; + + TABLE_LIST **tables_start_pos; + TABLE_LIST **tables_end_pos; + /* Set to true if dependencies between with elements have been checked */ bool dependencies_are_checked; /* @@ -341,6 +378,13 @@ class With_clause : public Sql_alloc void attach_to(st_select_lex *select_lex); With_clause *pop() { return embedding_with_clause; } + + void set_tables_start_pos(TABLE_LIST **table_pos) + { tables_start_pos= table_pos; } + void set_tables_end_pos(TABLE_LIST **table_pos) + { tables_end_pos= table_pos; } + + void move_tables_to_end(LEX *lex); bool check_dependencies(); @@ -360,9 +404,8 @@ class With_clause : public Sql_alloc friend class With_element; - friend - bool - check_dependencies_in_with_clauses(With_clause *with_clauses_list); + friend bool LEX::check_dependencies_in_with_clauses(); + friend bool LEX::resolve_references_to_cte_in_hanging_cte(TABLE_LIST**); }; inline diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index 5942efc..359ef46 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -339,11 +339,12 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, if (thd->lex->handle_list_of_derived(table_list, DT_PREPARE)) DBUG_RETURN(TRUE); - if (!table_list->single_table_updatable()) + if (!table_list->single_table_updatable(thd)) { my_error(ER_NON_UPDATABLE_TABLE, MYF(0), table_list->alias.str, "DELETE"); DBUG_RETURN(TRUE); } + if (!(table= table_list->table) || !table->is_created()) { my_error(ER_VIEW_DELETE_MERGE_VIEW, MYF(0), @@ -1022,7 +1023,7 @@ int mysql_prepare_delete(THD *thd, TABLE_LIST *table_list, Item **conds, setup_conds(thd, table_list, select_lex->leaf_tables, conds) || setup_ftfuncs(select_lex)) DBUG_RETURN(TRUE); - if (!table_list->single_table_updatable() || + if (!table_list->single_table_updatable(thd) || check_key_in_view(thd, table_list)) { my_error(ER_NON_UPDATABLE_TABLE, MYF(0), table_list->alias.str, "DELETE"); @@ -1121,7 +1122,7 @@ int mysql_multi_delete_prepare(THD *thd) DBUG_RETURN(TRUE); } - if (!target_tbl->correspondent_table->single_table_updatable() || + if (!target_tbl->correspondent_table->single_table_updatable(thd) || check_key_in_view(thd, target_tbl->correspondent_table)) { my_error(ER_NON_UPDATABLE_TABLE, MYF(0), @@ -1181,12 +1182,12 @@ multi_delete::prepare(List<Item> &values, SELECT_LEX_UNIT *u) DBUG_RETURN(0); } -void multi_delete::prepare_to_read_rows() +void multi_delete::prepare_to_read_rows(THD *thd) { /* see multi_update::prepare_to_read_rows() */ for (TABLE_LIST *walk= delete_tables; walk; walk= walk->next_local) { - TABLE_LIST *tbl= walk->correspondent_table->find_table_for_update(); + TABLE_LIST *tbl= walk->correspondent_table->find_table_for_update(thd); tbl->table->mark_columns_needed_for_delete(); } } @@ -1206,7 +1207,7 @@ multi_delete::initialize_tables(JOIN *join) delete_while_scanning= true; for (walk= delete_tables; walk; walk= walk->next_local) { - TABLE_LIST *tbl= walk->correspondent_table->find_table_for_update(); + TABLE_LIST *tbl= walk->correspondent_table->find_table_for_update(thd); tables_to_delete_from|= tbl->table->map; if (delete_while_scanning && unique_table(thd, tbl, join->tables_list, 0)) diff --git a/sql/sql_derived.cc b/sql/sql_derived.cc index 428e7b1..596902e 100644 --- a/sql/sql_derived.cc +++ b/sql/sql_derived.cc @@ -382,10 +382,6 @@ bool mysql_derived_merge(THD *thd, LEX *lex, TABLE_LIST *derived) DBUG_RETURN(FALSE); } - if (thd->lex->sql_command == SQLCOM_UPDATE_MULTI || - thd->lex->sql_command == SQLCOM_DELETE_MULTI) - thd->save_prep_leaf_list= TRUE; - arena= thd->activate_stmt_arena_if_needed(&backup); // For easier test if (!derived->merged_for_insert || @@ -531,7 +527,7 @@ bool mysql_derived_merge_for_insert(THD *thd, LEX *lex, TABLE_LIST *derived) derived->merged_for_insert, derived->is_materialized_derived(), derived->is_multitable(), - derived->single_table_updatable(), + derived->single_table_updatable(thd), derived->merge_underlying_list != 0)); if (derived->merged_for_insert) DBUG_RETURN(FALSE); @@ -544,20 +540,35 @@ bool mysql_derived_merge_for_insert(THD *thd, LEX *lex, TABLE_LIST *derived) DBUG_RETURN(FALSE); if (!derived->is_multitable()) { - if (!derived->single_table_updatable()) + if (!derived->is_view() || + !derived->single_table_updatable(thd) || + derived->merge_underlying_list->is_derived()) DBUG_RETURN(derived->create_field_translation(thd)); if (derived->merge_underlying_list) { derived->table= derived->merge_underlying_list->table; derived->schema_table= derived->merge_underlying_list->schema_table; derived->merged_for_insert= TRUE; - DBUG_ASSERT(derived->table); } } DBUG_RETURN(FALSE); } +void TABLE_LIST::propagate_properties_for_mergeable_derived() +{ + for (TABLE_LIST *tbl= derived->first_select()->table_list.first; + tbl; + tbl= tbl->next_local) + { + tbl->lock_type= lock_type; + if (!tbl->mdl_request.ticket) + tbl->mdl_request.set_type(mdl_request.type); + tbl->updating= updating; + } +} + + /* Initialize a derived table/view @@ -590,8 +601,6 @@ bool mysql_derived_init(THD *thd, LEX *lex, TABLE_LIST *derived) bool res= derived->init_derived(thd, TRUE); - derived->updatable= derived->updatable && derived->is_view(); - DBUG_RETURN(res); } @@ -754,6 +763,12 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) break; } } + if (derived->is_recursive_with_table() && + derived->is_with_table_recursive_reference()) + { + derived->table->grant.privilege= SELECT_ACL; + derived->grant.privilege= SELECT_ACL; + } DBUG_RETURN(FALSE); } @@ -827,8 +842,14 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) Depending on the result field translation will or will not be created. */ - if (derived->init_derived(thd, FALSE)) - goto exit; + if (derived->is_merged_derived()) + { + if ((derived->is_view() || + (derived->get_unit()->prepared && + !(thd->lex->context_analysis_only & CONTEXT_ANALYSIS_ONLY_VIEW))) && + derived->create_field_translation(thd)) + goto exit; + } /* Temp table is created so that it hounours if UNION without ALL is to be @@ -920,8 +941,17 @@ bool mysql_derived_prepare(THD *thd, LEX *lex, TABLE_LIST *derived) { DBUG_ASSERT(derived->is_derived()); DBUG_ASSERT(derived->is_anonymous_derived_table()); - table->grant.privilege= SELECT_ACL; - derived->grant.privilege= SELECT_ACL; + if (derived->is_materialized_derived()) + { + table->grant.privilege= SELECT_ACL; + derived->grant.privilege= SELECT_ACL; + } + else + { + if (table->grant.privilege == NO_ACL) + table->grant.privilege= VIEW_ANY_ACL; + table->grant= derived->grant; + } } #endif /* Add new temporary table to list of open derived tables */ diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index a934427..228d5e9 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -121,7 +121,8 @@ static int binlog_show_create_table(THD *thd, TABLE *table, @returns false if success. */ -static bool check_view_single_update(List<Item> &fields, List<Item> *values, +static bool check_view_single_update(THD *thd, + List<Item> &fields, List<Item> *values, TABLE_LIST *view, table_map *map, bool insert) { @@ -171,7 +172,7 @@ static bool check_view_single_update(List<Item> &fields, List<Item> *values, */ tbl->table->insert_values= view->table->insert_values; view->table= tbl->table; - if (!tbl->single_table_updatable()) + if (!tbl->single_table_updatable(thd)) { if (insert) my_error(ER_NON_INSERTABLE_TABLE, MYF(0), view->alias.str, "INSERT"); @@ -179,6 +180,10 @@ static bool check_view_single_update(List<Item> &fields, List<Item> *values, my_error(ER_NON_UPDATABLE_TABLE, MYF(0), view->alias.str, "UPDATE"); return TRUE; } + else if (tbl->is_derived() && insert) + { + my_error(ER_NON_INSERTABLE_TABLE, MYF(0), view->alias.str, "INSERT"); + } *map= tables; return FALSE; @@ -214,7 +219,7 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, TABLE *table= table_list->table; DBUG_ENTER("check_insert_fields"); - if (!table_list->single_table_updatable()) + if (!table_list->single_table_updatable(thd)) { my_error(ER_NON_INSERTABLE_TABLE, MYF(0), table_list->alias.str, "INSERT"); DBUG_RETURN(-1); @@ -286,7 +291,7 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, if (table_list->is_view() && table_list->is_merged_derived()) { - if (check_view_single_update(fields, + if (check_view_single_update(thd, fields, fields_and_values_from_different_maps ? (List<Item>*) 0 : &values, table_list, map, true)) @@ -392,7 +397,7 @@ static int check_update_fields(THD *thd, TABLE_LIST *insert_table_list, if (insert_table_list->is_view() && insert_table_list->is_merged_derived() && - check_view_single_update(update_fields, + check_view_single_update(thd, update_fields, fields_and_values_from_different_maps ? (List<Item>*) 0 : &update_values, insert_table_list, map, false)) @@ -1462,7 +1467,7 @@ static bool mysql_prepare_insert_check_table(THD *thd, TABLE_LIST *table_list, bool insert_into_view= (table_list->view != 0); DBUG_ENTER("mysql_prepare_insert_check_table"); - if (!table_list->single_table_updatable()) + if (!table_list->single_table_updatable(thd) || table_list->is_derived()) { my_error(ER_NON_INSERTABLE_TABLE, MYF(0), table_list->alias.str, "INSERT"); DBUG_RETURN(TRUE); @@ -1576,11 +1581,11 @@ bool mysql_prepare_insert(THD *thd, TABLE_LIST *table_list, DBUG_ASSERT (!select_insert || !values); if (mysql_handle_derived(thd->lex, DT_INIT)) - DBUG_RETURN(TRUE); + DBUG_RETURN(TRUE); if (table_list->handle_derived(thd->lex, DT_MERGE_FOR_INSERT)) - DBUG_RETURN(TRUE); + DBUG_RETURN(TRUE); if (thd->lex->handle_list_of_derived(table_list, DT_PREPARE)) - DBUG_RETURN(TRUE); + DBUG_RETURN(TRUE); if (duplic == DUP_UPDATE) { diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 671948f..3d98a17 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1227,6 +1227,7 @@ void LEX::start(THD *thd_arg) curr_with_clause= 0; with_clauses_list= 0; with_clauses_list_last_next= &with_clauses_list; + all_cte_resolved= 0; clone_spec_offset= 0; create_view= NULL; field_list.empty(); @@ -1249,6 +1250,7 @@ void LEX::start(THD *thd_arg) explain_json= false; context_analysis_only= 0; derived_tables= 0; + with_cte_resolution= false; safe_to_cache_query= 1; parsing_options.reset(); empty_field_list_on_rset= 0; @@ -1267,6 +1269,7 @@ void LEX::start(THD *thd_arg) selects_allow_into= FALSE; selects_allow_procedure= FALSE; use_only_table_context= FALSE; + skip_access_check= false; parse_vcol_expr= FALSE; check_exists= FALSE; create_info.lex_start(); @@ -8859,6 +8862,8 @@ bool LEX::check_main_unit_semantics() if (unit.set_nest_level(0) || unit.check_parameters(first_select_lex())) return TRUE; + if (check_cte_dependencies_and_resolve_references()) + return TRUE; return FALSE; } @@ -9551,8 +9556,13 @@ void st_select_lex::add_statistics(SELECT_LEX_UNIT *unit) bool LEX::main_select_push() { DBUG_ENTER("LEX::main_select_push"); +#if 0 current_select_number= 1; builtin_select.select_number= 1; +#else + current_select_number= ++thd->lex->stmt_lex->current_select_number; + builtin_select.select_number= current_select_number; +#endif if (push_select(&builtin_select)) DBUG_RETURN(TRUE); DBUG_RETURN(FALSE); @@ -9648,7 +9658,7 @@ bool LEX::insert_select_hack(SELECT_LEX *sel) builtin_select.link_prev= NULL; // indicator of removal } - if (set_main_unit(sel->master_unit())) + if (set_main_unit(this, sel->master_unit())) return true; DBUG_ASSERT(builtin_select.table_list.elements == 1); @@ -10046,7 +10056,7 @@ TABLE_LIST *LEX::parsed_derived_table(SELECT_LEX_UNIT *unit, bool LEX::parsed_create_view(SELECT_LEX_UNIT *unit, int check) { SQL_I_List<TABLE_LIST> *save= &first_select_lex()->table_list; - if (set_main_unit(unit)) + if (set_main_unit(this, unit)) return true; if (check_main_unit_semantics()) return true; @@ -10070,7 +10080,7 @@ bool LEX::select_finalize(st_select_lex_unit *expr) sql_command= SQLCOM_SELECT; selects_allow_into= TRUE; selects_allow_procedure= TRUE; - if (set_main_unit(expr)) + if (set_main_unit(this, expr)) return true; return check_main_unit_semantics(); } @@ -10377,7 +10387,7 @@ void st_select_lex::pushdown_cond_into_where_clause(THD *thd, Item *cond, above are marked with NO_EXTRACTION_FL. @note - This method is called for pushdown into materialized + This mesthod is called for pushdown into materialized derived tables/views/IN subqueries optimization. */ diff --git a/sql/sql_lex.h b/sql/sql_lex.h index adfa0c0..81621c9 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -969,7 +969,7 @@ class st_select_lex_unit: public st_select_lex_node { { return reinterpret_cast<st_select_lex*>(slave); } - void set_with_clause(With_clause *with_cl); + void set_with_clause(LEX *lex, With_clause *with_cl); st_select_lex_unit* next_unit() { return reinterpret_cast<st_select_lex_unit*>(next); @@ -1762,6 +1762,16 @@ class Query_tables_list */ void add_to_query_tables(TABLE_LIST *table) { + if (table->derived) + { + TABLE_LIST *first_local= table->derived->first_select()->table_list.first; + if (first_local) + { + *(table->prev_global= first_local->prev_global)= table; + *(first_local->prev_global= &table->next_global)= first_local; + return; + } + } *(table->prev_global= query_tables_last)= table; query_tables_last= &table->next_global; } @@ -3132,6 +3142,9 @@ class Lex_grant_privilege: public Grant_privilege, public Sql_alloc }; +class Query_name; + + struct LEX: public Query_tables_list { SELECT_LEX_UNIT unit; /* most upper unit */ @@ -3154,6 +3167,7 @@ struct LEX: public Query_tables_list with clause in the current statement */ With_clause **with_clauses_list_last_next; + bool all_cte_resolved; /* When a copy of a with element is parsed this is set to the offset of the with element in the input string, otherwise it's set to 0 @@ -3372,6 +3386,7 @@ struct LEX: public Query_tables_list */ uint8 derived_tables; uint8 context_analysis_only; + bool with_cte_resolution; bool local_file; bool check_exists; bool autocommit; @@ -3471,6 +3486,8 @@ struct LEX: public Query_tables_list */ bool use_only_table_context; + bool skip_access_check; + /* Reference to a struct that contains information in various commands to add/create/drop/change table spaces. @@ -4524,7 +4541,7 @@ struct LEX: public Query_tables_list bool insert_select_hack(SELECT_LEX *sel); SELECT_LEX *create_priority_nest(SELECT_LEX *first_in_nest); - bool set_main_unit(st_select_lex_unit *u) + bool set_main_unit(LEX *lex, st_select_lex_unit *u) { unit.options= u->options; unit.uncacheable= u->uncacheable; @@ -4532,7 +4549,7 @@ struct LEX: public Query_tables_list unit.first_select()->options|= builtin_select.options; unit.fake_select_lex= u->fake_select_lex; unit.union_distinct= u->union_distinct; - unit.set_with_clause(u->with_clause); + unit.set_with_clause(lex, u->with_clause); builtin_select.exclude_from_global(); return false; } @@ -4675,6 +4692,15 @@ struct LEX: public Query_tables_list const LEX_CSTRING *constraint_name, Table_ident *ref_table_name, DDL_options ddl_options); + + bool check_dependencies_in_with_clauses(); + bool resolve_references_to_cte_in_hanging_cte(TABLE_LIST **start_ptr); + bool check_cte_dependencies_and_resolve_references(); + bool resolve_and_order_references_to_cte(TABLE_LIST *tables, + TABLE_LIST **tables_last, + TABLE_LIST **last_ordered); + void reorder_table_list(TABLE_LIST *tables, TABLE_LIST **start_ptr); + }; diff --git a/sql/sql_load.cc b/sql/sql_load.cc index c3e301c..0637a68 100644 --- a/sql/sql_load.cc +++ b/sql/sql_load.cc @@ -403,7 +403,7 @@ int mysql_load(THD *thd, const sql_exchange *ex, TABLE_LIST *table_list, INSERT_ACL | UPDATE_ACL, FALSE)) DBUG_RETURN(-1); if (!table_list->table || // do not suport join view - !table_list->single_table_updatable() || // and derived tables + !table_list->single_table_updatable(thd) || // and derived tables check_key_in_view(thd, table_list)) { my_error(ER_NON_UPDATABLE_TABLE, MYF(0), table_list->alias.str, "LOAD"); diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index 86f81dd..bf362da 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -3366,6 +3366,7 @@ mysql_execute_command(THD *thd) already. */ DBUG_ASSERT(! thd->transaction_rollback_request || thd->in_sub_stmt); + /* In many cases first table of main SELECT_LEX have special meaning => check that it is first table in global list and relink it first in @@ -3411,9 +3412,6 @@ mysql_execute_command(THD *thd) thd->get_stmt_da()->opt_clear_warning_info(thd->query_id); } - if (check_dependencies_in_with_clauses(thd->lex->with_clauses_list)) - DBUG_RETURN(1); - #ifdef HAVE_REPLICATION if (unlikely(thd->slave_thread)) { @@ -6903,7 +6901,7 @@ bool check_one_table_access(THD *thd, privilege_t privilege, UINT_MAX, FALSE))) return 1; } - return 0; + return 0; } @@ -8183,7 +8181,7 @@ TABLE_LIST *st_select_lex::add_table_to_list(THD *thd, ptr->is_fqtn= TRUE; ptr->db= table->db; } - else if (lex->copy_db_to(&ptr->db)) + else if (!lex->with_cte_resolution && lex->copy_db_to(&ptr->db)) DBUG_RETURN(0); else ptr->is_fqtn= FALSE; @@ -8200,7 +8198,9 @@ TABLE_LIST *st_select_lex::add_table_to_list(THD *thd, } ptr->table_name= table->table; - ptr->lock_type= lock_type; + ptr->lock_type= lock_type; + ptr->mdl_type= mdl_type; + ptr->table_options= table_options; ptr->updating= MY_TEST(table_options & TL_OPTION_UPDATING); /* TODO: remove TL_OPTION_FORCE_INDEX as it looks like it's not used */ ptr->force_index= MY_TEST(table_options & TL_OPTION_FORCE_INDEX); @@ -8871,8 +8871,11 @@ void st_select_lex::set_lock_for_tables(thr_lock_type lock_type, bool for_update { tables->lock_type= lock_type; tables->updating= for_update; - tables->mdl_request.set_type((lock_type >= TL_WRITE_ALLOW_WRITE) ? - MDL_SHARED_WRITE : MDL_SHARED_READ); + if (!tables->db.str) + tables->is_mdl_request_type_to_be_set= true; + else + tables->mdl_request.set_type((lock_type >= TL_WRITE_ALLOW_WRITE) ? + MDL_SHARED_WRITE : MDL_SHARED_READ); } DBUG_VOID_RETURN; } diff --git a/sql/sql_prepare.cc b/sql/sql_prepare.cc index 6dbdfe7..54288f2 100644 --- a/sql/sql_prepare.cc +++ b/sql/sql_prepare.cc @@ -1392,7 +1392,7 @@ static int mysql_test_update(Prepared_statement *stmt, if (table_list->handle_derived(thd->lex, DT_PREPARE)) goto error; - if (!table_list->single_table_updatable()) + if (!table_list->single_table_updatable(thd)) { my_error(ER_NON_UPDATABLE_TABLE, MYF(0), table_list->alias.str, "UPDATE"); goto error; @@ -1470,7 +1470,7 @@ static bool mysql_test_delete(Prepared_statement *stmt, if (mysql_handle_derived(thd->lex, DT_PREPARE)) goto error; - if (!table_list->single_table_updatable()) + if (!table_list->single_table_updatable(thd)) { my_error(ER_NON_UPDATABLE_TABLE, MYF(0), table_list->alias.str, "DELETE"); goto error; @@ -2303,9 +2303,6 @@ static bool check_prepared_statement(Prepared_statement *stmt) if (tables) thd->get_stmt_da()->opt_clear_warning_info(thd->query_id); - if (check_dependencies_in_with_clauses(thd->lex->with_clauses_list)) - goto error; - if (sql_command_flags[sql_command] & CF_HA_CLOSE) mysql_ha_rm_tables(thd, tables); diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 76cb96b..24f534d 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1154,11 +1154,22 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num, Affects only materialized derived tables. */ /* Check that all tables, fields, conds and order are ok */ - if (!(select_options & OPTION_SETUP_TABLES_DONE) && - setup_tables_and_check_access(thd, &select_lex->context, join_list, - tables_list, select_lex->leaf_tables, - FALSE, SELECT_ACL, SELECT_ACL, FALSE)) - DBUG_RETURN(-1); + if (!(select_options & OPTION_SETUP_TABLES_DONE)) + { + if (thd->lex->skip_access_check) + { + if (setup_tables(thd, &select_lex->context, join_list, tables_list, + select_lex->leaf_tables, FALSE, FALSE)) + DBUG_RETURN(-1); + } + else + { + if (setup_tables_and_check_access(thd, &select_lex->context, join_list, + tables_list, select_lex->leaf_tables, + FALSE, SELECT_ACL, SELECT_ACL, FALSE)) + DBUG_RETURN(-1); + } + } /* Permanently remove redundant parts from the query if @@ -2232,7 +2243,7 @@ JOIN::optimize_inner() /* Calculate how to do the join */ THD_STAGE_INFO(thd, stage_statistics); - result->prepare_to_read_rows(); + result->prepare_to_read_rows(thd); if (unlikely(make_join_statistics(this, select_lex->leaf_tables, &keyuse)) || unlikely(thd->is_fatal_error)) diff --git a/sql/sql_show.cc b/sql/sql_show.cc index 62c93f6..e72ed05 100644 --- a/sql/sql_show.cc +++ b/sql/sql_show.cc @@ -2581,6 +2581,8 @@ static int show_create_view(THD *thd, TABLE_LIST *table, String *buff) tbl; tbl= tbl->next_global) { + if (!tbl->db.str || !tbl->db.str[0]) + continue; if (cmp(&table->view_db, tbl->view ? &tbl->view_db : &tbl->db)) { table->compact_view_format= FALSE; diff --git a/sql/sql_tvc.cc b/sql/sql_tvc.cc index 37f0f80..06d74a2 100644 --- a/sql/sql_tvc.cc +++ b/sql/sql_tvc.cc @@ -730,7 +730,7 @@ st_select_lex *wrap_tvc(THD *thd, st_select_lex *tvc_sl, wrapper_sl->where= 0; wrapper_sl->set_braces(false); - derived_unit->set_with_clause(0); + derived_unit->set_with_clause(lex, 0); if (arena) thd->restore_active_arena(arena, &backup); @@ -997,7 +997,7 @@ Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd, sq_select->where= 0; sq_select->set_braces(false); - derived_unit->set_with_clause(0); + derived_unit->set_with_clause(thd->lex, 0); /* Create IN subquery predicate */ sq_select->parsing_place= parent_select->parsing_place; diff --git a/sql/sql_update.cc b/sql/sql_update.cc index 8cd3b9f..dc2f8f4 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -401,9 +401,17 @@ int mysql_update(THD *thd, if (open_tables(thd, &table_list, &table_count, 0)) DBUG_RETURN(1); - /* Prepare views so they are handled correctly */ - if (mysql_handle_derived(thd->lex, DT_INIT)) + for (TABLE_LIST *tbl= thd->lex->query_tables; tbl; tbl= tbl->next_global) + { + if (tbl->handle_derived(thd->lex, DT_INIT)) + DBUG_RETURN(1); + } + + if (!table_list->is_multitable() && !table_list->single_table_updatable(thd)) + { + my_error(ER_NON_UPDATABLE_TABLE, MYF(0), table_list->alias.str, "UPDATE"); DBUG_RETURN(1); + } if (table_list->has_period() && table_list->is_view_or_derived()) { @@ -411,9 +419,13 @@ int mysql_update(THD *thd, DBUG_RETURN(TRUE); } - if (((update_source_table=unique_table(thd, table_list, - table_list->next_global, 0)) || - table_list->is_multitable())) + table_list->single_table_update= table_list->single_table_updatable(thd); + + if ((update_source_table= unique_table(thd, table_list, + table_list->next_global, 0)) || + table_list->is_multitable() || + (table_list->single_table_update && + (update_source_table= table_list->find_table_for_update(thd)))) { DBUG_ASSERT(update_source_table || table_list->view != 0); DBUG_PRINT("info", ("Switch to multi-update")); @@ -435,7 +447,7 @@ int mysql_update(THD *thd, table= table_list->table; - if (!table_list->single_table_updatable()) + if (!table_list->single_table_updatable(thd)) { my_error(ER_NON_UPDATABLE_TABLE, MYF(0), table_list->alias.str, "UPDATE"); DBUG_RETURN(1); @@ -1402,7 +1414,7 @@ bool mysql_prepare_update(THD *thd, TABLE_LIST *table_list, We do not call DT_MERGE_FOR_INSERT because it has no sense for simple (not multi-) update */ - if (mysql_handle_derived(thd->lex, DT_PREPARE)) + if (table_list->handle_derived(thd->lex, DT_PREPARE)) DBUG_RETURN(TRUE); if (setup_tables_and_check_access(thd, &select_lex->context, @@ -1680,10 +1692,16 @@ bool Multiupdate_prelocking_strategy::handle_end(THD *thd) done= true; - if (mysql_handle_derived(lex, DT_INIT) || - mysql_handle_derived(lex, DT_MERGE_FOR_INSERT) || - mysql_handle_derived(lex, DT_PREPARE)) + if (!table_list->single_table_update && + select_lex->handle_derived(lex, DT_INIT)) DBUG_RETURN(1); + lex->skip_access_check= true; + if (select_lex->handle_derived(lex, DT_PREPARE)) + { + lex->skip_access_check= false; + DBUG_RETURN(1); + } + lex->skip_access_check= false; /* setup_tables() need for VIEWs. JOIN::prepare() will call setup_tables() @@ -1691,12 +1709,8 @@ bool Multiupdate_prelocking_strategy::handle_end(THD *thd) call in setup_tables()). */ - if (setup_tables_and_check_access(thd, &select_lex->context, - &select_lex->top_join_list, table_list, select_lex->leaf_tables, - FALSE, UPDATE_ACL, SELECT_ACL, FALSE)) - DBUG_RETURN(1); - - if (select_lex->handle_derived(thd->lex, DT_MERGE)) + if (setup_tables(thd, &select_lex->context, &select_lex->top_join_list, + table_list, select_lex->leaf_tables, FALSE, TRUE)) DBUG_RETURN(1); List<Item> *fields= &lex->first_select_lex()->item_list; @@ -1706,7 +1720,7 @@ bool Multiupdate_prelocking_strategy::handle_end(THD *thd) // Check if we have a view in the list ... for (tl= table_list; tl ; tl= tl->next_local) - if (tl->view) + if (tl->view || tl->is_merged_derived()) break; // ... and pass this knowlage in check_fields call if (check_fields(thd, table_list, *fields, tl != NULL )) @@ -1732,7 +1746,7 @@ bool Multiupdate_prelocking_strategy::handle_end(THD *thd) /* if table will be updated then check that it is unique */ if (table->map & tables_for_update) { - if (!tl->single_table_updatable() || check_key_in_view(thd, tl)) + if (!tl->single_table_updatable(thd) || check_key_in_view(thd, tl)) { my_error(ER_NON_UPDATABLE_TABLE, MYF(0), tl->top_table()->alias.str, "UPDATE"); @@ -1790,6 +1804,7 @@ bool Multiupdate_prelocking_strategy::handle_end(THD *thd) DBUG_RETURN(TRUE); } +#if 0 /* check single table update for view compound from several tables */ for (tl= table_list; tl; tl= tl->next_local) { @@ -1803,6 +1818,7 @@ bool Multiupdate_prelocking_strategy::handle_end(THD *thd) DBUG_RETURN(1); } } +#endif DBUG_RETURN(0); } @@ -1887,9 +1903,6 @@ int mysql_multi_update_prepare(THD *thd) */ lex->first_select_lex()->exclude_from_table_unique_test= FALSE; - if (lex->save_prep_leaf_tables()) - DBUG_RETURN(TRUE); - DBUG_RETURN (FALSE); } @@ -1914,12 +1927,20 @@ bool mysql_multi_update(THD *thd, TABLE_LIST *table_list, List<Item> *fields, DBUG_RETURN(TRUE); } + if ((*result)->init(thd)) + DBUG_RETURN(1); + thd->abort_on_warning= !ignore && thd->is_strict_mode(); List<Item> total_list; + if (setup_tables(thd, &select_lex->context, &select_lex->top_join_list, + table_list, select_lex->leaf_tables, FALSE, FALSE)) + DBUG_RETURN(1); + if (select_lex->vers_setup_conds(thd, table_list)) DBUG_RETURN(1); + res= mysql_select(thd, table_list, total_list, conds, select_lex->order_list.elements, @@ -1957,6 +1978,20 @@ multi_update::multi_update(THD *thd_arg, TABLE_LIST *table_list, { } +bool multi_update::init(THD *thd) +{ + table_map tables_to_update= get_table_map(fields); + List_iterator_fast<TABLE_LIST> li(*leaves); + TABLE_LIST *tbl; + while ((tbl =li++)) + { + if (!(tbl->table->map & tables_to_update)) + continue; + if (updated_leaves.push_back(tbl, thd->mem_root)) + return true; + } + return false; +} /* Connect fields with tables and create list of tables that are updated @@ -1974,7 +2009,7 @@ int multi_update::prepare(List<Item> ¬_used_values, List_iterator_fast<Item> value_it(*values); uint i, max_fields; uint leaf_table_count= 0; - List_iterator<TABLE_LIST> ti(*leaves); + List_iterator<TABLE_LIST> ti(updated_leaves); DBUG_ENTER("multi_update::prepare"); if (prepared) @@ -2000,16 +2035,10 @@ int multi_update::prepare(List<Item> ¬_used_values, */ while ((table_ref= ti++)) { - if (table_ref->is_jtbm()) - continue; - TABLE *table= table_ref->table; - if (tables_to_update & table->map) - { - DBUG_ASSERT(table->read_set == &table->def_read_set); - table->read_set= &table->tmp_set; - bitmap_clear_all(table->read_set); - } + DBUG_ASSERT(table->read_set == &table->def_read_set); + table->read_set= &table->value_set; + bitmap_clear_all(table->read_set); } /* @@ -2023,16 +2052,10 @@ int multi_update::prepare(List<Item> ¬_used_values, ti.rewind(); while ((table_ref= ti++)) { - if (table_ref->is_jtbm()) - continue; - TABLE *table= table_ref->table; - if (tables_to_update & table->map) - { - table->read_set= &table->def_read_set; - bitmap_union(table->read_set, &table->tmp_set); - table->file->prepare_for_insert(1); - } + table->read_set= &table->def_read_set; + bitmap_union(table->read_set, &table->value_set); + table->file->prepare_for_insert(1); } if (unlikely(error)) DBUG_RETURN(1); @@ -2047,25 +2070,26 @@ int multi_update::prepare(List<Item> ¬_used_values, ti.rewind(); while ((table_ref= ti++)) { - /* TODO: add support of view of join support */ + TABLE *table=table_ref->table; + TABLE_LIST *tl= (TABLE_LIST*) thd->memdup(table_ref, + sizeof(*tl)); + if (!tl) + DBUG_RETURN(1); + update.link_in_list(tl, &tl->next_local); + tl->shared= table_count++; + table->no_keyread=1; + table->covering_keys.clear_all(); + table->pos_in_table_list= tl; + table->prepare_triggers_for_update_stmt_or_event(); + table->reset_default_fields(); + } + + List_iterator_fast<TABLE_LIST> li(*leaves); + while ((table_ref= li++)) + { if (table_ref->is_jtbm()) continue; - TABLE *table=table_ref->table; leaf_table_count++; - if (tables_to_update & table->map) - { - TABLE_LIST *tl= (TABLE_LIST*) thd->memdup(table_ref, - sizeof(*tl)); - if (!tl) - DBUG_RETURN(1); - update.link_in_list(tl, &tl->next_local); - tl->shared= table_count++; - table->no_keyread=1; - table->covering_keys.clear_all(); - table->pos_in_table_list= tl; - table->prepare_triggers_for_update_stmt_or_event(); - table->reset_default_fields(); - } } table_count= update.elements; @@ -2126,7 +2150,7 @@ void multi_update::update_used_tables() } } -void multi_update::prepare_to_read_rows() +void multi_update::prepare_to_read_rows(THD *thd) { /* update column maps now. it cannot be done in ::prepare() before the @@ -2196,7 +2220,7 @@ static bool safe_update_on_fly(THD *thd, JOIN_TAB *join_tab, case JT_REF_OR_NULL: return !is_key_used(table, join_tab->ref.key, table->write_set); case JT_ALL: - if (bitmap_is_overlapping(&table->tmp_set, table->write_set)) + if (bitmap_is_overlapping(&table->value_set, table->write_set)) return FALSE; /* If range search on index */ if (join_tab->quick) @@ -2227,6 +2251,7 @@ bool multi_update::initialize_tables(JOIN *join) { TABLE_LIST *table_ref; + table_map all_tables_to_update= get_table_map(fields); DBUG_ENTER("initialize_tables"); if (unlikely((thd->variables.option_bits & OPTION_SAFE_UPDATES) && @@ -2249,6 +2274,8 @@ multi_update::initialize_tables(JOIN *join) for (table_ref= update_tables; table_ref; table_ref= table_ref->next_local) { TABLE *table=table_ref->table; + if (!(table->map & all_tables_to_update)) + continue; uint cnt= table_ref->shared; List<Item> temp_fields; ORDER group; @@ -2459,11 +2486,14 @@ multi_update::~multi_update() int multi_update::send_data(List<Item> ¬_used_values) { TABLE_LIST *cur_table; + table_map all_tables_to_update= get_table_map(fields); DBUG_ENTER("multi_update::send_data"); for (cur_table= update_tables; cur_table; cur_table= cur_table->next_local) { TABLE *table= cur_table->table; + if (!(table->map & all_tables_to_update)) + continue; uint offset= cur_table->shared; /* Check if we are using outer join and we didn't find the row @@ -2682,6 +2712,7 @@ void multi_update::abort_result_set() int multi_update::do_updates() { TABLE_LIST *cur_table; + table_map all_tables_to_update= get_table_map(fields); int local_error= 0; ha_rows org_updated; TABLE *table, *tmp_table, *err_table; @@ -2710,8 +2741,12 @@ int multi_update::do_updates() uint offset= cur_table->shared; table = cur_table->table; + if (!(table->map & all_tables_to_update)) + continue; if (table == table_to_update) + { continue; // Already updated + } org_updated= updated; tmp_table= tmp_tables[cur_table->shared]; tmp_table->file->extra(HA_EXTRA_CACHE); // Change to read cache diff --git a/sql/sql_view.cc b/sql/sql_view.cc index 6666f2e..0863beb 100644 --- a/sql/sql_view.cc +++ b/sql/sql_view.cc @@ -34,7 +34,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() +#include "sql_cte.h" // check_cte_dependencies_and_resolve_references() #include "opt_trace.h" #include "wsrep_mysqld.h" @@ -429,12 +429,6 @@ 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(lex->with_clauses_list)) - { - res= TRUE; - goto err_no_relink; - } - WSREP_TO_ISOLATION_BEGIN(WSREP_MYSQL_DB, NULL, NULL); /* @@ -1104,6 +1098,7 @@ static int mysql_register_view(THD *thd, TABLE_LIST *view, goto err; } +#if 0 /* Check that table of main select do not used in subqueries. @@ -1123,6 +1118,7 @@ static int mysql_register_view(THD *thd, TABLE_LIST *view, { view->updatable_view= 0; } +#endif if (view->with_check != VIEW_CHECK_NONE && !view->updatable_view) @@ -1417,9 +1413,6 @@ 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->lex->with_clauses_list)) - goto err; - /* Check rights to run commands which show underlying tables. In the optimizer trace we would not like to show trace for diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index d8ad3ae..bcc68c4 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -268,6 +268,8 @@ void _CONCAT_UNDERSCORED(turn_parser_debug_on,yyparse)() class sp_head *sphead; class sp_name *spname; class sp_variable *spvar; +/* class Query_name *query_name; */ + class With_element_head *with_element_head; class With_clause *with_clause; class Virtual_column_info *virtual_column; @@ -1747,9 +1749,11 @@ End SQL_MODE_ORACLE_SPECIFIC */ '-' '+' '*' '/' '%' '(' ')' ',' '!' '{' '}' '&' '|' -%type <with_clause> with_clause +%type <with_clause> with_clause opt_with_clause -%type <lex_str_ptr> query_name +/* %type <query_name> query_name*/ +/* %type <lex_str_ptr> query_name */ +%type <with_element_head> with_element_head %type <ident_sys_list> comma_separated_ident_list @@ -3741,6 +3745,8 @@ expr_lex: $$= $<expr_lex>1; $$->sp_lex_in_use= true; $$->set_item($2); + if ($$->check_cte_dependencies_and_resolve_references()) + MYSQL_YYABORT; if ($$->sphead->restore_lex(thd)) MYSQL_YYABORT; } @@ -4628,7 +4634,7 @@ create_select_query_expression: | LEFT_PAREN_WITH with_clause query_expression_no_with_clause ')' { SELECT_LEX *first_select= $3->first_select(); - $3->set_with_clause($2); + $3->set_with_clause(Lex, $2); $2->attach_to(first_select); if (Lex->parsed_insert_select(first_select)) MYSQL_YYABORT; @@ -8524,7 +8530,7 @@ select: opt_procedure_or_into { Lex->pop_select(); - $1->set_with_clause(NULL); + $1->set_with_clause(Lex, NULL); if (Lex->select_finalize($1, $3)) MYSQL_YYABORT; } @@ -8538,7 +8544,7 @@ select: opt_procedure_or_into { Lex->pop_select(); - $2->set_with_clause($1); + $2->set_with_clause(Lex, $1); $1->attach_to($2->first_select()); if (Lex->select_finalize($2, $4)) MYSQL_YYABORT; @@ -8574,7 +8580,7 @@ select_into: MYSQL_YYABORT; if ($4) unit= Lex->add_tail_to_query_expression_body(unit, $4); - unit->set_with_clause($1); + unit->set_with_clause(Lex, $1); $1->attach_to($2); if (Lex->select_finalize(unit)) MYSQL_YYABORT; @@ -8698,13 +8704,13 @@ select_into_query_specification: query_expression: query_expression_no_with_clause { - $1->set_with_clause(NULL); + $1->set_with_clause(Lex, NULL); $$= $1; } | with_clause query_expression_no_with_clause { - $2->set_with_clause($1); + $2->set_with_clause(Lex, $1); $1->attach_to($2->first_select()); $$= $2; } @@ -8883,7 +8889,7 @@ subquery: } | '(' with_clause query_expression_no_with_clause ')' { - $3->set_with_clause($2); + $3->set_with_clause(Lex, $2); $2->attach_to($3->first_select()); if (!($$= Lex->parsed_subselect($3))) YYABORT; @@ -13094,7 +13100,7 @@ update_table_list: /* Update rows in a table */ update: - UPDATE_SYM + opt_with_clause UPDATE_SYM { LEX *lex= Lex; if (Lex->main_select_push()) @@ -13109,24 +13115,23 @@ update: SELECT_LEX *slex= Lex->first_select_lex(); if (slex->table_list.elements > 1) Lex->sql_command= SQLCOM_UPDATE_MULTI; - else if (slex->get_table_list()->derived) - { - /* it is single table update and it is update of derived table */ - my_error(ER_NON_UPDATABLE_TABLE, MYF(0), - slex->get_table_list()->alias.str, "UPDATE"); - MYSQL_YYABORT; - } /* In case of multi-update setting write lock for all tables may be too pessimistic. We will decrease lock level if possible in mysql_multi_update(). */ - slex->set_lock_for_tables($3, slex->table_list.elements == 1); + slex->set_lock_for_tables($4, slex->table_list.elements == 1); + if ($1) + { + st_select_lex_unit *unit= Lex->current_select->master_unit(); + unit->set_with_clause(Lex, $1); + $1->attach_to(unit->first_select()); + } } opt_where_clause opt_order_clause delete_limit_clause { - if ($10) - Select->order_list= *($10); + if ($11) + Select->order_list= *($11); } stmt_end {} ; @@ -13167,7 +13172,7 @@ opt_low_priority: /* Delete rows from a table */ delete: - DELETE_SYM + opt_with_clause DELETE_SYM { LEX *lex= Lex; lex->sql_command= SQLCOM_DELETE; @@ -13178,6 +13183,12 @@ delete: mysql_init_select(lex); lex->ignore= 0; lex->first_select_lex()->order_list.empty(); + if ($1) + { + st_select_lex_unit *unit= Lex->current_select->master_unit(); + unit->set_with_clause(Lex, $1); + $1->attach_to(unit->first_select()); + } } delete_part2 { } @@ -13224,6 +13235,9 @@ delete_single_table_for_period: if ($2) Lex->last_table()->period_conditions= Lex->period_conditions; } +/* + | FROM table_primary_derived +*/ ; single_multi: @@ -14780,15 +14794,22 @@ temporal_literal: } ; +opt_with_clause: + /* empty */ { $$= 0; } + | with_clause { $$= $1; } + ; + with_clause: WITH opt_recursive { LEX *lex= Lex; With_clause *with_clause= new With_clause($2, Lex->curr_with_clause); + with_clause->set_tables_start_pos(lex->query_tables_last); if (unlikely(with_clause == NULL)) MYSQL_YYABORT; lex->derived_tables|= DERIVED_WITH; + lex->with_cte_resolution= true; lex->curr_with_clause= with_clause; with_clause->add_to_list(Lex->with_clauses_list_last_next); if (lex->current_select && @@ -14798,6 +14819,7 @@ with_clause: with_list { $$= Lex->curr_with_clause; + Lex->curr_with_clause->set_tables_end_pos(Lex->query_tables_last); Lex->curr_with_clause= Lex->curr_with_clause->pop(); } ; @@ -14816,7 +14838,7 @@ with_list: with_list_element: - query_name + with_element_head opt_with_column_list AS '(' query_expression ')' opt_cycle { @@ -14830,6 +14852,7 @@ with_list_element: if (elem->set_unparsed_spec(thd, spec_start, $6.pos(), spec_start - query_start)) MYSQL_YYABORT; + elem->set_tables_end_pos(lex->query_tables_last); if ($7) { elem->set_cycle_list($7); @@ -14894,12 +14917,15 @@ comma_separated_ident_list: ; -query_name: +with_element_head: ident { - $$= (LEX_CSTRING *) thd->memdup(&$1, sizeof(LEX_CSTRING)); - if (unlikely($$ == NULL)) + LEX_CSTRING *name= + (LEX_CSTRING *) thd->memdup(&$1, sizeof(LEX_CSTRING)); + $$= new (thd->mem_root) With_element_head(name); + if (unlikely(name == NULL || $$ == NULL)) MYSQL_YYABORT; + $$->tables_pos.set_start_pos(Lex->query_tables_last); } ; diff --git a/sql/table.cc b/sql/table.cc index bec89db..8bc5fe7 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -4139,7 +4139,7 @@ enum open_frm_error open_table_from_share(THD *thd, TABLE_SHARE *share, /* Allocate bitmaps */ bitmap_size= share->column_bitmap_size; - bitmap_count= 7; + bitmap_count= 8; if (share->virtual_fields) bitmap_count++; @@ -4166,6 +4166,9 @@ enum open_frm_error open_table_from_share(THD *thd, TABLE_SHARE *share, my_bitmap_init(&outparam->cond_set, (my_bitmap_map*) bitmaps, share->fields, FALSE); bitmaps+= bitmap_size; + my_bitmap_init(&outparam->value_set, + (my_bitmap_map*) bitmaps, share->fields, FALSE); + bitmaps+= bitmap_size; my_bitmap_init(&outparam->def_rpl_write_set, (my_bitmap_map*) bitmaps, share->fields, FALSE); outparam->default_column_bitmaps(); @@ -5609,7 +5612,7 @@ bool TABLE_LIST::setup_underlying(THD *thd) { DBUG_ENTER("TABLE_LIST::setup_underlying"); - if (!view || (!field_translation && merge_underlying_list)) + if (!field_translation && merge_underlying_list) { SELECT_LEX *select= get_single_select(); @@ -5722,141 +5725,163 @@ bool TABLE_LIST::prep_where(THD *thd, Item **conds, @return Result of the check. */ -bool TABLE_LIST::single_table_updatable() +bool TABLE_LIST::single_table_updatable(THD *thd) { - if (!updatable) + if (!updatable || + (is_derived() && !optimizer_flag(thd, OPTIMIZER_SWITCH_DERIVED_MERGE))) return false; - if (view && view->first_select_lex()->table_list.elements == 1) + if (is_view_or_derived() && + get_unit()->first_select()->table_list.elements == 1) { /* We need to check deeply only single table views. Multi-table views will be turned to multi-table updates and then checked by leaf tables */ - return (((TABLE_LIST *)view->first_select_lex()->table_list.first)-> - single_table_updatable()); + TABLE_LIST *first= (TABLE_LIST *)get_unit()->first_select()->table_list.first; + bool res= first->single_table_updatable(thd); + return res; } return true; } -/* - Merge ON expressions for a view +/** + Return merged WHERE clause and join conditions for a view - SYNOPSIS - merge_on_conds() - thd thread handle - table table for the VIEW - is_cascaded TRUE <=> merge ON expressions from underlying views + @param thd thread handle + @param table table for the VIEW + @param[out] pcond Pointer to the built condition (NULL if none) - DESCRIPTION - This function returns the result of ANDing the ON expressions - of the given view and all underlying views. The ON expressions - of the underlying views are added only if is_cascaded is TRUE. + This function returns the result of ANDing the WHERE clause and the + join conditions of the given view. - RETURN - Pointer to the built expression if there is any. - Otherwise and in the case of a failure NULL is returned. + @returns false for success, true for error */ -static Item * -merge_on_conds(THD *thd, TABLE_LIST *table, bool is_cascaded) +static bool merge_join_conditions(THD *thd, TABLE_LIST *table, Item **pcond) { - DBUG_ENTER("merge_on_conds"); - - Item *cond= NULL; - DBUG_PRINT("info", ("alias: %s", table->alias.str)); - if (table->on_expr) - cond= table->on_expr->copy_andor_structure(thd); - if (!table->view) - DBUG_RETURN(cond); - for (TABLE_LIST *tbl= - (TABLE_LIST*)table->view->first_select_lex()->table_list.first; - tbl; - tbl= tbl->next_local) + DBUG_ENTER("merge_join_conditions"); + *pcond = NULL; + DBUG_PRINT("info", ("alias: %s", table->alias)); + if (table->where) + { + if (!(*pcond = table->where->copy_andor_structure(thd))) + DBUG_RETURN(true); /* purecov: inspected */ + } + else if (table->on_expr) + { + if (!(*pcond = table->on_expr->copy_andor_structure(thd))) + DBUG_RETURN(true); /* purecov: inspected */ + } + if (!table->nested_join && !table->is_merged_derived()) + DBUG_RETURN(false); + List<TABLE_LIST> *join_list= table->is_merged_derived() ? + table->get_unit()->first_select()->join_list : + &table->nested_join->join_list; + List_iterator<TABLE_LIST> li(*join_list); + while (TABLE_LIST *tbl = li++) { - if (tbl->view && !is_cascaded) + if (tbl->is_view()) continue; - cond= and_conds(thd, cond, merge_on_conds(thd, tbl, is_cascaded)); + Item *cond; + if (merge_join_conditions(thd, tbl, &cond)) + DBUG_RETURN(true); /* purecov: inspected */ + if (cond && !(*pcond = and_conds(thd, *pcond, cond))) + DBUG_RETURN(true); /* purecov: inspected */ } - DBUG_RETURN(cond); + DBUG_RETURN(false); } -/* +/** Prepare check option expression of table - SYNOPSIS - TABLE_LIST::prep_check_option() - thd - thread handler - check_opt_type - WITH CHECK OPTION type (VIEW_CHECK_NONE, - VIEW_CHECK_LOCAL, VIEW_CHECK_CASCADED) - we use this parameter instead of direct check of - effective_with_check to change type of underlying - views to VIEW_CHECK_CASCADED if outer view have - such option and prevent processing of underlying - view check options if outer view have just - VIEW_CHECK_LOCAL option. + @param thd thread handler + @param is_cascaded True if parent view requests that this view's + filtering condition be treated as WITH CASCADED CHECK OPTION; this is for + recursive calls; user code should omit this argument. - NOTE - This method builds check option condition to use it later on - every call (usual execution or every SP/PS call). - This method have to be called after WHERE preparation - (TABLE_LIST::prep_where) + @details - RETURN - FALSE - OK - TRUE - error + This function builds check option condition for use in regular execution or + subsequent SP/PS executions. + + This function must be called after the WHERE clause and join condition + of this and all underlying derived tables/views have been resolved. + + The function will always call itself recursively for all underlying views + and base tables. + + On first invocation, the check option condition is built bottom-up in + statement mem_root, and check_option_processed is set true. + + On subsequent executions, check_option_processed is true and no + expression building is necessary. However, the function needs to assure that + the expression is resolved by calling fix_fields() on it. + + @returns false if success, true if error */ bool TABLE_LIST::prep_check_option(THD *thd, uint8 check_opt_type) { DBUG_ENTER("TABLE_LIST::prep_check_option"); - bool is_cascaded= check_opt_type == VIEW_CHECK_CASCADED; - TABLE_LIST *merge_underlying_list= view->first_select_lex()->get_table_list(); - for (TABLE_LIST *tbl= merge_underlying_list; tbl; tbl= tbl->next_local) + DBUG_ASSERT(is_view_or_derived()); + + /* + True if conditions of underlying views should be treated as WITH CASCADED + CHECK OPTION + */ + for (TABLE_LIST *tbl = merge_underlying_list; tbl; tbl = tbl->next_local) { - /* see comment of check_opt_type parameter */ - if (tbl->view && tbl->prep_check_option(thd, (is_cascaded ? - VIEW_CHECK_CASCADED : - VIEW_CHECK_NONE))) - DBUG_RETURN(TRUE); + if (!tbl->is_view_or_derived()) + continue; + uint8 next_check_opt_type= tbl->with_check; + if (tbl->is_derived() || check_opt_type == VIEW_CHECK_CASCADED) + next_check_opt_type= check_opt_type; + if (tbl->is_view() && + tbl->prep_check_option(thd, next_check_opt_type)) + DBUG_RETURN(true); /* purecov: inspected */ } - if (check_opt_type && !check_option_processed) + if (check_opt_type != VIEW_CHECK_NONE && !check_option_processed) { Query_arena *arena= thd->stmt_arena, backup; arena= thd->activate_stmt_arena_if_needed(&backup); // For easier test - if (where) + if (merge_join_conditions(thd, this, &check_option)) + DBUG_RETURN(true); + + for (TABLE_LIST *tbl = merge_underlying_list; tbl; tbl = tbl->next_local) { - check_option= where->copy_andor_structure(thd); + if (tbl->check_option && + !(check_option = and_conds(thd, check_option, tbl->check_option))) + DBUG_RETURN(true); /* purecov: inspected */ } - if (is_cascaded) + + if (check_option) { - for (TABLE_LIST *tbl= merge_underlying_list; tbl; tbl= tbl->next_local) + Item *clone= check_option->build_clone(thd); + // DBUG_ASSERT(clone); + if (clone) { - if (tbl->check_option) - check_option= and_conds(thd, check_option, tbl->check_option); + check_option= clone; + check_option->cleanup(); } } - check_option= and_conds(thd, check_option, - merge_on_conds(thd, this, is_cascaded)); - if (arena) thd->restore_active_arena(arena, &backup); - check_option_processed= TRUE; - + check_option_processed= true; } - if (check_option) - { - const char *save_where= thd->where; - thd->where= "check option"; + if (check_option) { + const char *save_where = thd->where; + thd->where = "check option"; if (check_option->fix_fields_if_needed_for_bool(thd, &check_option)) - DBUG_RETURN(TRUE); - thd->where= save_where; + DBUG_RETURN(true); /* purecov: inspected */ + thd->where = save_where; } - DBUG_RETURN(FALSE); + + DBUG_RETURN(false); } @@ -6470,6 +6495,8 @@ void TABLE_LIST::set_check_merged() !derived->first_select()->exclude_from_table_unique_test || derived->outer_select()-> exclude_from_table_unique_test); + if (is_derived()) + grant.privilege= ALL_KNOWN_ACL; } #endif @@ -6654,7 +6681,7 @@ LEX_CSTRING *Field_iterator_table::name() Item *Field_iterator_table::create_item(THD *thd) { - SELECT_LEX *select= thd->lex->current_select; + SELECT_LEX *select= table->select_lex; Item_field *item= new (thd->mem_root) Item_field(thd, &select->context, *ptr); DBUG_ASSERT(strlen(item->name.str) == item->name.length); @@ -6715,9 +6742,14 @@ Item *create_view_field(THD *thd, TABLE_LIST *view, Item **field_ref, { DBUG_RETURN(field); } - Name_resolution_context *context= (view->view ? - &view->view->first_select_lex()->context: - &thd->lex->first_select_lex()->context); + Name_resolution_context *context; + if (view->is_view()) + context= &view->view->first_select_lex()->context; + else if (view->is_derived()) + context= &view->derived->first_select()->context; + else + context= &thd->lex->first_select_lex()->context; + Item *item= (new (thd->mem_root) Item_direct_view_ref(thd, context, field_ref, view->alias, *name, view)); @@ -6788,7 +6820,10 @@ void Field_iterator_table_ref::set_field_iterator() table_ref->alias.str)); } /* This is a merge view, so use field_translation. */ - else if (table_ref->field_translation) + else if (table_ref->field_translation && + !(table_ref->is_view_or_derived() && + table_ref->select_lex->master_unit()-> + thd->lex->context_analysis_only & CONTEXT_ANALYSIS_ONLY_PREPARE)) { DBUG_ASSERT(table_ref->is_merged_derived()); field_it= &view_field_it; @@ -6798,7 +6833,7 @@ void Field_iterator_table_ref::set_field_iterator() /* This is a base table or stored view. */ else { - DBUG_ASSERT(table_ref->table || table_ref->view); + DBUG_ASSERT(table_ref->table || table_ref->view || table_ref->is_merged_derived()); field_it= &table_field_it; DBUG_PRINT("info", ("field_it for '%s' is Field_iterator_table", table_ref->alias.str)); @@ -6841,7 +6876,11 @@ const char *Field_iterator_table_ref::get_table_name() if (table_ref->view) return table_ref->view_name.str; if (table_ref->is_derived()) + { + if (table_ref->is_merged_derived()) + return table_ref->alias.str; return table_ref->table->s->table_name.str; + } else if (table_ref->is_natural_join) return natural_join_it.column_ref()->safe_table_name(); @@ -6856,6 +6895,8 @@ const char *Field_iterator_table_ref::get_db_name() { if (table_ref->view) return table_ref->view_db.str; + if (table_ref->is_merged_derived()) + return 0; else if (table_ref->is_natural_join) return natural_join_it.column_ref()->safe_db_name(); @@ -9180,13 +9221,14 @@ bool TABLE_LIST::init_derived(THD *thd, bool init_view) /* A subquery might be forced to be materialized due to a side-effect. */ if (!is_materialized_derived() && first_select->is_mergeable() && optimizer_flag(thd, OPTIMIZER_SWITCH_DERIVED_MERGE) && - !thd->lex->can_not_use_merged() && - !(thd->lex->sql_command == SQLCOM_UPDATE_MULTI || - thd->lex->sql_command == SQLCOM_DELETE_MULTI) && + (!thd->lex->can_not_use_merged() || is_derived()) && !is_recursive_with_table()) set_merged_derived(); else + { + merge_underlying_list= 0; set_materialized_derived(); + } } /* Derived tables/view are materialized prior to UPDATE, thus we can skip @@ -9196,7 +9238,34 @@ bool TABLE_LIST::init_derived(THD *thd, bool init_view) { set_check_materialized(); } + else if ((is_derived()) && + (updatable= unit->first_select()->is_mergeable())) + { + List_iterator<Item> it(first_select->item_list); + Item *item; + bool updatable_field= false; + while ((item= it++)) + { + if (item->real_item()->type() == Item::FIELD_ITEM) + updatable_field= true; + } + bool underlying_updatable_table= false; + for (TABLE_LIST *tbl= unit->first_select()->table_list.first; + tbl; tbl= tbl->next_local) + { + if ((tbl->is_view() && !tbl->updatable_view) || + (tbl->is_derived() && !tbl->updatable) || + !tbl->updatable || tbl->schema_table) + continue; + underlying_updatable_table= true; + break; + } + updatable= underlying_updatable_table && updatable_field; + } + int rc= 0; + if (!thd->lex->can_use_merged()) + merge_underlying_list= 0; /* Create field translation for mergeable derived tables/views. For derived tables field translation can be created only after @@ -9207,10 +9276,10 @@ bool TABLE_LIST::init_derived(THD *thd, bool init_view) if (is_view() || (unit->prepared && !(thd->lex->context_analysis_only & CONTEXT_ANALYSIS_ONLY_VIEW))) - create_field_translation(thd); + rc= create_field_translation(thd); } - return FALSE; + return MY_TEST(rc); } diff --git a/sql/table.h b/sql/table.h index f2fad6c..fc4ec1f 100644 --- a/sql/table.h +++ b/sql/table.h @@ -1306,6 +1306,7 @@ struct TABLE MY_BITMAP def_rpl_write_set; MY_BITMAP eq_join_set; /* used to mark equi-joined fields */ MY_BITMAP cond_set; /* used to mark fields from sargable conditions*/ + MY_BITMAP value_set; /* Active column sets */ MY_BITMAP *read_set, *write_set, *rpl_write_set; /* On INSERT: fields that the user specified a value for */ @@ -1690,7 +1691,6 @@ struct TABLE best_range_rowid_filter_for_partial_join(uint access_key_no, double records, double access_cost_factor); - /** System Versioning support */ @@ -2100,6 +2100,20 @@ struct vers_select_conds_t struct LEX; class Index_hint; + + +struct TABLE_CHAIN +{ + TABLE_CHAIN() {} + + TABLE_LIST **start_pos; + TABLE_LIST ** end_pos; + + void set_start_pos(TABLE_LIST **pos) { start_pos= pos; } + void set_end_pos(TABLE_LIST **pos) { end_pos= pos; } +}; + + struct TABLE_LIST { TABLE_LIST() {} /* Remove gcc warning */ @@ -2187,6 +2201,7 @@ struct TABLE_LIST TABLE_LIST *next_local; /* link in a global list of all queries tables */ TABLE_LIST *next_global, **prev_global; + TABLE_LIST *next_ordered; LEX_CSTRING db; LEX_CSTRING table_name; LEX_CSTRING schema_table_name; @@ -2434,9 +2449,13 @@ struct TABLE_LIST /* call back function for asking handler about caching in query cache */ qc_engine_callback callback_func; thr_lock_type lock_type; + enum_mdl_type mdl_type; + ulong table_options; + bool is_mdl_request_type_to_be_set; uint outer_join; /* Which join type */ uint shared; /* Used in multi-upd */ bool updatable; /* VIEW/TABLE can be updated now */ + bool single_table_update; bool straight; /* optimize with prev table */ bool updating; /* for replicate-do/ignore table */ bool force_index; /* prefer index over table scan */ @@ -2612,10 +2631,10 @@ struct TABLE_LIST This is used for single-table UPDATE/DELETE when they are modifying a single-table VIEW. */ - TABLE_LIST *find_table_for_update() + TABLE_LIST *find_table_for_update(THD *thd) { TABLE_LIST *tbl= this; - while(!tbl->is_multitable() && tbl->single_table_updatable() && + while(!tbl->is_multitable() && tbl->single_table_updatable(thd) && tbl->merge_underlying_list) { tbl= tbl->merge_underlying_list; @@ -2737,6 +2756,7 @@ struct TABLE_LIST (derived ? DTYPE_MASK : DTYPE_VIEW)) | DTYPE_TABLE | DTYPE_MATERIALIZE); set_check_materialized(); + field_translation= 0; DBUG_VOID_RETURN; } bool is_multitable() const { return (derived_type & DTYPE_MULTITABLE); } @@ -2744,9 +2764,9 @@ struct TABLE_LIST { derived_type|= DTYPE_MULTITABLE; } - bool set_as_with_table(THD *thd, With_element *with_elem); void reset_const_table(); bool handle_derived(LEX *lex, uint phases); + void propagate_properties_for_mergeable_derived(); /** @brief True if this TABLE_LIST represents an anonymous derived table, @@ -2776,7 +2796,7 @@ struct TABLE_LIST int fetch_number_of_rows(); bool change_refs_to_fields(); - bool single_table_updatable(); + bool single_table_updatable(THD *thd); bool is_inner_table_of_outer_join() { @@ -2826,7 +2846,7 @@ class Item; class Field_iterator: public Sql_alloc { public: - Field_iterator() {} /* Remove gcc warning */ + Field_iterator() {} /* Remove gcc warning */ virtual ~Field_iterator() {} virtual void set(TABLE_LIST *)= 0; virtual void next()= 0; @@ -2845,9 +2865,10 @@ class Field_iterator: public Sql_alloc class Field_iterator_table: public Field_iterator { Field **ptr; + TABLE_LIST *table; public: - Field_iterator_table() :ptr(0) {} - void set(TABLE_LIST *table) { ptr= table->table->field; } + Field_iterator_table() :ptr(0), table(0) {} + void set(TABLE_LIST *tl) { table= tl; ptr= tl->table->field; } void set_table(TABLE *table) { ptr= table->field; } void next() { ptr++; } bool end_of_fields() { return *ptr == 0; }
participants (1)
-
IgorBabaev