Oracle报告分区索引

Oracle报告分区索引
从关于索引的数据字典中可以收集到很多信息,它们包括以下内容:
.分区名称
.索引类型
.索引分区的状态(需要查询相应的视图)
.索引分区的大小

在下面的例子中,你只是希望得到employees_part表的索引名,分区名和状态的列表。因为此表上既有分区索引又有非分区索引。所以你用union操作把对两种索引的查询合并在一起。

SQL> select table_name,index_name,partition_name,p.status
  2  from user_ind_partitions p join user_indexes i using(index_name)
  3  where table_name='EMPLOYEES_PART'
  4  union
  5  select table_name,index_name,null,status
  6  from user_indexes
  7  where table_name='EMPLOYEES_PART'
  8  order by 2,3;

TABLE_NAME                     INDEX_NAME                     PARTITION_NAME                           STATUS
------------------------------ ------------------------------ ---------------------------------------- --------
EMPLOYEES_PART                 EMPLOYEES_PART_PK                                                       VALID
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_100                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_200                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_300                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_400                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_500                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_600                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_700                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_800                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_900                              UNUSABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             MANAGER_MAX                              USABLE
EMPLOYEES_PART                 EMPLOYEES_PART_UK1                                                      N/A
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1990                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1991                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1992                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1993                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1994                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1995                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1996                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1997                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1998                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P1999                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               P2000                                    USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI               PMAX                                     USABLE
EMPLOYEES_PART                 EMPLOYEE_PART_LI                                                        N/A

25 rows selected.

请注意,在查询user_indexes视图时,分区索引对应的状态(status)列中显示N/A(表示不可用)。只有(基于索引分区的)最精细的数据字典视图的状态列才会被填入数据。也就是说,对于分区索引,user_ind_partitions视图的status列将被填充。如果你查询的最子分区索引,那么只有user_ind_subpartitions视图的status列将被填充,而user_indexes和user_ind_partitions视图的status列将是N/A。

接下来,需要执行一个查询,以确定表上所有索引分区的类型.

SQL> select table_name,index_name,partitioning_type,locality,alignment from user_part_indexes;

TABLE_NAME                     INDEX_NAME                     PARTITION LOCALI ALIGNMENT
------------------------------ ------------------------------ --------- ------ ------------
EMPLOYEES_JY                   EMPLOYEES_UK1                  RANGE     GLOBAL PREFIXED
EMPLOYEES_JY                   EMPLOYEES_JY_IH1               HASH      GLOBAL PREFIXED
EMPLOYEES_PART                 EMPLOYEE_PART_LI               RANGE     LOCAL  PREFIXED
EMPLOYEES_PART                 EMPLOYEES_PART_UK1             RANGE     GLOBAL PREFIXED

在查询段信息时,需要注意区分子分区索引。对于子分区索引,为了获得子分区的信息,大多数数据字典视图中都有一个子分区列。但这有一个例外,当需要从dba_segments等视图中获得段信息时,只有实际分区或表示实际段的子分区名才会在dba_segments中表示。换句话说,对于子分区索引,子分区名称将在dba_segments的partition_name列中出现。在下面的例子中,想要获得billing_fact表中大小超过8GB的索引子分区。你对user_ind_subpartitions执行了一个子查询,这表明dba_segments视图的partition_name列实际上代表了user_ind_subpartitions视图的subpartition_name列。

select segment_name,partition_name,round(bytes/1048576) meg
from dba_segments
where (segment_name,partition_name) in
(select index_name,subpartition_name from user_ind_subpartitions
where index_name in
(select index_name from user_indexes
where table_name='BILLING_FACT'))
and bytes>1048576*8192
order by 3 desc;

Oracle把索引分区设置为不可用后重建

把索引分区设置为不可用后重建
在数据仓库环境中装载大量数据时,由于索引的存在,批量dml操作的速度可能会非常慢。分区索引的关键好处之一是,可以在批量加载数据前,把索引的某些部分设置为unusable,然后在加载完成后,仅仅需要对那些受影响的部分索引分区进行重建。

