Here’s a query to calculate the Age in Years, Months, Days, Hours and Minutes
declare @birth_day datetime
set @birth_day ='19660527 12:34:22'
select
years,
months,
case
when day(@birth_day)>day(getdate())
then day(getdate())+
datediff(day,@birth_day,dateadd(month,datediff(month,0,@birth_day)+1,0))-1
else day(getdate())-day(@birth_day)
end as days,
datepart(hour,convert(varchar(10),dateadd(minute,minutes,0),108)) as hours,
datepart(minute,convert(varchar(10),dateadd(minute,minutes,0),108)) as minutes
from
(
select
years,
datediff(month,dateadd(year,years,@birth_day),getdate())+
case
when day(getdate())>=day(@birth_day)
then 0
else -1
end as months,
datediff(minute,convert(varchar(8),@birth_day,108),
convert(varchar(8),getdate(),108)) as minutes
from
(
select
datediff(year,@birth_day,getdate()) +
case
when month(getdate())>=month(@birth_day)
then 0
else -1
end as years
) as t
) as t
In the query shown above, the inner query finds the year difference between current date and birth date. The case expression checks whether current month is greater than the month of birth date. If it is greater, a full year is completed, else the full year is not completed and one year is reduced from the result.
A similar check is done for month too. The outer parts calculate the hours and minutes.
OUTPUT
5 comments:
so, if someone was born on February 28 2010 (20100228) he is 0 years, 4 month, 23 days old.
but, if he was born on March 1 2010 (20100301) he is 0 years, 4 month, 20 days old?
Anonymous: Madhivanan has updated the post making some changes to the query. Care to try again?
yes, i think it works fine now.
this is table-valued function that calculates difference between two dates based on Madhivanan code:
CREATE FUNCTION [dbo].[YMDHM] (@dateFrom DATETIME , @dateTo DATETIME)
RETURNS @result TABLE (years INT, months INT, days INT, hours INT, minutes INT)
AS
BEGIN
DECLARE @Y INT;
DECLARE @M INT;
DECLARE @D INT;
DECLARE @H INT;
DECLARE @MI INT;
SELECT @Y = years,
@M = months,
@D = (CASE
WHEN DAY(@dateFrom) > DAY(@dateTo) THEN DAY(@dateTo)+ DATEDIFF(DAY, @dateFrom, DATEADD(MONTH, DATEDIFF(MONTH ,0 , @dateFrom) + 1, 0)) - 1
ELSE DAY(@dateTo) - DAY(@dateFrom)
END),
@H = DATEPART(HOUR, CONVERT(VARCHAR(10), DATEADD(MINUTE, minutes, 0), 108)),
@MI = DATEPART(MINUTE, CONVERT(VARCHAR(10), DATEADD(MINUTE, minutes, 0), 108))
FROM
(
SELECT years,
(DATEDIFF(MONTH, DATEADD(YEAR, years, @dateFrom), @dateTo) +
CASE
WHEN DAY(@dateTo) >= DAY(@dateFrom) THEN 0
ELSE -1
END) AS months,
DATEDIFF(MINUTE, CONVERT(VARCHAR(8), @dateFrom, 108), CONVERT(VARCHAR(8), @dateTo, 108)) AS minutes
FROM
(
SELECT (DATEDIFF(YEAR, @dateFrom, @dateTo) +
CASE
WHEN MONTH(@dateTo) >= MONTH(@dateFrom) THEN 0
ELSE -1
END) AS years
) AS t
) AS t
INSERT INTO @result (years, months, days, hours, minutes) VALUES(@Y, @M, @D, @H, @MI)
RETURN
END
If you set @birth_day = tomorrow's date it will show *years* as 1 more then its suppose to. It also shows *months* as -1.
SET @dateFrom = '1982-08-31'
SET @dateTo = '2011-08-30'
does not work with those days
Post a Comment