亚洲Aⅴ无码Av红楼在线观看_国产午夜福利涩爱AⅤ_国产sm调教一区二区三区_精品人妻一区二区三区不卡毛片

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

SQL調(diào)優(yōu)之關(guān)注filter信息

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

開(kāi)發(fā)人員發(fā)來(lái)郵件,叫我優(yōu)化下面SQL

Hi Robinson,
-
 

Kindly need your help to check the below SQL for performance issue with Hyper plan detail report. Thanks in advance.

 

select avg(T2094771.MEASR_AMT) as c1,

     sum(T2094771.MEASR_YA_AMT) as c2,

     sum(T2094771.MEASR_CURR_AMT) as c3,

     sum(T2094771.MEASR_AMT) as c4,

     T2095164.ACCT_LONG_NAME as c5,

     T2095164.NAME as c6,

     T2095002.PROD_DESC as c7,

     T2093992.MTH_NAME as c8,

     T2093992.MTH_NUM as c9,

     T2094784.MEASR_NAME as c10,

     T2094784.MEASR_ORDR_SKID as c11,

     upper(T2095164.FUND_FRCST_MODEL_DESC) as c12

from

     ADWU_OPTIMA_WE11.OPT_MEASR_DIM T2094784,

     ADWU_OPTIMA_WE11.OPT_ACCT_FDIM T2095164 /* OPT_ACCT_PRMTN_FDIM */ ,

     ADWU_OPTIMA_WE11.OPT_PROD_BRAND_ASDN_DIM T2095002,

     ADWU_OPTIMA_WE11.OPT_BUS_UNIT_FDIM T2093691,

     ADWU_OPTIMA_WE11.OPT_CAL_MASTR_DIM T2093992 /* OPT_CAL_MASTR_DIM01 */ ,

     ADWU_OPTIMA_WE11.OPT_HYPER_PLAN_FCT T2094771

where  ( T2094771.MEASR_SKID = T2094784.MEASR_SKID

and T2094771.PROD_SKID = T2095002.BRAND_SKID

and T2094771.BUS_UNIT_SKID = T2095002.BUS_UNIT_SKID

and T2093691.BUS_UNIT_SKID = T2094771.BUS_UNIT_SKID

and T2093992.CAL_MASTR_SKID = T2094771.DATE_SKID

and T2094771.ACCT_SKID = T2095164.ACCT_SKID

and T2094771.BUS_UNIT_SKID = T2095164.BUS_UNIT_SKID

and T2093691.BUS_UNIT_NAME = 'Austria Retail'

and T2093992.FISC_YR_ABBR_NAME = 'FY10/11'

and T2094771.FY_DATE_SKID = T2095002.FY_DATE_SKID

and T2095002.PROD_LVL_DESC = 'Category'

and T2095164.ACCT_LONG_NAME = 'SPAR AT - 2000122510'

and T2094771.MEASR_SKID <> 1 and T2094771.MEASR_SKID <> 2

and T2094784.MEASR_SKID <> 1 and T2094784.MEASR_SKID <> 2

and (T2095002.PROD_DESC in ('Baby Wipes - 1000045671', 'Childrens Personal Care - 1101158952', 'Diapers - 1000043704', 'Dummy Category for Unknown Category - 0'))

and T2094784.MEASR_NAME <> 'D-NOS Index YA' )

group by T2093992.MTH_NAME, T2093992.MTH_NUM, T2094784.MEASR_ORDR_SKID, T2094784.MEASR_NAME, T2095002.PROD_DESC,

T2095164.NAME, T2095164.ACCT_LONG_NAME, upper(T2095164.FUND_FRCST_MODEL_DESC)

order by c8, c7, c5, c11, c10

 

 

------Run SQL on UAT-----UAT要跑2分44秒

 

508 rows selected.

 

Elapsed: 00:02:24.22 

 

On UAT, SQL can be finished in about 2minutes and 25 seconds.

 

-----Run SQL on Prod-----Prod要跑6分44秒

 

482 rows selected.

 

Elapsed: 00:06:44.27

 

 

