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: Setting a Length Limit on Cells.
Written by Allen Wyatt (last updated February 13, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Craig is developing a worksheet and wants to know if there is a way to specify the maximum number of characters that can be entered in any given cell. He doesn't want to use Data Validation to impose the limitation.
There is no way to do this directly in Excel without (as Craig mentions) using Data Validation. There are a few things you can try to achieve the desired effect, however. First, you can use a formula to check the length of any cell, and then display an error message, if desired. For instance, if the cells you want to check are in column C, you could use a formula such as the following:
=IF((LEN(C1)>15),"Cell is Too Long","")
Place the formula in the cell to the right of the cell being checked (such as in cell D1), and then copy it down as many cells as necessary. When an entry is made in C1, and if it is more than 15 characters, then the message is displayed.
If such a direct approach is undesirable, then you'll need to use macros to do the checking. The following is a simple example that is triggered whenever something is changed in the worksheet. Each cell in the worksheet is then checked to make sure it is not longer than 15 characters. If such a cell is discovered, then a message box is displayed and the cell is cleared.
Private Sub Worksheet_SelectionChange(ByVal Target As Range) For Each cell In UsedRange If Len(cell.Value) > 15 Then MsgBox " Can't enter more than 15 characters" cell.Value = "" End If Next End Sub
A more robust approach is to check in the event handler to see if the change was made somewhere within a range of cells that need to be length-limited.
Private Sub Worksheet_Change(ByVal Target As Range) Dim rng As Range Dim rCell As Range Dim iChars As Integer On Error GoTo ErrHandler 'Change these as desired iChars = 15 Set rng = Me.Range("A1:A10") If Not Intersect(Target, rng) Is Nothing Then Application.EnableEvents = False For Each rCell In Intersect(Target, rng) If Len(rCell.Value) > iChars Then rCell.Value = Left(rCell.Value, iChars) MsgBox rCell.Address & " has more than" _ & iChars & " characters." & vbCrLf _ & "It has been truncated." End If Next End If ExitHandler: Application.EnableEvents = True Set rCell = Nothing Set rng = Nothing Exit Sub ErrHandler: MsgBox Err.Description Resume ExitHandler End Sub
To use this macro, you simply need to change the value assigned to iChars (represents the maximum length allowed) and the range assigned to rng (currently set to A1:A10). Because the macro checks only for changes within the specified range, it is much faster with larger worksheets than the macro that checks all the cells used.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10003) 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: Setting a Length Limit on Cells.
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!
Need to edit the data within a cell? There are any number of ways you can perform the edit; this tip documents them all.
Discover MoreIs your worksheet, imported from an external source, plagued by non-printing characters that show up like small boxes ...
Discover MoreCopying from one cell to another is easy when editing your worksheet. Doing the copying without selecting a cell other ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-02-16 08:34:54
CJ
Willy, it seems that your approach assumes the event is triggered by having the same value pasted into multiple cells, but that's just one scenario. If the values differ then a loop must be used.
2021-02-13 12:16:36
Willy Vanhaelen
If you enter the same value in more than one cell a the time by pressing Ctrl+Enter, the second macro has an annoying behavior of displaying the message box for each of the cells because a For Each loop is used, which has no sense in this case. When you enter something to long in several cells at the time, Excel enters the full entry in all cells. Then Excel runs the event macro Worksheet_ChangeWorksheet_Change. My version of the macro hereafter checks if the first value in the range is to long and if so it truncates the whole range in one go:
Private Sub Worksheet_Change(ByVal Target As Range)
Const iChars As Integer = 15 'change as disired
Dim rng As Range
Set rng = Intersect(Target, Range("A1:A10")) 'change range as disired
If rng Is Nothing Then Exit Sub
If Len(rng(1)) <= iChars Then Exit Sub
On Error GoTo ErrHandler
Application.EnableEvents = False
rng = Left(rng(1).Value, iChars)
MsgBox "Range " & rng.Address & " has more than " & iChars _
& " characters." & vbCrLf & "It has been truncated."
ExitHandler:
Application.EnableEvents = True
Exit Sub
ErrHandler:
MsgBox Err.Description
Resume ExitHandler
End Sub
I removed Set rCell = Nothing and Set rng = Nothing because after that the macro finishes and the memory they might use is then freed anyway.
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