Automatic Memory Management (AMM) on 11g & 12c

Introduction to Database Memory Components

The basic memory structures associated with Oracle Database include:

  • System Global Area (SGA)

    The SGA is a group of shared memory structures, known as SGA components, that contain data and control information for one Oracle Database instance. The SGA is shared by all server and background processes.
  • Program Global Area (PGA)

    A PGA is a memory region that contains data and control information for a server process. It is nonshared memory created by Oracle Database when a server process is started. Access to the PGA is exclusive to the server process. There is one PGA for each server process. Background processes also allocate their own PGAs. The total PGA memory allocated for all background and server processes attached to an Oracle Database instance is referred to as the total instance PGA memory, and the collection of all individual PGAs is referred to as the total instance PGA, or just instance PGA.

    It contains global variables and data structures and control information for a server process. An example of such information is the runtime area of a cursor. Each time a cursor is executed, a new runtime area is created for that cursor in the PGA memory region of the server process executing that cursor.

    The performance of complex long running queries, typical in a DSS environment, depend to a large extent on the memory available in the Program Global Area (PGA) which is also called work area.

The below figure illustrates the relationships among these memory structures:

Evolution of Memory Management Features

Memory management has evolved with each database release:

  • Oracle 9i

    Beginning with Oracle9i, the dynamic SGA infrastructure allowed for the sizing of the Buffer Cache, Shared Pool and the Large Pool without having to shut down the database. Key features being:
    • Dynamic Memory resizing
    • DB_CACHE_SIZE instead of DB_BLOCK_BUFFERS
    • DB_nK_CACHE_SIZE for multiple block sizes
    • PGA_AGGREGATE_TARGET Introduction of Automatic PGA Memory management

  • Oracle Database 10g

    Automatic Shared Memory Management (ASMM) was introduced in 10g. You enable the automatic shared memory management feature by setting the SGA_TARGET parameter to a non-zero value.

  • Oracle Database 11g

    Automatic Memory Management is being introduced in 11g. This enables automatic tuning of PGA and SGA with use of two new parameters named MEMORY_MAX_TARGET and MEMORY_TARGET
  • Oracle Database 12c

            Automatic Memory Management keeps the same behaviour as in 11g.

The most important SGA components are the following:

Component Description Parameter
Database Buffer Cache The database buffer cache is the portion of the SGA that holds copies of data blocks read from datafiles. All users concurrently connected to the instance share access to the database buffer cache. DB_CACHE_SIZE 
DB_KEEP_CACHE_SIZE 
DB_RECYCLE_CACHE_SIZE
DB_nK_CACHE_SIZE
Redo Log Buffer The redo log buffer is a circular buffer in the SGA that holds information about changes made to the database. This information is stored in redo entries. Redo entries contain the information necessary to reconstruct, or redo, changes made to the database by INSERT, UPDATE, DELETE, CREATE, ALTER, or DROP operations. Redo entries are used for database recovery, if necessary. LOG_BUFFER
Shared Pool The shared pool portion of the SGA contains the library cache, the dictionary cache, the result cache, buffers for parallel execution messages, and control structures. SHARED_POOL_SIZE
SHARED_POOL_RESERVED_SIZE
RESULT_CACHE_MAX_SIZE *
Large Pool Used for allocating session memory for shared server, Oracle XA, or parallel query buffers or for RMAN. LARGE_POOL_SIZE
Java Pool Java pool memory is used in server memory for all session-specific Java code and data within the JVM. JAVA_POOL_SIZE
Streams Pool The streams pool is used exclusively by Oracle Streams. The Streams pool stores buffered queue messages, and it provides memory for Oracle Streams capture processes and apply processes. STREAMS_POOL_SIZE

 

* RESULT_CACHE_MAX_SIZE is new component which has been introduced as part of 11g Memory architecture. The result cache is composed of the SQL query result cache and PL/SQL function result cache, which share the same infrastructure.Results of queries and query fragments can be cached in memory in the SQL query result cache. The database can then use cached results to answer future executions of these queries and query fragments.  Similarly PL/SQL Function Result can also be cached.

You have to use RESULT_CACHE_MODE initialization parameter which determines the SQL query result cache behavior. The possible initialization parameter values are MANUAL and FORCE.


