Get our FREE VBA eBook of the 30 most useful Excel VBA macros.

Automate Excel so that you can save time and stop doing the jobs a trained monkey could do.

Claim your free eBook


How to run any macro from one button (magic macro)

One Button Any Macro

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.

Download the example file: Click the link below to download the example file used for this post:

Watch the video:

Watch the video on YouTube

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.

Example workbook

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.

Create the shape and rename - run any macro from one button

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.

Assign the macro

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:


Headshot Round

About the author

Hey, I’m Mark, and I run Excel Off The Grid.

My parents tell me that at the age of 7 I declared I was going to become a qualified accountant. I was either psychic or had no imagination, as that is exactly what happened. However, it wasn't until I was 35 that my journey really began.

In 2015, I started a new job, for which I was regularly working after 10pm. As a result, I rarely saw my children during the week. So, I started searching for the secrets to automating Excel. I discovered that by building a small number of simple tools, I could combine them together in different ways to automate nearly all my regular tasks. This meant I could work less hours (and I got pay raises!). Today, I teach these techniques to other professionals in our training program so they too can spend less time at work (and more time with their children and doing the things they love).


Do you need help adapting this post to your needs?

I'm guessing the examples in this post don't exactly match your situation. We all use Excel differently, so it's impossible to write a post that will meet everybody's needs. By taking the time to understand the techniques and principles in this post (and elsewhere on this site), you should be able to adapt it to your needs.

But, if you're still struggling you should:

  1. Read other blogs, or watch YouTube videos on the same topic. You will benefit much more by discovering your own solutions.
  2. Ask the 'Excel Ninja' in your office. It's amazing what things other people know.
  3. Ask a question in a forum like Mr Excel, or the Microsoft Answers Community. Remember, the people on these forums are generally giving their time for free. So take care to craft your question, make sure it's clear and concise.  List all the things you've tried, and provide screenshots, code segments and example workbooks.
  4. Use Excel Rescue, who are my consultancy partner. They help by providing solutions to smaller Excel problems.

What next?
Don't go yet, there is plenty more to learn on Excel Off The Grid.  Check out the latest posts:

Leave a Reply

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