am  Wed, dem 05.09.2007, um 13:45:46 +1000 mailte novice folgendes:
> Hello All,
> 
> SELECT notification_time, finished_time, sum(finished_time -
> notification_time) as actual
> FROM log
> GROUP BY notification_time, finished_time;
> 
> gives me:
> 
>    notification_time    |     finished_time      |     actual
> ------------------------+------------------------+-----------------
>  2007-07-06 15:50:00+10 | 2007-07-09 07:10:00+10 | 2 days 15:20:00
>  2007-07-07 12:30:00+10 | 2007-07-09 07:20:00+10 | 1 day 18:50:00
> 
> 
> How can write a query to calculate the duration using custom work
> hours which is Monday 7am /  Friday 5pm?
> 
> The result I'm expecting for the above to be
> 
>    notification_time    |     finished_time      |     actual
> ------------------------+------------------------+-----------------
>  2007-07-06 15:50:00+10 | 2007-07-09 07:10:00+10 | 00:20:00
>  2007-07-07 12:30:00+10 | 2007-07-09 07:20:00+10 | 00:20:00

You can write a function. Calculate for every day between
notification_time and finished_time this timestamps for every day. I
mean, for instance your first row:


2007-07-06 15:50:00+10       2007-07-07 00:00:00+10
2007-07-07 00:00:00+10       2007-07-08 00:00:00+10
2007-07-08 00:00:00+10       2007-07-09 00:00:00+10
2007-07-09 00:00:00+10       2007-07-09 07:20:00+10

Now check, if the first timestamp are a working day (select
extract('dow' from '2007-07-06 15:50:00+10'::timestamptz)). If so, than
calculate the working-time and adds all.

A little function for you:

<--- cut
create or replace function intersect_time (IN start timestamptz, IN stop 
timestamptz, IN w_start timestamptz, IN w_end timestamptz, OUT duration 
interval) as $$
declare
        _s1     alias for $1;
        _e1     alias for $2;
        _s2     alias for $3;
        _e2     alias for $4;
        _start  timestamptz;
        _end    timestamptz;

begin

        if _s1 < _s2 then
                _start := _s2;
        else
                _start := _s1;
        end if;

        if _e1 < _e2 then
                _end := _e1;
        else
                _end := _e2;
        end if;

        if _start < _end then
                duration := _end - _start;
        else
                duration := '0'::interval;
        end if;

        return;

end;
$$language plpgsql;

--- cut

A simple test:

Only the first and the last are working days, so we call the function
for this rows:


test=*# select intersect_time('2007-07-06 15:50:00+10'::timestamptz,'2007-07-07 
00:00:00+10'::timestamptz, '2007-07-06 07:00:00+10'::timestamptz, '2007-07-06 
17:00:00+10'::timestamptz);
 intersect_time
----------------
 01:10:00
(1 row)

test=*# select intersect_time('2007-07-09 00:00:00+10'::timestamptz,'2007-07-09 
07:10:00+10'::timestamptz, '2007-07-09 07:00:00+10'::timestamptz, '2007-07-09 
17:00:00+10'::timestamptz);
 intersect_time
----------------
 00:10:00
(1 row)


test=*# select '01:10:00'::interval + '00:10:00'::interval;
 ?column?
----------
 01:20:00
(1 row)



Hope that helps, Andreas
-- 
Andreas Kretschmer
Kontakt:  Heynitz: 035242/47150,   D1: 0160/7141639 (mehr: -> Header)
GnuPG-ID:   0x3FFF606C, privat 0x7F4584DA   http://wwwkeys.de.pgp.net

---------------------------(end of broadcast)---------------------------
TIP 2: Don't 'kill -9' the postmaster

Reply via email to