If you have a cell that contains a value, you may want to devise a way to add together all the digits in the value. For instance, if a cell contains the value 554, you might want to determine the sum of 5+5+4, which is 14.
There are several ways you can approach this task. (Doesn't that always seem the way in Excel?) The first is to use a formula that relies on several functions:
=SUMPRODUCT(--MID(A1,ROW(INDIRECT("1:" & LEN(A1))),1))
This regular formula will sum the digits in any integer value (in cell A1) in a simple, elegant manner. This is not the only possible formula, however. The following is an array formula (terminated by pressing Ctrl+Shift+Enter) version of the same formula:
=SUM(1*MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1))
Either of these formulas work fine if the value in A1 is a positive whole number. If there are any non-digit characters in the number (such as a negative sign or a decimal point), then the formulas return a #VALUE! error.
You can also use a user-defined function to return the desired sum. The following macro steps through each digit in the referenced cell and calculates a total. This value is then returned to the user:
Function AddDigits(Number As Long) As Integer Dim i As Integer Dim Sum As Integer Dim sNumber As String sNumber = CStr(Number) For i = 1 To Len(sNumber) Sum = Sum + Mid(sNumber, i, 1) Next AddDigits = Sum End Function
To use this function, just use a formula such as =AddDigits(A1) in a cell. An even more compact user-defined function (invoked in the same manner) is the following:
Function AddDigits(ByVal N As Long) As Integer Do While N >= 1 AddDigits = AddDigits + N Mod 10 N = Int(N / 10) Loop End Function
Unlike the earlier macro, this version doesn't convert the cell contents to a string in order to process it. Instead, it steps through each digit of the value, stripping off the last digit and adding it to the total.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2424) 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: Summing Digits in a Value.
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 is very good at counting things, even when those things need to meet specific criteria. This tip shows how you can ...
Discover MoreIn a series of values you may need to know the smallest value that isn't a zero. There is no built-in function to do ...
Discover MoreIf you have a lot of values in a single row, you might want to pull the last non-zero value from that row. There are a ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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