RSS

Userform with calendar - no ActiveX, just VBA

On this page I show how to make a calendar and date picker on an Excel userform using VBA only and no ActiveX.

This is how it looks in the Danish version of Excel 2003:

Calendar

In the U.S.A (English), where the first day of the week is Sunday and not Monday, the "day labels" from left to right will be SU, MO, TU, WE, TH, FR and SA, and February 1st 2016 will be in the second column, below MO.

In other words it is sensitive to the system's language and first day of the week settings. The possible date formats are also based on the system settings.

By using VBA only and no ActiveX you avoid compatibility problems, because different MS Office versions use different ActiveX controls for calendars.

You can use the calendar to select (up to) two dates for whatever purpose you want. The selected dates are put in two labels, and if you click one of these labels, you can copy the date to a cell or a range of cells.

I show and explain some of the macros below, but I cannot show them all. If you want to see the rest, you can download a zip compressed workbook with the example.

The workbook was updated with a minor bug fix February 26th 2017.

The calendar is on a userform (see image above) with a frame, labels, combo boxes and command buttons.

For event handling (when the user selects a date) the calendar uses a simple class module instead of writing a click procedure for each and every date label.

Of course it also uses quite a few date functions like getting the first day of the week, first day of the month, weekday names in the user's language, checking for leap year etc.

I am a lousy designer, so change the userform's look as you like; but unless you change the code, the labels for date picking must all be in Frame1.

The Collections

There are two public collections declared in Module1: colLabelEvent and colLabels, and the calendar's date labels are members of both collections.

colLabelEvent is a collection of the event handler classes for the labels, and colLabels enables us to change the properties of each label like e.g.: colLabels.Item(variable for label name).Visible = False

We'll get back to the event handling class - it is really not complicated.

The userform's Initialize procedure

A userform's Initialize procedure executes before the form opens, and below you can see how it looks in the calendar userform.


Private Sub UserForm_Initialize()
'This procedure executes before
'the userform opens.
Dim ctl As Control               'Userform control variable
Dim lCount As Long               'Counter
Dim InputLblEvt As clLabelClass  'Temporary class

On Error GoTo ErrorHandle

'The collections colLabelEvent and colLabels
'are declared in Module1.
'colLabelEvent is a collection of classes,
'clLabelClasses, that control the event
'driven action, when a date label is clicked.
'colLabels is a collection of the date labels
'used for identifying labels, setting their
'properties and more.
Set colLabelEvent = New Collection
Set colLabels = New Collection

'Loop through the date labels in Frame1
'and add them to the collections.
For Each ctl In Frame1.Controls
   'If the control element is a label
   If TypeOf ctl Is MSForms.Label Then
      'Make a new instance of the clLabel class
      Set InputLblEvt = New clLabelClass
      
      'and assign it to this Label
      Set InputLblEvt.InputLabel = ctl
      
      'which we add to the collection, colLabelEvent.
      'Any click event on a label (day) in Frame1
      'will now be handled by the class,
      'because it declares:
      'Public WithEvents InputLabel As MSForms.Label
      'That way we avoid writing click events for
      'every label.
      colLabelEvent.Add InputLblEvt
      
      'and to the colLabels collection
      colLabels.Add ctl, ctl.Name
   End If
Next

'We have no use for InputLblEvent anymore
'and set it to Nothing to save memory.
Set InputLblEvt = Nothing

'Add month names to the month combobox.
'By using the VBA function MonthName it
'will automatically be in the user's
'language as defined in the country
'settings.
For lCount = 1 To 12
   With cmbMonth
      .AddItem MonthName(lCount)
   End With
Next

'Add years to the years combo box. VBA doesn't
'handle older years than 1900.
For lCount = 1900 To Year(Now) + 100
   With cmbYear
      .AddItem lCount
   End With
Next

