Sum Formula Needed

kelly mort

Well-known Member
Joined
Apr 10, 2017
Messages
2,169
Office Version
  1. 2016
Platform
  1. Windows
Hello All,
I wanna add six numbers in a column. There will be a maximum of nine numbers to choose what to add from. Before, I used the =Sum(Small(..... Function.

But now I want to add them by taking the first four numbers then look for the two smallest numbers from the remaining five numbers.

And here too, with the first four numbers, I am adding only those that are not zero or blank.

That's when one of the first four numbers is zero or blank then add the three left and add the next three smallest numbers from the five numbers left.

Look at what I have below here:
Numbers to add
2
5
8
1
4
4
6
5
7

So from the numbers , after choosing the first four, choose the two 4s since there are the two smallest numbers left. Then add them.


When some of the first four is blank or zero
Numbers to add
2

8
1
4
4
6
5
7

Since the second number is blank, choose the three left and then choose 4, 4, 5 from them and add to the other three.

I hope my expectations are clear enough.

Thanks for your attention
Kelly
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
This?


[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
Numbers​
[/td][td]
Result​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
2​
[/td][td]
24​
[/td][/tr]

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

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

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

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td]
4​
[/td][td][/td][/tr]

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

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

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

[tr][td="bgcolor: #DCE6F1"]
10
[/td][td]
7​
[/td][td][/td][/tr]
[/table]


Formula in B2
=SUM(A2:A5)+SUM(SMALL(A6:A10,{1;2;3}))

M.
 
Upvote 0
Yes .

But I will want the part {1;2;3} to be dynamic. That's if I added 4 numbers from the first set, then this part in curly bracket takes only two . If I added 3 numbers from the first set then the curly bracket must have 3 and so on.

Thanks a lot
But I can use nested if functions to do it from here:
@Marcelo
 
Last edited:
Upvote 0
Maybe

=SUM(A$2:A$5)+SUMPRODUCT(SMALL(A$6:A$10,ROW(A$1:INDEX($A:$A,6-COUNT(A$2:A$5)))))

M.
 
Upvote 0
Very sure!


Thanks for this wonderful formula. Can you explain it for me a little bit?
Kelly
 
Last edited:
Upvote 0
Hi Kelly

The function ROW(A1:A3), for example, generates a vertical array {1;2;3}.

Taking in account this, let's analyze this part
ROW(A$1:INDEX($A:$A,6-COUNT(A$2:A$5)))

COUNT(A$2:A$5) returns how many numbers there are in A2:A5
Subtracting from 6 we get how many numbers should be added from the range A6:A10, that is:
6-3 = 3
So ROW(...) becomes
ROW(A$1:INDEX($A:$A,3)) --> ROW(A$1:A$3) --> {1;2;3}

And, at last, we have
SUMPRODUCT(SMALL(A$6:A$10,{1;2;3}))
as desired

To see, step by step, what the formula does select B2 and try Formulas > Evaluate formula.

M.
 
Last edited:
Upvote 0
Oh okay thank you a lot for the explanation. I am still learning each day.
Kelly
 
Upvote 0
Why did you start the row from A1 but not A2?

I am a bit confused over there

Thanks again
Kelly


Ps:
Oh okay. I just found out why . For the vertical array. Oh nice . Thanks again
 
Last edited:
Upvote 0
Because we need an array {1;2;3} to get the smallest; 2nd smallest; 3rd smallest
ROW(A1:A3) has nothing to do with the location of your data, it's only a way to generate the array {1;2;3}
I could have used ROW(B1:B3) or ROW(Z1:Z3) for example.

M.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,021
Latest member
Justyna P

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