Re: Calculate next event date based on instance of the day of week

From: Jayadevan M <Jayadevan(dot)Maymala(at)ibsplc(dot)com>
To: Dimitri <a(dot)dmitri(at)gmail(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org, pgsql-sql-owner(at)postgresql(dot)org
Subject: Re: Calculate next event date based on instance of the day of week
Date: 2010-12-03 06:17:28
Message-ID: OF03EB9A17.A902FA47-ON652577EE.0022367A-652577EE.00228EF9@ibsplc.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Hello,
> I have a table which stores an event date. The event is stored as a
> standard mm/dd/yy entry.
>
> I then need to calculate based on the dd value, WHICH day of the
> week that is (e.g. Wednesday) and which occurrence of that day of
> the week, within the month, it is (e.g. the THIRD Wednesday).
>
Here is an example to reach this far ....

postgres=# create table mt(myd date);
postgres=# insert into mt select current_date+se from (select
generate_series(1,10000) as se ) as x;
postgres=# select * from mt order by
postgres-# myd limit 10;
myd
------------
2010-12-04
2010-12-05
2010-12-06
2010-12-07
2010-12-08
2010-12-09
2010-12-10
2010-12-11
2010-12-12
2010-12-13
(10 rows)

This is the query to get the data in the format you want...

select myd, d ,w from (
select myd, to_char(myd,'Day') as d , to_char(myd,'W') as w ,rank() over
(partition by to_char(myd,'W') order by myd ) as x from mt order by myd
) as t order by myd ;

myd | d | w
------------+-----------+---
2010-12-04 | Saturday | 1
2010-12-05 | Sunday | 1
2010-12-06 | Monday | 1
2010-12-07 | Tuesday | 1
2010-12-08 | Wednesday | 2
2010-12-09 | Thursday | 2
2010-12-10 | Friday | 2
2010-12-11 | Saturday | 2
2010-12-12 | Sunday | 2
2010-12-13 | Monday | 2
2010-12-14 | Tuesday | 2
2010-12-15 | Wednesday | 3
2010-12-16 | Thursday | 3
2010-12-17 | Friday | 3
2010-12-18 | Saturday | 3
2010-12-19 | Sunday | 3
2010-12-20 | Monday | 3
2010-12-21 | Tuesday | 3
2010-12-22 | Wednesday | 4
2010-12-23 | Thursday | 4
2010-12-24 | Friday | 4
2010-12-25 | Saturday | 4
2010-12-26 | Sunday | 4
2010-12-27 | Monday | 4
2010-12-28 | Tuesday | 4
2010-12-29 | Wednesday | 5
2010-12-30 | Thursday | 5
2010-12-31 | Friday | 5

Regards,
Jayadevan

DISCLAIMER:

"The information in this e-mail and any attachment is intended only for
the person to whom it is addressed and may contain confidential and/or
privileged material. If you have received this e-mail in error, kindly
contact the sender and destroy all copies of the original communication.
IBS makes no warranty, express or implied, nor guarantees the accuracy,
adequacy or completeness of the information contained in this email or any
attachment and is not liable for any errors, defects, omissions, viruses
or for resultant loss or damage, if any, direct or indirect."

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Mario Splivalo 2010-12-03 10:53:26 Get the max viewd product_id for user_id
Previous Message Dimitri 2010-12-02 21:46:44 Calculate next event date based on instance of the day of week