Sum from a table if the key matches a variable array

Scotster

Board Regular
Joined
May 29, 2017
Messages
59
Office Version
  1. 365
  2. 2019
  3. 2016
Platform
  1. Windows
I'm positive there's a way to do this but I can't figure it out and my searching has come up empty so far so hoping someone can help.

I have a reference table with a planned input quantity.

I then have a second table that references the above, I would like to sum the product of hits. Hopefully the examples below indicate what I'm looking to do, I cannot upload on the works PC for security reasons.

ItemAugSeptOctNovDecJanFeb
Apples00051100
Oranges31011135
Bananas111218523
Pears6151716262729
Grapes50100100100505010



LocationProvidesAugSeptOctNovDecJanFeb
Shop1Apples, Oranges31016
Shop2Bananas, Pears7
Shop3Apples, Oranges, Bananas, Pears10
Shop4Bananas, Pears, Grapes57

Hopefully the above makes sense. The items are variable and at any one time there are around 20, the basic method would be to create 20 columns for each month but that isn't practical. Provides are quite variable as well. Some have only one, others have many.

The locations are in the 1000s and wildly variable, hence why I would really like to get it working as suggested.

Any help appreciated.
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
For 365, how about
Fluff.xlsm
ABCDEFGH
1ItemAugSeptOctNovDecJanFeb
2Apples00051100
3Oranges31011135
4Bananas111218523
5Pears6151716262729
6Grapes50100100100505010
Sheet1


Fluff.xlsm
ABCDEFGHI
1LocationProvidesAugSeptOctNovDecJanFeb
2Shop1Apples, Oranges310162135
3Shop2Bananas, Pears7162934312932
4Shop3Apples, Oranges, Bananas, Pears10263040334237
5Shop4Bananas, Pears, Grapes57116129134817942
Sheet6
Cell Formulas
RangeFormula
C2:I5C2=SUM(SUMIFS(INDEX(Sheet1!$B$2:$H$100,,XMATCH(C$1,Sheet1!$B$1:$H$1)),Sheet1!$A$2:$A$100,TRIM(TEXTSPLIT($B2,","))))
 
Upvote 0
Solution
Spot on. Text split was the key that I was looking for. Thankyou so much, especially for getting back so quickly. My head is fried :LOL:
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,223,880
Messages
6,175,153
Members
452,615
Latest member
bogeys2birdies

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