Resource manager session_pga_limit has it’s own limits

Recently we hit an issue with a complex SQL statement (formatted was 44,000 lines, maybe subject of a separate blog post), causing the CBO to struggle consuming large amounts of PGA memory, and the host to start swapping memory and impacting other database users.

The pga_aggregate_limit parameter did not appear to be kicking in (maybe because this was happening during parse phase), so while looking for a proper solution we considered other ways to limit the effect of this problem SQL.

As we are on release 12.2 one thing we tried was a (relatively new) feature of resource manager, session_pga_limit. This should limit the PGA any one session can consume (as opposed to pga_aggregate_limit which is instance wide), however new features can be a little temperamental, especially in the first few versions after they have been introduced.

After a bit of trial and error we determined that setting it to any value greater than 4G (4096 MB) causes the feature not to kick in.

The following is my testcase on a 12.2.0.1.180717 PDB. I could not reproduce this behavior on 18c (non-multitenant) implying this limitation (bug?) has likely been fixed.

First we create a resource manager plan, consumer groups and directives, and configure the instance to use this plan.

SQL> BEGIN
  2    sys.DBMS_RESOURCE_MANAGER.clear_pending_area();
  3
  4    sys.DBMS_RESOURCE_MANAGER.create_pending_area();
  5
  6    sys.DBMS_RESOURCE_MANAGER.create_plan(
  7      plan    => 'PGA_PLAN',
  8      comment => 'Plan to demonstrate behaviour with session_pga_limit >= 4096');
  9
 10    sys.DBMS_RESOURCE_MANAGER.create_consumer_group(
 11      consumer_group => 'PGA_LIMIT_4095_GROUP',
 12      comment        => '4095 MB PGA Limit');
 13
 14    sys.DBMS_RESOURCE_MANAGER.create_consumer_group(
 15      consumer_group => 'PGA_LIMIT_4096_GROUP',
 16      comment        => '4096 MB PGA Limit');
 17
 18    sys.DBMS_RESOURCE_MANAGER.create_plan_directive (
 19      plan              => 'PGA_PLAN',
 20      group_or_subplan  => 'PGA_LIMIT_4095_GROUP',
 21      session_pga_limit => 4095);
 22
 23    sys.DBMS_RESOURCE_MANAGER.create_plan_directive (
 24      plan              => 'PGA_PLAN',
 25      group_or_subplan  => 'PGA_LIMIT_4096_GROUP',
 26      session_pga_limit => 4096);
 27
 28    sys.DBMS_RESOURCE_MANAGER.create_plan_directive (
 29      plan              => 'PGA_PLAN',
 30      group_or_subplan  => 'OTHER_GROUPS');
 31
 32    sys.DBMS_RESOURCE_MANAGER.validate_pending_area;
 33
 34    sys.DBMS_RESOURCE_MANAGER.submit_pending_area();
 35  END;
 36  /

PL/SQL procedure successfully completed.

SQL> ALTER SYSTEM SET RESOURCE_MANAGER_PLAN = PGA_PLAN;

System altered.

Then we configure my test user to use the consumer group limiting it to 4095 MB PGA.

SQL> BEGIN
  2    sys.DBMS_RESOURCE_MANAGER.clear_pending_area();
  3    sys.DBMS_RESOURCE_MANAGER.create_pending_area();
  4
  5    sys.DBMS_RESOURCE_MANAGER.set_consumer_group_mapping (
  6      attribute      => DBMS_RESOURCE_MANAGER.oracle_user,
  7      value          => 'TEST_PGA_USER',
  8      consumer_group => 'PGA_LIMIT_4095_GROUP');
  9
 10    sys.DBMS_RESOURCE_MANAGER.validate_pending_area;
 11    sys.DBMS_RESOURCE_MANAGER.submit_pending_area();
 12  END;
 13  /

We connect as the test user, and executing some stupid PL/SQL that sits in a tight loop eating PGA. Observe that the resource manager directive is obeyed when the PGA hits 4095 MB.

SQL>   declare
  2          type vc_tt is table of VARCHAR2(32767);
  3          vc_t vc_tt := vc_tt() ;
  4      begin
  5          while TRUE
  6          loop
  7               vc_t.extend();
  8          end loop;
  9      end;
 10   /
  declare
