Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: Long-running SQL

RE: Long-running SQL

From: Jack C. Applewhite <japplewhite_at_inetprofit.com>
Date: Wed, 27 Mar 2002 08:18:27 -0800
Message-ID: <F001.00434E22.20020327081827@fatcity.com>


Cherie,

At least the leading column in your index doesn't have an index-killing function on it in the Where clause - the NVL function on the other columns makes Oracle not use them for hitting the index.

Since you're only interested in returning a single value, perhaps a stored function that returns that value and takes :b1 - :b9 as input arguments could be tuned to be faster. It could be used in the SQL Select. Check out the docs for the use of stored functions in SQL statements.

Jack



Jack C. Applewhite
Database Administrator/Developer
OCP Oracle8 DBA
iNetProfit, Inc.
Austin, Texas
www.iNetProfit.com
japplewhite_at_inetprofit.com
(512)327-9068

-----Original Message-----
Cherie_Machler_at_gelco.com
Sent: Wednesday, March 27, 2002 8:33 AM
To: Multiple recipients of list ORACLE-L

We have a statement that I feel takes too long to run in a nightly data load.
The table it runs against has 386,000 records. It runs for about 10 seconds
on average. We're only loading about 50,000 records a night but this statement
is running during the majority of the 9-hour load time. This is causing the
load to run longer than our allowable window and causing me untold headaches.
If anyone has any suggestions to make this run faster, I'd be greatly appreciative.

The columns in the where statement are all part of an index. However, the functions on the columns add additional execution time and complexity.

This is an 8.0.4 database so I can not make this a function-based index.

I put this in a couple of SQL tuning tools and came up with no valid alternatives.
I can't help thinking that the statement could be rewritten into a couple of statements
so that it would be more efficient. However, I'm not skilled enough with SQL to
do it. Perhaps someone else is. Here's the code.

SELECT /*+ INDEX(EXP_COST_CENTER_DIM EXP_COST_CENTER_DIM_IDX1) + */ EXP_COST_CENTER_KEY
     FROM EXP_COST_CENTER_DIM

     WHERE ACCOUNT_NUMBER = :b1 AND
          NVL(ORG_LEVEL_1_VALUE,'NONE') = NVL(:b2,'NONE') AND
          NVL(ORG_LEVEL_2_VALUE,'NONE') = NVL(:b3,'NONE') AND
          NVL(ORG_LEVEL_3_VALUE,'NONE') = NVL(:b4,'NONE') AND
          NVL(ORG_LEVEL_4_VALUE,'NONE') = NVL(:b5,'NONE') AND
          NVL(ORG_LEVEL_5_VALUE,'NONE') = NVL(:b6,'NONE') AND
          NVL(ORG_LEVEL_6_VALUE,'NONE') = NVL(:b7,'NONE') AND
          NVL(ORG_LEVEL_7_VALUE,'NONE') = NVL(:b8,'NONE') AND
          NVL(ORG_LEVEL_8_VALUE,'NONE') = NVL(:b9,'NONE') AND
ROWNUM = 1 SQL> desc exp_cost_center_dim
 Name                            Null?    Type
 ------------------------------- -------- ----
 EXP_COST_CENTER_KEY             NOT NULL NUMBER(7)
 ACCOUNT_NUMBER                  NOT NULL NUMBER(9)
 BATCH_WINDOW_DATE_KEY           NOT NULL NUMBER(5)
 ORG_LEVEL_1_VALUE                        VARCHAR2(20)
 ORG_LEVEL_2_VALUE                        VARCHAR2(20)
 ORG_LEVEL_3_VALUE                        VARCHAR2(20)
 ORG_LEVEL_4_VALUE                        VARCHAR2(20)
 ORG_LEVEL_5_VALUE                        VARCHAR2(20)
 ORG_LEVEL_6_VALUE                        VARCHAR2(20)
 ORG_LEVEL_7_VALUE                        VARCHAR2(20)
 ORG_LEVEL_8_VALUE                        VARCHAR2(20)
 DATA_SOURCE_MOD_DATETIME        NOT NULL DATE
 DATA_WAREHOUSE_MOD_DATETIME     NOT NULL DATE
 DATA_MART_MOD_DATETIME          NOT NULL DATE


SQL> select column_name from dba_ind_columns where index_name ='EXP_COST_CENTER_D
IM_IDX1'; COLUMN_NAME




ACCOUNT_NUMBER
ORG_LEVEL_1_VALUE
ORG_LEVEL_2_VALUE
ORG_LEVEL_3_VALUE
ORG_LEVEL_4_VALUE
ORG_LEVEL_5_VALUE
ORG_LEVEL_6_VALUE
ORG_LEVEL_7_VALUE
ORG_LEVEL_8_VALUE


SQL> select column_name from dba_ind_columns where index_name ='EXP_COST_CENTER_D
IM_PK';

COLUMN_NAME




EXP_COST_CENTER_KEY Thanks,

Cherie Machler
Oracle DBA
Gelco Information Network

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Jack C. Applewhite
  INET: japplewhite_at_inetprofit.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L

(or the name of mailing list you want to be removed from). You may
also send the HELP command for other information (like subscribing).
Received on Wed Mar 27 2002 - 10:18:27 CST

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US