Solved Problems with "renewal date" code (1 Viewer)

HillTJ

To train a dog, first know more than the dog..
Local time
Today, 05:38
Joined
Apr 1, 2019
Messages
731
Hi all, I'm attempting to write a module that will return one of several warning messages when a training 'Renewal Date' approaches as Renewals are required 3 years after training.

So, I pass the last 'Completion Date' to the function below & add 3 years to it. (I call it 'dteRenewal' in the function for want of a better name).

I then wish to return a warning at 3 months till renewal, 1 month, 1 week & 'Expired' when the Renewal date is < actual date.

Seems I've gotten my wires crossed & would appreciate some guidance.

Thanks in advance.

Code:
Option Compare Database
Option Explicit
Public Function CalcExpiry(dteRenewal As Date) As String
Const conJetDate = "\#mm\/dd\/yyyy\#"
'system date format is dd/mm/yyyy
MsgBox Format(dteRenewal, conJetDate) ' for testing
MsgBox DateAdd("m", 3, Date) 'for testing

Select Case dteRenewal


        Case DateAdd("m", 3, Date) > Format(dteRenewal, conJetDate)
            CalcExpiry = "Expires in 3 Months"
           MsgBox "3 Months"
        
        Case DateAdd("m", 1, Date) > Format(dteRenewal, conJetDate)
            CalcExpiry = "Expires in 1 Month"
            
        Case DateAdd("WW", 1, Date) > Format(dteRenewal, conJetDate)
            CalcExpiry = "Expires in 1 Week"
            
        Case Date > Format(dteRenewal, conJetDate)
            CalcExpiry = "Expired"
 End Select
    MsgBox CalcExpiry
    
End Function
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Tomorrow, 00:38
Joined
May 7, 2009
Messages
19,245
Code:
' arnelgp
Public Function CalcExpiry(ByVal dteRenewal As Date) As String
    Dim imonths As Integer, iweeks As Integer, idays As Integer
    Dim status As String
    dteRenewal = DateAdd("m", 3, dteRenewal)
    idays = DateDiff("d", Date, dteRenewal)
    iweeks = DateDiff("ww", Date, dteRenewal)
    imonths = DateDiff("m", Date, dteRenewal)
    Select Case True
        Case idays < 1
            status = "Expired"
        Case imonths > 0
            status = "Expires in " & imonths & " month(s)"
        Case iweeks > 0
            status = "Expires in " & iweeks & " week(s)"
        Case Else
            status = "Expires in " & idays & " day(s)"
    End Select
    CalcExpiry = status
End Function
 

Gasman

Enthusiastic Amateur
Local time
Today, 17:38
Joined
Sep 21, 2011
Messages
14,308
Do not format dates when calculating, just do the math on the date field itself.
 

Gasman

Enthusiastic Amateur
Local time
Today, 17:38
Joined
Sep 21, 2011
Messages
14,308
Code:
' arnelgp
Public Function CalcExpiry(ByVal dteRenewal As Date) As String
    Dim imonths As Integer, iweeks As Integer, idays As Integer
    Dim status As String
    Select Case True
        Case idays < 1
            status = "Expired"
        Case imonths > 0
            status = "Expires in " & imonths & " month(s)"
        Case iweeks > 0
            status = "Expires in " & iweeks & " week(s)"
        Case Else
            status = "Expires in " & idays & " day(s)"
    End Select
    CalcExpiry = status
End Function
Arnel, where do any of those case tests get set?
 

Gasman

Enthusiastic Amateur
Local time
Today, 17:38
Joined
Sep 21, 2011
Messages
14,308
Code:
' arnelgp
Public Function CalcExpiry(ByVal dteRenewal As Date) As String
    Dim imonths As Integer, iweeks As Integer, idays As Integer
    Dim status As String
    dteRenewal = DateAdd("m", 3, dteRenewal)
    idays = DateDiff("d", Date, dteRenewal)
    iweeks = DateDiff("ww", Date, dteRenewal)
    imonths = DateDiff("m", Date, dteRenewal)
    Select Case True
        Case idays < 1
            status = "Expired"
        Case imonths > 0
            status = "Expires in " & imonths & " month(s)"
        Case iweeks > 0
            status = "Expires in " & iweeks & " week(s)"
        Case Else
            status = "Expires in " & idays & " day(s)"
    End Select
    CalcExpiry = status
End Function
Sneaky :) rofl
 

HillTJ

To train a dog, first know more than the dog..
Local time
Today, 05:38
Joined
Apr 1, 2019
Messages
731
Friends, thanks. Will give arnelgp's module a go & let this thread know.

Appreciate the prompt response.
 

Gasman

Enthusiastic Amateur
Local time
Today, 17:38
Joined
Sep 21, 2011
Messages
14,308
Friends, thanks. Will give arnelgp's module a go & let this thread know.

Appreciate the prompt response.
Do pass the value as a date though, as that is what the function expects.
 

Gasman

Enthusiastic Amateur
Local time
Today, 17:38
Joined
Sep 21, 2011
Messages
14,308
I would also be careful where you define the conJetDate?
I had mine in the declarations section of a module.
You have yours in the function, and whilst that function is Public, I do not think the Const is available elsewhere?

A quick test
Code:
Public Function fnTestConst(dtDate As Date) As String
Const conDate = "\#mm\/dd\/yyyy\#"
Debug.Print "dtDate is " & Format(dtDate, conDate)
End Function

produces
Code:
fntestconst(date)
dtDate is #10/03/2022#
? format(date,condate)
03/10/2022
 
Last edited:

HillTJ

To train a dog, first know more than the dog..
Local time
Today, 05:38
Joined
Apr 1, 2019
Messages
731
@arnelgp , thanks. Module works well. Only change I made was dteRenewal = DateAdd("yyyy", 3, dteRenewal) - changed "m" to "YYYY" to reflect 3 years. Appreciate your help and appreciate @Gasman's thoroughness.
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Tomorrow, 00:38
Joined
May 7, 2009
Messages
19,245
you can also add the Year option?
Code:
Public Function CalcExpiry(ByVal dteRenewal As Date) As String
    Dim iyears As Integer, imonths As Integer, iweeks As Integer, idays As Integer
    Dim status As String
    dteRenewal = DateAdd("yyyy", 3, dteRenewal)
    iyears = DateDiff("yyyy", Date, dteRenewal)
    idays = DateDiff("d", Date, dteRenewal)
    iweeks = DateDiff("ww", Date, dteRenewal)
    imonths = DateDiff("m", Date, dteRenewal)
    Select Case True
        Case idays < 1
            status = "Expired"
        Case iyears > 0
            status = "Expires in " & iyears & " year(s)"
        Case imonths > 0
            status = "Expires in " & imonths & " month(s)"
        Case iweeks > 0
            status = "Expires in " & iweeks & " week(s)"
        Case Else
            status = "Expires in " & idays & " day(s)"
    End Select
    CalcExpiry = status
End Function
 

Users who are viewing this thread

Top Bottom