Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Accepting Only a Single Digit.
Written by Allen Wyatt (last updated June 10, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Rich wonders how he can configure Excel so that when he enters a single digit it will automatically advance to the next cell. He wants to eliminate hitting Enter or Tab to get to the next cell. The value of the entry for a range of cells will always be a single positive digit.
This cannot be done with any native configuration setting in Excel. Instead, you will need to create a macro that will handle the entry for you. A natural choice for the macro is to use the Change event for the worksheet, so that any time a value is entered into a cell, the entry is "pulled apart" and stuffed in cells in the row.
Private Sub Worksheet_Change(ByVal Target As Range) If IsNumeric(Target.Value) Then CRow = Target.Row CColumn = Target.Column - 1 Entry = Target.Value For i = 1 To Len(Entry) Cells(CRow, CColumn + i).Value = Mid(Entry, i, 1) Next End If End Sub
This macro checks, first, to see if what was entered is numeric. If it is, then the digits are extracted from the value and placed in consecutive cells in the row.
The drawback to such a macro, of course, is that you still need to press Enter to trigger the event. If you want to get away from pressing Enter entirely, then you will need to rely upon a different approach. This technique relies upon the OnKey function to assign macros to specific keystrokes. Place the following code into a standard macro module.
Sub Assigns() Dim i As Variant With Application For i = 0 To 9 .OnKey i, "dig" & i Next End With End Sub
Sub ClearAssigns() Dim i As Variant With Application For i = 0 To 9 .OnKey i Next End With End Sub
Sub dig0() ActiveCell.Value = 0 ActiveCell.Offset(1, 0).Select End Sub
Sub dig1() ActiveCell.Value = 1 ActiveCell.Offset(1, 0).Select End Sub
Sub dig2() ActiveCell.Value = 2 ActiveCell.Offset(1, 0).Select End Sub
Sub dig3() ActiveCell.Value = 3 ActiveCell.Offset(1, 0).Select End Sub
Sub dig4() ActiveCell.Value = 4 ActiveCell.Offset(1, 0).Select End Sub
Sub dig5() ActiveCell.Value = 5 ActiveCell.Offset(1, 0).Select End Sub
Sub dig6() ActiveCell.Value = 6 ActiveCell.Offset(1, 0).Select End Sub
Sub dig7() ActiveCell.Value = 7 ActiveCell.Offset(1, 0).Select End Sub
Sub dig8() ActiveCell.Value = 8 ActiveCell.Offset(1, 0).Select End Sub
Sub dig9() ActiveCell.Value = 9 ActiveCell.Offset(1, 0).Select End Sub
To start the macro, run the Assigns macro. Thereafter, every time a digit is typed the digit is stuffed into the current cell and the next cell to the right selected. If you type in text, then nothing happens. (Of course, if you try to enter a mixed value, such as B2B, then when you press "2" that is what will end up in the cell.) When you are done with this type of data entry, run the ClearAssigns macro to finish up.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12276) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Accepting Only a Single Digit.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Excel has a great (and little known) shortcut for filling a column with information. It comes in very handy when you need ...
Discover MoreUsing the mouse to select a large cell range can be frustratingly slow. If you want to make copying to a large range of ...
Discover MoreHave you ever copied information from one worksheet to another, only to have the information you paste not look the way ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-06-12 10:03:36
J. Woolley
If you really want to use the single digit technique described in the Tip and implemented in my earliest comment below, perhaps there would be less trouble if you restrict it to the numeric keypad in combination with the Ctrl key, for example. In this case, modify the Assigns macro in my first comment as follows:
Sub Assigns()
Dim i As Integer, proc As String, key As String
For i = 0 To 9
proc = "'Dig(" & i & ")'" 'apostrophes are necessary
key = "^{" & (96 + i) & "}" 'Ctrl+numeral on numeric keypad
Application.OnKey key, proc
Next i
End Sub
Then make a similar change to the ClearAssigns macro. Notice the caret (^) represents the Ctrl key.
2023-06-11 18:04:06
J. Woolley
@Willy Vanhaelen
In my previous comment I said, "Also, the Tip's Assigns macro does not work as expected because OnKey expects text parameters." Now I believe the original macro's problem can be resolved by replacing this statement
.OnKey i, "dig" & i
with the following statement
.OnKey i, "'dig" & i & "'"
Although not mentioned in Microsoft's document, it is important to surround the OnKey procedure with apostrophes.
2023-06-11 15:49:04
J. Woolley
The Tip's ten dig# macros have a common issue: To select the "next cell to the right" (instead of down), replace this statement
ActiveCell.Offset(1, 0).Select
with the following statement
ActiveCell.Offset(0, 1).Select
Also, the Tip's Assigns macro does not work as expected because OnKey expects text parameters. Finally, the ten OnKey events addressed by the Tip's Assigns and ClearAssigns macros only apply to numerals above the alpha keys on the keyboard, not to numerals on the numeric keypad.
Here's an improved version of the Tip's macros with 12 procedures replaced by 3 servicing 20 OnKey events (counting the numeric keypad):
Sub Assigns()
Dim i As Integer, proc As String, key As String
For i = 0 To 9
proc = "'Dig(" & i & ")'" 'apostrophes are necessary
key = i 'numeral above alpha keys
Application.OnKey key, proc
key = "{" & (96 + i) & "}" 'numeral on numeric keypad
Application.OnKey key, proc
Next i
End Sub
Sub ClearAssigns()
Dim i As Integer, key As String
For i = 0 To 9
key = i 'numeral above alpha keys
Application.OnKey key
key = "{" & (96 + i) & "}" 'numeral on numeric keypad
Application.OnKey key
Next
End Sub
Sub Dig(arg As Byte)
ActiveCell.Value = arg
ActiveCell.Offset(0, 1).Select
End Sub
Although not mentioned in Microsoft's document, the OnKey procedure should be surrounded by apostrophes for reliable results.
2023-06-11 12:25:10
Willy Vanhaelen
I have an application where I could use the OnKeys macros. So I tested the macros of this tip but they don't do the job. I get the following error:
(see Figure 1 below)
So I started to experiment because at first sight there is nothing wrong with the macros and normally they should work. Finally I found the reason of the error but I can't explain it. Examining the "View Macros box" (Alt+F8) revealed that only the macro dig0 can be executed. The dig1 till dig9 macros are greyed out (disabled). After some trials I got it finally to work by changing the line of code in the For Next loop in the Assigns macro to:
.OnKey i, "Module1.dig" & i
and this works.
So only the first run of the For Next loop is executed and the 9 other runs are ignored. WEIRD !!!
I use Windows 10 and Excel 2019 but I tested it on my laptop with Windows 7 and Excel 2007 with the same result. So it seems to be general except perhaps in versions of Excel prior to 2007. Obviously these macros were not tested again before the tip was published in this week's (10 jun) Excel Tips (ribbon) :-(
Figure 1.
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments