Sum variable number of rows with formula

malisesaucier

New Member
Joined
Aug 13, 2013
Messages
2
I would like to be able to copy formula down to sum amounts in COL B based on how many text values in COL A. I have searched to no avail. Is this possible without VBA and without array (would prefer to avoid volatile functions if at all possible)? (Can't use these when uploaded to secondary program) This is simple example of problem.

TIA,
malise

abc110
def2
ghi3
jkl4
abc16
def2
ghi3
abc13
def2

<tbody>
</tbody>
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Hello and welcome to the board,

If you mean you want to sum the range for each cell that has text you could use something like this, okay for simple cases as you show, assumes the first example data from A1:B4:

=SUMIFS(B1:B4,A1:A4,">=a")
 
Upvote 0
Thanks for the welcome and assistance!

The range will change so can't have static range to copy down. There are another 50-60 in my real world problem. :)
Some are 2 lines, some are 40-50 lines.

Regards,
Malise
 
Upvote 0
If you are saying the data is in blocks, separated by blanks, in a single column as you show, then off the top of my head, I would say that is not possible with a non-array formula or without vba.
 
Upvote 0
You could use this CSE formula

=IF(A1="abc",SUM(OFFSET(B1,0,0,MATCH(0,LEN(A2:A$65536),0))),"") in C1

If the "abc" varies insert a blank column and put the below in C2
=IF(A1="",SUM(OFFSET(B2,0,0,MATCH(0,LEN(A3:A$65536),0))),"")

These formulas have to be entered with Ctrl-Shift-Enter (Cmd+Return for Mac), which, combined with the volatile OFFSET will slow things down.

There should be a better formula.
 
Upvote 0
Maybe....


A
B
C
1
Text​
Value​
Sum​
2
abc​
1​
10​
3
def​
2​
4
ghi​
3​
5
jkl​
4​
6
7
8
abc​
1​
6​
9
def​
2​
10
ghi​
3​
11
12
13
abc​
1​
3​
14
def​
2​
15
16
17
abc​
1​
21​
18
def​
2​
19
ghi​
3​
20
jkl​
4​
21
mno​
5​
22
pqr​
6​
23

Formula in C2 copied down
=IF(AND(A2<>"",OR(A1="Text",A1="")),SUMIF(A2:$A$1000,"<>",B2:$B$1000)-SUM(C3:$C$1000),"")

Hope this helps

M.
 
Upvote 0
Hello Marcello, nice approach,

The OP says "text" values in column A, maybe that is all that is there and your formula will do the job, but if it can contain numbers, I think the formula will still return the value for the cell/row with the number. Can your formula be modified to only sum the text, without an array formual?
 
Last edited:
Upvote 0
I think this may do it, but I need to test further:

=IF(AND(A2<>"",OR(A1="Text",A1="")),SUMPRODUCT(--ISTEXT(A2:$A$1001),B2:$B$1001)-SUM(C3:$C$1000),"")
 
Upvote 0

Forum statistics

Threads
1,213,511
Messages
6,114,054
Members
448,543
Latest member
MartinLarkin

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