Re: Fastest way / best practice to calculate "next birthdays"

From: Zoltan Boszormenyi <zb(at)cybertec(dot)at>
To: Hannes Dorbath <light(at)theendofthetunnel(dot)de>
Cc: "Joshua D(dot) Drake" <jd(at)commandprompt(dot)com>, pgsql-performance(at)postgresql(dot)org
Subject: Re: Fastest way / best practice to calculate "next birthdays"
Date: 2008-05-04 19:05:21
Message-ID: 481E08F1.3000604@cybertec.at
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

Hannes Dorbath írta:
> Joshua D. Drake wrote:
>> postgres=# SELECT current_date|| ' a ' || to_char(current_date, 'Day'),
>> current_date + '1 Year'::interval || ' a ' || to_char(current_date +
>> '1 Year'::interval, 'Day') as next_birthday;
>> ?column? | next_birthday
>> ------------------------+---------------------------------
>> 2008-05-04 a Sunday | 2009-05-04 00:00:00 a Monday
>>
>> ?
>
> Sorry, I think I phrased the question badly. What I'm after basically is:
>
> http://www.depesz.com/index.php/2007/10/26/who-has-birthday-tomorrow/

If you define the same functional index as in the above link:

CREATE OR REPLACE FUNCTION indexable_month_day(date) RETURNS TEXT as $BODY$
SELECT to_char($1, 'MM-DD');
$BODY$ language 'sql' IMMUTABLE STRICT;

create table user_birthdate (
id serial not null primary key,
birthdate date
);
create index user_birthdate_day_idx on user_birthdate (
indexable_month_day(birthdate) );

Then you can use this query:

select count(*) from user_birthdate where indexable_month_day(birthdate)
> '02-28' and indexable_month_day(birthdate) <= '03-01';

In a generic and parametrized way:

select * from user_birthdate
where
indexable_month_day(birthdate) > indexable_month_day(now()::date) and
indexable_month_day(birthdate) <= indexable_month_day((now() + '1
days'::interval)::date);

This will still use the index and it will work for the poor ones
who have birthday every 4 years, too. Assume, it's 02-08 today, 03-01
the next day.
The now() < X <= now() + 1 day range will find 02-29.

--
----------------------------------
Zoltán Böszörményi
Cybertec Schönig & Schönig GmbH
http://www.postgresql.at/

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Shane Ambler 2008-05-05 05:41:38 Re: Fastest way / best practice to calculate "next birthdays"
Previous Message Hannes Dorbath 2008-05-04 17:50:37 Re: Fastest way / best practice to calculate "next birthdays"