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

From: Kevin Grittner <kgrittn(at)ymail(dot)com>
To: "er(dot)tejaspatel88(at)gmail(dot)com" <er(dot)tejaspatel88(at)gmail(dot)com>, "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: Fastest way / best practice to calculate "next birthdays"
Date: 2015-06-01 19:11:15
Message-ID: 1217472852.2845919.1433185875147.JavaMail.yahoo@mail.yahoo.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

"er(dot)tejaspatel88(at)gmail(dot)com" <er(dot)tejaspatel88(at)gmail(dot)com> wrote:

> If I have to find upcoming birthdays in current week and the
> current week fall into different months - how would you handle
> that?

If you don't need to cross from December into January, I find the
easiest is:

SELECT * FROM person
WHERE (EXTRACT(MONTH FROM dob), EXTRACT(DAY FROM dob))
BETWEEN (6, 28) AND (7, 4);

That is logicically the same as:

SELECT * FROM person
WHERE (EXTRACT(MONTH FROM dob) >= 6
AND (EXTRACT(MONTH FROM dob) > 6
OR (EXTRACT(DAY FROM dob) >= 28)))
AND (EXTRACT(MONTH FROM dob) <= 7
AND (EXTRACT(MONTH FROM dob) < 7
OR (EXTRACT(DAY FROM dob) <= 4)));

That's the generalized case; with the months adjacent, this simpler
form is also equivalent:

SELECT * FROM person
WHERE (EXTRACT(MONTH FROM dob) = 6
AND EXTRACT(DAY FROM dob) >= 28)
OR (EXTRACT(MONTH FROM dob) = 7
AND EXTRACT(DAY FROM dob) <= 4);

The first query I showed is faster than either of the alternatives,
especially if there is an index on dob.

--
Kevin Grittner
EDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Scott Marlowe 2015-06-01 19:35:06 Re: Postgres is using 100% CPU
Previous Message Tom Lane 2015-06-01 17:58:12 Re: Slow hash join performance with many batches