+ Reply to Thread
Results 1 to 28 of 28

IFERROR, INDEX, MAX, MATCH Get latest date with array

  1. #1
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    IFERROR, INDEX, MAX, MATCH Get latest date with array

    Good morning all, I am trying to pull the latest of duplicate results using the following formula. Can anyone tell me where my syntax is incorrect?

    Please Login or Register  to view this content.

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

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Will you please attach a SMALL sample Excel workbook (10-20 rows of data is usually enough)? However, please give us an indication of the approximate number of rows of data you want the solution to work with (100, 1000, 100,000 or whatever). Please DO NOT attach a picture of an Excel sheet (I do not have the patience to re-type any/all your stuff before starting).

    1. It does NOT have to be your real sheet - mock up a SAMPLE if you need to. But not 1000's of rows!!! It makes manual checking so tedious. Whatever you do... make sure that all confidential information is removed first!!

    2. Make sure that your sample data are truly REPRESENTATIVE of your real data. For example, don't show text in a column if it's really a number. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    3. Make sure that your desired solution is also shown (mock up the results manually). To be honest, I am not interested in seeing a non-working formula... or a pile of blank cells. However, I am very interested in seeing your EXPECTED results in their EXPECTED location.

    4. Try not to use merged cells. They cause lots of problems and are DEFINITELY best avoided!

    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.
    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
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Here is a test sheet: ht tp s : //doc s. google .co m /spread sheets/d /1mFsTvtt8Gg UvUl2xqw43b5TDQyH0KKrapZR3SDT0zsQ

    I've highlighted some rows to narrow down testing.
    There are some spaces in the link as the forum wouldn't let me post a link.

  4. #4
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    I am trying to get all the information from Report Responses to auto populate the 1 2 and 3 column in Assignment's based on the value of column A, and matching the latest date.

  5. #5
    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,893

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Bump.

    Any takers? I couldn't tell a google sheet from a hole in my socks!!

  6. #6
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    That doesn't appear to be a publicly available link.
    Rory

  7. #7
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Quote Originally Posted by rorya View Post
    That doesn't appear to be a publicly available link.
    Sorry, it is now.

  8. #8
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    And what exactly should be the result in F20?

  9. #9
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    F20 should contain the value of Report Responses first column. (PASSED/REDO/etc)

  10. #10
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Anyone that may know how to help me out?

  11. #11
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Does this do what you want:

    =filter('Report Responses'!$A$1:$A$28,'Report Responses'!$G$1:$G$28=$A20,'Report Responses'!$J$1:$J$28=F$2,'Report Responses'!$B$1:$B$28=max(filter('Report Responses'!$B$1:$B$28,'Report Responses'!$G$1:$G$28=$A20,'Report Responses'!$J$1:$J$28=F$2)))

  12. #12
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Not really sure how to apply that. I'm looking to find the max date in Report Responses$C:$C for same values in Report Responses$K:$K. In other words, column K may have similar values = 1. I need it to pull another value based on it being that last 1 that was submitted.

    =ArrayFormula(IFERROR(INDEX('Report Responses'!$B:$B,MATCH(1,('Report Responses'!$H:$H=$A22)*('Report Responses'!$K:$K=F$2 * (MAX('Report Responses'!$C:$C))),0)),"NO")) The max function just doesn't work here, and i've tried a few other ways that I cannot figure out.

  13. #13
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Put that formula into F20. It will return the value from column A on 'Report Responses' for the latest date in column B where column H is 17 and column K is 1. Is that not what you asked for?

  14. #14
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Ah, I see, that actually does work. Where can I add an IFERROR to prevent the =N/A when there is no result yet?

  15. #15
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Just wrap the whole thing:


    =IFERROR(filter('Report Responses'!$A$1:$A$28,'Report Responses'!$G$1:$G$28=$A20,'Report Responses'!$J$1:$J$28=F$2,'Report Responses'!$B$1:$B$28=max(filter('Report Responses'!$B$1:$B$28,'Report Responses'!$G$1:$G$28=$A20,'Report Responses'!$J$1:$J$28=F$2))),"NO")

  16. #16
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    So that works as needed to pull the data for the latest result. One last question, is there a way to say "or" in this portion of the script:
    Please Login or Register  to view this content.
    so that it can pull value1 or value2 from $A20? Such as:
    Please Login or Register  to view this content.
    .

    One last thing to see if it's possible, I would like for it to display NO in the cell if there are instances of the ID it's looking up($A20), but no result matching $F2 or $F3. But if there is no instance of the ID it's looking up ($A20) at all, I would like it to display --- in the cell.
    Last edited by beau.young92; 10-29-2019 at 04:30 PM.

  17. #17
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Anyone available to help with this last bit?

  18. #18
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    For the OR part, you just add the criteria like this:

    =max(filter('Report Responses'!$B$1:$B$28,'Report Responses'!$G$1:$G$28=$A20,('Report Responses'!$J$1:$J$28=F$2)+('Report Responses'!$J$1:$J$28="Redo of Sit Along 1")))

    For the other part, you'd need to do a separate test first, like:

    =IF(COUNT(filter('Report Responses'!$B$1:$B$28,'Report Responses'!$G$1:$G$28=$A20))=0,"---", your existing iferror formula here )

  19. #19
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    =IF(COUNT(filter('Report Responses'!$B$1:$B$28,'Report Responses'!$G$1:$G$28=$A20))=0,"---", IFERROR(filter('Report Responses'!$A$1:$A$28,'Report Responses'!$G$1:$G$28=$A20,'Report Responses'!$J$1:$J$28=F$2,'Report Responses'!$B$1:$B$28=max(filter('Report Responses'!$B$1:$B$28,'Report Responses'!$G$1:$G$28=$A20,'Report Responses'!$J$1:$J$28=F$2))),"NO"))

    Like this? It doesn't seem to be working.

  20. #20
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Can you be more specific than "not working"?

  21. #21
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20
    Quote Originally Posted by rorya View Post
    Can you be more specific than "not working"?
    Absolutely, i apologize, it was late when i attempted it. It is only showing '---' when the desired result would have been 'REDO'.

  22. #22
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    You should have enough posts to post a link to the file now, so can you do that and specify which cell the formula is in, and what it should return?

  23. #23
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Would you be ok with a Private message containing the link and looking into it?

  24. #24
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Yes, as long as I can post any answers (i.e. just the formula) back to the thread.

  25. #25
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    Of course, sending link now.

  26. #26
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    I've amended the formula in F40 to:

    =IF(COUNT(filter('Report Responses'!$B$2:$B,'Report Responses'!$G$2:$G=$A40))=0,"---", IFERROR(filter('Report Responses'!$A$2:$A,'Report Responses'!$G$2:$G=$A40,'Report Responses'!$J$2:$J=F$3,'Report Responses'!$B$2:$B=max(filter('Report Responses'!$B$2:$B,'Report Responses'!$G$2:$G=$A40,'Report Responses'!$J$2:$J=F$3))),"NO"))

    which returns REDO, not PASSED, since the latest timestamp is for REDO?

  27. #27
    Registered User
    Join Date
    01-27-2019
    Location
    Nashville, Tennessee
    MS-Off Ver
    Office 365 // Excel
    Posts
    20

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    You are correct, I was not looking at the timestamp I copied. I think everything works on it, just one more question, when a report is submitted and there is no answer marked, like REDO or PASSED, the cell just turns an empty white, instead of the "---" in the cell.

  28. #28
    Forum Expert rorya's Avatar
    Join Date
    08-13-2008
    Location
    East Sussex, UK
    MS-Off Ver
    365 Ent SAC
    Posts
    8,885

    Re: IFERROR, INDEX, MAX, MATCH Get latest date with array

    That will require a very ugly formula:

    =IF(COUNT(filter('Report Responses'!$B$2:$B,'Report Responses'!$G$2:$G=$A40))=0,"---", IFERROR(IF(filter('Report Responses'!$A$2:$A,'Report Responses'!$G$2:$G=$A40,'Report Responses'!$J$2:$J=F$3,'Report Responses'!$B$2:$B=max(filter('Report Responses'!$B$2:$B,'Report Responses'!$G$2:$G=$A40,'Report Responses'!$J$2:$J=F$3)))="","---",filter('Report Responses'!$A$2:$A,'Report Responses'!$G$2:$G=$A40,'Report Responses'!$J$2:$J=F$3,'Report Responses'!$B$2:$B=max(filter('Report Responses'!$B$2:$B,'Report Responses'!$G$2:$G=$A40,'Report Responses'!$J$2:$J=F$3)))),"NO"))

+ 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. IFERROR, INDEX, MAX, MATCH Get latest date with array
    By beau.young92 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 10-02-2019, 07:20 PM
  2. Iferror + If + Index + Match in VBA
    By Andre2016 in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 07-10-2017, 06:58 AM
  3. Replies: 5
    Last Post: 02-09-2016, 07:02 PM
  4. [SOLVED] =IFERROR(INDEX... to match action items with due date
    By shellataylor in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 01-22-2016, 12:14 AM
  5. Replies: 14
    Last Post: 04-09-2015, 12:43 PM
  6. [SOLVED] Iferror, index, array...
    By JasonNeedsHelp in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 09-25-2014, 07:56 PM
  7. [SOLVED] Iferror, index & match
    By meh999 in forum Excel Formulas & Functions
    Replies: 12
    Last Post: 07-26-2014, 08:43 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