RE: Odd behavior of function-based index after DB upgrade

From: Hameed, Amir <Amir.Hameed_at_xerox.com>
Date: Wed, 5 Oct 2011 21:43:43 -0400
Message-ID: <304F58144267C5439E733532ABC9A3A112F47D51_at_USA0300MS02.na.xerox.net>



VOUCHER_NO contains 7 digits.
SYSTEM has 24 distinct values

This table contains around 10,749,644 rows and the function-based index has 10,442,518 distinct values. So, the index is pretty selective. Without forcing the index via the RULE hint, the job ran for over 8 hours and had to be killed. With the rule hint, it ran in 15 minutes.

-----Original Message-----

From: Chitale, Hemant Krishnarao [mailto:Hemant.Chitale_at_sc.com] Sent: Wednesday, October 05, 2011 9:30 PM To: Hameed, Amir
Cc: oracle-l_at_freelists.org
Subject: RE: Odd behavior of function-based index after DB upgrade

How many "digits" are present in VOUCHER_NUMBER ? With 7 leading "zero"s, you'd need a significant number of digits for the index to be selective.

Similarly, how many distinct non-NULL does SYSTEM have ? (All NULL values are "translated" to 1).

 
Hemant K Chitale

-----Original Message-----

From: oracle-l-bounce_at_freelists.org [mailto:oracle-l-bounce_at_freelists.org] On Behalf Of Hameed, Amir Sent: Thursday, October 06, 2011 7:25 AM To: oracle-l mailing list
Subject: Odd behavior of function-based index after DB upgrade

We have recently upgraded one of our Oracle ERP (11i.10.2) systems database from 10.2.0.4 to 11.1.0.7. After the upgrade, we are seeing some odd behavior on a custom job that was working fine prior to the upgrade. Prior to the upgrade, the job was using a function-based index, however, it has stopped using that index after the upgrade.  

select * from dba_ind_expressions where
table_name='TXRIOH0_INV_OUTBOUND_HDRS_ALL' ;  

OWNER  INDEX_NAME                     TABLE_NAME
COLUMN_EXPRESSION                        COLUMN_POSITION


------ ------------------------------ ------------------------------
---------------------------------------- ---------------
XRX TXRIOH0_INV_OUTBOUND_HDRS_IDX3 TXRIOH0_INV_OUTBOUND_HDRS_ALL LPAD(NVL("VOUCHER_NO",'0'),7,'0') 1 XRX TXRIOH0_INV_OUTBOUND_HDRS_IDX3 TXRIOH0_INV_OUTBOUND_HDRS_ALL NVL("SYSTEM",'1') 2

Below is one of the statements that are supposed to use this index:

SELECT LEGACY_VENDOR_NO FROM TXRIOH0_INV_OUTBOUND_HDRS_ALL WHERE LPAD(NVL(VOUCHER_NO,0),7,'0') = :B2 AND NVL(SYSTEM,1) = NVL(:B1 ,1) AND BATCH_STATUS NOT IN ('CONFIRMED','PAID','RECEIVED') ;  

The explain plan shows that the statement is doing FTS on the table:



| Id  | Operation           | Name                          | Starts |
E-Rows | A-Rows | A-Time | Buffers | Reads |

|   0 | SELECT STATEMENT    |                               |      1 |
|      0 |00:01:03.22 |     359K|    359K|

|   1 |  CONCATENATION      |                               |      1 |
|      0 |00:01:03.22 |     359K|    359K|

|*  2 |   FILTER            |                               |      1 |
|      0 |00:00:00.01 |       0 |      0 |

|*  3 |    TABLE ACCESS FULL| TXRIOH0_INV_OUTBOUND_HDRS_ALL |      0 |
1 |      0 |00:00:00.01 |       0 |      0 |

|*  4 |   FILTER            |                               |      1 |
|      0 |00:01:03.22 |     359K|    359K|

|*  5 |    TABLE ACCESS FULL| TXRIOH0_INV_OUTBOUND_HDRS_ALL |      1 |
1 |      0 |00:01:03.22 |     359K|    359K|


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

We re-ran statistics on the table but it did not help. The optimizer kept ignoring the index. I then set the optimizer mode to rule and the statement started using the index. I was able to create a test table and define a function-based index on it and it worked fine. So, I am not sure why the optimizer keeps ignoring this index. Has anyone run into a similar issue with 11g? There are lots of Oracle defined/standard function-based in the Oracle EBS database and they seemed to be working fine.  

Thanks

Amir  

--
http://www.freelists.org/webpage/oracle-l



This email and any attachments are confidential and may also be privileged.  If you are not the addressee, do not disclose, copy, circulate or in any other way use or rely on the information contained in this email or any attachments.  If received in error, notify the sender immediately and delete this email and any attachments from your system.  Emails cannot be guaranteed to be secure or error free as the message and any attachments could be intercepted, corrupted, lost, delayed, incomplete or amended.  Standard Chartered PLC and its subsidiaries do not accept liability for damage caused by this email or any attachments and may monitor email traffic.

Standard Chartered PLC is incorporated in England with limited liability under company number 966425 and has its registered office at 1 Aldermanbury Square, London, EC2V 7SB.

Standard Chartered Bank ("SCB") is incorporated in England with limited liability by Royal Charter 1853, under reference ZC18.  The Principal Office of SCB is situated in England at 1 Aldermanbury Square, London EC2V 7SB. In the United Kingdom, SCB is authorised and regulated by the Financial Services Authority under FSA register number 114276.

If you are receiving this email from SCB outside the UK, please click http://www.standardchartered.com/global/email_disclaimer.html to refer to the information on other jurisdictions.
--
http://www.freelists.org/webpage/oracle-l
Received on Wed Oct 05 2011 - 20:43:43 CDT

Original text of this message