SQL文本如下,跨分区查询,分区字段post_date(为保证客户隐私,已经将注释和文字部分去掉):
跨30个分区执行了6分钟。
SELECT /*+index(I IND_DATE_CORRE_AMOUNT_CODE)*/ I.POST_DATE AS JYRQ, --I.ACCT_NO AS ZH, NVL((SELECT S.ACCT_NO_DESC || S.ACCT_NO_ALL2 FROM INVM_ZMQ S WHERE S.ACCT_NO=I.ACCT_NO AND S.ZHLB='3'),I.ACCT_NO) AS ZH, (SELECT C.CUSTOMER_NAME FROM CB_ACCT C WHERE C.SYS_ID='INV' AND C.ACCT_NO=I.ACCT_NO) AS HM, I.TRAN_CODE AS JYDM, (SELECT SUBSTR(J.PROFIT_NARR,3,3) FROM JR01_01 J WHERE J.POST_DATE=I.POST_DATE AND J.JRNL_NO=I.JRNL_NO AND J.ACCT_NO=I.ACCT_NO AND ROWNUM=1 ) AS XJFXH, NVL((SELECT S.CURRENCY FROM INVM_ZMQ S WHERE S.ACCT_NO=I.ACCT_NO),I.CURRENCY) AS BZ, ABS(I.INCT_01_AMOUNT) AS JYJE, I.TELLER_NO AS CZY FROM INCT_01 I WHERE I.POST_DATE BETWEEN TO_DATE('2018-04-01','YYYY-MM-DD') AND TO_DATE('2018-04-30','YYYY-MM-DD') AND I.TRAN_BRANCH IN (SELECT JGM FROM JGDY WHERE JGDY.JGM='0500' OR SJJGM='0500') AND I.INCT_01_CORRECTION!='1' AND ABS(I.INCT_01_AMOUNT)*(SELECT HL FROM BBHL B WHERE B.STARTDATE<=I.POST_DATE AND B.ENDDATE>I.POST_DATE AND B.YB=I.CURRENCY AND ZB='CNY')>=NVL2('',0,50000) AND EXISTS (SELECT CB_EDP.TRAN_CODE FROM CB_EDP WHERE TRAN_CODE=I.TRAN_CODE AND CA_FLAG='0' AND CT_FLAG!='1' AND CD_FLAG='0');
执行计划:
查看索引,包含了分区字段,且少了TRAN_BRANCH列。
创建索引:
1
2 |
CREATE
INDEX
IND_TRAN_CORRECTION_ABS_TRAN
ON
INCT_01 (TRAN_BRANCH,INCT_01_CORRECTION,
ABS
(INCT_01_AMOUNT),TRAN_CODE)
local
PARALLEL 10 TABLESPACE IDXT; ALTER
INDEX
IND_TRAN_CORRECTION_ABS_TRAN NOPARALLEL; |
创建索引后跨30个分区查询需要8秒钟完成,IND_TRAN_CORRECTION_ABS_TRAN索引还是有点问题的,大家能看出来哪有问题吗?
当查询跨分区的时候,且where条件中包含分区字段,我们只需要在非分区字段建立本地索引(本地的组合索引),分区字段会自行的进行分区裁剪;如果查询不跨分区那么就需要建立包含分区字段的前缀索引,这时候能过滤掉大量的不必要的数据,当然具体情况还要根据分区的大小、系统中一般的查询条件、要求多长时间返回数据而定;当查询条件中没有分区字段这时候就需要建立global索引。
| 作者简介