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:
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:
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.
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.
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
Post a Comment