Would like to make edits to VBA Calendar Code

  • Thread starter Thread starter Legacy 352679
  • Start date Start date
L

Legacy 352679

Guest
G'day everyone,

Found a really nifty calendar code online, but would like to make a few edits to it and I'm unsure how to do so.

VBA Code:
 Sub CalendarMaker()

       ' Unprotect sheet if had previous calendar to prevent error.
       ActiveSheet.Protect DrawingObjects:=False, Contents:=False, _
          Scenarios:=False
       ' Prevent screen flashing while drawing calendar.
       Application.ScreenUpdating = False
       ' Set up error trapping.
       On Error GoTo MyErrorTrap
       ' Clear area a1:g14 including any previous calendar.
       Range("a1:g14").Clear
       ' Use InputBox to get desired month and year and set variable
       ' MyInput.
       MyInput = InputBox("Type in Month and year for Calendar ")
       ' Allow user to end macro with Cancel in InputBox.
       If MyInput = "" Then Exit Sub
       ' Get the date value of the beginning of inputted month.
       StartDay = DateValue(MyInput)
       ' Check if valid date but not the first of the month
       ' -- if so, reset StartDay to first day of month.
       If Day(StartDay) <> 1 Then
           StartDay = DateValue(Month(StartDay) & "/1/" & _
               Year(StartDay))
       End If
       ' Prepare cell for Month and Year as fully spelled out.
       Range("a1").NumberFormat = "mmmm yyyy"
       ' Center the Month and Year label across a1:g1 with appropriate
       ' size, height and bolding.
       With Range("a1:g1")
           .HorizontalAlignment = xlCenterAcrossSelection
           .VerticalAlignment = xlCenter
           .Font.Size = 18
           .Font.Bold = True
           .RowHeight = 35
       End With
       ' Prepare a2:g2 for day of week labels with centering, size,
       ' height and bolding.
       With Range("a2:g2")
           .ColumnWidth = 11
           .VerticalAlignment = xlCenter
           .HorizontalAlignment = xlCenter
           .VerticalAlignment = xlCenter
           .Orientation = xlHorizontal
           .Font.Size = 12
           .Font.Bold = True
           .RowHeight = 20
       End With
       ' Put days of week in a2:g2.
       Range("a2") = "Sunday"
       Range("b2") = "Monday"
       Range("c2") = "Tuesday"
       Range("d2") = "Wednesday"
       Range("e2") = "Thursday"
       Range("f2") = "Friday"
       Range("g2") = "Saturday"
       ' Prepare a3:g7 for dates with left/top alignment, size, height
       ' and bolding.
       With Range("a3:g8")
           .HorizontalAlignment = xlRight
           .VerticalAlignment = xlTop
           .Font.Size = 18
           .Font.Bold = True
           .RowHeight = 21
       End With
       ' Put inputted month and year fully spelling out into "a1".
       Range("a1").Value = Application.Text(MyInput, "mmmm yyyy")
       ' Set variable and get which day of the week the month starts.
       DayofWeek = Weekday(StartDay)
       ' Set variables to identify the year and month as separate
       ' variables.
       CurYear = Year(StartDay)
       CurMonth = Month(StartDay)
       ' Set variable and calculate the first day of the next month.
       FinalDay = DateSerial(CurYear, CurMonth + 1, 1)
       ' Place a "1" in cell position of the first day of the chosen
       ' month based on DayofWeek.
       Select Case DayofWeek
           Case 1
               Range("a3").Value = 1
           Case 2
               Range("b3").Value = 1
           Case 3
               Range("c3").Value = 1
           Case 4
               Range("d3").Value = 1
           Case 5
               Range("e3").Value = 1
           Case 6
               Range("f3").Value = 1
           Case 7
               Range("g3").Value = 1
       End Select
       ' Loop through range a3:g8 incrementing each cell after the "1"
       ' cell.
       For Each cell In Range("a3:g8")
           RowCell = cell.Row
           ColCell = cell.Column
           ' Do if "1" is in first column.
           If cell.Column = 1 And cell.Row = 3 Then
           ' Do if current cell is not in 1st column.
           ElseIf cell.Column <> 1 Then
               If cell.Offset(0, -1).Value >= 1 Then
                   cell.Value = cell.Offset(0, -1).Value + 1
                   ' Stop when the last day of the month has been
                   ' entered.
                   If cell.Value > (FinalDay - StartDay) Then
                       cell.Value = ""
                       ' Exit loop when calendar has correct number of
                       ' days shown.
                       Exit For
                   End If
               End If
           ' Do only if current cell is not in Row 3 and is in Column 1.
           ElseIf cell.Row > 3 And cell.Column = 1 Then
               cell.Value = cell.Offset(-1, 6).Value + 1
               ' Stop when the last day of the month has been entered.
               If cell.Value > (FinalDay - StartDay) Then
                   cell.Value = ""
                   ' Exit loop when calendar has correct number of days
                   ' shown.
                   Exit For
               End If
           End If
       Next

       ' Create Entry cells, format them centered, wrap text, and border
       ' around days.
       For x = 0 To 5
           Range("A4").Offset(x * 2, 0).EntireRow.Insert
           With Range("A4:G4").Offset(x * 2, 0)
               .RowHeight = 65
               .HorizontalAlignment = xlCenter
               .VerticalAlignment = xlTop
               .WrapText = True
               .Font.Size = 10
               .Font.Bold = False
               ' Unlock these cells to be able to enter text later after
               ' sheet is protected.
               .Locked = False
           End With
           ' Put border around the block of dates.
           With Range("A3").Offset(x * 2, 0).Resize(2, _
           7).Borders(xlLeft)
               .Weight = xlThick
               .ColorIndex = xlAutomatic
           End With

           With Range("A3").Offset(x * 2, 0).Resize(2, _
           7).Borders(xlRight)
               .Weight = xlThick
               .ColorIndex = xlAutomatic
           End With
           Range("A3").Offset(x * 2, 0).Resize(2, 7).BorderAround _
              Weight:=xlThick, ColorIndex:=xlAutomatic
       Next
       If Range("A13").Value = "" Then Range("A13").Offset(0, 0) _
          .Resize(2, 8).EntireRow.Delete
       ' Turn off gridlines.
       ActiveWindow.DisplayGridlines = False
       ' Protect sheet to prevent overwriting the dates.
       ActiveSheet.Protect DrawingObjects:=True, Contents:=True, _
          Scenarios:=True

       ' Resize window to show all of calendar (may have to be adjusted
       ' for video configuration).
       ActiveWindow.WindowState = xlMaximized
       ActiveWindow.ScrollRow = 1

       ' Allow screen to redraw with calendar showing.
       Application.ScreenUpdating = True
       ' Prevent going to error trap unless error found by exiting Sub
       ' here.
       Exit Sub
   ' Error causes msgbox to indicate the problem, provides new input box,
   ' and resumes at the line that caused the error.
MyErrorTrap:
       MsgBox "You may not have entered your Month and Year correctly." _
           & Chr(13) & "Spell the Month correctly" _
           & " (or use 3 letter abbreviation)" _
           & Chr(13) & "and 4 digits for the Year"
       MyInput = InputBox("Type in Month and year for Calendar")
       If MyInput = "" Then Exit Sub
       Resume
   End Sub

I would like, rather than 1 cell to enter data in, to have 5 cells under each day, and keep the general formatting (table lines etc) the same. Would anyone be able to explain how to achieve this?
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
These lines are inserting 1 entry row below each row of day numbers and formatting the 1 entry row:

VBA Code:
           Range("A4").Offset(x * 2, 0).EntireRow.Insert
           With Range("A4:G4").Offset(x * 2, 0)

The Offset x * 2 increases by 2 rows (the row of day numbers + the number of entry rows) each time through the loop.

You want 5 entry rows to be inserted and formatted and therefore the Offset needs to increase by 6 rows (the row of day numbers + the number of entry rows) therefore change those lines to:

VBA Code:
        Range("A4").Offset(x * 6, 0).Resize(5).EntireRow.Insert
        With Range("A4:G4").Offset(x * 6, 0).Resize(5)

Each border code should then be:
VBA Code:
        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlLeft)

Other changes are needed to reflect the increased number of rows the calendar is using.
 
Upvote 0
These lines are inserting 1 entry row below each row of day numbers and formatting the 1 entry row:

VBA Code:
           Range("A4").Offset(x * 2, 0).EntireRow.Insert
           With Range("A4:G4").Offset(x * 2, 0)

The Offset x * 2 increases by 2 rows (the row of day numbers + the number of entry rows) each time through the loop.

You want 5 entry rows to be inserted and formatted and therefore the Offset needs to increase by 6 rows (the row of day numbers + the number of entry rows) therefore change those lines to:

VBA Code:
        Range("A4").Offset(x * 6, 0).Resize(5).EntireRow.Insert
        With Range("A4:G4").Offset(x * 6, 0).Resize(5)

Each border code should then be:
VBA Code:
        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlLeft)

Other changes are needed to reflect the increased number of rows the calendar is using.
I'll give this a crack, but thank you for taking the time to explain and respond!
 
Upvote 0
These lines are inserting 1 entry row below each row of day numbers and formatting the 1 entry row:

VBA Code:
           Range("A4").Offset(x * 2, 0).EntireRow.Insert
           With Range("A4:G4").Offset(x * 2, 0)

The Offset x * 2 increases by 2 rows (the row of day numbers + the number of entry rows) each time through the loop.

You want 5 entry rows to be inserted and formatted and therefore the Offset needs to increase by 6 rows (the row of day numbers + the number of entry rows) therefore change those lines to:

VBA Code:
        Range("A4").Offset(x * 6, 0).Resize(5).EntireRow.Insert
        With Range("A4:G4").Offset(x * 6, 0).Resize(5)

Each border code should then be:
VBA Code:
        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlLeft)

Other changes are needed to reflect the increased number of rows the calendar is using.
G'day mate,

Unfortunately the changes you proposed did not work. It did not end up creating cells under each respective day, rather it created 5x blank cells under the generated calendar.
 
