MySQL provides several functions that you can use to perform calculations on dates, for example, to calculate ages or extract parts of dates.
To determine how many years old each of your pets is, compute the difference in the year part of the current date and the birth date, then subtract one if the current date occurs earlier in the calendar year than the birth date. The following query shows, for each pet, the birth date, the current date, and the age in years.
mysql>SELECT name, birth, CURDATE(),
->(YEAR(CURDATE())-YEAR(birth))
->- (RIGHT(CURDATE(),5)<RIGHT(birth,5))
->AS age
->FROM pet;
+----------+------------+------------+------+ | name | birth | CURDATE() | age | +----------+------------+------------+------+ | Fluffy | 1993-02-04 | 2003-08-19 | 10 | | Claws | 1994-03-17 | 2003-08-19 | 9 | | Buffy | 1989-05-13 | 2003-08-19 | 14 | | Fang | 1990-08-27 | 2003-08-19 | 12 | | Bowser | 1989-08-31 | 2003-08-19 | 13 | | Chirpy | 1998-09-11 | 2003-08-19 | 4 | | Whistler | 1997-12-09 | 2003-08-19 | 5 | | Slim | 1996-04-29 | 2003-08-19 | 7 | | Puffball | 1999-03-30 | 2003-08-19 | 4 | +----------+------------+------------+------+
Here, YEAR()
pulls out the year
part of a date and RIGHT()
pulls off the rightmost five characters that represent the
MM-DD
(calendar year) part of the date. The
part of the expression that compares the
MM-DD
values evaluates to 1 or 0, which
adjusts the year difference down a year if
CURDATE()
occurs earlier in the
year than birth
. The full expression is
somewhat ungainly, so an alias
(age
) is used to make the output column
label more meaningful.
The query works, but the result could be scanned more easily
if the rows were presented in some order. This can be done by
adding an ORDER BY name
clause to sort the
output by name:
mysql>SELECT name, birth, CURDATE(),
->(YEAR(CURDATE())-YEAR(birth))
->- (RIGHT(CURDATE(),5)<RIGHT(birth,5))
->AS age
->FROM pet ORDER BY name;
+----------+------------+------------+------+ | name | birth | CURDATE() | age | +----------+------------+------------+------+ | Bowser | 1989-08-31 | 2003-08-19 | 13 | | Buffy | 1989-05-13 | 2003-08-19 | 14 | | Chirpy | 1998-09-11 | 2003-08-19 | 4 | | Claws | 1994-03-17 | 2003-08-19 | 9 | | Fang | 1990-08-27 | 2003-08-19 | 12 | | Fluffy | 1993-02-04 | 2003-08-19 | 10 | | Puffball | 1999-03-30 | 2003-08-19 | 4 | | Slim | 1996-04-29 | 2003-08-19 | 7 | | Whistler | 1997-12-09 | 2003-08-19 | 5 | +----------+------------+------------+------+
To sort the output by age
rather than
name
, just use a different ORDER
BY
clause:
mysql>SELECT name, birth, CURDATE(),
->(YEAR(CURDATE())-YEAR(birth))
->- (RIGHT(CURDATE(),5)<RIGHT(birth,5))
->AS age
->FROM pet ORDER BY age;
+----------+------------+------------+------+ | name | birth | CURDATE() | age | +----------+------------+------------+------+ | Chirpy | 1998-09-11 | 2003-08-19 | 4 | | Puffball | 1999-03-30 | 2003-08-19 | 4 | | Whistler | 1997-12-09 | 2003-08-19 | 5 | | Slim | 1996-04-29 | 2003-08-19 | 7 | | Claws | 1994-03-17 | 2003-08-19 | 9 | | Fluffy | 1993-02-04 | 2003-08-19 | 10 | | Fang | 1990-08-27 | 2003-08-19 | 12 | | Bowser | 1989-08-31 | 2003-08-19 | 13 | | Buffy | 1989-05-13 | 2003-08-19 | 14 | +----------+------------+------------+------+
A similar query can be used to determine age at death for
animals that have died. You determine which animals these are
by checking whether the death
value is
NULL
. Then, for those with
non-NULL
values, compute the difference
between the death
and
birth
values:
mysql>SELECT name, birth, death,
->(YEAR(death)-YEAR(birth)) - (RIGHT(death,5)<RIGHT(birth,5))
->AS age
->FROM pet WHERE death IS NOT NULL ORDER BY age;
+--------+------------+------------+------+ | name | birth | death | age | +--------+------------+------------+------+ | Bowser | 1989-08-31 | 1995-07-29 | 5 | +--------+------------+------------+------+
The query uses death IS NOT NULL
rather
than death <> NULL
because
NULL
is a special value that cannot be
compared using the usual comparison operators. This is
discussed later. See Section 3.3.4.6, “Working with NULL
Values”.
What if you want to know which animals have birthdays next
month? For this type of calculation, year and day are
irrelevant; you simply want to extract the month part of the
birth
column. MySQL provides several
functions for extracting parts of dates, such as
YEAR()
,
MONTH()
, and
DAYOFMONTH()
.
MONTH()
is the appropriate
function here. To see how it works, run a simple query that
displays the value of both birth
and
MONTH(birth)
:
mysql> SELECT name, birth, MONTH(birth) FROM pet;
+----------+------------+--------------+
| name | birth | MONTH(birth) |
+----------+------------+--------------+
| Fluffy | 1993-02-04 | 2 |
| Claws | 1994-03-17 | 3 |
| Buffy | 1989-05-13 | 5 |
| Fang | 1990-08-27 | 8 |
| Bowser | 1989-08-31 | 8 |
| Chirpy | 1998-09-11 | 9 |
| Whistler | 1997-12-09 | 12 |
| Slim | 1996-04-29 | 4 |
| Puffball | 1999-03-30 | 3 |
+----------+------------+--------------+
Finding animals with birthdays in the upcoming month is also
simple. Suppose that the current month is April. Then the
month value is 4
and you can look for
animals born in May (month 5
) like this:
mysql> SELECT name, birth FROM pet WHERE MONTH(birth) = 5;
+-------+------------+
| name | birth |
+-------+------------+
| Buffy | 1989-05-13 |
+-------+------------+
There is a small complication if the current month is
December. You cannot merely add one to the month number
(12
) and look for animals born in month
13
, because there is no such month.
Instead, you look for animals born in January (month
1
).
You can write the query so that it works no matter what the
current month is, so that you do not have to use the number
for a particular month.
DATE_ADD()
allows you to add a
time interval to a given date. If you add a month to the value
of CURDATE()
, then extract the
month part with MONTH()
, the
result produces the month in which to look for birthdays:
mysql>SELECT name, birth FROM pet
->WHERE MONTH(birth) = MONTH(DATE_ADD(CURDATE(),INTERVAL 1 MONTH));
A different way to accomplish the same task is to add
1
to get the next month after the current
one after using the modulo function (MOD
)
to wrap the month value to 0
if it is
currently 12
:
mysql>SELECT name, birth FROM pet
->WHERE MONTH(birth) = MOD(MONTH(CURDATE()), 12) + 1;
MONTH()
returns a number
between 1
and 12
. And
MOD(something,12)
returns a
number between 0
and 11
.
So the addition has to be after the
MOD()
, otherwise we would go
from November (11
) to January
(1
).
User Comments
In a business context, a more interesting query
TO_DAYS(CONCAT(((RIGHT(birth,5) < RIGHTfor this sample db might be the one alluded to
earlier in the tutorial - select rows whose
birthdays are coming up soon to send out a
reminder...
Here is the way I did that:
SET @bdayThreshhold=150;
SELECT name, birth, CONCAT(((RIGHT(birth,5) <
RIGHT(CURRENT_DATE,5))
(CURRENT_DATE,5))
(CURRENT_DATE) AS toBday
FROM pet
WHERE (TO_DAYS(CONCAT(((RIGHT(birth,5) < RIGHT
(CURRENT_DATE,5))
(CURRENT_DATE) < @bdayThreshhold)
ORDER BY bday, RIGHT(birth,5);
Note that I set the threshhold kind of high in
order to make sure that I matched something in
the limited tutorial dataset. Normally you would
probably want 15-30 days.
Here is another useful way of calculating age that I
have used in some of my own work: SELECT DATE
FORMAT(FROM_DAYS(TO_DAYS(NOW())-TO_DAYS
(dob)), '%Y')+0 AS age FROM people;
RE:
How can I find next Friday's date?
SELECT DATE_ADD(CURRENT_DATE,INTERVAL (6-DAYOFWEEK(CURRENT_DATE)) DAY);
How can I find this month, second Wednesday's date?
SET @First = CONCAT(EXTRACT(YEAR_MONTH FROM (DATE_ADD(CURRENT_DATE,INTERVAL 1 MONTH))),"01");
SELECT DATE_ADD(@First,INTERVAL (11 + (7 * (DAYOFWEEK(@First) > 4)) - DAYOFWEEK(@First)) DAY);
Hope this helps, no matter how tardy it is.
-Bryan
If you need to know who's birthday is within the next X days, you can use something like This:
select * from YourTable
where
(unix_timestamp(date_format(fecnac,"2003-%m-%d 00:00:00")))
between (unix_timestamp(date_format(curdate(),"2003-%m-%d 00:00:00")))
and (unix_timestamp(date_format((curdate()+interval 7 day),"2003-%m-%d 00:00:00")))
fecnac is the date of birth.
Bryan,
I think your way to calculate next Friday is not correct:
SELECT DATE_ADD(CURRENT_DATE,INTERVAL (6-DAYOFWEEK(CURRENT_DATE)) DAY);
This will return the date of this Friday if the current date is Saturday.
It could be change to:
SELECT DATE_ADD(CURRENT_DATE,INTERVAL mod(6-DAYOFWEEK(current_date)+7,7) DAY);
Thank you for your example
Hi
How can this example be changed:
mysql> SELECT name, birth FROM pet
-> WHERE MONTH(birth) = MONTH(DATE_ADD(CURDATE(),INTERVAL 0 MONTH));
...so that the output will be "this week", rather than "this month"?
Regards
Gunnar Kristiansen
i think this function i made have only 4 functions:
left((CURDATE()-birth),(CHAR_LENGTH(CURDATE()-birth)-4)) as age
is better than this becouse it have 6(the example avobe documentation):
(YEAR(CURDATE())-YEAR(birth))-(RIGHT(CURDATE(),5)<RIGHT(birth,5)) as age
Re the documentation's note that... "Note that MONTH returns a number between 1 and 12"
Fyi, the Month() function additionally will return a zero value (if the month spots in your date are zero).
Get the first day and/or last day of the current year.
This is the first day of the year ( simple )
SELECT MAKEDATE( EXTRACT(YEAR FROM CURDATE()),1);
This is the last day ( not you can not just replace the 1 with a 365 , some years you need a 366)
SELECT STR_TO_DATE(CONCAT(12,31,EXTRACT(YEAR FROM CURDATE())), '%m%d%Y') ;
Here is the SP that i wrote , it may help somebody
DELIMITER $$
DROP FUNCTION IF EXISTS `yourdatabase`.`getage` $$
CREATE DEFINER=`yourname`@`localhost` FUNCTION `getage`(pdate DATE) RETURNS int(11)
BEGIN
DECLARE years INT;
DECLARE months INT;
DECLARE days INT;
DECLARE age INT;
SELECT YEAR(pdate) INTO years;
SELECT MONTH(pdate) INTO months;
SELECT DAY(pdate) INTO days;
IF ( MONTH(CURRENT_DATE()) > months ) THEN
SELECT ( YEAR(CURRENT_DATE()) - YEAR(pdate) ) INTO age;
ELSEIF ( MONTH(CURRENT_DATE()) < months ) THEN
SELECT ( ( YEAR(CURRENT_DATE()) - YEAR(pdate) ) -1 ) INTO age;
ELSE
IF ( DAY(CURRENT_DATE()) >= DAY(pdate) ) THEN
SELECT ( YEAR(CURRENT_DATE()) - YEAR(pdate) ) INTO age;
ELSE
SELECT ( ( YEAR(CURRENT_DATE()) - YEAR(pdate) ) -1 ) INTO age;
END IF;
END IF;
RETURN age;
END $$
DELIMITER ;
For anyone trying to determine a birthday within the next x number of days this may help. Ignoring the year. The code below seems to work well. I'm also waiting for the bug preventing storage of 0000 year values to be resolved, so you can store dates when the year value is unknown.
SELECT birthday,name,lastname from contact where(DAYOFYEAR(curdate()) <= dayofyear(birthday) AND DAYOFYEAR(curdate()) +15 >= dayofyear(birthday) OR DAYOFYEAR(curdate()) <= dayofyear(birthday)+365 AND DAYOFYEAR(curdate()) +15 >= dayofyear(birthday)+365);
Here is what I used to find birthdays for the current day:
SELECT birth, email, username FROM members
WHERE MONTH(birth) = MONTH(curdate()) AND DAYOFMONTH(birth) = DAYOFMONTH(curdate());
Just try this..
SELECT DATE_FORMAT(DATE(concat('2000-',FIELD('Feb', 'Jan', 'Feb', 'Mar', 'Apr', 'May'),'-01')), '%m');
Calculating age:
"CAST((TO_DAYS(NOW())- TO_DAYS(birthdate)) / 365.25 as SIGNED)" has rounding problems, but "FLOOR((TO_DAYS(NOW())- TO_DAYS(birthdate)) / 365.25)" works as expected.
I found that when trying to look for a pet's birthday a half year from now, it won't return anything from month 7 to 12 using this:
SELECT name,birth FROM pet WHERE MONTH(birth)=MONTH(CURDATE())+6;
However, when I used this:
SELECT name,birth FROM pet WHERE MONTH(birth)=MONTH(CURDATE())+6 or MONTH(birth)=MONTH(CURDATE())-6;
It does work (probably because it's looking past the month 12).
The same goes with looking for a pet's birthday one month from now:
SELECT name,birth FROM pet WHERE MONTH(birth)=MONTH(CURDATE())+1 or MONTH(birth)=MONTH(CURDATE())-11;
Did any of you out there come with other solutions, as this did seems a bit tedious to me.
Cheers.
i think a command like
SELECT name,birth FROM pet WHERE MONTH(birth)=MONTH(CURDATE())+1 or MONTH(birth)=MONTH(CURDATE())-11;
just one OR sub clause works.Say,MONTH(CURDATE()=10 then just MONTH(CURDATE())+1 works, MONTH(CURDATE())-11 not.it seems just the expression value within 1 to 12 for MONTH works.
I think the most trivial solution for the "birthdays in next X days" should be things like:
SELECT `name`,`birthday`,IF (STR_TO_DATE(CONCAT(YEAR(CURDATE()),'/',MONTH(`birthday`),'/',DAY(`birthday`)),'%Y/%c/%e') >= CURDATE(), STR_TO_DATE(CONCAT(YEAR(CURDATE()),'/',MONTH(`birthday`),'/',DAY(`birthday`)),'%Y/%c/%e') , STR_TO_DATE(CONCAT(YEAR(CURDATE())+1,'/',MONTH(`birthday`),'/',DAY(`birthday`)),'%Y/%c/%e')) as `upcoming` FROM `contact` HAVING `upcoming` BETWEEN CURDATE() AND ADDDATE(CURDATE(),INTERVAL 30 DAY) ORDER BY `upcoming`;
upcoming birthdays on mysql 5.0
SELECT
FLOOR((UNIX_TIMESTAMP(CONCAT(((RIGHT(birth, 5) < RIGHT(CURRENT_DATE, 5)) + YEAR(CURRENT_DATE)), RIGHT(birth, 6))) - UNIX_TIMESTAMP(CURRENT_DATE)) / 86400) AS upcoming_days
FROM pet
Here's another way to calculate age, using a nested SELECT statement. It's not 100% precise because not every four years is a leap year. Still working on how to SELECT pets with NULL value for death (i.e. living pets only).
SELECT name, birth, datediff(curdate(), birth)/365.25 AS Age
FROM pet
WHERE birth =
(SELECT min(birth)
FROM pet);
Add your own comment.