sum minutes in this format 45'50'60'

Peterfc2

Active Member
Joined
Jan 2, 2004
Messages
404
Office Version
  1. 2013
Platform
  1. Windows
I have a column of minutes from goals scored

45'
5'67'89'
2'5'89'
15'67'79'78'

is there a way of adding them all up please?
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
can try use the built-in text to columns function with ' as delimiter them add them up with sum()
 
Upvote 0
Here is a UDF (user defined function) that you can use, simply pass the vertical range containing your minutes into the function...
Code:
[table="width: 500"]
[tr]
	[td]Function SumMinutes(VerticalRange As Range) As Long
  SumMinutes = Evaluate(Replace(Join(Application.Transpose(VerticalRange), "'") & 0, "'", "+"))
End Function[/td]
[/tr]
[/table]

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 SumMinutes just like it was a built-in Excel function. For example,

=SumMinutes(A1:A4)

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
with PowerQuery

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]minutes[/td][td][/td][td=bgcolor:#70AD47]Evaluate[/td][td][/td][td=bgcolor:#70AD47]Sum[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]45'[/td][td][/td][td=bgcolor:#E2EFDA]
45​
[/td][td][/td][td=bgcolor:#E2EFDA]
541​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td]5'67'89'[/td][td][/td][td]
161​
[/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]2'5'89'[/td][td][/td][td=bgcolor:#E2EFDA]
96​
[/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]15'67'79'78'[/td][td][/td][td]
239​
[/td][td][/td][td][/td][/tr]
[/table]


for the first green table

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Type = Table.TransformColumnTypes(Source,{{"minutes", type text}}),
    Replace = Table.ReplaceValue(Type,"'","+",Replacer.ReplaceText,{"minutes"}),
    Extract = Table.TransformColumns(Replace, {{"minutes", each Text.BeforeDelimiter(_, "+", {0, RelativePosition.FromEnd}), type text}}),
    Eval = Table.AddColumn(Extract, "Evaluate", each Expression.Evaluate([minutes])),
    RC = Table.RemoveColumns(Eval,{"minutes"})
in
    RC[/SIZE]
 
Upvote 0
Hi

If you want a formula, with the values in A2:A5, try:

=SUM(0+(0&TRIM(MID(SUBSTITUTE(A2:A5,"'",REPT(" ",200)),(TRANSPOSE(ROW(INDIRECT("1:"&MAX(LEN(A2:A5)-LEN(SUBSTITUTE(A2:A5,"'",""))))))-1)*200+1,200))))

This is an array formula and so MUST be entered with CTRL+SHIFT+ENTER and not just ENTER.
 
Upvote 0
Now sorted thank for you help. Must admit never heard of power query
 
Upvote 0
Or,

Sum the values in A2:A5

Try,

=SUMPRODUCT(FILTERXML("<t><s>"&SUBSTITUTE(A2&A3&A4&A5,"'","</s><s>")&"</s></t>","//s[.>0]"))

p.s. I have try to edit the above formula, but the forum auto removed some of my formula characters ??

Regards
Bosco
 
Last edited by a moderator:
Upvote 0
@bosco_yip
The board interprets the < & > as HTML tags & formats the post accordingly.
You either need to put spaces around them, or "Go Advanced" and set "HTML" to Off

I have edited your post & hopefully the formula is correct.
 
Last edited:
Upvote 0
Hi Fluff,

Thanks for your help to edit my formula

Regards
Bosco
 
Upvote 0

Forum statistics

Threads
1,223,896
Messages
6,175,260
Members
452,627
Latest member
KitkatToby

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