Written by Allen Wyatt (last updated October 31, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
Sherry has a column of numbers ranging from 13 to 15 digits long. She needs to remove just the last digit in each number and wonders how this can be easily done.
The easiest way is to use a formula to strip off the digit. The following works just fine, assuming that the original value is in cell A1:
=LEFT(A1,LEN(A1)-1)*1
What is returned by the LEFT function is a string, which is why it is multiplied by 1 at the end of the formula—it converts that string value back into a numeric value.
Perhaps the shortest formula would be the following, however:
=TRUNC(A1/10)
Dividing by 10, of course, is a quick way to move the decimal point one position to the left. You could use the INT function instead of TRUNC, but you should only do so if the original values are all positive numbers. (INT and TRUNC behave differently from each other when working with negative values.)
Obviously, the formulas described above require the use of a helper column. They also aren't terribly discriminating; they will remove the last digit from any value in cell A1 and they won't "adjust" if A1 contains text or is empty. If you want a bit more flexibility, you might consider using a macro:
Sub ShortenByOne() Dim c As Range For Each c In Selection If (Not c.HasFormula) And (Application.WorksheetFunction.IsNumber(c)) Then c = Left(c, Len(c) - 1) End If Next c End Sub
To use the macro, select the range of cells you want to affect and then run it. The values are changed to reflect the dropping of the right-most digit. Note that the macro won't make any changes in cells containing formulas or cells that don't contain numeric values. (The IsNumber worksheet function is used in preference to the IsNumeric function because IsNumeric will treat empty cells as if they are actually numeric which will crash the macro without additional testing. IsNumber doesn't exhibit that problem.)
If you want to make sure that only cells containing 13, 14, or 15 digits are modified, then you can use a variation on the above macro:
Sub ShortenByOne() Dim c As Range For Each c In Selection If (Not c.HasFormula) And (Application.WorksheetFunction.IsNumber(c)) Then If Len(c) > 12 And Len(c) < 16 Then c = Left(c, Len(c) - 1) End If End If Next c End Sub
Note that after the macro determines that the cell doesn't contain a formula and that it contains a number, then it checks to see if the length of the number is greater than 12 and less than 16. (In other words, 13, 14, or 15.) Only then does it strip off the right-most digit.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13796) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
If you need to evaluate a row of values to meet specific criteria, then you'll appreciate the discussion in this tip. It ...
Discover MoreWhen you are working with large data sets, you may want to filter the information in those data sets according to various ...
Discover MoreIf you want to figure out the sum of all cells that contain formulas, there are a couple of ways you can go about it. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-11-02 12:40:25
Yvan Loranger
I prefer =LEFT(A1,LEN(A1)-1)*1 over =TRUNC(A1/10)
since the first properly handles decimals as well as whole numbers in the 13-15digit samples.
Example: 111111111111.1 is properly handled by the LEFT function.
thanks
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 © 2025 Sharon Parq Associates, Inc.
Comments