'Weekday labels to local settings (first day of the week) and language.
'If for instance the country is the USA and the language is English,
'the first day of the week will be Sunday, and the labels from left to
'right will say: "SU" "MO" "TU" "WE" "TH" "FR" "SA"
'The VBA function StrConv(String,1) converts to upper case.
lblDay1.Caption = StrConv(Left(WeekdayName(1, , vbUseSystemDayOfWeek), 2), 1)
lblDay2.Caption = StrConv(Left(WeekdayName(2, , vbUseSystemDayOfWeek), 2), 1)
lblDay3.Caption = StrConv(Left(WeekdayName(3, , vbUseSystemDayOfWeek), 2), 1)
lblDay4.Caption = StrConv(Left(WeekdayName(4, , vbUseSystemDayOfWeek), 2), 1)
lblDay5.Caption = StrConv(Left(WeekdayName(5, , vbUseSystemDayOfWeek), 2), 1)
lblDay6.Caption = StrConv(Left(WeekdayName(6, , vbUseSystemDayOfWeek), 2), 1)
lblDay7.Caption = StrConv(Left(WeekdayName(7, , vbUseSystemDayOfWeek), 2), 1)

'Tag the labels. The tags are used by clLabelClass to check,
'if a date is in the selected month, the previous or next.
With colLabels
   For lCount = 1 To .Count
      .Item(lCount).Tag = lCount
   Next
End With

'The LabelCaptions procedure will arrange
'the calendar's look depending on month and year.
LabelCaptions Month(Now), Year(Now)

'Possible date formats
With cmbDateFormat
   .AddItem Format(Now, "Long Date")
   .AddItem Format(Now, "Medium Date")
   .AddItem Format(Now, "Short Date")
   .Text = Format(Now, "Short Date")
End With

'Find the system settings for sequence of day
'and month.
lDayPos = Day("01-02-03")
lMonthPos = Month("01-02-03")

Exit Sub
ErrorHandle:
MsgBox Err.Description
End Sub

The Initialize procedure ended by calling the LabelCaptions procedure passing two arguments, namely the present month and year.

The LabelCaptions procedure does several things that determine the look of the calendar, and it is called every time the user changes month or year.

It checks stuff like the number of days in the month, where to put the first date according to the first day of the week, it finds the first day of the month and more. Here is how it looks:


Sub LabelCaptions(lMonth As Long, lYear As Long)
Dim lCount As Long            'Counter
Dim lNumber As Long           'Counter
Dim lMonthPrev As Long        'Previous month
Dim lDaysPrev As Long         'Days in previous month
Dim lYearPrev As Long         'Previous year

'Get the month name from the month number
sMonth = MonthName(lMonth)

'Save month number in variable
lSelMonth = lMonth

'Save year in variable
lSelYear = lYear

'Prepare for getting days in previous month
Select Case lMonth
   Case 2 To 11
      lMonthPrev = lMonth - 1
      lYearPrev = lYear
   Case 1
      lMonthPrev = 12
      lYearPrev = lYear - 1
   Case 12
      lMonthPrev = 11
      lYearPrev = lYear
End Select

'Days in month (function call - see below)
lDays = DaysInMonth(lMonth, lYear)
'Days in previous month
lDaysPrev = DaysInMonth(lMonthPrev, lYearPrev)

'If it is Jan. 1900 the
'back button is disabled.
If lSelYear >= 1900 And lSelMonth > 1 Then
   lblBack.Enabled = True
ElseIf lSelYear = 1900 And lSelMonth = 1 Then
   lblBack.Enabled = False
End If

'If this wasn't started by a selection
'in one of the combo boxes (month, year).
If bCmbSel = False Then
   cmbMonth.Text = sMonth
   cmbYear.Text = lYear
End If

'Find the first date in the month.
lFirstDayInMonth = DateSerial(lSelYear, lSelMonth, 1)

'Find the weekday number using local settings for
'first day of the week. We want to know if it is a
'Monday etc. for putting the first day of the month
'in the right weekday position.
'The first day of a week varies from country to country.
'In USA it is Sunday, in Denmark it is Monday.
'So we use vbUseSystemDayOfWeek to get the local settings.
lFirstDayInMonth = Weekday(lFirstDayInMonth, vbUseSystemDayOfWeek)

