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: Slow query

RE: Slow query

From: Naveen Nahata <naveen_nahata_at_mindtree.com>
Date: Wed, 05 Mar 2003 03:34:11 -0800
Message-ID: <F001.00560689.20030305033411@fatcity.com>


A small follow up question:

Why will oracle do a to_date() on second query for each row returned, as the date mentioned is a literal and doesn't change for the duration of the query. Won't it be calculated once and used for all the rows with trunc() applied to each row?

Regards
Naveen

-----Original Message-----
Sent: Wednesday, March 05, 2003 3:04 PM
To: Multiple recipients of list ORACLE-L

Which version of Oracle ?

The second query has to do a trunc() and a to_date() on every single row. The first only has to do a to_char on every single row. There is a CPU difference between the two queries and if you run the execution plan through v9 with cpu_costing, you will find a difference in cost - though probably not enough to agree with your clock test.

A simple test on 8.1.7.4 and 9.2.0.2 where I created a table of 128,000 rows with a date column scattered inside a single date showed that one query used about twice the CPU of the other in v9, and four times in v8. (Unfortunately, in all cases, the CPU reported by Oracle was consistently larger than the elapsed time reported by SQL*Plus).

First check, though, is the test repeatable, or did something happen elsewhere to affect the elapsed time. (e.g. was one tested subject to a lot of delayed block cleanout).

NB - The execution plan shown is not the plan for either of the two statements, and I am fairly sure that neither statement could actually return 120,000 rows in 10 ms. Do your timings refer to a test where you changed the query to do a count() ?

Regards

Jonathan Lewis
http://www.jlcomp.demon.co.uk

Coming soon one-day tutorials:
Cost Based Optimisation
Trouble-shooting and Tuning
Indexing Strategies
(see http://www.jlcomp.demon.co.uk/tutorial.html )

____UK_______March 19th
____UK_______April 8th
____UK_______April 22nd

____USA_(FL)_May 2nd

Next Seminar dates:
(see http://www.jlcomp.demon.co.uk/seminar.html )

____USA_(CA, TX)_August

The Co-operative Oracle Users' FAQ
http://www.jlcomp.demon.co.uk/faq/ind_faq.html

> 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

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Jonathan Lewis
  INET: jonathan_at_jlcomp.demon.co.uk

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).



DISCLAIMER:
This message (including attachment if any) is confidential and may be privileged. Before opening attachments please check them for viruses and defects. MindTree Consulting Private Limited (MindTree) will not be responsible for any viruses or defects or any forwarded attachments emanating either from within MindTree or outside. If you have received this message by mistake please notify the sender by return  e-mail and delete this message from your system. Any unauthorized use or dissemination of this message in whole or in part is strictly prohibited.  Please note that e-mails are susceptible to change and MindTree shall not be liable for any improper, untimely or incomplete transmission.
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Naveen Nahata
  INET: naveen_nahata_at_mindtree.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 - 05:34:11 CST

Original text of this message

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