wuqingyong 2017-01-01
我们都知道,在12C之前,对于PGA内存的管理是使用PGA_AGGREGATE_TARGET参数来控制的,但这个参数也只是一个参考值,Oracle实例只是尽量保证总的PGA使用量在这个值范围内,当会话使用的PGA内存超过这个限制时,Oracle也不能做出什么强制措施来限制使用内存的大小。
12.1.0.1版本中引入了新特性:使用PGA_AGGREGATE_LIMIT参数来限制Oracle实例PGA使用内存的上限。后台进程ckpt每三秒检查一次PGA使用的内存总量,如果超过限制就采取终止会话的方式来降低PGA内存的使用量,对于SYS用户进程和后台进程不包括job队列不会被终止掉。有了这个限制,不会造成PGA内存疯涨,导致内存耗尽。
官方文档:http://docs.oracle.com/database/121/TGDBA/tune_pga.htm#TGDBA95344
默认地PGA_AGGREGATE_LIMIT参数为2G或200%的PGA_AGGREGATE_TARGET值或PROCESSES参数值*3M
测试数据库版本12.1.0.2
SQL> select * from v$version;
BANNER CON_ID
-------------------------------------------------------------------------------- ----------
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production 0
PL/SQL Release 12.1.0.2.0 - Production 0
CORE 12.1.0.2.0 Production 0
TNS for Linux: Version 12.1.0.2.0 - Production 0
NLSRTL Version 12.1.0.2.0 - Production 0
查看PGA_AGGREGATE_LIMIT参数值大小为2G
SQL> show parameter pga
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_limit big integer 2G
pga_aggregate_target big integer 250M
创建测试用户
SQL> alter session set container=pdb_orcl;
Session altered.
SQL> create user zx identified by zx;
User created.
SQL> grant dba to zx;
Grant succeeded.
SQL> conn zx/zx@pdb_orcl
Connected.
创建一个包用于演示占用PGA
SQL> create or replace package demo_pkg
2 as
3 type array is table of char(2000) index by binary_integer;
4 g_data array;
5 end;
6 /
Package created.
查看当前会话sid和使用PGA内存情况
SQL> select userenv('sid') from dual;
USERENV('SID')
--------------
22
--当前会话sid为22
SQL> select a.name, to_char(b.value, '999,999,999') bytes,
2 to_char(round(b.value/1024/1024,1), '99,999.9' ) mbytes
3 from v$statname a, v$mystat b
4 where a.statistic# = b.statistic#
5 and a.name like '%ga memory%';
NAME BYTES MBYTES
---------------------------------------------------------------- ------------ ---------
session uga memory 2,301,312 2.2
session uga memory max 2,424,824 2.3
session pga memory 3,715,176 3.5
session pga memory max 3,715,176 3.5
--当前会话使用PGA内存为3.5MB
执行前面创建的包,查看PGA内存使用情况
--循环执行200000次查看PGA内存使用情况
SQL> begin
2 for i in 1 .. 200000
3 loop
4 demo_pkg.g_data(i) := 'x';
5 end loop;
6 end;
7 /
PL/SQL procedure successfully completed.
SQL> select a.name, to_char(b.value, '999,999,999') bytes,
2 to_char(round(b.value/1024/1024,1), '99,999.9' ) mbytes
3 from v$statname a, v$mystat b
4 where a.statistic# = b.statistic#
5 and a.name like '%ga memory%';
NAME BYTES MBYTES
---------------------------------------------------------------- ------------ ---------
session uga memory 470,213,072 448.4
session uga memory max 470,213,072 448.4
session pga memory 471,773,288 449.9
session pga memory max 471,773,288 449.9
--共使用449MB内存,可以算出循环执行200000*5次占用的PGA就会超过设置的2G
SQL> begin
2 for i in 1 .. 1000000
3 loop
4 demo_pkg.g_data(i) := 'x';
5 end loop;
6 end;
7 /
begin
*
ERROR at line 1:
ORA-04036: PGA memory used by the instance exceeds PGA_AGGREGATE_LIMIT
--报错ORA-4036超过了PGA_AGGREGATE_LIMIT设置的2G
调整PGA_AGGREGATE_LIMIT为4G后再次执行报错的过程,就没有问题了
SQL> conn / as sysdba
Connected.
SQL> alter system set PGA_AGGREGATE_LIMIT=4G;
System altered.
SQL> conn zx/zx@pdb_orcl
Connected.
SQL> begin
2 for i in 1 .. 1000000
3 loop
4 demo_pkg.g_data(i) := 'x';
5 end loop;
6 end;
7 /
PL/SQL procedure successfully completed.
SQL> show parameter pga
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_limit big integer 4G
pga_aggregate_target big integer 250M
取消PGA限制,设置pga_aggregate_limit=0即可。
alter system set PGA_AGGREGATE_LIMIT=0;