+ Reply to Thread
Results 1 to 5 of 5

Average OFFSET with drop-down list

  1. #1
    Registered User
    Join Date
    06-30-2017
    Location
    Wirral, UK
    MS-Off Ver
    2016
    Posts
    16

    Average OFFSET with drop-down list

    I have been following Leila Gharanis’ You Tube video on OFFSET Function for Dynamic Calculations.

    At 10 ins 46 secs into the video, Leila explains how to obtain an average using a drop-down list to select a month for data held in columns.

    Is it possible to do the same data held in rows? I have tried several different formulas but to no avail.

    What I am trying to achieve on the attached example is;

    If I select the month of Jan-20, I get the average for Jan-20, Feb-20, Mar-20 & Apr-20, if I select the month of Feb-20, I get the average for Feb-20, Mar-20, Apr-20 & May-20 and soon.

    Any help on this would be greatly appreciated.
    Attached Files Attached Files

  2. #2
    Forum Expert XLent's Avatar
    Join Date
    10-13-2010
    Location
    Northumberland, UK
    MS-Off Ver
    various
    Posts
    2,704

    Re: Average OFFSET with drop-down list

    using OFFSET in this scenario is not a good suggestion IMO - as it's Volatile - just use INDEX to help define the requisite range.

    =AVERAGE($A2:INDEX($A2:$X2,MATCH(A6,$A$1:$X$1,0)))

    if you want to use OFFSET

    =AVERAGE(OFFSET($A$2,0,0,1,MATCH($A6,$A$1:$X$1,0)))
    Last edited by XLent; 06-05-2020 at 05:21 AM. Reason: edit: added offset example - for OP

  3. #3
    Registered User
    Join Date
    06-30-2017
    Location
    Wirral, UK
    MS-Off Ver
    2016
    Posts
    16

    Re: Average OFFSET with drop-down list

    Hi XLent,

    Many thanks for your reply.

    Unfortunately, using either of the formulas that you have suggested returns an average for the months previous to the month selected.

    I am after getting an average for the month chosen and the next 3 months.

    Regards

  4. #4
    Forum Expert XLent's Avatar
    Join Date
    10-13-2010
    Location
    Northumberland, UK
    MS-Off Ver
    various
    Posts
    2,704

    Re: Average OFFSET with drop-down list

    Ah, apologies, in which case either:

    =AVERAGE(INDEX($A2:$X2,MATCH($A6,$A$1:$X$1,0)):INDEX($A2:$X2,MATCH($A6,$A$1:$X$1,0)+2))

    or

    =AVERAGE(OFFSET($A$2,0,MATCH($A6,$A$1:$X$1,0)-1,1,3))

  5. #5
    Registered User
    Join Date
    06-30-2017
    Location
    Wirral, UK
    MS-Off Ver
    2016
    Posts
    16

    Re: Average OFFSET with drop-down list

    Hi XLent,

    That works great.

    Many thanks for your help.

    Regards

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Dynamic Drop Down List Using OFFSET With Color
    By oxicottin in forum Excel General
    Replies: 12
    Last Post: 08-17-2017, 12:51 AM
  2. [SOLVED] Offset Function using Validation Drop Down List
    By FANNINGT in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 02-26-2015, 07:35 PM
  3. Average excel user needs help with either macro or web query from a drop down list
    By chadboehne in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 07-31-2013, 11:02 PM
  4. Replies: 2
    Last Post: 03-01-2013, 07:01 AM
  5. Using Drop-Down list with offset
    By rzacharia21 in forum Excel - New Users/Basics
    Replies: 10
    Last Post: 11-23-2012, 04:39 PM
  6. Replies: 4
    Last Post: 06-11-2012, 06:17 PM
  7. Using LEFT with OFFSET to get a dynamic drop down list
    By alcopoppa in forum Excel General
    Replies: 6
    Last Post: 01-20-2012, 08:53 AM

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