Skip to Main Content
  • Questions
  • Unusable Index on a Partitioned table

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, Ajeet.

Asked: January 25, 2003 - 4:11 pm UTC

Last updated: January 04, 2006 - 10:45 am UTC

Version: 8.1.7

Viewed 10K+ times! This question is

You Asked

Tom - I have a partitioned table. And there is non unique and non partitioned index --PART_IE1 on this table (which I plan to partition ).
This table is being loaded daily using SQL Loader Direct path option.Everything has been working ok since quite some time.Then we got an error -- index PART_IE1 is unusable.And data load failed.
I added skip_unsed_indexes = true in sql loader control file script to avoid load failure ,and it worked.But still this index becomes unusable.We do re build after each load.
There are few other details too -
1. we disbale constraints before load.
2. we trucate the particular partitions before load.
3. we enable constraints after load.
4. we rebuild the index after the load.
My Question is
1. When and why an index becomes unusable.
2. If I will partition this index , will it help me. or will I not get this error.
I have searched this site and read through your book but i have not found an answer.yes i have not gone through oracle documentation which I will.
Thanks for your help.

--Ajeet

and Tom said...

well, a global index will definitely become unusable if you truncate one of the underlying partitions.

Think of it this way "If I were Oracle and you did operation X -- would I be able to maintain the index". 99.99% of the time you should be able to answer -- it is the tricky (but very uncommon 0.01%) that we have to think about it.

If you know how a globally partitioned index works (which is what you have, it is just in one partition) -- you should be able to make the leap that "hey, the index will be unusable if I just wipe out part of the underlying data with a truncate".

One of the most subtle ones might be if you have a UNIQUE index -- direct path load -- but load some duplicates. They will load into the segment and when sqlldr tries to update the index at the end, it'll fail -- and mark the index as unusable.


Now, if you have a locally partitioned index -- and you truncate a partition -- oracle won't have to mark it unusable, we can simply truncate the table partition AND the index partition and they are in sync.

Does that mean "go out and do a local partitioned index" -- no way, it might KILL your query performance....




