Sum if it's bottom n values in other sheet

reagk

New Member
Joined
Apr 7, 2019
Messages
4
Hi, I want to sum n values in sheet 2, if the same rows in sheet1 it's the bottom n values.
For example:
Sheet 1Sheet 2
A8A1
B3B15
C2C14
D7D3
E10E4
F1F20
G4G7
H5H6

<tbody>
</tbody>


So in this case, if n=3, the bottom 3 value are F, C, B.
So the formula should sum F,C,B in sheet 2: 20+14+15= 49

Thanks in advance
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
Try this

<b>sheet2</b><br /><br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:80px;" /><col style="width:80px;" /><col style="width:35px;" /><col style="width:80px;" /><col style="width:80px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">DATA</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">VALUES</td><td > </td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">n</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">RESULT</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >A</td><td style="text-align:right; ">1</td><td > </td><td style="text-align:right; ">3</td><td style="text-align:right; ">49</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >B</td><td style="text-align:right; ">15</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >C</td><td style="text-align:right; ">14</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >D</td><td style="text-align:right; ">3</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >E</td><td style="text-align:right; ">4</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td >F</td><td style="text-align:right; ">20</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td >G</td><td style="text-align:right; ">7</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td >H</td><td style="text-align:right; ">6</td><td > </td><td > </td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >E2</td><td >=SUMPRODUCT((sheet1!B2:B9<=D2)*(B2:B9))</td></tr></table></td></tr></table> <br /><br />
 
Upvote 0
Hi DanteAmor,
Thanks but it's not really working.
The value is not always 3 and changing all the time.
 
Upvote 0
Didn't bother to set up Sheet2 )On its page), but maybe...
Copy DOWN F2


Excel 2010
ABCDEFGH
1Sheet 1Sheet 2Extractionn = >>3
2A8A120
3B3B1514Total >>49
4C2C1415
5D7D30
6E10E40
7F1F200
8G4G70
9H5H60

<tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
H3=SUM(F2:F9)
F2=IF(ROW()-1<=$H$1,OFFSET(E$7,-B7+1,0,1,1),0)

<tbody>
</tbody>

<tbody>
</tbody>
 
Upvote 0
Hi DanteAmor,
Thanks but it's not really working.
Describe "not really working" for us. As far as I can tell, Dante's formula should work fine.



The value is not always 3 and changing all the time.
Perhaps the problem is in the way the "3" is specified. Dante assumed it would always be specified in cell D2. How did you want the number to be specified for the formula?
 
Upvote 0
Hi Rick, It does works once I specify the value in D2 as =small('sheet1'!b2:b11,3)
Just think there is more beautiful way for this solution.
Thanks
 
Upvote 0
Hi DanteAmor,
Thanks but it's not really working.
The value is not always 3 and changing all the time.


I already know that the value is not always 3, so you have the option to put it in cell D2, if you do not want it in a cell, just put the number in the formula:


=SUMPRODUCT((sheet1!B2:B9<=3)*(B2:B9))

or
=SUMPRODUCT((sheet1!B2:B9<=4)*(B2:B9))

Or the number you want.
 
Upvote 0
Describe "not really working" for us. As far as I can tell, Dante's formula should work fine.

Perhaps the problem is in the way the "3" is specified. Dante assumed it would always be specified in cell D2. How did you want the number to be specified for the formula?

Thanks Rick Rothstein
user-offline.png
for the support, let's wait for him to define where he wants the 3 or how is the most beautiful solution.
 
Upvote 0
Thanks Rick Rothstein
user-offline.png
for the support, let's wait for him to define where he wants the 3 or how is the most beautiful solution.
Maybe all he needs to do is incorporate his SMALL function into your formula and do away with the need for cell D2 altogether...

=SUMPRODUCT((sheet1!B2:B9<=SMALL(sheet1!B2:B11,3))*(B2:B9))
 
Last edited:
Upvote 0
Maybe all he needs to do is incorporate his SMALL function into your formula and do away with the need for cell D2 altogether...

=SUMPRODUCT((sheet1!B2:B9<=SMALL(sheet1!B2:B11,3))*(B2:B9))


Oh, that's right, you need the 3 minor numbers, not the ones that are less than 3

How about:

=SUMPRODUCT((sheet1!B2:B9<=SMALL(sheet1!B2:B9,D2))*(B2:B9))

:LOL:
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,636
Messages
6,120,669
Members
448,977
Latest member
moonlight6

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