How to hide/unhide columns based on month chosen form a drop down list

Grev1

New Member
Joined
Dec 29, 2021
Messages
3
Office Version
  1. 365
Platform
  1. Windows
Hi, I am trying to complete an attendance sheet by automatically hiding any column that is not in the month chosen. The drop down list is in cell B6 which is the months of the year (Date formatted to mmmm) and the days of the year are in D6:NE6.
I am trying to use the code below but nothing happens, I am not too familiar with VBA just what I've learned from googling and Youtube. Any help is greatly appreciated.

Private Sub Worksheet_SelectionChange(ByVal Target As Range)
If Range("B6").Value = "January" Then
Columns("D:AH").EntireColumn.Hidden = False
Columns("AI:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "February" Then
Columns("D:AH").EntireColumn.Hidden = True
Columns("AI:BJ").EntireColumn.Hidden = False
Columns("BK:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "March" Then
Columns("D:BJ").EntireColumn.Hidden = True
Columns("BK:CO").EntireColumn.Hidden = False
Columns("CP:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "April" Then
Columns("D:CO").EntireColumn.Hidden = True
Columns("CP:DS").EntireColumn.Hidden = False
Columns("DT:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "May" Then
Columns("D:DS").EntireColumn.Hidden = True
Columns("DT:EX").EntireColumn.Hidden = False
Columns("EY:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "June" Then
Columns("D:EX").EntireColumn.Hidden = True
Columns("EY:GB").EntireColumn.Hidden = False
Columns("GC:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "July" Then
Columns("D:GB").EntireColumn.Hidden = True
Columns("GC:HG").EntireColumn.Hidden = False
Columns("HH:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "August" Then
Columns("D:HG").EntireColumn.Hidden = True
Columns("HH:IL").EntireColumn.Hidden = False
Columns("IM:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "September" Then
Columns("D:IL").EntireColumn.Hidden = True
Columns("IM:JP").EntireColumn.Hidden = False
Columns("JQ:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "October" Then
Columns("D:JP").EntireColumn.Hidden = True
Columns("JQ:KU").EntireColumn.Hidden = False
Columns("KV:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "November" Then
Columns("D:KU").EntireColumn.Hidden = True
Columns("KV:LY").EntireColumn.Hidden = False
Columns("LZ:NE").EntireColumn.Hidden = True
ElseIf Range("B6").Value = "December" Then
Columns("D:LY").EntireColumn.Hidden = True
Columns("LZ:NE").EntireColumn.Hidden = False
Else
Columns("D:NE").EntireColumn.Hidden = False
End If
End Sub
 
I would recommend a change event, as already mentioned, rather than a selection change. In which case you could use
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   If Target.CountLarge > 1 Then Exit Sub
   If Target.Address(0, 0) = "B6" Then
      Columns("D:NE").Hidden = False
      Select Case Format(Target.Value, "mmmm")
         Case "January"
            Columns("AI:NE").EntireColumn.Hidden = True
         Case "February"
            Columns("D:AH").EntireColumn.Hidden = True
            Columns("BK:NE").EntireColumn.Hidden = True
         Case "March"
            Columns("D:BJ").EntireColumn.Hidden = True
            Columns("CP:NE").EntireColumn.Hidden = True
         Case "April"
            Columns("D:CO").EntireColumn.Hidden = True
            Columns("DT:NE").EntireColumn.Hidden = True
         Case "May"
            Columns("D:DS").EntireColumn.Hidden = True
            Columns("EY:NE").EntireColumn.Hidden = True
         Case "June"
            Columns("D:EX").EntireColumn.Hidden = True
            Columns("GC:NE").EntireColumn.Hidden = True
         Case "July"
            Columns("D:GB").EntireColumn.Hidden = True
            Columns("HH:NE").EntireColumn.Hidden = True
         Case "August"
            Columns("D:HG").EntireColumn.Hidden = True
            Columns("IM:NE").EntireColumn.Hidden = True
         Case "September"
            Columns("D:IL").EntireColumn.Hidden = True
            Columns("JQ:NE").EntireColumn.Hidden = True
         Case "October"
            Columns("D:JP").EntireColumn.Hidden = True
            Columns("KV:NE").EntireColumn.Hidden = True
         Case "November"
            Columns("D:KU").EntireColumn.Hidden = True
            Columns("LZ:NE").EntireColumn.Hidden = True
         Case "December"
            Columns("D:LY").EntireColumn.Hidden = True
      End Select
   End If
End Sub
 
Upvote 0

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Try it like
VBA Code:
Select Case Format(Target.Value, "mmmm")
This and changing it to worksheet_change worked! Thank you all so much, this has been wrecking my head for weeks now.
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,991
Messages
6,122,628
Members
449,095
Latest member
bsb1122

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