上面的SQL是OBIEE報(bào)表使用的,我們無(wú)法更改代碼,客戶(hù)使用的肯定是PROD環(huán)境,這個(gè)SQL要跑6分44秒肯定是不能接受的,一般客戶(hù)最多能等3分鐘,也就是說(shuō)要讓SQL再3分鐘以?xún)?nèi)出結(jié)果。SQL調(diào)優(yōu)做多了,這種SQL真的沒(méi)什么挑戰(zhàn)性,也就看看執(zhí)行計(jì)劃,1分鐘就能搞定的事情

 

我們來(lái)看一下執(zhí)行計(jì)劃:

SQL> select * from table(dbms_xplan.display);

 

PLAN_TABLE_OUTPUT

-----------------------------------------------------------------------------------------------------------------------------------------

Plan hash value: 1422339931

 

------------------------------------------------------------------------------------------------------------------------------------

| Id  | Operation                                | Name                    | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |

------------------------------------------------------------------------------------------------------------------------------------

|   0 | SELECT STATEMENT                         |                         |     1 |   250 |   847  (58)| 00:00:04 |       |       |

|   1 |  SORT GROUP BY                           |                         |     1 |   250 |   847  (58)| 00:00:04 |       |       |

|   2 |   NESTED LOOPS                           |                         |       |       |         |     |       |       |

|   3 |    NESTED LOOPS                          |                         |     1 |   250 |   846  (58)| 00:00:04 |       |       |

|   4 |     NESTED LOOPS                         |                         |     1 |   220 |   845  (58)| 00:00:04 |       |       |

|   5 |      NESTED LOOPS                        |                         |     1 |   161 |   841  (58)| 00:00:04 |       |       |

|*  6 |       HASH JOIN                          |                         |    14 |  1778 |   827  (59)| 00:00:04 |       |       |

|   7 |        PARTITION LIST ALL                |                         |     4 |   280 |    19   (0)| 00:00:01 |     1 |    14 |

|   8 |         TABLE ACCESS BY LOCAL INDEX ROWID| OPT_ACCT_FDIM           |     4 |   280 |    19   (0)| 00:00:01 |     1 |    14 |

|*  9 |          INDEX RANGE SCAN                | OPT_ACCT_FDIM_NX2       |     4 |       |    15   (0)| 00:00:01 |     1 |    14 |

|  10 |        NESTED LOOPS                      |                         |  2417K|   131M|   698  (54)| 00:00:03 |       |       |

|* 11 |         INDEX RANGE SCAN                 | OPT_BUS_UNIT_FDIM_UX2   |     1 |    19 |     1   (0)| 00:00:01 |       |       |

|  12 |         PARTITION LIST ITERATOR          |                         |  2417K|    87M|   697  (54)| 00:00:03 |   KEY |   KEY |

|* 13 |          TABLE ACCESS FULL               | OPT_HYPER_PLAN_FCT      |  2417K|    87M|   697  (54)| 00:00:03 |   KEY |   KEY |

|* 14 |       TABLE ACCESS BY INDEX ROWID        | OPT_MEASR_DIM           |     1 |    34 |     1   (0)| 00:00:01 |       |       |

|* 15 |        INDEX UNIQUE SCAN                 | OPT_MEASR_DIM_PK        |     1 |       |     0   (0)| 00:00:01 |       |       |

|  16 |      PARTITION LIST ITERATOR             |                         |     1 |    59 |     3  (34)| 00:00:01 |   KEY |   KEY |

|* 17 |       TABLE ACCESS FULL                  | OPT_PROD_BRAND_ASDN_DIM |     1 |    59 |     3  (34)| 00:00:01 |   KEY |   KEY |

|* 18 |     INDEX UNIQUE SCAN                    | OPT_CAL_MASTR_DIM_PK    |     1 |       |     0   (0)| 00:00:01 |       |       |

|* 19 |    TABLE ACCESS BY INDEX ROWID           | OPT_CAL_MASTR_DIM       |     1 |    30 |     1   (0)| 00:00:01 |       |       |

------------------------------------------------------------------------------------------------------------------------------------

 

Predicate Information (identified by operation id):