Oracle Database 11g supports various memory management methods, which are chosen by initialization parameter settings. Oracle recommends that you enable the automatic memory management method.

  1. Automatic Memory Management – For Both the SGA and Instance PGA
  2. Automatic Shared Memory Management – For the SGA
  3. Manual Shared Memory Management – For the SGA
  4. Automatic PGA Memory Management –For the Instance PGA
  5. Manual PGA Memory Management – For the Instance PGA

1. Automatic Memory Management – For Both the SGA and Instance PGA

Beginning with Oracle Database 11g, Oracle Database can manage the SGA memory and instance PGA memory completely automatically. You designate only the total memory size to be used by the instance, and Oracle Database dynamically exchanges memory between the SGA and the instance PGA as needed to meet processing demands. This capability is referred to as automatic memory management. With this memory management method, the database also dynamically tunes the sizes of the individual SGA components and the sizes of the individual PGAs.

To achieve this, two new parameters have been introduced named MEMORY_MAX_TARGET and MEMORY_TARGET. To do so (on most platforms), you set only a target memory size initialization parameter (MEMORY_TARGET) and optionally a maximum memory size initialization parameter (MEMORY_MAX_TARGET).

If you create your database with Database Configuration Assistant (DBCA) and choose the basic installation option, automatic memory management is enabled. If you choose advanced installation, Database Configuration Assistant (DBCA) enables you to select automatic memory management.

 

Switching to Automatic Memory Management

  1. Check the current values configured for SGA_TARGET and PGA_AGGREGATE_TARGET.

    SQL> SHOW PARAMETER target
    NAME                                 TYPE        VALUE
    ------------------------------------ ----------- ------------------------------
    archive_lag_target                   integer     0
    db_flashback_retention_target        integer     1440
    fast_start_io_target                 integer     0
    fast_start_mttr_target               integer     0
    memory_max_target                    big integer 0
    memory_target                        big integer 0
    pga_aggregate_target                 big integer 200M
    sga_target                           big integer 500M


    Add the values of PGA_AGGREGATE_TARGET and SGA_TARGET. In our case it would sum to 700MB.

    Check also for SGA_MAX_SIZE being set. When switching to AMM, i.e. using MEMORY_TARGET, the parameter SGA_MAX_SIZE (used for ASMM) should not be set as doing so fixes the size of the SGA, and hence conflicts with the intended use of MEMORY_TARGET.

  2. Decide on a maximum amount of memory that you would want to allocate to the database which will determine the maximum value for the sum of the SGA and instance PGA sizes. In our case we decide to set to 808M

  3. Change the parameters in the initialization parameter file. 

    When using a server parameter file, issue:

    SQL> ALTER SYSTEM SET memory_max_target=808M SCOPE=SPFILE;
    SQL> ALTER SYSTEM SET memory_target=808M SCOPE=SPFILE;
    SQL> ALTER SYSTEM SET sga_target=0 SCOPE=SPFILE;
    SQL> ALTER SYSTEM SET pga_aggregate_target=0 SCOPE=SPFILE;


    When using a text initialization parameter file, then edit the parameter file and set the parameters manually:

    MEMORY_MAX_TARGET=808M
    MEMORY_TARGET=808M
    SGA_TARGET=0
    PGA_AGGREGATE_TARGET=0


    In case you do not specify any value for MEMORY_MAX_TARGET and only use MEMORY_TARGET then database automatically sets MEMORY_MAX_TARGET to the value of MEMORY_TARGET. 

    If you omit the line for MEMORY_TARGET and include a value for MEMORY_MAX_TARGET, the MEMORY_TARGET parameter defaults to zero. After startup, you can then dynamically change MEMORY_TARGET to a non-zero value, provided that it does not exceed the value of MEMORY_MAX_TARGET.

    MEMORY_MAX_TARGET is a static parameter i.e it cannot be changed dynamically and the instance has to be bounced for modifying its value. So ensure that you have set it to an appropriate value.

     

  4. Shutdown and startup the database:

    SQL> shutdown immediate;
    Database closed.
    Database dismounted.
    ORACLE instance shut down.
    SQL> startup mount
    ORACLE instance started.

    Total System Global Area  845348864 bytes
    Fixed Size                  1303188 bytes
    Variable Size             469765484 bytes
    Database Buffers          369098752 bytes
    Redo Buffers                5181440 bytes
    SQL> show parameter target

    NAME                                 TYPE        VALUE
    ------------------------------------ ----------- ------------------------------
    archive_lag_target                   integer     0
    db_flashback_retention_target        integer     1440
    fast_start_io_target                 integer     0
    fast_start_mttr_target               integer     0
    memory_max_target                    big integer 808M
    memory_target                        big integer 808M
    pga_aggregate_target                 big integer 0
    sga_target                           big integer 0


