Search This Blog

Saturday, March 5, 2011

Error Handling : Back Trace


PL/SQL offers a powerful and flexible exception architecture. Of course, there is always room for improvement, and in Oracle Database 10g, exception handling takes a big step forward with the introduction of the DBMS_UTILITY.FORMAT_ERROR_BACKTRACE function. This article explores the problem that this function solves and how best to use it.
Who Raised That Exception?
When an exception is raised, one of the most important pieces of information a programmer would like to uncover is the line of code that raised the exception. Prior to Oracle Database 10g, one could obtain this information only by allowing the exception to go unhandled.
Let's revisit the error-handling behavior available to programmers in Oracle9i Database. Consider this simple chain of program calls in Listing 1: procedure proc3 calls proc2 calls proc1 , at which point proc1 raises the NO_DATA_FOUND exception. Notice that there is no error handling in any of the procedures; it is most significantly lacking in the top-level proc3 procedure. If I run proc3 in SQL*Plus, I will see the following results:
ERROR at line 1:
ORA-01403: no data found
ORA-06512: at "SCOTT.PROC1", line 4
ORA-06512: at "SCOTT.PROC2", line 6
ORA-06512: at "SCOTT.PROC3", line 4
ORA-06512: at line 3


Code Listing 1: A stack of procedures
CREATE OR REPLACE PROCEDURE proc1 IS
BEGIN
   DBMS_OUTPUT.put_line ('running proc1');
   RAISE NO_DATA_FOUND;
END;
/
CREATE OR REPLACE PROCEDURE proc2 IS
   l_str VARCHAR2(30) 
         := 'calling proc1';
BEGIN
   DBMS_OUTPUT.put_line (l_str);
   proc1;  
END;
/
CREATE OR REPLACE PROCEDURE proc3 IS
BEGIN
   DBMS_OUTPUT.put_line ('calling proc2');
   proc2;
END;
/


This is the error trace dump of an unhandled exception, and it shows that the error was raised on line 4 of proc1. On the one hand, we should be very pleased with this behavior. Now that we have the line number, we can zoom right in on the problem code and fix it. On the other hand, we got this information by letting the exception go unhandled. In many applications, however, we work to avoid unhandled exceptions.
Let's see what happens when I add an exception section to the proc3 procedure and then display the error information (the simplest form of error logging). Here is the second version of proc3 :
CREATE OR REPLACE PROCEDURE proc3
IS
BEGIN
  DBMS_OUTPUT.put_line ('calling proc2');
  proc2;
EXCEPTION
  WHEN OTHERS THEN
    DBMS_OUTPUT.PUT_LINE (DBMS_UTILITY.FORMAT_ERROR_STACK);
END;
/


Notice that I call DBMS_UTILITY.FORMAT_ERROR_STACK , because it will return the full error message. 
Having compiled the new proc3 , when I run it inside SQL*Plus I see the following output:
SQL> SET SERVEROUTPUT ON
SQL> exec proc3
calling proc2
calling proc1
running proc1
ORA-01403: no data found


In other words, DBMS_UTILITY.FORMAT_ERROR_STACK does not show the full error stack with line numbers; SQLERRM acts in the same manner.
Backtrace to the Rescue
In Oracle Database 10g, Oracle added DBMS_UTILITY.FORMAT_ERROR_BACKTRACE , which can and should be called in your exception handler. It displays the call stack at the point where an exception was raised, even if the function is called in a PL/SQL block in an outer scope from that where the exception was raised. Thus, you can call DBMS_UTILITY.FORMAT_ERROR_BACKTRACE within an exception section at the top level of your stack and still find out where the error was raised deep within the call stack.

Code Listing 2: proc3 rewritten with FORMAT_ERROR_BACKTRACE
CREATE OR REPLACE PROCEDURE proc3
IS
BEGIN
  DBMS_OUTPUT.put_line ('calling proc2');
  proc2;
EXCEPTION
  WHEN OTHERS
  THEN
    DBMS_OUTPUT.put_line ('Error stack at top level:');
    DBMS_OUTPUT.put_line (DBMS_UTILITY.FORMAT_ERROR_BACKTRACE);
END;
/


And now when I run proc3 , I will see the following output:
SQL> SET SERVEROUTPUT ON
SQL> exec proc3
calling proc2
calling proc1
running proc1
Error stack at top level:
ORA-06512: at "SCOTT.PROC1", line 4
ORA-06512: at "SCOTT.PROC2", line 6
ORA-06512: at "SCOTT.PROC3", line 4


In other words, the information that had previously been available only through an unhandled exception is now retrievable from within the PL/SQL code.
Impact of Multiple RAISEs
An exception often occurs deep within the execution stack. If you want that exception to propagate all the way to the outermost PL/SQL block, it will have to be re-raised within each exception handler in the stack of blocks. Listing 3 shows an example of such an occurrence.
Code Listing 3: Re-raising exceptions to the outermost block in the stack
CREATE OR REPLACE PROCEDURE proc1 IS
BEGIN
   DBMS_OUTPUT.put_line ('running proc1');
   RAISE NO_DATA_FOUND;
EXCEPTION
   WHEN OTHERS THEN
      DBMS_OUTPUT.put_line (
         'Error stack in block where raised:');
      DBMS_OUTPUT.put_line (
         DBMS_UTILITY.format_error_backtrace);
      RAISE;
END;
/
CREATE OR REPLACE PROCEDURE proc2
IS
   l_str VARCHAR2 (30) := 'calling proc1';
BEGIN
   DBMS_OUTPUT.put_line (l_str);
   proc1;
END;
/
CREATE OR REPLACE PROCEDURE proc3 IS
BEGIN
   DBMS_OUTPUT.put_line ('calling proc2');
   proc2;
EXCEPTION
   WHEN OTHERS
   THEN
      DBMS_OUTPUT.put_line ('Error stack at top level:');
      DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace);
     
END;
/


When I run the code in Listing 3, I see the following output:
SQL> exec proc3
calling proc2
calling proc1
running proc1
Error stack in block where raised:
ORA-06512: at "SCOTT.PROC1", line 4
Error stack at top level:
ORA-06512: at "SCOTT.PROC1", line 11
ORA-06512: at "SCOTT.PROC2", line 6
ORA-06512: at "SCOTT.PROC3", line 4

Program owner = SCOTT
Program name = PROC1
Line number = 11


When I call the backtrace function within the lowest-level program, it correctly identifies line 4 of proc1 as the line in which the error is first raised. I then re-raise the same exception using the RAISE statement. When the exception propagates to the outermost block, I call the backtrace function again, and this time it shows that the error was raised on line 11 of proc1.
From this behavior, we can conclude that DBMS_UTILITY.FORMAT_ERROR_BACKTRACE shows the trace of execution back to the last RAISE in one's session. As soon as you issue a RAISE of a particular exception or re-raise the current exception, you restart the stack that the backtrace function produces. This means that if you want to take advantage of DBMS_UTILITY.FORMAT_ERROR_BACKTRACE , take one of the following two approaches:
  • Call the backtrace function in the exception section of the block in which the error was raised. This way you have (and can log) that critical line number, even if the exception is re-raised further up in the stack.
  • Avoid exception handlers in intermediate programs in your stack, and call the backtrace function in the exception section of the outermost program in your stack.