Variable Range for SUM Function

bajturner

New Member
Joined
May 1, 2002
Messages
5
I tried posting this once but it didn't seem to work, my apologies if it appears twice.

I would like to dynamically construct a range to be used in a SUM function but I can not get the addresses into the function after constructing them.

For example, I create the addresses of lower and upper limits of the range using the ADDRESS function, and then I want to put them in the SUM function. I thought the following would work to add up only the data under the months up to this month (I have the data for 12 months in row 5 starting at column H):

SUM(ADDRESS(ROW(F5),8,4):ADDRESS(ROW(F5),(7+MONTH(TODAY())),4))

but the output from the ADDRESS function is text and not accepted as an actual address.

Can anyone help?

Thank you,
Brian
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
you could use indirect

=SUM(INDIRECT(ADDRESS(ROW(F5),8,4)&":"&ADDRESS(ROW(F5),(7+MONTH(TODAY())),4)))

Or depending on your criteria, maybe a sumif statement maybe better suited. I'm not going to pretend I tried to figure out what you wanted to add here.
 
Upvote 0
On 2002-05-02 11:52, bajturner wrote:
I tried posting this once but it didn't seem to work, my apologies if it appears twice.

I would like to dynamically construct a range to be used in a SUM function but I can not get the addresses into the function after constructing them.

For example, I create the addresses of lower and upper limits of the range using the ADDRESS function, and then I want to put them in the SUM function. I thought the following would work to add up only the data under the months up to this month (I have the data for 12 months in row 5 starting at column H):

SUM(ADDRESS(ROW(F5),8,4):ADDRESS(ROW(F5),(7+MONTH(TODAY())),4))

but the output from the ADDRESS function is text and not accepted as an actual address.

Can anyone help?

Thank you,
Brian

Brian,

If you build a range reference using the ADDRESS worksheet function, you need to deference it with INDIRECT before feeding the built range to another worksheet function.

So:

=SUM(INDIRECT(ADDRESS(ROW(F5),8,4)&":"&ADDRESS(ROW(F5),(7+MONTH(TODAY())),4)))

should work.

I might as well add that although fully legal, it's not most efficient way.

Regards,

Aladin
 
Upvote 0
The INDIRECT function returns the reference specified by text. Try something like:

SUM(IDIRECT(ADDRESS(ROW(F5),8,4)&":"&ADDRESS(ROW(F5),(7+MONTH(TODAY())),4)))
 
Upvote 0
Thank you both for you replies. It worked! I had tried using INDIRECT but did not include the &":"&. That was the problem.

Just out of curiosity Aladin, what is a more elegant way to achieve the same thing?

Brian
 
Upvote 0
On 2002-05-02 12:07, bajturner wrote:
Thank you both for you replies. It worked! I had tried using INDIRECT but did not include the &":"&. That was the problem.

Just out of curiosity Aladin, what is a more elegant way to achieve the same thing?

Brian


I'd use the OFFSET worksheet function to specify the range over which to compute SUM, etc.

But, try to figure out whether the SUMIF function would serve your purpose as IML noted.

Aladin
 
Upvote 0

Forum statistics

Threads
1,213,534
Messages
6,114,186
Members
448,554
Latest member
Gleisner2

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