The preceding steps instruct you to set SGA_TARGET and PGA_AGGREGATE_TARGET to zero so that the sizes of the SGA and instance PGA are tuned up and down as required, without restrictions. You can omit the statements that set these parameter values to zero and leave either or both of the values as positive numbers. In this case, the values act as minimum values for the sizes of the SGA or instance PGA.

Note: in case you set any parameter value to value which is higher then MEMORY_TARGET, then you get the ORA-844 error. E.g. setting SGA_MAX_SIZE to value of 900 M results in the following:

SQL> startup
ORA-00844: Parameter not taking MEMORY_TARGET into account, see alert log for more information

The explanation given for this error is:
00844, 00000, "Parameter not taking MEMORY_TARGET into account, see alert log for more information"
// *Cause: The parameter was larger than MEMORY_TARGET.
// *Action: Set the parameter to a lower value than MEMORY_TARGET.

Monitoring and Tuning Automatic Memory Management

The dynamic performance view V$MEMORY_DYNAMIC_COMPONENTS shows the current sizes of all dynamically tuned memory components, including the total sizes of the SGA and instance PGA. The view V$MEMORY_TARGET_ADVICE provides tuning advice for the MEMORY_TARGET initialization parameter:

SQL> SELECT * FROM v$memory_target_advice ORDER BY memory_size;


You can also use V$MEMORY_RESIZE_OPS which has a circular history buffer of the last 800 memory resize requests.

Note: if both MEMORY_TARGET and PGA_AGGREGATE_TARGET instance parameters have been set, then querying V$PGASTAT can show a value for 'total PGA allocated' which is less than PGA_AGGREGATE_TARGET. This is correct behaviour. The Oracle? Database Performance Tuning Guide shows the following remark about this phenomenon:

total PGA allocated: This gives the current amount of PGA memory allocated by the instance. Oracle tries to keep this number less than the value of PGA_AGGREGATE_TARGET. However, it is possible for the PGA allocated to exceed that value by a small percentage and for a short period of time, when the work area workload is increasing very rapidly or when the initialization parameter PGA_AGGREGATE_TARGET is set to a too small value.

11g MEMORY_TARGET Parameter Dependency

If MEMORY_TARGET is set to a non-zero value:

  • If SGA_TARGET and PGA_AGGREGATE_TARGET are set, they will be considered the minimum values for the sizes of SGA and the PGA respectively. MEMORY_TARGET values can range from SGA_TARGET + PGA_AGGREGATE_TARGET to MEMORY_MAX_TARGET.
  • If SGA_TARGET is set and PGA_AGGREGATE_TARGET is not set, we will still auto-tune both parameters. PGA_AGGREGATE_TARGET will be initialized to a value of MEMORY_TARGET - SGA_TARGET.
  • If PGA_AGGREGATE_TARGET is set and SGA_TARGET is not set, we will still auto-tune both parameters. SGA_TARGET will be initialized to the minimum non-zero value of MEMORY_TARGET - PGA_AGGREGATE_TARGET and SGA_MAX_SIZE and will auto tune its components.
  • If neither is set, they will be auto-tuned without any minimum or default values. We will have a policy of distributing the total memory set by MEMORY_TARGET parameter in a fixed ratio to the the SGA and PGA during initialization. The policy is to give 60% to the SGA and 40% to the PGA at startup.

If MEMORY_MAX_TARGET has not been explicitly set, but MEMORY_TARGET has, the instance automatically sets MEMORY_MAX_TARGET to the same value as MEMORY_TARGET. If MEMORY_TARGET has not been explicitly set, but MEMORY_MAX_TARGET has, then MEMORY_TARGET defaults to 0. After instance startup, it then is possible to dynamically change MEMORY_TARGET to a non-zero value, provided that it does not exceed the value of MEMORY_MAX_TARGET.

