+ Reply to Thread
Results 1 to 9 of 9

Use only data found in a specified region

  1. #1
    Registered User
    Join Date
    02-02-2017
    Location
    Sweden
    MS-Off Ver
    Office 365
    Posts
    12

    Use only data found in a specified region

    I'm looking for a way to make a average value out of values below 4. Also out of the values below 4 I need to choose the values between 25% and 75% from the total number of values.

    Example
    A row with those values...
    4
    4
    2.5
    3.0
    2.0
    2.5
    4

    ...would result in an other row with the average

    3.5

    or
    4
    4
    4
    3.0
    3.0
    1.0
    3.0
    3.0
    3.0
    1
    2.0
    4
    4

    would result in the average:
    2.5
    Last edited by Ejje; 10-11-2017 at 08:31 AM.

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

    Re: Use only data found in a specified region

    Nope. Don't understand.

    Will you please attach a SMALL sample Excel workbook (10-20 rows of data is usually enough)? Please don't attach a picture of one (no-one will want to re-type all your stuff before starting).

    1. Make sure that your sample data are truly 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 solution is also shown (mock up the results manually).

    3. Make sure that all confidential information is removed first!!

    4. Try to avoid using merged cells. 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.
    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
    12-07-2013
    Location
    Long Beach
    MS-Off Ver
    Excel 2013
    Posts
    4

    Re: Use only data found in a specified region

    I believe you can just use "AVERAGEIF" function, but let me summarize what you have just to make sure.

    Your examples and the premise of the question don't jive. I am of the understanding that you would like to take the mean (average) of all values in a range (in this case, column) that are less than 4. In the first example, the only values that are less than 4 are 2.5, 3.0, 2.0, and 2.5. That result for that average is 2.5, not 3.5. In the second example, you only have three examples that are less than 4. They add to 7, so the answer would be 2.33 (2 1/3).

    Is this what you want? If so, just use the AVERAGEIF function as it is straightforward. Here is the format:

    =AVERAGEIF(range, condition, [average_range])

    Note that average_range is optional, and you don't need it (it's a bit complicated to explain here, go see the example on the excel page at Microsoft).

    If the second example you posted were located in cells A1:A13, then in A14 (or any other cell) use the formula as follows:

    =AVERAGEIF(A1:A13,"<4")

    Note that you have to put the condition in quotes.
    Last edited by MS Excel Sheet Pro; 10-10-2017 at 01:42 PM.

  4. #4
    Registered User
    Join Date
    02-02-2017
    Location
    Sweden
    MS-Off Ver
    Office 365
    Posts
    12

    Re: Use only data found in a specified region

    Sorry about the confusion, I have now updated the values so that they are below 4 and attached a xlsx

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

    Re: Use only data found in a specified region

    6 and 8 aren't below 4.... If that's just a typo, say so and I'll have a think about this...

  6. #6
    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,118

    Re: Use only data found in a specified region

    No reply...

    This is not elegant, but it works:

    =AVERAGE(INDEX(A:A,SMALL(IF($A$1:$A$7<4,ROW($A$1:$A$7)),1+ROUND(COUNTIF(A:A,"<4")/4,0))):INDEX(A:A,SMALL(IF($A$1:$A$7<4,ROW($A$1:$A$7)),ROUND(3*COUNTIF(A:A,"<4")/4,0))))

    and

    =AVERAGE(INDEX(K:K,SMALL(IF($K$1:$K$13<4,ROW($K$1:$K$13)),1+ROUND(COUNTIF(K:K,"<4")/4,0))):INDEX(K:K,SMALL(IF($K$1:$K$13<4,ROW($K$1:$K$13)),ROUND(3*COUNTIF(K:K,"<4")/4,0))))

    Both are array formulae. 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...

  7. #7
    Registered User
    Join Date
    02-02-2017
    Location
    Sweden
    MS-Off Ver
    Office 365
    Posts
    12

    Re: Use only data found in a specified region

    Yes it was a typo...

  8. #8
    Registered User
    Join Date
    02-02-2017
    Location
    Sweden
    MS-Off Ver
    Office 365
    Posts
    12

    Re: Use only data found in a specified region

    Thanks, the soultion worked fine

  9. #9
    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,118

    Re: Use only data found in a specified region

    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. Grouping, If X They Y, ordering data by region
    By JoeExcelStruggler in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 09-19-2017, 04:59 AM
  2. Sales Data - restaurants per region
    By Lewis.Henderson88 in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 07-19-2017, 07:23 AM
  3. Searching column 1 with data from 2 and reporting found or not found
    By San75 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 11-15-2016, 05:23 PM
  4. Replies: 2
    Last Post: 06-01-2015, 06:23 PM
  5. [SOLVED] OptionButton choice to populate ListBox based on the "Region" found in a PivotField.
    By EnigmaMatter in forum Excel Programming / VBA / Macros
    Replies: 10
    Last Post: 02-26-2014, 04:30 PM
  6. Replies: 4
    Last Post: 05-17-2012, 06:30 PM
  7. Replies: 1
    Last Post: 10-04-2007, 12:04 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