RE: MV's monitoring

  • From: John Hallas <John.Hallas@xxxxxxxxxxxxxxxxxx>
  • To: "justin@xxxxxxx" <justin@xxxxxxx>, oracle-l-freelists <oracle-l@xxxxxxxxxxxxx>
  • Date: Tue, 14 Jan 2014 10:21:42 +0000

What an excellent response Justin

John
www.jhdba.wordpress.com

From: oracle-l-bounce@xxxxxxxxxxxxx [mailto:oracle-l-bounce@xxxxxxxxxxxxx] On 
Behalf Of Justin Mungal
Sent: 13 January 2014 19:29
To: oracle-l-freelists
Subject: Fwd: MV's monitoring

Whoops, forgot to include the list.
---------- Forwarded message ----------
From: Justin Mungal <justin@xxxxxxx<mailto:justin@xxxxxxx>>
Date: Sun, Jan 12, 2014 at 7:16 PM
Subject: Re: MV's monitoring
To: smishra_97@xxxxxxxxx<mailto:smishra_97@xxxxxxxxx>

Yes, you can use standard auditing for auditing materialized view access. If 
it's not working make sure you're not doing the operation as SYS and also have 
AUDIT_SYS_OPERATIONS set to false.

As SYS:

SQL> create materialized view mv_data_files as (select * from dba_data_files);

Materialized view created.

SQL> audit select on mv_data_files;

Audit succeeded.


As JUSTIN:

SQL> select count(*) from sys.mv_data_files;

  COUNT(*)
----------
         5


As SYS again:

SQL> select distinct obj_name from dba_audit_trail;

OBJ_NAME
--------------------------------------------------------------------------------

MV_DATA_FILES

If you're only concerned with access from the last few days, the audit trail 
provides the time stamp of when the action took place.

Fine Grained Auditing requires Enterprise Edition, and would be most useful 
when you are interested in auditing only specific activities. See the manual 
for more information on this.
http://docs.oracle.com/cd/E11882_01/network.112/e36292/auditing.htm#DBSEG525

You can also see the actual text of the query if you need to with standard 
auditing, by using extended auditing.

ie.

As SYS:

SQL> alter system set audit_trail=db_extended scope=spfile;

System altered.

<bounce db>


As justin:

SQL> select count(*) from sys.mv_data_files;

  COUNT(*)
----------
         5



Now, we can see the actual sql text in the view:

  1  select username, sql_text from dba_audit_trail
  2* where sql_text is not null



______________________________________________________________________
Wm Morrison Supermarkets Plc is registered in England with number 358949. The 
registered office of the company is situated at Gain Lane, Bradford, West 
Yorkshire BD3 7DL. This email and any attachments are intended for the 
addressee(s) only and may be confidential. 

If you are not the intended recipient, please inform the sender by replying to 
the email that you have received in error and then destroy the email. 
If you are not the intended recipient, you must not use, disclose, copy or rely 
on the email or its attachments in any way. 

This email does not constitute a contract in writing for the purposes of the 
Law of Property (Miscellaneous Provisions) Act 1989.

Our Standard Terms and Conditions of Purchase, as may be amended from time to 
time, apply to any contract that we enter into. The current version of our 
Standard Terms and Conditions of Purchase is available at: 
http://www.morrisons.co.uk/gscop

Although we have taken steps to ensure the email and its attachments are 
virus-free, we cannot guarantee this or accept any responsibility, 
and it is the responsibility of recipients to carry out their own virus checks. 
______________________________________________________________________

Other related posts: