Error Checking in Excel
Thanks Thanks:  0
Likes Likes:  0
Results 1 to 7 of 7

Thread: Adding the values in a cell...

  1. #1
    New Member
    Join Date
    Apr 2002
    Location
    New Jersey
    Posts
    6
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    I am trying to write a formula to add the number values in a cell. For example If I populate cell (A1) with the number 12345 I would like to see the sum of those numbers in cell (B1). I can pull this off using LEN and MID.

    However, if column A is populated with number values of varying lengths my formula breaks. I DO NOT want to do this using VBA. Any ideas?

  2. #2
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Austin, Texas USA
    Posts
    11,654
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    {=SUM(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1)+0)}

    Note: This is an array formula which is entered using the Control+Shift+Enter key combination.

    [ This Message was edited by: Mark W. on 2002-04-25 16:04 ]

  3. #3
    MrExcel MVP Jay Petrulis's Avatar
    Join Date
    Mar 2002
    Location
    Chicago, IL USA
    Posts
    2,040
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Hi,

    Array enter
    =SUM(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1)+0)

    Must be entered with Ctrl-Shift-Enter

    HTH,
    Jay

    EDIT: Obviously Mark was quicker on the draw here with the same answer. He is one fast gunslinger. This post isn't big enough for the two of us, so I will slink away now.

    [ This Message was edited by: Jay Petrulis on 2002-04-25 16:07 ]

  4. #4
    MrExcel MVP Jay Petrulis's Avatar
    Join Date
    Mar 2002
    Location
    Chicago, IL USA
    Posts
    2,040
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Hi,

    The above formulas fail if the cell is:

    a. < 0
    b. blank
    c. non-integer
    d. contain any non-numeric characters

    The following corrects the first three (assuming the decimal separator is a .)

    {=IF(LEN(A1),SUM(MID(ABS(SUBSTITUTE(A1,".","")),ROW(INDIRECT("1:"&LEN(ABS(SUBSTITUTE(A1,".",""))))),1)+0),0)}

    again, array-entered.

    Obviously this is overkill, so please take this with a grain of salt, as the primary formula works fine.

    Bye,
    Jay


    EDIT: Or, to correct all four
    =IF(ISNUMBER(A1),SUM(MID(ABS(SUBSTITUTE(A1,".","")),ROW(INDIRECT("1:"&LEN(ABS(SUBSTITUTE(A1,".",""))))),1)+0),0)

    [ This Message was edited by: Jay Petrulis on 2002-04-25 17:08 ]

  5. #5
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Austin, Texas USA
    Posts
    11,654
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    On 2002-04-25 17:05, Jay Petrulis wrote:
    Hi,

    The above formulas fail if the cell is:

    a. < 0
    b. blank
    c. non-integer
    d. contain any non-numeric characters

    The following corrects the first three (assuming the decimal separator is a .)

    ...

    [ This Message was edited by: Jay Petrulis on 2002-04-25 17:08 ]
    Or, you could setup Data Validation on A1.

  6. #6
    MrExcel MVP Jay Petrulis's Avatar
    Join Date
    Mar 2002
    Location
    Chicago, IL USA
    Posts
    2,040
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    On 2002-04-25 17:41, Mark W. wrote:
    On 2002-04-25 17:05, Jay Petrulis wrote:
    Hi,

    The above formulas fail if the cell is:

    a. < 0
    b. blank
    c. non-integer
    d. contain any non-numeric characters

    The following corrects the first three (assuming the decimal separator is a .)

    ...

    [ This Message was edited by: Jay Petrulis on 2002-04-25 17:08 ]
    Or, you could setup Data Validation on A1.
    Now why would anybody want to do something simple and painless when they can do something that is nearly impossible to decipher? Who want easy when you can have a Rube Goldberg solution.

    I didn't even think of the obvious. Way cool.

    Bye,
    Jay

  7. #7
    New Member
    Join Date
    Apr 2002
    Location
    New Jersey
    Posts
    6
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    THANKS FOR THE QUICK HELP!!!!!

Some videos you may like

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

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