 |
|
Oracle PL/SQL - Passing Large Data Structures with NOCOPY
Oracle Database Tips by Donald Burleson |
Mike Ault
The PL/SQL runtime engine has two different methods for passing
parameter values between stored procedures and functions, by
value and by reference.
When a parameter is passed by value the PL/SQL runtime
engine copies the actual value of the parameter into the formal
parameter. Any changes made to the parameter inside the procedure
has no effect on the values of the variables that were passed to the
procedure from outside.
When a parameter is passed by reference the runtime
engine sets up the procedure call so that both the actual and the
formal parameters point (reference) the same memory location that
holds the value of the parameter.
By default OUT and IN OUT parameters are passed by value and IN
parameters are passed by reference. When an OUT or IN OUT parameter
is modified inside the procedure the procedure actually only
modifies a copy of the parameter value. Only when the procedure has
finished without exception is the result value copied back to the
formal parameter.
Now, if you pass a large collection as an OUT or an IN OUT
parameter then it will be passed by value, in other words the entire
collection will be copied to the formal parameter when entering the
procedure and back again when exiting the procedure. If the
collection is large this can lead to unnecessary CPU and memory
consumption.
The NOCOPY hint alleviates this problem because you can use it to
instruct the runtime engine to try to pass OUT or IN OUT parameters
by reference instead of by value. For example:
procedure get_customer_orders(
p_customer_id in number,
p_orders out nocopy orders_coll
);
theorders orders_coll;
get_customer_orders(124, theorders);
|
In the absence of the NOCOPY hint the entire orders collection
would have been copied into the theorders variable upon exit from
the procedure. Instead the collection is now passed by reference.
Keep in mind, however, that there is a downside to using NOCOPY.
When you pass parameters to a procedure by reference then any
modifications you perform on the parameters inside the procedure is
done on the same memory location as the actual parameter, so the
modifications are visible. In other words, there is no way to ?undo?
or ?rollback? these modifications, even when an exception is raised
midway. So if an exception is raised inside the procedure the value
of the parameter is ?undefined? and cannot be trusted.
Consider our get_customer_orders example. If the p_orders
parameter was half-filled with orders when an exception was raised,
then upon exit our theorders variable will also be half-filled
because it points to the same memory location as the p_orders
parameter. This downside is most problematic for IN OUT parameters
because if an exception occurs midway then not only is the output
garbage, but you?ve also made the input garbage.
To sum up, a NOCOPY hint can offer a small performance boost, but
you must be careful and know how it affects program behavior, in
particular exception handling.
 |
If you like Oracle tuning, you may enjoy my new book "Oracle
Tuning: The Definitive Reference", over 900 pages
of BC's favorite tuning tips & scripts.
You can buy it direct from the publisher for 30%-off and get
instant access to the code depot of Oracle tuning scripts. |
|