[AccessD] Age calculation

Gustav Brock Gustav at cactus.dk
Sun Apr 27 13:28:04 CDT 2008


Hi all

A bug was found in my Years() function which caused negative linear age (see in-line comments) to be calculated wrongly for some dates of Feb. 29th.
This has been corrected: 

<code>
Public Function Years( _
  ByVal datDOB As Date, _
  ByVal datNow As Date, _
  Optional ByVal booLinear As Boolean) _
  As Integer
 
' Returns the difference in full years between datDOB and datNow.
'
' Calculates correctly for:
'   negative differences
'   leap years
'   dates of 29. February
'   date/time values with embedded time values
'   negative date/time values (prior to 1899-12-29)
'
' Optionally returns negative counts rounded down to provide a
' linear sequence of year counts.
' For a given datDOB, if datNow is decreased step wise one year from
' returning a positive count to returning a negative count, one or two
' occurrences of count zero will be returned.
' If booLinear is False, the sequence will be:
'   3, 2, 1, 0,  0, -1, -2
' If booLinear is True, the sequence will be:
'   3, 2, 1, 0, -1, -2, -3
'
' If booLinear is False, reversing datDOB and datNow will return
' results of same absolute value, only the sign will change.
' This behaviour mimics that of Fix().
' If booLinear is True, reversing datDOB and datNow will return
' results where the negative count is offset by -1.
' This behaviour mimics that of Int().
 
' DateAdd() is used for check for month end of February as it correctly
' returns Feb. 28. when adding a count of years to dates of Feb. 29.
' when the resulting year is a common year.
'
' 2000-11-03. Cactus Data ApS, CPH.
' 2000-12-16. Leap year correction modified to be symmetrical.
'             Calculation of intDaysDiff simplified.
'             Renamed from YearsDiff() to Years().
' 2000-12-18. Introduced cbytMonthDaysMax.
' 2007-06-22. Version 2. Complete rewrite.
'             Check for month end of February performed with DateAdd()
'             after idea of Markus G. Fischer.
' 2008-04-27. Version 2.1.
'             Correction for calculation of linear age from Feb. 29th.
'             to Feb. 28th of a previous non-leap year as documented
'             by Lester Hui.
'
'             Example:
'               DOB: 2000-02-29, Today: 1999-02-28, Age linear: -1.
'
'             Parameters renamed to stress that for age calculations
'             first parameter must be Date of Birth as documented
'             by Markus G. Fischer.
' 2008-04-27. Version 2.2
'             Rewrite to correct negative years count bug.
 
  Dim intSign   As Integer
  Dim intYears  As Integer
  
  ' Find difference in calendar years.
  intYears = DateDiff("yyyy", datDOB, datNow)
  ' For positive resp. negative intervals, check if the second date
  ' falls before, on, or after the crossing date for a full 12 months period
  ' while at the same time correcting for February 29. of leap years.
  
  If DateDiff("d", datDOB, datNow) > 0 Then
    If DateDiff("d", DateAdd("yyyy", intYears, datDOB), datNow) < 0 Then
      ' The last year is not a full year.
      ' Reduce year count by one.
      intYears = intYears - 1
    End If
  Else
    intSign = Sgn(DateDiff("d", DateAdd("yyyy", -intYears, datNow), datDOB))
    If intSign <> 0 Then
      If intSign < 0 Then
        ' The last year is not a full year.
        ' Reduce negative year count by one.
        intYears = intYears + 1
      End If
      If booLinear Then
        ' Offset negative count of years to continuous sequence if requested.
        If DateDiff("d", DateAdd("yyyy", intYears, datDOB), datNow) < 0 Then
          ' Time interval includes a partial year.
          ' Increase negative year count by one.
          intYears = intYears - 1
        End If
      End If
    End If
  End If
  
  ' Return count of years as count of full 12 months periods.
  Years = intYears
  
End Function
</code>

Lester Hui who located the bug has another method for calculating age:

<code>
Public Function MyYearsFunction( _
  ByVal datDate1 As Date, _
  ByVal datDate2 As Date, _
  Optional ByVal booLinear As Boolean) _
  As Integer
  
  Dim intYears As Integer
  Dim booSameDate As Boolean
  
  booSameDate = Format(datDate2, "mmdd") = Format(datDate1, "mmdd") Or Format(datDate2 + 1, "mmdd") = Format(datDate1 + 1, "mmdd")
  intYears = DateDiff("yyyy", datDate1, datDate2)
  If Format(datDate1, "mmdd") > Format(datDate2, "mmdd") And Not booSameDate Then intYears = intYears - 1
  If Not booLinear And datDate1 > datDate2 And Not booSameDate Then intYears = intYears + 1
 
  MyYearsFunction = intYears
End Function
</code>

This is the only other method I've seen to deal correctly with positive as well as negative age calculation. It is, however, about 50% slower than mine due to the use of Format.

/gustav

>>> Gustav at cactus.dk 23-06-2007 19:56 >>>
Hi all

As I have posted several times, most of the functions published around the web for this simple task is crap because they fail for calculations around Feb. 28./29., thus they are not suited for business use.

Recently I noticed that DateAdd() correctly returns Feb. 28 when adding a count of years to dates of Feb. 29. resulting in dates of common years.
Markus G. Fischer at Expert-Exchange came up with the idea of using this feature for serious age calculation, and so I did.

I did a rewrite of my previous Years function as it could be simplified considerably using DateAdd and with the option to return negative ages in either of two ways.

For a given datDate1, if datDate2 is decreased step wise one year from returning a positive count to returning a negative count, one or two occurrences of count zero will be returned.
If booLinear is False, the sequence will be:
  3, 2, 1, 0,  0, -1, -2
If booLinear is True, the sequence will be:
  3, 2, 1, 0, -1, -2, -3

More explanation in the in-line comments.

Here it is:

Public Function Age( _
  ByVal datDateOfBirth As Date, _
  Optional ByVal varDate As Variant) _
  As Integer

' Calculates age at today's date or at a specified date earlier or later in time.
' Uses Years() for calculating difference in years.
'
' Will return 0 for any varDate of the first year before datDateOfBirth.
' See comments for Years().
'
' 2000-11-03. Cactus Data ApS, CPH.
' 2007-06-23. Supplemented with AgeLinear for count of negative ages offset by -1.

  Dim datDate As Date
  
  ' No special error handling.
  On Error Resume Next
  
  If IsDate(varDate) Then
    datDate = CDate(varDate)
  Else
    datDate = Date
  End If

  Age = Years(datDateOfBirth, datDate)
  
End Function

Public Function AgeLinear( _
  ByVal datDateOfBirth As Date, _
  Optional ByVal varDate As Variant) _
  As Integer

' Calculates age at today's date or at a specified date earlier or later in time.
' Uses Years() for calculating difference in years.
'
' Will return -1 for any varDate of the first year before datDateOfBirth.
' See comments for Years().
'
' 2007-06-23. Cactus Data ApS, CPH.

  Dim datDate As Date
  
  ' No special error handling.
  On Error Resume Next
  
  If IsDate(varDate) Then
    datDate = CDate(varDate)
  Else
    datDate = Date
  End If

  AgeLinear = Years(datDateOfBirth, datDate, True)
  
End Function





More information about the AccessD mailing list