If lFirstDayInMonth = 1 Then
   lStartPos = 8
Else
   lStartPos = lFirstDayInMonth
End If

'Days from previous month if the
'first day in the month is not a monday.
lNumber = lDaysPrev + 1
For lCount = lStartPos - 1 To 1 Step -1
   lNumber = lNumber - 1
   With colLabels.Item(lCount)
      .Caption = lNumber
      .ForeColor = &HE0E0E0
   End With
Next

'The labels/buttons for the days of the month.
lNumber = 0
For lCount = lStartPos To lDays + lStartPos - 1
   lNumber = lNumber + 1
   With colLabels.Item(lCount)
      .Caption = lNumber
      .ForeColor = &H80000012
   End With
Next

'The days (labels) in next month
lNumber = 0
For lCount = lDays + lStartPos To 42
   lNumber = lNumber + 1
   With colLabels.Item(lCount)
      .Caption = lNumber
      .ForeColor = &HE0E0E0
   End With
Next

End Sub

Below is the function that finds the number of days in the selected month. It is quite simple.


Function DaysInMonth(lMonth As Long, lYear As Long) As Long

'Number of days in month
Select Case lMonth
   Case 1, 3, 5, 7, 8, 10, 12
      DaysInMonth = 31
   Case 2
      'Leap year?
      If IsDate("29/2/" & lYear) = False Then
         DaysInMonth = 28
      Else
         DaysInMonth = 29
      End If
   Case Else
      DaysInMonth = 30
End Select

End Function

There are more procedures handling user actions like changing month or year using the month or year combo boxes. That is more or less trivial stuff, and you can see the code, if you download the workbook.

The most important thing left is the label event handling class.

The event handling class

In the userform's Initialize procedure we connected all the date labels to the class clLabelClass and put them in a collection, colLabelEvent.

The user picks a date by clicking a date label, and if you didn't have the class handling this event, you would have to write a click procedure for each end every label. Now all clicks are handled by the class module code below.

The code uses some Public variables like sActiveDay declared im Module1.


Option Explicit

'By declaring Public WithEvents we can handle
'events "collectively". In this case it is
'the click event on a date label, and by
'doing it this way we avoid writing click
'events for each and every date label.
Public WithEvents InputLabel As MSForms.Label
Private Sub InputLabel_click()

'We change the look of the selected day
With InputLabel
   'If previous month
   If .Tag < lStartPos Then
      If UserForm1.lblBack.Enabled = True Then
         UserForm1.lblBack_Click
      End If
      Exit Sub
   End If
   If .Tag > lDays + lStartPos - 1 Then
      UserForm1.lblForward_Click
      Exit Sub
   End If
   'If selected already, we exit
   If .BorderColor = vbBlue Then Exit Sub
   
   .BorderColor = vbBlue
   .BorderStyle = fmBorderStyleSingle

   'If another day was chosen before this
   'one, we make that label look normal.
   If Len(sActiveDay) > 0 Then
      If sActiveDay <> InputLabel.Name Then
         With colLabels.Item(sActiveDay)
            .BorderColor = &H8000000E
            .BorderStyle = fmBorderStyleNone
         End With
      End If
   End If
   sActiveDay = InputLabel.Name
   lFirstDay = Val(InputLabel.Caption)
   
   'If a second date has not been selected
   If bSecondDate = False Then
      UserForm1.FillFirstDay
   Else
      'If it is the second date selected
      UserForm1.FillSecondDay
   End If
End With

End Sub

That was the most important parts of the calendar's code. To see the rest, download the workbook.

The selected date or dates will be in two labels on the user form, but internally they are stored in the variables datFirstDay and datLastDay (declared on module level in the userform).

A date or dates can be used in many ways, and you can put your own code in the OK button's click procedure.

As sample code I find the difference in days between the two dates and display it in a message box, before the form closes. You can just replace that with your own code.

By picking my birthday and the day I write this, I can see, that I have lived for 21979 days. Time sure flies ...

Related: