+ Reply to Thread
Results 1 to 11 of 11

How to get an array formula to work both vertically and horizontally?

  1. #1
    Registered User
    Join Date
    11-16-2014
    Location
    Mt Isa
    MS-Off Ver
    2016
    Posts
    62

    How to get an array formula to work both vertically and horizontally?

    Hi Team Excel

    I am at a loss as to why this array formula works for my horizontal values but wont work vertically. I am sure there is a simple reason, but i am still learning all this and i dont know what it is, please help.

    Attached is a very simple table. It contains letter grades, which are then reference a number value from another table (_Reports) to give it a numerical value, so that it can then be averaged, before changing it back into a Letter grade again. This works if i place the array formula in the horizontal average cell, but wont work if i try an average down a column.
    Attached Files Attached Files

  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,984

    Re: How to get an array formula to work both vertically and horizontally?

    Try this array formula instead:

    =INDEX(_Reports[Grade],MATCH(ROUNDDOWN(AVERAGE(IF(TRANSPOSE(D4:D7)=_Reports[Grade],_Reports[Score])),0),_Reports[Score],0))
    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 Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,432

    Re: How to get an array formula to work both vertically and horizontally?

    For the columns, you need to transpose the lookup arrays:

    =INDEX(_Reports[Grade],MATCH(ROUNDDOWN(AVERAGE(IF(D4:D7=TRANSPOSE(_Reports[Grade]),TRANSPOSE(_Reports[Score]))),0),TRANSPOSE(_Reports[Score]),0))
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  4. #4
    Registered User
    Join Date
    11-16-2014
    Location
    Mt Isa
    MS-Off Ver
    2016
    Posts
    62

    Re: How to get an array formula to work both vertically and horizontally?

    Thank you, that worked a treat. Can you please explain what is happening here, so i can increase my understanding of excel. Cheers.

    No dramas if you cant/dont want too

  5. #5
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,432

    Re: How to get an array formula to work both vertically and horizontally?

    Which one of us are you addressing? You have been offered two solutions.

    Use the Evaluate Formula option on the Formulas ribbon to step through it so you can see what is happening. Essentially in mine, because you were working with rows in the main table and columns in the lookup table, you need to switch this when you want to work with columns in the main table. TRANSPOSE simply turns the lookup arrays 90 degrees to facilitate this.
    Last edited by AliGW; 07-14-2019 at 02:33 AM.

  6. #6
    Registered User
    Join Date
    11-16-2014
    Location
    Mt Isa
    MS-Off Ver
    2016
    Posts
    62

    Re: How to get an array formula to work both vertically and horizontally?

    Hi Ali,

    Either, what does Transposing do? Why is it needed for vertical rather than horizontal?

  7. #7
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,432

    Re: How to get an array formula to work both vertically and horizontally?

    I've answered your question above.

    Glenn's approach is the same, but he's chosen to transpose the main table column instead. Essentially, one or other of the arrays needs transposing.
    Last edited by AliGW; 07-14-2019 at 02:39 AM.

  8. #8
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,432

    Re: How to get an array formula to work both vertically and horizontally?

    Does this answer your question?

  9. #9
    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,984

    Re: How to get an array formula to work both vertically and horizontally?

    In your original (working) formula, the construction of the formula meant that you were multiplying two arrays. One (sheet 1) was a horizontal array, and the other (Codes) was a vertical array. When multiplied together they produced a 4 x 15 array of TRUE/FALSE responses.

    In your original (non-working) formula, the two arrays were vertical. When multiplied together The first four rows of the codes array were searched for the 4 values in sheet 1. the remaining 11 rows of codes produced an error and the formual fell over. To get it to work, you had to coerce Excel to make one of the arrays horizonatal. That's what TRANSPOSE does.

  10. #10
    Registered User
    Join Date
    11-16-2014
    Location
    Mt Isa
    MS-Off Ver
    2016
    Posts
    62

    Re: How to get an array formula to work both vertically and horizontally?

    Thank you both, youre awesome. I figured it was something like this, but it is always good to ask and seek clarification from those in the know.

    Thank you for your help and support again.

  11. #11
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,432

    Re: How to get an array formula to work both vertically and horizontally?

    Glad to have helped.

+ 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. Copy formula horizontally- cell addresses should be vertically
    By Jan Zitniak in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 06-21-2016, 11:14 AM
  2. Copy formula horizontally- cell addresses should be vertically
    By Jan Zitniak in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 06-21-2016, 11:13 AM
  3. [SOLVED] Applying single formula horizontally and vertically
    By rajre in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 07-21-2014, 07:10 AM
  4. [SOLVED] Is it possible to freeze both vertically and horizontally?
    By claralou in forum Excel General
    Replies: 4
    Last Post: 09-27-2013, 05:04 AM
  5. Join Tables Vertically With an Array Instead of Horizontally?
    By Theclint in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 05-15-2013, 11:10 AM
  6. [SOLVED] Sumproduct vertically and horizontally
    By jimstrongy in forum Excel General
    Replies: 2
    Last Post: 03-21-2012, 04:37 PM
  7. Drag horizontally but have formula increase vertically?
    By Greg_2 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 07-15-2011, 09:24 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