+ Reply to Thread
Results 1 to 7 of 7

Using Substitute within a MAXIF formula

  1. #1
    Registered User
    Join Date
    05-14-2017
    Location
    UAE
    MS-Off Ver
    1
    Posts
    3

    Using Substitute within a MAXIF formula

    Hi. I need to use a MAX IF formula that has a mix of 0, 1, A, B, 2, 3, 4, 5, 6, etc. It only has a couple of A's and B's mixed in with the numbers, but it's enough to mess up the formula. Ideally I would like to combine the MAXIF formula (which works just great when there are no letters), and tell it to substitute any A's for 1 and B's for 2. I've searched the forums and can't find a solution so any help would be very much appreciated.

    i.e.

    Purpose AEEAAAAAA
    Revision 01B345678

    Look for highest Purpose 'E' = Revision 'B'
    Look for highest Purpose 'A' - Revision '8'

    Many thanks!

  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
    44,127

    Re: Using Substitute within a MAXIF formula

    Are these numbers/letters in one cell or several?
    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
    05-14-2017
    Location
    UAE
    MS-Off Ver
    1
    Posts
    3

    Re: Using Substitute within a MAXIF formula

    1 digit per cell (over about 200 columns....)

  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 2403
    Posts
    44,127

    Re: Using Substitute within a MAXIF formula

    I have it half working...

    =INDEX($B$2:$J$2,MATCH(MAX(($B$1:$J$1=$A3)*IF($B$2:$J$2="B", 2,$B$2:$J$2)),IF($B$2:$J$2="B", 2,$B$2:$J$2),0))

    Array Formulae 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 curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - 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...
    Attached Files Attached Files

  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
    44,127

    Re: Using Substitute within a MAXIF formula

    fINALLY...

    =INDEX($B$2:$J$2,MATCH(MAX(($B$1:$J$1=$A3)*IF($B$2:$J$2="A",1,IF($B$2:$J$2="B",2,$B$2:$J$2))),IF($B$2:$J$2="A",1,IF($B$2:$J$2="B",2,$B$2:$J$2)),0))

    array entered.
    Attached Files Attached Files

  6. #6
    Registered User
    Join Date
    05-14-2017
    Location
    UAE
    MS-Off Ver
    1
    Posts
    3

    Re: Using Substitute within a MAXIF formula

    I've just done a quick try and it looks like it's a winner! Thanks so much. I will run it across the whole excel in the morning and see how it goes. Brilliant.

  7. #7
    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
    44,127

    Re: Using Substitute within a MAXIF formula

    That's a relief!! You don't want to know how long I spent playing with this one!!

    Anyhow, here's hoping. And, of course, you're welcome.



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

    It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.

+ 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. MaxIf without using an array formula
    By tigeravatar in forum Tips and Tutorials
    Replies: 13
    Last Post: 11-08-2019, 08:52 PM
  2. [SOLVED] MAXIF formula help!! Possible formatting Issue?
    By mconwayjr in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 10-05-2015, 12:03 PM
  3. MAXIF formula
    By dmaniov in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 06-01-2015, 01:50 PM
  4. [SOLVED] Minif or maxif formula help
    By MARKSTRO in forum Excel Formulas & Functions
    Replies: 22
    Last Post: 11-08-2013, 11:40 AM
  5. Maxif - VBA or Formula
    By rajeev.raj in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 06-06-2013, 03:36 AM
  6. I'm looking for a maxif formula, basically
    By TracyW in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 09-20-2012, 10:20 AM
  7. How to use a substitute formula to substitute text entries to a different text entry
    By andybocchi in forum Excel Programming / VBA / Macros
    Replies: 9
    Last Post: 11-01-2010, 07:50 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