修复inlist to join + for update 场景下的宕机问题
根因分析: 在inlist to join优化中,如果被优化的目标表为for update/share的操作目标,处理逻辑有误 解决方案: (1)在inlist to join中,如果存在for update作用于基表,此时plan中的rowmarks会被标记为RowMarkRequiresRowShareLock,但是在 inist2join_qrw_optimization优化中,会将该目标表改为subquen加入到可选路径中,对于子查询而言,此时plan中的标记不能被标记为RowMarkRequiresRowshareLock, 应该被标记为仅引用或者复制,但此时尚未选择哪种路径(扫描基表或者子查询),也即无法确定rowmarks中的值,所以冲突,目前将此种场景下的优化禁止。 (2)在inlist to join中,如果for update作用于子查询,此时的rowmark跟变换成子查询后一致,可以继续进行优化。
This commit is contained in:
@ -165,6 +165,20 @@ void inlist2join_qrw_optimization(PlannerInfo* root, int rti)
|
||||
return;
|
||||
}
|
||||
|
||||
/*
|
||||
* if rowmarks effect on this rel is true lock,
|
||||
* bypass inlist optimize to avoid conflict
|
||||
*/
|
||||
ListCell* lc = NULL;
|
||||
foreach(lc, root->rowMarks) {
|
||||
PlanRowMark* rc = (PlanRowMark*)lfirst(lc);
|
||||
if ((int)rc->rti == rti) {
|
||||
if (RowMarkRequiresRowShareLock(rc->markType)) {
|
||||
return;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
* Return directly if inlist2join optimization can not apply to current rel,
|
||||
* [1]. When inlist2join optimization is not enabled
|
||||
|
@ -336,6 +336,109 @@ SELECT 1 FROM ( SELECT 1 FROM table1 WHERE NOT EXISTS ( SELECT 1 WHERE column63
|
||||
(1 row)
|
||||
|
||||
drop table table1;
|
||||
--test for update + inlist to join bug
|
||||
reset all;
|
||||
set current_schema = query_rewrite;
|
||||
set qrw_inlist2join_optmode = 'rule_base';
|
||||
create table test_forupdate(a int,b int,c text);
|
||||
create table test_helper(a int, b int, c text);
|
||||
insert into test_forupdate values(1,1,'test');
|
||||
insert into test_helper values(1,1,'bbbtest');
|
||||
explain (costs off) select * from test_forupdate where a in (1,2,3,4, 5,6,7,8,9,10,11,12);
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------
|
||||
Hash Join
|
||||
Hash Cond: (query_rewrite.test_forupdate.a = "*VALUES*".column1)
|
||||
-> Seq Scan on test_forupdate
|
||||
-> Hash
|
||||
-> HashAggregate
|
||||
Group By Key: "*VALUES*".column1
|
||||
-> Values Scan on "*VALUES*"
|
||||
(7 rows)
|
||||
|
||||
select * from test_forupdate where a in(1,2,3,4,5,6,7,8,9,10,11,12);
|
||||
a | b | c
|
||||
---+---+------
|
||||
1 | 1 | test
|
||||
(1 row)
|
||||
|
||||
--can not inlist to join
|
||||
explain (costs off) select * from test_forupdate where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
LockRows
|
||||
-> Seq Scan on test_forupdate
|
||||
Filter: (a = ANY ('{1,2,3,4,5,6,7,8,9,10,11,12}'::integer[]))
|
||||
(3 rows)
|
||||
|
||||
select * from test_forupdate where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
a | b | c
|
||||
---+---+------
|
||||
1 | 1 | test
|
||||
(1 row)
|
||||
|
||||
--not target table,ok
|
||||
explain (costs off) select * from test_forupdate,test_helper where test_forupdate.a in (1,2,3,4,5,6,7,8,9,10,11,12) for update of test_helper;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------------------------
|
||||
LockRows
|
||||
-> Nested Loop
|
||||
-> Seq Scan on test_helper
|
||||
-> Materialize
|
||||
-> Hash Join
|
||||
Hash Cond: (query_rewrite.test_forupdate.a = "*VALUES*".column1)
|
||||
-> Seq Scan on test_forupdate
|
||||
-> Hash
|
||||
-> HashAggregate
|
||||
Group By Key: "*VALUES*".column1
|
||||
-> Values Scan on "*VALUES*"
|
||||
(11 rows)
|
||||
|
||||
select * from test_forupdate,test_helper where test_forupdate.a in (1,2,3,4,5,6,7,8,9,10,11,12) for update of test_helper;
|
||||
a | b | c | a | b | c
|
||||
---+---+------+---+---+---------
|
||||
1 | 1 | test | 1 | 1 | bbbtest
|
||||
(1 row)
|
||||
|
||||
--subquery,target table,ok
|
||||
explain (costs off) select * from (select * from test_forupdate limit 1) where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------
|
||||
LockRows
|
||||
-> Subquery Scan on __unnamed_subquery__
|
||||
-> Hash Right Semi Join
|
||||
Hash Cond: ("*VALUES*".column1 = __unnamed_subquery__.a)
|
||||
-> Values Scan on "*VALUES*"
|
||||
-> Hash
|
||||
-> Subquery Scan on __unnamed_subquery__
|
||||
-> Limit
|
||||
-> LockRows
|
||||
-> Seq Scan on test_forupdate
|
||||
(10 rows)
|
||||
|
||||
select * from (select * from test_forupdate limit 1) where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
a | b | c
|
||||
---+---+------
|
||||
1 | 1 | test
|
||||
(1 row)
|
||||
|
||||
--test bug scene,concurrent update
|
||||
\parallel on 2
|
||||
begin
|
||||
set qrw_inlist2join_optmode = 'rule_base';
|
||||
perform pg_sleep(3);
|
||||
perform c,a from test_forupdate where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
end;
|
||||
/
|
||||
begin
|
||||
update test_forupdate set b=10 where a=1;
|
||||
perform pg_sleep(3);
|
||||
end;
|
||||
/
|
||||
\parallel off
|
||||
drop table test_forupdate;
|
||||
drop table test_helper;
|
||||
reset qrw_inlist2join_optmode;
|
||||
drop schema query_rewrite cascade;
|
||||
NOTICE: drop cascades to 7 other objects
|
||||
DETAIL: drop cascades to table t3
|
||||
|
@ -194,5 +194,47 @@ insert into table1 values(4,4);
|
||||
SELECT 1 FROM ( SELECT 1 FROM table1 WHERE NOT EXISTS ( SELECT 1 WHERE column63 = column44 ) ) AS alias1 ;
|
||||
drop table table1;
|
||||
|
||||
--test for update + inlist to join bug
|
||||
reset all;
|
||||
set current_schema = query_rewrite;
|
||||
set qrw_inlist2join_optmode = 'rule_base';
|
||||
|
||||
|
||||
create table test_forupdate(a int,b int,c text);
|
||||
create table test_helper(a int, b int, c text);
|
||||
insert into test_forupdate values(1,1,'test');
|
||||
insert into test_helper values(1,1,'bbbtest');
|
||||
|
||||
explain (costs off) select * from test_forupdate where a in (1,2,3,4, 5,6,7,8,9,10,11,12);
|
||||
select * from test_forupdate where a in(1,2,3,4,5,6,7,8,9,10,11,12);
|
||||
--can not inlist to join
|
||||
explain (costs off) select * from test_forupdate where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
select * from test_forupdate where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
--not target table,ok
|
||||
explain (costs off) select * from test_forupdate,test_helper where test_forupdate.a in (1,2,3,4,5,6,7,8,9,10,11,12) for update of test_helper;
|
||||
select * from test_forupdate,test_helper where test_forupdate.a in (1,2,3,4,5,6,7,8,9,10,11,12) for update of test_helper;
|
||||
--subquery,target table,ok
|
||||
explain (costs off) select * from (select * from test_forupdate limit 1) where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
select * from (select * from test_forupdate limit 1) where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
|
||||
--test bug scene,concurrent update
|
||||
\parallel on 2
|
||||
begin
|
||||
set qrw_inlist2join_optmode = 'rule_base';
|
||||
perform pg_sleep(3);
|
||||
perform c,a from test_forupdate where a in (1,2,3,4,5,6,7,8,9,10,11,12) for update;
|
||||
end;
|
||||
/
|
||||
|
||||
begin
|
||||
update test_forupdate set b=10 where a=1;
|
||||
perform pg_sleep(3);
|
||||
end;
|
||||
/
|
||||
\parallel off
|
||||
drop table test_forupdate;
|
||||
drop table test_helper;
|
||||
reset qrw_inlist2join_optmode;
|
||||
|
||||
drop schema query_rewrite cascade;
|
||||
reset current_schema;
|
||||
|
Reference in New Issue
Block a user