+ Reply to Thread
Results 1 to 12 of 12

MAXIFS alternate date range if cell is blank

  1. #1
    Registered User
    Join Date
    02-16-2023
    Location
    Ontario Canada
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2301 Build 16.0.16026.20002) 64-bit
    Posts
    5

    MAXIFS alternate date range if cell is blank

    I'm using MAXIFS to lookup dates for specific courses. It looks up employee in Col B and Course ID in Col C and if it's a match, returns the latest expired date in column E.

    My problem is that If a expiration date is blank, I get zeros and I'd like it to ignore the blank and look at col D for the most recent dates (the last time when the course was credited)

    This is what I have so far, it works if there is a real expiration date.. just need to figure out how to handle the blanks.
    =MAXIFS($E$3:$E$30,$B$3:$B$30,$H3,$C$3:$C$30,$I$2)
    Attached Images Attached Images
    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 2406
    Posts
    44,662

    Re: MAXIFS alternate date range if cell is blank

    Use a double reciprocal to induce a #DIV/0 error:

    =IFERROR(1/(1/MAXIFS($E$3:$E$30,$B$3:$B$30,$H3,$C$3:$C$30,J$2)),"")
    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

  3. #3
    Registered User
    Join Date
    02-16-2023
    Location
    Ontario Canada
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2301 Build 16.0.16026.20002) 64-bit
    Posts
    5

    Re: MAXIFS alternate date range if cell is blank

    Thank you very much Glenn, it almost got me what I wanted but I was able to build on your idea with =IFERROR(1/(1/MAXIFS($E$3:$E$30,$B$3:$B$30,$H5,$C$3:$C$30,J$2)),MAXIFS($D$3:$D$30,$B$3:$B$30,$H5,$C$3:$C$30,J$2))

    I'll just add some conditional formatting to hide any zero dates...

    thanks again.
    Attached Files Attached Files

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

    Re: MAXIFS alternate date range if cell is blank

    Ahhh. I read your thread too quickly (a common failing of mine).

    You're welcome.



    It would be very nice if you were to just click the Add Reputation button at the foot of any of the posts of members who helped you reach a solution.

    Finally, if that takes care of your original question, please click on "Thread Tools" from the menu link (just above the first post in the thread) and mark this thread as SOLVED.

  5. #5
    Forum Expert
    Join Date
    09-25-2015
    Location
    Milan Italy
    MS-Off Ver
    office 365
    Posts
    1,986

    Re: MAXIFS alternate date range if cell is blank

    I3=IFERROR(AGGREGATE(14,6,$E$3:$E$100/($E$3:$E$100<>"")/($B$3:$B$100=$H3)/($C$3:$C$100=I$2),1),"")

    Copy across and down

  6. #6
    Registered User
    Join Date
    02-16-2023
    Location
    Ontario Canada
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2301 Build 16.0.16026.20002) 64-bit
    Posts
    5

    Re: MAXIFS alternate date range if cell is blank

    Quote Originally Posted by Glenn Kennedy View Post
    Ahhh. I read your thread too quickly (a common failing of mine).

    You're welcome.



    It would be very nice if you were to just click the Add Reputation button at the foot of any of the posts of members who helped you reach a solution.

    Finally, if that takes care of your original question, please click on "Thread Tools" from the menu link (just above the first post in the thread) and mark this thread as SOLVED.
    Thanks again for your fast response. The original problem is technically solved but unfortunately I just learned that the formula will only work on a 365 version. Is it appropriate to keep the thread open for alternate solutions?
    Last edited by PaulJMac; 02-18-2023 at 10:28 AM.

  7. #7
    Registered User
    Join Date
    02-16-2023
    Location
    Ontario Canada
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2301 Build 16.0.16026.20002) 64-bit
    Posts
    5

    Re: MAXIFS alternate date range if cell is blank

    Thank you Caracalla, this does clear the cells to show blanks instead of 1900-01-00 , however the sheet still needs to look for the alternate date in column D (the date the course was taken) . I've played on your idea with AGGREGATE but have not been able to get anything that will work. Could you (or others) expand on how to use AGGREGATE for this ?

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

    Re: MAXIFS alternate date range if cell is blank

    Well, your profile says O365.... hence my reply. What product do you want it to work with?

  9. #9
    Registered User
    Join Date
    02-16-2023
    Location
    Ontario Canada
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2301 Build 16.0.16026.20002) 64-bit
    Posts
    5

    Re: MAXIFS alternate date range if cell is blank

    Yes, and thanks for that and the fast response. I have O365 but the people I need to share with do not. I didn't realize at the time MAXIFS was unique to O365. Most should have been updated to v2013 as a minimum and I'm assuming that most of the functions carry forward?

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

    Re: MAXIFS alternate date range if cell is blank

    Also, your ORIGINAL formula was a MAXIFS, so it was reasonable to assume that it was OK for you.

    Try:

    =IFERROR(1/(1/MAX(IF(($B$3:$B$30=$H3)*(($C$3:$C$30=J$2)),$E$3:$E$30,""))),MAX(IF(($B$3:$B$30=$H3)*(($C$3:$C$30=J$2)),$D$3:$D$30,"")))



    You seem to be using an older version of Excel than me. So, please refer to the attached file. If the formulae are enclosed within a pair of { }, these are array formulae.

    These are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see the curly brackets { } appear around the outside of your formula. If you do not use 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 brackets yourself - it won't work...

    BUT. Try caracalla's it may not need ARRAY-ENTRY, IF IT'S ok (NOT TESTED).
    Attached Files Attached Files

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

    Re: MAXIFS alternate date range if cell is blank

    Functions carry forward, but never carry backwards... otherwise Mr Gates might have to visit the local food bank!!

  12. #12
    Forum Expert
    Join Date
    09-25-2015
    Location
    Milan Italy
    MS-Off Ver
    office 365
    Posts
    1,986

    Re: MAXIFS alternate date range if cell is blank

    I3=IFERROR(IFERROR(AGGREGATE(14,6,$E$3:$E$100/($E$3:$E$100<>"")/($B$3:$B$100=$H3)/($C$3:$C$100=I$2),1),AGGREGATE(14,6,$D$3:$D$100/($D$3:$D$100<>"")/($B$3:$B$100=$H3)/($C$3:$C$100=I$2),1)),"")

    Copy across and down

+ 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. Two questions : named range display & alternate cell
    By shahab47 in forum Excel General
    Replies: 12
    Last Post: 02-02-2021, 09:30 PM
  2. [SOLVED] Finding Latest Date of Multiple Transactions per User Using MAXIFS
    By heyhsia in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 07-24-2019, 07:47 AM
  3. MAXIFS formula that excludes based on date
    By xavior1325 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 06-11-2019, 01:41 PM
  4. MAXIFS Problem - Non-Adjacent Range Name
    By willyt19712 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 01-24-2019, 06:02 PM
  5. [SOLVED] formula to pick date from range where first non blank cell is.
    By anotherbe01 in forum Excel General
    Replies: 2
    Last Post: 01-27-2017, 03:00 AM
  6. Copy and paste specific range to date specific range in alternate sheet
    By alanalmarza in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 01-21-2013, 08:29 AM
  7. Match Cell Then Copy Alternate to Next Blank Cell
    By kingsolo in forum Excel General
    Replies: 4
    Last Post: 01-29-2008, 06:16 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