Fwd: MV's monitoring

  • From: Justin Mungal <justin@xxxxxxx>
  • To: oracle-l-freelists <oracle-l@xxxxxxxxxxxxx>
  • Date: Mon, 13 Jan 2014 09:29:18 -1000

Whoops, forgot to include the list.

---------- Forwarded message ----------
From: Justin Mungal <justin@xxxxxxx>
Date: Sun, Jan 12, 2014 at 7:16 PM
Subject: Re: MV's monitoring
To: 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
SQL> /

USERNAME
------------------------------
SQL_TEXT
--------------------------------------------------------------------------------
JUSTIN
select count(*) from sys.mv_data_files






On Mon, Dec 23, 2013 at 11:44 AM, Sanjay Mishra <smishra_97@xxxxxxxxx>wrote:

> Hi
>
> Do we know any best way to check if a particular MV's is been used in last
> couple of days. I know that we can enable monitoring on Table level to
> check it but look like this is not valid for MV's . I think one solution
> can be audit on select on MV and keep monitoring aud$. Any more suggestions
> are appreciated.
>
> TIA
> Sanjay
>

Other related posts:

  • » Fwd: MV's monitoring - Justin Mungal