Upvote 0
Post your code.
My apologies, some of the errors were me missing the other range edits I needed to make.

However I have just encountered a different issue. Please find the code and an image of what it has produced.
I have omitted the last row of dates as I didn't want to make the capture too small. Just note that there is no thick line at the bottom where the calendar ends.

I am not sure why dates between 3 - 9 have less cells.

I would also like to eliminate the cell (example A4) that sits just under the number representing the day for each day, as this may seem confusing when I want to enter in data. Again, not quite sure how to achieve this.

VBA Code:
 Sub CalendarMaker()

       ' Unprotect sheet if had previous calendar to prevent error.
       ActiveSheet.Protect DrawingObjects:=False, Contents:=False, _
          Scenarios:=False
       ' Prevent screen flashing while drawing calendar.
       Application.ScreenUpdating = False
       ' Set up error trapping.
       On Error GoTo MyErrorTrap
       ' Clear area a1:g14 including any previous calendar.
       Range("a1:g14").Clear
       ' Use InputBox to get desired month and year and set variable
       ' MyInput.
       MyInput = InputBox("Type in Month and year for Calendar ")
       ' Allow user to end macro with Cancel in InputBox.
       If MyInput = "" Then Exit Sub
       ' Get the date value of the beginning of inputted month.
       StartDay = DateValue(MyInput)
       ' Check if valid date but not the first of the month
       ' -- if so, reset StartDay to first day of month.
       If Day(StartDay) <> 1 Then
           StartDay = DateValue(Month(StartDay) & "/1/" & _
               Year(StartDay))
       End If
       ' Prepare cell for Month and Year as fully spelled out.
       Range("a1").NumberFormat = "mmmm yyyy"
       ' Center the Month and Year label across a1:g1 with appropriate
       ' size, height and bolding.
       With Range("a1:g1")
           .HorizontalAlignment = xlCenterAcrossSelection
           .VerticalAlignment = xlCenter
           .Font.Size = 18
           .Font.Bold = True
           .RowHeight = 35
       End With
       ' Prepare a2:g2 for day of week labels with centering, size,
       ' height and bolding.
       With Range("a2:g2")
           .ColumnWidth = 11
           .VerticalAlignment = xlCenter
           .HorizontalAlignment = xlCenter
           .VerticalAlignment = xlCenter
           .Orientation = xlHorizontal
           .Font.Size = 12
           .Font.Bold = True
           .RowHeight = 20
       End With
       ' Put days of week in a2:g2.
       Range("a2") = "Sunday"
       Range("b2") = "Monday"
       Range("c2") = "Tuesday"
       Range("d2") = "Wednesday"
       Range("e2") = "Thursday"
       Range("f2") = "Friday"
       Range("g2") = "Saturday"
       ' Prepare a3:g7 for dates with left/top alignment, size, height
       ' and bolding.
       With Range("a3:g8")
           .HorizontalAlignment = xlRight
           .VerticalAlignment = xlTop
           .Font.Size = 18
           .Font.Bold = True
           .RowHeight = 21
       End With
       ' Put inputted month and year fully spelling out into "a1".
       Range("a1").Value = Application.Text(MyInput, "mmmm yyyy")
       ' Set variable and get which day of the week the month starts.
       DayofWeek = Weekday(StartDay)
       ' Set variables to identify the year and month as separate
       ' variables.
       CurYear = Year(StartDay)
       CurMonth = Month(StartDay)
       ' Set variable and calculate the first day of the next month.
       FinalDay = DateSerial(CurYear, CurMonth + 1, 1)
       ' Place a "1" in cell position of the first day of the chosen
       ' month based on DayofWeek.
       Select Case DayofWeek
           Case 1
               Range("a3").Value = 1
           Case 2
               Range("b3").Value = 1
           Case 3
               Range("c3").Value = 1
           Case 4
               Range("d3").Value = 1
           Case 5
               Range("e3").Value = 1
           Case 6
               Range("f3").Value = 1
           Case 7
               Range("g3").Value = 1
       End Select
       ' Loop through range a3:g8 incrementing each cell after the "1"
       ' cell.
       For Each cell In Range("a3:g8")
           RowCell = cell.Row
           ColCell = cell.Column
           ' Do if "1" is in first column.
           If cell.Column = 1 And cell.Row = 3 Then
           ' Do if current cell is not in 1st column.
           ElseIf cell.Column <> 1 Then
               If cell.Offset(0, -1).Value >= 1 Then
                   cell.Value = cell.Offset(0, -1).Value + 1
                   ' Stop when the last day of the month has been
                   ' entered.
                   If cell.Value > (FinalDay - StartDay) Then
                       cell.Value = ""
                       ' Exit loop when calendar has correct number of
                       ' days shown.
                       Exit For
                   End If
               End If
           ' Do only if current cell is not in Row 3 and is in Column 1.
           ElseIf cell.Row > 3 And cell.Column = 1 Then
               cell.Value = cell.Offset(-1, 6).Value + 1
               ' Stop when the last day of the month has been entered.
               If cell.Value > (FinalDay - StartDay) Then
                   cell.Value = ""
                   ' Exit loop when calendar has correct number of days
                   ' shown.
                   Exit For
               End If
           End If
       Next

       ' Create Entry cells, format them centered, wrap text, and border
       ' around days.
       For x = 0 To 5
                Range("A4").Offset(x * 6, 0).Resize(5).EntireRow.Insert
                With Range("A4:G4").Offset(x * 6, 0).Resize(5)
               .RowHeight = 65
               .HorizontalAlignment = xlCenter
               .VerticalAlignment = xlTop
               .WrapText = True
               .Font.Size = 10
               .Font.Bold = False
               ' Unlock these cells to be able to enter text later after
               ' sheet is protected.
               .Locked = False
           End With
           ' Put border around the block of dates.
           With Range("A3").Offset(x * 6, 0).Resize(6, _
           7).Borders(xlLeft)
               .Weight = xlThick
               .ColorIndex = xlAutomatic
           End With

           With Range("A3").Offset(x * 6, 0).Resize(6, _
           7).Borders(xlRight)
               .Weight = xlThick
               .ColorIndex = xlAutomatic
           End With
           Range("A3").Offset(x * 6, 0).Resize(2, 7).BorderAround _
              Weight:=xlThick, ColorIndex:=xlAutomatic
       Next
       If Range("A13").Value = "" Then Range("A13").Offset(0, 0) _
          .Resize(2, 8).EntireRow.Delete
       ' Turn off gridlines.
       ActiveWindow.DisplayGridlines = False
       ' Protect sheet to prevent overwriting the dates.
       ActiveSheet.Protect DrawingObjects:=True, Contents:=True, _
          Scenarios:=True

       ' Resize window to show all of calendar (may have to be adjusted
       ' for video configuration).
       ActiveWindow.WindowState = xlMaximized
       ActiveWindow.ScrollRow = 1

       ' Allow screen to redraw with calendar showing.
       Application.ScreenUpdating = True
       ' Prevent going to error trap unless error found by exiting Sub
       ' here.
       Exit Sub
   ' Error causes msgbox to indicate the problem, provides new input box,
   ' and resumes at the line that caused the error.
MyErrorTrap:
       MsgBox "You may not have entered your Month and Year correctly." _
           & Chr(13) & "Spell the Month correctly" _
           & " (or use 3 letter abbreviation)" _
           & Chr(13) & "and 4 digits for the Year"
       MyInput = InputBox("Type in Month and year for Calendar")
       If MyInput = "" Then Exit Sub
       Resume
   End Sub
 

Attachments

  • Screenshot 2024-02-14 081530.png
    Screenshot 2024-02-14 081530.png
    7.9 KB · Views: 19
Upvote 0
You missed the BorderAround change and changes to 2 lines because the calendar now ends at row 33 instead of 13.

VBA Code:
Sub CalendarMaker()

    ' Unprotect sheet if had previous calendar to prevent error.
    ActiveSheet.Protect DrawingObjects:=False, Contents:=False, _
       Scenarios:=False
    ' Prevent screen flashing while drawing calendar.
    Application.ScreenUpdating = False
    ' Set up error trapping.
    On Error GoTo MyErrorTrap
    ' Clear area a1:g33 including any previous calendar.
    Range("a1:g33").Clear                                                '<---- HERE
    ' Use InputBox to get desired month and year and set variable
    ' MyInput.
    MyInput = InputBox("Type in Month and year for Calendar ")
    ' Allow user to end macro with Cancel in InputBox.
    If MyInput = "" Then Exit Sub
    ' Get the date value of the beginning of inputted month.
    StartDay = DateValue(MyInput)
    ' Check if valid date but not the first of the month
    ' -- if so, reset StartDay to first day of month.
    If Day(StartDay) <> 1 Then
        StartDay = DateValue(Month(StartDay) & "/1/" & _
            Year(StartDay))
    End If
    ' Prepare cell for Month and Year as fully spelled out.
    Range("a1").NumberFormat = "mmmm yyyy"
    ' Center the Month and Year label across a1:g1 with appropriate
    ' size, height and bolding.
    With Range("a1:g1")
        .HorizontalAlignment = xlCenterAcrossSelection
        .VerticalAlignment = xlCenter
        .Font.Size = 18
        .Font.Bold = True
        .RowHeight = 35
    End With
    ' Prepare a2:g2 for day of week labels with centering, size,
    ' height and bolding.
    With Range("a2:g2")
        .ColumnWidth = 11
        .VerticalAlignment = xlCenter
        .HorizontalAlignment = xlCenter
        .VerticalAlignment = xlCenter
        .Orientation = xlHorizontal
        .Font.Size = 12
        .Font.Bold = True
        .RowHeight = 20
    End With
    ' Put days of week in a2:g2.
    Range("a2") = "Sunday"
    Range("b2") = "Monday"
    Range("c2") = "Tuesday"
    Range("d2") = "Wednesday"
    Range("e2") = "Thursday"
    Range("f2") = "Friday"
    Range("g2") = "Saturday"
    ' Prepare a3:g7 for dates with left/top alignment, size, height
    ' and bolding.
    With Range("a3:g8")
        .HorizontalAlignment = xlRight
        .VerticalAlignment = xlTop
        .Font.Size = 18
        .Font.Bold = True
        .RowHeight = 21
    End With
    ' Put inputted month and year fully spelling out into "a1".
    Range("a1").Value = Application.Text(MyInput, "mmmm yyyy")
    ' Set variable and get which day of the week the month starts.
    DayOfWeek = Weekday(StartDay)
    ' Set variables to identify the year and month as separate
    ' variables.
    CurYear = Year(StartDay)
    CurMonth = Month(StartDay)
    ' Set variable and calculate the first day of the next month.
    FinalDay = DateSerial(CurYear, CurMonth + 1, 1)
    ' Place a "1" in cell position of the first day of the chosen
    ' month based on DayofWeek.
    Select Case DayOfWeek
        Case 1
            Range("a3").Value = 1
        Case 2
            Range("b3").Value = 1
        Case 3
            Range("c3").Value = 1
        Case 4
            Range("d3").Value = 1
        Case 5
            Range("e3").Value = 1
        Case 6
            Range("f3").Value = 1
        Case 7
            Range("g3").Value = 1
    End Select
    ' Loop through range a3:g8 incrementing each cell after the "1"
    ' cell.
    For Each cell In Range("a3:g8")
        RowCell = cell.Row
        ColCell = cell.Column
        ' Do if "1" is in first column.
        If cell.Column = 1 And cell.Row = 3 Then
        ' Do if current cell is not in 1st column.
        ElseIf cell.Column <> 1 Then
            If cell.Offset(0, -1).Value >= 1 Then
                cell.Value = cell.Offset(0, -1).Value + 1
                ' Stop when the last day of the month has been
                ' entered.
                If cell.Value > (FinalDay - StartDay) Then
                    cell.Value = ""
                    ' Exit loop when calendar has correct number of
                    ' days shown.
                    Exit For
                End If
            End If
        ' Do only if current cell is not in Row 3 and is in Column 1.
        ElseIf cell.Row > 3 And cell.Column = 1 Then
            cell.Value = cell.Offset(-1, 6).Value + 1
            ' Stop when the last day of the month has been entered.
            If cell.Value > (FinalDay - StartDay) Then
                cell.Value = ""
                ' Exit loop when calendar has correct number of days
                ' shown.
                Exit For
            End If
        End If
    Next

    ' Create Entry cells, format them centered, wrap text, and border
    ' around days.
    For x = 0 To 5
             Range("A4").Offset(x * 6, 0).Resize(5).EntireRow.Insert
             With Range("A4:G4").Offset(x * 6, 0).Resize(5)
            .RowHeight = 15
            .HorizontalAlignment = xlCenter
            .VerticalAlignment = xlTop
            .WrapText = True
            .Font.Size = 10
            .Font.Bold = False
            ' Unlock these cells to be able to enter text later after
            ' sheet is protected.
            .Locked = False
        End With
        ' Put border around the block of dates.
        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlLeft)
            .Weight = xlThick
            .ColorIndex = xlAutomatic
        End With

        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlRight)
            .Weight = xlThick
            .ColorIndex = xlAutomatic
        End With
        Range("A3").Offset(x * 6, 0).Resize(6, 7).BorderAround Weight:=xlThick, ColorIndex:=xlAutomatic   '<---- HERE
    Next
    If Range("A33").Value = "" Then Range("A33").Resize(6, 8).EntireRow.Delete    '<---- HERE
    ' Turn off gridlines.
    ActiveWindow.DisplayGridlines = False
    ' Protect sheet to prevent overwriting the dates.
    ActiveSheet.Protect DrawingObjects:=True, Contents:=True, _
       Scenarios:=True

    ' Resize window to show all of calendar (may have to be adjusted
    ' for video configuration).
    ActiveWindow.WindowState = xlMaximized
    ActiveWindow.ScrollRow = 1

    ' Allow screen to redraw with calendar showing.
    Application.ScreenUpdating = True
    ' Prevent going to error trap unless error found by exiting Sub
    ' here.
    Exit Sub
