+ Reply to Thread
Results 1 to 17 of 17

maximum deviation whilst retaining sign

Hybrid View

  1. #1
    Registered User
    Join Date
    03-25-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    20

    maximum deviation whilst retaining sign

    Hi all,

    I need to identify the top ten extremes (+ive and -ive) in a set of figures. This effectively gives me the largest "10" deviations from 0. It may be for example that 8 of the ten are negative.

    I need a formula will compile this list (similar to LARGE() ) but which retains the sign. (so can't just use abs() ).

    Thanks in advance

    PJ

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    Assuming data is in A1:A15, use a helper column to find the matches.

    So in B1:

    =IF(ABS(A1)>=LARGE(ABS($A$1:$A$15),10),A1,"")

    confirmed with CTRL+SHIFT+ENTER not just ENTER and copied down

    Then in the result cells, enter:

    =LARGE($B$1:$B$15,ROWS($A$1:$A1))

    copied down 10 cells
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    You could also use a single array formula:

    =LARGE(IF(ABS($A$1:$A$15)>=LARGE(ABS($A$1:$A$15),10),$A$1:$A$15),ROWS($A$1:$A1))

    confirmed with CTRL+SHIFT+ENTER and copied down.

  4. #4
    Registered User
    Join Date
    03-25-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: maximum deviation whilst retaining sign

    Edit: just saw your second post - let me look at that - cheers

    Thanks for your help so far, much appreciated.
    Unfortunately the size of the range of the data is variable (as is the start point). I have everything outomated (its periodic data) and the proposed solution would be quite difficult to integrate. Is it possible to do this in one cell, in a manner where the start and end of the range can be determined using indirect/offset?

    I guess, Im looking for a "maxdeviation(range,k) solution or something that looks a little like it format wise. I'm beggining to fear this might not be achievable!
    Did you have any further thoughts?

  5. #5
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    Assuming you have a list of numbers (no blanks between) in column A, then you could use something like:

    =LARGE(IF(ABS($A$1:INDEX($A:$A,COUNT($A:$A)-ROW($A$1)+1))>=LARGE(ABS($A$1:INDEX($A:$A,COUNT($A:$A)-ROW($A$1)+1)),10),$A$1:INDEX($A:$A,COUNT($A:$A)-ROW($A$1)+1)),ROWS($A$1:$A1))
    Where A1 represents first row...

  6. #6
    Registered User
    Join Date
    03-25-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: maximum deviation whilst retaining sign

    OK I think you may be very close to cracking this for me and I think the issue is I haven't been clear with the format of my output.

    I am dealing with periodic data streams (quarterly and annual sections of an ever increasing stream of data). I will have three tables, quarter to date, year to date, and since inception. Each of these will have ten cells. In the large() scenario, I'd have:

    Large(range_defined_by_indirect_or_offset,1/2/3/4/5/6/7/8/9/10)

    So the locations of the cells would be static, as would what they reference ("2nd largest deviation from x range").

    Sorry if its simple to convert your solution to this format but I'm not terribly skilled in excel!

    Thanks again

  7. #7
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    To best describe or illustrate your problem you would be better off attaching a dummy workbook, the workbook should contain the same structure and some dummy data of the same type as the type you have in your real workbook - so, if a cell contains numbers & letters in this format abc-123 then that should be reflected in the dummy workbook.

    If needed supply a before and after sheet in the workbook so the person helping you can see what you are trying to achieve.

    Doing this will ensure you get the result you need!

  8. #8
    Registered User
    Join Date
    03-25-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: maximum deviation whilst retaining sign

    Thanks, file attached (assuming it worked!)

    The table in red is what I will eventually populate. THe column in red is the (ever expanding) data set. The other red bit highlights the fact that the period end of the Q and 1 year periods will change. (I've sorted out dynamic ranges thanks to this forum so that isn't an issue so long as I can manipulate the proposed solution).

    Does this help?
    Attached Files Attached Files

  9. #9
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    I am a little confused about the 3 columns in the table... are we only concerned with filling 1 column with those 10 numbers?

    If so, try:

    =LARGE(IF(ABS($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I)))>=LARGE(ABS($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I))),10),$I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I))),ROWS($I$37:$I37))
    confirmed with CTRL+SHIFT+ENTER not just ENTER and copied down

  10. #10
    Registered User
    Join Date
    03-25-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: maximum deviation whilst retaining sign

    The formula does not work - "too few arguments" - it may be a copy and paste issue as in the code box it ends on "999" which I don't think is where you intended it to end. This may be because my monitor has a low resolution and the scrollbars on the "code box" are buggy.

    re the three columns, each colum is top ten deviations over a period - over the quarter, over the year, and since the start of the data stream. THis particular data stream does not have a year's worth of data. So, each column will have to reference a dynamic range with different start and end points. Hopefully I can figure that out for myself given your "static" solution using offset. If you feel adventurous however, the variables are the third red-highlighted section!

  11. #11
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    Here is the sheet with the above formula working.
    Attached Files Attached Files

  12. #12
    Registered User
    Join Date
    03-25-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: maximum deviation whilst retaining sign

    Thanks very much. Two further questions:
    1) Technically the largest deviation is the one that currently appears as the 10th largest. Is there a way to re-order this correctly?
    2) If I replace all I37 references with a dynamic start reference and I:I references with dynamic range references, should the formula still function?

  13. #13
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    1. Change the first LARGE to a SMALL

    =SMALL(IF(ABS($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I)))>=LARGE(ABS($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I))),10),$I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I))),ROWS($I$37:$I37))
    2. It should still work.. Make sure to make the references absolute (i.e. add $ signs to freeze references).

  14. #14
    Registered User
    Join Date
    03-25-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: maximum deviation whilst retaining sign

    Thanks again - sorry I feel like I'm being a right pain! That solution simply reverses the order; the output should be:
    -0.63
    -0.11
    -0.10
    +0.10
    -0.09
    +0.09
    +0.09

    etc

  15. #15
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    Probably not see easily with a single formula... it might require some helper formula(s) as we had originally started with.

  16. #16
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: maximum deviation whilst retaining sign

    If the likelihood of having the exact same number (with all decimals) repeated in the range (even in the opposite sign) is very close to nil, you may be able to get away with:

    =INDEX($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I)),MATCH(LARGE(IF(ABS($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I)))>=LARGE(ABS($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I))),10),ABS($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I)))),ROWS($I$37:$I37)),ABS($I$37:INDEX($I:$I,MATCH(9.999999E+307,$I:$I))),0))
    confirmed with CTRL+SHIFT+ENTER and copied down....

    ... but this doesn't guarantee accuracy if a number is duplicated exactly (in opposite sign).

  17. #17
    Registered User
    Join Date
    03-25-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    20

    Re: maximum deviation whilst retaining sign

    OK thank you for all your help I'll think on it!
    Why this isn't a standard excel formula is beyond me - this would seem like a pretty standard requirement for contribution to risk type analysis.

+ 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