---------------------------------------------------

 

   6 - access("T2094771"."BUS_UNIT_SKID"="T2095164"."BUS_UNIT_SKID" AND "T2094771"."ACCT_SKID"="T2095164"."ACCT_SKID")

   9 - access("T2095164"."ACCT_LONG_NAME"='SPAR AT - 2000122510')

  11 - access("T2093691"."BUS_UNIT_NAME"='Austria Retail')

  13 - filter("T2094771"."MEASR_SKID"<>2 AND "T2094771"."MEASR_SKID"<>1 AND

              "T2093691"."BUS_UNIT_SKID"="T2094771"."BUS_UNIT_SKID")

  14 - filter("T2094784"."MEASR_NAME"<>'D-NOS Index YA')

  15 - access("T2094771"."MEASR_SKID"="T2094784"."MEASR_SKID")

       filter("T2094784"."MEASR_SKID"<>1 AND "T2094784"."MEASR_SKID"<>2)

  17 - filter("T2095002"."PROD_LVL_DESC"='Category' AND ("T2095002"."PROD_DESC"='Baby Wipes - 1000045671' OR

              "T2095002"."PROD_DESC"='Childrens Personal Care - 1101158952' OR "T2095002"."PROD_DESC"='Diapers - 1000043704' OR

              "T2095002"."PROD_DESC"='Dummy Category for Unknown Category - 0') AND "T2094771"."PROD_SKID"="T2095002"."BRAND_SKID" AND

              "T2094771"."BUS_UNIT_SKID"="T2095002"."BUS_UNIT_SKID" AND "T2094771"."FY_DATE_SKID"="T2095002"."FY_DATE_SKID")

  18 - access("T2093992"."CAL_MASTR_SKID"="T2094771"."DATE_SKID")

  19 - filter("T2093992"."FISC_YR_ABBR_NAME"='FY10/11')

 

44 rows selected.

看出來(lái)了嗎,問(wèn)題在于

17 - filter("T2095002"."PROD_LVL_DESC"='Category' AND ("T2095002"."PROD_DESC"='Baby Wipes - 1000045671' OR
            "T2095002"."PROD_DESC"='Childrens Personal Care - 1101158952' OR "T2095002"."PROD_DESC"='Diapers - 1000043704' OR
            "T2095002"."PROD_DESC"='Dummy Category for Unknown Category - 0') AND "T2094771"."PROD_SKID"="T2095002"."BRAND_SKID" AND
            "T2094771"."BUS_UNIT_SKID"="T2095002"."BUS_UNIT_SKID" AND "T2094771"."FY_DATE_SKID"="T2095002"."FY_DATE_SKID")

 

有人可能會(huì)說(shuō)問(wèn)題在于這里:

13 - filter("T2094771"."MEASR_SKID"<>2 AND "T2094771"."MEASR_SKID"<>1 AND
            "T2093691"."BUS_UNIT_SKID"="T2094771"."BUS_UNIT_SKID")

 

OK,測(cè)試一把

 

SQL> select BUS_UNIT_SKID,count(*) from OPT_HYPER_PLAN_FCT group by BUS_UNIT_SKID;

BUS_UNIT_SKID   COUNT(*)
------------- ----------
        14346     629624
        14347    9283369
        14348    4405691
        14349    3811875
        14361     105556
        14362    2128613
        14363    1284530
        14364    6633483
        14365       4344
        14366      93072
        14369        324

 

11 rows selected.

所以不合適。

所以創(chuàng)建如下索引:

SQL> create index OPT_PROD_BRAND_ASDN_DIM_NX1 ON OPT_PROD_BRAND_ASDN_DIM(PROD_DESC,BRAND_SKID,FY_DATE_SKID,PROD_LVL_DESC,BUS_UNIT_SKID);

 

Index created.

 

Elapsed: 00:00:01.79

 

------RUN SQL ON PROD------

 

482 rows selected.

 

Elapsed: 00:00:24.50 -------- SQL能在24秒跑完。

 

看到這里明白怎么做SQL優(yōu)化了沒(méi)?我只要是看見(jiàn)一個(gè)人用工具看執(zhí)行計(jì)劃,我就知道他是個(gè)SQL調(diào)優(yōu)菜鳥(niǎo)。


本文出自:億恩科技【www.allwellnessguide.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ù)電話(huà):0371-60135900
  • 虛擬主機(jī)/智能建站 24小時(shí)售后服務(wù)電話(huà):0371-60135900
  • 專(zhuān)注服務(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)
      0
     
     
     
     

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