*
ERROR at line 1:
ORA-04068: existing state of packages has been discarded
ORA-10260: PGA limit (4095 MB) exceeded - process terminated
ORA-06512: at line 7

Let’s remap my test user to the consumer group limited to 4096 MB.

SQL> BEGIN
  2    sys.DBMS_RESOURCE_MANAGER.clear_pending_area();
  3    sys.DBMS_RESOURCE_MANAGER.create_pending_area();
  4
  5    sys.DBMS_RESOURCE_MANAGER.set_consumer_group_mapping (
  6      attribute      => DBMS_RESOURCE_MANAGER.oracle_user,
  7      value          => 'TEST_PGA_USER',
  8      consumer_group => 'PGA_LIMIT_4096_GROUP');
  9
 10    sys.DBMS_RESOURCE_MANAGER.validate_pending_area;
 11    sys.DBMS_RESOURCE_MANAGER.submit_pending_area();
 12  END;
 13  /

PL/SQL procedure successfully completed.

My test program runs unchecked:

SQL> declare
  2      type vc_tt is table of VARCHAR2(32767);
  3      vc_t vc_tt := vc_tt() ;
  4  begin
  5      while TRUE
  6      loop
  7           vc_t.extend();
  8      end loop;
  9  end;
 10  /

Checking PGA allocation from another session we can see it’s up to 8546MB, way past the 4096MB it should be limited to.

SQL>  SELECT
  2      spid,
  3      resource_consumer_group,
  4      round(pga_used_mem / 1024 / 1024) pga_used_mb
  5  FROM
  6      v$session s,
  7      v$process p
  8  WHERE
  9      s.username LIKE 'TEST_PGA_USER'
 10      AND p.addr = s.paddr;

SPID                     RESOURCE_CONSUMER_GROUP          PGA_USED_MB
------------------------ -------------------------------- -----------
234513                   PGA_LIMIT_4096_GROUP                    8546

Note if you’re testing this yourself, I suggest to be careful, don’t do this on a production instance and be prepared to kill the run-away session forcefully.

12.2 controlfile backup never gets marked as obsolete

I’ve blogged about this bug in passing, but I thought would be worthwhile to document my testcase.    Basically backups of controlfiles never get marked as obsolete. The issue reproduces for both image copies and backupsets, my test-case uses the latter for simplicity.

RMAN> show all;

RMAN configuration parameters for database with db_unique_name PVJTEST are:
CONFIGURE RETENTION POLICY TO REDUNDANCY 1; # default
CONFIGURE BACKUP OPTIMIZATION OFF;
CONFIGURE DEFAULT DEVICE TYPE TO DISK; # default
CONFIGURE CONTROLFILE AUTOBACKUP ON; # default
CONFIGURE CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE DISK TO '%F'; # default
CONFIGURE DEVICE TYPE DISK PARALLELISM 1 BACKUP TYPE TO BACKUPSET; # default
CONFIGURE DATAFILE BACKUP COPIES FOR DEVICE TYPE DISK TO 1; # default
CONFIGURE ARCHIVELOG BACKUP COPIES FOR DEVICE TYPE DISK TO 1; # default
CONFIGURE MAXSETSIZE TO UNLIMITED; # default
CONFIGURE ENCRYPTION FOR DATABASE OFF; # default
CONFIGURE ENCRYPTION ALGORITHM 'AES128'; # default
CONFIGURE COMPRESSION ALGORITHM 'BASIC' AS OF RELEASE 'DEFAULT' OPTIMIZE FOR LOAD TRUE ; # default
CONFIGURE RMAN OUTPUT TO KEEP FOR 7 DAYS; # default
CONFIGURE ARCHIVELOG DELETION POLICY TO NONE; # default
CONFIGURE SNAPSHOT CONTROLFILE NAME TO '/u01/app/oracle/product/12.2.0.1/dbhome/dbs/snapcf_PVJTEST.f'; # default

RMAN> list backup of controlfile;

specification does not match any backup in the repository

RMAN> backup database;