If MEMORY_TARGET is not set or set to set to 0 explicitly (default value is 0 for 11g):

  • If SGA_TARGET is set we will only auto-tune the sizes of the components of the SGA. PGA will be autotuned independent of whether it is explicitly set or not. However, the combination of SGA and PGA will not be auto-tuned, i.e. the SGA and PGA will not share memory and resize as with the case of MEMORY_TARGET being set to a non-zero value.
  • If neither SGA_TARGET nor PGA_AGGREGATE_TARGET is set, we will follow the same policy as we have today; PGA will be auto-tuned and the SGA will not be auto-tuned and parameters for some of the SGA components will have to be set explicitly (for SGA_TARGET).
  • If only MEMORY_MAX_TARGET is set, MEMORY_TARGET will default to 0 and we will not auto tune the SGA and PGA. It will default to 10gR2 behavior.
  • If SGA_MAX_SIZE is not user set, it is internally set to MEMORY_MAX_TARGET.

2. Automatic Shared Memory Management – For the SGA

If you want to exercise more direct control over the size of the SGA, you can disable automatic memory management and enable automatic shared memory management. This feature was introduced in 10g with a parameter known as SGA_TARGET. When automatic SGA memory management is enabled, the sizes of the different SGA components are flexible and can adapt to the needs of current workload without requiring any additional configuration.

Please refer to following document for setting SGA_TARGET:

Document 295626.1 - How To Use Automatic Shared Memory Management (ASMM) In Oracle10g & 11g

In case you have enabled Automatic Memory Management and wish to switch to Automatic Shared Memory Management, then follow the below procedure:

SQL> ALTER SYSTEM SET memory_target=0 SCOPE=BOTH;
SQL> ALTER SYSTEM SET SGA_TARGET=500M SCOPE=BOTH;

 

3. Manual Shared Memory Management – For the SGA

If you want complete control of individual SGA component sizes, you can disable both automatic memory management and automatic shared memory management. In this mode, you need to set the sizes of several individual SGA components, thereby determining the overall SGA size. You then manually tune these individual SGA components on an ongoing basis.

In this case you set SGA_TARGET and MEMORY_TARGET to 0 and set value for other SGA components upto the total value of SGA_MAX_SIZE.

Please refer to Document 148495.1 - Dynamic SGA.


Please note that SGA re-sizes can occur after upgrade to 11.2 despite the fact that automatic memory management
(AMM/ASMM) is disabled via the MEMORY_TARGET and SGA_TARGET parameters being set to zero.  This typically appears as
growth in the __SHARED_POOL_SIZE value and a reduction in the __DB_CACHE_SIZE value being used in the instance, such that
__DB_CACHE_SIZE may be shrunk below the DB_CACHE_SIZE value specified in the init.ora/spfile.
This is expected behavior in 11.2 for immediate memory allocation requests, which added this as a new feature when
automatic memory management was disabled.

You can set the parameter _MEMORY_IMM_MODE_WITHOUT_AUTOSGA=false in the instance to disable this feature with the
consequence that in future an ORA-4031 error would be raised, e.g.:

connect / as sysdba
alter system set "_memory_imm_mode_without_autosga"=FALSE scope=both;
exit

Parameter:        _MEMORY_IMM_MODE_WITHOUT_AUTOSGA
Default value:   0   (SGA autotuning is disabled for DEFERRED mode autotuning requests, but allowed for IMMEDIATE mode  autotuning requests)

4. Automatic PGA Memory Management – For the Instance PGA

While using Automatic memory management, PGA memory is allocated based upon the value of MEMORY_TARGET. In case you enable automatic shared memory management or manual shared memory management, you also implicitly enable automatic PGA memory management. For more information, see Document 1392549.1 - SGA and PGA Management in 11g's Automatic Memory Management (AMM).

Automatic/Manual PGA memory management is decided by the initialization parameter WORKAREA_SIZE_POLICY which is a session- and system-level parameter that can take only two values: MANUAL or AUTO. The default is AUTO.


With automatic PGA memory management, you set a target size for the instance PGA by defining value for parameter named PGA_AGGREGATE_TARGET and sizing of SQL work areas is automatic and all *_AREA_SIZE initialization parameters are ignored for these sessions. This feature is available from 9i.

At any given time, the total amount of PGA memory available to active work areas on the instance is automatically derived from the parameter PGA_AGGREGATE_TARGET. This amount is set to the value of PGA_AGGREGATE_TARGET minus the PGA memory allocated for other purposes (for example, session memory). The resulting PGA memory is then allotted to individual active work areas based on their specific memory requirements.

Please refer to following document for more details on Automatic PGA Memory Management:

Document 223730.1 - Automatic PGA Memory Management

