Disabling All Function Keys Except One

by Allen Wyatt
(last updated December 10, 2018)

3

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

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13523) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 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

Dissecting a String

Want to pull a string apart in a macro? It's easy using the string functions introduced in this tip.

Discover More

Pulling Initial Letters from a String

When working with names or a different series of words, you may need to pull the initial letters from each word in the ...

Discover More

Excel 2007 Graphics and Charts (Table of Contents)

Excel allows you to add all sorts of graphics to your worksheets or to convert your data into meaningful charts. Here's ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Finding Other Instances of Excel in a Macro

When processing information using a macro, you may need to know if there are any other instances of Excel running on a ...

Discover More

Resetting Default Names for New Worksheets

When you add a new worksheet to a workbook, Excel gives it a default name that consists of "Sheet" followed by a number. ...

Discover More

Understanding Subroutines

When developing macros, you can create subroutines. This is a great way to reuse common code and make your programming ...

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}] 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 7 + 9?

2018-05-06 12:46:38

Willy Vanhaelen

@Bob
That is not correct. If you don't reset the keys, they stay disabled as long as the current session of Excel runs and they even are disabled in any other workbook(s) you opened or will open in that session. So it can be pretty annoying to use this because as long as the workbook containing these macros is not closed these function key are not available in ai all other open workbooks of that session.


2018-05-06 01:44:32

Bob

I found that it was unnecessary to reset the function keys on worksheet closure. It went back to defaults on closure because we were using worksheet macro.


2018-05-05 11:25:16

Willy Vanhaelen

Be aware that the macros in this tip only disable the function keys pressed alone.
Combinations with Ctrl, Alt and Shift are still possible (and there are a lot of them).


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.