Sales for multiple products in 1 Cell (to account for table order and #N/A)

bilal_aoun

New Member
Joined
May 3, 2021
Messages
25
Office Version
  1. 2016
Platform
  1. Windows
Would you please help me find the sale in a single cell?
Sales per day in cells B2:H9
Product type A5:A9
Product Price
B16:C21

If we are to transpose the date in cells E17:E24, can we find the total sales in dollar in F18:F24?
1620077205704.png




=SUMPRODUCT(INDEX($B$5:$H$9,0,MATCH(E18,$B$4:$H$4,0))*($A$5:$A$9=TRANSPOSE($B$17:$B$21))*$C$17:$C$21)

Now I am trying to make this more dynamic (not impacted by NA or the order in B17:C21
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
How about
Excel Formula:
=SUMPRODUCT(INDEX($B$5:$H$10,0,MATCH(E18,$B$4:$H$4,0))*($A$5:$A$10=TRANSPOSE($B$17:$B$22))*TRANSPOSE($C$17:$C$22))
 
Upvote 0
Please use XL2BB next time so that no one has to type your data.

Book7
ABCDEFGH
3
43/28/20214/4/20214/11/20214/18/20214/25/20215/2/20215/9/2021
5Apple26910253
6Orange1362824
7Cherry1035621
8Water23011011
9Juice10002380
10
11
12
13
14
15
16
17Apple$ 1.003/28/2021149
18Orange$ 2.004/4/202112
19Cherry$ 3.004/11/202134
20Water$ 4.004/18/202143
21Juice$ 5.004/25/202151
225/2/202159
235/9/202118
Sheet1
Cell Formulas
RangeFormula
F17:F23F17=SUMPRODUCT(($C$17:$C$21)*INDEX($B$5:$H$9,,MATCH(E17,$B$4:$H$4,0)))
 
Upvote 0
How about
Excel Formula:
=SUMPRODUCT(INDEX($B$5:$H$10,0,MATCH(E18,$B$4:$H$4,0))*($A$5:$A$10=TRANSPOSE($B$17:$B$22))*TRANSPOSE($C$17:$C$22))
This will error if I extend the range for any of my tables
 
Upvote 0
Which ranges are you changing?
 
Upvote 0
If either of our formulas are adjusted for more dates, etc., they both work.

Book7
ABCDEFGHIJKLM
43/28/20214/4/20214/11/20214/18/20214/25/20215/2/20215/9/20215/16/20215/23/20215/30/20216/6/20216/13/2021
5Apple269102531010
6Orange136282420
7Cherry103562130
8Water2301101140
9Juice1000238050
10
11
12
13
14
15
16
17Apple$ 1.003/28/2021149149
18Orange$ 2.004/4/20211212
19Cherry$ 3.004/11/20213434
20Water$ 4.004/18/20214343
21Juice$ 5.004/25/20215151
225/2/20215959
235/9/20211818
245/16/202100
255/23/20211010
265/30/202100
276/6/2021550550
286/13/202100
Sheet1
Cell Formulas
RangeFormula
F17:F28F17=SUMPRODUCT(($C$17:$C$21)*INDEX($B$5:$M$9,,MATCH(E17,$B$4:$M$4,0)))
H17:H28H17=SUMPRODUCT(INDEX($B$5:$M$9,0,MATCH(E17,$B$4:$M$4,0))*($A$5:$A$9=TRANSPOSE($B$17:$B$21))*TRANSPOSE($C$17:$C$21))
 
Upvote 0
Which ranges are you changing?
Both A4:H9 and E17:F23 more transactions and more items will be added to this I Know I will have to organize this but trying to get the logic :)

Thanks,
 
Upvote 0
@kweaver
Your formula wont work if the order of the products differs.
+Fluff 1.xlsm
ABCDEFGHI
1
2
3
428/03/202104/04/202111/04/202118/04/202125/04/202102/05/202109/05/2021
5Apple26910253
6Orange1362824
7Cherry1035621
8Water23011011
9Juice10002380
10
11
12
13
14
15
16
17Apple1
18cherry328/03/202114996
19juice504/04/20211215
20orange211/04/20213444
21water418/04/20214351
2225/04/20215168
2302/05/20215955
2409/05/20211822
25
Master
Cell Formulas
RangeFormula
F18:F24F18=SUMPRODUCT(INDEX($B$5:$J$10,0,MATCH(E18,$B$4:$J$4,0))*($A$5:$A$10=TRANSPOSE($B$17:$B$31))*TRANSPOSE($C$17:$C$31))
G18:G24G18=SUMPRODUCT(($C$17:$C$21)*INDEX($B$5:$H$9,,MATCH(E18,$B$4:$H$4,0)))
 
Upvote 0
Solution
Do you have any dates in E18:E24 that do not exist in row 4?
 
Upvote 0
This why I trying to get a fix for this to account for different order .

Also if I would like to extended the range for the future ( The table will have blanks which will cause an error )
 
Upvote 0

Forum statistics

Threads
1,212,927
Messages
6,110,720
Members
448,294
Latest member
jmjmjmjmjmjm

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