+ Reply to Thread
Results 1 to 8 of 8

Return Maximum value with Conditions

  1. #1
    Registered User
    Join Date
    04-06-2011
    Location
    Kibbutz Lotan, Israel
    MS-Off Ver
    Office 2010
    Posts
    1

    Question Return Maximum value with Conditions

    Hi guys.
    I really hope you could help me with this one.

    My table is:
    A B
    0.71 1
    0.26 0
    1.11 0
    1.11 1
    7.63 1
    0.19 0
    0.16 0
    3.00 1
    0.17 0
    0.17 0
    0.17 0
    0.17 0
    1.24 1
    1.68 2
    2.54 2
    1.01 2
    1.65 2
    2.11 2
    1.01 2
    1.85 2
    2.45 2
    2.07 2

    So I have the A column tat consists of, let's say, electricity consumption of a house and the B column that consists of, say, the number of occupants in the house.

    Now, I want to use the MIN & MAX functions on the A column to get, respectively, the MAXimum value from the A column and the MINimum value from the A column.

    But, now comes the tricky part. I want to do so with excluding the cells that have the number 0 next to them in column B.

    In other words, I need a function that'll tell Excel: "Find the MAX & MIN values from range A1:A20. Put into the calculation only the cells in the range that have a number larger than zero in the cell directly to their right."

    Of course, my actual project is in a much larger scale.

    BTW, I use Excel 2010.

    Thank you very much
    Last edited by Ore4444; 07-06-2011 at 02:55 AM. Reason: Title change

  2. #2
    Valued Forum Contributor
    Join Date
    05-23-2011
    Location
    Lahore PK
    MS-Off Ver
    Excel 2007, 2013
    Posts
    627

    Re: Return Maximum value with Conditions

    Hi Ore4444

    formula is given soft file is enclosed.

    Kindly note that it is an array formula and should be executed through Shif+Ctrl+Entr
    Attached Files Attached Files

  3. #3
    Forum Moderator zbor's Avatar
    Join Date
    02-10-2009
    Location
    Croatia
    MS-Off Ver
    365 ProPlus
    Posts
    15,576

    Re: Return Maximum value with Conditions

    Here is also one solution, slightly different in one case:

    If you put character in B column you'll get different result so decide what you want:
    Attached Files Attached Files

  4. #4
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Return Maximum value with Conditions

    Hi everyone,

    maybe another way to exclude zeros:

    =MIN(IF($B$2:$B$100,$A$2:$A$100))

    =MAX(IF($B$2:$B$100,$A$2:$A$100))

    To be confirmed with control+shift+enter.

    Regards,

  5. #5
    Valued Forum Contributor
    Join Date
    05-23-2011
    Location
    Lahore PK
    MS-Off Ver
    Excel 2007, 2013
    Posts
    627

    Re: Return Maximum value with Conditions

    Hi zbor & CANAPONE

    i dont get the reqired answer throgh these formula may be i am making some mistakes.

    Kindly look at the attatched file.

    i also add formula to exclude both zero & non numerics from column B
    Attached Files Attached Files

  6. #6
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    Office 2021
    Posts
    2,237

    Re: Return Maximum value with Conditions

    Hello Ore4444,

    You can also use AGGREGATE function.

    MIN;

    =AGGREGATE(15,6,A2:A20/(B2:B20<>0),1)

    MAX;

    =AGGREGATE(14,6,A2:A20/(B2:B20<>0),1)
    Last edited by Haseeb Avarakkan; 07-07-2011 at 01:18 PM.
    Regards,
    Haseeb Avarakkan

    __________________________________
    "Feedback is the breakfast of champions"

  7. #7
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    Office 2021
    Posts
    2,237

    Re: Return Maximum value with Conditions

    Hello Azam,

    Use this Array formulas.

    =MIN(IF(ISNUMBER(1/$B$2:$B$100),$A$2:$A$100))

    =MAX(IF(ISNUMBER(1/$B$2:$B$100),$A$2:$A$100))

  8. #8
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Return Maximum value with Conditions

    Hi Azam Ali (no mistakes from you),

    as far as MIN(IF... or MAX(IF... are concerned you can use these array formulae only relating to ranges of numbers. Relating your example, you should adjust the formulae using ISNUMBER.

    In other words, the formulae exclude zeros playing only with numbers and don't accept non numeric strings.

    Excuse my English if it's not clear.

    Regards

    Edit: Sorry Haseeb A, I did not mean to overlap.
    नमस्ते
    Last edited by canapone; 07-07-2011 at 02:24 AM.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

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