Sum based on looking up mutliple comma seperated values.

Ronanm

Board Regular
Joined
Nov 13, 2010
Messages
107
Hi

In Cell E2 below I have the formula =SUMPRODUCT(SUMIF($A$2:$A$5,MID(SUBSTITUTE(D2,",",""),ROW(INDIRECT("1:"&LEN(SUBSTITUTE(D2,",","")))),4),$B$2:$B$5)) and it works a treat.
However I need the same in G2 to J2 (the ?'s), where it pulls out the values based on the Heading in G1 to J2. Thanks if you can help.



CodeAmountA123A124A125A126
A123
5​
A124,A126
15​
???
A124
6​
A125
8​
A126
9​
 
Thanks but the values I need to consider are in Cell D2 as well. So in the case of H2, the "?" That will sum up A124 Codes, as the header in H1 saysA124, and as there are two of them in Cell D2, the total will be 12.
Cheers
 
Upvote 0

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
In G2, formula copied across to J2 :

=IFERROR(1/(1/(VLOOKUP(G$1,$A$2:$B$5,2,0)*((LEN($D2)-LEN(SUBSTITUTE($D2,G$1,"")))/LEN(G$1)))),"")

Regards
 
Upvote 0
I'm looking for a very similar formula for cell E2 (see below). How would this formula be modified if the "Code" was not always 4 characters (could be any number of characters) and the delimiter in cell D2 is a ", " (comma followed by a space)?

=SUMPRODUCT(SUMIF($A$2:$A$5,MID(SUBSTITUTE(D2,",",""),ROW(INDIRECT("1:"&LEN(SUBSTITUTE(D2,",","")))),4),$B$2:$B$5))
 
Upvote 0
Please start a new thread for this question.

Also I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
 
Upvote 0

Forum statistics

Threads
1,213,506
Messages
6,114,025
Members
448,543
Latest member
MartinLarkin

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