From 6a7d869396399f70d46c603b8d07c91cde8e8d89 Mon Sep 17 00:00:00 2001 From: Steven Feuerstein Date: Tue, 8 Oct 2019 15:59:32 -0400 Subject: [PATCH 1/2] change extension --- .../{raising-exceptions => raising-exceptions.sql} | 0 1 file changed, 0 insertions(+), 0 deletions(-) rename plsql/error-management/{raising-exceptions => raising-exceptions.sql} (100%) diff --git a/plsql/error-management/raising-exceptions b/plsql/error-management/raising-exceptions.sql similarity index 100% rename from plsql/error-management/raising-exceptions rename to plsql/error-management/raising-exceptions.sql From 9734dd5490d3cd4e0b0347f6e70b92b9e527dedc Mon Sep 17 00:00:00 2001 From: Steven Feuerstein Date: Tue, 8 Oct 2019 16:55:35 -0400 Subject: [PATCH 2/2] error files --- .../basic-error-logging-package.sql | 83 +++ .../dbms-utility-backtrace.sql | 159 ++++++ plsql/error-management/emulate-backtrace.sql | 200 +++++++ .../exception-in-declaration.sql | 73 +++ plsql/error-management/exception-init.sql | 204 +++++++ .../handle-exception-where.sql | 138 +++++ .../log-errors-helper-package.sql | 538 ++++++++++++++++++ .../log-errors-with-limit.sql | 86 +++ plsql/error-management/log-errors.sql | 141 +++++ .../no-reraise-no-exception.sql | 90 +++ .../raise-application-error.sql | 54 ++ .../error-management/save-exc-and-forall.sql | 282 +++++++++ .../sqlerrm-format-error-stack.sql | 162 ++++++ plsql/error-management/utl-call-stack.sql | 119 ++++ 14 files changed, 2329 insertions(+) create mode 100644 plsql/error-management/basic-error-logging-package.sql create mode 100644 plsql/error-management/dbms-utility-backtrace.sql create mode 100644 plsql/error-management/emulate-backtrace.sql create mode 100644 plsql/error-management/exception-in-declaration.sql create mode 100644 plsql/error-management/exception-init.sql create mode 100644 plsql/error-management/handle-exception-where.sql create mode 100644 plsql/error-management/log-errors-helper-package.sql create mode 100644 plsql/error-management/log-errors-with-limit.sql create mode 100644 plsql/error-management/log-errors.sql create mode 100644 plsql/error-management/no-reraise-no-exception.sql create mode 100644 plsql/error-management/raise-application-error.sql create mode 100644 plsql/error-management/save-exc-and-forall.sql create mode 100644 plsql/error-management/sqlerrm-format-error-stack.sql create mode 100644 plsql/error-management/utl-call-stack.sql diff --git a/plsql/error-management/basic-error-logging-package.sql b/plsql/error-management/basic-error-logging-package.sql new file mode 100644 index 00000000..fcfe0274 --- /dev/null +++ b/plsql/error-management/basic-error-logging-package.sql @@ -0,0 +1,83 @@ +/* +This very, VERY basic error logging package demonstrations the critical elements: use an autonomous +transaction to write a row to the error log; call the full suite of error-related built-in functions +to gather all generic information; pass in application-specific data for logging. +*/ + +-- Error Logging Table +CREATE TABLE error_log +( + log_id NUMBER GENERATED ALWAYS AS IDENTITY, + created_on TIMESTAMP WITH LOCAL TIME ZONE, + created_by VARCHAR2 (100), + errorcode INTEGER, + callstack VARCHAR2 (4000), + errorstack VARCHAR2 (4000), + backtrace VARCHAR2 (4000), + error_info VARCHAR2 (4000) +); + +-- Totally Minimal API for Error Logging +-- Including an example of providing a name for an un-named system exception +-- raised when a FORALL with SAVE EXCEPTIONS encounters at least one failed statement. +CREATE OR REPLACE PACKAGE error_mgr +IS + failure_in_forall EXCEPTION; + + PRAGMA EXCEPTION_INIT (failure_in_forall, -24381); + + PROCEDURE log_error (app_info_in IN VARCHAR2); +END; +/ + +-- Log the Error! +-- Key points: it's an autonomous transaction, which means the row is inserted into the error +-- log without also committing other unsaved changes in the session (likely part of a business +-- transaction that is in trouble). Plus, I invoke the full set of built-in functions to gather +-- system-level information and write to table. Finally, I add the application-specific information. + +CREATE OR REPLACE PACKAGE BODY error_mgr +IS + PROCEDURE log_error (app_info_in IN VARCHAR2) + IS + PRAGMA AUTONOMOUS_TRANSACTION; + /* Cannot call this function directly in SQL */ + c_code CONSTANT INTEGER := SQLCODE; + BEGIN + INSERT INTO error_log (created_on, + created_by, + errorcode, + callstack, + errorstack, + backtrace, + error_info) + VALUES (SYSTIMESTAMP, + USER, + c_code, + DBMS_UTILITY.format_call_stack, + DBMS_UTILITY.format_error_stack, + DBMS_UTILITY.format_error_backtrace, + app_info_in); + + COMMIT; + END; +END; +/ + +-- Try it Out +DECLARE + l_company_id INTEGER; +BEGIN + IF l_company_id IS NULL + THEN + RAISE VALUE_ERROR; + END IF; +EXCEPTION + WHEN OTHERS + THEN + error_mgr.log_error ('Company ID is NULL - not allowed.'); +END; +/ + +SELECT backtrace, errorstack, callstack FROM error_log; + diff --git a/plsql/error-management/dbms-utility-backtrace.sql b/plsql/error-management/dbms-utility-backtrace.sql new file mode 100644 index 00000000..3fe2e587 --- /dev/null +++ b/plsql/error-management/dbms-utility-backtrace.sql @@ -0,0 +1,159 @@ +/* +The DBMS_UTILITY.format_error_backtrace function, added in Oracle Database 10g Release 2, +is a critical subprogram to call when logging exceptions. It returns a string that traces +the error back to the line on which it was raised! Note: if you re-raise an exception as +it propagates up the stack, you will lose the "original" line number. The back trace function +always only traces back to the most recently raised exception. +*/ + +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; +/ + +-- Without Back Trace.... +-- The only way to "see" the line number on which the error was raised was to let the exception go unhandled. +BEGIN + DBMS_OUTPUT.put_line ('Proc3 -> Proc2 -> Proc1 unhandled'); + proc3; +END; +/ + +-- Trap and Display Error Stack (Error Message) +-- 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! +BEGIN + DBMS_OUTPUT.put_line ('Proc3 -> Proc2 -> Proc1 unhandled'); + proc3; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); +END; +/ + +-- Add Back Trace to Error Handler +-- Now we trap the exception at the top level subprogram and view both the error stack and the back trace. +CREATE OR REPLACE PROCEDURE proc3 +IS +BEGIN + DBMS_OUTPUT.put_line ('calling proc2'); + proc2; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line ('Error backtrace at top level:'); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); +END; +/ + +BEGIN + DBMS_OUTPUT.put_line ('Proc3 -> Proc2 -> Proc1 backtrace'); + proc3; +END; +/ + +-- Re-Raise Exception +-- I show the back trace, but then re-raise. +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 backtrace in block where raised:'); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); + RAISE; +END; +/ + +-- Can't Trace All the Way Back +-- 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; +CREATE OR REPLACE PROCEDURE proc3 +IS +BEGIN + DBMS_OUTPUT.put_line ('calling proc2'); + proc2; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line ('Error backtrace at top level:'); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); +END; +/ + +BEGIN + DBMS_OUTPUT.put_line ('Proc3 -> Proc2 -> Proc1, re-reraise in Proc1'); + proc3; +END; +/ + +-- Handle and Raise At Every Level +-- And see how the back trace changes! +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 +BEGIN + DBMS_OUTPUT.put_line ('calling proc1'); + proc1; +EXCEPTION + WHEN OTHERS + THEN + RAISE VALUE_ERROR; +END; +/ + +CREATE OR REPLACE PROCEDURE proc3 +IS +BEGIN + DBMS_OUTPUT.put_line ('calling proc2'); + proc2; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line ('Error backtrace at top level:'); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); +END; +/ + +BEGIN + DBMS_OUTPUT.put_line + ('Proc3 -> Proc2 -> Proc1, re-reraise in Proc1, raise VE in Proc2'); + proc3; +END; +/ diff --git a/plsql/error-management/emulate-backtrace.sql b/plsql/error-management/emulate-backtrace.sql new file mode 100644 index 00000000..aae1184a --- /dev/null +++ b/plsql/error-management/emulate-backtrace.sql @@ -0,0 +1,200 @@ +/* +UTL_CALL_STACK, introduced in Oracle Database 12c, offers fine-grained access to +the execution call stack, error stack, and backtrace information. Prior to +UTL_CALL_STACK, developers used functions in DBMS_UTILITY to obtain this infromation: +FORMAT_CALL_STACK, FORMAT_ERROR_STACK, FORMAT_ERROR_BACKTRACE. +The my_utl_call_stack offers functions of the same name to replace those functions. +*/ + +CREATE OR REPLACE PACKAGE my_utl_call_stack + AUTHID DEFINER +IS + FUNCTION format_call_stack RETURN VARCHAR2; + FUNCTION format_error_stack RETURN VARCHAR2; + FUNCTION format_error_backtrace RETURN VARCHAR2; + FUNCTION backtrace_to RETURN VARCHAR2; +END; +/ + +CREATE OR REPLACE PACKAGE BODY my_utl_call_stack +IS + FUNCTION format_call_stack + RETURN VARCHAR2 + IS + l_return VARCHAR2 (32767) + := '----- PL/SQL Call Stack -------' + || CHR (10) + || 'Line Object name' + || CHR (10) + || '-------- ----------------------'; + BEGIN + /* 1 is always this function, so ignore it. */ + FOR indx IN 2 .. utl_call_stack.dynamic_depth + LOOP + l_return := + l_return + || case when l_return is not null then CHR (10) end + || LPAD (TO_CHAR (utl_call_stack.unit_line (indx)), 8) + || ' ' + || utl_call_stack.owner (indx) + || '.' + || utl_call_stack.concatenate_subprogram ( + utl_call_stack.subprogram (indx)); + END LOOP; + + RETURN l_return; + END; + + FUNCTION format_error_stack + RETURN VARCHAR2 + IS + l_return VARCHAR2 (32767); + BEGIN + FOR indx IN 1 .. utl_call_stack.error_depth + LOOP + l_return := + l_return + || case when l_return is not null then CHR (10) end + || 'ORA-' + || LPAD (TO_CHAR (utl_call_stack.error_number (indx)), 5, '0') + || ': ' + || utl_call_stack.error_msg (indx); + END LOOP; + + RETURN l_return; + END; + + FUNCTION format_error_backtrace + RETURN VARCHAR2 + IS + l_return VARCHAR2 (32767); + BEGIN + FOR indx IN 1 .. utl_call_stack.backtrace_depth + LOOP + l_return := + l_return + || case when l_return is not null then CHR (10) end + || indx + || ' -> ' + || utl_call_stack.backtrace_unit (indx) + || ' - Line ' + || TO_CHAR (utl_call_stack.backtrace_line (indx)); + END LOOP; + + RETURN l_return; + EXCEPTION + WHEN OTHERS + THEN + IF SQLCODE = -64610 + THEN + /* ORA-64610: bad depth indicator */ + RETURN l_return; + ELSE + RAISE; + END IF; + END; + + FUNCTION backtrace_to + RETURN VARCHAR2 + IS + BEGIN + RETURN utl_call_stack.backtrace_unit (1) + || ' on line ' + || utl_call_stack.backtrace_line (1); + END; +END; +/ + +SET SERVEROUTPUT ON + + +CREATE OR REPLACE PROCEDURE p1 +IS + PROCEDURE nested_in_p1 + IS + BEGIN + DBMS_OUTPUT.put_line ('Call Stack from DBMS_UTILITY'); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_call_stack); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line ('Call Stack from UTL_CALL_STACK'); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line (my_utl_call_stack.format_call_stack); + RAISE NO_DATA_FOUND; + END; +BEGIN + nested_in_p1; +END; +/ + +CREATE OR REPLACE PACKAGE pkg + AUTHID DEFINER +IS + PROCEDURE p; +END; +/ + +CREATE OR REPLACE PACKAGE BODY pkg +IS + PROCEDURE p + IS + BEGIN + p1; + END; +END; +/ + +CREATE OR REPLACE PROCEDURE p2 + AUTHID DEFINER +IS +BEGIN + pkg.p; +END; +/ + +CREATE OR REPLACE PROCEDURE p3 + AUTHID DEFINER +IS +BEGIN + p2; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line ('-'); + + DBMS_OUTPUT.put_line ('Error Stack from DBMS_UTILTY'); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + + DBMS_OUTPUT.put_line ('Error Stack from UTL_CALL_STACK'); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line (my_utl_call_stack.format_error_stack); + + DBMS_OUTPUT.put_line ('-'); + + DBMS_OUTPUT.put_line ('Backtrace from DBMS_UTILITY'); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line ('Backtrace from UTL_CALL_STACK'); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line (my_utl_call_stack.format_error_backtrace); + DBMS_OUTPUT.put_line ('-'); + DBMS_OUTPUT.put_line ('Backtrace to: ' || my_utl_call_stack.backtrace_to()); + RAISE; +END; +/ + +BEGIN + p3; + +/* Trapping the exception because if I do not, LiveSQL will not + show the contents of the DBMS_OUTPUT buffer. +*/ + +EXCEPTION WHEN OTHERS + THEN + NULL; +END; +/ + diff --git a/plsql/error-management/exception-in-declaration.sql b/plsql/error-management/exception-in-declaration.sql new file mode 100644 index 00000000..49e8e889 --- /dev/null +++ b/plsql/error-management/exception-in-declaration.sql @@ -0,0 +1,73 @@ +/* +This sometimes surprises a developer new to PL/SQL. The exception section of a +PL/SQL block can only possibly handle an exception raised in the executable section. +An exception raised in the declaration section (in an attempt to assign a default +value to a variable or constant) always propagates out unhandled to the enclosing block. +*/ + +-- Error Raised in Declaration Section - Not Handled +DECLARE + aname VARCHAR2 (5) := 'Big String'; +BEGIN + DBMS_OUTPUT.put_line (aname); +EXCEPTION + WHEN VALUE_ERROR + THEN + DBMS_OUTPUT.put_line ('Handled!'); +END; +/ + +-- Trapped in Outer Block +-- Can't trap the exception in the same block (when raised in the declaration section), +-- but certainly it is trappable in an outer block. +BEGIN + DECLARE + aname VARCHAR2 (5) := 'Big String'; + BEGIN + DBMS_OUTPUT.put_line (aname); + EXCEPTION + WHEN VALUE_ERROR + THEN + DBMS_OUTPUT.put_line ('Handled!'); + END; +EXCEPTION + WHEN VALUE_ERROR + THEN + DBMS_OUTPUT.put_line ('Handled in outer block!'); +END; +/ + +-- What's a Developer to Do? Initialize Later! +/* +Generally, I recommend that you created a nested subprogram called +"initialize" and move all of your initialization into that procedure. +Then call it as the first line in your "main" subprogram. That way, +an exception raised when assigning a value can be trapped in that +subprogram's exception section. +*/ + +BEGIN + DECLARE + aname VARCHAR2 (5); + + PROCEDURE initialize + IS + BEGIN + aname := 'Big String'; -- pkg.func (); + END; + BEGIN + initialize; + + DBMS_OUTPUT.put_line (aname); + EXCEPTION + WHEN VALUE_ERROR + THEN + DBMS_OUTPUT.put_line ('Handled!'); + END; +EXCEPTION + WHEN VALUE_ERROR + THEN + DBMS_OUTPUT.put_line ('Handled in outer block!'); +END; +/ + diff --git a/plsql/error-management/exception-init.sql b/plsql/error-management/exception-init.sql new file mode 100644 index 00000000..63ec2608 --- /dev/null +++ b/plsql/error-management/exception-init.sql @@ -0,0 +1,204 @@ +/* +Oracle Database pre-defines a number of exceptions for common ORA errors, +such as NO_DATA_FOUND and VALUE_ERROR. But there a whole lot more errors for +which there is no pre-defined name. And some of these can be encountered quite +often in code. The key thing for developers is to avoid hard-coding these error +numbers in your code. Instead, use the EXCEPTION_INIT pragma to assign a name +for that error code, and then handle it by name. +*/ + +-- Give a Name to an Unnamed Error +-- Oracle will never create pre-defined exceptions for all the ORA errors. + +So if you need to trap one of these in your code, create your OWN named exception and associate it to the desired error code with the EXCEPTION_INIT pragma. Then you can angle it by name. +DECLARE + e_bad_date_format EXCEPTION; + PRAGMA EXCEPTION_INIT (e_bad_date_format, -1830); +BEGIN + DBMS_OUTPUT.put_line (TO_DATE ('2010 10 10 44:55:66', 'YYYSS')); +EXCEPTION + WHEN e_bad_date_format + THEN + DBMS_OUTPUT.put_line ('Bad date format'); +END; +/ + +-- Pragma Expects a Negative Integer +-- Both SAVE EXCEPTIONS and LOG ERRORS record error codes as unsigned integers. +-- But SQLERRM and this pragma definitely believe that an Oracle error code is negative. + +DECLARE + my_exception EXCEPTION; + PRAGMA EXCEPTION_INIT (my_exception, 1830); +BEGIN + RAISE my_exception; +END; +/ + +-- Special Case: Can't EXCEPTION_INIT -1403 +-- The NO_DATA_FOUND error actually has two numbers associated with it: 100 (ANSI standard) +-- and -1403 (Oracle error). You can't associate an exception with -1403. Only 100. Not sure why you'd want to anyway. + +DECLARE + my_exception EXCEPTION; + PRAGMA EXCEPTION_INIT (my_exception, -1403); +BEGIN + RAISE my_exception; +END; +/ + +-- This One Works +DECLARE + my_exception EXCEPTION; + PRAGMA EXCEPTION_INIT (my_exception, 100); +BEGIN + RAISE my_exception; +END; +/ + +-- Distinguish Between Different Application-Specific Errors +-- When you define your own exception, the error code is always by default set to 1 +-- and the error message is "User-defined exception". If you want to distinguish +-- between those exceptions with SQLCODE, use the EXCEPTION_INIT pragma, and +-- select your error code between -20999 and -20000. Once you do that, you will +-- need to use RAISE_APPLICATION_ERROR to raise the exception, if you want to associate +-- an error message with the error code. + +DECLARE + e_bad_data EXCEPTION; + + e_bal_too_low EXCEPTION; + PRAGMA EXCEPTION_INIT (e_bal_too_low, -20100); + + e_account_closed EXCEPTION; + en_account_closed PLS_INTEGER := -20200; + PRAGMA EXCEPTION_INIT (e_account_closed, -20200); +BEGIN + BEGIN + RAISE e_bad_data; + EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (SQLCODE); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + END; + + BEGIN + RAISE e_bal_too_low; + EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (SQLCODE); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + END; + + BEGIN + RAISE e_account_closed; + EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (SQLCODE); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + END; + + /* Now with RAISE_APPLICATION_ERROR */ + BEGIN + RAISE_APPLICATION_ERROR (en_account_closed, 'Account has been closed.'); + EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (SQLCODE); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + END; +END; +/ + +CREATE TABLE employees AS SELECT * FROM hr.employees ; + +-- The Bad Way: Hard-Coding the Error Code in Exception Section +-- The problem with writing code like WHEN OTHERS THEN IF SQLCODE = -24381 ..." +-- is that Oracle might change the error code at some point. No, you can trust +-- that -24381 will ALWAYS be the error code when a FORALL with SAVE EXCEPTIONS fails. +-- The problem is that when you write code like this, you are saying to anyone coming +-- along later: "Ha, ha! I know all about obscure Oracle error codes, and you don't." +-- In other words, the code makes people who are responsible for maintaining feel stupid. +-- It raises questions in their minds and makes them uncomfortable. + +DECLARE + TYPE namelist_t IS TABLE OF VARCHAR2 (1000); + + enames_with_errors namelist_t + := namelist_t ('ABC', RPAD ('BIGBIGGERBIGGEST', 1000, 'ABC'), 'DEF'); +BEGIN + FORALL indx IN 1 .. enames_with_errors.COUNT SAVE EXCEPTIONS + UPDATE employees + SET first_name = enames_with_errors (indx); +EXCEPTION + WHEN OTHERS + THEN + IF SQLCODE = -24381 + THEN + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + DBMS_OUTPUT.put_line ( + 'Number of failed statements = ' || SQL%BULK_EXCEPTIONS.COUNT); + ELSE + RAISE; + END IF; +END; +/ + +-- A Better Way to Go: Declare Exception +-- This is much better: I declare a local exception, associate it with -24381, then use +-- that exception in the WHEN clause. The problem with this code is that the exception is +-- declared locally, but I will/might use FORALL in many places in my code. + +DECLARE + failure_in_forall EXCEPTION; + PRAGMA EXCEPTION_INIT (failure_in_forall, -24381); + + TYPE namelist_t IS TABLE OF VARCHAR2 (1000); + + enames_with_errors namelist_t + := namelist_t ('ABC', RPAD ('BIGBIGGERBIGGEST', 1000, 'ABC'), 'DEF'); +BEGIN + FORALL indx IN 1 .. enames_with_errors.COUNT SAVE EXCEPTIONS + UPDATE employees + SET first_name = enames_with_errors (indx); +EXCEPTION + WHEN failure_in_forall + THEN + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + DBMS_OUTPUT.put_line ( + 'Number of failed statements = ' || SQL%BULK_EXCEPTIONS.COUNT); +END; +/ + +-- The Best Approach: Declare Exception in Package Specification +-- Now, any schema with EXECUTE authority on this package can reference the exception. +CREATE OR REPLACE PACKAGE app_errs_pkg +IS + failure_in_forall EXCEPTION; + PRAGMA EXCEPTION_INIT (failure_in_forall, -24381); +END; +/ + +-- No Need for Local Declaration of Exception +-- I just reference the exception as package.exception_name in my WHEN clause. Nice. +DECLARE + TYPE namelist_t IS TABLE OF VARCHAR2 (1000); + + enames_with_errors namelist_t + := namelist_t ('ABC', RPAD ('BIGBIGGERBIGGEST', 1000, 'ABC'), 'DEF'); +BEGIN + FORALL indx IN 1 .. enames_with_errors.COUNT SAVE EXCEPTIONS + UPDATE employees + SET first_name = enames_with_errors (indx); +EXCEPTION + WHEN app_errs_pkg.failure_in_forall + THEN + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + DBMS_OUTPUT.put_line ( + 'Number of failed statements = ' || SQL%BULK_EXCEPTIONS.COUNT); +END; +/ + diff --git a/plsql/error-management/handle-exception-where.sql b/plsql/error-management/handle-exception-where.sql new file mode 100644 index 00000000..c1bb6246 --- /dev/null +++ b/plsql/error-management/handle-exception-where.sql @@ -0,0 +1,138 @@ +/* +Where should you handle an exception? In each subprogram? Only at the top-level +subprogram or anonymous block? I suggest that including exception sections in many +"deep" subprograms is critical if you want to capture your application state +(values of local variables or parameters, contents of tables, etc.) at the +time of the error. Note: all database objects start with "plch" indicating that this +script was taken from the Oracle Dev Gym (formerly known as the PL/SQL Challenge): + +https://devgym.oracle.com +*/ + +-- Create "Scratchpad" Package +-- I include this package to demonstrate how you *could* use a "global" variable +-- to hold the values of local variables in deeply nested subprogram calls, to then log at a higher level. +CREATE OR REPLACE PACKAGE plch_pkg +IS + g_save_value NUMBER; +END; +/ + +-- Very Simple Error Logger +-- Regardless of how you implement it, you should have a generalized error logging +-- procedure that all developers on the team can invoke. Normally it would be an +-- autonomous transaction procedure and insert into a table! I encourage you check +-- out the Logger utility at oraopensource.com. +CREATE OR REPLACE PROCEDURE plch_log_error ( + data_in IN VARCHAR2) +IS +BEGIN + /* Can and SHOULD also call: + - DBMS_UTILITY.FORMAT_ERROR_STACK + - DBMS_UTILITY.FORMAT_ERROR_BACKTRACE + - (12.1) UTL_CALL_STACK subprograms + + But this gets the point across. + */ + DBMS_OUTPUT.put_line ( + SQLCODE || '-' || data_in); +END; +/ + +-- Procedure with Local Variable +-- So, like many of your subprograms, my procedure has a parameter and a +-- local variable. If something goes wrong in this procedure, I'd really like +-- to know what the values of those elements are. After all, it is likely that +-- they play a role in the error. So when I log the error, I pass the local +-- variable. Then I re-raise to indicate to the invoking block that there is a problem. +CREATE OR REPLACE PROCEDURE plch_do_stuff ( + value_in IN NUMBER) +IS + l_value NUMBER := value_in * 100; +BEGIN + RAISE VALUE_ERROR; +EXCEPTION + WHEN OTHERS + THEN + plch_log_error ('Value=' || l_value); + RAISE; +END; +/ + +-- Verify Local Variable Value Accessible +-- Now I invoke my subprogram. Notice that I can see the value of my local variable. +-- Excellent! So easy to diagnose the problem now. Or, at least, a little easier. :-) +BEGIN + plch_do_stuff (10); + +/* Note: + I include this exception handler so you can see the DBMS_OUTPUT text. + Otherwise, LiveSQL (currently) only displays the error that went unhanded. +*/ +EXCEPTION + WHEN OTHERS THEN NULL; +END; +/ + +-- Procedure Saves State to Global Variable +-- Now let's take a look at a different approach. I do not log the error +-- "locally" in my procedure. Instead, I copy the local value to a "global" +-- in a package specification. Then I re-raise. +CREATE OR REPLACE PROCEDURE plch_do_stuff ( + value_in IN NUMBER) +IS + l_value NUMBER := value_in * 100; +BEGIN + RAISE VALUE_ERROR; +EXCEPTION + WHEN OTHERS + THEN + plch_pkg.g_save_value := l_value; + RAISE; +END; +/ + +-- Global Value Available in Invoking Block +-- Now at my higher-level block, I can trap the exception, and log the error, +-- accessing my global value. This works, but it is not a dependable approach. +-- What if A calls B calls C and: C fails and writes to plch_pkg.g_save_value, +-- but then B also writes to plch_pkg.g_save_value, changing the value? +-- By the time you get up to A, the value from C is lost. And then of course +-- you get into issues like: should I declare a separate global for each data +-- type? This approach is messy and best avoided. +BEGIN + plch_do_stuff (10); +EXCEPTION + WHEN OTHERS + THEN + plch_log_error ('Value=' || plch_pkg.g_save_value); +END; +/ + +-- No Local Exception Section +-- Now suppose I recompile my procedure - without any exception section at all. +-- This is the approach suggested by others. Just have a single exception handler +-- at the top level, trap any error there, and log whatever information you can. +CREATE OR REPLACE PROCEDURE plch_do_stuff ( + value_in IN NUMBER) +IS + l_value NUMBER := value_in * 100; +BEGIN + RAISE VALUE_ERROR; +END; +/ + +-- What Can I Log "Up" Here? +-- So now I trap the exception at the top level - but I have lost the +-- plch_do_stuff.l_value variable's value. I can only log "generic" information +-- about the state of my application through calls to DBMS_UTILITY functions or +-- UTL_CALL_STACK (12.1). That's good information - critical - but often not enough. +BEGIN + plch_do_stuff (10); +EXCEPTION + WHEN OTHERS + THEN + plch_log_error ('Value=?'); +END; +/ + diff --git a/plsql/error-management/log-errors-helper-package.sql b/plsql/error-management/log-errors-helper-package.sql new file mode 100644 index 00000000..194559e4 --- /dev/null +++ b/plsql/error-management/log-errors-helper-package.sql @@ -0,0 +1,538 @@ + +/* +The LOG ERRORS feature allows you to suppress errors at the row level in DML statements. +Instead of raising the error, the error information is written to a log table (generated by a call +to DBMS_ERRLOG.CREATE_ERROR_LOG). But the design of the log table leaves a few things to +be desired (doesn't include when the error occurred, "who" did it, and where in the code stack +the statement was executed). This package helps "fill the gap" by creating the log table, +altering it to add key columns and a trigger to set their values, and generate a package +to make it easier to manage the table. +*/ + +CREATE OR REPLACE PACKAGE pkg1 AUTHID DEFINER +IS + PROCEDURE proc1; +END pkg1; +/ + +-- Down to Subprogram Name! +-- The FORMAT_CALL_STACK function in DBMS_UTILITY only shows you the name of the program unit +-- in the call stack (i.e., the package name, but not the function within the package). +-- UTL_CALL_STACK only shows you the name of the package subprogram, but even the name of +-- nested (local) subprograms within those. VERY COOL! +CREATE OR REPLACE PACKAGE BODY pkg1 +IS + PROCEDURE proc1 + IS + PROCEDURE nested_in_proc1 + IS + BEGIN + DBMS_OUTPUT.put_line ( + '*** "Traditional" Call Stack using FORMAT_CALL_STACK'); + + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_call_stack); + + DBMS_OUTPUT.put_line ( + '*** Fully Qualified Nested Subprogram vis UTL_CALL_STACK'); + + DBMS_OUTPUT.put_line ( + utl_call_stack.concatenate_subprogram ( + utl_call_stack.subprogram (1))); + END; + BEGIN + nested_in_proc1; + END; +END pkg1; +/ + +-- The Call Stack Output +-- First, you will see the "Traditional" formatted call stack, next the fully-qualified name of the top of that stack, culled out of the "mess" with the UTL_CALL_STACK API. +BEGIN + pkg1.proc1; +END; +/ + +-- Backtrace Info, Too! +-- Need to get the line number on which an error was raised? You can stick with DBMS_UTILITY.FORMAT_ERROR_BACKTRACE, sure. But now you can also opt for the UTL_CALL_STACK backtrace functions! +CREATE OR REPLACE FUNCTION backtrace_to + RETURN VARCHAR2 AUTHID DEFINER +IS +BEGIN + RETURN + utl_call_stack.backtrace_unit ( + utl_call_stack.backtrace_depth) + || ' line ' + || utl_call_stack.backtrace_line ( + utl_call_stack.backtrace_depth); +END; +/ + +CREATE OR REPLACE PACKAGE pkg1 AUTHID DEFINER +IS + PROCEDURE proc1; + + PROCEDURE proc2; +END; +/ + +CREATE OR REPLACE PACKAGE BODY pkg1 +IS + PROCEDURE proc1 + IS + PROCEDURE nested_in_proc1 + IS + BEGIN + RAISE VALUE_ERROR; + END; + BEGIN + nested_in_proc1; + END; + + PROCEDURE proc2 + IS + BEGIN + proc1; + EXCEPTION + WHEN OTHERS + THEN + RAISE NO_DATA_FOUND; + END; +END pkg1; +/ + +CREATE OR REPLACE PROCEDURE proc3 AUTHID DEFINER +IS +BEGIN + pkg1.proc2; +END; +/ + +BEGIN + proc3; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (backtrace_to); +END; +/ + +-- Package Specification +-- The create_objects procedure (overloaded) calls the built-in DBMS_ERRLOG.create_error_log procedure, and then takes some other steps. +CREATE OR REPLACE PACKAGE dbms_errlog_helper + AUTHID CURRENT_USER +/* +| File name: dbms_errlog_helper.sql +| +| Author: Steven Feuerstein, steven.feuerstein@oracle.com +| +| Overview: Run this program to create a database error log table +| (via the DBMS_ERRLOG mechanism) so that you can log errors for +| this table and continue processing DML statements. It will also +| generate a helper package for the specified table that you can +| use after running the DML statement(s) so you can easily view +| and manage any errors that are raised. Finally, it automatically +| adds audit columns created_by and created_on so you can keep +| track of where and when the errors were added, and a trigger is +| defined on the table to populate those columns. +| +| TO DO +| * Execute grants on error log table so that anyone who can make +| a change to the DML table can insert into the log table. +| +| Modification History: +| Date Who What +| +| Dec 2008 SF Stop creating the trigger with a static name. +| Instead, the name varies by the table name. +| Add option to clear error log after retrieval. +| +| Mar 2008 SF Create audit columns, create trigger, +| change to AUTHID CURRENT_USER. +| +| Feb 2008 SF Convert to package that offers ability +| to immediately compile package rather +| than return CLOBS. +| +| Oct 3 2007 SF Carve out from q$error_manager to make it +| available as a stand-alone utility. +| +*/ +IS + PROCEDURE create_objects (dml_table_name VARCHAR2 + , err_log_table_name VARCHAR2 DEFAULT NULL + , err_log_table_owner VARCHAR2 DEFAULT NULL + , err_log_table_space VARCHAR2 DEFAULT NULL + , skip_unsupported BOOLEAN DEFAULT FALSE + , overwrite_log_table BOOLEAN DEFAULT TRUE + , err_log_package_name VARCHAR2 DEFAULT NULL + , err_log_package_spec OUT DBMS_SQL.varchar2s + , err_log_package_body OUT DBMS_SQL.varchar2s + ); + + PROCEDURE create_objects (dml_table_name VARCHAR2 + , err_log_table_name VARCHAR2 DEFAULT NULL + , err_log_table_owner VARCHAR2 DEFAULT NULL + , err_log_table_space VARCHAR2 DEFAULT NULL + , skip_unsupported BOOLEAN DEFAULT FALSE + , overwrite_log_table BOOLEAN DEFAULT TRUE + , err_log_package_name VARCHAR2 DEFAULT NULL + , err_log_package_spec OUT VARCHAR2 + , err_log_package_body OUT VARCHAR2 + ); + + PROCEDURE create_objects (dml_table_name VARCHAR2 + , err_log_table_name VARCHAR2 DEFAULT NULL + , err_log_table_owner VARCHAR2 DEFAULT NULL + , err_log_table_space VARCHAR2 DEFAULT NULL + , skip_unsupported BOOLEAN DEFAULT FALSE + , overwrite_log_table BOOLEAN DEFAULT TRUE + , err_log_package_name VARCHAR2 DEFAULT NULL + ); +END dbms_errlog_helper; +/ + +-- Package Body +-- I love using dynamic SQL to perform tasks like this. Of course, you'd have to be very careful if this was running in production (and users could supply text), but this is a developer utility. So don't worry, be happy! +CREATE OR REPLACE PACKAGE BODY dbms_errlog_helper +IS + /* + | Overview: Run this program to create a database error log table + | (via the DBMS_ERRLOG mechanism) so that you can log errors for + | this table and continue processing DML statements. It will also + | generate a helper package for the specified table that you can + | use after running the DML statement(s) so you can easily view + | and manage any errors that are raised + | + | Author(s): Steven Feuerstein + | + | Modification History: + | Date Who What + | Feb 2008 SF Convert to package that offers ability + | to immediately compile package rather + | return CLOBS.A + | Oct 3 2007 SF Carve out from q$error_manager to make it + | available as a stand-alone utility. + | + */ + + SUBTYPE maxvarchar2_t IS VARCHAR2 (32767); + + PROCEDURE create_objects (dml_table_name VARCHAR2 + , err_log_table_name VARCHAR2 DEFAULT NULL + , err_log_table_owner VARCHAR2 DEFAULT NULL + , err_log_table_space VARCHAR2 DEFAULT NULL + , skip_unsupported BOOLEAN DEFAULT FALSE + , overwrite_log_table BOOLEAN DEFAULT TRUE + , err_log_package_name VARCHAR2 DEFAULT NULL + , err_log_package_spec OUT DBMS_SQL.varchar2s + , err_log_package_body OUT DBMS_SQL.varchar2s + ) + IS + PRAGMA AUTONOMOUS_TRANSACTION; + c_package_name CONSTANT maxvarchar2_t + := SUBSTR (NVL (err_log_package_name, 'ELP$_' || dml_table_name) + , 1 + , 30 + ) ; + c_errlog_table_name CONSTANT maxvarchar2_t + := SUBSTR (NVL (err_log_table_name, 'ERR$_' || dml_table_name) + , 1 + , 30 + ) ; + c_qual_errlog_table_name CONSTANT maxvarchar2_t + := CASE + WHEN err_log_table_owner IS NULL THEN NULL + ELSE err_log_table_owner || '.' + END + || c_errlog_table_name ; + l_spec DBMS_SQL.varchar2s; + l_body DBMS_SQL.varchar2s; + + PROCEDURE create_error_log + IS + BEGIN + IF overwrite_log_table + THEN + BEGIN + EXECUTE IMMEDIATE 'DROP TABLE ' || c_qual_errlog_table_name; + EXCEPTION + WHEN OTHERS + THEN + NULL; + END; + END IF; + + /* + Create the error log; any errors raised by this program will + terminate the rest of the processing of this helper program. + */ + DBMS_ERRLOG.create_error_log ( + dml_table_name => dml_table_name + , err_log_table_name => err_log_table_name + , err_log_table_owner => err_log_table_owner + , err_log_table_space => err_log_table_space + , skip_unsupported => skip_unsupported + ); + + /* Alter the error log table to add audit columns. */ + EXECUTE IMMEDIATE 'ALTER TABLE ' || NVL (err_log_table_owner, USER) + || '.' || c_errlog_table_name || ' ADD created_by VARCHAR2(30)'; + + EXECUTE IMMEDIATE 'ALTER TABLE ' || NVL (err_log_table_owner, USER) + || '.' || c_errlog_table_name || ' ADD created_on DATE'; + + /* Add Call Stack: Thanks, IFMC! */ + EXECUTE IMMEDIATE 'ALTER TABLE ' || NVL (err_log_table_owner, USER) + || '.' || c_errlog_table_name || ' ADD call_stack VARCHAR2(4000)'; + + /* Add the trigger to update these columns. */ + EXECUTE IMMEDIATE 'CREATE OR REPLACE TRIGGER ' + || SUBSTR (dml_table_name || '$BEF_EL', 1, 30) + || ' BEFORE INSERT OR UPDATE ON ' || NVL (err_log_table_owner, USER) + || '.' || c_errlog_table_name || ' FOR EACH ROW BEGIN :NEW.created_by := USER; ' + || ' :NEW.created_on := SYSDATE; ' || ' :NEW.call_stack := ' + || 'SUBSTR (dbms_utility.Format_call_stack (), 1, 4000); END;'; + END create_error_log; + + PROCEDURE generate_spec (package_name_in IN VARCHAR2 + , code_out OUT DBMS_SQL.varchar2s + ) + IS + PROCEDURE add_line (line_in IN VARCHAR2) + IS + BEGIN + l_spec (l_spec.COUNT + 1) := line_in; + END add_line; + BEGIN + add_line ('CREATE OR REPLACE PACKAGE ' || c_package_name || ' IS '); + add_line( 'SUBTYPE error_log_r IS ' + || c_qual_errlog_table_name + || '%ROWTYPE;'); + add_line( 'TYPE error_log_tc IS TABLE OF ' + || c_qual_errlog_table_name + || '%ROWTYPE;'); + add_line ('PROCEDURE clear_error_log;'); + add_line ('FUNCTION error_log_contents ('); + add_line (' ORA_ERR_NUMBER$_IN IN PLS_INTEGER DEFAULT NULL'); + add_line (', ORA_ERR_OPTYP$_IN IN VARCHAR2 DEFAULT NULL'); + add_line (', ORA_ERR_TAG$_IN IN VARCHAR2 DEFAULT NULL'); + add_line (', where_in IN VARCHAR2 DEFAULT NULL'); + add_line (', preserve_log_in IN BOOLEAN DEFAULT TRUE'); + add_line (') RETURN error_log_tc;'); + -- add_line ('PROCEDURE dump_error_log;'); + add_line ('END ' || c_package_name || ';'); + code_out := l_spec; + END generate_spec; + + PROCEDURE generate_body (package_name_in IN VARCHAR2 + , code_out OUT DBMS_SQL.varchar2s + ) + IS + PROCEDURE add_line (line_in IN VARCHAR2) + IS + BEGIN + l_body (l_body.COUNT + 1) := line_in; + END add_line; + BEGIN + add_line ( + 'CREATE OR REPLACE PACKAGE BODY ' || c_package_name || ' IS ' + ); + add_line ('PROCEDURE clear_error_log'); + add_line ('IS PRAGMA AUTONOMOUS_TRANSACTION; BEGIN '); + add_line ('DELETE FROM ' || c_qual_errlog_table_name || '; COMMIT;'); + add_line ('END clear_error_log;'); + add_line ('FUNCTION error_log_contents ('); + add_line (' ORA_ERR_NUMBER$_IN IN PLS_INTEGER DEFAULT NULL'); + add_line (', ORA_ERR_OPTYP$_IN IN VARCHAR2 DEFAULT NULL'); + add_line (', ORA_ERR_TAG$_IN IN VARCHAR2 DEFAULT NULL'); + add_line (', where_in IN VARCHAR2 DEFAULT NULL'); + add_line (', preserve_log_in IN BOOLEAN DEFAULT TRUE'); + add_line (') RETURN error_log_tc'); + add_line (' IS '); + add_line('l_query VARCHAR2 (32767) + := ''SELECT * FROM ' + || c_qual_errlog_table_name + || ' WHERE ( ora_err_number$ LIKE :ora_err_number$_in + OR :ora_err_number$_in IS NULL'); + add_line(') AND ( ora_err_optyp$ LIKE :ora_err_optyp$_in + OR :ora_err_optyp$_in IS NULL )'); + add_line('AND (ora_err_tag$ LIKE :ora_err_tag$_in OR :ora_err_tag$_in IS NULL)'' + || CASE WHEN where_in IS NULL'); + add_line('THEN NULL ELSE '' AND '' || REPLACE (where_in, '''''''', '''''''''''') END; + l_log_rows error_log_tc;'); + add_line ( + 'BEGIN EXECUTE IMMEDIATE l_query BULK COLLECT INTO l_log_rows' + ); + add_line('USING ORA_ERR_NUMBER$_IN, ORA_ERR_NUMBER$_IN, + ORA_ERR_OPTYP$_IN, ORA_ERR_OPTYP$_IN, + ORA_ERR_TAG$_IN, ORA_ERR_TAG$_IN; RETURN l_log_rows;'); + add_line ('IF NOT preserve_log_in THEN clear_error_log(); END IF;'); + add_line('EXCEPTION WHEN OTHERS THEN + DBMS_OUTPUT.put_line (''Error retrieving log contents for :''); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + DBMS_OUTPUT.put_line (l_query); + RAISE;'); + add_line ('END error_log_contents; END ' || c_package_name || ';'); + code_out := l_body; + END generate_body; + BEGIN + create_error_log; + generate_spec (c_package_name, err_log_package_spec); + generate_body (c_package_name, err_log_package_body); + END create_objects; + + PROCEDURE create_objects (dml_table_name VARCHAR2 + , err_log_table_name VARCHAR2 DEFAULT NULL + , err_log_table_owner VARCHAR2 DEFAULT NULL + , err_log_table_space VARCHAR2 DEFAULT NULL + , skip_unsupported BOOLEAN DEFAULT FALSE + , overwrite_log_table BOOLEAN DEFAULT TRUE + , err_log_package_name VARCHAR2 DEFAULT NULL + , err_log_package_spec OUT VARCHAR2 + , err_log_package_body OUT VARCHAR2 + ) + IS + l_spec DBMS_SQL.varchar2s; + l_body DBMS_SQL.varchar2s; + l_spec_string maxvarchar2_t; + l_body_string maxvarchar2_t; + BEGIN + create_objects (dml_table_name => dml_table_name + , err_log_table_name => err_log_table_name + , err_log_table_owner => err_log_table_owner + , err_log_table_space => err_log_table_space + , skip_unsupported => skip_unsupported + , overwrite_log_table => overwrite_log_table + , err_log_package_name => err_log_package_name + , err_log_package_spec => l_spec + , err_log_package_body => l_body + ); + + FOR indx IN 1 .. l_spec.COUNT + LOOP + l_spec_string := + CASE + WHEN indx = 1 THEN l_spec (indx) + ELSE l_spec_string || CHR (10) || l_spec (indx) + END; + END LOOP; + + FOR indx IN 1 .. l_body.COUNT + LOOP + l_body_string := + CASE + WHEN indx = 1 THEN l_body (indx) + ELSE l_body_string || CHR (10) || l_body (indx) + END; + END LOOP; + + err_log_package_spec := l_spec_string; + err_log_package_body := l_body_string; + END create_objects; + + PROCEDURE create_objects (dml_table_name VARCHAR2 + , err_log_table_name VARCHAR2 DEFAULT NULL + , err_log_table_owner VARCHAR2 DEFAULT NULL + , err_log_table_space VARCHAR2 DEFAULT NULL + , skip_unsupported BOOLEAN DEFAULT FALSE + , overwrite_log_table BOOLEAN DEFAULT TRUE + , err_log_package_name VARCHAR2 DEFAULT NULL + ) + IS + PRAGMA AUTONOMOUS_TRANSACTION; + l_spec DBMS_SQL.varchar2s; + l_body DBMS_SQL.varchar2s; + + PROCEDURE compile_statement (array_in IN DBMS_SQL.varchar2s) + IS + l_cur PLS_INTEGER := DBMS_SQL.open_cursor; + BEGIN + DBMS_SQL.parse (l_cur + , array_in + , 1 + , array_in.COUNT + , TRUE + , DBMS_SQL.native + ); + DBMS_SQL.close_cursor (l_cur); + END compile_statement; + BEGIN + create_objects (dml_table_name => dml_table_name + , err_log_table_name => err_log_table_name + , err_log_table_owner => err_log_table_owner + , err_log_table_space => err_log_table_space + , skip_unsupported => skip_unsupported + , overwrite_log_table => overwrite_log_table + , err_log_package_name => err_log_package_name + , err_log_package_spec => l_spec + , err_log_package_body => l_body + ); + compile_statement (l_spec); + compile_statement (l_body); + EXCEPTION + WHEN OTHERS THEN dbms_output.put_line (dbms_utility.format_error_backtrace); raise; + END create_objects; +END dbms_errlog_helper; +/ + +-- Run the Helper Package Through Some Paces +CREATE TABLE employees AS SELECT * FROM hr.employees ; + +-- Run the Helper Package Through Some Paces +BEGIN + dbms_errlog_helper.create_objects ('EMPLOYEES'); +END; +/ + +-- Run the Helper Package Through Some Paces +SELECT column_id, column_name + FROM user_tab_columns + WHERE table_name = 'ERR$_EMPLOYEES' ; + +-- Run the Helper Package Through Some Paces +SELECT text + FROM user_source + WHERE name = 'ELP$_EMPLOYEES' + ORDER BY line ; + +-- Run the Helper Package Through Some Paces +DECLARE + l_count PLS_INTEGER; +BEGIN + SELECT COUNT ( * ) + INTO l_count + FROM employees + WHERE salary > 24000; + + DBMS_OUTPUT.put_line ('Before ' || l_count); + + UPDATE employees + SET salary = salary * 200 + LOG ERRORS REJECT LIMIT UNLIMITED; + + SELECT COUNT ( * ) + INTO l_count + FROM employees + WHERE salary > 24000; + + DBMS_OUTPUT.put_line ('After ' || l_count); + + ROLLBACK; +END; +/ + +-- Run the Helper Package Through Some Paces +DECLARE + l_errors elp$_employees.error_log_tc; +BEGIN + l_errors := elp$_employees.error_log_contents; + + FOR indx IN 1 .. l_errors.COUNT + LOOP + DBMS_OUTPUT.put_line ( + l_errors (indx).ora_err_mesg$ || ' - ' || l_errors (indx).last_name + ); + END LOOP; +END; +/ + diff --git a/plsql/error-management/log-errors-with-limit.sql b/plsql/error-management/log-errors-with-limit.sql new file mode 100644 index 00000000..34ed3c3b --- /dev/null +++ b/plsql/error-management/log-errors-with-limit.sql @@ -0,0 +1,86 @@ + +/* +When you specify a limit for the LOG ERRORS clause, Oracle will terminate +the execution of the DML statement when that number of errors have been raised. +*/ + +-- Create and populate a table +-- The "plch" prefix indicates this code was taken from a PL/SQL Challenge quiz. +CREATE TABLE plch_parts +( + partnum NUMBER (3) PRIMARY KEY + , partname VARCHAR2 (100) UNIQUE +); + +BEGIN + INSERT INTO plch_parts + VALUES (999, 'Mouse'); + + INSERT INTO plch_parts + VALUES (998, 'Keyboard'); + + INSERT INTO plch_parts + VALUES (997, 'Monitor'); + + COMMIT; +END; +/ + +-- Create error logging table for parts table +-- If you want to use LOG ERRORS with a DML statement, you need to first create an error logging table. +BEGIN + DBMS_ERRLOG.create_error_log (dml_table_name => 'PLCH_PARTS'); +END; +/ + +-- If I use UNLIMITED with REJECT LIMIT, then Oracle will (attempt to) modify +-- every single row identified by the DML statement. Any problems? Write it to the error +-- log table! When it is done? No exception will be raised! +DECLARE + l_count PLS_INTEGER; +BEGIN + SELECT COUNT (*) INTO l_count FROM err$_plch_parts; + + DBMS_OUTPUT.put_line ('Before = ' || l_count); + + UPDATE plch_parts + SET partnum = partnum * 10 + LOG ERRORS REJECT LIMIT UNLIMITED; + + SELECT COUNT (*) INTO l_count FROM err$_plch_parts; + + DBMS_OUTPUT.put_line ('After = ' || l_count); +END; +/ + +-- Impact of REJECT LIMIT clause (not UNLIMITED) +-- So suppose I am updating 1M rows. Normally, I would expect an error rate of no more +-- than .1% - 1000 rows that might have problems. But if the number goes above that, +-- something is badly wrong and I just want to stop the whole thing. In this case, +-- I add an integer value after REJECT LIMIT. Now, Oracle will halt DML processing +-- when the number of errors exceeds the specified limit. Plus, it will terminate with an error. +DECLARE + l_count PLS_INTEGER; +BEGIN + SELECT COUNT (*) INTO l_count FROM err$_plch_parts; + + DBMS_OUTPUT.put_line ('Before = ' || l_count); + + UPDATE plch_parts + SET partnum = partnum * 10 + LOG ERRORS REJECT LIMIT 2; + + SELECT COUNT (*) INTO l_count FROM err$_plch_parts; + + DBMS_OUTPUT.put_line ('After = ' || l_count); +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line ('Error = ' || DBMS_UTILITY.FORMAT_ERROR_STACK); + + SELECT COUNT (*) INTO l_count FROM err$_plch_parts; + + DBMS_OUTPUT.put_line ('After Error = ' || l_count); +END; +/ + diff --git a/plsql/error-management/log-errors.sql b/plsql/error-management/log-errors.sql new file mode 100644 index 00000000..8515fb1a --- /dev/null +++ b/plsql/error-management/log-errors.sql @@ -0,0 +1,141 @@ +/* +Add the LOG ERRORS clause to your non-query DML statement, and the SQL engine will +continue executing the statement, even if changes to individual rows fail. Any failed +row changes are written to an error log table. Used in conjunction with the DBMS_ERRLOG +package. DBMS_ERRLOG doc: http://docs.oracle.com/database/121/ARPLS/d_errlog.htm#ARPLS680 +*/ + +-- Local Table to Modify +CREATE TABLE employees AS SELECT * FROM hr.employees; + +-- Create the Error Log Table +-- This simple usage of the create_error_log procedure creates a table named ERR$_EMPLOYEES +-- in my schema. Additional parameters allow me to specify my own name (clearly necessary +-- if your original table name has > 25 characters and you are not yet on 12.2!) and a specific tablespace. +-- You can also ask it to "skip" incompatible columns - the meaning of which is clear +-- when we look at the columns in an error log table.... + +BEGIN + DBMS_ERRLOG.create_error_log (dml_table_name => 'EMPLOYEES'); +END; +/ + +-- Show Columns of Error Log Table +-- DBMS_ERRLOG creates a table that starts with five error-related columns: +-- ORA_ERR_NUMBER$ (error code), ORA_ERR_MESG$ (error message), ORA_ERR_ROWID$, ORA_ERR_OPTYP$ +-- (operation type - U, I, D), ORA_ERR_TAG$ (optional "tag" text you can provide in LOG ERRORS clause). +-- Then it adds VARCHAR2(4000) columns for any column in DML table that is compatible with +-- VARCHAR2. Example: DATE works, but CLOB does not. +SELECT column_name, data_type + FROM user_tab_columns + WHERE table_name = 'ERR$_EMPLOYEES' +ORDER BY COLUMN_ID; + +-- All or Nothing - Without LOG ERRORS +-- This step shows you how the results of a DML statement are usually "all or nothing" +-- either all rows specified by the DML statement are changed successfully, or none are. +-- That is, if N rows are modified, but then the N+1 row causes an error, the changes +-- to the previous N rows are rolled back. So the number of people making a salary > 24000 +-- is 0, both before and after the UPDATE, since at least one person's salary, +-- when multiplied by 200, exceeds the constraint on the salary column. +DECLARE + l_count PLS_INTEGER; +BEGIN + SELECT COUNT ( * ) + INTO l_count + FROM employees + WHERE salary > 24000; + + DBMS_OUTPUT.put_line ('Before ' || l_count); + + UPDATE employees + SET salary = salary * 200; + + SELECT COUNT ( * ) + INTO l_count + FROM employees + WHERE salary > 24000; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + + SELECT COUNT ( * ) + INTO l_count + FROM employees + WHERE salary > 24000; + + DBMS_OUTPUT.put_line ('After ' || l_count); +END; +/ + +-- Suppressing Row-Level Errors +-- Now I run the script again, with LOG ERRORS added, also specifying that I don't +-- care how many errors occur - just keeping going. The net result is that of the 107 +-- rows in the employees table, 49 are updated, while 58 have errors. Nice! +DECLARE + l_count PLS_INTEGER; +BEGIN + SELECT COUNT ( * ) + INTO l_count + FROM employees + WHERE salary > 24000; + + DBMS_OUTPUT.put_line ('Before ' || l_count); + + UPDATE employees + SET salary = salary * 200 +LOG ERRORS INTO ERR$_EMPLOYEES (substr (last_name, 1, 20)) REJECT LIMIT UNLIMITED; + + DBMS_OUTPUT.put_line ('After - SQL%ROWCOUNT ' || SQL%ROWCOUNT); + + SELECT COUNT ( * ) + INTO l_count + FROM employees + WHERE salary > 24000; + + DBMS_OUTPUT.put_line ('After - Count in Table ' || l_count); + + ROLLBACK; +END; +/ + +SELECT COUNT ( * ) "Number of Failures" + FROM err$_employees ; + +-- Check the Error Log Table! +-- When you use LOG ERRORS, it is absolutely critical that you check the table +-- immediately after the DML statement for errors from that statement. The SQL statement +-- does not terminate with an exception, so looking at the table is THE ONLY WAY to know +-- if anything went wrong! A common action at this point is to move the error information +-- from your table-specific DML error log table to a persistent application error log table. +SELECT ora_err_number$, ora_err_mesg$, ora_err_rowid$, ora_err_tag$, last_name + FROM err$_employees + WHERE ROWNUM < 10 ; + +-- Clean Up the Error Log Table +-- After checking the contents, I clean out the table, so the contents do not confuse +-- me when I execute the next DML statement on the table. +BEGIN + DELETE FROM err$_employees; + + COMMIT; +END; +/ + +-- Specify Limit on Rejections (Errors) +-- Suppose I am doing a bulk update, but I expect that very few errors will occur. +-- If more than 10 row updates fail, something is wrong, and I want to simply stop. +--Then LOG ERRORS REJECT LIMIT 10 will do the trick. +BEGIN + UPDATE employees + SET first_name = first_name || first_name || first_name + LOG ERRORS REJECT LIMIT 10; + + ROLLBACK; +END; +/ + +SELECT 'Number of errors = ' || COUNT ( * ) + FROM err$_employees ; + diff --git a/plsql/error-management/no-reraise-no-exception.sql b/plsql/error-management/no-reraise-no-exception.sql new file mode 100644 index 00000000..b91b3787 --- /dev/null +++ b/plsql/error-management/no-reraise-no-exception.sql @@ -0,0 +1,90 @@ +/* +You have a subprogram that invokes another subprogram (or nested block). +That "inner" subprogram fails with an exception. It contains an exception handler. +It logs the error, but then neglects to re-raise that exception (or another). +Control passes out to the invoking subprogram, and it continues executing statements, +completely unaware that an error occurred in that inner block. Which means, +by the way, that a call to SQLCODE will return 0. This may be just what +you want, but make sure you do this deliberately. + +-- SQLCODE Outside of Exception Section Always 0 +-- Because outside of an exception section, there is no exception. You are either declaring or executing. +BEGIN + DBMS_OUTPUT.put_line (SQLCODE); +END; +/ + +-- SQLCODE Invoked via Nested Subprogram from Exception Section +-- Just to avoid any misunderstanding: in this block, SQLCODE is "written" +-- outside of the exception section, but it is executed from within the OTHERS handler, +-- so SQLCODE will properly show the non-zero error code. +DECLARE + PROCEDURE my_proc + IS + BEGIN + DBMS_OUTPUT.put_line ( + 'Nested subprogram called from exception section SQLCODE=' + || SQLCODE); + END; +BEGIN + RAISE NO_DATA_FOUND; +EXCEPTION + WHEN OTHERS + THEN + my_proc; +END; +/ + +-- Watch the Changing SQLCODE Value +DECLARE + aname VARCHAR2 (5); +BEGIN + BEGIN + aname := 'Big String'; + DBMS_OUTPUT.put_line (aname); + EXCEPTION + WHEN VALUE_ERROR + THEN + DBMS_OUTPUT.put_line ( + 'Inner block exception section SQLCODE='||SQLCODE); + END; + + DBMS_OUTPUT.put_line ('In executable section SQLCODE='||SQLCODE); +EXCEPTION + WHEN VALUE_ERROR + THEN + DBMS_OUTPUT.put_line ( + 'Outer block exception section SQLCODE='||SQLCODE); +END; +/ + +ALTER SESSION SET plsql_warnings = 'enable:all' ; + +CREATE OR REPLACE PROCEDURE swallow_error AUTHID DEFINER +IS + aname VARCHAR2 (5); +BEGIN + BEGIN + aname := 'Big'; + DBMS_OUTPUT.put_line (aname); + EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line ( + 'Inner block exception section SQLCODE='||SQLCODE); + END; + + DBMS_OUTPUT.put_line ('In executable section SQLCODE='||SQLCODE); +EXCEPTION + WHEN VALUE_ERROR + THEN + DBMS_OUTPUT.put_line ( + 'Outer block exception section SQLCODE='||SQLCODE); +END; +/ + +SELECT text FROM USER_ERRORS + WHERE name = 'SWALLOW_ERROR' +/ + + diff --git a/plsql/error-management/raise-application-error.sql b/plsql/error-management/raise-application-error.sql new file mode 100644 index 00000000..0a3729c3 --- /dev/null +++ b/plsql/error-management/raise-application-error.sql @@ -0,0 +1,54 @@ +/* +If you execute a SELECT-INTO that does not identify any rows, the PL/SQL runtime +engine raises: ORA-01403 and the error message (retrieved via SQLERRM or +DBMS_UTILITY.FORMAT_ERROR_STACK) is simply "No data found". + +That may be exactly what you want your users to see. But there is a very good chance +you'd like to offer something more informative, such as "An employee with that ID is not in the system." + +In this case, you can use RAISE_APPLICATION_ERROR. +*/ + +CREATE OR REPLACE PACKAGE employees_mgr AUTHID DEFINER +IS + FUNCTION onerow (employee_id_in IN hr.employees.employee_id%TYPE) + RETURN hr.employees%ROWTYPE + RESULT_CACHE; +END; +/ + +-- Trap NO_DATA_FOUND, Change Message +-- In this function, I trap the NO_DATA_FOUND exception, raised by the SELECT-INTO, +-- and then I convert this "generic" error into something specific for my users. + +CREATE OR REPLACE PACKAGE BODY employees_mgr +IS + FUNCTION onerow (employee_id_in IN hr.employees.employee_id%TYPE) + RETURN hr.employees%ROWTYPE + RESULT_CACHE + IS + l_employee hr.employees%ROWTYPE; + BEGIN + SELECT * + INTO l_employee + FROM hr.employees + WHERE employee_id = employee_id_in; + + RETURN l_employee; + EXCEPTION + WHEN NO_DATA_FOUND + THEN + raise_application_error ( + -20000, + 'An employee with ID ' || employee_id_in || ' is not in the system.'); + END; +END; +/ + +DECLARE + l_employee hr.employees%ROWTYPE; +BEGIN + l_employee := employees_mgr.onerow (-100); +END; +/ + diff --git a/plsql/error-management/save-exc-and-forall.sql b/plsql/error-management/save-exc-and-forall.sql new file mode 100644 index 00000000..5ee9d255 --- /dev/null +++ b/plsql/error-management/save-exc-and-forall.sql @@ -0,0 +1,282 @@ +/* +Add the SAVE EXCEPTIONS clause to your FORALL statement when you want the +PL/SQL runtime engine to execute all DML statements generated by the FORALL, +even if one or more than fail with an error. If you use INDICES OF, you will +need to take some care to find your way back to the offending statement. +*/ + +CREATE TABLE employees +AS + SELECT * FROM hr.employees ; + +-- Name that -24381! (once) +/* +PL/SQL raises ORA-24381 if at least one statement failed in a FORALL that +uses SAVE EXCEPTION. It is best to handle exceptions by name, but this error +is not named in STANDARD. So we do it ourselves! +*/ + +CREATE OR REPLACE PACKAGE std_errs +IS + failure_in_forall EXCEPTION; + PRAGMA EXCEPTION_INIT (failure_in_forall, -24381); +END; +/ + +-- First, Without SAVE EXCEPTIONS +/* +You can't update a first_name to a string of 1000 or 3000 bytes. But without +SAVE EXCEPTIONS we never get past the third element in the bind array. +The employees table has 107 rows. How many were updated? +*/ +DECLARE + TYPE namelist_t IS TABLE OF VARCHAR2 (5000); + + enames_with_errors namelist_t + := namelist_t ('ABC', + 'DEF', + RPAD ('BIGBIGGERBIGGEST', 1000, 'ABC'), + 'LITTLE', + RPAD ('BIGBIGGERBIGGEST', 3000, 'ABC'), + 'SMITHIE'); +BEGIN + FORALL indx IN 1 .. enames_with_errors.COUNT + UPDATE employees + SET first_name = enames_with_errors (indx); + + ROLLBACK; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line ( + 'Updated ' || SQL%ROWCOUNT || ' rows.'); + DBMS_OUTPUT.put_line (SQLERRM); + ROLLBACK; +END; +/ + +-- Now With SAVE EXCEPTIONS +/* +Execute every generated statement no matter how of them fail, please! +Now how many rows were updated? Notice that with SAVE EXCEPTIONS in place, +I can take advantage of SQL%BULK_EXCEPTIONS to see how statements failed, +and which ones, and with which error. Can you see, however, the difference +between the error information displayed in the previous step and this one? +*/ + +DECLARE + TYPE namelist_t IS TABLE OF VARCHAR2 (5000); + + enames_with_errors namelist_t + := namelist_t ('ABC', + 'DEF', + RPAD ('BIGBIGGERBIGGEST', 1000, 'ABC'), + 'LITTLE', + RPAD ('BIGBIGGERBIGGEST', 3000, 'ABC'), + 'SMITHIE'); +BEGIN + FORALL indx IN 1 .. enames_with_errors.COUNT SAVE EXCEPTIONS + UPDATE employees + SET first_name = enames_with_errors (indx); + + ROLLBACK; +EXCEPTION + WHEN std_errs.failure_in_forall + THEN + DBMS_OUTPUT.put_line (SQLERRM); + DBMS_OUTPUT.put_line ( + 'Updated ' || SQL%ROWCOUNT || ' rows.'); + + FOR indx IN 1 .. SQL%BULK_EXCEPTIONS.COUNT + LOOP + DBMS_OUTPUT.put_line ( + 'Error ' + || indx + || ' occurred on index ' + || SQL%BULK_EXCEPTIONS (indx).ERROR_INDEX + || ' attempting to update name to "' + || enames_with_errors ( + SQL%BULK_EXCEPTIONS (indx).ERROR_INDEX) + || '"'); + DBMS_OUTPUT.put_line ( + 'Oracle error is ' + || SQLERRM ( + -1 * SQL%BULK_EXCEPTIONS (indx).ERROR_CODE)); + END LOOP; + + ROLLBACK; +END; +/ + +-- Now Explore SAVE EXCEPTIONS with Sparse Bind Arrays +/* +If the array that drives the FORALL statement (the bind array) is not +dense and you use INDICES OF, you can run into some complications. +*/ + +CREATE TABLE plch_employees +( + employee_id INTEGER, + last_name VARCHAR2 (100), + salary NUMBER (8, 0) +) ; + +BEGIN + INSERT INTO plch_employees + VALUES (100, 'Ninhursag ', 1000000); + + INSERT INTO plch_employees + VALUES (200, 'Inanna', 1000000); + + INSERT INTO plch_employees + VALUES (300, 'Enlil', 1000000); + + COMMIT; +END; +/ + +-- INDICES OF - BETWEEN - Complications! +/* +INDICES OF is a great feature: you can use it when your bind array is not +densely filled. And you can use BETWEEN to further finesse which elements +in the bind array are used to generate statements. But then it is a challenge +to correlate the SQL%BULK_EXCEPTIONS ERROR_INDEX value back to the right +index value in the bind array! Which index values do you think will be displayed here? +*/ + +DECLARE + TYPE employee_aat IS TABLE OF employees.employee_id%TYPE + INDEX BY PLS_INTEGER; + + l_employees employee_aat; +BEGIN + l_employees (1) := 100; + l_employees (2) := 200; + l_employees (3) := 300; + l_employees (4) := 200; + l_employees (5) := 100; + + FORALL l_index IN INDICES OF l_employees BETWEEN 3 AND 5 + SAVE EXCEPTIONS + UPDATE plch_employees + SET salary = + salary + * CASE employee_id WHEN 200 THEN 1 ELSE 100 END + WHERE employee_id = l_employees (l_index); +EXCEPTION + WHEN std_errs.failure_in_forall + THEN + DBMS_OUTPUT.put_line ('Errors:'); + + FOR indx IN 1 .. SQL%BULK_EXCEPTIONS.COUNT + LOOP + DBMS_OUTPUT.put_line ( + SQL%BULK_EXCEPTIONS (indx).ERROR_INDEX); + END LOOP; + + ROLLBACK; +END; +/ + +-- Correlate ERROR INDEX Back to Bind Array +/* +Now I offer a helpful utility, bind_array_index_for, that figures out the +actual index value in the bind array from the ERROR_INDEX value and the +start/end values in the INDICES OF BETWEEN's clause. +*/ + +DECLARE + TYPE employee_aat IS TABLE OF employees.employee_id%TYPE + INDEX BY PLS_INTEGER; + + l_employees employee_aat; + + FUNCTION bind_array_index_for ( + bind_array_in IN employee_aat, + error_index_in IN PLS_INTEGER, + start_in IN PLS_INTEGER DEFAULT NULL, + end_in IN PLS_INTEGER DEFAULT NULL) + RETURN PLS_INTEGER + IS + l_index PLS_INTEGER + := NVL (start_in, bind_array_in.FIRST); + BEGIN + FOR indx IN 1 .. error_index_in - 1 + LOOP + l_index := bind_array_in.NEXT (l_index); + END LOOP; + + RETURN l_index; + END; +BEGIN + BEGIN + l_employees (1) := 100; + l_employees (100) := 200; + l_employees (500) := 300; + + FORALL l_index IN INDICES OF l_employees SAVE EXCEPTIONS + UPDATE plch_employees + SET salary = + salary + * CASE employee_id + WHEN 200 THEN 1 + ELSE 100 + END + WHERE employee_id = l_employees (l_index); + EXCEPTION + WHEN failure_in_forall + THEN + DBMS_OUTPUT.put_line ('Errors:'); + + FOR indx IN 1 .. SQL%BULK_EXCEPTIONS.COUNT + LOOP + DBMS_OUTPUT.put_line ( + SQL%BULK_EXCEPTIONS (indx).ERROR_INDEX); + DBMS_OUTPUT.put_line ( + bind_array_index_for ( + l_employees, + SQL%BULK_EXCEPTIONS (indx).ERROR_INDEX)); + END LOOP; + + ROLLBACK; + END; + + BEGIN + l_employees (1) := 100; + l_employees (2) := 200; + l_employees (3) := 300; + l_employees (4) := 200; + l_employees (5) := 100; + + FORALL l_index IN INDICES OF l_employees BETWEEN 3 AND 5 + SAVE EXCEPTIONS + UPDATE plch_employees + SET salary = + salary + * CASE employee_id + WHEN 200 THEN 1 + ELSE 100 + END + WHERE employee_id = l_employees (l_index); + EXCEPTION + WHEN std_errs.failure_in_forall + THEN + DBMS_OUTPUT.put_line ('Errors:'); + + FOR indx IN 1 .. SQL%BULK_EXCEPTIONS.COUNT + LOOP + DBMS_OUTPUT.put_line ( + SQL%BULK_EXCEPTIONS (indx).ERROR_INDEX); + DBMS_OUTPUT.put_line ( + bind_array_index_for ( + l_employees, + SQL%BULK_EXCEPTIONS (indx).ERROR_INDEX, + 3, + 5)); + END LOOP; + + ROLLBACK; + END; +END; +/ + diff --git a/plsql/error-management/sqlerrm-format-error-stack.sql b/plsql/error-management/sqlerrm-format-error-stack.sql new file mode 100644 index 00000000..35313379 --- /dev/null +++ b/plsql/error-management/sqlerrm-format-error-stack.sql @@ -0,0 +1,162 @@ +/* +SQLERRM is a function that returns the current error message (if no argument is passed to it) +or the system error message associated with the specified error code. DBMS_UTILITY.FORMAT_ERROR_STACK +also returns the error message (or stack, if there is a stack of errors) and avoids truncation issues +that may occur with SQLERRM. +*/ + +-- SQLERRM with No Arguments +BEGIN + RAISE TOO_MANY_ROWS; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (SQLERRM); +END; +/ + +-- SQLERRM as Lookup Function +BEGIN + DBMS_OUTPUT.put_line (SQLERRM (-1422)); +END; +/ + +-- That's Right: Oracle Errors are Negative +-- Even though some other parts of Oracle Database store error codes as unsigned integers (LOG ERRORS, SAVE EXCEPTIONS). +BEGIN + DBMS_OUTPUT.put_line (SQLERRM (1422)); +END; +/ + +-- Call Both Error Message Functions +-- And show the length of the string (useful when examining truncation issues in last step of script). +CREATE OR REPLACE PROCEDURE show_errors +IS +BEGIN + DBMS_OUTPUT.put_line ('-------SQLERRM-------------'); + DBMS_OUTPUT.put_line (SQLERRM); + DBMS_OUTPUT.put_line ('-------FORMAT_ERROR_STACK--'); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + DBMS_OUTPUT.put_line (' '); +END; +/ + +CREATE OR REPLACE PROCEDURE proc1 +IS +BEGIN + RAISE NO_DATA_FOUND; +END; +/ + +CREATE OR REPLACE PACKAGE pkg1 +IS + PROCEDURE proc2; +END pkg1; +/ + +CREATE OR REPLACE PACKAGE BODY pkg1 +IS + PROCEDURE proc2 + IS + BEGIN + proc1; + EXCEPTION + WHEN OTHERS + THEN + RAISE DUP_VAL_ON_INDEX; + END; +END pkg1; +/ + +-- Raise Application Error - and Keep the Stack +-- The third argument of raise_application_error determines whether or not the stack of errors is kept +-- or discarded. TRUE = Keep. +CREATE OR REPLACE PROCEDURE proc3 +IS +BEGIN + FOR indx IN 1 .. 1000 + LOOP + NULL; + END LOOP; + + pkg1.proc2; +EXCEPTION + WHEN OTHERS + THEN + raise_application_error (-20000, 'TOP MOST ERROR MESSAGE', TRUE); +END; +/ + +BEGIN + proc3; +EXCEPTION + WHEN OTHERS + THEN + show_errors; +END; +/ + +-- Now Discard Error Stack +CREATE OR REPLACE PROCEDURE proc3 +IS +BEGIN + FOR indx IN 1 .. 1000 + LOOP + NULL; + END LOOP; + + pkg1.proc2; +EXCEPTION + WHEN OTHERS + THEN + raise_application_error (-20000, 'TOP MOST ERROR MESSAGE', FALSE); +END; +/ + +BEGIN + proc3; +EXCEPTION + WHEN OTHERS + THEN + show_errors; +END; +/ + +-- SQLERRM Can Truncate on Long Stacks +-- DBMS_UTILITY.format_error_stack? Not so much. And notice down at the bottom: the original exception. +DECLARE + PROCEDURE show_errors + IS + BEGIN + DBMS_OUTPUT.put_line ('-------SQLERRM-------------'); + DBMS_OUTPUT.put_line (LENGTH (SQLERRM)); + DBMS_OUTPUT.put_line (SQLERRM); + DBMS_OUTPUT.put_line ('-------FORMAT_ERROR_STACK--'); + DBMS_OUTPUT.put_line ( + LENGTH (DBMS_UTILITY.format_error_stack)); + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); + END; + + PROCEDURE raise_error (nth_in IN INTEGER) + IS + BEGIN + IF nth_in <= 10000 + THEN + raise_error (nth_in + 1); + ELSE + RAISE NO_DATA_FOUND; + END IF; + EXCEPTION + WHEN OTHERS + THEN + RAISE VALUE_ERROR; + END; +BEGIN + raise_error (1); +EXCEPTION + WHEN OTHERS + THEN + show_errors; +END; +/ + diff --git a/plsql/error-management/utl-call-stack.sql b/plsql/error-management/utl-call-stack.sql new file mode 100644 index 00000000..9cc8efa5 --- /dev/null +++ b/plsql/error-management/utl-call-stack.sql @@ -0,0 +1,119 @@ +/* +UTL_CALL_STACK, introduced in Oracle Database 12c, offers fine grained information about your +execution call stack, as well as an API to the error stack and back trace. Or, as the doc states: +"The UTL_CALL_STACK package provides an interface to provide information about currently executing +subprograms. Functions return subprogram names, unit names, owner names, edition names, and +line numbers for given dynamic depths. Other functions return error stack information." +http://docs.oracle.com/database/121/ARPLS/u_call_stack.htm#ARPLS74078 +*/ + +CREATE OR REPLACE PACKAGE pkg1 AUTHID DEFINER +IS + PROCEDURE proc1; +END pkg1; +/ + +-- Down to Subprogram Name! +-- The FORMAT_CALL_STACK function in DBMS_UTILITY only shows you the name of the program unit in +-- the call stack (i.e., the package name, but not the function within the package). +-- UTL_CALL_STACK only shows you the name of the package subprogram, but even the name of nested +-- (local) subprograms within those. VERY COOL! +CREATE OR REPLACE PACKAGE BODY pkg1 +IS + PROCEDURE proc1 + IS + PROCEDURE nested_in_proc1 + IS + BEGIN + DBMS_OUTPUT.put_line ( + '*** "Traditional" Call Stack using FORMAT_CALL_STACK'); + + DBMS_OUTPUT.put_line (DBMS_UTILITY.format_call_stack); + + DBMS_OUTPUT.put_line ( + '*** Fully Qualified Nested Subprogram vis UTL_CALL_STACK'); + + DBMS_OUTPUT.put_line ( + utl_call_stack.concatenate_subprogram ( + utl_call_stack.subprogram (1))); + END; + BEGIN + nested_in_proc1; + END; +END pkg1; +/ + +-- The Call Stack Output +-- First, you will see the "Traditional" formatted call stack, next the fully-qualified name of +-- the top of that stack, culled out of the "mess" with the UTL_CALL_STACK API. +BEGIN + pkg1.proc1; +END; +/ + +-- Backtrace Info, Too! +-- Need to get the line number on which an error was raised? You can stick with +-- DBMS_UTILITY.FORMAT_ERROR_BACKTRACE, sure. But now you can also opt for the +-- UTL_CALL_STACK backtrace functions! +CREATE OR REPLACE FUNCTION backtrace_to + RETURN VARCHAR2 AUTHID DEFINER +IS +BEGIN + RETURN + utl_call_stack.backtrace_unit ( + utl_call_stack.backtrace_depth) + || ' line ' + || utl_call_stack.backtrace_line ( + utl_call_stack.backtrace_depth); +END; +/ + +CREATE OR REPLACE PACKAGE pkg1 AUTHID DEFINER +IS + PROCEDURE proc1; + + PROCEDURE proc2; +END; +/ + +CREATE OR REPLACE PACKAGE BODY pkg1 +IS + PROCEDURE proc1 + IS + PROCEDURE nested_in_proc1 + IS + BEGIN + RAISE VALUE_ERROR; + END; + BEGIN + nested_in_proc1; + END; + + PROCEDURE proc2 + IS + BEGIN + proc1; + EXCEPTION + WHEN OTHERS + THEN + RAISE NO_DATA_FOUND; + END; +END pkg1; +/ + +CREATE OR REPLACE PROCEDURE proc3 AUTHID DEFINER +IS +BEGIN + pkg1.proc2; +END; +/ + +BEGIN + proc3; +EXCEPTION + WHEN OTHERS + THEN + DBMS_OUTPUT.put_line (backtrace_to); +END; +/ +