|
| 1 | +/* |
| 2 | +The DBMS_UTILITY.format_error_backtrace function, added in Oracle Database 10g Release 2, |
| 3 | +is a critical subprogram to call when logging exceptions. It returns a string that traces |
| 4 | +the error back to the line on which it was raised! Note: if you re-raise an exception as |
| 5 | +it propagates up the stack, you will lose the "original" line number. The back trace function |
| 6 | +always only traces back to the most recently raised exception. |
| 7 | +*/ |
| 8 | + |
| 9 | +CREATE OR REPLACE PROCEDURE proc1 |
| 10 | +IS |
| 11 | +BEGIN |
| 12 | + DBMS_OUTPUT.put_line ('running proc1'); |
| 13 | + RAISE NO_DATA_FOUND; |
| 14 | +END; |
| 15 | +/ |
| 16 | + |
| 17 | +CREATE OR REPLACE PROCEDURE proc2 |
| 18 | +IS |
| 19 | + l_str VARCHAR2 (30) := 'calling proc1'; |
| 20 | +BEGIN |
| 21 | + DBMS_OUTPUT.put_line (l_str); |
| 22 | + proc1; |
| 23 | +END; |
| 24 | +/ |
| 25 | + |
| 26 | +CREATE OR REPLACE PROCEDURE proc3 |
| 27 | +IS |
| 28 | +BEGIN |
| 29 | + DBMS_OUTPUT.put_line ('calling proc2'); |
| 30 | + proc2; |
| 31 | +END; |
| 32 | +/ |
| 33 | + |
| 34 | +-- Without Back Trace.... |
| 35 | +-- The only way to "see" the line number on which the error was raised was to let the exception go unhandled. |
| 36 | +BEGIN |
| 37 | + DBMS_OUTPUT.put_line ('Proc3 -> Proc2 -> Proc1 unhandled'); |
| 38 | + proc3; |
| 39 | +END; |
| 40 | +/ |
| 41 | + |
| 42 | +-- Trap and Display Error Stack (Error Message) |
| 43 | +-- Sure, that works fine and is very good info to have, but the error stack (error message) will contain the line number on which the error was raised! |
| 44 | +BEGIN |
| 45 | + DBMS_OUTPUT.put_line ('Proc3 -> Proc2 -> Proc1 unhandled'); |
| 46 | + proc3; |
| 47 | +EXCEPTION |
| 48 | + WHEN OTHERS |
| 49 | + THEN |
| 50 | + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); |
| 51 | +END; |
| 52 | +/ |
| 53 | + |
| 54 | +-- Add Back Trace to Error Handler |
| 55 | +-- Now we trap the exception at the top level subprogram and view both the error stack and the back trace. |
| 56 | +CREATE OR REPLACE PROCEDURE proc3 |
| 57 | +IS |
| 58 | +BEGIN |
| 59 | + DBMS_OUTPUT.put_line ('calling proc2'); |
| 60 | + proc2; |
| 61 | +EXCEPTION |
| 62 | + WHEN OTHERS |
| 63 | + THEN |
| 64 | + DBMS_OUTPUT.put_line ('Error backtrace at top level:'); |
| 65 | + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); |
| 66 | + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); |
| 67 | +END; |
| 68 | +/ |
| 69 | + |
| 70 | +BEGIN |
| 71 | + DBMS_OUTPUT.put_line ('Proc3 -> Proc2 -> Proc1 backtrace'); |
| 72 | + proc3; |
| 73 | +END; |
| 74 | +/ |
| 75 | + |
| 76 | +-- Re-Raise Exception |
| 77 | +-- I show the back trace, but then re-raise. |
| 78 | +CREATE OR REPLACE PROCEDURE proc1 |
| 79 | +IS |
| 80 | +BEGIN |
| 81 | + DBMS_OUTPUT.put_line ('running proc1'); |
| 82 | + RAISE NO_DATA_FOUND; |
| 83 | +EXCEPTION |
| 84 | + WHEN OTHERS |
| 85 | + THEN |
| 86 | + DBMS_OUTPUT.put_line ('Error backtrace in block where raised:'); |
| 87 | + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); |
| 88 | + RAISE; |
| 89 | +END; |
| 90 | +/ |
| 91 | + |
| 92 | +-- Can't Trace All the Way Back |
| 93 | +-- The call to back trace in this upper-level subprogram no longer finds it way back to the line number of the original exception. That was wiped out with the call to RAISE; |
| 94 | +CREATE OR REPLACE PROCEDURE proc3 |
| 95 | +IS |
| 96 | +BEGIN |
| 97 | + DBMS_OUTPUT.put_line ('calling proc2'); |
| 98 | + proc2; |
| 99 | +EXCEPTION |
| 100 | + WHEN OTHERS |
| 101 | + THEN |
| 102 | + DBMS_OUTPUT.put_line ('Error backtrace at top level:'); |
| 103 | + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); |
| 104 | +END; |
| 105 | +/ |
| 106 | + |
| 107 | +BEGIN |
| 108 | + DBMS_OUTPUT.put_line ('Proc3 -> Proc2 -> Proc1, re-reraise in Proc1'); |
| 109 | + proc3; |
| 110 | +END; |
| 111 | +/ |
| 112 | + |
| 113 | +-- Handle and Raise At Every Level |
| 114 | +-- And see how the back trace changes! |
| 115 | +CREATE OR REPLACE PROCEDURE proc1 |
| 116 | +IS |
| 117 | +BEGIN |
| 118 | + DBMS_OUTPUT.put_line ('running proc1'); |
| 119 | + RAISE NO_DATA_FOUND; |
| 120 | +EXCEPTION |
| 121 | + WHEN OTHERS |
| 122 | + THEN |
| 123 | + DBMS_OUTPUT.put_line ('Error stack in block where raised:'); |
| 124 | + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); |
| 125 | + RAISE; |
| 126 | +END; |
| 127 | +/ |
| 128 | + |
| 129 | +CREATE OR REPLACE PROCEDURE proc2 |
| 130 | +IS |
| 131 | +BEGIN |
| 132 | + DBMS_OUTPUT.put_line ('calling proc1'); |
| 133 | + proc1; |
| 134 | +EXCEPTION |
| 135 | + WHEN OTHERS |
| 136 | + THEN |
| 137 | + RAISE VALUE_ERROR; |
| 138 | +END; |
| 139 | +/ |
| 140 | + |
| 141 | +CREATE OR REPLACE PROCEDURE proc3 |
| 142 | +IS |
| 143 | +BEGIN |
| 144 | + DBMS_OUTPUT.put_line ('calling proc2'); |
| 145 | + proc2; |
| 146 | +EXCEPTION |
| 147 | + WHEN OTHERS |
| 148 | + THEN |
| 149 | + DBMS_OUTPUT.put_line ('Error backtrace at top level:'); |
| 150 | + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); |
| 151 | +END; |
| 152 | +/ |
| 153 | + |
| 154 | +BEGIN |
| 155 | + DBMS_OUTPUT.put_line |
| 156 | + ('Proc3 -> Proc2 -> Proc1, re-reraise in Proc1, raise VE in Proc2'); |
| 157 | + proc3; |
| 158 | +END; |
| 159 | +/ |
0 commit comments