Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: dbms_stats broken

RE: dbms_stats broken

From: Goulet, Dick <DGoulet_at_vicr.com>
Date: Thu, 29 May 2003 06:10:18 -0800
Message-ID: <F001.005A56D7.20030529061018@fatcity.com>


Darrell,

        I put dbms_stats into production, on 8.1.7.4, over two months ago & have not had a problem. Here is what I did to compute the stats automatically. (BTW: this runs under system)

create procedure compute_daily_stats is
begin
  for a in (select distinct table_owner from dba_tab_modifications) loop

        DBMS_STATS.GATHER_SCHEMA_STATS(a.table_owner,
                                       NULL,FALSE,
                                       'FOR ALL indexed COLUMNS SIZE 1',
                                       NULL,'DEFAULT',TRUE,NULL,NULL,'GATHER STALE','DEFAULT');
  end loop;
end;
/

declare
  jb integer;
begin
  dbms_job.submit(jb, 'compute_daily_stats;',trunc(sysdate+1)+(6/24),'trunc(sysdate+1)+(6/24)',FALSE);   dbms_output.put_line('Job is '||jb);
end;
/

Dick Goulet
Senior Oracle DBA
Oracle Certified 8i DBA

-----Original Message-----
Sent: Thursday, May 29, 2003 12:30 AM
To: Multiple recipients of list ORACLE-L

Lisa,

Wow, you might be saving me from peril right now. I have tested this with a small set of tables with no problems (in and 8.1.7.4 instance). I'm preparing to go 'schema' wide in the next week or so for further testing prior to implementing in production. I'd be very interested in more details of your problems in 8.1.7.4 and of course I'll post reports of testing to the list as well.

For starters, here is the code I use to obtain a list of 'stale' qualified tables:
( For proper credit, I think I got this from asktom.oracle.com)

set serverout on size 90000

declare
l_objList dbms_stats.objecttab;
begin
dbms_stats.gather_schema_stats
( ownname => '&1',
options => 'LIST STALE',
objlist => l_objlist );
for i in 1 .. l_objlist.count
loop
--dbms_output.put_line( l_objlist(i).objtype ); dbms_output.put_line( l_objlist(i).objname ); end loop;
end;
/

And the code to gather stats:

set serverout on size 99000

begin
dbms_stats.gather_schema_stats(

        ownname=>'&1',
        options=>'GATHER STALE',
        cascade=>TRUE,
        degree=>8,
        granularity=>'ALL',
        method_opt=>'FOR ALL INDEXED COLUMNS SIZE 1'
        );

end;
/

Thanks,
Darrell

>>> Lisa.Koivu_at_Fairfieldresorts.com 05/28/03 09:24PM >>>
Hello everyone,  

Is anyone using dbms_stats and gather stale or gather auto in 9.2? I'm
trying to use dbms_stats gather schema stats with the stale option and it just isn't working in 8.1.7.4. This is documented on Metalink. I'd
love to hear from someone else if this is fixed in 9.2 and if it can be
reliably used.  

Thank you
Lisa Monkey.    

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Darrell Landrum
  INET: dlandrum_at_zalecorp.com

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Goulet, Dick
  INET: DGoulet_at_vicr.com

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Thu May 29 2003 - 09:10:18 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US