' Error causes msgbox to indicate the problem, provides new input box,
' and resumes at the line that caused the error.
MyErrorTrap:
    MsgBox "You may not have entered your Month and Year correctly." _
        & Chr(13) & "Spell the Month correctly" _
        & " (or use 3 letter abbreviation)" _
        & Chr(13) & "and 4 digits for the Year"
    MyInput = InputBox("Type in Month and year for Calendar")
    If MyInput = "" Then Exit Sub
    Resume
End Sub
Entry line row heights reduced to 15.

Is this what you want?

1707865815403.png
 
Upvote 0
I would also like to eliminate the cell (example A4) that sits just under the number representing the day for each day, as this may seem confusing when I want to enter in data. Again, not quite sure how to achieve this.

I've modified the code to lock such entry cells, i.e. they are for dates which fall outside the calendar month. For the 02 2024 calendar above it locks A4:D8 and F28:G32.

VBA Code:
Sub CalendarMaker()

    ' Unprotect sheet if had previous calendar to prevent error.
    ActiveSheet.Protect DrawingObjects:=False, Contents:=False, _
       Scenarios:=False
    ' Prevent screen flashing while drawing calendar.
    Application.ScreenUpdating = False
    ' Set up error trapping.
    On Error GoTo MyErrorTrap
    ' Clear area a1:g33 including any previous calendar.
    Range("a1:g33").Clear                                                '<---- HERE
    ' Use InputBox to get desired month and year and set variable
    ' MyInput.
    MyInput = InputBox("Type in Month and year for Calendar ")
    ' Allow user to end macro with Cancel in InputBox.
    If MyInput = "" Then Exit Sub
    ' Get the date value of the beginning of inputted month.
    StartDay = DateValue(MyInput)
    ' Check if valid date but not the first of the month
    ' -- if so, reset StartDay to first day of month.
    If Day(StartDay) <> 1 Then
        StartDay = DateValue(Month(StartDay) & "/1/" & _
            Year(StartDay))
    End If
    ' Prepare cell for Month and Year as fully spelled out.
    Range("a1").NumberFormat = "mmmm yyyy"
    ' Center the Month and Year label across a1:g1 with appropriate
    ' size, height and bolding.
    With Range("a1:g1")
        .HorizontalAlignment = xlCenterAcrossSelection
        .VerticalAlignment = xlCenter
        .Font.Size = 18
        .Font.Bold = True
        .RowHeight = 35
    End With
    ' Prepare a2:g2 for day of week labels with centering, size,
    ' height and bolding.
    With Range("a2:g2")
        .ColumnWidth = 11
        .VerticalAlignment = xlCenter
        .HorizontalAlignment = xlCenter
        .VerticalAlignment = xlCenter
        .Orientation = xlHorizontal
        .Font.Size = 12
        .Font.Bold = True
        .RowHeight = 20
    End With
    ' Put days of week in a2:g2.
    Range("a2") = "Sunday"
    Range("b2") = "Monday"
    Range("c2") = "Tuesday"
    Range("d2") = "Wednesday"
    Range("e2") = "Thursday"
    Range("f2") = "Friday"
    Range("g2") = "Saturday"
    ' Prepare a3:g7 for dates with left/top alignment, size, height
    ' and bolding.
    With Range("a3:g8")
        .HorizontalAlignment = xlRight
        .VerticalAlignment = xlTop
        .Font.Size = 18
        .Font.Bold = True
        .RowHeight = 21
    End With
    ' Put inputted month and year fully spelling out into "a1".
    Range("a1").Value = Application.Text(MyInput, "mmmm yyyy")
    ' Set variable and get which day of the week the month starts.
    DayOfWeek = Weekday(StartDay)
    ' Set variables to identify the year and month as separate
    ' variables.
    CurYear = Year(StartDay)
    CurMonth = Month(StartDay)
    ' Set variable and calculate the first day of the next month.
    FinalDay = DateSerial(CurYear, CurMonth + 1, 1)
    ' Place a "1" in cell position of the first day of the chosen
    ' month based on DayofWeek.
    
    Select Case DayOfWeek
        Case 1
            Range("a3").Value = 1
        Case 2
            Range("b3").Value = 1
        Case 3
            Range("c3").Value = 1
        Case 4
            Range("d3").Value = 1
        Case 5
            Range("e3").Value = 1
        Case 6
            Range("f3").Value = 1
        Case 7
            Range("g3").Value = 1
    End Select
    ' Loop through range a3:g8 incrementing each cell after the "1"
    ' cell.
    For Each cell In Range("a3:g8")
        RowCell = cell.Row
        ColCell = cell.Column
        ' Do if "1" is in first column.
        If cell.Column = 1 And cell.Row = 3 Then
        ' Do if current cell is not in 1st column.
        ElseIf cell.Column <> 1 Then
            If cell.Offset(0, -1).Value >= 1 Then
                cell.Value = cell.Offset(0, -1).Value + 1
                ' Stop when the last day of the month has been
                ' entered.
                If cell.Value > (FinalDay - StartDay) Then
                    cell.Value = ""
                    ' Exit loop when calendar has correct number of
                    ' days shown.
                    Exit For
                End If
            End If
        ' Do only if current cell is not in Row 3 and is in Column 1.
        ElseIf cell.Row > 3 And cell.Column = 1 Then
            cell.Value = cell.Offset(-1, 6).Value + 1
            ' Stop when the last day of the month has been entered.
            If cell.Value > (FinalDay - StartDay) Then
                cell.Value = ""
                ' Exit loop when calendar has correct number of days
                ' shown.
                Exit For
            End If
        End If
    Next

    Dim SundayDate As Date, c As Long
    SundayDate = StartDay - Weekday(StartDay) + 1

    ' Create Entry cells, format them centered, wrap text, and border
    ' around days.
    For x = 0 To 5
        Range("A4").Offset(x * 6, 0).Resize(5).EntireRow.Insert
        With Range("A4:G4").Offset(x * 6, 0).Resize(5)
            .RowHeight = 15
            .HorizontalAlignment = xlCenter
            .VerticalAlignment = xlTop
            .WrapText = True
            .Font.Size = 10
            .Font.Bold = False
            ' Unlock these cells to be able to enter text later after
            ' sheet is protected.
            .Locked = False
        End With
        ' Put border around the block of dates.
        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlLeft)
            .Weight = xlThick
            .ColorIndex = xlAutomatic
        End With
        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlRight)
            .Weight = xlThick
            .ColorIndex = xlAutomatic
        End With
        Range("A3").Offset(x * 6, 0).Resize(6, 7).BorderAround Weight:=xlThick, ColorIndex:=xlAutomatic   '<---- HERE
        'Relock entry cells whose dates fall outside the month for the 7 days in this week starting Sunday
        For c = 0 To 6
            If SundayDate + c < StartDay Or SundayDate + c > FinalDay - 1 Then
                Range("A4").Offset(x * 6, c).Resize(5).Locked = True
            End If
        Next
        SundayDate = SundayDate + 7
    Next
    If Range("A33").Value = "" Then Range("A33").Resize(6, 8).EntireRow.Delete    '<---- HERE
    ' Turn off gridlines.
    ActiveWindow.DisplayGridlines = False
    ' Protect sheet to prevent overwriting the dates.
    ActiveSheet.Protect DrawingObjects:=True, Contents:=True, _
       Scenarios:=True

    ' Resize window to show all of calendar (may have to be adjusted
    ' for video configuration).
    ActiveWindow.WindowState = xlMaximized
    ActiveWindow.ScrollRow = 1

    ' Allow screen to redraw with calendar showing.
    Application.ScreenUpdating = True
    ' Prevent going to error trap unless error found by exiting Sub
    ' here.
    Exit Sub
