Sum up values based on comma separated values that reference a table

aperkinsptx

New Member
Joined
Dec 2, 2014
Messages
2
Hi, I'm new to posting on forums like this so bare with me as I try to explain what I'm attempting to accomplish.

My company has a lab and we run different tests for different samples. I'm trying to find the total time the sample will take to run based on the tests selected. We currently have lists of tests to run listed in a single cell as comma separated values. I have a separate sheet where I have listed each of those tests and the average time for each test to be run. I'd like to return the sum.

Below is how I would do it manually. The formula would be in the "Total Sample Time" column.

Tests to Run
Total Sample Time
Test 1, Test 2, Test 3 = 5+10+12=27
Test 3, Test 4
=12+1=13
Test 1, Test 3, Test 4 , Test 5 =5+12+1+15=33

<colgroup><col><col></colgroup><tbody>
</tbody>

Test Type
Time (min)
Test 15
Test 210
Test 312
Test 41
Test 515

<colgroup><col><col></colgroup><tbody>
</tbody>

I'm just not sure what type of formula needs to be in the cell to be able to sum up the values from a table based on the comma separated values.

Thanks in advance for your help!
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Assuming that A1:B11 contains the table, try...

B2, confirmed with CONTROL+SHIFT+ENTER, and copied down:

=SUM(IF(ISNUMBER(SEARCH(","&$A$7:$A$11&",",","&SUBSTITUTE(SUBSTITUTE(TRIM(A2)," ,",","),", ",",")&",")),$B$7:$B$11))

Note that the formula allows extra spaces within the text string, such as the text string in A4. Also, note that the SEARCH function is not case-sensitive. For a case-sensitive formula, replace SEARCH with FIND.

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,214,935
Messages
6,122,337
Members
449,077
Latest member
Jocksteriom

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