From d57c44f62635d6afe026345c11b13f543741e83e Mon Sep 17 00:00:00 2001 From: Igor Babaev Date: Tue, 20 Feb 2024 22:05:00 -0800 Subject: [PATCH] MDEV-31277 Wrong result on 2-nd execution of PS to select from view using derived As a result of this bug the second execution of the prepared statement created for select from materialized view could return a wrong result set if - the specification of the view used a left join - an inner table the left join was a mergeable derived table - the derived table contained a constant column. The problem appeared because the flag 'maybe-null' of the wrapper Item_direct_view_ref constructed for the constant field of the mergeable derived table was not set to 'true' on the second execution of the prepared statement. The patch always sets this flag properly when calling the function Item_direct_view_ref::set_null_ref-table(). The latter is invoked in Item_direct_view_ref constructor if it is created for some reference of a constant column belonging to a mergeable derived table. Approved by Oleksandr Byelkin --- mysql-test/main/derived_view.result | 32 +++++++++++++++++++++++++ mysql-test/main/derived_view.test | 36 +++++++++++++++++++++++++++++ mysql-test/main/join_outer.test | 12 ---------- sql/item.h | 2 ++ 4 files changed, 70 insertions(+), 12 deletions(-) diff --git a/mysql-test/main/derived_view.result b/mysql-test/main/derived_view.result index c2fe217ee97..64113cbe403 100644 --- a/mysql-test/main/derived_view.result +++ b/mysql-test/main/derived_view.result @@ -4250,3 +4250,35 @@ dim1 dim2 dim3 p SUM(p) 100 10 1 2 371 DROP VIEW v; # End of 10.4 tests +# +# MDEV-31277: 2-nd execution of PS to select from materialized view +# specified as left join whose inner table is mergeable +# derived containing a constant column +# +create table t1 ( +Election int(10) unsigned NOT NULL +) engine=MyISAM; +insert into t1 (Election) values (1), (4); +create table t2 ( +VoteID int(10), +ElectionID int(10), +UserID int(10) +); +insert into t2 (ElectionID, UserID) values (2, 30), (3, 30); +create view v1 as select * from t1 +left join ( select 'Y' AS Voted, ElectionID from t2 ) AS T +on T.ElectionID = t1.Election +limit 9; +prepare stmt1 from "select * from v1"; +execute stmt1; +Election Voted ElectionID +1 NULL NULL +4 NULL NULL +execute stmt1; +Election Voted ElectionID +1 NULL NULL +4 NULL NULL +deallocate prepare stmt1; +drop view v1; +drop table t1, t2; +# End of 10.5 tests diff --git a/mysql-test/main/derived_view.test b/mysql-test/main/derived_view.test index f9ab0443bc0..9747f1df61f 100644 --- a/mysql-test/main/derived_view.test +++ b/mysql-test/main/derived_view.test @@ -2832,3 +2832,39 @@ SELECT d.*, SUM(p) FROM demo d; DROP VIEW v; --echo # End of 10.4 tests + +--echo # +--echo # MDEV-31277: 2-nd execution of PS to select from materialized view +--echo # specified as left join whose inner table is mergeable +--echo # derived containing a constant column +--echo # + +create table t1 ( + Election int(10) unsigned NOT NULL +) engine=MyISAM; + +insert into t1 (Election) values (1), (4); + +create table t2 ( + VoteID int(10), + ElectionID int(10), + UserID int(10) +); + +insert into t2 (ElectionID, UserID) values (2, 30), (3, 30); +create view v1 as select * from t1 + left join ( select 'Y' AS Voted, ElectionID from t2 ) AS T + on T.ElectionID = t1.Election +limit 9; + +prepare stmt1 from "select * from v1"; + +execute stmt1; +execute stmt1; + +deallocate prepare stmt1; + +drop view v1; +drop table t1, t2; + +--echo # End of 10.5 tests diff --git a/mysql-test/main/join_outer.test b/mysql-test/main/join_outer.test index 857a9ced41b..da3c82109d8 100644 --- a/mysql-test/main/join_outer.test +++ b/mysql-test/main/join_outer.test @@ -2372,11 +2372,8 @@ create view v1 as select * from t1 left join ( select 'Y' AS Voted, ElectionID from t2 ) AS T on T.ElectionID = t1.Election limit 9; -#enable after fix MDEV-31277 ---disable_ps2_protocol # limit X causes merge algorithm select as opposed to temp table select * from v1; ---enable_ps2_protocol drop table t1, t2; drop view v1; @@ -2391,10 +2388,7 @@ create view v10 as select *, 'U' as u from t10 left join (select 'Y' as y, t20.b create table t30 (c int); insert into t30 values (1),(3); create view v20 as select * from t30 left join (select 'X' as x, v10.u, v10.y, v10.b from v10) dt2 on t30.c=dt2.b limit 6; -#check after fix MDEV-31277 ---disable_ps2_protocol select * from v20 limit 9; ---enable_ps2_protocol drop view v10, v20; drop table t10, t20, t30; @@ -2408,8 +2402,6 @@ insert into t3 values (3),(1); create table t1 (a int); insert into t1 values (1),(2),(7),(1); -#check after fix MDEV-31277 ---disable_ps2_protocol select * from ( select * from @@ -2422,7 +2414,6 @@ select * from on dt1.a=dt2.b limit 9 ) dt; ---enable_ps2_protocol ## Same as dt3 above create view v3(x,c) as select * from (select 'X' as x, t3.c from t3) dt3; @@ -2436,10 +2427,7 @@ create view v0(y,b,x,c) as select * from v2 left join v3 on v2.b=v3.c; # Same as above select statement create view v1 as select 'Z' as z, t1.a, v0.* from t1 left join v0 on t1.a=v0.b limit 9; -#check after fix MDEV-31277 ---disable_ps2_protocol select * from v1; ---enable_ps2_protocol set statement join_cache_level=0 for select * from v1; diff --git a/sql/item.h b/sql/item.h index c08671d46bb..f5c9ed2a7ab 100644 --- a/sql/item.h +++ b/sql/item.h @@ -5876,6 +5876,8 @@ class Item_direct_view_ref :public Item_direct_ref if (!view->is_inner_table_of_outer_join() || !(null_ref_table= view->get_real_join_table())) null_ref_table= NO_NULL_TABLE; + if (null_ref_table && null_ref_table != NO_NULL_TABLE) + maybe_null= true; } bool check_null_ref()