RE: SYS.HIST_HEAD$ defrag?

  • From: "Herring Dave - dherri" <Dave.Herring@xxxxxxxxxx>
  • To: "Alex Gorbachev" <ag@xxxxxxxxxxxx>
  • Date: Thu, 23 Aug 2007 06:21:21 -0500

Thanks Alex.

I tested a variety of options - deleting table stats first, setting
column stats, then deleting column stats - and by far the last test was
the fastest.  Like you said, really odd.

I really should test this under various 10g releases.  Then if the
problem shows up I'd be more willing to open an SR with Oracle.  Under
9.2.0.8 I'm too pessimistic about the results.

Another note on this.  A SELECT statement is issued per row to be
deleted against HIST_HEAD$.  This is the statement that's killing us:

select /*+ rule */ bucket_cnt, row_cnt, cache_cnt, null_cnt, timestamp#,
  sample_size, minimum, maximum, distcnt, lowval, hival, density, col#,
  spare1, spare2, avgcln
from
 hist_head$ where obj#=:1 and intcol#=:2

------------------------------------------------------------------------
----
|Id |Operation                   | Name             |Rows  | Bytes |
Cost  |
------------------------------------------------------------------------
----
|  0|SELECT STATEMENT            |                  |      |       |
|
|  1| TABLE ACCESS BY INDEX ROWID|HIST_HEAD$        |      |       |
|
|* 2|  INDEX RANGE SCAN          |I_HH_OBJ#_INTCOL# |      |       |
|
------------------------------------------------------------------------
---

This statement is NOT issued when the table isn't partitioned.

Anyway, even if I gathered stats on the table and index (don't like the
idea against a SYS-owned, 9i database on production), I'd still be out
of luck due to the RULE hint.

Dave
___________________________________

David C. Herring, DBA  |   A c x i o m  Delivery Center Organization

630-944-4762 office | 630-430-5988 wireless | 630-944-4989 fax

> -----Original Message-----
> From: gorbyx@xxxxxxxxx [mailto:gorbyx@xxxxxxxxx] On Behalf Of Alex
> Gorbachev
> Sent: Wednesday, August 22, 2007 8:32 PM
> To: Herring Dave - dherri
> Cc: oracle-l@xxxxxxxxxxxxx
> Subject: Re: SYS.HIST_HEAD$ defrag?
> 
> Dave,
> 
> First of all, I think you did a good job identifying the problem. So
> you are half way through! ;-)
> 
> I'd rather log a bug with Oracle and make them rewrite it properly -
> deleting 1000s of rows with one delete per row is the most inefficient
> way you can find. Fragmented or not - it's bound to have performance
> issues.
> 
> As a workaround you might consider to not collect histograms or to use
> granularity global but that might impact your data warehouse (it's
> data warehouse. isn't it?). You mentioned that might be unavailable.
> 
> Another idea would be to try removing stats before dropping the table.
> Maybe it's done more efficient in dbms_stats?
> 
> On 8/22/07, Herring Dave - dherri <Dave.Herring@xxxxxxxxxx> wrote:
> > Folks,
> >
> > I've noticed that access of SYS.HIST_HEAD$ takes rather long,
especially
> during the drop of an option with hundreds of partitions, hundreds of
> columns.  The table referenced has statistics gathered on it using
>
DBMS_STATS.GATHER_TABLE_STATS(<owner>,<tabname>,estimate=>1,granularity=
>'
> ALL'), which I believe creates 1 row per column per partition, which
in
> this particular table's case consumes 100,000+ entries.  A drop of
this
> table takes around 1.5 hrs!  The table has around 60,000,000 rows in
it.
> >
> > I've found using event 10046 that nearly all elapsed time is spent
> removing rows from HIST_HEAD$, one DELETE statement per entry.
> >
> > My question is, can SYS.HIST_HEAD$ be rebuilt/defragmented somehow?
I
> gathered stats on it to get some info (then deleted those stats), then
> created a copy of the table with same storage info.  The block count
> dropped 50%.
> >
> > This is on a 9.2.0.8 database under Tru64 5.1b.  The ETL process
which
> drops/recreates this table weekly is not something I can control.  So
I
> can't change the object's configuration nor how stats are gathered.
> >
> > I will add that I've created a BEFORE DDL trigger to check for a
DROP of
> this table.  When triggered, a loop runs
DBMS_STATS.DROP_COLUMN_STATISTICS
> per column in the table, which speeds things up to the point of the
DROP
> taking at most .5 hrs.
> >
> > I'd appreciate any helpful suggestions or experiences with any type
of
> SYS-owned objects related to problems like the above.
> >
> > Thanks.
> >
> > Dave
> >
> >
> > ___________________________________
> > David C. Herring, DBA| A c x i o m Delivery Center Organization
> > 630-944-4762office |630-430-5988 wireless|630-944-4989 fax
> >
>
************************************************************************
*
> > The information contained in this communication is confidential, is
> > intended only for the use of the recipient named above, and may be
> > legally privileged.
> >
> > If the reader of this message is not the intended recipient, you are
> > hereby notified that any dissemination, distribution or copying of
this
> > communication is strictly prohibited.
> >
> > If you have received this communication in error, please resend this
> > communication to the sender and delete the original message or any
copy
> > of it from your computer system.
> >
> > Thank you.
> >
>
************************************************************************
*
> > --
> > //www.freelists.org/webpage/oracle-l
> >
> >
> >
> 
> 
> --
> Alex Gorbachev, Oracle DBA Brewer, The Pythian Group
> http://www.pythian.com/blogs/author/alex http://www.oracloid.com
> BAAG party - www.BattleAgainstAnyGuess.com
--
//www.freelists.org/webpage/oracle-l


Other related posts: