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.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Google+ photo

You are commenting using your Google+ account. Log Out /  Change )

Twitter picture

You are commenting using your Twitter account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s