Skip to main content

Emulating a finally clause in PL/SQL

PL/SQL does not support a finally clause, as many other languages do, including Java. Here's a description of the finally block from the Java SE doc:
The finally block always executes when the try block exits. This ensures that the finally block is executed even if an unexpected exception occurs. But finally is useful for more than just exception handling — it allows the programmer to avoid having cleanup code accidentally bypassed by a return, continue, or break. Putting cleanup code in a finally block is always a good practice, even when no exceptions are anticipated.
The first thing to say regarding PL/SQL and finally is that the need for it in PL/SQL is likely less critical than in other languages, precisely because the PL/SQL runtime engine (and the underlying Oracle Database engine) does most of the clean up for you.

Any variables you declare, cursors you open, types you define inside a block are automatically cleaned up (memory released) when that block terminates.

Still, there are exceptions to this rule, including:

>> Changes to tables are not automatically rolled back or committed when a block terminates.

If you include an autonomous transaction pragma in your block, PL/SQL will "insist" (raise an exception at runtime) if you do not  rollback or commit, but that's different.

>> Elements declared at the package level have session scope. They will not be automatically cleaned up when a block in which they are used terminates.

Here's a very simple demonstration of that fact. I declare a cursor at the package level, open it inside a block, "forget" to close it, and then try to open it again in another block:
CREATE OR REPLACE PACKAGE serial_package AUTHID DEFINER
AS
   CURSOR emps_cur
   IS
      SELECT *
        FROM employees;
END serial_package;
/

BEGIN
   OPEN serial_package.emps_cur;
END;
/

BEGIN
   OPEN serial_package.emps_cur;
END;
/

BEGIN
   OPEN serial_package.emps_cur;
END;
/

ORA-06511: PL/SQL: cursor already open
ORA-06512: at "STEVEN.SERIAL_PACKAGE", line 5
ORA-06512: at line 2
Try it out yourself in LiveSQL.

Since there is no finally clause, you have to take care of things yourself. The best way to do this - and I am not claiming it is optimal - is to create a nested cleanup procedure and invoke that as needed.

Here we go - no more error when I attempt to open the cursor the second time.
CREATE OR REPLACE PACKAGE serial_package AUTHID DEFINER
AS
   CURSOR emps_cur
   IS
      SELECT *
        FROM employees;
END serial_package;
/

CREATE OR REPLACE PROCEDURE use_packaged_cursor AUTHID DEFINER
IS
   PROCEDURE cleanup
   IS
   BEGIN
      /* If called from exception section log the error */
      IF SQLCODE <> 0
      THEN
         /* Uses open source Logger utility:
               https://github.com/OraOpenSource/Logger */
         logger.log_error ('use_packaged_cursor');
      END IF;
      
      IF serial_package.emps_cur%ISOPEN
      THEN
         CLOSE serial_package.emps_cur;
      END IF;
   END cleanup;
BEGIN
   OPEN serial_package.emps_cur;
   
   cleanup;
EXCEPTION
   WHEN NO_DATA_FOUND
   THEN
      /* Clean up but do not re-raise (just to show that you might want
         different behaviors for different exceptions). */
      cleanup;
      
   WHEN OTHERS
   THEN
      cleanup;
      RAISE;
END;
/

BEGIN
   use_packaged_cursor;
END;
/

PL/SQL procedure successfully completed.

BEGIN
   use_packaged_cursor;
END;
/

PL/SQL procedure successfully completed.
(also available in LiveSQL)

Now, I am not, repeat NOT, claiming that this is as good as having a finally clause. I am just saying: this is how you can (have to) achieve a similar effect.

Comments

Popular posts from this blog

Running out of PGA memory with MULTISET ops? Watch out for DISTINCT!

A PL/SQL team inside Oracle made excellent use of nested tables and MULTISET operators in SQL, blending data in tables with procedurally-generated datasets (nested tables).  All was going well when they hit the dreaded: ORA-04030: out of process memory when trying to allocate 2032 bytes  They asked for my help.  The error occurred on this SELECT: SELECT  *    FROM header_tab trx    WHERE (generated_ntab1 SUBMULTISET OF trx.column_ntab)       AND ((trx.column_ntab MULTISET             EXCEPT DISTINCT generated_ntab2) IS EMPTY) The problem is clearly related to the use of those nested tables. Now, there was clearly sufficient PGA for the nested tables themselves. So the problem was in executing the MULTISET-related functionality. We talked for a bit about dropping the use of nested tables and instead doing everything in SQL, to avoid the PGA error. That would, however require lots of work, revamping algorithms, ensuring correctness, you know the score. Then my eyes snagge

How to Pick the Limit for BULK COLLECT

This question rolled into my In Box today: In the case of using the LIMIT clause of BULK COLLECT, how do we decide what value to use for the limit? First I give the quick answer, then I provide support for that answer Quick Answer Start with 100. That's the default (and only) setting for cursor FOR loop optimizations. It offers a sweet spot of improved performance over row-by-row and not-too-much PGA memory consumption. Test to see if that's fast enough (likely will be for many cases). If not, try higher values until you reach the performance level you need - and you are not consuming too much PGA memory.  Don't hard-code the limit value: make it a parameter to your subprogram or a constant in a package specification. Don't put anything in the collection you don't need. [from Giulio Dottorini] Remember: each session that runs this code will use that amount of memory. Background When you use BULK COLLECT, you retrieve more than row with each fetch,

Quick Guide to User-Defined Types in Oracle PL/SQL

A Twitter follower recently asked for more information on user-defined types in the PL/SQL language, and I figured the best way to answer is to offer up this blog post. PL/SQL is a strongly-typed language . Before you can work with a variable or constant, it must be declared with a type (yes, PL/SQL also supports lots of implicit conversions from one type to another, but still, everything must be declared with a type). PL/SQL offers a wide array of pre-defined data types , both in the language natively (such as VARCHAR2, PLS_INTEGER, BOOLEAN, etc.) and in a variety of supplied packages (e.g., the NUMBER_TABLE collection type in the DBMS_SQL package). Data types in PL/SQL can be scalars, such as strings and numbers, or composite (consisting of one or more scalars), such as record types, collection types and object types. You can't really declare your own "user-defined" scalars, though you can define subtypes  from those scalars, which can be very helpful from the p