5. Manual PGA Memory Management – For the Instance PGA

In case you wish to manually specify the maximum work area size for each type of SQL operator (such as sort or hash-join) then you can enable Manual PGA Memory management.

Set WORKAREA_SIZE_POLICY value to MANUAL and also specify values for *_AREA_SIZE such as SORT_AREA_SIZE, HASH_AREA_SIZE, BITMAP_MERGE_AREA_SIZE, and CREATE_BITMAP_AREA_SIZE, etc. 

Although the Oracle Database 11g supports this manual PGA memory management method, Oracle strongly recommends that you leave automatic PGA memory management enabled.

The table below summarizes the various memory management methods:

Memory Management Mode For You Set Oracle Database Automatically Tunes
Automatic memory management (AMM) SGA and PGA
  • Total memory target size for the Oracle instance (MEMORY_TARGET)
  • (Optional) Maximum memory size for the Oracle instance (MEMORY_MAX_TARGET)
  • Total SGA size
  • SGA component sizes
  • Instance PGA size
  • Individual PGA sizes
Automatic shared memory management (ASMM)
(AMM disabled)
SGA
  • SGA target size (SGA_TARGET)
  • (Optional) SGA maximum size (SGA_MAX_SIZE)
SGA component sizes
Manual shared memory management
(AMM and ASMM disabled)
SGA
  • Shared pool size (SHARED_POOL_SIZE)
  • Buffer cache size (DB_CACHE_SIZEor DB_BLOCK_BUFFERS)
  • Java pool size (JAVA_POOL_SIZE)
  • Large pool size (LARGE_POOL_SIZE)
  • (Optional) SGA maximum size (SGA_MAX_SIZE)
None
Automatic PGA memory management PGA Instance PGA target size (PGA_AGGREGATE_TARGET) Individual PGA sizes
Manual PGA memory management
(Not recommended)
PGA Maximum work area size for each type of SQL operator None

The Automatic Memory Management (AMM) feature uses the Memory Manager (MMAN) background process. This process was introduced in 10g which assisted in Automatic Shared Memory Management (ASMM) using SGA_TARGET. MMAN serves as the SGA Memory Broker and coordinates the sizing of the memory components. The SGA Memory Broker keeps track of the sizes of the components and pending resize operations.

6. AMM impact on Solaris OS

Configuring AMM or ASMM on Solaris OS will cause the OS to use a feature called Dynamic Intimate Shared Memory (DISM). This allows for shared memory segments to be dynamically resizable. Oracle uses DISM for its dynamic System Global Area (SGA) capability when AMM or ASMM is configured. With Oracle 9i and higher, if SGA_MAX_SIZE > SGA_TARGET (or sum of sga compenents), then DISM is used. On 11g, DISM is also used if MEMORY_TARGET or MEMORY_MAX_TARGET is set. Otherwise, ISM is used if DISM is not enabled.

DISM (unlike ISM), requires a swap reservation for all pages, whether or not they're allocated. This basically means you will need to configure at least as much swap space as the SGA size for instances that are using DISM. Otherwise, memory errors could occur when trying to run the instance with inadequate swap space.

To determine if DISM is being used for an Oracle instance, you can look on the OS side with ps utility:

$ ps -aef | grep dism


If DISM is being used it will show as a process in format ora_dism_$ORACLE_SID.

The only way to avoid the use of DISM and the swap space requirement would be to use manual memory management.

7. Automatic PGA memory management limitations on Linux

The realfree allocator will be used when PGA_AGGREGATE_TARGET > 0.

On Linux systems, a process can reach a 4G limit due to default settings and error with ORA-4030. These errors show up because running out of map entries. By default there are only 65536 memory map entries per process.

Although not necessary to diagnose, an OS trace using strace/truss of Oracle process may show using mmap() instead of malloc() for memory allocation. 

There are two ways to allow the process to access more memory than 4G:

  1. On the OS side, increase the map entries:

    $ more /proc/sys/vm/max_map_count

    $ sysctl -w vm.max_map_count=200000 (for example)
  2. Or set the database hidden parameter higher; for example:
    _realfree_heap_pagesize_hint = 262144

    The default realfree allocator pagesize is 64 KB, so 64K entries take up 4GB. With 256KB pages as specified above, the limit goes up to 16GB.

 

No quantitative data available regarding performance for either setting. May want to test both settings to determine if either provides better performance.

请使用浏览器的分享功能分享到微信等