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: sysdate - 90 mins query

Re: sysdate - 90 mins query

From: Stephane Faroult <sfaroult_at_oriole.com>
Date: Sat, 04 May 2002 07:48:22 -0800
Message-ID: <F001.00458055.20020504074822@fatcity.com>


sarath kumar wrote:
>
> i hava a table tbl_tmstmp with date and time as 2
> different columns (tm_date number)and tm_time
> varchar2(6).
> select * from tbl_tmstmp;
> tmstmp_id tm_date tm_time
> -------- -------- -------
> 1 20020502 12:30
> 2 20020503 19:30
> 3 20020503 23:30
> 4 20020504 00:30
> 5 20020504 02:30
> 6 20020504 08:30
>
> i have requuirement to pickup the records which are
> sysdate - 90 minutes. Assuming the sysdate is 20020504
> and time is 03:00 AM i need to pick up the first 4
> records.
>
> is it possible without using the UNION as DBAS are
> picky about using UNIONS.
>
> thanks
> Srini.
>

where tm_date >= to_number(to_char(sysdate - 0.0625, 'YYYYMMDD'))   and to_date(to_char(tm_date)||tm_time, 'YYYYMMDDHH24:MI') >= sysdate - 0.0625

Word of explanation : 0.0625 is 90 minutes expressed as a number of days (90 / 1440).
The first condition is somewhat redundant with the second one. However, if tm_date is indexed and you have a huge number of rows, it will allow you to take advantage of the index, contrarily to the second condition, necessary to test the hour:minutes part.

Oh .. not tested ...

-- 
Regards,

Stephane Faroult
Oriole Software
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Stephane Faroult
  INET: sfaroult_at_oriole.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 Sat May 04 2002 - 10:48:22 CDT

Original text of this message

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