Disabling All Function Keys Except One

Written by Allen Wyatt (last updated April 27, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


2

When someone is using Lorenzo's workbook, he would like only the F2 key to be accessible to the user. He wonders if there is a way to disable all the function keys in Excel, with the exception of the F2 key?

There is a way, but it must be done using macros. Specifically, you'll want to use the OnKey method of the Application object. This code will disable all the function keys with the exception of F2:

Private Sub Workbook_Open()
    Application.OnKey "{F1}", ""
    Application.OnKey "{F3}", ""
    Application.OnKey "{F4}", ""
    Application.OnKey "{F5}", ""
    Application.OnKey "{F6}", ""
    Application.OnKey "{F7}", ""
    Application.OnKey "{F8}", ""
    Application.OnKey "{F9}", ""
    Application.OnKey "{F10}", ""
    Application.OnKey "{F11}", ""
    Application.OnKey "{F12}", ""
End Sub

The macro must be added to the ThisWorkbook module and it will run automatically when the workbook is opened. If desired, you could make the macro a bit shorter:

Private Sub Workbook_Open()
    Dim sTemp As String
    Dim J As Integer

    For J = 1 to 12
        If J <> 2 Then
            sTemp = "{F" & Trim(Str(J)) & "}"
            Application.OnKey sTemp, ""
        End If
    Next J
End Sub

You'll want to also make sure that when you close the workbook that you re-enable all the function keys. This macro, again, should be added to the ThisWorkbook module:

Private Sub Workbook_BeforeClose(CANCEL As Boolean)
    Application.OnKey "{F1}"
    Application.OnKey "{F3}"
    Application.OnKey "{F4}"
    Application.OnKey "{F5}"
    Application.OnKey "{F6}"
    Application.OnKey "{F7}"
    Application.OnKey "{F8}"
    Application.OnKey "{F9}"
    Application.OnKey "{F10}"
    Application.OnKey "{F11}"
    Application.OnKey "{F12}"
End Sub

You could also use a shorter version of the same code:

Private Sub Workbook_BeforeClose(CANCEL As Boolean)
    Dim sTemp As String
    Dim J As Integer

    For J = 1 to 12
        If J <> 2 Then
            sTemp = "{F" & Trim(Str(J)) & "}"
            Application.OnKey sTemp
        End If
    Next J
End Sub

There are a couple of caveats to using these macros. First, realize that the only thing that is disabled are the function keys themselves. Variations on the function keys that use combinations of Shift, Alt, and Ctrl are not affected. Second, once the function keys have been disabled, they are disabled for all workbooks you may have open at the time.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13523) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.

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

Understanding Paragraph Alignment

One of the most basic ways to align paragraphs is to set the alignment used for the text in the paragraph. Word provides ...

Discover More

Deriving Monthly Median Values

When processing huge amounts of data, it can be a challenge to figure out how to derive the aggregate values you need. ...

Discover More

Changing How Changes are Noted in Word

Do you want to modify how Word marks changes in your document? It's easy to do, if you know where to look.

Discover More

Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!

More ExcelTips (ribbon)

Trouble Recording Paste Special Formula

Sometimes, when you upgrade to a new version of Excel, you could run into a problem recording macros that you had no ...

Discover More

Replacing Letters with Numbers

If you have a text string that contains both letters and numbers and you want to convert those letters to numbers ...

Discover More

Finding Positions of Formatted Characters in a Cell

With a little bit of work, Excel allows you to format individual characters of the text you place in a cell. If you want ...

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

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is five more than 1?

2024-04-27 11:37:07

J. Woolley

The Tip's macros include the following statement:
    sTemp = "{F" & Trim(Str(J)) & "}"
VBA's Str(Number) function returns a String (text) representation of Number (numeric). A leading space is always reserved for the sign of Number. If Number is positive, the returned string contains a leading space and the plus sign is implied. Therefore, Trim(Str(J)) is necessary. However, the following statement is simpler because the & operator automatically converts numeric values to text:
    sTemp = "{F" & J & "}"


2024-04-27 06:17:08

Mike J

If you wish to disable/re-program the Shift/Control/Alt versions, just precede the codes in this tip with:

Shift + (plus sign)
Ctrl ^ (caret)
Alt % (percent sign)

For a complete list of codes that can be controlled in this way, see:-

https://learn.microsoft.com/en-us/office/vba/api/excel.application.onkey


This Site

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

Newest Tips
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.