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 Tunning

RE: SQL Tunning

From: Lex de Haan <lex.de.haan_at_naturaljoin.nl>
Date: Tue, 3 Aug 2004 19:04:13 +0200
Message-ID: <JFEEIGBIDOCCDALDIPLNEEMFCGAA.lex.de.haan@naturaljoin.nl>


Hi Mark,
I was only referring to the two syntax examples somewhere down this thread, where the parens are forcing an illegal precedence (I copy and paste):

SELECT TRUNC(SYSDATE-22)/86400 from dual; SELECT (TRUNC(SYSDATE)-22)/86400 from dual;

Kind regards,
Lex.



visit my website at http://www.naturaljoin.nl

-----Original Message-----
From: oracle-l-bounce_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org]On Behalf Of Powell, Mark D Sent: Tuesday, August 03, 2004 17:12
To: 'oracle-l_at_freelists.org'
Subject: RE: SQL Tunning

Lex, I do not agree with your example. I understand your point but Oracle has supported using + and - of a number or simple numeric expression as long as I can remember:

UT1 > l
  1 select to_char(trunc(sysdate),'YYYYMMDD HH24:MI:SS') as D1,   2 trunc(sysdate) - 22/86400 as D2
  3* from dual
UT1 > /

D1                D2
----------------- ---------

20040803 00:00:00 02-AUG-04 Looks like Oracle handles it correctly. We have used this syntax from 6.36 to now, 9.2.0.4 on AIX 5.2. I think we need to see the real SQL and Oracle error to know what problem Wes was encountering.

HTH -- Mark D Powell --

-----Original Message-----
From: oracle-l-bounce_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org]On Behalf Of Lex de Haan Sent: Tuesday, August 03, 2004 12:01 PM
To: oracle-l_at_freelists.org
Subject: RE: SQL Tunning

you get errors because you cannot divide a DATE by a NUMBER -- trunc(sysdate) returns a DATE, and a DATE minus a NUMBER returns a DATE again.
so you can only do things like:
trunc(sysdate) - (22/86400)

Kind regards,
Lex.



visit my website at http://www.naturaljoin.nl

-----Original Message-----
From: oracle-l-bounce_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org]On Behalf Of Wes Brooks Sent: Tuesday, August 03, 2004 16:54
To: oracle-l_at_freelists.org
Subject: Re: SQL Tunning

Hello expert,

Thank you very much for all of your reply.

But in my case, the 1 is variable. I tried the following but it complains that

SELECT TRUNC(SYSDATE)-22/86400 from dual;

TRUNC(SYS



02-AUG-04 <--- Wrong date.

SELECT TRUNC(SYSDATE-22)/86400 from dual; SELECT (TRUNC(SYSDATE)-22)/86400 from dual;

These two SQL statements gave the error:

ORA-00932: inconsistent datatypes

If I try this one, it works.

SELECT TRUNC(SYSDATE - 22), TO_DATE(TO_CHAR(TRUNC(SYSDATE-22+1), 'DD-MON-YYYY HH24:MI:SS'),
'DD-MON-YYYY HH24:MI:SS') from dual;

Is there any way to improve this lengthly statement?

Thanks,
Wes

> Hello Wes,

>

> WB> WHERE TRUNC(last_update_date) = TRUNC(SYSDATE - 1)
> WB> How to improve the performance? Do I need to create a new index field
on the table with
> TRUNC(last_update_date)?
>

> You have several opportunities:
> a) you can rewrite your query to this:
> where last_update_date between trunc(sysdate)-1 and
trunc(sysdate)-1/86400
> b) you can create function based index like:
> create index tt_idx on tt(trunc(last_update_date));
> c) you can add column to your table with values from
trunc(last_update_date)
>
> What option to choose mostly depends on your requirements.


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

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------


-- Binary/unsupported file stripped by Ecartis --
-- Type: text/x-vcard
-- File: Lex de Haan.vcf


----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request_at_freelists.org
put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request_at_freelists.org
put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------


-- Binary/unsupported file stripped by Ecartis --
-- Type: text/x-vcard
-- File: Lex de Haan.vcf


----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request_at_freelists.org
put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Tue Aug 03 2004 - 12:00:09 CDT

Original text of this message

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