It is easy to trace a process initiated by the process scheduler with a trigger (see Enabling Oracle Database Trace on PeopleSoft processes with a Trigger).
Another tactic is to use an AFTER LOGON trigger with logic to look at the program name. The program name can be read using SYS_CONTEXT(). If it matches what I am looking for, I can enable session trace.
Here is an example I used for the OpenXML nVision server PSNVSSRV
- I want to trace SQL and not any wait events or bind variables. Therefore, I will set event 10046 at level 1.
- I also set a tracefile_identifier that will be included in the trace file name, so I can more easily identify the trace file.
REM additional SQL trace triggers
CREATE OR REPLACE TRIGGER sysadm.gfc_nvision_trace_on_logon
AFTER LOGON
ON sysadm.schema
DECLARE
l_process_instance INTEGER;
l_program VARCHAR2(64 CHAR);
l_sql VARCHAR2(100);
BEGIN
SELECT sys_context('USERENV', 'CLIENT_PROGRAM_NAME')
INTO l_program
FROM dual;
IF l_program like 'PSNVSSRV%' THEN --then this is a NVISION session
EXECUTE IMMEDIATE 'ALTER SESSION SET tracefile_identifier = ''PSNVSSRV''';
EXECUTE IMMEDIATE 'ALTER SESSION SET events ''10046 TRACE NAME CONTEXT FOREVER, LEVEL 1''';
END IF;
EXCEPTION
WHEN OTHERS THEN NULL;
END;
/
show errors
ALTER TRIGGER sysadm.gfc_nvision_trace_on_logon ENABLE;
See also Reading Trace files with SQL
No comments :
Post a Comment