The question is tricky,
I have asked accessed not modified/changed. If so modified/changed dba_tab_modifications can give you a clue.
For both of this questions, the below query will help.
Table is in use or not? This question may arise from App team that they have released a new module which may not require certain tables , but before dropping they want to confirm that no query using those tables,
select p.object_owner owners, p.object_name Obj_Name, p.operation Operation, p.options Options, count(1) Idx_Usg_Cnt from dba_hist_sql_plan p,dba_hist_sqlstat s where p.object_owner = '&USERNAME' and p.operation like 'TABLE%' and p.sql_id = s.sql_id and p.object_name='&OBJNAME' group by p.object_owner,p.object_name,p.operation,p.options order by 1,2,3
Similarly Index is in use or not? This question may arise from App team or from DBA team, does certain index has an value or an overhead to the storage, so if any sql execution plans does not use that index it means that index does not need at all.
For a given object i.e index
select p.object_owner owners, p.object_name Obj_Name, p.operation Operation, p.options Options, count(1) Idx_Usg_Cnt from dba_hist_sql_plan p,dba_hist_sqlstat s where p.object_owner = '&USERNAME' and p.operation like '%INDEX' and p.sql_id = s.sql_id and p.object_name='&objname' group by p.object_owner, p.object_name,p.operation,p.options order by 1,2,3;
For a given owner i.e schema level,
So if you found index with count zero, that means that index is not used at all any time in execution plan.
select p.object_owner owners, p.object_name Obj_Name, p.operation Operation, p.options Options, count(1) Idx_Usg_Cnt from dba_hist_sql_plan p,dba_hist_sqlstat s where p.object_owner = '&USERNAME' and p.operation like '%INDEX' and p.sql_id = s.sql_id group by p.object_owner, p.object_name,p.operation,p.options order by 1,2,3;
For just to find only index that has count zero means never used, add condition having count(1) <=0
select p.object_owner owners, p.object_name Obj_Name, p.operation Operation, p.options Options, count(1) Idx_Usg_Cnt from dba_hist_sql_plan p,dba_hist_sqlstat s where p.object_owner = '&USERNAME' and p.operation like '%INDEX' and p.sql_id = s.sql_id group by p.object_owner, p.object_name,p.operation,p.options having Idx_usg_cnt <=0 order by 1,2,3;
Another script to use track of object usage. This will show you the date & time as well
select to_char(sn.begin_interval_time,'yy-mm-dd hh24') Begin_Int_Time, p.search_columns Search_Col, count(*) Invocation_Cnt from dba_hist_snapshot sn, dba_hist_sql_plan p, dba_hist_sqlstat st where st.sql_id = p.sql_id and sn.snap_id = st.snap_id and lower(object_name) like /*lower('%&idxname%')*/ lower ('Idx_Name') group by begin_interval_time,search_columns
-Thanks
Geek DBA
thanks Geek DBA
alert to me about index .
Welcome,
This script works for index as well. The search_columns and the invocation counts tells how many times the said object has been accessed.
The thing is we are seeing them in view where the executions plan statistics are stored historically for dba_hist_sqlstat and dba_hist_sqlplan
If you want to see in run time v$sql_plan_statistics can be viewed
-Thanks
Sures
[…] http://Geek DBAGeek DBA.wordpress.com/2013/03/02/quick-question-when-is-my-table-last-accessed-does-my-i… […]