+ Reply to Thread
Results 1 to 6 of 6

Array formulas using structured references?

  1. #1
    Registered User
    Join Date
    03-17-2014
    Location
    London, UK
    MS-Off Ver
    Excel 2010
    Posts
    26

    Array formulas using structured references?

    Hello everyone,

    I've been trying to set up an array formula for MEDIAN IF. The formula looks like this at present:

    =AVERAGE(IF(AND(Table[Range1]="Criteria1", Table[Range2]="Criteria2", Table[Range3]="Criteria3"), Table[Values to calculate the Median]))

    Basically, I have need to operate the IF on 3 criteria, and my data source is structured as a named table*

    *Because the data is dynamic and it might be 600 rows one time, or 100000 another time, plus it's easier to "see" what I'm filtering

    The formula is not working at present, gives #N/A error.

    Questions:
    1. Can I use array functions on structured references (i.e: tables)?
    2. Is the above formula alright?
    Last edited by lucazzo; 08-26-2016 at 05:07 AM.

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,986

    Re: Array formulas using structured references?

    This is one way to make it work:

    =AVERAGE(IF(Table1[ColA]="B",IF(Table1[ColB]="X",IF(Table1[ColC]="G",Table1[ColC2]))))

    entered as an array formula. Array Formulae are a little different from ordinary formulas in that they MUST be confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER.

    You will know the array is active when you see curly braces { } appear around the outside of your formula. If you do not CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly braces yourself - it won't work...
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Forum Guru Jonmo1's Avatar
    Join Date
    03-08-2013
    Location
    Bryan, TX
    MS-Off Ver
    Excel 2010
    Posts
    9,763

    Re: Array formulas using structured references?

    AND doesn't work in an array formula like that, it can't return an array of true's and false's

    Try

    =AVERAGE(IF((Table[Range1]="Criteria1")*(Table[Range2]="Criteria2")*(Table[Range3]="Criteria3"), Table[Values to calculate the Median]))

    But you can use the built in AverageifS function, so it doesn't need to be an array
    =AVERAGEIFS(Table[Values to calculate the Median],Table[Range1],"Criteria1",Table[Range2],"Criteria2",Table[Range3],"Criteria3")

  4. #4
    Registered User
    Join Date
    03-17-2014
    Location
    London, UK
    MS-Off Ver
    Excel 2010
    Posts
    26

    Re: Array formulas using structured references?

    Thank you Glenn and Jonmo1 (very much like that true/false multiplier solution!), both work perfectly on sample data but still not working on my sheet.

    It's a bit weird. I've done the following test:
    1. Filtered my table to only show the criteria I want met
    2. Copied the remaining rows (72 of them) onto another sheet
    3. Made a table with these ("Table2")

    If I run either solution on Table2, everything works like a charm. If I try it on my original table, however, I get error.

    Would it matter if one of my criteria is set to be an integer, but some values in that column are strings? (I'm guessing the operator would just give a FALSE for that instance).

    Or might it be more to do with my original table having ~7000 rows?

    Sorry, just a bit baffled on why it's working on a sample of the data, but not on the entire table

    I'll keep testing and see if anything comes up. Any idea welcome, and thank you already for the great solutions!

    EDIT:

    Problem solved. One of my rows had an error (#N/A) in a cell, which screwed up everything. THANK YOU EVERYONE!
    Last edited by lucazzo; 08-26-2016 at 05:07 AM.

  5. #5
    Forum Guru Jonmo1's Avatar
    Join Date
    03-08-2013
    Location
    Bryan, TX
    MS-Off Ver
    Excel 2010
    Posts
    9,763

    Re: Array formulas using structured references?

    One of my rows had an error (#N/A) in a cell
    Which column had the #N/A ?

    The AVERAGIFS version would be able to ignore them, depending on which cells actually had it.
    It would only be a problem in the column that is actually being avaraged, Table[Values to calculate the Median]
    And only if the criteria for that paricular row are met.

  6. #6
    Registered User
    Join Date
    03-17-2014
    Location
    London, UK
    MS-Off Ver
    Excel 2010
    Posts
    26

    Re: Array formulas using structured references?

    The #N/A was on the criteria columns. The column to average was empty.

    AVERAGEIF would indeed be easier, but I'll be using Average(IF...), as I also need to do Median(If...), and so on. Keeps the structure identical, so it's easier to keep track of everything (and replicate!)

+ 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] Cannot use structured references for tables
    By aliceinwonderland in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 03-09-2018, 01:29 PM
  2. Nested IF functions and structured references
    By mscales1977 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 10-25-2015, 09:01 PM
  3. Structured references for Pivot Table?
    By Cam in forum Excel Charting & Pivots
    Replies: 1
    Last Post: 06-15-2015, 01:33 AM
  4. VBA / Structured Table References
    By carlyman in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 04-08-2014, 06:11 AM
  5. Variants on Structured References i.e. [@Header]
    By SymphonyTomorrow in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 12-05-2013, 03:59 PM
  6. Help with structured references
    By hellur_kitty in forum Excel Formulas & Functions
    Replies: 10
    Last Post: 10-07-2013, 10:50 PM
  7. [SOLVED] Structured references in vlookup functions
    By Simon.Ward in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 06-25-2013, 09:56 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