+ Reply to Thread
Results 1 to 11 of 11

Changing formula to NOT array

  1. #1
    Forum Contributor
    Join Date
    08-23-2013
    Location
    Alberta, Canada
    MS-Off Ver
    Excel 365
    Posts
    166

    Changing formula to NOT array

    Hi Guys,
    I have a formula that I have been using to Index/Match with 3 column based criteria. I am looking to alter it so it is NOT an array formula. As I sort/adjust criteria it is screwing up. Anything I can do so it is just a sitting formula, NOT array.

    Thanks a lot!
    Please Login or Register  to view this content.

  2. #2
    Forum Expert tim201110's Avatar
    Join Date
    10-23-2011
    Location
    Russia
    MS-Off Ver
    2016, 2019
    Posts
    2,357

    Re: Changing formula to NOT array

    =IFERROR(INDEX(MILL!D:D,MATCH(1,INDEX(('2018'!$F11=MILL!$A:$A)*('2018'!$C11=MILL!$B:$B)*('2018'!$J$9=MILL!$C:$C),),)),"-")

    PS i'd not recommend to search full columns in this case

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

    Re: Changing formula to NOT array

    Try

    =IFERROR(LOOKUP(2,1/(('2018'!$F11=MILL!$A:$A)*('2018'!$C11=MILL!$B:$B)*('2018'!$J$9=MILL!$C:$C)),MILL!D:D),"-")

    Also recommend NOT using entire column references

  4. #4
    Forum Contributor
    Join Date
    08-23-2013
    Location
    Alberta, Canada
    MS-Off Ver
    Excel 365
    Posts
    166

    Re: Changing formula to NOT array

    Thanks a lot Jon,
    Just for the speed of the processor is why you wouldn't use the entire column reference?

    THX

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

    Re: Changing formula to NOT array

    It's because the formulae use arrays (even the standard ones!) to make the calculations, so limiting the ranges to just what is required is going to speed up those calculations.
    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. It's a universal courtesy.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    NB:
    as a Moderator, I never accept friendship requests.
    Forum Rules (updated August 2023): please read them here.

  6. #6
    Forum Contributor
    Join Date
    08-23-2013
    Location
    Alberta, Canada
    MS-Off Ver
    Excel 365
    Posts
    166

    Re: Changing formula to NOT array

    Can I apply these 2 things (1: change it to NOT array 2: lookup range from 2:10000 to the below formula), I want to collect a list based on the $A$9 criteria:
    {=IFERROR(INDEX('2018M'!$H:$H,SMALL(INDEX(($A$9='2018M'!$A:$A)*(MATCH(ROW('2018M'!$A:$A), ROW('2018M'!$A:$A)))+($A$9<>'2018M'!$A:$A)*1048577,),ROWS('2018M'!$A$1:A1))), "-")}

    Thanks for the help Ali, I made another thread with the same name because it is a new question about a different formula, I will close the other thread.


    Thanks guys,

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

    Re: Changing formula to NOT array

    It's ostensibly the same issue. I have therefore marked this thread as unsolved.

  8. #8
    Forum Expert tim201110's Avatar
    Join Date
    10-23-2011
    Location
    Russia
    MS-Off Ver
    2016, 2019
    Posts
    2,357

    Re: Changing formula to NOT array

    =IFERROR(INDEX('2018M'!$H:$H,aggregate(15,6,ROW('2018M'!$A:$A)/($A$9='2018M'!$A:$A)/($A$9<>'2018M'!$A:$A),ROWS('2018M'!$A$1:A1)),"-")

  9. #9
    Forum Contributor
    Join Date
    08-23-2013
    Location
    Alberta, Canada
    MS-Off Ver
    Excel 365
    Posts
    166

    Re: Changing formula to NOT array

    Thx Tim, but I didn't have any luck. It did not retrieve any entries in H based off of a column A to $A$9 match.

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

    Re: Changing formula to NOT array

    Will you please attach a sample Excel workbook? We are not able to work with or manipulate a picture of one and nobody wants to have to recreate your data from scratch.

    1. Make sure that your sample data are REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired results are also shown (mock up the results manually).

    3. Make sure that all confidential data is removed or replaced with dummy data first (e.g. names, addresses, E-mails, etc.).

    4. Try to avoid using merged cells as they cause lots of problems.

    Unfortunately the attachment icon doesn't work at the moment, so to attach an Excel file you have to do the following: just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.

    Please pay particular attention to point 2 (above): without an idea of your intended outcomes, it is often very difficult to offer appropriate advice.

  11. #11
    Forum Expert tim201110's Avatar
    Join Date
    10-23-2011
    Location
    Russia
    MS-Off Ver
    2016, 2019
    Posts
    2,357

    Re: Changing formula to NOT array

    i did not check your links (How could i?)
    red font. what it is?
    {=IFERROR(INDEX('2018M'!$H:$H,SMALL(INDEX(($A$9='2018M'!$A:$A)*(MATCH(ROW('2018M'!$A:$A), ROW('2018M'!$A:$A)))+($A$9<>'2018M'!$A:$A)*1048577,),ROWS('2018M'!$A$1:A1))), "-")}

+ 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] Array formula not changing rows for an unlocked range when run in VBA
    By Dgp2012 in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 07-02-2014, 10:34 AM
  2. [SOLVED] Formula to work out the average of an array from a changing cell
    By francesc in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 01-06-2014, 10:00 PM
  3. Array Formula should adjust to changing range
    By Shinga in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 07-27-2013, 05:38 AM
  4. [SOLVED] Formula for a continuously changing array
    By gururajendrak in forum Excel Formulas & Functions
    Replies: 21
    Last Post: 03-01-2013, 12:05 PM
  5. Formula to answer Y/N to a value changing (More than once) in an array?
    By agf12555 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 12-17-2012, 11:17 PM
  6. Filling Down with an Array Formula - Changing Relative Reference
    By fervorking in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 01-25-2011, 06:29 PM
  7. Replies: 4
    Last Post: 05-04-2005, 12:06 PM

Tags for this Thread

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