Calculate SUM of Values in Text String

artsyangel7

New Member
Joined
Aug 28, 2017
Messages
3
Hello! I am looking for an easy way to calculate the sum of numbers present in a long string of text. Our website exports order data in this fashion (product x quantity):

Hot Apple Pie Candle (#010) | x 1; Gma's ******* Candle (#009) | x 1; Fresh Linen Candle (#008) | x 2

For reporting purposes we need to calculate the total number of units on each order. So in the above example it would be 1+1+2=4. I've tried several formulas without much luck so I was hoping someone here might be able to offer some suggestions on how to achieve this. Thank you in advance. Have a nice day!
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Assuming the text is in cell A1, enter the following array formula in cell B1 to get the result.

=SUM(IFERROR((MID(SUBSTITUTE(SUBSTITUTE(A1;";";"");" ";REPT(" ";LEN(A1)));1+LEN(A1)*(ROW(A$1:INDEX(A:A;LEN(A1)-LEN(SUBSTITUTE(A1;" ";""))+(A1<>"")))-1);LEN(A1)))+0;0))

Depending on your Excel settings, you may need to use the following formula;

=SUM(IFERROR((MID(SUBSTITUTE(SUBSTITUTE(A1,";","")," ",REPT(" ",LEN(A1))),1+LEN(A1)*(ROW(A$1:INDEX(A:A,LEN(A1)-LEN(SUBSTITUTE(A1," ",""))+(A1<>"")))-1),LEN(A1)))+0,0))

In order to get the result, you have to hit "Ctrl+Shift+Enter" keys to have the "{" and "}" signs at the beginning and end of the formula
 
Last edited:
Upvote 0
Depending on your Excel settings, you may need to use the following formula;

=SUM(IFERROR((MID(SUBSTITUTE(SUBSTITUTE(A1,";","")," ",REPT(" ",LEN(A1))),1+LEN(A1)*(ROW(A$1:INDEX(A:A,LEN(A1)-LEN(SUBSTITUTE(A1," ",""))+(A1<>"")))-1),LEN(A1)))+0,0))

In order to get the result, you have to hit "Ctrl+Shift+Enter" keys to have the "{" and "}" signs at the beginning and end of the formula[/QUOTE]


Thank you, thank you, thank you, Haluk! You made my day. :) The second formula worked perfectly. I have never used most of these functions so I'm certain I would never have been able to figure this out on my own. I'm still learning all the advanced things Excel can do.

Just wondering...is this something that could easily be saved as a macro? Would be fantastic if I could just open my exported CSV file every day and click a button and have a script run the sum and return the answer in the next column. I have never created a macro before so I don't know if this is relatively easy to achieve or not.
 
Upvote 0
Hi;

Nice to hear that the proposed formula solved the problem.

In case of using a macro instead of the formula approach, you can use the below procedure.

Code:
Sub SumQnty()
    Dim MyArray As Variant, MyArray2 As Variant
    NoA = Range("A" & Rows.Count).End(xlUp).Row
    For i = 1 To NoA
        MySum = 0
        MyArray = Split(Range("A" & i), ";")
        For Each aData In MyArray
            MyArray2 = Split(aData, "x")
            MySum = MySum + Val(MyArray2(1))
        Next
        Range("B" & i) = MySum
    Next
End Sub

Insert this code into a new module and when the sheet housing the data is the active sheet, run the code. The sum of the quantities in cells of Column A will be given on Column B.

Hope this helps,
 
Last edited:
Upvote 0
Perfect! Your solution did the trick. Thank you kindly for your assistance; you've been so very helpful! So glad I found this forum as I'm sure I will have many more questions as I continue exploring more advanced Excel features. Have a wonderful day!!! =)
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,210
Members
453,023
Latest member
alabaz

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top