? ? ? ㈠ 先看兩個來自生產環境的真實案例:
? ? ? ? ?
? ? ? ? ?? 案例1
? ? ? ? ?? 案例2
?
? ? ? ㈡ 原理:
? ? ?
? ? ?Oracle 在對于 varchar等字符型字段收集統計信息時,并不會對每個值都進行精確的統計
? ? ?而是,對值進行substr(,32)。一般來講,這種方式沒有什么問題
? ? ?但是,如果恰巧列中存儲的數據,前32bytes相同,那么,Oracle 的統計就會與實際情況不符
? ? ?
? ? ?
㈢ 測試:
?
?
hr@ORCL> drop table t purge; Table dropped. hr@ORCL> create table t (id number,name varchar2(300)); Table created. hr@ORCL> create index idx_t on t (name); Index created. hr@ORCL> insert into t select rownum,lpad('a',6,'a')||to_char(rownum) from dba_objects; 50322 rows created. hr@ORCL> commit; Commit complete. hr@ORCL> exec dbms_stats.gather_table_stats(user,'T',null,null,method_opt=>'for columns size 254 name',cascade=>true); PL/SQL procedure successfully completed. hr@ORCL> select column_name, endpoint_actual_value 2 from user_tab_histograms 3 where table_name = 'T' 4 and rownum<5 5 order by column_name, endpoint_Number; COLUM ENDPOINT_ACTUAL_VALUE ----- -------------------------------------------------- NAME aaaaaa46556 NAME aaaaaa46734 NAME aaaaaa46912 NAME aaaaaa47090 hr@ORCL> truncate table t; Table truncated. hr@ORCL> insert into t select rownum,lpad('a',31,'a')||to_char(rownum) from dba_objects; 50322 rows created. hr@ORCL> exec dbms_stats.gather_table_stats(user,'T',null,null,method_opt=>'for columns size 254 name',cascade=>true); PL/SQL procedure successfully completed. hr@ORCL> select column_name, endpoint_actual_value 2 from user_tab_histograms 3 where table_name = 'T' 4 and rownum<5 5 order by column_name, endpoint_Number; COLUM ENDPOINT_ACTUAL_VALUE ----- -------------------------------------------------- NAME aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa1 NAME aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa2 NAME aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa3 NAME aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa4 hr@ORCL> truncate table t; Table truncated. hr@ORCL> insert into t select rownum,lpad('a',32,'a')||to_char(rownum) from dba_objects; 50322 rows created. hr@ORCL> exec dbms_stats.gather_table_stats(user,'T',null,null,method_opt=>'for columns size 254 name',cascade=>true); PL/SQL procedure successfully completed. hr@ORCL> select column_name, endpoint_actual_value 2 from user_tab_histograms 3 where table_name = 'T' 4 and rownum<5 5 order by column_name, endpoint_Number; COLUM ENDPOINT_ACTUAL_VALUE ----- -------------------------------------------------- ID ID NAME
?
? ? ? ㈣ 解決方案:
? ? ?
? ? ? ? ?
刪除索引列的直方圖
? ? ? ? ? 例子:
?
?
SQL> begin dbms_stats.gather_table_stats(ownname => 'HR', tabname => 'T' , estimate_percent => null , method_opt => 'for columns SIZE 1 name' , cascade => true); end; /
?
?
更多文章、技術交流、商務合作、聯系博主
微信掃碼或搜索:z360901061

微信掃一掃加我為好友
QQ號聯系: 360901061
您的支持是博主寫作最大的動力,如果您喜歡我的文章,感覺我的文章對您有幫助,請用微信掃描下面二維碼支持博主2元、5元、10元、20元等您想捐的金額吧,狠狠點擊下面給點支持吧,站長非常感激您!手機微信長按不能支付解決辦法:請將微信支付二維碼保存到相冊,切換到微信,然后點擊微信右上角掃一掃功能,選擇支付二維碼完成支付。
【本文對您有幫助就好】元