从根本上说,先把索引标记为不可用,然后重建索引是相当简单的。例如:

SQL> alter table employees_part modify partition pmax unusable local indexes;

Table altered.
SQL> select index_name,null partition_name,status from user_indexes where table_name='EMPLOYEES_PART' and partitioned='NO'
  2  union
  3  select index_name,partition_name,status from user_ind_partitions where index_name in
  4  (select index_name from user_indexes where table_name='EMPLOYEES_PART')
  5  order by 1,2,3;

INDEX_NAME                     PARTITION_NAME                           STATUS
------------------------------ ---------------------------------------- --------
EMPLOYEES_PART_PK                                                       VALID
EMPLOYEES_PART_UK1             MANAGER_100                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_200                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_300                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_400                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_500                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_600                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_700                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_800                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_900                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_MAX                              USABLE
EMPLOYEE_PART_LI               P1990                                    USABLE
EMPLOYEE_PART_LI               P1991                                    USABLE
EMPLOYEE_PART_LI               P1992                                    USABLE
EMPLOYEE_PART_LI               P1993                                    USABLE
EMPLOYEE_PART_LI               P1994                                    USABLE
EMPLOYEE_PART_LI               P1995                                    USABLE
EMPLOYEE_PART_LI               P1996                                    USABLE
EMPLOYEE_PART_LI               P1997                                    USABLE
EMPLOYEE_PART_LI               P1998                                    USABLE
EMPLOYEE_PART_LI               P1999                                    USABLE
EMPLOYEE_PART_LI               P2000                                    USABLE
EMPLOYEE_PART_LI               PMAX                                     UNUSABLE

23 rows selected.

然后,在批量加载操作完成之后,就可以执行以下命令,重建那些受批量加载操作影响的索引分区:

SQL> alter table employees_part modify partition pmax rebuild unusable local indexes;

Table altered.

SQL> select index_name,null partition_name,status from user_indexes where table_name='EMPLOYEES_PART' and partitioned='NO'
  2  union
  3  select index_name,partition_name,status from user_ind_partitions where index_name in
  4  (select index_name from user_indexes where table_name='EMPLOYEES_PART')
  5  order by 1,2,3;

INDEX_NAME                     PARTITION_NAME                           STATUS
------------------------------ ---------------------------------------- --------
EMPLOYEES_PART_PK                                                       VALID
EMPLOYEES_PART_UK1             MANAGER_100                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_200                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_300                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_400                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_500                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_600                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_700                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_800                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_900                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_MAX                              USABLE
EMPLOYEE_PART_LI               P1990                                    USABLE
EMPLOYEE_PART_LI               P1991                                    USABLE
EMPLOYEE_PART_LI               P1992                                    USABLE
EMPLOYEE_PART_LI               P1993                                    USABLE
EMPLOYEE_PART_LI               P1994                                    USABLE
EMPLOYEE_PART_LI               P1995                                    USABLE
EMPLOYEE_PART_LI               P1996                                    USABLE
EMPLOYEE_PART_LI               P1997                                    USABLE
EMPLOYEE_PART_LI               P1998                                    USABLE
EMPLOYEE_PART_LI               P1999                                    USABLE
EMPLOYEE_PART_LI               P2000                                    USABLE
EMPLOYEE_PART_LI               PMAX                                     USABLE

23 rows selected.

使用此命令重建索引有一个明显的缺点:索引分区是顺序建立的,即一次重建一个索引分区。如果表上有许多索引,那么用这个命令会减缓重建过程,如果此操作是常规性处理任务的一部分,那么这种减缓会令人难以接受。一种缓解alter table … rebuild local indexes unusable命令的串行限制的方法是,并行重建每个受影响的分区。

实现并行重建索引操作有好几种方法。

Oracle重建全局分区索引和非分区索引

