Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Burned by DBMS_STATS **AGAIN**
I did too. I thought it was from the virus incident, that is a current
thread and I have deleted all but the last message. Here is what is left.
I have attached a document that I made while I was at smartforc as well
I've just checked on my 8.1.7.4
create table t1 (n1 number, v1 varchar2(10)); create index t1_idx on t1(n1);
insert into t1
select rownum rownum
from all_objects
where rownum <= 100;
analyze table T1 compute statistics;
select * from user_tab_histograms
where table_name = 'T1';
This gives me two rows each
for N1 and V1.
Similarly
select low_value, high_value
from user_tab_columns
where table_name = 'T1';
gives me one row for each column,
with the high and low value set.
analyze table XXX compute statistics;
should be the equivalent of
'for table for ALL columns size 1';
Regards
Jonathan Lewis
http://www.jlcomp.demon.co.uk
> OK, I've saved the histograms generated by each method using:
>
>
> Sure enough, the query returns no rows, leading me to believe that AALYZE
> TABLE...COMPUTE STATISTICS generates histograms of SIZE 1 for all
> NON-indexed columns. Does this conclusion sound correct? If so, then it
> doesn't appear from the 8i docs that there is a method in DBMS_STATS to
> emulate this. So, now what? I'm a little hesitant to initially gather
> stats using ANALYZE, then rely on DBMS_STATS afterwards because of the
> differences in the stats they gather. It would seem to me that there's a
> very good chance that the stats that aren't regularly updated with
> DBMS_STATS will become stale and at some point could negatively alter
> explain plans.
>
-----Original Message-----
Sent: Tuesday, April 08, 2003 7:09 PM
To: Multiple recipients of list ORACLE-L
I've just checked on my 8.1.7.4
create table t1 (n1 number, v1 varchar2(10)); create index t1_idx on t1(n1);
insert into t1
select rownum rownum
from all_objects
where rownum <= 100;
analyze table T1 compute statistics;
select * from user_tab_histograms
where table_name = 'T1';
This gives me two rows each
for N1 and V1.
Similarly
select low_value, high_value
from user_tab_columns
where table_name = 'T1';
gives me one row for each column,
with the high and low value set.
analyze table XXX compute statistics;
should be the equivalent of
'for table for ALL columns size 1';
Regards
Jonathan Lewis
http://www.jlcomp.demon.co.uk
The educated person is not the person
who can answer the questions, but the
person who can question the answers -- T. Schick Jr
One-day tutorials:
http://www.jlcomp.demon.co.uk/tutorial.html
____UK_______April 22nd ____Denmark__May 21-23rd ____USA_(FL)_May 2nd
Three-day seminar:
see http://www.jlcomp.demon.co.uk/seminar.html
____UK_(Manchester)_May ____Estonia___June (provisional) ____Australia_June (provisional) ____USA_(CA, TX)_August
The Co-operative Oracle Users' FAQ
http://www.jlcomp.demon.co.uk/faq/ind_faq.html
> OK, I've saved the histograms generated by each method using:
>
>
> Sure enough, the query returns no rows, leading me to believe that
ANALYZE
> TABLE...COMPUTE STATISTICS generates histograms of SIZE 1 for all
> NON-indexed columns. Does this conclusion sound correct? If so,
then it
> doesn't appear from the 8i docs that there is a method in DBMS_STATS
to
> emulate this. So, now what? I'm a little hesitant to initially
gather
> stats using ANALYZE, then rely on DBMS_STATS afterwards because of
the
> differences in the stats they gather. It would seem to me that
there's a
> very good chance that the stats that aren't regularly updated with
> DBMS_STATS will become stale and at some point could negatively
alter
> explain plans.
>
-- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Jonathan Lewis INET: jonathan_at_jlcomp.demon.co.uk 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 Wed Apr 09 2003 - 08:13:39 CDTContent-Type: text/plain; name="ReadMe.txt"; charset="us-ascii" Content-Transfer-Encoding: 7bit The previous attachment was filtered out by the ListGuru mailing software at fatcity.com because binary attachments are not appropriate for mailing lists. If you want a copy of the attachment which was removed, contact the sender directly and ask for it to be sent to you by private E-mail. This warning is inserted into all messages containing binary attachments which have been removed by ListGuru. If you have questions about this message, contact Postmaster_at_fatcity.com for clarification. ------_=_NextPart_000_01C2FE91.A11FE410-- -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Earle, Jay (SNB/xwave) INET: Jay.Earle_at_snb.ca 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).
- application/msword attachment: dbms_stats.doc