Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Date / Time
Here is my attempt to display the difference between two dates in the format
<days>:<Hours>:<Minutes>:<seconds>
The two dates are dt1 and dt2
If dt1 is later than dt2 then result returned as negative.
It should work for differences of +/- 99 days - to increase the range,
change '09' at the end of the first line to the size desired.
to_char(trunc(greatest(dt2,dt1) - least(dt2,dt1)) * sign(dt2 - dt1),'09') ||
':' ||
to_char(to_date(1,'J') + (greatest(dt2,dt1) - least(dt2,dt1)) ,'HH24:MI:SS')
Regards
Garry
-----Original Message-----
From: Scott Canaan [mailto:srcdco_at_ritvax.isc.rit.edu]
Sent: 10 July 2001 15:12
To: Multiple recipients of list ORACLE-L
Subject: Re: Date / Time
Sajid,
Unfortunately, I ran into the same problem. I didn't find anything to do
it for me, either, so I had to write the pl/sql code. It is very long and
messy, but can be done. When I did it, I didn't even attempt the days
notation. Here is the code that I wrote:
date_diff := trans_cur.modified_date - last_date; date_diff_tot := trans_cur.modified_date - first_date; SELECT decode( trunc( date_diff * 24),0,24)
to_char( trunc( date_diff * 1440), 'FM90') || ':' ||
to_char( round( date_diff * 86400) - trunc( date_diff
* 1440) * 60,'FM00'),
to_char( trunc( date_diff * 24),'FM90') || ':' ||
to_char( trunc( date_diff * 1440 - trunc( date_diff *
* 60),'FM00') || ':' ||
to_char( round( date_diff * 86400 - trunc( date_diff
* 1440) * 60), 'FM00')),
decode( trunc( date_diff_tot * 24), 0,
to_char( trunc( date_diff_tot * 1440),'FM90') || ':' ||
to_char( round( date_diff_tot * 86400)
- trunc( date_diff_tot * 1440) * 60,'FM00'),
to_char( trunc( date_diff_tot * 24),'FM90') || ':' ||
to_char( trunc( date_diff_tot * 1440
- trunc( date_diff_tot * 24) * 60),'FM00') || ':' ||
to_char( round( date_diff_tot * 86400
- trunc( date_diff_tot * 1440) * 60), 'FM00')) INTO elapsed_1, elapsed_2 FROM dual;
I hope this helps.
Sajid Iqbal wrote:
> Hello All > > I want to display the "time elapsed" between two dates - in days, hours, > minutes and seconds. > > If I do "select date1 - date2", the result is : 12.0194907 > > Is there a function that will turn the number of days into something more > legible? Ideally i'd like to do ; > > "to_char(12.0194907,'DD:HH:MI:SS')" but obviously that won't work. Is > there a solution other than writing a complex function myself which will > have to * by 24, / by 60 and substr etc to get the different bits of the > number? > > Please CC any replies directly to me at siqbal_at_vianetworks.co.uk > > Thanks in advance, > Saj. > > -- > Sajid Iqbal > Database Team Leader > > -- > Please see the official ORACLE-L FAQ: http://www.orafaq.com > -- > Author: Sajid Iqbal > INET: siqbal_at_vianetworks.co.uk > > 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).
-- Scott Canaan (srcdco_at_rit.edu) (716) 475-7886 "Life is like a sewer, what you get out of it depends on what you put into it" - Tom Lehrer -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Scott Canaan INET: srcdco_at_ritvax.isc.rit.edu 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). ++++++++++++++++++++++++++++++++++++ All internet traffic to this site is automatically scanned for viruses and vandals. ++++++++++++++++++++++++++++++++++++Received on Wed Jul 11 2001 - 11:40:43 CDT
![]() |
![]() |