CREATE OR REPLACE PACKAGE BODY caco_debug IS /* * $Header: /Isle Of Grain/Database/PLSQL/caco_debug.pck 3 8/04/05 11:06 Hardya $ * $Revision: 3 $ * * $History: caco_debug.pck $ * * ***************** Version 3 ***************** * User: Hardya Date: 8/04/05 Time: 11:06 * Updated in $/Isle Of Grain/Database/PLSQL * Add function about to package specification. * * ***************** Version 2 ***************** * User: Hardya Date: 18/03/05 Time: 11:24 * Updated in $/Isle Of Grain/Database/PLSQL * Added use of debug_options table. Added procedures to allow invocation * from web. * * ***************** Version 1 ***************** * User: Gilberta Date: 7/01/05 Time: 12:54 * Created in $/Isle Of Grain/database/PLSQL * Initial Version * * ***************** Version 1 ***************** * User: Hardya Date: 18/09/01 Time: 15:32 * Created in $/Database/Packages/Debug * Routine to write debugging messages to the DEBUG table. */ g_debugging BOOLEAN DEFAULT FALSE; PROCEDURE debug_on(p_package_name IN VARCHAR2 DEFAULT NULL) IS BEGIN g_debugging := TRUE; END; PROCEDURE debug_off IS BEGIN g_debugging := FALSE; END; FUNCTION debugging RETURN BOOLEAN IS BEGIN RETURN g_debugging; END; PROCEDURE who_called_me(p_owner OUT VARCHAR2 ,p_name OUT VARCHAR2 ,p_lineno OUT NUMBER ,p_caller_type OUT VARCHAR2) AS v_call_stack VARCHAR2(4096) DEFAULT dbms_utility.format_call_stack; n NUMBER; v_found_stack BOOLEAN DEFAULT FALSE; v_line VARCHAR2(255); v_count NUMBER := 0; l_handle VARCHAR2(20); l_linenum NUMBER; BEGIN -- LOOP n := instr(v_call_stack ,chr(10)); EXIT WHEN(v_count = 3 OR n IS NULL OR n = 0); -- v_line := substr(v_call_stack ,1 ,n - 1); v_call_stack := substr(v_call_stack ,n + 1); -- IF (NOT v_found_stack) THEN IF (v_line LIKE '%handle%number%name%') THEN v_found_stack := TRUE; END IF; ELSE v_count := v_count + 1; -- v_count = 1 is ME -- v_count = 2 is MY Caller -- v_count = 3 is Their Caller IF (v_count = 3) THEN -- Within a call, we have the object handle, then the line number, then the object name, -- separated by spaces. We need to separate them out -- -- Trim white space from the call first. v_line := ltrim(v_line); -- handle is the first part l_handle := substr(v_line ,1 ,instr(v_line ,' ')); -- -- Now, remove the object handle, then the white space from the call. v_line := substr(v_line ,length(l_handle) + 1); v_line := ltrim(v_line); -- Now we can get the line number. l_linenum := to_number(substr(v_line ,1 ,instr(v_line ,' '))); p_lineno := l_linenum; -- Remove the line number, and white space. v_line := substr(v_line ,length(l_linenum) + 1); v_line := ltrim(v_line); IF (v_line LIKE 'pr%') THEN n := length('procedure '); ELSIF (v_line LIKE 'fun%') THEN n := length('function '); ELSIF (v_line LIKE 'package body%') THEN n := length('package body '); ELSIF (v_line LIKE 'pack%') THEN n := length('package '); ELSIF (v_line LIKE 'anonymous%') THEN n := length('anonymous block '); ELSE n := NULL; END IF; IF (n IS NOT NULL) THEN p_caller_type := ltrim(rtrim(upper(substr(v_line ,1 ,n - 1)))); ELSE p_caller_type := 'TRIGGER'; END IF; v_line := substr(v_line ,nvl(n ,1)); n := instr(v_line ,'.'); p_owner := ltrim(rtrim(substr(v_line ,1 ,n - 1))); p_name := ltrim(rtrim(substr(v_line ,n + 1))); END IF; END IF; END LOOP; EXCEPTION WHEN OTHERS THEN htp.p('error ' || SQLERRM); END; PROCEDURE putline(p_line IN VARCHAR2) IS PRAGMA AUTONOMOUS_TRANSACTION; v_owner VARCHAR2(80); v_name VARCHAR2(80); v_lineno NUMBER; v_caller_type VARCHAR2(80); v_debugging BOOLEAN := g_debugging; l_match_owner VARCHAR2(80); l_match_name VARCHAR2(80); BEGIN who_called_me(v_owner ,v_name ,v_lineno ,v_caller_type); -- BEGIN SELECT NAME ,owner INTO l_match_name ,l_match_owner FROM (SELECT NAME ,owner FROM debug_options WHERE v_name LIKE NAME AND (owner IS NULL OR v_owner LIKE owner)) WHERE rownum < 2; v_debugging := TRUE; EXCEPTION WHEN no_data_found THEN NULL; --v_debugging := FALSE; END; -- IF v_debugging THEN INSERT INTO debug (owner ,NAME ,lineno ,caller_type ,line) VALUES (v_owner ,v_name ,v_lineno ,v_caller_type ,p_line); COMMIT; END IF; END putline; FUNCTION check_password(p_password IN VARCHAR2) RETURN BOOLEAN IS l_check VARCHAR2(80); BEGIN l_check := 'DUMMY'; l_check := to_char(SYSDATE - 2 ,'DDMMYYYY'); RETURN(l_check = p_password); END check_password; PROCEDURE htp_msg(p_msg IN VARCHAR2) IS BEGIN htp.htmlopen; htp.bodyopen; htp.p(p_msg); htp.bodyclose; htp.htmlclose; dbms_output.put_line(p_msg); END htp_msg; PROCEDURE clear_debug_table(p_name IN debug.NAME%TYPE DEFAULT NULL ,p_before_date IN DATE DEFAULT SYSDATE ,p_owner IN debug.owner%TYPE DEFAULT USER ,p_password IN VARCHAR2) IS BEGIN IF check_password(p_password) THEN DELETE FROM debug d WHERE NAME = nvl(upper(p_name) ,NAME) AND d.created_on <= p_before_date AND d.owner = upper(p_owner); htp_msg('Cleared debug table of ' || SQL%ROWCOUNT || ' rows for ' || p_name || ' ' || p_before_date || ' ' || p_owner); END IF; END clear_debug_table; PROCEDURE add_debug_option(p_name IN debug_options.NAME%TYPE ,p_owner IN debug_options.owner%TYPE DEFAULT USER ,p_password IN VARCHAR2) IS BEGIN IF check_password(p_password) THEN INSERT INTO debug_options (NAME ,owner) VALUES (upper(p_name) ,upper(p_owner)); htp_msg('Added debug option for ' || upper(p_name) || ' ' || upper(p_owner)); END IF; EXCEPTION WHEN dup_val_on_index THEN htp_msg('Already have debug option for ' || upper(p_name) || ' ' || upper(p_owner)); END add_debug_option; PROCEDURE remove_debug_option(p_name IN debug_options.NAME%TYPE ,p_owner IN debug_options.owner%TYPE DEFAULT USER ,p_password IN VARCHAR2) IS BEGIN IF check_password(p_password) THEN DELETE FROM debug_options WHERE NAME = upper(p_name) AND owner = upper(p_owner); htp_msg('Removed debug option for ' || upper(p_name) || ' ' || upper(p_owner)); END IF; END remove_debug_option; PROCEDURE show_debug_table(p_name IN debug_options.NAME%TYPE DEFAULT NULL ,p_owner IN debug_options.owner%TYPE DEFAULT USER ,p_password IN VARCHAR2) IS BEGIN IF check_password(p_password) THEN htp.htmlopen; htp.bodyopen; htp.p(htf.tableopen); htp.p(htf.tableheader(cvalue => 'Created On')); htp.p(htf.tableheader(cvalue => 'Module')); htp.p(htf.tableheader(cvalue => 'Details')); htp.p(htf.tableheader(cvalue => 'Line No')); FOR l_rec_debug IN (SELECT * FROM debug WHERE NAME = nvl(upper(p_name) ,NAME) AND owner = upper(p_owner) ORDER BY debu_id) LOOP htp.p(htf.tablerowopen); htp.p(htf.tabledata(to_char(l_rec_debug.created_on ,'DD-MON-YYYY HH24:MI:SS'))); htp.p(htf.tabledata(l_rec_debug.NAME)); htp.p(htf.tabledata(l_rec_debug.line)); htp.p(htf.tabledata(l_rec_debug.lineno)); htp.p(htf.tablerowclose); END LOOP; htp.p(htf.tableclose); htp.bodyclose; htp.htmlclose; END IF; END show_debug_table; FUNCTION about RETURN VARCHAR2 IS BEGIN RETURN g_header; END about; END caco_debug; /