Use one macro for multiple buttons to hide individual columns

288enzo

Well-known Member
Joined
Feb 8, 2009
Messages
721
Office Version
  1. 2016
Platform
  1. Windows
I have 12 buttons across E3:P3. Each button would run the same macro "Hide", which simply hides the column. I know I could create 12 separate macros for each button. How can I have one macro "Hide" and for it to know which button the user clicked on thus knowing which column to hide? Each button is named button 1, 2, 3, and so on. So, if my macro "Hide" knew that Button2 was pressed then it would hide columns("F"). I just can't figure out how to pass the name of the button to the "Hide" macro. I thought if I could pass it on I then could use Case Select?

What I came up with to create the buttons is:
VBA Code:
    Dim i As Long, rng As Range
    Set rng = Range("E3")
    For i = 1 To 12
        ActiveSheet.Buttons.Add(rng.Offset(0, i - 1).Left, rng.Offset(0, i - 1).Top, rng.Offset(0, i - 1).Width, rng.Offset(0, i - 1).Height).Select
        Selection.OnAction = "Hide"
        Selection.Characters.Text = "Hide"
        Selection.Name = "Button" & i
    Next i
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
It just occurred to me that the title for my question could be much better.

How do I pass a variable from a button?

I thought this would work, am I getting close?
VBA Code:
Sub Hide()

Dim col As String

col = ActiveSheet.Buttons(Application.Caller).Name

Select Case col
    Case button1
        Columns("E").EntireColumn.Hidden = True
    Case button2
        Columns("F").EntireColumn.Hidden = True
End Select

End Sub
 
Upvote 0
Got it. I was missing the quotation marks.
VBA Code:
Sub Hide()

Dim col As String

col = ActiveSheet.Buttons(Application.Caller).Name

Select Case col
    Case "Button1"
        Columns("E").EntireColumn.Hidden = True
    Case "Button2"
        Columns("F").EntireColumn.Hidden = True
End Select

End Sub
 
Upvote 0
Well, that sort of worked. It got me half way there.

The problem I just came to find out is, if I click on button1 and hide column E, then button2 is now technically on column E but is set to hide column F if clicked. I haven't the foggiest idea where to go from here? It seems to be very complicated, to keep calculating if button1, 3, 4, 6 were pressed, then if button 5 is also pressed which column is it actually on that will hide that same column? Ugh. I was so excited for a moment :(

Thoughts?

Thank you
 
Upvote 0
I found a way to do it, instead of using .Name, I used the location .Left
VBA Code:
Dim col As String

col = ActiveSheet.Buttons(Application.Caller).Left

Select Case col
    Case 192
        Columns("E").EntireColumn.Hidden = True
    Case 240
        Columns("F").EntireColumn.Hidden = True
    Case 288
        Columns("G").EntireColumn.Hidden = True

' and so on
End Select
I'm all eyes if there is a better way. I'm a sponge right now.
 
Upvote 0
Do you have to use buttons to trigger the macro? Also, how do you unhide the columns if you need to afterwards?
 
Upvote 0
I found a way to do it, instead of using .Name, I used the location .Left
VBA Code:
Dim col As String

col = ActiveSheet.Buttons(Application.Caller).Left

Select Case col
    Case 192
        Columns("E").EntireColumn.Hidden = True
    Case 240
        Columns("F").EntireColumn.Hidden = True
    Case 288
        Columns("G").EntireColumn.Hidden = True

' and so on
End Select
I'm all eyes if there is a better way. I'm a sponge right now.
Well, that didn't work either :(
 
Upvote 0
Do you have to use buttons to trigger the macro? Also, how do you unhide the columns if you need to afterwards?
I was going to create one master "unhide" button. I don't have to use a button, I just didn't think of anything else to get the job done. I want to give the users an option to easily hide any column they want.
 
Upvote 0
I'd be tempted to use a Worksheet.SelectionChange event to trigger the macro. Something like:

VBA Code:
Option Explicit
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
If Not Intersect(Me.Range("E3:P3"), Target) Is Nothing Then
    Selection.Columns.Hidden = True
End If
End Sub

That would hide the column if the user selected any cell in the range E3:P3, and a simple Sub to unhide all the hidden columns:

VBA Code:
Sub unhideColumns()
    ActiveSheet.Cells.Columns.Hidden = False
End Sub

With a shortcut key such as Ctrl+u to run it.
 
Upvote 0
See if the following works for you (you can assign macros to shapes as well):
VBA Code:
Sub AddButtons()
    Dim i As Long, rng As Range
    Set rng = Range("E3")
    For i = 1 To 12
        With ActiveSheet.Buttons.Add(rng.Offset(0, i - 1).Left + 1, rng.Offset(0, i - 1).Top + 1, rng.Offset(0, i - 1).Width - 2, rng.Offset(0, i - 1).Height - 2)
            .OnAction = "Hide"
            .Characters.Text = "Hide"
            .Name = "Button" & i
        End With
    Next i
End Sub
Sub Hide()
    ActiveSheet.Buttons(Application.Caller).TopLeftCell.EntireColumn.Hidden = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,606
Messages
6,120,492
Members
448,967
Latest member
visheshkotha

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