VBA: Hide columns in one sheet, given the result of a dropdown list in another sheet

mlikoudis

New Member
Joined
Aug 14, 2019
Messages
7
Hey guys!

I'm a newbie on VBA and I need some help with a VBA code. Baiscally I have a workbook with several sheets. In one sheet (Summary), I have a dropdown list with all the months in the year (dropdown list is in cell "F9". What I would like to do is that: if Januray is select in the "Summary" sheet, then to hide specific columns of my choosing in the "Deposits" sheet.

I have found online plenty of VBA codes to hide colums based on dropdown list, but all the info is on one sheet (both the dropdown list and the columns to hide are on the same sheet). How do I go about making the VBA so that if there is a change in the "Summary" sheet, to perfom the actions in the "Deposits" sheet?

Thank you for your help
 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
Put this change_event code in the "Summary" sheet.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Not Intersect(Target, Range("F9")) Is Nothing Then
    Application.EnableEvents = False
    With Sheets("Deposits")
        .Cells.EntireColumn.Hidden = False
        .Columns("A").Hidden = True  'Change column letter to suit
        'add other columns here
    End With
    Application.EnableEvents = True
End If
End Sub
 
Upvote 0
You said:
then to hide specific columns of my choosing in the "Deposits" sheet.

How do you plan to this? Do you plan to choose the columns Manually before the script starts?

So if user selects March what column or columns will be hidden on Deposits sheet.
 
Upvote 0
The columns to hide are fixed. By my choosing, I meant that I will set the specific columns to hide depending on the user's month selection. For example: If January, then hide columns A, E, J. If February, B, C G...... And so on
 
Upvote 0
Hi JoeMo!

Thank you for the reply and your help! Correct if I'm wrong, but shouldn't the code include what the will happen depending on the value from the dropdown selection? The code setup you presented seems fine, but isn't it missing the value of F9? (example: if F9 = "January" Then hide columns A,B,D. If F9 = February, Then Hide colums C, E G. And so on......)

Put this change_event code in the "Summary" sheet.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Not Intersect(Target, Range("F9")) Is Nothing Then
    Application.EnableEvents = False
    With Sheets("Deposits")
        .Cells.EntireColumn.Hidden = False
        .Columns("A").Hidden = True  'Change column letter to suit
        'add other columns here
    End With
    Application.EnableEvents = True
End If
End Sub
 
Upvote 0
I could help you but still not sure I see a trend.


You said:
If January, then hide columns A, E, J. If February, B, C G...... And so on

I do not see a trend here.




 
Upvote 0
Hi JoeMo!Top

Thank you for the reply and your help! Correct if I'm wrong, but shouldn't the code include what the will happen depending on the value from the dropdown selection? The code setup you presented seems fine, but isn't it missing the value of F9? (example: if F9 = "January" Then hide columns A,B,D. If F9 = February, Then Hide colums C, E G. And so on......)
Sure, but you didn't provide much information on that so I provided a framework that obviously needs some additions, but only you know what combinations of months and columns should be in play.
 
Upvote 0
With the limited information you have provide.
Try this for January and February

You should be able to do the other Months.

This is an auto sheet event script
Your Workbook must be Macro enabled
To install this code:
Right-click on the sheet tab
Select View Code from the pop-up context menu
Paste the code in the VBA edit window
Put this script in sheet named Summary.

When you change a value in Sheets Summary Range("F9") the script will run.

You will need to have a sheet named "Deposits"

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
'Modified  8/16/2019  4:17:26 PM  EDT
If Target.Cells.CountLarge > 1 Or IsEmpty(Target) Then Exit Sub
    If Target.Address = Range("F9").Address Then
    With Sheets("Deposits")
        Select Case Target.Value
            Case "January"
                .Range("A1,E1, J1").EntireColumn.Hidden = True
            Case "February"
                .Range("B1,C1, G1").EntireColumn.Hidden = True
            'Add more  here
            End Select
    End With
End If
End Sub
 
Upvote 0
Allow Me to rephrase what I need by actually giving specifications:

I have to 2 sheets in a workbook. One sheet is named "Summary" and the other sheet is named "Deposits"

The sheet "Summary" has a dropdown list in cell F9 with the following selections: January, February, March, Q1, April, May, June, Q2, July, August, September, Q3, October, November, December, Q4.
The sheet "Deposits" contains columns with data relating to its respective month, as well as columns for the names of the accounts.

What I would like to do is automate the following:

If "January" is selected from the drop down menu (from the "Summary" sheet), then to hide the columns E and H:BS (from the "Deposits" sheet)
If "February" is selected from the drop down menu (from the "Summary" sheet), then to hide the columns E, G and I:BS (from the "Deposits" sheet)
If "March" is selected from the drop down menu (from the "Summary" sheet), then to hide the columns E, G:H and J:BS (from the "Deposits" sheet)
If "Q1" is selected from the drop down menu (from the "Summary" sheet), then to hide the columns E, G:I and K:BS (from the "Deposits" sheet)
And so on until Q4

Basically I want to hide the columns relating to the other months

I'm sorry if I didn't explain it clearly earlier. I was trying to keep my description in general terms so I can simply use the structure/concept of the code to my needs
 
Upvote 0
I tried the code and it doesn't hide any columns... Perhaps I need to enable something?

Also, for my own personal education (so I can learn): Why start the code with the following: If Target.Cells.CountLarge > 1 Or IsEmpty(Target) Then Exit Sub

With the limited information you have provide.
Try this for January and February

You should be able to do the other Months.

This is an auto sheet event script
Your Workbook must be Macro enabled
To install this code:
Right-click on the sheet tab
Select View Code from the pop-up context menu
Paste the code in the VBA edit window
Put this script in sheet named Summary.

When you change a value in Sheets Summary Range("F9") the script will run.

You will need to have a sheet named "Deposits"

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
'Modified  8/16/2019  4:17:26 PM  EDT
If Target.Cells.CountLarge > 1 Or IsEmpty(Target) Then Exit Sub
    If Target.Address = Range("F9").Address Then
    With Sheets("Deposits")
        Select Case Target.Value
            Case "January"
                .Range("A1,E1, J1").EntireColumn.Hidden = True
            Case "February"
                .Range("B1,C1, G1").EntireColumn.Hidden = True
            'Add more  here
            End Select
    End With
End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,954
Messages
6,175,603
Members
452,660
Latest member
Zatman

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