' Error causes msgbox to indicate the problem, provides new input box,
' and resumes at the line that caused the error.
MyErrorTrap:
    MsgBox "You may not have entered your Month and Year correctly." _
        & Chr(13) & "Spell the Month correctly" _
        & " (or use 3 letter abbreviation)" _
        & Chr(13) & "and 4 digits for the Year"
    MyInput = InputBox("Type in Month and year for Calendar")
    If MyInput = "" Then Exit Sub
    Resume
End Sub
 
Upvote 0
Solution
I've modified the code to lock such entry cells, i.e. they are for dates which fall outside the calendar month. For the 02 2024 calendar above it locks A4:D8 and F28:G32.

VBA Code:
Sub CalendarMaker()

    ' Unprotect sheet if had previous calendar to prevent error.
    ActiveSheet.Protect DrawingObjects:=False, Contents:=False, _
       Scenarios:=False
    ' Prevent screen flashing while drawing calendar.
    Application.ScreenUpdating = False
    ' Set up error trapping.
    On Error GoTo MyErrorTrap
    ' Clear area a1:g33 including any previous calendar.
    Range("a1:g33").Clear                                                '<---- HERE
    ' Use InputBox to get desired month and year and set variable
    ' MyInput.
    MyInput = InputBox("Type in Month and year for Calendar ")
    ' Allow user to end macro with Cancel in InputBox.
    If MyInput = "" Then Exit Sub
    ' Get the date value of the beginning of inputted month.
    StartDay = DateValue(MyInput)
    ' Check if valid date but not the first of the month
    ' -- if so, reset StartDay to first day of month.
    If Day(StartDay) <> 1 Then
        StartDay = DateValue(Month(StartDay) & "/1/" & _
            Year(StartDay))
    End If
    ' Prepare cell for Month and Year as fully spelled out.
    Range("a1").NumberFormat = "mmmm yyyy"
    ' Center the Month and Year label across a1:g1 with appropriate
    ' size, height and bolding.
    With Range("a1:g1")
        .HorizontalAlignment = xlCenterAcrossSelection
        .VerticalAlignment = xlCenter
        .Font.Size = 18
        .Font.Bold = True
        .RowHeight = 35
    End With
    ' Prepare a2:g2 for day of week labels with centering, size,
    ' height and bolding.
    With Range("a2:g2")
        .ColumnWidth = 11
        .VerticalAlignment = xlCenter
        .HorizontalAlignment = xlCenter
        .VerticalAlignment = xlCenter
        .Orientation = xlHorizontal
        .Font.Size = 12
        .Font.Bold = True
        .RowHeight = 20
    End With
    ' Put days of week in a2:g2.
    Range("a2") = "Sunday"
    Range("b2") = "Monday"
    Range("c2") = "Tuesday"
    Range("d2") = "Wednesday"
    Range("e2") = "Thursday"
    Range("f2") = "Friday"
    Range("g2") = "Saturday"
    ' Prepare a3:g7 for dates with left/top alignment, size, height
    ' and bolding.
    With Range("a3:g8")
        .HorizontalAlignment = xlRight
        .VerticalAlignment = xlTop
        .Font.Size = 18
        .Font.Bold = True
        .RowHeight = 21
    End With
    ' Put inputted month and year fully spelling out into "a1".
    Range("a1").Value = Application.Text(MyInput, "mmmm yyyy")
    ' Set variable and get which day of the week the month starts.
    DayOfWeek = Weekday(StartDay)
    ' Set variables to identify the year and month as separate
    ' variables.
    CurYear = Year(StartDay)
    CurMonth = Month(StartDay)
    ' Set variable and calculate the first day of the next month.
    FinalDay = DateSerial(CurYear, CurMonth + 1, 1)
    ' Place a "1" in cell position of the first day of the chosen
    ' month based on DayofWeek.
   
    Select Case DayOfWeek
        Case 1
            Range("a3").Value = 1
        Case 2
            Range("b3").Value = 1
        Case 3
            Range("c3").Value = 1
        Case 4
            Range("d3").Value = 1
        Case 5
            Range("e3").Value = 1
        Case 6
            Range("f3").Value = 1
        Case 7
            Range("g3").Value = 1
    End Select
    ' Loop through range a3:g8 incrementing each cell after the "1"
    ' cell.
    For Each cell In Range("a3:g8")
        RowCell = cell.Row
        ColCell = cell.Column
        ' Do if "1" is in first column.
        If cell.Column = 1 And cell.Row = 3 Then
        ' Do if current cell is not in 1st column.
        ElseIf cell.Column <> 1 Then
            If cell.Offset(0, -1).Value >= 1 Then
                cell.Value = cell.Offset(0, -1).Value + 1
                ' Stop when the last day of the month has been
                ' entered.
                If cell.Value > (FinalDay - StartDay) Then
                    cell.Value = ""
                    ' Exit loop when calendar has correct number of
                    ' days shown.
                    Exit For
                End If
            End If
        ' Do only if current cell is not in Row 3 and is in Column 1.
        ElseIf cell.Row > 3 And cell.Column = 1 Then
            cell.Value = cell.Offset(-1, 6).Value + 1
            ' Stop when the last day of the month has been entered.
            If cell.Value > (FinalDay - StartDay) Then
                cell.Value = ""
                ' Exit loop when calendar has correct number of days
                ' shown.
                Exit For
            End If
        End If
    Next

    Dim SundayDate As Date, c As Long
    SundayDate = StartDay - Weekday(StartDay) + 1

    ' Create Entry cells, format them centered, wrap text, and border
    ' around days.
    For x = 0 To 5
        Range("A4").Offset(x * 6, 0).Resize(5).EntireRow.Insert
        With Range("A4:G4").Offset(x * 6, 0).Resize(5)
            .RowHeight = 15
            .HorizontalAlignment = xlCenter
            .VerticalAlignment = xlTop
            .WrapText = True
            .Font.Size = 10
            .Font.Bold = False
            ' Unlock these cells to be able to enter text later after
            ' sheet is protected.
            .Locked = False
        End With
        ' Put border around the block of dates.
        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlLeft)
            .Weight = xlThick
            .ColorIndex = xlAutomatic
        End With
        With Range("A3").Offset(x * 6, 0).Resize(6, 7).Borders(xlRight)
            .Weight = xlThick
            .ColorIndex = xlAutomatic
        End With
        Range("A3").Offset(x * 6, 0).Resize(6, 7).BorderAround Weight:=xlThick, ColorIndex:=xlAutomatic   '<---- HERE
        'Relock entry cells whose dates fall outside the month for the 7 days in this week starting Sunday
        For c = 0 To 6
            If SundayDate + c < StartDay Or SundayDate + c > FinalDay - 1 Then
                Range("A4").Offset(x * 6, c).Resize(5).Locked = True
            End If
        Next
        SundayDate = SundayDate + 7
    Next
    If Range("A33").Value = "" Then Range("A33").Resize(6, 8).EntireRow.Delete    '<---- HERE
    ' Turn off gridlines.
    ActiveWindow.DisplayGridlines = False
    ' Protect sheet to prevent overwriting the dates.
    ActiveSheet.Protect DrawingObjects:=True, Contents:=True, _
       Scenarios:=True

    ' Resize window to show all of calendar (may have to be adjusted
    ' for video configuration).
    ActiveWindow.WindowState = xlMaximized
    ActiveWindow.ScrollRow = 1

    ' Allow screen to redraw with calendar showing.
    Application.ScreenUpdating = True
    ' Prevent going to error trap unless error found by exiting Sub
    ' here.
    Exit Sub
' Error causes msgbox to indicate the problem, provides new input box,
' and resumes at the line that caused the error.
MyErrorTrap:
    MsgBox "You may not have entered your Month and Year correctly." _
        & Chr(13) & "Spell the Month correctly" _
        & " (or use 3 letter abbreviation)" _
        & Chr(13) & "and 4 digits for the Year"
    MyInput = InputBox("Type in Month and year for Calendar")
    If MyInput = "" Then Exit Sub
    Resume
End Sub
I just tested it and this seems to address all the issues that I wanted resolved. Thank you for continuing to help me. I'm not sure I learnt much but at least I have a product I can use.
 
Upvote 0

Forum statistics

Threads
1,224,811
Messages
6,181,081
Members
453,021
Latest member
Justyna P

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top