Array Formula Question, probably fairly basic

TomCon

Active Member
Joined
Mar 31, 2011
Messages
270
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
 

Some videos you may like

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
The OFFSET function doesn't accept an array as an argument. The Formula Evaluation tool shows that only the first value is used.
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,192
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)))
 

TomCon

Active Member
Joined
Mar 31, 2011
Messages
270
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
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
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,192
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.
 

Watch MrExcel Video

Forum statistics

Threads
1,108,624
Messages
5,523,966
Members
409,547
Latest member
AW2020

This Week's Hot Topics

Top