Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Automatically Moving from Cell to Cell when Entering Data

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Automatically Moving from Cell to Cell when Entering Data.

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 use 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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3923) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Automatically Moving from Cell to Cell when Entering Data.

Related Tips:

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!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

GULAM    16 Aug 2016, 05:14
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


-if i apply this macro this will Put value in the same row.BUT I WANT TO PUT THE SPLIT VALUE IN NEXT ROW
lmc    27 Jun 2015, 13:20
Trying to use Excel VBA code to move to a certain cell enter or change a formula, press enter, move to another cell in worksheet, enter or change a formula, press enter and etc. until all formulas are entered, move to next worksheet and repeat the code until all worksheets are completed in the workbook.
Nick    17 Apr 2014, 22:33
I have a much simpler data entry but can't figure out how to change the code you've provided. I want to enter only "1" or "2" but automatically move down a column instead of across a row. This is for a test administration that will always have 467 items in it. So I need to input "1" or "2" for A1, A2, A3, A4...to A467. I've read your posts and switched the offset to (y, 0) but can't figure out the rest. Any help would be greatly appreciated. Thank you for this wonderful site.
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.