Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Summing Digits in a Value.
Written by Allen Wyatt (last updated October 22, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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.
These are not the only formulas possible for this type of calculation. You can find some other examples of formulas in the Microsoft Knowledge Base:
http://support.microsoft.com/?kbid=214053
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 (12002) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Summing Digits in a Value.
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!
Sometimes putting together a formula can be a challenge. Part of the process, though, is examining the data with which ...
Discover MoreIf you need to randomly match up items in two lists, there are a variety of techniques you can use. Here are a couple of ...
Discover MoreYou might wonder how you can calculate an IRR (internal rate of return) when the person repaying the loan pays different ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-05-01 09:55:15
J. Woolley
The following dynamic array function in My Excel Toolbox returns an array of numeric values beginning with Start incrementing by Step until Finish (not beyond):
=ForNext(Start, Finish, [Step], [AsColumn])
Start, Finish, and Step can be any numeric value. Default Step is 1.
If AsColumn is FALSE (default), the result is a row array; TRUE returns a column array. Expect N elements: N = 1 + INT((Finish - Start) / Step)
Here is a version of Andy's formula (see the previous comment below) that does not require Excel 365 (or 2021+):
=SUM(VALUE(MID(A1, ForNext(1, LEN(A1)), 1)))
In older Excel versions yoou probably need to use Ctrl+Shift+Enter (CSE).
For an example that has nothing to do with the Tip, here is the date of every Sunday for the next 52 weeks beginning with the most recent Sunday:
=ForNext(TODAY()-WEEKDAY(TODAY())+1, TODAY()+52*7, 7, TRUE)
In older Excel, select 52 cells in a column and use CSE. The resulting column array should be manually formatted as Date.
See https://sites.google.com/view/MyExcelToolbox/
2022-10-22 07:42:28
Andy
Here is another formula approach. It requires Excel 365.
=SUM(VALUE(MID(A1,SEQUENCE(LEN(A1)),1)))
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