Sum top items between two sheets

joeltes

New Member
Joined
Mar 16, 2018
Messages
21
Hi all,

I have two sheets that contain products and the amount sold, I'm trying to sum the total items sold for only 5 items that sold most. Trick is I want to split the 5 items to sum between two sheets, on sheet1 sum only 2 of 5 (value in D1)

ABCD
1# Rows Count2
2PA15
3PB45
4PC7
5PD12
6PE2
7PM6
8PN18

<tbody>
</tbody>

then check sheet2 and sum the rest of 5 (in this case 3)

AB
1PF21
2PG5
3PH9
4PI16
5PJ8
6PK33
7PL2

<tbody>
</tbody>

In this example the results would be, the top 5 items sold a total of 133. note that only sheet1 specifies the amount of rows to sum.
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
This?


Excel 2010
AB
1PF21
2PG5
3PH9
4PI16
5PJ8
6PK33
7PL2
Sheet10



Excel 2010
ABCD
1# Rows Count2
2PA15
3PB45133
4PC7
5PD12
6PE2
7PM6
8PN18
Sheet9
Cell Formulas
RangeFormula
D3=SUMPRODUCT(--($B$2:$B$8>=LARGE($B$2:$B$8,D1)),$B$2:$B$8)+SUMPRODUCT(--(Sheet10!$B$1:$B$7>=LARGE(Sheet10!$B$1:$B$7,5-D1)),Sheet10!$B$1:$B$7)
 
Last edited:
Upvote 0

Book1
ABCDE
1#Rows Count2133
2PA15
3PB45
4PC7
5PD12
6PE2
7PM6
8PN18
Sheet1
Cell Formulas
RangeFormula
E1=SUMPRODUCT(LARGE($B$2:$B$8,ROW(INDIRECT("1:"&$D$1))))+SUMPRODUCT(LARGE(Sheet2!$B$1:$B$7,ROW(INDIRECT("1:"&5-$D$1))))



Book1
AB
1PF21
2PG5
3PH9
4PI16
5PJ8
6PK33
7PL2
Sheet2


WBD
 
Upvote 0
Both of these worked great as there will be no dups. Thanks for response and knowledge.

How can I add a condition to sum only if C:C=1 and if C:C=0 look at the next row until total is 5 rows?
 
Upvote 0
What will be in the other column C cells besides 0s and 1s? blanks?


When using the following, it excludes where C:C=0 from the sum but it doesn't look for another row to fulfill its place in the sum (from the total 5)
=SUMPRODUCT(--(PTRN!$M:$M>=LARGE(PTRN!$M:$M,PTRN!$X$2)),PTRN!$M:$M)+SUMPRODUCT(--($C:$C=1),--($O:$O>=LARGE($O:$O,50-PTRN!$X$2)),$O:$O)
 
Upvote 0
This?


Excel 2010
ABCDE
1# Rows Count2
2PA150
3PB45088
4PC71
5PD121
6PE20
7PM60
8PN181
Sheet1
Cell Formulas
RangeFormula
E3{=SUM(LARGE(IF($C$2:$C$8=1,$B$2:$B$8),ROW(INDIRECT("1:"&$D$1))))+SUM(LARGE(IF(Sheet2!$C$1:$C$7=1,Sheet2!$B$1:$B$7),ROW(INDIRECT("1:"&5-$D$1))))}
Press CTRL+SHIFT+ENTER to enter array formulas.



Excel 2010
ABC
1PF210
2PG50
3PH91
4PI161
5PJ80
6PK331
7PL21
Sheet2
 
Upvote 0
This?

Array Formulas
CellFormula
E3{=SUM(LARGE(IF($C$2:$C$8=1,$B$2:$B$8),ROW(INDIRECT("1:"&$D$1))))+SUM(LARGE(IF(Sheet2!$C$1:$C$7=1,Sheet2!$B$1:$B$7),ROW(INDIRECT("1:"&5-$D$1))))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>

This returns only the largest value of both sheets, its also ignoring if C=1
 
Upvote 0

Forum statistics

Threads
1,212,933
Messages
6,110,759
Members
448,295
Latest member
Uzair Tahir Khan

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