Re: SQL Challenge: Skip Weekends

Lists: pgsql-sql
From: Josh Berkus <josh(at)agliodbs(dot)com>
To: pgsql-sql(at)postgresql(dot)org
Subject: SQL Challenge: Skip Weekends
Date: 2002-06-21 00:13:03
Message-ID: 200206201713.03801.josh@agliodbs.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Folks,

Hey, I need to write a date calculation function that calculates the date
after a number of *workdays* from a specific date. I pretty much have the
"skip holidays" part nailed down, but I don't have a really good way to skip
all weekends in the caluclation. Here's the ideas I've come up with:

Idea #1: Use a reference table
1. Using a script, generate a table of all weekends from 2000 to 2050.
2. Increase the interval by the number of weekends that fall in the relevant
period.

Idea #2: Some sort of calculation using 5/7 of the interval, adjusted
according to the day of the week of our starting date. My head hurts trying
to figure this one out.

--
-Josh Berkus


From: Joe Conway <mail(at)joeconway(dot)com>
To: josh(at)agliodbs(dot)com
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL Challenge: Skip Weekends
Date: 2002-06-21 05:32:47
Message-ID: 3D12BA7F.1090209@joeconway.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Josh Berkus wrote:
> Folks,
>
> Hey, I need to write a date calculation function that calculates the
> date after a number of *workdays* from a specific date. I pretty
> much have the "skip holidays" part nailed down, but I don't have a
> really good way to skip all weekends in the caluclation. Here's the
> ideas I've come up with:

How about this (a bit ugly, but I think it does what you want -- minus
the holidays, which you said you already have figured out):

create or replace function
get_future_work_day(timestamp, int)
returns timestamp as '
select
case when extract(dow from future_work_date) = 6
then future_work_date + ''2 days''
when extract(dow from future_work_date) = 0
then future_work_date + ''1 day''
else
future_work_date
end
from
(
select $1
+ (($2 / 5)::text || '' weeks'')
+ (($2 % 5)::text || '' days'')
as future_work_date
) as t1
' language sql;
CREATE
testslv=# select get_future_work_day('2002-06-20',27);
get_future_work_day
------------------------
2002-07-29 00:00:00-07
(1 row)

HTH,
Joe


From: Jean-Luc Lachance <jllachan(at)nsd(dot)ca>
To: josh(at)agliodbs(dot)com
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL Challenge: Skip Weekends
Date: 2002-06-21 17:46:19
Message-ID: 3D13666B.AC687A4A@nsd.ca
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

here is the algorithm:

date := now - day_of_the_week
interval := interval + day_of_the_week
date := date + int( interval/5)x7 + ( interval mod 5)

Josh Berkus wrote:
>
> Folks,
>
> Hey, I need to write a date calculation function that calculates the date
> after a number of *workdays* from a specific date. I pretty much have the
> "skip holidays" part nailed down, but I don't have a really good way to skip
> all weekends in the caluclation. Here's the ideas I've come up with:
>
> Idea #1: Use a reference table
> 1. Using a script, generate a table of all weekends from 2000 to 2050.
> 2. Increase the interval by the number of weekends that fall in the relevant
> period.
>
> Idea #2: Some sort of calculation using 5/7 of the interval, adjusted
> according to the day of the week of our starting date. My head hurts trying
> to figure this one out.
>
> --
> -Josh Berkus
>
> ---------------------------(end of broadcast)---------------------------
> TIP 4: Don't 'kill -9' the postmaster


From: "Josh Berkus" <josh(at)agliodbs(dot)com>
To: Jean-Luc Lachance <jllachan(at)nsd(dot)ca>, josh(at)agliodbs(dot)com
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL Challenge: Skip Weekends
Date: 2002-06-21 19:29:27
Message-ID: web-1552104@davinci.ethosmedia.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Jean-Luc,

> date := now - day_of_the_week
> interval := interval + day_of_the_week
> date := date + int( interval/5)x7 + ( interval mod 5)

Merci, merci, merci!

-Josh


From: "Josh Berkus" <josh(at)agliodbs(dot)com>
To: Joe Conway <mail(at)joeconway(dot)com>, josh(at)agliodbs(dot)com
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL Challenge: Skip Weekends
Date: 2002-06-21 19:31:23
Message-ID: web-1552107@davinci.ethosmedia.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Joe,

> How about this (a bit ugly, but I think it does what you want --
> minus the holidays, which you said you already have figured out):
>
> create or replace function
> get_future_work_day(timestamp, int)

Thank you. Once again, you come to the rescue when I'm stuck. I'll
try your solution and Jean-Luc's, and see which works better/faster.
And report back.

-Josh Berkus