Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 35.3Mb
PDF (A4) - 35.5Mb
PDF (RPM) - 33.8Mb
EPUB - 8.6Mb
HTML Download (TGZ) - 8.4Mb
HTML Download (Zip) - 8.5Mb
HTML Download (RPM) - 7.3Mb
Eclipse Doc Plugin (TGZ) - 9.3Mb
Eclipse Doc Plugin (Zip) - 11.3Mb
Man Pages (TGZ) - 197.9Kb
Man Pages (Zip) - 301.8Kb
Info (Gzip) - 3.2Mb
Info (Zip) - 3.2Mb
Excerpts from this Manual

4.3.4.5 Date Calculations

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, use the TIMESTAMPDIFF() function. Its arguments are the unit in which you want the result expressed, and the two date for which to take the difference. The following query shows, for each pet, the birth date, the current date, and the age in years. An alias (age) is used to make the final output column label more meaningful.

mysql> SELECT name, birth, CURDATE(),
    -> TIMESTAMPDIFF(YEAR,birth,CURDATE()) 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 |
+----------+------------+------------+------+

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(),
    -> TIMESTAMPDIFF(YEAR,birth,CURDATE()) 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(),
    -> TIMESTAMPDIFF(YEAR,birth,CURDATE()) 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,
    -> TIMESTAMPDIFF(YEAR,birth,death) 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 4.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() enables 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
  Posted by Dan Fitzpatrick on May 28, 2002
In a business context, a more interesting query
for 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))
+ YEAR(CURRENT_DATE)), RIGHT(birth,6)) AS bday, 
TO_DAYS(CONCAT(((RIGHT(birth,5) < RIGHT
(CURRENT_DATE,5))
+ YEAR(CURRENT_DATE)), RIGHT(birth,6))) - TO_DAYS
(CURRENT_DATE) AS toBday
FROM pet
WHERE (TO_DAYS(CONCAT(((RIGHT(birth,5) < RIGHT
(CURRENT_DATE,5))
+ YEAR(CURRENT_DATE)), RIGHT(birth,6))) - TO_DAYS
(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.
  Posted by Bryan on March 12, 2003
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
  Posted by Manuel Guerrero on April 21, 2003
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.

  Posted by Qing on August 7, 2003
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

  Posted by Gunnar Kristiansen on March 9, 2004
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
  Posted by Juan Sanjuan on June 1, 2005
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
  Posted by Frances D on June 7, 2006
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).
  Posted by jeremy levine on August 22, 2006
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') ;
  Posted by Vijay Kumar on March 13, 2007
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 ;
  Posted by Michael Jay on April 6, 2007
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);
  Posted by Tim Mousel on August 17, 2007
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());
  Posted by Kedar Acharekar on January 24, 2008
Just try this..

