Results 1 to 9 of 9

Thread: Sum Of The Digits Of Numeric Value In A Cell Range

  1. #1
    Junior Member Zaigham's Avatar
    Join Date
    Mar 2013
    Posts
    13
    Rep Power
    0

    Sum Of The Digits Of Numeric Value In A Cell Range

    Hi
    I need to sum the digits of a numeric value in a cell e.g.

    123 = 6 i.e.(1+2+3)
    12546 = 18 i.e. (1+2+5+4+6)
    etc.

    Regards
    Zaigham

    https://www.youtube.com/channel/UCnxwq2aGJRbjOo_MO54oaHA
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgykemWTw-fGoPwu8E14AaABAg.9iECYNx-n4U9iK75iCEaGN
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgykemWTw-fGoPwu8E14AaABAg.9iECYNx-n4U9iK7XF33njy
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=Ugy_1xkcndYdzUapw-J4AaABAg.9iGOq_leF_E9iKCSgpAqA1
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=Ugy_1xkcndYdzUapw-J4AaABAg.9iGOq_leF_E9iKCy--3x8E
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgwNaJiNATXshvJ0Zz94AaABAg. 9iEktVkTAHk9iF9_pdshr6
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgykemWTw-fGoPwu8E14AaABAg.9iECYNx-n4U9iFAZq-JEZ-
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgxV2r7KQnuAyZVLHH54AaABAg. 9iDVgy6wzct9iFBxma9zXI
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=Ugx12mI-a39T41NaZ8F4AaABAg.9iDQqIP56NV9iFD0AkeeJG
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgwnYuSngiuYaUhEMWN4AaABAg. 9iDQN7TORHv9iFGQQ5z_3f
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgwJ3yzdk_EE98dndmt4AaABAg. 9iDLC2uEPRW9iFGvgk11nH
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgyDWAVqCa4yMot463x4AaABAg. 9iH3wvUZj3n9iHnpOxOeXa
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=UgwvLFdMEAba5rLHIz94AaABAg. 9iGReNGzP4v9iHoeaCpTG8
    https://www.youtube.com/watch?v=ITI1HaFeq_g&lc=Ugy_1xkcndYdzUapw-J4AaABAg.9iGOq_leF_E9iHpsWCdJ5I
    https://www.youtube.com/channel/UCnxwq2aGJRbjOo_MO54oaHA
    Last edited by DocAElstein; 09-22-2023 at 04:13 PM.

  2. #2
    Forum Guru Rick Rothstein's Avatar
    Join Date
    Feb 2012
    Posts
    662
    Rep Power
    13
    Give this formula a try...

    =SUMPRODUCT(--MID(A1,ROW(INDIRECT("A1:A"&LEN(A1))),1))

  3. #3
    Junior Member Zaigham's Avatar
    Join Date
    Mar 2013
    Posts
    13
    Rep Power
    0
    Thank you very much.
    It works. Can you explain use of "MID" within SUMPRODUCT or be kind enough to evaluate the formula?

  4. #4
    Forum Guru Rick Rothstein's Avatar
    Join Date
    Feb 2012
    Posts
    662
    Rep Power
    13
    Quote Originally Posted by Zaigham View Post
    Thank you very much.
    It works. Can you explain use of "MID" within SUMPRODUCT or be kind enough to evaluate the formula?
    First off, we note that SUMPRODUCT is an array processing function... give it a range of cells and it performs the indicated "calculation" by iterating the range one cell at a time and summing the results of each of those iterations to produce its return value. The MID function returns a substring from within a larger text string. It has 3 arguments... the first is the larger text string, the second is a starting point within that larger text string from which the substring will be acquired and the third is how many characters (from that starting point) to take. So, we need to create an range (for the SUMPRODUCT function to process) which iterates through each digit of the number in A1 (first argument for MID) one digit at a time (third argument for MID)... that range of starting points from which to draw one digit at a time is what the second argument for the MID function is providing. The INDIRECT function creates a Range in Column A from Row 1 to the row number corresponding to the length of the number in A1... that range is the argument for the ROW function which is what SUMPRODUCT will iterate... so for the number 12546, the SUMPRODUCT function sees ROW(A1:A5) and when SUMPRODUCT iterates this range, it pulls out the numbers 1, 2, 3, 4 and 5... each of those is the starting point from whch 1 (third argument for MID) digit will be returned from the number in A1 for SUMPRODUCT to total up. The double minus sign is equivalent to multiplying each value returned by the iteration through the range in the second argument by +1 which doesn't change any values but, in Excel formulas, performing a math operation (multiply by +1 being such an operation) on a "text number" converts it from being text to being a real number... we do this so SUMPRODUCT has real numbers to sum up.

  5. #5
    Junior Member Zaigham's Avatar
    Join Date
    Mar 2013
    Posts
    13
    Rep Power
    0
    Mr. Rick
    I am very very thankful to you for devoting your precious time for me. You have explained the method in detail that would guide me in future. I have found you very kind before this on another forum. Thank you very much again.

  6. #6
    Forum Guru Rick Rothstein's Avatar
    Join Date
    Feb 2012
    Posts
    662
    Rep Power
    13
    Quote Originally Posted by Zaigham View Post
    Mr. Rick
    I am very very thankful to you for devoting your precious time for me. You have explained the method in detail that would guide me in future. I have found you very kind before this on another forum. Thank you very much again.
    My pleasure... and you are quite welcome... I am glad I have been able to be of help to you (both in this forum and the other one you referred to).

  7. #7
    Junior Member Haseeb A's Avatar
    Join Date
    Apr 2011
    Posts
    21
    Rep Power
    0
    Another way...

    Code:
    =SUM((LEN(A1)-LEN(SUBSTITUTE(A1,{1,2,3,4,5,6,7,8,9},"")))*{1,2,3,4,5,6,7,8,9})
    Should also work if the cell mixed with text & numbers.

  8. #8
    Senior Member
    Join Date
    Jun 2012
    Posts
    337
    Rep Power
    13
    alternative; a UDF

    e.g. in B5:

    =snb_001(A5)

    Code:
    Function snb_001(y)
      snb_001 = Evaluate(Replace(StrConv(y, 64), Chr(0), "+") & "0")
    End Function

  9. #9
    Junior Member Zaigham's Avatar
    Join Date
    Mar 2013
    Posts
    13
    Rep Power
    0
    It is just amazing for me, as I was not sure for a single solution.
    Thank you very much.

Similar Threads

  1. Sum Of The Digits In A Cell Using Formula
    By venkat1926 in forum Excel Help
    Replies: 0
    Last Post: 04-30-2013, 07:11 PM
  2. Replies: 11
    Last Post: 04-07-2013, 07:51 PM
  3. Replies: 5
    Last Post: 03-09-2013, 09:01 AM
  4. Sum Ifs Formula needed with Max Date range
    By trankim in forum Excel Help
    Replies: 2
    Last Post: 09-19-2012, 09:50 AM
  5. Replies: 2
    Last Post: 02-29-2012, 08:24 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •