ITPub博客

首页 > Linux操作系统 > Linux操作系统 > Literal SQL is not shared in PL/SQL with cursor_sharing set to Force/ Similar

Literal SQL is not shared in PL/SQL with cursor_sharing set to Force/ Similar

原创 Linux操作系统 作者:spider0283 时间:2012-04-05 21:05:31 0 删除 编辑
ID 285447.1

Applies to:

Oracle Server - Enterprise Edition - Version: 9.2.0.5 to 11.2.0.3 - Release: 9.2 to 11.2
Information in this document applies to any platform.

Symptoms

Statements containing literals in pl/sql blocks do not share when cursor_sharing = force or cursor_sharing = force similar.

Literal replacement does not occur.
If the same statements are executed in standard SQL or via execute immediate then they are shared.

e.g.

Using the following table:

create table table1 (
a number,
b number
);


PL/SQL example:


alter system flush shared_pool;

declare
c number(10);
begin
c:=124;
insert into table1 values(1,192);
insert into table1 values(c,193);
insert into table1 values(c,194);
insert into table1 values(1,195);
execute immediate 'insert into table1 values(2,2)';
execute immediate 'insert into table1 values(2,3)';
commit;
end;
/

set lines 132 pages 999
column text format a51
select EXECUTIONS, USERS_EXECUTING, LOADS , substr(SQL_TEXT,1,50) Text from v$sqlarea
where SQL_TEXT like '%table1%' OR SQL_TEXT like '%TABLE1%';

EXECUTIONS USERS_EXECUTING      LOADS TEXT
---------- --------------- ---------- ------------------------------------------------
1 0 1 INSERT INTO TABLE1 VALUES(1,192)
1 0 1 INSERT INTO TABLE1 VALUES(1,195)
1 0 1 INSERT INTO TABLE1 VALUES(:B1,193)
1 0 1 INSERT INTO TABLE1 VALUES(:B1,194)
2 0 1 insert into table1 values(:"SYS_B_0",:"SYS_B_1")


Notice only the execute immediate statements are shared and the literals are not replaced



SQL example:


alter system flush shared_pool;

variable c number;
begin
:c:=124;
end;
/
insert into table1 values(1,192);
insert into table1 values(:c,193);
insert into table1 values(:c,194);
insert into table1 values(1,195);
commit;

EXECUTIONS USERS_EXECUTING      LOADS TEXT
---------- --------------- ---------- ------------------------------------------------
2 0 1 insert into table1 values(:c,:"SYS_B_0")
2 0 1 insert into table1 values(:"SYS_B_0",:"SYS_B_1")


Notice that the example with the literals in and the example with the literal and bind in are shared
as different cursors since the replacement name for the bind variables is different.

NB The wholly literal example would share with the execute immediate statements

Cause

Not sharing the statements in a pl/sql block is a design decision and is not a bug.
It is also non-trivial to change
If this needs to be changed then it would be an enhancement.

Solution

Rewrite the query.
Do not expect these statements to be shared.

See: 

Bug:1767203 CURSOR_SHARING=FORCE DOES NOT REPLACE LITERALS WHEN QUERY HAS BIND

@

References

BUG:2175934 - LITERAL REPLACEMENT (CURSOR_SHARING) NOT ENABLED FOR "MERGE" STATEMENTS

来自 “ ITPUB博客 ” ,链接:http://blog.itpub.net/38267/viewspace-720409/,如需转载,请注明出处,否则将追究法律责任。

请登录后发表评论 登录
全部评论

注册时间:2011-03-29

  • 博文量
    194
  • 访问量
    611360