SELECT DATE_FORMAT(DATE(concat('2000-',FIELD('Feb', 'Jan', 'Feb', 'Mar', 'Apr', 'May'),'-01')), '%m');
  Posted by Niels van Amstel on August 20, 2008
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.
  Posted by huang legend on October 31, 2008
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.
  Posted by Osbert Ngok on March 10, 2009
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`;
  Posted by Alexander Gavazov on October 22, 2009
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
  Posted by Allan Cano on October 6, 2010
There are times when you want an age that includes months and days. In my case it's was for tracking rounding notes on a paediatric floor. Here's the simple function I came up with for calculating age.

Tried this popular trick originally and found it failed to give a correct answer.

SELECT FROM_DAYS(DATEDIFF(current_date(),dob)) INTO age;

-- Function --

DELIMITER $$

DROP FUNCTION IF EXISTS Age $$

CREATE FUNCTION Age( dob DATE )
RETURNS CHAR(20)
BEGIN
DECLARE years INT default 0;
DECLARE months INT default 0;
DECLARE days INT default 0;
DECLARE age DATE;

-- Check that the dob we're given is useful
IF dob is null or dob = 0 or dob = '0000-00-00' THEN
RETURN dob;
END IF;

SELECT date_add('0001-01-01', interval datediff(current_date(),dob) day ) INTO age;

SELECT YEAR(age) -1 INTO years;
SELECT MONTH(age)-1 INTO months;
SELECT DAY(age) -1 INTO days;

IF years THEN
RETURN concat(years,'y ',months,'m');

ELSEIF months THEN
RETURN concat(months,'m ',days,'d');

ELSE
RETURN concat(days,' days');
END IF;

END $$

DELIMITER ;

  Posted by Mark Stafford on January 6, 2011
-- working with the other examples on this page I decided to return age as a date which facilitates further parsing of the results

DELIMITER //

DROP FUNCTION IF EXISTS get_age //

CREATE FUNCTION get_age( p_after date, p_before date )
RETURNS date
BEGIN

DECLARE l_offset DATE default date_format('0001-01-01', '%Y-%m-%d');
DECLARE l_date_age DATE default date_sub( date_add( l_offset, INTERVAL datediff( p_after , p_before ) DAY ) - l_offset , interval 2000 year );

RETURN l_date_age;

END //

DELIMITER ;

  Posted by Poldi Rijke on March 8, 2011
MySQl 5.0 or higher: TIMESTAMPDIFF

SELECT TIMESTAMPDIFF(YEAR, birthday, CURDATE() ) AS 'age in years'
FROM person;

From MySQL Cookbook p248
  Posted by Rahul Sonar on May 16, 2011
SELECT CURDATE(),
(YEAR(CURDATE())- YEAR(dob))
- (
RIGHT(CURDATE(),5)<
RIGHT(dob,5)) AS age,
case when ((MONTH(CURDATE())- MONTH(dob))
- (RIGHT(CURDATE(),2)<RIGHT(dob,2)))>0 then ((MONTH(CURDATE())- MONTH(dob))
- (RIGHT(CURDATE(),2)<RIGHT(dob,2))) else ((MONTH(CURDATE())- MONTH(dob))
- (RIGHT(CURDATE(),2)<RIGHT(dob,2))) + 12 end AS Months,

(DAY(CURDATE() - DAY(dob))) AS Days;
  Posted by SOUMEN DAS on December 9, 2011
BIRTH DAY

SELECT emp_name,email FROM employee where DATE_FORMAT(now(),'%m')-DATE_FORMAT(emp_dob,'%m')=0 and DATE_FORMAT(now(),'%d')-DATE_FORMAT(emp_dob,'%d')=0

UPCOMING BIRTHDAY

SELECT emp_name,email,DATE_FORMAT(emp_dob,'%d-%M') as bdt FROM employee where DATE_FORMAT(now(),'%m')-DATE_FORMAT(emp_dob,'%m')=0 and DATE_FORMAT(now(),'%d')-DATE_FORMAT(emp_dob,'%d')<0
  Posted by Thomas Pepe on March 9, 2012
MySQL noob here. To get all pets of a certain age (like 5 years old or more) I think this would be more efficient. Please let me know if I am mistaken.

##5 year old pets
DECLARE fiveYearsAgo = CURDATE() - INTERVAL 5 YEAR;
SELECT name, birth
FROM pet
WHERE pet.birth <= fiveYearsAgo
;

##5 years only
DECLARE fourYearsAgo = CURDATE() - INTERVAL 4 YEAR;
SELECT name, birth
FROM pet
WHERE pet.birth BETWEEN fiveYearsAgo AND fourYearsAgo
;

##NOTE: To consider time I could truncate the time off of the five year date and add to the last nanosecond of the four year date

Thank you.
  Posted by Uchechukwu Chikezie on October 30, 2014
So from the lesson, I can infer that the query below will select age in terms of years and months:

SELECT birth_date,
CONCAT(TIMESTAMPDIFF(YEAR, birth_date, CURRENT_DATE()), ' years ', TIMESTAMPDIFF(MONTH, CONCAT(YEAR(CURRENT_DATE()), '-',MONTH(birth_date), '-', DAY(birth_date)), CURRENT_DATE()), ' months ') as currentage,
CONCAT(YEAR(CURRENT_DATE()), '-',MONTH(birth_date), '-', DAY(birth_date)) AS thisyearsbirthday,
CURRENT_DATE() AS today
FROM pet
  Posted by Gauravkumar Mishra on February 26, 2015
I had a similar problem when I was requested to calculate age of Patients in Years, Months and Days. I did not find any solution and had to create the below for my rescue. I hope this helps everyone, until we have a inbuilt function which calculates age accurately in Years, Months and Days.

select CONCAT(
CASE WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - (MONTH(dob) - MONTH(CURDATE())) - 1 ,' Month ',30 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - (MONTH(dob) - MONTH(CURDATE())) - 1 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - (MONTH(dob) - MONTH(CURDATE())) - 1 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - (MONTH(dob) - MONTH(CURDATE())) - 1 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 11 ,' Month ',3 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 11 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 11 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 11 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ',30 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) > DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ',31 - (DAY(dob) - DAY(CURDATE())) ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - (MONTH(dob) - MONTH(CURDATE())) ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - (MONTH(dob) - MONTH(CURDATE())) ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - (MONTH(dob) - MONTH(CURDATE())) ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - (MONTH(dob) - MONTH(CURDATE())) ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', MONTH(CURDATE()) - MONTH(dob) ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', MONTH(CURDATE()) - MONTH(dob) ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', MONTH(CURDATE()) - MONTH(dob) ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) = DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', MONTH(CURDATE()) - MONTH(dob) ,' Month ', 0 ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - MONTH(dob) + MONTH(CURDATE()) ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - MONTH(dob) + MONTH(CURDATE()) ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - MONTH(dob) + MONTH(CURDATE()) ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) > MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - 1 - YEAR(dob), ' Year ', 12 - MONTH(dob) + MONTH(CURDATE()) ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) = MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', 0 ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 1) OR (MONTH(CURDATE()) = 3) OR (MONTH(CURDATE()) = 5) OR (MONTH(CURDATE()) = 7) OR (MONTH(CURDATE()) = 8) OR (MONTH(CURDATE()) = 10) OR (MONTH(CURDATE()) = 12))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', MONTH(CURDATE()) - MONTH(dob) ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND ((MONTH(CURDATE()) = 4) OR (MONTH(CURDATE()) = 6) OR (MONTH(CURDATE()) = 9) OR (MONTH(CURDATE()) = 11))
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', MONTH(CURDATE()) - MONTH(dob) ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) = 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', MONTH(CURDATE()) - MONTH(dob) ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
WHEN DAY(dob) < DAY(CURDATE()) AND (MONTH(dob) < MONTH(CURDATE())) AND (MONTH(CURDATE()) = 2) AND (MOD(YEAR(CURDATE()),4) != 0)
THEN(
CONCAT(YEAR(CURDATE()) - YEAR(dob), ' Year ', MONTH(CURDATE()) - MONTH(dob) ,' Month ', DAY(CURDATE()) - DAY(dob) ,' Day ')
)
END
) as "Age" from Patient_Details;
  Posted by Rob Bartram on May 27, 2015
Using Gauravkumar Mishra's method for Years, Months, Days, I was getting -1 days for some dates.

Here is what I ended up with: (sorry, I'm not sure how to make it more readable)

SELECT (CONCAT(CONCAT(CONCAT(TIMESTAMPDIFF(YEAR, dob, CURDATE()), ' years, ')
,CONCAT(TIMESTAMPDIFF(MONTH, dob, CURDATE()) - ((TIMESTAMPDIFF(MONTH, dob, CURDATE()) div 12) * 12), ' months, '))
,CONCAT(TIMESTAMPDIFF(DAY, DATE_ADD(DATE_ADD(dob,INTERVAL TIMESTAMPDIFF(YEAR, dob, CURDATE()) YEAR), INTERVAL TIMESTAMPDIFF(MONTH, dob, CURDATE()) -
((TIMESTAMPDIFF(MONTH, dob, CURDATE()) div 12) * 12) MONTH), CURDATE()), ' days')) as "Age" from Patient_Details;
Sign Up Login You must be logged in to post a comment.