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, and 2016. You can find a version of this tip for the older menu interface of Excel here: Accepting Only a Single Digit.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Excel allows you to reference data in other workbooks by establishing links to that data. If you later want to get rid of ...
Discover MoreYou may be looking for a way to have a formula determine if a particular cell has anything in it. Here's how you can find ...
Discover MoreWhen you type information into a cell, Excel tries to figure out what type of information you are entering. If Excel can ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2017-01-03 13:35:48
Jon
The problem I had was that the names of the macros dig1(), dig2(), etc, were clashing with something else, don't know what, and so they were not being created by the Assign() macro.
So I changed the macro names to digit1(), digit() and all worked OK - for the alpha keys 0 - 9.
To get the numbers on the numeric keypad to work I added this to the Assign() macro:
Dim j As Variant
With Application
For j = 96 To 105
.OnKey "{" & j & "}", "digit" & j
Next
End With
I also added this to the ClearAssigns() macro:
Dim j As Variant
With Application
For j = 96 To 105
.OnKey "{" & j & "}"
Next
End With
(I guess you could both assignments in one loop if you wanted.)
This works as the codes for the 0 - 9 numeric keys are as follows:
0 {96}
1 {97}
2 {98}
3 {99}
4 {100}
5 {101}
6 {102}
7 {103}
8 {104}
9 {105}
2017-01-03 05:14:06
Michael (Micky) Avidan
@Chuck,
Will yolu suggestion eliminate the need of hitting Enter or Tab to get to the next cell ?!
--------------------------
Michael (Micky) Avidan
“Microsoft®” MVP – Excel (2009-2017)
ISRAEL
2017-01-02 18:57:36
Chuck
Much easier with data validation....
2017-01-01 19:20:22
Peter Atherton
Jon
Use this for the Assigns macro
Sub Assigns()
Dim i As Variant
With Application
Select Case i
Case Is = 1
.OnKey 1, "dig1"
Case Is = 2
.OnKey 1, "dig2"
Case Is = 3
.OnKey 1, "dig3"
Case Is = 4
.OnKey 1, "dig4"
Case Is = 5
.OnKey 1, "dig5"
Case Is = 6
.OnKey 1, "dig6"
Case Is = 7
.OnKey 1, "dig7"
Case Is = 8
.OnKey 1, "dig8"
Case Is = 9
.OnKey 1, "dig9"
Case Is = 0
.OnKey 1, "dig0"
End Select
End With
End Sub
There is a caveat, if you use the Alpha keyboard the the macro insert a zero. This problems does not occur with the numeric keypad.
Regards
2016-12-31 08:49:22
Jon
I get this error message when typing keys 1 through 9 (pressing 2 in this particular case):
Cannot run the macro "C:......!dig2" The macro may not be available in this workbook or all the macros may be disabled.
It works fine when pressing 0.
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 © 2021 Sharon Parq Associates, Inc.
Comments