From: | Richard Broersma Jr <rabroersma(at)yahoo(dot)com> |
---|---|
To: | Kenji Morishige <kenjim(at)juniper(dot)net>, pgsql-general(at)postgresql(dot)org |
Cc: | kenjim(at)juniper(dot)net, test-tools(at)juniper(dot)net, Joel Holveck <joelh(at)juniper(dot)net> |
Subject: | Re: best way to calculate accumulating intervals timestamps |
Date: | 2007-04-02 21:34:13 |
Message-ID: | 778680.97323.qm@web31815.mail.mud.yahoo.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
> Management wants to know A+B over the course of multiple days and the start
> and finish times can occur in arbitrary times. Any ideas for quickest way to
> solve this problem? I know I can do it the dirty way in perl or whatever,
> but I was hoping for a solution in SQL/PLSQL.
Without using a function, you will need an auxillary table that holds calendar dates to join
against. However, you can simulate the auxilary table by using the generate_series function.
Also, I expect that the UNIONS can be eliminated if you use the CASE predicate to handle the
various conditions.
SELECT
A.resource,
B.calendardate,
A.endtime - A.starttime AS duration
FROM
your_table A
INNER JOIN
aux_calendartable B
on
(
(A.calendardate + '8 hours') <= A.starttime
AND
(A.calendardate + '16 hours') >= A.enddate
)
UNION
SELECT
A.resource,
B.calendardate,
A.endtime - (A.calendardate + '8 hours') AS duration
FROM
your_table A
INNER JOIN
aux_calendartable B
on
(
A.starttime < (A.calendardate + '8 hours')
AND
(A.calendardate + '16 hours') >= A.enddate
)
UNION
SELECT
A.resource,
B.calendardate,
(A.calendardate + '16 hours') - A.starttime AS duration
FROM
your_table A
INNER JOIN
aux_calendartable B
on
(
(A.calendardate + '8 hours') <= A.starttime
AND
A.enddate > (A.calendardate + '16 hours')
)
UNION
SELECT
A.resource,
B.calendardate,
'10 hours' AS duration
FROM
your_table A
INNER JOIN
aux_calendartable B
on
(
A.starttime < (A.calendardate + '8 hours')
AND
A.enddate > (A.calendardate + '16 hours')
)
;
From | Date | Subject | |
---|---|---|---|
Next Message | greg | 2007-04-02 21:36:31 | SQLConnect failure |
Previous Message | Walter Vaughan | 2007-04-02 21:01:16 | Re: Importing data into views fails |