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.

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


2

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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Inserting the Total Number of Pages in Your Document

Word keeps track of many statistics for each of your documents. One statistic is the total number of pages in the printed ...

Discover More

Can't Update Excel 2007 PivotTables in Excel 2003

If you create a PivotTable in Excel 2007, you may have problems editing or updating that PivotTable in Excel 2003. The ...

Discover More

Adjusting to a Maximum Row Height

Need to check the height of all the rows in a worksheet and then adjust them if a particular criterion is met? This tip ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Checking for Duplicate Rows Based on a Range of Columns

When working with data in Excel, you might want to figure out which rows of data represent duplicates of other rows. If ...

Discover More

Counting Jobs Completed On a Date

When you store the date and time in a single cell, it can be a bit confusing to count how many cells contain a particular ...

Discover More

Starting Out Formulas

When you enter a formula from the keyboard, Excel only knows it is a formula if you start it with an equal sign. You can ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 8 + 7?

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)))


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.