It is relatively easy to calculate the number of either years, months days hours or seconds between two dates using the native DATEDIFF
built in function which comes with SQL.
e.g.
SELECT dbo.t001trees.pkid, dbo.t001trees.plantdate, DATEDIFF(Year, dbo.t001trees.plantdate, GETDATE()) as treeage from dbo.t001trees;
But here is a function that will spell it out into a string that reads something like
2 days
1 month 2 days
2 years 1 month 2 days
CREATE OR ALTER FUNCTION dbo.functionyearmonthday ( @datefrom Date, @dateto Date ) RETURNS varchar(100) as BEGIN DECLARE @date1 DATETIME, @date2 DATETIME, @result VARCHAR(100); DECLARE @years INT, @months INT, @days INT; SET @date1 = @datefrom SET @date2 = @dateto SELECT @years = DATEDIFF(yy, @date1, @date2) IF DATEADD(yy, -@years, @date2) < @date1 SELECT @years = @years-1 SET @date2 = DATEADD(yy, -@years, @date2) SELECT @months = DATEDIFF(mm, @date1, @date2) IF DATEADD(mm, -@months, @date2) < @date1 SELECT @months=@months-1 SET @date2= DATEADD(mm, -@months, @date2) SELECT @days=DATEDIFF(dd, @date1, @date2) IF DATEADD(dd, -@days, @date2) < @date1 SELECT @days=@days-1 SET @date2= DATEADD(dd, -@days, @date2) SELECT @result= ISNULL(CAST(NULLIF(@years,0) AS VARCHAR(10)) + ' years ','') + ISNULL(' ' + CAST(NULLIF(@months,0) AS VARCHAR(10)) + ' months ','') + ISNULL(' ' + CAST(NULLIF(@days,0) AS VARCHAR(10)) + ' days','') RETURN @result; END
And if you would like to call the function from another query here is an example
SELECT dbo.functionyearmonthday(dbo.t001trees.plantdate, GETDATE()) as treeage FROM dbo.t001trees
That is enough for most people but it can be expanded to include hours minutes seconds and milliseconds which could be useful if you need more precision it can be seen that the DATEDIFF native function is included extensively within this function.
CREATE OR ALTER FUNCTION dbo.functiontimeperiodmoreprecision ( @datefrom Date, @dateto Date ) RETURNS varchar(100) as BEGIN DECLARE @date1 DATETIME, @date2 DATETIME, @result VARCHAR(100); DECLARE @years INT, @months INT, @days INT, @hours INT, @minutes INT, @seconds INT, @milliseconds INT; SET @date1 = @datefrom SET @date2 = @dateto SELECT @years = DATEDIFF(yy, @date1, @date2) IF DATEADD(yy, -@years, @date2) < @date1 SELECT @years = @years-1 SET @date2 = DATEADD(yy, -@years, @date2) SELECT @months = DATEDIFF(mm, @date1, @date2) IF DATEADD(mm, -@months, @date2) < @date1 SELECT @months=@months-1 SET @date2= DATEADD(mm, -@months, @date2) SELECT @days=DATEDIFF(dd, @date1, @date2) IF DATEADD(dd, -@days, @date2) < @date1 SELECT @days=@days-1 SET @date2= DATEADD(dd, -@days, @date2) SELECT @hours=DATEDIFF(hh, @date1, @date2) IF DATEADD(hh, -@hours, @date2) < @date1 SELECT @hours=@hours-1 SET @date2= DATEADD(hh, -@hours, @date2) SELECT @minutes=DATEDIFF(mi, @date1, @date2) IF DATEADD(mi, -@minutes, @date2) < @date1 SELECT @minutes=@minutes-1 SET @date2= DATEADD(mi, -@minutes, @date2) SELECT @seconds=DATEDIFF(s, @date1, @date2) IF DATEADD(s, -@seconds, @date2) < @date1 SELECT @seconds=@seconds-1 SET @date2= DATEADD(s, -@seconds, @date2) SELECT @milliseconds=DATEDIFF(ms, @date1, @date2) SELECT @result= ISNULL(CAST(NULLIF(@years,0) AS VARCHAR(10)) + ' years,','') + ISNULL(' ' + CAST(NULLIF(@months,0) AS VARCHAR(10)) + ' months,','') + ISNULL(' ' + CAST(NULLIF(@days,0) AS VARCHAR(10)) + ' days,','') + ISNULL(' ' + CAST(NULLIF(@hours,0) AS VARCHAR(10)) + ' hours,','') + ISNULL(' ' + CAST(@minutes AS VARCHAR(10)) + ' minutes and','') + ISNULL(' ' + CAST(@seconds AS VARCHAR(10)) + CASE WHEN @milliseconds > 0 THEN '.' + CAST(@milliseconds AS VARCHAR(10)) ELSE '' END + ' seconds','') RETURN @result END