Normally, we build user interfaces so that one button runs one macro. But what if we want the user to select which macro to run? How can we handle that scenario? Well, that’s what we are looking at in this post, how to run any macro from one button. Yes, you heard me. One button can every macro in the workbook.
Table of Contents
Download the example file: Join the free Insiders Program and gain access to the example file used for this post.
File name: 0138 Any macro from button.zip
Watch the video:
Example
For this post, we are working with the following example.
The workbook contains 4 macros.
- toggleGridlines – Toggles the gridlines on/off
- createSheet – Creates a new worksheet
- colorCell – Changes the cell color of the selected range
- messageBox – Displays a message box
What those macros do is irrelevant, as you will use the techniques on your macros. But I need something to demonstrate the technique. So, for completeness, here are the codes in the example file.
Private Sub toggleGridlines()
ActiveWindow.DisplayGridlines = Not ActiveWindow.DisplayGridlines
End Sub
Private Sub createSheet()
Sheets.Add after:=ActiveSheet
End Sub
Private Sub colorCell()
ActiveCell.Interior.Color = RGB(22, 82, 46)
End Sub
Private Sub messageBox()
MsgBox myMessage
End Sub
In our example, we want the user to select the macro to run from a data validation list.

Cell C2 contains a data validation list, which is populated based on cell E6:E9.
Cell F2 contains the following lookup formula to return the corresponding Macro Name from cells F6:F9.
=INDEX(F6:F9,MATCH(C2,E6:E9,0))
So, when a user selects a value in cell C2, cell F2 changes to display the corresponding macro name.
The magic macro code
Now that’s set up, we need to add another macro into the workbook. This is the macro that does all the work. It doesn’t look like much, but it’s magic.
Sub magicMacro()
Dim shapeName As String
Dim macroName As String
Dim cellRef As String
'Get the name of the clicked shape
shapeName = Application.Caller
'Extract the name of the cell reference
cellRef = Right(shapeName, Len(shapeName) - InStr(shapeName, ":"))
'Get the macro name
macroName = ActiveSheet.Range(cellRef).Value
'Run the recipe sheet
Application.Run "'" & ThisWorkbook.Name & "'!" & macroName
End Sub
Create the shape
Now we need to create a shape to act as the button. Insert any shape you like, with any style. I’ve used a robot icon.
Select the shape, then in the Name Box enter Range:F2, press Enter to commit the name.
F2 is the cell containing the macro name.
This may seem random, but trust me on this one.

Assign the shape to the magic macro
Here is where everything comes together.
Right-click on the shape and select Assign Macro… from the menu.
In the Assign Macro dialog box, select the magicMacro, then click OK.

Test it out – Any macro from one button
Select something from the drop-down list, then click the button. Ta-dah! The selected macro runs.
Change the value in the drop-down list, and click the button again. Ta-dah… again! It’s like Magic!
If we add more macros to the workbook, we just need to add them into the data validation list and the lookup formula cells.
How does this work?
You might be wondering how this works?
- When we click the shape to run the magicMacro, the Application.Caller code gives us the name of the shape which we clicked. It returns Range:F2 as text
- From the text Range:F2, we extract the characters after the colon. It returns F2
- The cell value from F2 gives us the name of the macro (toggleGridlines, createSheet, etc.)
- Finally, we use Application.Run to execute the chosen macro
Want to know more about the Application.Run method? Click here.
Conclusion
In this post, we’ve seen how to run any macro from one button. It even works if the macros are private. I hope you can use this to build some nice simple interfaces for your spreadsheets.
Related Posts:
- How to run a macro from a macro (from another workbook)
- Automatically run a Macro when opening a workbook
- Private vs Public Subs, Variables & Functions in VBA
Discover how you can automate your work with our Excel courses and tools.
The Excel Academy

Make working late a thing of the past.
The Excel Academy is Excel training for professionals who want to save time.
‘Tis BRILLIANT… Mark. Thank you for kaking it available.
Great idea, Mark! Thanks for this article.