Adding Items to a Context Menu

by Allen Wyatt
(last updated December 27, 2014)

When you right-click on a cell, Excel provides you with a feature-rich Context menu that allows you to do any number of things. You may want to add some features to that Context menu, particularly if they are features you use often.

Unfortunately, you cannot edit Context menus in the same manner that you can edit other menus—by using Customize from the Tools menu. Instead, you must manipulate Context menus through VBA.

If you want to add an item to the Context menu that appears when you right-click on a cell, you can use the following code:

Sub AddItemToContextMenu()
    Dim cmdNew As CommandBarButton
    Set cmdNew = CommandBars("cell").Controls.Add

    With cmdNew
        .Caption = "My Procedure"
        .OnAction = "MyProcedure"
        .BeginGroup = True
    End With
End Sub

All you need to do is set the .Caption property to whatever menu text you want used, and then change the .OnAction property so that it points to a macro or command you want used. When you later want to remove the menu option, you can use the following macro:

Sub RemoveContextMenuItem()
    On Error Resume Next
    CommandBars("cell").Controls("My Procedure").Delete
End Sub

To use this, change the "My Procedure" text to whatever text you used in the .Caption property of the previous macro. The On Error statement is used in this macro just in case the specified macro item had not been previously added.

By modifying your macro just a bit, you can specify that the addition to the Context menu should occur only when right-clicking on specific cells. The following macro checks to see if you are clicking on a cell in the range of C10:E25. If you are, then it adds a menu option for your procedure at the end of the Context menu.

Private Sub Worksheet_BeforeRightClick(ByVal Target As Range, _
  Cancel As Boolean)
    Dim cmdNew As CommandBarButton

    For Each icbc In Application.CommandBars("cell").Controls
        If icbc.Tag = "brccm" Then icbc.Delete
    Next icbc

    If Not Application.Intersect(Target, Range("c10:e25")) _
      Is Nothing Then
        Set cmdNew = CommandBars("cell").Controls.Add
        With cmdNew
            .Caption = "My Procedure"
            .OnAction = "MyProcedure"
            .BeginGroup = True
            .Tag = "brccm"
        End With
    End If
End Sub

In the VBA editor, this macro needs to be added to the specific worksheet that you want it used with. All you need to do is double-click on that worksheet, in the Project Explorer (upper-left corner of the VBA editor), and then enter it into the code window for that worksheet.

As with the earlier macro, all you need to do is modify the settings specified for the .Caption and .OnAction properties. In addition, you may want to change the cell range that is considered "valid" when adding a menu choice—just change the "c:10:e25" range specification to the range desired. You can even use a named range in place of the cell range, which is great if your valid range is really a set of non-contiguous cells.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2064) applies to Microsoft Excel 97, 2000, 2002, and 2003.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Can't Merge Alphanumeric Data Correctly

When you merge data from Excel into a Word document, you may need to do some conditional processing based on the data you are ...

Discover More

Defining Styles

Styles are a powerful component of Word. You use them to determine the way that your text should appear. This tip explains ...

Discover More

Understanding the For ... Next Structure

Part of the power of VBA is being able to control when some of your code executes and when it doesn't. A primary way to do ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

MORE EXCELTIPS (MENU)

Resetting Excel Menus

Excel allows you to easily change what appears on its menus. If you later want to return to Excel's default menu structure, ...

Discover More

Changing the Shortcut Menu

If you want to change the Context menus used in Excel, on purpose, here's how to go about it. Just create a macro and make ...

Discover More

Resetting Dynamic Menus

Excel's menus, by default, only display the most common commands that you use. After a time you may want to reset the usage ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)

This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.

Links and Sharing
Share