extract all numbers (double digit) in excel and sum

sosolid4u09

New Member
Joined
Feb 8, 2018
Messages
6
Hi everyone,

I have a bit of a complex problem.

I have a column like the following;

Training: 7, Fighting: 12, Speed: 3

I need a formula that sums together 7+12+3 automatically.

Now I got a solution where i extract all the digits in that cell and sum. But that ends up giving me 7+1+2+3 which is obviously not correct.

Does anyone have an idea?

Thanks
 

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.
Welcome to Mr Excel Forum

Maybe something like this

[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][td="bgcolor: #DCE6F1"]
C
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
Values​
[/td][td][/td][td]
Result​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Training: 7​
[/td][td][/td][td]
22​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
Fighting: 12​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
Speed: 3​
[/td][td][/td][td][/td][/tr]
[/table]


Formula in C2
=SUMPRODUCT(--MID(A2:A4,SEARCH(":",A2:A4)+1,100))

M.
 
Upvote 0
Welcome to Mr Excel Forum

Maybe something like this

[TABLE="class: grid"]
<tbody>[TR]
[TD="bgcolor: #DCE6F1"][/TD]
[TD="bgcolor: #DCE6F1"]
A
[/TD]
[TD="bgcolor: #DCE6F1"]
B
[/TD]
[TD="bgcolor: #DCE6F1"]
C
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
1
[/TD]
[TD]
Values​
[/TD]
[TD][/TD]
[TD]
Result​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
2
[/TD]
[TD]
Training: 7​
[/TD]
[TD][/TD]
[TD]
22​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
3
[/TD]
[TD]
Fighting: 12​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
4
[/TD]
[TD]
Speed: 3​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Formula in C2
=SUMPRODUCT(--MID(A2:A4,SEARCH(":",A2:A4)+1,100))

M.

thanks for the response

But the

Training: 7, Fighting: 12, Speed: 3

Is in one row, not in columns

 
Upvote 0
Is there are always exactly 3 "skills" whose values you want to add up or could the number of "skills" vary?

Skill names don't vary.

Always three skills.

One DQ issue though is that there are times people leave the value blank. i.e.
Training: , Fighting: 12, Speed:
Training: 0, Fighting: , Speed: 3

 
Upvote 0
Can you make use of a VBA solution, namely, a UDF (user defined function)? If so...
Code:
Function SkillSum(S As String) As Double
  Dim V As Variant
  For Each V In Split(S, ":")
    SkillSum = SkillSum + Val(V)
  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 SkillSum just like it was a built-in Excel function. For example,

=SkillSum(A1)

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.
 
Upvote 0
Can you make use of a VBA solution, namely, a UDF (user defined function)? If so...
Code:
Function SkillSum(S As String) As Double
  Dim V As Variant
  For Each V In Split(S, ":")
    SkillSum = SkillSum + Val(V)
  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 SkillSum just like it was a built-in Excel function. For example,

=SkillSum(A1)

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.

Outstanding good man.

Thanks a lot
 
Upvote 0
I think an User Defined Function (UDF) should be the proper solution.

Anyway, this array formula worked for your examples


[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
Text​
[/td][td]
Result​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Training: 7, Fighting: 12, Speed:3​
[/td][td]
22​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
Training: , Fighting: 12, Speed:​
[/td][td]
12​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
Training: 0, Fighting: , Speed: 3​
[/td][td]
3​
[/td][/tr]
[/table]


Array Formula in B2 copied down
=SUM(IFERROR(0+TRIM(MID(SUBSTITUTE(SUBSTITUTE(":"&A2,":",REPT(" ",500)),",",REPT(" ",500)),ROW(A$1:A$100)*500,500)),0))

confirmed with Ctrl+Shift+Enter, not just Enter

M.
 
Upvote 0

Forum statistics

Threads
1,223,164
Messages
6,170,444
Members
452,326
Latest member
johnshaji

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