Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

PL/SQL RAM Memory


Oracle Tips by Burleson Consulting

 

The following Tip is from the outstanding book "Oracle PL/SQL Tuning: Expert Secrets for High Performance Programming" by Dr. Tim Hall, Oracle ACE of the year, 2006:

The approach taken during PL/SQL development can impact the memory usage of the resulting code.  In this chapter, details are given on several areas, some of which affect the total memory used by PL/SQL code and some that affect memory management within the shared pool.

How bind variables can affect the size and contents of the shared pool is the subject of the next section.

Bind Variables and the Shared Pool

Although much discussion about the use of bind variables was presented in Chapter 2, it is worth reiterating that using bind variables reduces the amount of parsed statements held in the shared pool.  This represents a reduction in memory usage at the instance level, rather than the session level.

The NOCOPY Hint and Memory Usage

Chapter 2 contained information about performance improvements associated with using the NOCOPY hint when passing large OUT and IN OUT parameters to procedures and functions.  By default these parameters are passed by-value, requiring the initial value of the actual parameters to be copied to temporary variables for use inside the subprogram.  When passing large parameters, the NOCOPY hint allows parameters to be passed by-reference, negating the need for these temporary variables and resulting in a considerable reduction in memory consumption.

Bigger is Better for VARCHAR2 Variables

The Oracle documentation states that PL/SQL optimizes the memory usage of VARCHAR2 variables defined with sizes of 2000 bytes or greater by allocating the correct amount of memory at assignment time based on the size of the value assigned, not the definition size.  For variable sizes smaller than 2000 bytes, the memory is allocated as specified in the declaration.  This means that when defining a variable to hold data of an indeterminate size, it is better to use variable sizes of 2000 bytes or more.

This is true for Oracle 9i, but during testing it was noted that for Oracle 10g the optimization seems to be triggered by variables defined with sizes greater than 4000 bytes, as shown by the varchar2_definitions.sql script.

varchar2_definitions.sql

-- *****************************************************************
-- Requirements:
--   GRANT SELECT ON v_$mystat TO test;
--   GRANT SELECT ON v_$statname TO test;
-- *****************************************************************

conn test/test

CREATE OR REPLACE FUNCTION get_used_memory RETURN NUMBER AS
  l_used_memory  NUMBER;
BEGIN
  SELECT ms.value
  INTO   l_used_memory
  FROM   v$mystat ms,
         v$statname sn
  WHERE  ms.statistic# = sn.statistic#
  AND    sn.name = 'session pga memory';
  RETURN l_used_memory;
END get_used_memory;
/
SHOW ERRORS

-- Reconnect each time to make sure extra memory has not been allocated to the PGA already.

conn test/test
SET SERVEROUTPUT ON
DECLARE
  l_recursion_level  NUMBER := 10000;
  l_start            NUMBER;

  PROCEDURE varchar2_1 (p_varchar  IN  VARCHAR2,
                        p_number   IN  NUMBER) AS
    l_varchar  VARCHAR2(1) := p_varchar;
  BEGIN
    IF p_number < l_recursion_level THEN
      varchar2_1 (l_varchar, p_number + 1);
    END IF;
  END varchar2_1;
BEGIN
  l_start := get_used_memory;

  varchar2_1('1', 0);

  DBMS_OUTPUT.put_line('VARCHAR2_1     : ' || (get_used_memory - l_start));
END;
/

conn test/test
SET SERVEROUTPUT ON
DECLARE
  l_recursion_level  NUMBER := 10000;
  l_start            NUMBER;

  PROCEDURE varchar2_1999 (p_varchar  IN  VARCHAR2,
                        p_number   IN  NUMBER) AS
    l_varchar  VARCHAR2(1999) := p_varchar;
  BEGIN
    IF p_number < l_recursion_level THEN
      varchar2_1999 (l_varchar, p_number + 1);
    END IF;
  END varchar2_1999;
BEGIN
  l_start := get_used_memory;

  varchar2_1999('1', 0);


  DBMS_OUTPUT.put_line('VARCHAR2_1999  : ' || (get_used_memory - l_start));
END;
/

conn test/test
SET SERVEROUTPUT ON
DECLARE
  l_recursion_level  NUMBER := 10000;
  l_start            NUMBER;

  PROCEDURE varchar2_2000 (p_varchar  IN  VARCHAR2,
                        p_number   IN  NUMBER) AS
    l_varchar  VARCHAR2(2000) := p_varchar;
  BEGIN
    IF p_number < l_recursion_level THEN
      varchar2_2000 (l_varchar, p_number + 1);
    END IF;
  END varchar2_2000;
BEGIN
  l_start := get_used_memory;

  varchar2_2000('1', 0);

  DBMS_OUTPUT.put_line('VARCHAR2_2000  : ' || (get_used_memory - l_start));
END;
/

conn test/test
SET SERVEROUTPUT ON
DECLARE
  l_recursion_level  NUMBER := 10000;
  l_start            NUMBER;

  PROCEDURE varchar2_4000 (p_varchar  IN  VARCHAR2,
                        p_number   IN  NUMBER) AS
    l_varchar  VARCHAR2(4000) := p_varchar;
  BEGIN
    IF p_number < l_recursion_level THEN
      varchar2_4000 (l_varchar, p_number + 1);
    END IF;
  END varchar2_4000;
BEGIN
  l_start := get_used_memory;

  varchar2_4000('1', 0);

  DBMS_OUTPUT.put_line('VARCHAR2_4000  : ' || (get_used_memory - l_start));
END;
/

conn test/test
SET SERVEROUTPUT ON
DECLARE
  l_recursion_level  NUMBER := 10000;
  l_start            NUMBER;

  PROCEDURE varchar2_4001 (p_varchar  IN  VARCHAR2,
                        p_number   IN  NUMBER) AS
    l_varchar  VARCHAR2(4001) := p_varchar;
  BEGIN
    IF p_number < l_recursion_level THEN
      varchar2_4001 (l_varchar, p_number + 1);
    END IF;
  END varchar2_4001;
BEGIN
  l_start := get_used_memory;

  varchar2_4001('1', 0);

  DBMS_OUTPUT.put_line('VARCHAR2_4001  : ' || (get_used_memory - l_start));
END;
/

conn test/test
SET SERVEROUTPUT ON
DECLARE
  l_recursion_level  NUMBER := 10000;
  l_start            NUMBER;

  PROCEDURE varchar2_32767 (p_varchar  IN  VARCHAR2,
                       p_number   IN  NUMBER) AS
    l_varchar  VARCHAR2(32767) := p_varchar;
  BEGIN
    IF p_number < l_recursion_level THEN
      varchar2_32767 (l_varchar, p_number + 1);
    END IF;
  END varchar2_32767;
BEGIN
  l_start := get_used_memory;

  varchar2_32767('1', 0);

  DBMS_OUTPUT.put_line('VARCHAR2_32767 : ' || (get_used_memory - l_start));
END;
/

DROP FUNCTION get_used_memory;

The varchar2_definitions.sql script contains a function to return the amount of PGA memory being used by the session, which is used to take before and after snapshots to calculate the memory allocated for each test.  It also contains blocks with procedures that call themselves recursively, each defining various size VARCHAR2 variables.  The recursion means that the definitions stay in focus allowing us to define enough variables to notice the change in the memory usage.  The results from the script run against an Oracle 10g database are listed below.

SQL> @ varchar2_definintions.sql
Connected.

Function created.

No errors.
Connected.
VARCHAR2_1     : 2686976

PL/SQL procedure successfully completed.

Connected.
VARCHAR2_1999  : 31129600

PL/SQL procedure successfully completed.

Connected.
VARCHAR2_2000  : 31129600

PL/SQL procedure successfully completed.

Connected.
VARCHAR2_4000  : 93585408

PL/SQL procedure successfully completed.

Connected.
VARCHAR2_4001  : 3080192

PL/SQL procedure successfully completed.

Connected.
VARCHAR2_32767 : 3080192

PL/SQL procedure successfully completed.

Function dropped.

The 4001 byte definition requires a little more memory than the 1 byte definition, but as expected the 32767 byte definition requires no more memory than the 4001 byte definition.  If the variable size is reduced to 4000 bytes, more memory is required.  This implies that the optimization level is actually 4001 bytes in Oracle 10g, not 2000 as the document states.

At the time of this writing, the issue has been raised as a bug (Bug no. 4330467) with Oracle support, and the Oracle 10g Release 2 documentation has been amended to reflect this new threshold for VARCHAR2 optimization.  So bigger is truly better for VARCHAR2 variables.

The following section shows how the use of packages can affect response time and shared pool usage.

Using Packages Correctly

The first call to a package causes the whole package to be loaded into memory, reducing the cost and increasing the speed of subsequent calls to procedures and functions within the same package.  Therefore it makes sense to group procedures and functions often used together into a single package so they are all loaded into memory simultaneously.

At the same time, care must be taken not to group unrelated code together.  Imagine a scenario in which a session performs a call to a single small procedure in a massive package.  The whole package must be loaded into memory before the procedure can be executed, resulting in a large waste of memory and disk I/O.

A previous chapter covered the use of package variables to cache global session data.  If used correctly, this can reduce memory usage by reducing duplication of variable definitions. But caching large lookup tables can increase memory requirements greatly.  The trade off between performance gains and memory usage must be assessed on a case-by-case basis.

The next section shows how some issues related to package load times can be managed by pinning objects in the shared pool.

 

This is an excerpt from the bestselling book "Oracle PL/SQL Tuning: Expert Secrets for High Performance Programming" by Dr. Tim Hall, Oracle ACE of the year, 2006.

You can buy the book for only $23.95 (30%-off) when you buy directly from the publisher, and you also get instant access to the code depot of PL/SQL tuning scripts:


 

 
��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational