Category: Database

  • Oracle #DB12c New – MAX_STRING_SIZE

    In pre-12c database releases, VARCHAR2, NVARCHAR2 data types were limited to 4000 bytes and RAW data type was limited to 2000 bytes. If there is a need to store more data in VARCHAR2 column, you can in 12c after setting the parameter MAX_STRING_SIZE to EXTENDED. With setting MAX_STRING_SIZE to EXTENDED, you can store up to 32KB (32767 bytes) in VARCHAR2, NVARCHAR2 and RAW columns. Though it is an initialization parameter, there are few restrictions and requirements around the parameter setting.

    The default for MAX_STRING_SIZE is STANDARD in Oracle Database 12c, where the maximum size for VARCHAR2, NVARCHAR2 and RAW are same as previous Oracle releases. To change value of this parameter to extended, you have to follow certain steps, and once you set to EXTENDED, there is no going back to STANDARD. To increase the maximum size, do:

    • Shutdown the database
    • Start database in UPGRADE mode
    • Use ALTER SYSTEM to change MAX_STRING_SIZE to EXTENDED
    • Run script $ORACLE_HOME/rdbms/admin/utl32k.sql connected as SYSDBA
    • Shutdown database
    • Start database in NORMAL mode
    • Recompile invalid objects using $ORACLE_HOME/rdbms/admin/utlrp.sql connected as SYSDBA

    There are several overheads associated with enabling increased maximum size for columns, including how such columns are stored. So, make this change only if absolutely necessary, after careful testing. The feature is introduced to help migrating data from non-Oracle databases to Oracle, where the non-Oracle databases have varchar maximum size well over 4K.

  • Oracle #DB12c New – PGA_AGGREGATE_LIMIT

    Program Global Area (PGA) in Oracle database is a private memory region that contains the data and control information for a server process. PGA is allocated per server process, used for storing run-time area of cursor, sorting, bitmap merge, etc.

    Automatic PGA management in Oracle Database was managed by two parameters up until 11gR2 – PGA_AGGREGATE_TARGET and WORKAREA_SIZE_POLICY. When WORKAREA_SIZE_POLICY is set to AUTO (the default) Automatic PGA memory management is enabled, thus no need to define individual work areas (no need to worry about SORT_AREA_SIZE, HASH_AREA_SIZE, BITMAP_MERGE_AREA_SIZE and CREATE_BITMAP_AREA_SIZE). PGA_AGGREGATE_TARGET specifies the target aggregate PGA memory available to all server processes attached to the instance. If you explicitly did not set the PGA_AGGREGATE_TARGET parameter, Oracle sets it to 20% of the SGA or 10 MB, whichever is greater.

    If Automatic Memory Management is enabled (MEMORY_TARGET is set to a positive value) and PGA_AGGREGATE_TARGET is also set to a positive value, the PGA_AGGREGATE_TARGET value acts as the minimum value for the PGA size.

    The PGA_AGGREGATE_TARGET parameter behavior or its default values did not change in Oracle Database 12c from 11gR2, but we have a new parameter in 12c, PGA_AGGREGATE_LIMIT, to limit the aggregate PGA memory consumed by the instance.

    Why limit? What was happening in 11gR2 or before without the limit?

    Well, PGA_AGGREGATE_TARGET is only a target, there is no limit, hence at times PGA memory usage could exceed the target and lead to high rate of swapping, and thus performance issues. To avoid this, the PGA_AGGREGATE_LIMIT parameter sets a hard limit on the PGA size. If you do not explicitly set a limit (provide a value), Oracle sets the default by picking the biggest value from:

    • 2 GB or
    • 200% of the PGA_AGGREGATE_TARGET value or
    • 3 MB times the value of the PROCESSES parameter

    However, it will not exceed 120% of the physical memory size minus the total SGA size.

    If you manually set the PGA_AGGREGATE_LIMIT, it must be bigger than the default value derived by Oracle. You can set the parameter to 0, to have no limit. If you try to set it to a smaller value, you will get an error. For example below, the minimum value determined by Oracle is 909M, and hence we cannot set it lower.

    CDB$ROOT@ORCL> show parameter pga_aggregate_limit
    
    
    NAME                         TYPE       VALUE
    --------------------------- ----------- ------------
    pga_aggregate_limit         big integer 2G
    
    CDB$ROOT@ORCL> alter system set pga_aggregate_limit=200m ;
    
    alter system set pga_aggregate_limit=200m
    *
    ERROR at line 1:
    ORA-02097: parameter cannot be modified because specified value is invalid
    ORA-00093: pga_aggregate_limit must be between 909M and 100000G
    CDB$ROOT@ORCL>
    

    Caution: Since Oracle derives a default limit for PGA, DBAs upgrading database to 12c must be aware of what happens if the process requires more memory and the total PGA exceeds PGA_AGGREGATE_LIMIT. Once the limit exceeds, the sessions that are using the most untunable memory will have their calls aborted. Then, if the total PGA memory usage is still over the limit, the sessions that are using the most untunable memory will be terminated. So, don’t be surprised if you start seeing PGA memory exceeded error messages (ORA-04036) in the alert log after upgrading to 12c!