Rating

  (4 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

So If I partition this index -- i will not have to rebuild it ?

Ajeet, January 25, 2003 - 4:50 pm UTC

Tom - Thanks for help.
Per your answer -- is it correct to conclude that if I partition this index , I will not have to rebuild as it will not be set unusable ( unlike in the case of a global index). Another thing is why it is becoming unusable even I have a explicit re-build statement in my script ?


Tom Kyte
January 25, 2003 - 6:52 pm UTC

it becomes unusable the second you truncate the partion, stays that way until you rebuild it.

making it locally partitioned will stop that HOWEVER -- big HOWEVER, it could literally mess everything else up. Make sure you understand how partitioning works -- how your existing queries use this index -- before doing anything.

Else you could turn a single index range scan per query into N index range scans per query -- causing your LIOs to go up by a factor of N, causing performance to go down the tubes.

How to minimize downtime?

Albert Nelson A, January 04, 2006 - 7:44 am UTC

Hi Tom,

As you have told, a global index on a partitioned table becomes unusable when a partition is truncated. Till the index is rebuilt, queries that uses the index fail.

Is there any way to reduce the downtime? (For version 9.2.0.6)

Thanks and Regards,

Albert Nelson A

Tom Kyte
January 04, 2006 - 10:45 am UTC

You may "update global indexes" in Oracle9i

<quote src=Expert Oracle: Database Architecture>

"Live" Global Index Maintenance

Starting in Oracle9i, another option was added to partition maintenance: the ability to maintain the global indexes during the partition operation using the UPDATE GLOBAL INDEXES clause. This means that as you drop a partition, split a partition, perform whatever operation necessary on a partition -  Oracle will perform the necessary modifications to the global index to keep it up to date. Since most partition operations will cause this global index invalidation to occur, this feature can be a boon to systems that need to provide continual access to the data. You'll find that you sacrifice the raw speed of the partition operation, but with the associated window of unavailability immediately afterward as you rebuild indexes, for a slower overall response time from the partition operation but coupled with 100 percent data availability. In short, if you have a data warehouse that cannot have downtime, but must support these common data warehouse techniques of sliding data in and out, then this feature is for you-but you must understand the implications.

Revisiting our previous example, if our partition operations had used the UPDATE GLOBAL INDEXES clause when relevant (in this example, it would not be needed on the ADD PARTITION statement since the newly added partition would not have any rows in it)

ops$tkyte@ORA10G> alter table partitioned
  2  exchange partition fy_2004
  3  with table fy_2004
  4  including indexes
  5  without validation
  6  UPDATE GLOBAL INDEXES
  7  /
Table altered.
 
ops$tkyte@ORA10G> alter table partitioned
  2  drop partition fy_2004
  3  UPDATE GLOBAL INDEXES
  4  /
Table altered.
 
ops$tkyte@ORA10G> alter table partitioned
  2  add partition fy_2006
  3  values less than ( to_date('01-jan-2007','dd-mon-yyyy') )
  4  /
Table altered.
 
ops$tkyte@ORA10G> alter table partitioned
  2  exchange partition fy_2006
  3  with table fy_2006
  4  including indexes
  5  without validation
  6  UPDATE GLOBAL INDEXES
  7  /
Table altered.

we would have discovered the indexes to be perfectly valid and usable both during and after the operation:

ops$tkyte@ORA10G> select index_name, status from user_indexes;
 
INDEX_NAME                     STATUS
------------------------------ --------
FY_2006_IDX                    VALID
FY_2004_IDX                    VALID
PARTITIONED_IDX_GLOBAL         VALID
PARTITIONED_IDX_LOCAL          N/A
 
6 rows selected.
 
ops$tkyte@ORA10G> set autotrace on explain
ops$tkyte@ORA10G> select count(*)
  2  from partitioned
  3  where timestamp between sysdate-50 and sysdate;
 
  COUNT(*)
----------
      6750
 
Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=9 Card=1 Bytes=9)
   1    0   SORT (AGGREGATE)
   2    1     FILTER
   3    2       INDEX (RANGE SCAN) OF 'PARTITIONED_IDX_GLOBAL' (INDEX) (Cost=9

But there is a tradeoff: we are performing the logical equivalent of INSERT and DELETE operations on the global index structures. When we drop a partition, we have to delete all of the global index entries that might be pointing to that that partition. When we did the exchange of a table with a partition, we had to delete all of the global index entries pointing to the original data and then insert all of the new ones that we just slid in there. So the amount of work performed by the ALTER commands was significantly increased.

In fact, using runstats and a slightly modified version of the preceding example, we can measure the amount of "extra" work performed to maintain the global indexes during the partition operation. We'll slide out FY_2004 and slide in FY_2006 as before, adding in the requisite index rebuild. This will be the sliding window implementation that causes the data to become unavailable due to the need to rebuild the global indexes. We'll also then slide out FY_2005 and slide in FY_2007 using the UPDATE GLOBAL INDEXES clause, to emulate the sliding window implementation that provides for full data availability, even during the partition operations. In that manner, we can measure the same operations using the different techniques and compare them. Our expected outcome will be that the first approach will consume fewer database resources and therefore perform "faster" but incur a measurable period of "downtime." The second approach, while consuming more resources and perhaps taking longer overall, will not incur downtime. As far as the end users are concerned, their ability to work never ceased. They might have been processing a bit slower (since we were competing with them for resources), but they were still processing, and they never stopped.

So, if we take the earlier example, but also create an empty FY_2005 table like FY_2004, and a full FY_2007 table like FY_2006, we can measure the differences between the index rebuild approaches, starting first with the "less available approach":

exec runStats_pkg.rs_start;

alter table partitioned exchange partition fy_2004
with table fy_2004 including indexes without validation;

alter table partitioned drop partition fy_2004;

alter table partitioned add partition fy_2006
values less than ( to_date('01-jan-2007','dd-mon-yyyy') );

alter table partitioned exchange partition fy_2006
with table fy_2006 including indexes without validation;

alter index partitioned_idx_global rebuild;

exec runStats_pkg.rs_middle;

Here is the highly available UPDATE GLOBAL INDEXES approach:

alter table partitioned exchange partition fy_2005
with table fy_2005 including indexes without validation 
update global indexes;

alter table partitioned drop partition fy_2005
update global indexes;

alter table partitioned add partition fy_2007
values less than ( to_date('01-jan-2008','dd-mon-yyyy') );

alter table partitioned exchange partition fy_2007
with table fy_2007 including indexes without validation
update global indexes;

exec runStats_pkg.rs_stop;
We might observe the following:
ops$tkyte@ORA10G> exec runStats_pkg.rs_stop;
Run1 ran in 81 hsecs
Run2 ran in 94 hsecs
run 1 ran in 86.17% of the time

Name                                  Run1        Run2        Diff
...
STAT...CPU used when call star          39          59          20
...
STAT...redo entries                    938       3,340       2,402
STAT...db block gets                 1,348       5,441       4,093
STAT...session logical reads         2,178       6,455       4,277
...
LATCH.cache buffers chains           5,675      27,695      22,020
...
STAT...table scan rows gotten       97,711     131,427      33,716
STAT...undo change vector size      35,100   3,404,056   3,368,956
STAT...redo size                 2,694,172   6,197,988   3,503,816

The index rebuild approach did run faster, both as observed by the elapsed time and the CPU time. This fact has caused many a DBA to pause and say, "Hey, I don't want to use UPDATE GLOBAL INDEXES-it's slower." That is too simplistic of a view, however. What you need to remember is that while the operations overall took longer, processing on your system was not necessarily interrupted. Sure, you as the DBA might be looking at your screen for a longer period of time, but the really important work that takes place on your system was still taking place. What you need to do is see if this tradeoff makes sense for you. If you have an eight-hour maintenance window overnight in which to load new data, then by all means, use the rebuild approach if that makes sense. However, if you have a mandate to be available continuously, then the ability to maintain the global indexes will be crucial.

Looking at the redo generated by each approach, we can see that the UPDATE GLOBAL INDEXES generated considerably more-over 230 percent more-and we would expect that to only go up as we add more and more global indexes to the table. The redo generated by the UPDATE GLOBAL INDEXES is unavoidable and cannot be turned off via NOLOGGING, since the maintenance of the global indexes is not a complete rebuild of their structure but more of an incremental "maintenance." Additionally, since we are maintaining the live index structure, we must generate undo for that-in the event the partition operation fails, we must be prepared to put the index back the way it was. And remember, undo is protected by redo itself, so some of the redo you see generated is from the index updates and some is from the rollback. Add another global index or two and you would reasonably expect these numbers to increase.

So, UPDATE GLOBAL INDEXES is an option that allows you to trade off availability for resource consumption. If you have the need to provide continuous availability, it will be the option for you. But you will have to understand the ramifications and size other components of your system appropriately. Specifically, many data warehouses have been crafted over time to use bulk, direct path operations, bypassing undo generation and, when permitted, redo generation as well. Using UPDATE GLOBAL INDEXES cannot bypass either of those two elements. You'll need to examine the rules you used to size these components before using this feature, so you can assure yourself it can work on your system.
</quote>

 

Thanks for the excellent reply.

Albert Nelson A, January 04, 2006 - 1:21 pm UTC


Unusable Index on a Partitioned table

Paul Hill, February 15, 2006 - 10:59 am UTC

Tom,

I've been searching everywhere for some examples of using Global indexes, even the Oracle manuals didn't appear to supply anything that I could use, including the Oracle 9i Data Warehousing Guide.

The examples you have given of the effect of manipulating partitioned tables on Global indexes has made things much clearer to me.

Thanks for your help.