+ Reply to Thread
Results 1 to 10 of 10

Behavior of Offset function in an array formula

  1. #1
    Valued Forum Contributor mohd9876's Avatar
    Join Date
    05-04-2011
    Location
    Amman, Jordan
    MS-Off Ver
    Excel 2010
    Posts
    426

    Behavior of Offset function in an array formula

    Dear Experts,

    I have noticed a strange behavior in Offset function when used in an array formula. The problem is that I used Offset to create an array of the non blank cells from a range and when I evaluate the formula in edit mode (by selecting the whole formula and pressing F9) it evaluates to the array that I want. However, when I use the same formula with the SUM function or COUNT function or whatever, it only takes the first element.

    Is this a normal behavior of the Offset function?? or am I missing something?
    Please refer to the attached workbook to get a grip of what I am experiencing.

    Regards,
    Mohammad
    Attached Files Attached Files

  2. #2
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,086

    Re: Behavior of Offset function in an array formula

    Not entirely sure why this works, it was just a "what if" ...

    =SUM(SUM(OFFSET($A$1,SMALL(IF($A$1:$A$8<>"",ROW($A$1:$A$8)),ROW(INDIRECT("1:"&COUNT($A$1:$A$8))))-1,0)))

    Array Entered with Ctrl-Shift-Enter and displayed as:

    {=SUM(SUM(OFFSET($A$1,SMALL(IF($A$1:$A$8<>"",ROW($A$1:$A$8)),ROW(INDIRECT("1:"&COUNT($A$1:$A$8))))-1,0)))}


    Regards, TMS
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  3. #3
    Valued Forum Contributor mohd9876's Avatar
    Join Date
    05-04-2011
    Location
    Amman, Jordan
    MS-Off Ver
    Excel 2010
    Posts
    426

    Re: Behavior of Offset function in an array formula

    That is a mystery!!!!

    the purpose was to create data validation list using the used Offset function but when used it displays only the first element and also when you define a name referring to the same formula (offset formula) it also only displays the first element.

    i guess i will have to use a helper column to create the list!!

    Thanks for you help

  4. #4
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,086

    Re: Behavior of Offset function in an array formula

    You're welcome. Thanks for the rep.

    Sorry I couldn't provide more help.

  5. #5
    Forum Guru JosephP's Avatar
    Join Date
    03-27-2012
    Location
    Ut
    MS-Off Ver
    2003/10
    Posts
    7,328

    Re: Behavior of Offset function in an array formula

    a data validation list must be a contiguous range. there is no way round that
    Josie

    if at first you don't succeed try doing it the way your wife told you to

  6. #6
    Valued Forum Contributor mohd9876's Avatar
    Join Date
    05-04-2011
    Location
    Amman, Jordan
    MS-Off Ver
    Excel 2010
    Posts
    426

    Re: Behavior of Offset function in an array formula

    OK what about a named range?? why when i define it as a named range it only displays the first value?? an why when i use it in a function it only takes the first value??

  7. #7
    Forum Guru JosephP's Avatar
    Join Date
    03-27-2012
    Location
    Ut
    MS-Off Ver
    2003/10
    Posts
    7,328

    Re: Behavior of Offset function in an array formula

    because that syntax of offset returns an array of discrete ranges

  8. #8
    Valued Forum Contributor mohd9876's Avatar
    Join Date
    05-04-2011
    Location
    Amman, Jordan
    MS-Off Ver
    Excel 2010
    Posts
    426

    Re: Behavior of Offset function in an array formula

    Does this mean that this type of array is not usable anywhere in excel? I can't sum it, count it, use it in a named range, etc??
    Why does it exist then? Mystery

  9. #9
    Forum Guru JosephP's Avatar
    Join Date
    03-27-2012
    Location
    Ut
    MS-Off Ver
    2003/10
    Posts
    7,328

    Re: Behavior of Offset function in an array formula

    you can use it in functions by converting to a regular array using n()
    =SUM(N(OFFSET($A$1,SMALL(IF($A$1:$A$8<>"",ROW($A$1:$A$8)),ROW(INDIRECT("1:"&COUNT($A$1:$A$8))))-1,0,1)))
    for instance

  10. #10
    Valued Forum Contributor mohd9876's Avatar
    Join Date
    05-04-2011
    Location
    Amman, Jordan
    MS-Off Ver
    Excel 2010
    Posts
    426

    Re: Behavior of Offset function in an array formula

    AHA... This is what I am looking for then, thank you so much

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1