Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations gmmastros on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

Date arthmetic.

Status
Not open for further replies.

GRP

MIS
Aug 5, 2001
26
IN
Hi friends,

I am using IDS 7.31 on HP-D370 Server. In SQL query I would like to find out the time difference between two days. For. E.g Previous day say 19/04/02 22:30:00 to 20/04/02 06:30:00 Hrs. I would like to know the time difference i.e 8 Hrs, 9 Hrs etc.

I tried same thing in 4GL also, since the from time is more than to time I am not getting the proper reuslt.

Will you give me a solution.


G.R.P.
 
G.R.P:

There's many ways of handling this problem. Since I never took the time to learn all the nuances of the Informix datetime stuff, my solution was creating this Stored Procedure:

-- This function returns the number of seconds between
--datetime dt1 and dt2.
-- change to character first because the interval to
-- integer conversion fails. Ed Schaefer 09/23/98
CREATE PROCEDURE int_in_sec(dt1 DATETIME YEAR TO SECOND, dt2 DATETIME YEAR
TO SECOND) RETURNING INTEGER;
DEFINE int_sec INTERVAL SECOND(9) TO SECOND;
DEFINE xchar CHAR(20);
DEFINE xint INTEGER;

LET int_sec = dt2 - dt1; -- get the interval
LET xchar = int_sec; -- change to char
LET xint = xchar; -- change to integer

RETURN xint;
END PROCEDURE;

Since you want days and not seconds, divide by 3600. Here's an example:

create temp table dts (
dt1 datetime year to second,
dt2 datetime year to second
) with no log;
insert into dts values ("2000-04-19 22:30:00", "2000-04-20 22:30:00");
select dt1, dt2, int_in_sec(dt1, dt2)/3600 from dts;
drop table dts;

You could modify the S.P. to return days instead of seconds by changing the interval declaration to something like:

DEFINE int_days INTERVAL DAY(5) TO DAY

although I've never tested this. If you choose to do this make sure whatever day range you choose i.e. DAY(5) is large enough to hold the largest number of days.

Regards,


Ed
Schaefer

 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top