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: SQL Tuning - How to avoid TOCHAR function against a date

RE: SQL Tuning - How to avoid TOCHAR function against a date

From: Pardee, Roy E <roy.e.pardee_at_lmco.com>
Date: Mon, 08 Apr 2002 10:42:42 -0800
Message-ID: <F001.0043EBDB.20020408104242@fatcity.com>


Could you maybe calculate a range of date values that encompasses the period you want and use BETWEEN on the raw date column? I'm thinking something along the lines of:

   SELECT DATE_KEY
   FROM DATE_DIM
   WHERE ORACLE_DATE BETWEEN TRUNC(:b1) AND TRUNC(:b1) + .99999 ;

but like, more elegant. 8^)

HTH,
-Roy

Roy Pardee
Programmer/Analyst
SWFPAC Lockheed Martin IT
Extension 8487

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

Sent: Monday, April 08, 2002 10:57 AM
To: Multiple recipients of list ORACLE-L

I've got the following SQL statement that is running very long on a nightly data load. The problem is the TO_CHAR function which is preventing me from using the index on this small (20,000-row table).

This is an 8.0.4 database so it is not possible for me to use make this a function-based index.

The problem is that the date field has minutes, etc. included and those need to be eliminated before the comparison can be made. That's why I can't just eliminate the TO_CHAR from both sides of the equation.

Isn't there a way that I can pull this function out of the select statement and do it in a preceeding statement? Then I could just pass in both variables to this statement without the TO_CHAR and use my index.

Is this realistic? How, exactly could it be done?

SELECT DATE_KEY
FROM DATE_DIM
WHERE TO_CHAR(ORACLE_DATE,'DD-MON-YYYY') = TO_CHAR(:b1,'DD-MON-YYYY')

SQL> desc date_dim;

 Name                            Null?    Type
 ------------------------------- -------- ----
 DATE_KEY                        NOT NULL NUMBER(5)
 ORACLE_DATE                     NOT NULL DATE
 DATACOM_DATE                             NUMBER(6)
 DATACOM_REVERSE_DATE                     NUMBER(6)
 DAY_OF_WEEK                     NOT NULL VARCHAR2(30)
 DAY_NUMBER_IN_MONTH             NOT NULL NUMBER(3)
 DAY_NUMBER_OVERALL              NOT NULL NUMBER(9)
 WEEK_NUMBER_IN_YEAR             NOT NULL NUMBER(3)
 WEEK_NUMBER_OVERALL             NOT NULL NUMBER(7)
 MONTH                           NOT NULL VARCHAR2(30)
 MONTH_NUMBER_OVERALL            NOT NULL NUMBER(7)
 YEAR                            NOT NULL NUMBER(5)
 WEEKDAY_IND                     NOT NULL CHAR(1)
 LAST_DAY_IN_MONTH_IND           NOT NULL CHAR(1)
 DATA_WAREHOUSE_MOD_DATETIME     NOT NULL DATE
 DATA_MART_MOD_DATETIME          NOT NULL DATE



SQL> select oracle_date from date_dim where rownum=1;

ORACLE_DA



01-JAN-70 Thanks in advance for any help.

Cherie Machler
Oracle DBA
Gelco Information Network

--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author:
  INET: Cherie_Machler_at_gelco.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).
--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: Pardee, Roy E
  INET: roy.e.pardee_at_lmco.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 Mon Apr 08 2002 - 13:42:42 CDT

Original text of this message

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