array formula to perform vlookup and sumproduct at once

jerryjacobi

New Member
Joined
Nov 27, 2017
Messages
2
Hi,
I am trying to compile an array formula to perform following action:

Here are input data:

Prices in EUR for parts for months
[TABLE="width: 500"]
<tbody>[TR]
[TD][/TD]
[TD]Jan 2018[/TD]
[TD]Feb 2018[/TD]
[TD]Mar 2018[/TD]
[TD]Apr 2018[/TD]
[/TR]
[TR]
[TD]PART1[/TD]
[TD]1[/TD]
[TD]2[/TD]
[TD]2[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]PART2[/TD]
[TD]2[/TD]
[TD]3[/TD]
[TD]4[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD]PART3[/TD]
[TD]3[/TD]
[TD]4[/TD]
[TD]5[/TD]
[TD]6[/TD]
[/TR]
</tbody>[/TABLE]

Structures (bill of material) of finished products
[TABLE="width: 500"]
<tbody>[TR]
[TD][/TD]
[TD]PRODUCT1[/TD]
[TD]PRODUCT2[/TD]
[TD]PRODUCT3[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]PRODUCT1[/TD]
[TD]1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]PRODUCT2[/TD]
[TD][/TD]
[TD]1[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]PRODUCT3[/TD]
[TD][/TD]
[TD][/TD]
[TD]1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]PART1[/TD]
[TD]1[/TD]
[TD][/TD]
[TD]1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]PART2[/TD]
[TD]1[/TD]
[TD]1[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]PART3[/TD]
[TD][/TD]
[TD]1[/TD]
[TD]1[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

And now I need to get price of each final product of each month. For example PRODUCT1 is composed of one piece PART1 and one piece PART2. For January they have prices in the first table (1 EUR and 2 EUR). So total price of PRODUCT1 for January is 1x1 + 1x2 => 3 EUR. For February it is 1x2 + 1x3 => 5 EUR.

Final PRICELIST should look like this:
[TABLE="width: 500"]
<tbody>[TR]
[TD][/TD]
[TD]Jan 2018[/TD]
[TD]Feb 2018[/TD]
[TD]Mar 2018[/TD]
[TD]Apr 2018[/TD]
[/TR]
[TR]
[TD]PRODUCT1[/TD]
[TD]3[/TD]
[TD]5[/TD]
[TD]7[/TD]
[TD]9[/TD]
[/TR]
[TR]
[TD]PRODUCT2[/TD]
[TD]5[/TD]
[TD]7[/TD]
[TD]9[/TD]
[TD]11[/TD]
[/TR]
[TR]
[TD]PRODUCT3[/TD]
[TD]4[/TD]
[TD]6[/TD]
[TD]8[/TD]
[TD]10[/TD]
[/TR]
</tbody>[/TABLE]

Is there a way how make an array formula to calculate price in PRICELIST based on above data? I am trying to solve this for days but still can't make it work :-(

It should be combination of vlookup (to find valid price) and sumproduct (to multiply piece prices by number of parts in final product). But this vlookup must return price of all parts for given month ... Am I going in the right direction?

Thank you very much for you help.
BR
Lukas
 

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Welcome to Mr Excel

Maybe something like this - for testing purposes i changed the qty of Part2 in PRODUCT1 (in red)

[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][td="bgcolor: #DCE6F1"]
C
[/td][td="bgcolor: #DCE6F1"]
D
[/td][td="bgcolor: #DCE6F1"]
E
[/td][td="bgcolor: #DCE6F1"]
F
[/td][td="bgcolor: #DCE6F1"]
G
[/td][td="bgcolor: #DCE6F1"]
H
[/td][td="bgcolor: #DCE6F1"]
I
[/td][td="bgcolor: #DCE6F1"]
J
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td][/td][td]
Jan 2018​
[/td][td]
Feb 2018​
[/td][td]
Mar 2018​
[/td][td]
Apr 2018​
[/td][td][/td][td][/td][td]
PRODUCT1​
[/td][td]
PRODUCT2​
[/td][td]
PRODUCT3​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
PART1​
[/td][td]
1​
[/td][td]
2​
[/td][td]
2​
[/td][td]
4​
[/td][td][/td][td]
PRODUCT1​
[/td][td]
1​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
PART2​
[/td][td]
2​
[/td][td]
3​
[/td][td]
4​
[/td][td]
5​
[/td][td][/td][td]
PRODUCT2​
[/td][td][/td][td]
1​
[/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
PART3​
[/td][td]
3​
[/td][td]
4​
[/td][td]
5​
[/td][td]
6​
[/td][td][/td][td]
PRODUCT3​
[/td][td][/td][td][/td][td]
1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
5
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td]
PART1​
[/td][td]
1​
[/td][td][/td][td]
1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td]
PART2​
[/td][td]
2​
[/td][td]
1​
[/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
7
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td]
PART3​
[/td][td][/td][td]
1​
[/td][td]
1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
8
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
9
[/td][td][/td][td]
Jan 2018​
[/td][td]
Feb 2018​
[/td][td]
Mar 2018​
[/td][td]
Apr 2018​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
10
[/td][td]
PRODUCT1​
[/td][td="bgcolor:#D9D9D9"]
5​
[/td][td="bgcolor:#D9D9D9"]
8​
[/td][td="bgcolor:#D9D9D9"]
10​
[/td][td="bgcolor:#D9D9D9"]
14​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
11
[/td][td]
PRODUCT2​
[/td][td="bgcolor:#D9D9D9"]
5​
[/td][td="bgcolor:#D9D9D9"]
7​
[/td][td="bgcolor:#D9D9D9"]
9​
[/td][td="bgcolor:#D9D9D9"]
11​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
12
[/td][td]
PRODUCT3​
[/td][td="bgcolor:#D9D9D9"]
4​
[/td][td="bgcolor:#D9D9D9"]
6​
[/td][td="bgcolor:#D9D9D9"]
7​
[/td][td="bgcolor:#D9D9D9"]
10​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
13
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


Array formula in B10 copied across and down (gray area)
=SUM(INDEX($H$2:$J$7,0,MATCH($A10,$H$1:$J$1,0))*SUMIF($A$2:$A$4,IF(ISNUMBER(INDEX($H$2:$J$7,0,MATCH($A10,$H$1:$J$1,0))),$G$2:$G$7),INDEX($B$2:$E$4,0,MATCH(B$9,$B$1:$E$1,0))))
Ctrl+Shift+Enter

Hope this helps

M.
 
Upvote 0

Forum statistics

Threads
1,223,902
Messages
6,175,278
Members
452,629
Latest member
SahilPolekar

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