Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Automatically Moving from Cell to Cell when Entering Data.
Written by Allen Wyatt (last updated April 3, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Sheila has a worksheet in which a series of four-digit numbers needs to be entered. She would like a way where Enter or Tab doesn't need to be pressed between each entry. In other words, after each fourth digit is pressed, Sheila wants Excel to automatically advance to the next cell.
Excel does not provide this type of data entry as an option. You can, however, create a macro to handle the data entry. One way is to us a simple macro that prompts the user for a string of characters. When the user presses Enter (to signify that the string is complete), then the macro takes each successive four-character chunk and puts them in consecutive cells.
Sub FourCharEntry1() Dim str As String Dim x As Integer Dim y As Integer str = InputBox("Enter string") y = 0 For x = 1 To Len(str) Step 4 ActiveCell.Offset(0, y) = "'" & Mid(str, x, 4) y = y + 1 Next End Sub
Notice that the macro, as it is putting four-character chunks into cells, makes sure that each chunk is preceded by an apostrophe. The reason for this is to handle those instances when the four-character chunk may consist of only numbers and those numbers begin with one or more zeroes. Adding the apostrophe makes sure that Excel treats the cell entry as text and the leading zeroes won't be wiped out.
You could, as well, avoid the use of an InputBox by simply allowing someone to enter text into a cell in the worksheet. The person could type away as much as desired (thousands of characters, if necessary). Then, with the cell selected, you could run a macro that will pull the information from the cell and perform the same task—breaking it up into four-character chunks. The following macro does just that:
Sub FourCharEntry2() Dim str As String Dim x As Integer Dim y As Integer str = ActiveCell.Value y = 0 For x = 1 To Len(str) Step 4 ActiveCell.Offset(0, y) = "'" & Mid(str, x, 4) y = y + 1 Next End Sub
Another approach is to use a custom user form for the user input. The form provides a much richer interaction with VBA, so you can actually have it stuff information into cells after every fourth character is entered.
Start by creating a user form (as described in other issues of ExcelTips) that contains two controls—a text box and a button. Name the text box vText and associate the following code with it:
Private Sub vText_Change() If Len(vText) = 4 Then ActiveCell = vText ActiveCell.Offset(0, 1).Activate UserForm1.vText.Value = "" End If End Sub
This simply runs every time the contents of the text box change (i.e., when you type each character) and then checks the length of whatever it contains. When the length reaches 4 the code takes those characters and stuffs them into a cell. The contents of vText are then emptied.
The name of the button you create in the user form doesn't really matter. It will be used as a way to close the user form, and should have the following code associated with it:
Private Sub Cancel_Click() Unload UserForm1 End Sub
When you are ready to use the user form, simply select the cell where you want input to start and then run the following macro:
Sub Start() UserForm1.Show End Sub
The user form appears and you can start typing away. When you are done, just click the button and the user form is closed.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13102) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Automatically Moving from Cell to Cell when Entering Data.
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!
If you need to swap the contents of two cells in your worksheet, Excel provides a number of ways you can approach the ...
Discover MoreEntering data in a worksheet can be time consuming. One of the tools that Excel provides to make entry easier is ...
Discover MoreEnter information into a cell, and Excel needs to figure out what type of information it is. Here's how Excel interprets ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-04-03 13:00:45
kiwerry
Another way of stopping leading zeros from being trimmed off by Excel would be to format the cell as Text before putting the four characters there; for example, Sub FourCharEntry would look like this:
...
For x = 1 To Len(str) Step 4
ActiveCell.Offset(0, y).NumberFormat = "@"
ActiveCell.Offset(0, y) = Mid(str, x, 4)
y = y + 1
Next
...
The User Form solution doesn't counter the "leading zeros" problem, but could easily be modified to do so.
@ Philip:
That's why the solution proposed at the bottom of the tip involves a user form, I guess.
2021-04-03 10:12:54
Rick Rothstein
@Philip,
When you are entering characters into a cell, Excel is in "edit mode"... VBA code cannot run while Excel is in "edit mode", so the answer to your question is "No".
2021-04-03 09:42:30
Philip
From the description of the question, seems to me that the search is rather for a solution that takes automated action after each 4th character entered. Is there any VBA event that captures the typing of an individual key when in an active cell ?
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