Thread: question with times and intervals

question with times and intervals

From
"A. Kretschmer"
Date:
Hi,

I have a table like this:

test=# select * from status_log ;id | status |        t_start         |         t_end
----+--------+------------------------+------------------------ 1 |      1 | 2006-01-20 23:00:00+01 | 2006-01-21
06:00:00+011 |      1 | 2006-01-21 06:00:00+01 | 2006-01-21 22:00:00+01 1 |      2 | 2006-01-21 22:00:00+01 |
2006-01-2205:00:00+01 1 |      1 | 2006-01-22 05:00:00+01 | 2006-01-22 15:00:00+01 1 |      2 | 2006-01-22 15:00:00+01
|2006-01-23 02:00:00+01
 
(5 rows)

Now i need for a particular intervall (one day or two days, entires
days) the accumulated time for id=X and status=Y. 

Exampel:

id=1, status=1, date=2006-01-21:

from 00:00:00 - 06:00:00 and    06:00:00 - 22:00:00

===> 6 hours + 16 hours = 22 hours

id=1, status=2, date=2006-01-21:from 22:00:00 - 23:59:59

===> 2 hours


I need also this for a week or month. How can i calculate this?


Thanks very much for help.
-- 
Andreas Kretschmer    (Kontakt: siehe Header)
Heynitz:  035242/47215,      D1: 0160/7141639
GnuPG-ID 0x3FFF606C http://wwwkeys.de.pgp.net===    Schollglas Unternehmensgruppe    === 


Re: question with times and intervals

From
Richard Huxton
Date:
A. Kretschmer wrote:
> Hi,
> 
> I have a table like this:
> 
> test=# select * from status_log ;
>  id | status |        t_start         |         t_end
> ----+--------+------------------------+------------------------
>   1 |      1 | 2006-01-20 23:00:00+01 | 2006-01-21 06:00:00+01
>   1 |      1 | 2006-01-21 06:00:00+01 | 2006-01-21 22:00:00+01
>   1 |      2 | 2006-01-21 22:00:00+01 | 2006-01-22 05:00:00+01
>   1 |      1 | 2006-01-22 05:00:00+01 | 2006-01-22 15:00:00+01
>   1 |      2 | 2006-01-22 15:00:00+01 | 2006-01-23 02:00:00+01
> (5 rows)
> 
> Now i need for a particular intervall (one day or two days, entires
> days) the accumulated time for id=X and status=Y. 
> 
> Exampel:
> 
> id=1, status=1, date=2006-01-21:
> 
> from 00:00:00 - 06:00:00 and
>      06:00:00 - 22:00:00
> 
> ===> 6 hours + 16 hours = 22 hours

OK - all untested...

First step - don't ask for a date, ask between two timestamptz's (which 
I'll call t1, t2)

Then, define two functions: earlier(timestamptz, timesatmptz) and 
later(...) as SQL functions using SELECT ... CASE

SELECT  later(T1, t_start) AS lower_time  earlier(T2, t_end) AS upper_time
FROM  status_log
WHERE  id = X  AND status = Y  AND ts_end >= T1  AND ts_start <= T2
;

Now (upper_time - lower_time) is the interval you want and summing them 
will give you your answer.

Any help?
--   Richard Huxton  Archonet Ltd


Re: question with times and intervals

From
Andreas Kretschmer
Date:
Richard Huxton <dev@archonet.com> schrieb:

> Now (upper_time - lower_time) is the interval you want and summing them 
> will give you your answer.
> 
> Any help?

Yes, thanks.

But, i remember a little function that i wrote in the past:
http://a-kretschmer.de/tools/time_intersect.sql

And now i have a solution (i hope):

test=# select id, status,
test-#         sum((time_intersect(t_start, t_end, '2006/01/21 00:00:00'::timestamptz, '2006/01/22
23:59:59'::timestamptz)).t2-
 
test(#                 (time_intersect(t_start, t_end, '2006/01/21 00:00:00+1'::timestamptz, '2006/01/22
23:59:59+1'::timestamptz)).t1)
test-# from status_log
test-# where  (t_start, t_end) overlaps ('2006/01/21 00:00:00+1'::timestamptz, '2006/01/22 23:59:59'::timestamptz)
test-# group by id, status
test-# order by 1,2;id | status |   sum
----+--------+---------- 1 |      1 | 32:00:00 1 |      2 | 15:59:59
(2 rows)


Okay, now i can write a function similar above which returns the
interval and the i can sum() this.


Thanks, Andreas
-- 
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect.                              (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly."    (unknow)
Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°