无码视频在线观看,99人妻,国产午夜视频,久久久久国产一级毛片高清版新婚

  • 始創(chuàng)于2000年 股票代碼:831685
    咨詢熱線:0371-60135900 注冊(cè)有禮 登錄
    • 掛牌上市企業(yè)
    • 60秒人工響應(yīng)
    • 99.99%連通率
    • 7*24h人工
    • 故障100倍補(bǔ)償
    全部產(chǎn)品
    您的位置: 網(wǎng)站首頁(yè) > 幫助中心>文章內(nèi)容

    Oracle 11g R2 INDEX FAST FULL SCAN 成本計(jì)算

    發(fā)布時(shí)間:  2012/8/24 17:27:25

    SQL> select * from v$version where rownum<2;
    BANNER
    --------------------------------------------------------------------------------
    Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - Production
    -
     

    create index i_test_owner on test(owner);

    SQL> create index i_test_owner on test(owner);

    Index created.

    INDEX FAST FULL SCAN只需要掃描葉子塊,并且采用多塊讀,所以查詢LEAF_BLOCKS

    SQL>  select leaf_blocks from user_indexes where index_name='I_TEST_OWNER';

    LEAF_BLOCKS
    -----------
             22

    SQL> explain plan for select count(owner) from test;

    Explained.

    SQL> select cpu_cost from plan_table;

      CPU_COST
    ----------
       1356672
      
    SQL>  select pname, pval1 from sys.aux_stats$ where sname='SYSSTATS_MAIN';

    PNAME                               PVAL1
    ------------------------------ ----------
    CPUSPEED                             2500
    CPUSPEEDNW                     2696.05568
    IOSEEKTIM                              10
    IOTFRSPEED                           4096
    MAXTHR
    MBRC                                   12
    MREADTIM                               30
    SLAVETHR
    SREADTIM                                5

    9 rows selected.

    因?yàn)镸BRC不為空,所以CBO會(huì)采用工作量模式計(jì)算Cost
      
    INDEX FAST FULL SCAN 成本計(jì)算公式如下:

    Cost = (
           #SRds * sreadtim +
           #MRds * mreadtim +
           CPUCycles / cpuspeed /1000
           ) / sreadtime
          
    #SRds - number of single block reads
    #MRds - number of multi block reads
    #CPUCyles - number of CPU cycles

    sreadtim - single block read time
    mreadtim - multi block read time
    cpuspeed - CPU cycles per second

    Cost = (
           #SRds * sreadtim +                            ---SRds=0
           #MRds * mreadtim +                          ---MRds=Leaf_Blocks/MBCR=22/12, mreadtim=30
           CPUCycles / cpuspeed / 1000         ---CPUCycles=PLAN_TABLE.CPU_COST,cpuspeed=2500
           ) / sreadtime

    所以人工計(jì)算的成本等于:
    SQL> select ceil(22/12*30/5)+ceil(1356672/2500/5/1000)+1 from dual; ---+1是因?yàn)?_table_scan_cost_plus_one設(shè)置為true

    CEIL(22/12*30/5)+CEIL(1356672/2500/5/1000)+1
    --------------------------------------------
                                              13
                                                                                       
    SQL> select count(owner) from test;

    Execution Plan
    ----------------------------------------------------------
    Plan hash value: 1992658997

    --------------------------------------------------------------------------------------
    | Id  | Operation             | Name         | Rows  | Bytes | Cost (%CPU)| Time     |
    --------------------------------------------------------------------------------------
    |   0 | SELECT STATEMENT      |              |     1 |     5 |    13   (0)| 00:00:01 |
    |   1 |  SORT AGGREGATE       |              |     1 |     5 |            |          |
    |   2 |   INDEX FAST FULL SCAN| I_TEST_OWNER | 10000 | 50000 |    13   (0)| 00:00:01 |
    --------------------------------------------------------------------------------------

    現(xiàn)在采用非工作量統(tǒng)計(jì)來(lái)計(jì)算Cost

    SQL> begin
       dbms_stats.set_system_stats('CPUSPEED',0);
       dbms_stats.set_system_stats('SREADTIM',0);
       dbms_stats.set_system_stats('MREADTIM',0);
       dbms_stats.set_system_stats('MBRC',0);
    end;
    /
      2    3    4    5    6    7

    PL/SQL procedure successfully completed.

    SQL> show parameter db_file_multiblock_read_count

    NAME                                 TYPE        VALUE
    ------------------------------------ ----------- ------------------------------
    db_file_multiblock_read_count        integer     16

    SQL> select (select pval1 from sys.aux_stats$ where pname = 'IOSEEKTIM') +
           (select value
              from v$parameter
             where name = 'db_file_multiblock_read_count') *
      2    3    4    5         (select value from v$parameter where name = 'db_block_size') /
      6         (select pval1 from sys.aux_stats$ where pname = 'IOTFRSPEED') "mreadtim"
      7    from dual;

      mreadtim
    ----------
            42
    SQL> select (select pval1 from sys.aux_stats$ where pname = 'IOSEEKTIM') +
           (select value from v$parameter where name = 'db_block_size') /
           (select pval1 from sys.aux_stats$ where pname = 'IOTFRSPEED') "sreadtim"
      from dual;  2    3    4

      sreadtim
    ----------
            12
           
    SQL> select cpu_cost from plan_table;

      CPU_COST
    ----------
       1356672

    根據(jù)成本計(jì)算公式

    Cost = (
           #SRds * sreadtim +                            ---SRds=0
           #MRds * mreadtim +                          ---MRds=Leaf_Blocks/db_file_multiblock_read_count=22/16, mreadtim=42
           CPUCycles / cpuspeed / 1000         ---CPUCycles=PLAN_TABLE.CPU_COST,cpuspeed=2696.05568
           ) / sreadtime
          
    那么手工計(jì)算的Cost等于:

    SQL> select ceil(22/16*42/12)+ceil(1356672/2696.05568/12/1000)+1 from dual;

    CEIL(22/16*42/12)+CEIL(1356672/2696.05568/12/1000)+1
    ----------------------------------------------------
                                                       7
    SQL> set autot trace
    SQL> select count(owner) from test;

    Execution Plan
    ----------------------------------------------------------
    Plan hash value: 1992658997

    --------------------------------------------------------------------------------------
    | Id  | Operation             | Name         | Rows  | Bytes | Cost (%CPU)| Time     |
    --------------------------------------------------------------------------------------
    |   0 | SELECT STATEMENT      |              |     1 |     5 |     7   (0)| 00:00:01 |
    |   1 |  SORT AGGREGATE       |              |     1 |     5 |            |          |
    |   2 |   INDEX FAST FULL SCAN| I_TEST_OWNER | 10000 | 50000 |     7   (0)| 00:00:01 |
    --------------------------------------------------------------------------------------

    從實(shí)驗(yàn)中可以看到,INDEX FAST FULL SCAN 在11gR2中的成本算法依然和9i,10g一樣,沒(méi)有變化。


    本文出自:億恩科技【mszdt.com】

    服務(wù)器租用/服務(wù)器托管中國(guó)五強(qiáng)!虛擬主機(jī)域名注冊(cè)頂級(jí)提供商!15年品質(zhì)保障!--億恩科技[ENKJ.COM]

  • 您可能在找
  • 億恩北京公司:
  • 經(jīng)營(yíng)性ICP/ISP證:京B2-20150015
  • 億恩鄭州公司:
  • 經(jīng)營(yíng)性ICP/ISP/IDC證:豫B1.B2-20060070
  • 億恩南昌公司:
  • 經(jīng)營(yíng)性ICP/ISP證:贛B2-20080012
  • 服務(wù)器/云主機(jī) 24小時(shí)售后服務(wù)電話:0371-60135900
  • 虛擬主機(jī)/智能建站 24小時(shí)售后服務(wù)電話:0371-60135900
  • 專注服務(wù)器托管17年
    掃掃關(guān)注-微信公眾號(hào)
    0371-60135900
    Copyright© 1999-2019 ENKJ All Rights Reserved 億恩科技 版權(quán)所有  地址:鄭州市高新區(qū)翠竹街1號(hào)總部企業(yè)基地億恩大廈  法律顧問(wèn):河南亞太人律師事務(wù)所郝建鋒、杜慧月律師   京公網(wǎng)安備41019702002023號(hào)
      1
     
     
     
     

    0371-60135900
    7*24小時(shí)客服服務(wù)熱線