
alter index 索引名 monitoring usage;
alter index 索引名 nomonitoring usage;
观察V$object_usage进行跟踪
select * from v$object_usage;
drop table t purge;
create table t as select * from dba_objects;
create index idx_t_id on t (object_id);
create index idx_t_name on t (object_name);
---未监控索引时,v$object_usage查询不到任何记录
select * from v$object_usage;
--接下来对idx_t_id和idx_t_name两列索引做监控
索引监控的实施
alter index idx_t_id monitoring usage;
alter index idx_t_name monitoring usage;
set linesize 166
col INDEX_NAME for a10
col TABLE_NAME for a10
col MONITORING for a10
col USED for a10
col START_MONITORING for a25
col END_MONITORING for a25
select * from v$object_usage;
若查询使用了索引后used状态变为yes
自己编写一个监控索引的脚本
SQL> select index_name from dba_indexes where table_name='TE';
INDEX_NAME
------------------------------
IDX_TE_OBJECT_NAME
SQL> Analyze index IDX_TE_OBJECT_NAME validate structure;
Index analyzed.
SQL> select height,DEL_LF_ROWS/LF_ROWS from index_stats where name='IDX_TE_OBJECT_NAME';
HEIGHT DEL_LF_ROWS/LF_ROWS
---------- -------------------
3 0
自己编写的一个脚本,该脚本的主要功能是列出需要rebuild的索引,列出状态为unusable的索引。我没有将ORACLE内置账户的索引考虑在内。
需要rebuild的索引遵循如下原则:
1.索引高度大于等于4
2.索引中被删除的数据超过索引数据的20%。
3.索引的状态为VALID
警告:别胡乱在生产库中运行该脚本,千万别在繁忙的时候运行该脚本,慎重,慎重
set serveroutput on
set linesize 200
set pagesize 100
declare
cursor spetial is
select index_name,owner from dba_indexes where owner not in
('SYS','SYSMAN','SYSTEM','MDSYS','OLAPSYS','DMSYS','ORDSYS','EXFSYS','XDB','CTXSYS','WMSYS','OUTLN','ISMSYS','DBSNMP','TSMSYS') and status='UNUSABLE';
cursor index_name is
select index_name,owner from dba_indexes where owner not in
('SYS','SYSMAN','SYSTEM','MDSYS','OLAPSYS','DMSYS','ORDSYS','EXFSYS','XDB','CTXSYS','WMSYS','OUTLN','ISMSYS','DBSNMP','TSMSYS') and status='VALID';
height index_stats.height%TYPE :=0;
lf_rows index_stats.lf_rows%TYPE :=0;
del_lf_rows index_stats.del_lf_rows%TYPE :=0;
distinct_keys index_stats.distinct_keys%TYPE :=0;
begin
for c_spetial in spetial loop
dbms_output.put_line(c_spetial.owner ||'.' || c_spetial.index_name ||' is unusable.');
end loop;
for indexname in index_name loop
execute immediate 'analyze index '|| indexname.owner ||'.'|| indexname.index_name ||' validate structure';
select height,decode(lf_rows,0,1,lf_rows),del_lf_rows,decode(distinct_keys,0,1,distinct_keys)
into height,lf_rows,del_lf_rows,distinct_keys from index_stats;
if(height>=4) or ((del_lf_rows/lf_rows)>0.2) then
dbms_output.put_line(' The height of '|| indexname.owner || '.'|| indexname.index_name || ' is '||
height || ' and the DEL_LF_ROWS/LF_ROWS is ' || del_lf_rows/lf_rows || ' needs rebuild!!!');
end if;
end loop;
exception
when others then
null;
end;
/
例子:
SQL> declare
2 cursor spetial is
3 select index_name,owner from dba_indexes where owner not in
4 ('SYS','SYSMAN','SYSTEM','MDSYS','OLAPSYS','DMSYS','ORDSYS','EXFSYS','XDB','CTXSYS','WMSYS','OUTLN','ISMSYS','DBSNMP','TSMSYS') and status='UNUSA
5 cursor index_name is
6 select index_name,owner from dba_indexes where owner not in
7 ('SYS','SYSMAN','SYSTEM','MDSYS','OLAPSYS','DMSYS','ORDSYS','EXFSYS','XDB','CTXSYS','WMSYS','OUTLN','ISMSYS','DBSNMP','TSMSYS') and status='VALID
8 height index_stats.height%TYPE :=0;
9 lf_rows index_stats.lf_rows%TYPE :=0;
10 del_lf_rows index_stats.del_lf_rows%TYPE :=0;
11 distinct_keys index_stats.distinct_keys%TYPE :=0;
12 begin
13 for c_spetial in spetial loop
14 dbms_output.put_line(c_spetial.owner ||'.' || c_spetial.index_name ||' is unusable.');
15 end loop;
16 for indexname in index_name loop
17 execute immediate 'analyze index '|| indexname.owner ||'.'|| indexname.index_name ||' validate structure';
18 select height,decode(lf_rows,0,1,lf_rows),del_lf_rows,decode(distinct_keys,0,1,distinct_keys)
19 into height,lf_rows,del_lf_rows,distinct_keys from index_stats;
20 if(height>=4) or ((del_lf_rows/lf_rows)>0.2) then
21 dbms_output.put_line(' The height of '|| indexname.owner || '.'|| indexname.index_name || ' is '||
22 height || ' and the DEL_LF_ROWS/LF_ROWS is ' || del_lf_rows/lf_rows || ' needs rebuild!!!');
23 end if;
24 end loop;
25 end;
26
SCOTT.LOWERNAME is unusable.
PL/SQL 过程已成功完成。





