Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: Using a trigger to turn on tracing

Re: Using a trigger to turn on tracing

From: Paul Baumgartel <treegarden_at_yahoo.com>
Date: Mon, 16 Feb 2004 08:13:38 -0800 (PST)
Message-ID: <20040216161338.55058.qmail@web13425.mail.yahoo.com>


Daniel,

PL/SQL does not require direct granting; stored objects, including views, do. An anonymous block using privileges granted via a role will work:

oet_at_PBD1> select * from user_sys_privs;

USERNAME                       PRIVILEGE                               
ADM
------------------------------ ----------------------------------------
---
OET                            CREATE SESSION                          
NO
OET                            SELECT ANY DICTIONARY                   
NO

oet_at_PBD1> begin
  2 execute immediate 'alter session set sql_trace=true';   3 end;
  4 /

PL/SQL procedure successfully completed.

oet_at_PBD1> create procedure foo as
  2 begin
  3 execute immediate 'alter session set sql_trace=false';   4 end;
  5 /

Procedure created.

oet_at_PBD1> exec foo
BEGIN foo; END;

*
ERROR at line 1:

ORA-01031: insufficient privileges
ORA-06512: at "OET.FOO", line 3
ORA-06512: at line 1



Do you Yahoo!?
Yahoo! Finance: Get your refund fast by filing online. http://taxes.yahoo.com/filing.html

Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Mon Feb 16 2004 - 10:13:38 CST

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US