Add cells with numbers and random text

Anonymous
2016-08-16T21:06:33+00:00

Looked at a lot of examples and all of them are slightly different.  I have the following data, a few rows and columns of random text with numbers, and I need a sum of all the numbers. 

EH2FX
MUF
JH2 EC2F
JH2
EU2FX EH2F

I have a different amount of data most times (maybe more or less rows or columns).  Some of the cells are blank and some contain text but no number.  There is no space before the number and the same letter doesn't always come before or after the number which most of the other examples are based on.  I would prefer just an excel equation vs a macro and I'm pretty sure it will have to be an array formula.

Microsoft 365 and Office | Excel | For home | Windows

Locked Question. This question was migrated from the Microsoft Support Community. You can vote on whether it's helpful, but you can't add comments or replies or follow the question.

0 comments No comments
{count} votes
Answer accepted by question author
  1. Anonymous
    2016-08-16T21:57:40+00:00

    I am not so sure you will be able to find a formula solution; so here is a UDF (user defined function) that you can turn to if it turns out that I am right...

    Function SumNums(Rng As Range) As Double

      Dim Cell As Range

      For Each Cell In Rng

        SumNums = SumNums + Val(Mid(Cell.Value, _

                  Evaluate("MIN(FIND({0,1,2,3,4,5,6,7,8,9}," & _

                  Cell.Address & "&""0123456789""))")))

      Next

    End Function

    HOW TO INSTALL UDFs


    If you are new to UDFs, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. You can now use SumNums just like it was a built-in Excel function. Now just pass in the range whose cells you want to examine; for example...

    =SumNums(B4:C8)

    If you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

    0 comments No comments

3 additional answers

Sort by: Most helpful
  1. Anonymous
    2016-08-17T07:12:22+00:00

    A solution using Excel Formulas - 2 options.

    Option 1 - If there is only a single digit in the alphanumeric string, refer below image:

    Enter below formula in cell D2 & copy down & to the next column E:

    =IFERROR(LOOKUP(9.99999999999999E+307,--MID(A2,MIN(SEARCH({0,1,2,3,4,5,6,7,8,9},A2&"0123456789")),ROW(INDIRECT("1:"&LEN(A2))))),0)

    This formula extracts a single digit from the alpha-numeric string & cell F2 sums the range: =SUM(D2:E6).

    Option 2 - If there are multiple digits in the alphanumeric string, refer below image:

    Enter below formula as an array formula (CTRL+SHIFT+ENTER) in cell G2 7 copy down and to the right column H:

    =IFERROR(SUM(MID(0&A2,LARGE(ISNUMBER(--MID(A2,ROW(INDIRECT("1:"&LEN(A2))),1))*ROW(INDIRECT("1:"&LEN(A2))),ROW(INDIRECT("1:"&LEN(A2))))+1,1)*10^ROW(INDIRECT("1:"&LEN(A2)))/10),0)

    This formula extracts multiple digits (obviously it also extract a single digit where applicable) from the alpha-numeric string & cell I2 sums the range: =SUM(G2:H6).

    Regards,

    Amit Tandon

    0 comments No comments
  2. Anonymous
    2016-08-17T15:35:31+00:00

    Thanks for the help.  I ended up going with the UDF from Rick.  I should have stated this in my initial post, but I wanted the solution to only take up one cell because there is more data in the columns next to this data so I would have had to insert columns and then hide them to do the in between step required by Amit's solution or do that somewhere else in the spreadsheet which would have been confusing.  That's why I was thinking it would have to be an array formula or be done in VBA.  Thanks to both of you though for the help.  One of these days I need to spend some more time diving into VBA.  There are just so many commands to learn along with the sytax that makes it difficult to do something relatively easy like this task unless you understand it properly.

    0 comments No comments
  3. Anonymous
    2016-08-17T15:57:00+00:00

    You are correct ... for additional data in adjacent columns, Rick's vba solution might be preferable ... using excel formulas will entail additional columns for this.

    Regards,

    Amit Tandon

    0 comments No comments