重建全局分区索引和非分区索引

对表进行任何一种分区级的操作,几乎都会使用所有全局分区索引或非分区索引无法使用。从本质上讲,索引始终必须重建。Oracle11g中的一个内置功能,允许把重建索引作为分区表操作的一部分来执行。使用分区级合并操作的例子,你可以看到,可以在alter table … merge命令中添加更新索引(update indexes)子句,这指示Oracle重建被分区级操作标记为不可用的任何索引。请看下面的例子:

SQL> alter table employees_part merge partitions p2001,pmax into partition pmax update indexes;

Table altered.

SQL> select index_name,null partition_name,status from user_indexes where table_name='EMPLOYEES_PART' and partitioned='NO'
  2  union
  3  select index_name,partition_name,status from user_ind_partitions where index_name in
  4  (select index_name from user_indexes where table_name='EMPLOYEES_PART')
  5  order by 1,2,3;

INDEX_NAME                     PARTITION_NAME                           STATUS
------------------------------ ---------------------------------------- --------
EMPLOYEES_PART_PK                                                       VALID
EMPLOYEES_PART_UK1             MANAGER_100                              USABLE
EMPLOYEES_PART_UK1             MANAGER_200                              USABLE
EMPLOYEES_PART_UK1             MANAGER_300                              USABLE
EMPLOYEES_PART_UK1             MANAGER_400                              USABLE
EMPLOYEES_PART_UK1             MANAGER_500                              USABLE
EMPLOYEES_PART_UK1             MANAGER_600                              USABLE
EMPLOYEES_PART_UK1             MANAGER_700                              USABLE
EMPLOYEES_PART_UK1             MANAGER_800                              USABLE
EMPLOYEES_PART_UK1             MANAGER_900                              USABLE
EMPLOYEES_PART_UK1             MANAGER_MAX                              USABLE
EMPLOYEE_PART_LI               P1990                                    USABLE
EMPLOYEE_PART_LI               P1991                                    USABLE
EMPLOYEE_PART_LI               P1992                                    USABLE
EMPLOYEE_PART_LI               P1993                                    USABLE
EMPLOYEE_PART_LI               P1994                                    USABLE
EMPLOYEE_PART_LI               P1995                                    USABLE
EMPLOYEE_PART_LI               P1996                                    USABLE
EMPLOYEE_PART_LI               P1997                                    USABLE
EMPLOYEE_PART_LI               P1998                                    USABLE
EMPLOYEE_PART_LI               P1999                                    USABLE
EMPLOYEE_PART_LI               P2000                                    USABLE
EMPLOYEE_PART_LI               PMAX                                     USABLE

23 rows selected.

使用update indexes子句重建索引的一个关键优势是,在重建操作过程中索引仍然是在线和可用的。虽然上述例子非常简单,但使用update indexes子句的缺点之一是,由于在分区级别的操作中包装了索引重建操作,在如何重建索引方面,你失去了一定的灵活性。例如,如果你有多个索引需要重建。分别发出命令来重建每个索引的速度可能会更快。要达到这种效果,就可以同时并发地运行多个alter index … rebuild命令。虽然这种方法比较复杂,但哪怕只为了加快速度,这么做可能也是有必要的。

要重建非分区索引,只需要执行alter index … rebuild命令即可。

SQL> alter index employees_part_pk rebuild;

Index altered.

此外,对于每个索引,可以选择性地决定使用并行机制,如下面的例子所示:

SQL> alter index employees_part_pk rebuild parallel(degree 4);

Index altered.

SQL> select index_name,null partition_name,status from user_indexes where table_name='EMPLOYEES_PART' and partitioned='NO'
  2  union
  3  select index_name,partition_name,status from user_ind_partitions where index_name in
  4  (select index_name from user_indexes where table_name='EMPLOYEES_PART')
  5  order by 1,2,3;

INDEX_NAME                     PARTITION_NAME                           STATUS
------------------------------ ---------------------------------------- --------
EMPLOYEES_PART_PK                                                       VALID
EMPLOYEES_PART_UK1             MANAGER_100                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_200                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_300                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_400                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_500                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_600                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_700                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_800                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_900                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_MAX                              UNUSABLE
EMPLOYEE_PART_LI               P1990                                    USABLE
EMPLOYEE_PART_LI               P1991                                    USABLE
EMPLOYEE_PART_LI               P1992                                    USABLE
EMPLOYEE_PART_LI               P1993                                    USABLE
EMPLOYEE_PART_LI               P1994                                    USABLE
EMPLOYEE_PART_LI               P1995                                    USABLE
EMPLOYEE_PART_LI               P1996                                    USABLE
EMPLOYEE_PART_LI               P1997                                    USABLE
EMPLOYEE_PART_LI               P1998                                    USABLE
EMPLOYEE_PART_LI               P1999                                    USABLE
EMPLOYEE_PART_LI               P2000                                    USABLE
EMPLOYEE_PART_LI               PMAX                                     USABLE

23 rows selected.

使用这种方法同样需要有足够的判断力和常识。如果需要一次性重建许多索引,同时又想使用并行机制,那么你必须注意到并发操作会有一个缺点。这需要根据具体的环境来作出决定。最初,最好用谨慎的态度开始。可以先慢慢提交少量的操作,以确保并发操作不造成IO或CPU瓶颈,也不造成临时表空间的瓶颈。如果并发操作没有造成这些瓶颈,那么就可以同时运行更多的重建命令。

重建非分区索引还有另一种选择,即简单地删除非分区不可用索引,并使用create index命令重新创建索引。

如果要重建全局分区索引,也有两种选择,既可以删除索引并使用create index命令作为一个整体重新创建索引,也可以逐个分区的重建全局分区索引。请看下面的例子:

SQL> alter index employees_part_uk1 rebuild partition manager_max;

Index altered.

SQL> select index_name,null partition_name,status from user_indexes where table_name='EMPLOYEES_PART' and partitioned='NO'
  2  union
  3  select index_name,partition_name,status from user_ind_partitions where index_name in
  4  (select index_name from user_indexes where table_name='EMPLOYEES_PART')
  5  order by 1,2,3;

INDEX_NAME                     PARTITION_NAME                           STATUS
------------------------------ ---------------------------------------- --------
EMPLOYEES_PART_PK                                                       VALID
EMPLOYEES_PART_UK1             MANAGER_100                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_200                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_300                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_400                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_500                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_600                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_700                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_800                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_900                              UNUSABLE
EMPLOYEES_PART_UK1             MANAGER_MAX                              USABLE
EMPLOYEE_PART_LI               P1990                                    USABLE
EMPLOYEE_PART_LI               P1991                                    USABLE
EMPLOYEE_PART_LI               P1992                                    USABLE
EMPLOYEE_PART_LI               P1993                                    USABLE
EMPLOYEE_PART_LI               P1994                                    USABLE
EMPLOYEE_PART_LI               P1995                                    USABLE
EMPLOYEE_PART_LI               P1996                                    USABLE
EMPLOYEE_PART_LI               P1997                                    USABLE
EMPLOYEE_PART_LI               P1998                                    USABLE
EMPLOYEE_PART_LI               P1999                                    USABLE
EMPLOYEE_PART_LI               P2000                                    USABLE
EMPLOYEE_PART_LI               PMAX                                     USABLE

23 rows selected.

你将需要对每个全局索引分区执行alter index … rebuild命令。

请注意不能把全局分区索引作为一个整体来重建。请看下面的例子:

SQL> alter index employees_part_uk1 rebuild;
alter index employees_part_uk1 rebuild
            *
ERROR at line 1:
ORA-14086: a partitioned index may not be rebuilt as a whole

正因为如此,当整个全局分区索引被标记为unusable时,删除它并使用create index命令重新创建索引,这样操作起来可能更为简单。