Auto adjust sum

tiredofit

Well-known Member
Joined
Apr 11, 2013
Messages
1,825
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Assume I have the values 10 and 20 in cells A1 and A2 and cell A3 contains the formula:

Code:
=Sum(A1:A2)

which evaluates to 30, as expected.

If I inserted a row between rows 1 and 2, cell A1 would still show 10, cell A3 now shows 20 and cell A4 shows an adjusted formula:

Code:
=Sum(A1:A3)

Now if I deleted row 2, the sum row (now reverts to row 3) will show:

Code:
=Sum(A1:A2)

The problem is if I deleted row 2, the sum row now will shift up one row to row 2 and show:

Code:
Sum(A1:A1)

but now if I inserted a row after row 1, the sum row (although will shift to row 2) will still show:

Code:
=Sum(A1:A1)

which is incorrect.

Is there a way to correct this?

Thanks
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Based on what you've said, try
Excel Formula:
=SUM(INDEX(A:A,1):INDEX(A:A,ROW()-1)))
 
Upvote 0
Based on what you've said, try
Excel Formula:
=SUM(INDEX(A:A,1):INDEX(A:A,ROW()-1)))
Thanks, that worked as required.

However if the condition changed slightly, how might your solution be amended?

Suppose instead there are values in cells A1 through to A9 and cell A10 is the sum row, summing rows 1 to 9.

Also cells A11 through to A19 contain values and cell A20 is the sum row, summing rows 11 to 19.

If the user inserted / removed rows (obviously NOT removing the sum rows), how can you adjust your formula to make it work?

I tried:

Code:
=SUM(INDEX(A1:A9,1):INDEX(A1:A9,ROW()-1))

which almost worked except if I inserted above row 1 or the sum row, it returned #REF.
 
Last edited:
Upvote 0
There are likely more ways to break it that you haven't found yet. This is a bit clunky but it appears to be reliable.
Excel Formula:
=SUBTOTAL(9,INDEX(A:A,1):INDEX(A:A,ROW()-1))-(SUM(INDEX(A:A,1):INDEX(A:A,ROW()-1))-SUBTOTAL(9,INDEX(A:A,1):INDEX(A:A,ROW()-1)))
 
Upvote 0
Solution
There are likely more ways to break it that you haven't found yet. This is a bit clunky but it appears to be reliable.
Excel Formula:
=SUBTOTAL(9,INDEX(A:A,1):INDEX(A:A,ROW()-1))-(SUM(INDEX(A:A,1):INDEX(A:A,ROW()-1))-SUBTOTAL(9,INDEX(A:A,1):INDEX(A:A,ROW()-1)))
Thanks, it works but can you explain what it's doing?

I've broken down your formula into three parts:

Subtotal-(sum-subtotal).

Why do you need (sum-subtotal)?

Is it because subtotal(9,Index(A:A,1):Index(A:A, Row()-1)) sums the entire where value is NOT a formula?
 
Last edited:
Upvote 0
Is it because subtotal(9,Index(A:A,1):Index(A:A, Row()-1)) sums the entire where value is NOT a formula?
Effectively, yes. The subtotal function ignores other subtotals while the sum function doesn't.

(sum-subtotal) will give you the sum of the previous formulas (zero in the case of the first one) which is also the same as the sum for the previous group(s) of data.
Summing all of the groups of data (with the first subtotal in the formula) then subtracting the sum of the previous group(s) using (sum - subtotal) gives you the total for the current group.
 
Upvote 0
Effectively, yes. The subtotal function ignores other subtotals while the sum function doesn't.

(sum-subtotal) will give you the sum of the previous formulas (zero in the case of the first one) which is also the same as the sum for the previous group(s) of data.
Summing all of the groups of data (with the first subtotal in the formula) then subtracting the sum of the previous group(s) using (sum - subtotal) gives you the total for the current group.
brilliant, thanks for your help.
 
Upvote 0

Forum statistics

Threads
1,213,504
Messages
6,114,020
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