Question about formulas

rwmill9716

Active Member
Joined
May 20, 2006
Messages
485
Office Version
  1. 2013
Platform
  1. Windows
I'm looking for a more elegant solution than the brute force approach that I've taken here.

First, Cell B4 houses a number that can vary from 5 to 8 for this example (in reality, it can vary from 1 to 100).

For this example, I have another cell that contains the following formula:

= IF($B$4=5,Sum(E10:E15), IF($B$4=6,Sum(E9:E15), IF($B$4=7,Sum(E8:E15), IF($B$4=8,Sum(E7:E15), 0)))

This formula is then copied through 5,000 cells.

Is their a way to incorporate the value in cell B4 directly into the range values in the Sum(s) so the formula simplifies. Since B4 can contain many more values, this brute force method becomes burdensome.

Thanks,

Ric Miller
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Hi Ric,

Here's one variation which should do what I think you want it to:

Code:
=SUM(INDEX(E1:E15,ROWS(E1:E15)-B4):E15)
 
Upvote 0
You'll get some volatility with 5000 copies with the INDEX versions as well as with:

=SUM(OFFSET(E15,0,0,-$B$4))
 
Upvote 0

Forum statistics

Threads
1,203,760
Messages
6,057,210
Members
444,914
Latest member
Mamun12345

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