Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Slow query
>
>Dear all,
>
>Please find below the 2 queries :
>
>select dep_date from test_date1
>where to_char(dep_date,'dd-mon-yyyy') =
>'12-jan-2002'
>
>select dep_date from test_date1
>where TRUNC(dep_date) = to_DATE(
>'12-jan-2002','dd-mon-yyyy')
>
>The execution plan for both the queries shows a FTS
>on test_date1.
>
>Execution Plan
> 0 SELECT STATEMENT Optimizer=CHOOSE
> 1 0 SORT (AGGREGATE)
> 2 1 TABLE ACCESS (FULL) OF 'TEST_DATE1'
>
>The number of rows to be retrieved are 120010.
>
>The first query took 10msec to execute whereas the
>second took about 2
>secs.
>
>Could anyone help me figure out what the problem
>would be.
>
>TIA
>
>Best Regards
>Jai
>---------------------------------------------------
>-------
Which problem? I guess that, if the execution plans are identical, what you are experiencing is just the effect of caching. For a reason or another the data already was in memory in one case, and had to be loaded from disk in the other one. Check your trace statistics under SQL*Plus, logical IOs will probably be more or less identical and physical IOs wildly different.
Note that as long as you apply a function to dep_date, your only way to escape the FTS is (supposing 8.1.7 or above) function-based indexes. If dep_date is indexed, then you should use something like
dep_date >= some_date and dep_date < some_date + 1 instead of
trunc(dep_date) = some_date
It will allow for range scans.
Regards,
Stephane Faroult
Oriole
-- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Stephane Faroult INET: sfaroult_at_oriolecorp.com Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- 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 05 2003 - 02:19:23 CST
![]() |
![]() |