Array Formula Question, probably fairly basic

TomCon

Active Member
Joined
Mar 31, 2011
Messages
373
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
I'm fairly new to array formulas. I thought i "got it" but this one is not behaving as i expect, so maybe i do not fullly understand.

I entered this as an array formula.
{=SUM(OFFSET(M2,{0,1,2},0))}

I thought that it would be equivalent to
=SUM((OFFSET(M2,0,0,3,1)))

And equivalent, of course, to:
=SUM(M2:M4)

But, the array formula always returns the first value, i.e. the value in M2.

Can somebody explain why the array formula does not sum the values M2, M3, M4?

(Of course this is a reduced, clearer question, of a more complex situation I have).

Thanks!
Tom
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
The OFFSET function doesn't accept an array as an argument. The Formula Evaluation tool shows that only the first value is used.
 
Upvote 0
I'm fairly new to array formulas. I thought i "got it" but this one is not behaving as i expect, so maybe i do not fullly understand.

I entered this as an array formula.
{=SUM(OFFSET(M2,{0,1,2},0))}

I thought that it would be equivalent to
=SUM((OFFSET(M2,0,0,3,1)))

And equivalent, of course, to:
=SUM(M2:M4)

But, the array formula always returns the first value, i.e. the value in M2.

Can somebody explain why the array formula does not sum the values M2, M3, M4?

(Of course this is a reduced, clearer question, of a more complex situation I have).

Thanks!
Tom

=SUM(OFFSET(M2,{0,1,2},0))

suffers from what is known as the dereferencing problem. In order to get
the desired total, you need a second round of evaluation like in:

=SUM(SUBTOTAL(9,(OFFSET(M2,{0,1,2},0))))

=SUM(N(OFFSET(M2,{0,1,2},0)))
 
Upvote 0
Thanks for the help. Good idea to use the formula eval tool to help diagnose. As for reference to the "dereferencing problem" can you explain that more (and/or a link)? For instance, while i can veriy that this formula works {=SUM(N(OFFSET(M2,{0,1,2},0)))}, i don't really understand why it is necessary to use the N() fucntion in that way.

Thanks!
Tom
 
Upvote 0
Thanks for the help. Good idea to use the formula eval tool to help diagnose. As for reference to the "dereferencing problem" can you explain that more (and/or a link)? For instance, while i can veriy that this formula works {=SUM(N(OFFSET(M2,{0,1,2},0)))}, i don't really understand why it is necessary to use the N() fucntion in that way.

Thanks!
Tom

http://tinyurl.com/3hhjayv

The link shows many discussions of the issue on this board. A few more can be found on (the old) Excel-related newsgroups.
 
Upvote 0

Forum statistics

Threads
1,214,814
Messages
6,121,711
Members
449,049
Latest member
THMarana

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