+ Reply to Thread
Results 1 to 17 of 17

Index match with filters

  1. #1
    Registered User
    Join Date
    08-13-2022
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    14

    Lightbulb Index match with filters

    Hi,

    I am looking to create an searching system built on values with a > or < operator with an archive position.

    I have uploaded (correctly this time) a condensed template of how the one I am working with looks. The desired actions are in purple on tab 'Finder'.

    If it is not possible in this format, I am wondering whether a pivot table is best?

    Appreciate any assistance with this!

    Thanks, ChemistryBMS
    Attached Files Attached Files
    Last edited by ChemistryBMS; 07-06-2023 at 11:34 AM. Reason: Missed attachment

  2. #2
    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,831

    Re: Index match with filters

    No attachment ...
    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.

  3. #3
    Registered User
    Join Date
    08-13-2022
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    14

    Re: Index match with filters

    Apologies Ali - attachment now with post!

  4. #4
    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,831

    Re: Index match with filters

    Can you tell me all operators you are likely to use?

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

    Re: Index match with filters

    Try this in E2:

    =CHOOSECOLS(FILTER(INDIRECT(A2&"!A2:L6"),IF(B2=">",INDIRECT(A2&"!I2:I6")>C2,INDIRECT(A2&"!I2:I6")<C2)),5,9,11)

  6. #6
    Registered User
    Join Date
    08-13-2022
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    14

    Re: Index match with filters

    We would only be using the greater or less than operators, i.e., if we wanted to search for all calciums >2.6 then it would return the 2 sample IDs listed.

    Similarly, if we wanted to set it to [ALBUMIN | < | 29] it should 3 sample IDs.

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

    Re: Index match with filters

    Please see post #6.

  8. #8
    Registered User
    Join Date
    08-13-2022
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    14

    Re: Index match with filters

    Hi Ali,

    Thanks for your prompt response.

    I should have made the title clearer with the restrictions my workplace MS systems are, excel 2013 and therefore unable to use the FILTER function.

    Using it on my personal laptop the formula does work as expected!

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

    Re: Index match with filters

    Your profile said 365 - have you changed it?

    Your title was misleading, too.

    Over to someone welse - I'm watching the tennis!

  10. #10
    Registered User
    Join Date
    08-13-2022
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    14

    Re: Index match with filters

    I haven't changed my MS version so unsure why that shows 365?

    I've attached a snapshot of a similar worksheet with less criteria.

    Thanks for your help AliGW.
    Attached Files Attached Files

  11. #11
    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,831

    Re: Index match with filters

    I produced a 365 solution because that’s what I thought your profile said. I must have been mistaken. I’m off the laptop now.

  12. #12
    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,831

    Re: Index match with filters

    Administrative Note:

    We would very much like to help you with your query, however it has been brought to our attention that the same query has been posted on one or more other forums and you have not told us about this. You are required to do so.

    Please see Forum Rule #3 about cross-posting and adjust accordingly. Read this to understand why we (and other sites like us) consider this to be important: https://excelguru.ca/a-message-to-forum-cross-posters/

    (Note: this requirement is not optional. No help to be offered until you provide a link or, for members with fewer than 10 posts, a comment telling us where else you have posted this query.)

  13. #13
    Registered User
    Join Date
    08-13-2022
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    14

    Re: Index match with filters

    Hi AliGW,

    I have posted a similar query here: https://www.mrexcel.com/board/thread...teria.1240730/

    From my misleading title, I believed posting with a revised title and more description may have helped other users to understand my query better. Would you like me to remove the post or is it ok to remain?

    Thanks, ChemistryBMS

  14. #14
    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,831

    Re: Index match with filters

    You can't remove this thread and you don't need to, but you can improve the title of the opening post to attract more help.

    116 views and at least 9 downloads of the original workbook and only I have responded so far - hopefully someone else with Excel 2013 will soon.

    If you get a resolution on Mr Excel, please share it here.

  15. #15
    Registered User
    Join Date
    08-13-2022
    Location
    London, England
    MS-Off Ver
    2013
    Posts
    14

    Re: Index match with filters

    Hi AliGW,

    Fluff from MrExcel has provided a solution:

    Cell Formulas
    Range Formula
    E2:E20 E2 =IFERROR(INDEX(INDIRECT("'"&$A$2&"'!E:E"),AGGREGATE(15,6,ROW(INDIRECT("'"&$A$2&"'!I2:I100"))/(IF($B$2="<",INDIRECT("'"&$A$2&"'!I2:I100")<$C$2,INDIRECT("'"&$A$2&"'!I2:I100")>$C$2)),ROWS(E$2:E2))),"")

    F2:F20 F2 =IFERROR(INDEX(INDIRECT("'"&$A$2&"'!I:I"),AGGREGATE(15,6,ROW(INDIRECT("'"&$A$2&"'!I2:I100"))/(IF($B$2="<",INDIRECT("'"&$A$2&"'!I2:I100")<$C$2,INDIRECT("'"&$A$2&"'!I2:I100")>$C$2)),ROWS(E$2:E2))),"")

    G2:G20 G2 =IF(E2="","",INDEX('Archive position'!$I$2:$I$100,MATCH(E2,'Archive position'!$E$2:$E$100,0)))

  16. #16
    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,831

    Re: Index match with filters

    He’s on here as well.

    If that takes care of your original question, please choose Thread Tools from the menu link above and mark this thread as SOLVED.

    Also, if you have not already done so, you may not be aware that you can thank anyone who offered you help towards a solution for your issue by clicking the small star icon (* Add Reputation) located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of all those who offered help.

  17. #17
    Forum Expert wk9128's Avatar
    Join Date
    08-15-2020
    Location
    China Shanghai
    MS-Off Ver
    365 V2503 and WPS V2024(12.1.0.18543)
    Posts
    3,924

    Re: Index match with filters

    worksheet or tab name: Finder
    pls try this formula A

    Cell E2 formula , Drag down
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    pls try this formula B , Drag down and across
    Formula: copy to clipboard
    Please Login or Register  to view this content.

+ 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. Index Match slowing filters
    By doghouse308 in forum Excel General
    Replies: 8
    Last Post: 02-09-2020, 12:27 PM
  2. Adding filters into index/match/array formula
    By MonsterLobster in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 08-02-2018, 05:58 PM
  3. [SOLVED] Index, Match and filters
    By Steve M in forum Excel General
    Replies: 6
    Last Post: 07-28-2017, 11:12 AM
  4. Index/Match Function & Filters - NodeXL
    By r.cristobal in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 06-17-2014, 04:33 AM
  5. Replies: 6
    Last Post: 04-30-2014, 02:42 AM
  6. Replies: 6
    Last Post: 11-08-2013, 10:29 PM
  7. Replies: 3
    Last Post: 05-02-2013, 01:31 AM

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