+ Reply to Thread
Results 1 to 9 of 9

Determine first 3 out of 5 cells that pass acceptance criteria

  1. #1
    Registered User
    Join Date
    07-06-2007
    Posts
    5

    Determine first 3 out of 5 cells that pass acceptance criteria

    I have 5 cells that contain numbers that will either pass or fail depending on acceptance criteria. I need to calculate the standard deviation of the first 3 of those cells that pass the criteria. I know that I could use a bunch of IF statements and capture all 10 possible combinations of the 5 cells but I was hoping there was a little more elegant way of solving it.
    Last edited by andykputtmann; 02-21-2018 at 01:53 PM.

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,410

    Re: Determine first 3 out of 5 cells that pass acceptance criteria

    Will you please attach a sample Excel workbook?

    1. Make sure that your sample data are REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired results are also shown (mock up the results manually).

    3. Make sure that all confidential data is removed or replaced with dummy data first (e.g. names, addresses, E-mails, etc.).

    4. Try to avoid using merged cells as they cause lots of problems.

    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.

    Please pay particular attention to point 2 (above): without an idea of your intended outcomes, it is often very difficult to offer appropriate advice.
    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.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  3. #3
    Registered User
    Join Date
    07-06-2007
    Posts
    5

    Re: Determine first 3 out of 5 cells that pass acceptance criteria

    Attached is a representative example of the data I am using. Please let me know if more clarification is needed.
    Attached Files Attached Files

  4. #4
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Determine first 3 out of 5 cells that pass acceptance criteria

    Try this:

    =STDEV.P(IF((B4:F4="PASS")*(B2:F2<=AGGREGATE(15,6,B2:F2/(B4:F4="PASS"),3)),B2:F2)) Ctrl Shift Enter

  5. #5
    Registered User
    Join Date
    07-06-2007
    Posts
    5

    Re: Determine first 3 out of 5 cells that pass acceptance criteria

    That is very close. If they all pass it uses cells 1, 2, 5 instead of 1, 2, 3. If cell 3 fails it should use 1, 2, 4 but it uses 1, 2, 5 instead. If cell 2 fails it uses 1, 4, 5 instead of 1, 3, 4. So it seems to be defaulting to the the last cells if any of the first cells fail. I did not check all of the possible combinations.

  6. #6
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Determine first 3 out of 5 cells that pass acceptance criteria

    I see. The formula takes the standard deviation of the smallest 3 (not the first 3) numbers that are ≤ 169.

    Working on a fix.

  7. #7
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Determine first 3 out of 5 cells that pass acceptance criteria

    Here's how I would do it:

    B5 =COUNTIF($B4:B4,"PASS") Drag this formula through F5.

    Then, you can use this simple array formula in another cell:
    =STDEV.P(IF((B4:F4="PASS")*(B5:F5<=3),B2:F2)) Ctrl Shift Enter

  8. #8
    Registered User
    Join Date
    07-06-2007
    Posts
    5

    Re: Determine first 3 out of 5 cells that pass acceptance criteria

    that works beautifully. THANK YOU!

  9. #9
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Determine first 3 out of 5 cells that pass acceptance criteria

    You're welcome, happy to help.

    Thanks for the rep!

+ 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. Acceptance form in the Outlook
    By sqt91 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 02-28-2017, 11:38 PM
  2. Pass/Fail determained by different sets of criteria.
    By Adamlee in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 03-31-2015, 01:49 PM
  3. [SOLVED] Forum Guru Nomination / Rejection / Non Acceptance Status
    By :) Sixthsense :) in forum The Water Cooler
    Replies: 20
    Last Post: 11-12-2013, 10:36 AM
  4. [SOLVED] 2 Criteria Need to Be Met Within a Date Range to Pass
    By rick60 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 09-20-2013, 07:56 PM
  5. [SOLVED] Friend acceptance/rejection problems, REDUX
    By dredwolf in forum Suggestions for Improvement
    Replies: 5
    Last Post: 06-01-2013, 10:08 PM
  6. Excel, data acceptance/find error.
    By ali84pk in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 12-28-2010, 01:38 PM
  7. Auto Determine Range to pass to vlookup
    By captlogic in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 08-17-2010, 02:40 PM

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