Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Summing Digits in a Value.

Summing Digits in a Value

by Allen Wyatt
(last updated January 4, 2020)

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:

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 (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.

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

Converting Mainframe Date Formats

Different industries and different computer systems specify dates in all sorts of strange ways. If you need to convert a ...

Discover More

Hiding and Unhiding Columns

Want to hide a column so it doesn't appear in the worksheet? It's easy to do using the formatting capabilities of Excel.

Discover More

Adding a Diagonal Watermark with a PostScript Printer

If you have a printer that understands PostScript, you can add your own watermark to each printed page. This tip ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (menu)

Summing Absolute Values

You can easily sum a series of values in Excel, but it is not so easy to sum the absolute values of each value in a ...

Discover More

Compiling a List of Students in a Course

Need to pull just a limited amount of information from a large list? Here are a few approaches you might be able to use ...

Discover More

Relative References to Cells in Other Workbooks

When you construct a formula and click on a cell in a different workbook, an absolute reference to that cell is placed in ...

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}] 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 six minus 6?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

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.