A colleague showed me a great way to get more useful debug information. Normally I used SQLERRM and SQLCODE in an exception to display or store error messages. Using DBMS_UTILITY you can get more detailed Oracle error messages. Here's an example:
-- I put this in a package for demo purposes
CREATE OR REPLACE PACKAGE pkg_err_test
AS
PROCEDURE sp_err_test (
p_empno IN emp.empno%TYPE
);
END pkg_err_test;
CREATE OR REPLACE PACKAGE BODY pkg_err_test
AS
PROCEDURE sp_err_test (
p_empno IN emp.empno%TYPE
)
AS
v_ename emp.ename%TYPE;
BEGIN
SELECT ename
INTO v_ename
FROM emp
WHERE empno = p_empno;
DBMS_OUTPUT.put_line ('Employee name is: ' || v_ename);
EXCEPTION
WHEN OTHERS THEN
-- Basic Error Message
DBMS_OUTPUT.put_line ('Old Error Message: ' || SUBSTR (SQLERRM, 1, 255));
DBMS_OUTPUT.put_line ('Old Err Code: ' || SQLCODE);
-- Advanced Error Messages
DBMS_OUTPUT.put_line ('-- New Error Messages --');
DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_stack); -- Error Message
DBMS_OUTPUT.put_line (DBMS_UTILITY.format_error_backtrace); -- Where it occurred
DBMS_OUTPUT.put_line (DBMS_UTILITY.format_call_stack); -- Call Stack
END sp_err_test;
END pkg_err_test;
-- Run the error test with an invalid employee number so an exception will be raised
EXEC pkg_err_test.sp_err_test(p_empno => 123);
DBMS Output:
Old Error Message: ORA-01403: no data found
Old Err Code: 100
-- New Error Messages --
ORA-01403: no data found
ORA-06512: at "GIFFY.PKG_ERR_TEST", line 9
----- PL/SQL Call Stack -----
object line object
handle number name
362D7814 24 package body GIFFY.PKG_ERR_TEST
362D70E0 1 anonymous block
The error message is displayed as well as where the error occurred and the call stack. In large systems this can be very helpful. You should be aware that when called from a package, it does not list the procedure or function (as seen in this example) where the error occurred so you may need to hard code the function or procedure name in your error message.
Hi Martin,
ReplyDeleteYou might want to consider using the PL/SQL compiler directives $$plsql_unit and $$plsql_line (10g and above) over hard-coding the plsql module name into your error handler....
[apologies for the code layout]
eg.
create or replace package body test_error_handler
is
g_module constant varchar2(30) := $$plsql_unit; -- NOTE: returns "TEST_ERROR_HANDLER" in package
g_action varchar2(30);
procedure throws_error
dummy integer;
is
-- FIXME: cover these in generic "begin_task" (similar to HOTSOS ILO)
g_action := 'throws_error';
dbms_application_info.set_module( g_module, g_action );
-- ERROR: throws a "no data found" exception
select 1
into dummy
from dual
where dummy != 'X';
-- FIXME: cover these in generic "end_task"
dbms_application_info.set_module( null, null );
exception
when others then
-- templated error visualisation
dbms_output.put_line( coalesce( g_module, 'anonymous block' ) || '.' || g_action );
dbms_output.put_line( '(handler) : ' || $$plsql_line );
dbms_output.put_line( dbms_utility.format_error_stack ); -- error message
dbms_output.put_line( dbms_utility.format_error_backtrace ); -- where it occurred
dbms_output.put_line( dbms_utility.format_call_stack ); -- call stack
-- FIXME: cover these in generic "exit_task"
dbms_application_info.set_module( null, null );
-- NOTE: generic exception so raise to enclosing scope (see Tom Kyte)
raise;
end throws_error;
end;
As suggested, a generic begin_task / end_task and exit_task like the HOTSOS ILO project is also useful. Further generic error recording/handling functionality is available from some of Steven Feuerstein's PL/Vision and other work.
Hope this helps,
Lachlan Pitts
Hi Martin,
ReplyDeleteEven more generic functionality is available using OWA_UTIL.WHO_CALLED_ME which gets away from hard coding the procedure name into the code.
Hope this helps,
Lachlan Pitts
Hi Lachlan,
ReplyDeleteThanks for all the help!
Martin