Starting backup at 2017-11-01 11:31:38
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00003 name=/u02/oradata/PVJTEST/sysaux01.dbf
input datafile file number=00001 name=/u02/oradata/PVJTEST/system01.dbf
input datafile file number=00004 name=/u02/oradata/PVJTEST/undotbs01.dbf
input datafile file number=00007 name=/u02/oradata/PVJTEST/users01.dbf
channel ORA_DISK_1: starting piece 1 at 2017-11-01 11:31:38
channel ORA_DISK_1: finished piece 1 at 2017-11-01 11:31:53
piece handle=/u01/app/oracle/product/12.2.0.1/dbhome/dbs/agsifi8q_1_1 tag=TAG20171101T113138 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
Finished backup at 2017-11-01 11:31:54

Starting Control File and SPFILE Autobackup at 2017-11-01 11:31:54
piece handle=/u01/app/oracle/product/12.2.0.1/dbhome/dbs/c-2122366327-20171101-07 comment=NONE
Finished Control File and SPFILE Autobackup at 2017-11-01 11:31:55

RMAN> backup database;

Starting backup at 2017-11-01 11:31:59
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00003 name=/u02/oradata/PVJTEST/sysaux01.dbf
input datafile file number=00001 name=/u02/oradata/PVJTEST/system01.dbf
input datafile file number=00004 name=/u02/oradata/PVJTEST/undotbs01.dbf
input datafile file number=00007 name=/u02/oradata/PVJTEST/users01.dbf
channel ORA_DISK_1: starting piece 1 at 2017-11-01 11:31:59
channel ORA_DISK_1: finished piece 1 at 2017-11-01 11:32:14
piece handle=/u01/app/oracle/product/12.2.0.1/dbhome/dbs/aisifi9f_1_1 tag=TAG20171101T113159 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
Finished backup at 2017-11-01 11:32:14

Starting Control File and SPFILE Autobackup at 2017-11-01 11:32:14
piece handle=/u01/app/oracle/product/12.2.0.1/dbhome/dbs/c-2122366327-20171101-08 comment=NONE
Finished Control File and SPFILE Autobackup at 2017-11-01 11:32:15

RMAN> delete obsolete;

RMAN retention policy will be applied to the command
RMAN retention policy is set to redundancy 1
using channel ORA_DISK_1
Deleting the following obsolete backups and copies:
Type Key Completion Time Filename/Handle
-------------------- ------ ------------------ --------------------
Backup Set 207 2017-11-01 11:31:53
Backup Piece 207 2017-11-01 11:31:53 /u01/app/oracle/product/12.2.0.1/dbhome/dbs/agsifi8q_1_1

Do you really want to delete the above objects (enter YES or NO)? YES
deleted backup piece
backup piece handle=/u01/app/oracle/product/12.2.0.1/dbhome/dbs/agsifi8q_1_1 RECID=207 STAMP=958908699
Deleted 1 objects

 

RMAN> list backup of controlfile;

 

List of Backup Sets
===================

 

BS Key Type LV Size Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ -------------------
208 Full 10.47M DISK 00:00:00 2017-11-01 11:31:54
BP Key: 208 Status: AVAILABLE Compressed: NO Tag: TAG20171101T113154
Piece Name: /u01/app/oracle/product/12.2.0.1/dbhome/dbs/c-2122366327-20171101-07
Control File Included: Ckp SCN: 12426398 Ckp time: 2017-11-01 11:31:54

BS Key Type LV Size Device Type Elapsed Time Completion Time
------- ---- -- ---------- ----------- ------------ -------------------
210 Full 10.47M DISK 00:00:00 2017-11-01 11:32:14
BP Key: 210 Status: AVAILABLE Compressed: NO Tag: TAG20171101T113214
Piece Name: /u01/app/oracle/product/12.2.0.1/dbhome/dbs/c-2122366327-20171101-08
Control File Included: Ckp SCN: 12426426 Ckp time: 2017-11-01 11:32:14

RMAN>

Oracle Support initially identified the following bug:
Bug 25943271 : RMAN REPORT OBSOLETE DOES NOT REPORT CONTROLFILE BACKUP AS OBSOLETE

However after waiting for the patch, it still did not resolve the issue. Seems this may now be the following bug:
Bug 26771767 : SPFILE BACKUP OR BACKUP PIECE INCLUDES SPFILE ARE NOT REPORTED AS OBSOLETE

We are working around the issue at the moment by modifying our rman scripts to delete controlfile backups older than a certain age.  Still waiting for the fix, after supplying reproducible testcase over six months ago 🙂