Press Alt+F11 to go to the VB editor, click Insert/Module from its menu bar,
then copy paste the following UDF (User Defined Function) into the code
window that opened up (see rest of my message after the code)...
'*************** START OF CODE ***************
Function YMWD(ByVal Date1 As Variant, ByVal Date2 As Variant) As String
Dim TempDate As Date
Dim NumOfYears As Long
Dim NumOfMonths As Long
Dim NumOfWeeks As Long
Dim NumOfDays As Long
If IsDate(CDate(Date1)) And IsDate(CDate(Date2)) Then
Date1 = CDate(Date1)
Date2 = CDate(Date2)
If Date1 > Date2 Then
TempDate = Date1
Date1 = Date2
Date2 = TempDate
End If
NumOfYears = DateDiff("yyyy", Date1, Date2)
Date1 = DateSerial(Year(Date2), Month(Date1), Day(Date1))
If Date1 > Date2 Then
Date1 = DateAdd("yyyy", -1, Date1)
NumOfYears = NumOfYears - 1
End If
NumOfMonths = DateDiff("m", Date1, Date2)
Date1 = DateSerial(Year(Date2), Month(Date2), Day(Date1))
If Date1 > Date2 Then
Date1 = DateAdd("m", -1, Date1)
NumOfMonths = NumOfMonths - 1
End If
NumOfDays = Abs(DateDiff("d", Date1, Date2))
NumOfWeeks = NumOfDays \ 7
NumOfDays = NumOfDays Mod 7
If NumOfYears > 0 Then
YMWD = CStr(NumOfYears) & " year" & _
IIf(NumOfYears = 1, "", "s")
End If
If NumOfMonths > 0 Then
If YMWD <> "" Then YMWD = YMWD & ", "
YMWD = YMWD & CStr(NumOfMonths) & " month" & _
IIf(NumOfMonths = 1, "", "s")
End If
If NumOfWeeks > 0 Then
If YMWD <> "" Then YMWD = YMWD & ", "
YMWD = YMWD & CStr(NumOfWeeks) & " week" & _
IIf(NumOfWeeks = 1, "", "s")
End If
If NumOfDays > 0 Then
If YMWD <> "" Then YMWD = YMWD & ", "
YMWD = YMWD & CStr(NumOfDays) & " day" & _
IIf(NumOfDays = 1, "", "s")
ElseIf YMWD = "" Then
YMWD = "0 Days"
End If
YMWD = RTrim$(YMWD)
End If
End Function
'*************** END OF CODE ***************
Now, go back to a worksheet and type this in...
=YMWD(A1,TODAY())
where I assume A1 contains your retirement date. You can also just put your
retirement date in as text like this...
=YMWD("20 Sep 2010",TODAY())
The UDF I gave you actually is more general than you asked for... it will
calculate the Years, Months, Weeks and Days between any two dates... just
put the dates in as arguments to the UDF (the order doesn't matter) and the
difference in Years, Months, Weeks and Days will be returned to you. Also
note that the UDF puts the "s" on multiple units and leaves it off for
single units (that is, for example, "1 Week", but "2 Weeks").
--
Rick (MVP - Excel)
"Using the date functions" <Using the date
(e-mail address removed)> wrote in message