This post may contain affiliate links. Please read my disclosure for more info.
Advertisement:

Assign macro with arguments to a Form Control button

Macro with arguments button

Macro with arguments button

One of the most popular methods of running a macro is having a button on the face of the worksheet.  These are simple enough to create with the basic Form Controls found on the Developer Ribbon, which is what makes them a popular option.

But what if you had lots of buttons, all of which did a similar thing apart from a few different variables, arguments or parameters?  One option is writing separate code for each button, or a second option maybe a big If statement to handle the logic for all the buttons.  But please don’t do either of those, that would be crazy.

To pass an argument to a macro just requires the right syntax when assigning the macro to the button.

 

The Example

For the purposes of proving how this works, here is our example scenario.  There are two Listboxes, each containing a list, with a button below each.   Whenever the button is clicked, the count of items in the Listbox above it is displayed in a message box.

Example scenario

Lets consider how we can achieve this in the most efficient way possible.

 

Setting up the VBA code

I will assume you already know how to create a button and assign a macro to it.

If we had created separate code for each button, then the VBA code for clicking the button below the lstBox1 would be as follows:

Sub lstBoxCount()

Dim ws As Worksheet
Dim lstBoxName As String
Dim lstBox As ListBox

Set ws = Sheets("Sheet1")
lstBoxName = "lstBox1"
Set lstBox = ws.ListBoxes(lstBoxName)

MsgBox lstBox.ListCount

End Sub

If you notice, the sheet name and Listbox name are hardcoded into the macro, therefore we would need one macro for each button.  Now imagine we had 30 Listboxes and 30 buttons… that would require 30 macros!  Bad idea.

This is where arguments are useful.  We can pass the worksheet name and Listbox name into the macro as arguments, by doing this, we can use a single piece of VBA code.

Sub lstBoxCount(wsName As String, lstBoxName As String)

Dim ws As Worksheet
Dim lstBox As ListBox

Set ws = Sheets(wsName)
Set lstBox = ws.ListBoxes(lstBoxName)

MsgBox lstBox.ListCount

End Sub

The code above can be used with any ListBox.  There are no hardcoded variables within the code; they are passed to the code when it is called.


Advertisement:

 

Running a macro with arguments

Having created a macro with arguments in the previous section, it raises a few new issues when assigning it to a button.

  1. The macro does not appear in the list of available macros.  We can still use the macro, but we have to know it’s name.
  2. We need to know the right syntax to pass the arguments to the macro

We can handle both of these issue; no big deal.

The syntax required to a call a macro from the same workbook is:

'NameOfMacro "variable1", "variable2"'

Take careful note of where the single quotes, double quotes, commas and spaces are.  There is nothing to help us complete this, apart from an error message to taunt us when we’ve got it wrong.

Assign Macro with aruments error message

To call our lstBoxCount macro from above, the text in the Assign Macro window would be:

lstBoxCount "Sheet1", "ListBox1"'

Assign Macro with arguments - entry

Where Sheet1 is the name of the worksheet and ListBox1 is the name of the first ListBox.

The same macro could be called from the second button, but the arguments would be different. Notice below the Listbox name has changed.

'lstBoxCount "Sheet1", "ListBox2"'

We can now use the same VBA code no matter how many Listboxes there are, or which worksheets they are on.  We just change the values in the arguments.

 

Passing Numbers as arguments

If passing a number as an argument do not surround it in double quotes.

'NameOfMacro "textInQuotes", 1000'

 

Assigning a macro from another workbook

When returning to the Assign Macro window, you will notice Excel has added the name of the workbook into the Macro name box.


Advertisement:

Assign Macro with arguments - entry different workbook

'Name of workbook.xlsm'!'lstBoxCount "Sheet1", "lstBox1"'

At first, this may seem annoying.  But Excel is helping us here, as this is now displaying the syntax required to call a macro from another workbook.

'Name of worksheet.xlsm'!'NameOfMacro "variable1", "variable2"'

 

Running a macro with arguments based on a cell value

So far we have assumed we know the arguments when creating the buttons.  That might not be the case; maybe the argument is based on a cell value.  But that is OK too; we can dynamically pass a cell value into the macro at the point the button is clicked by assigning a macro using the following syntax.

'NameOfMacro "variable1", EVALUATE("A1")'

The example above assume the argument is contained in Cell A1.  Once again, take careful note of where the single and double quotes are.

Using our specific example.  Let’s assume the name of the Listbox is contained in Cell B2:

'lstBoxCount "Sheet1", EVALUATE("B2")'

Assign Macro with arguments - from spreadsheet

This will work too!  Cool, eh?

 

Wrapping it all up

Hopefully, you see this is very powerful and being able to set arguments based on a cell value is simply amazing.  You no longer need lots of buttons.  Instead, a drop-down box and one button might be sufficient.



Want to Learn VBA & Macros?

If you want to automate Excel and save time, my recommended resouces for learning VBA Macros are:

Leave a Reply

Your email address will not be published. Required fields are marked *