top 3

debooo

Board Regular
Joined
Nov 2, 2006
Messages
86
hello,

Colum C has the results of Col A - Col B.

In D i want a formula that gives me the top 10 largest variances, but i want them to be displayed as they are (negative or positive).

currently i'm using {=large(abs(B:B),1)} entered as an array, which gives me the correct numbers. But if the largest variance is -500. the result from the array formula is giving me it as +500.

does anyone know of a way to get around this?
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
I'm using a range because in XL2003, you can't use whole column references in an array formula. If there are a positive and negative number that is the MAX variance, this will return the first one in the column. So if you had a -500 and a 500 and the -500 was first, it would return -500:

=INDEX(B1:B1000,MATCH(MAX(ABS(B1:B1000)),ABS(B1:B1000),0))

Confirm with CTRL-SHIFT-ENTER rather than just Enter.
 
Upvote 0
i think abs will always make it positive - maybe you should try

{=large(B:B,1)}
 
Upvote 0
iggydarsa:
The op wants the largest variance

If you have a set of

-500
37
12

Your formula would return 37 (although that formula doesn't need to be entered as an array formula), the correct answer is -500 as it is the largest variance.
 
Upvote 0
Or with LARGE:

=INDEX($B$1:$B$1000,MATCH(LARGE(ABS($B$1:$B$1000),1),ABS($B$1:$B$1000),0))

Confirm with CTRL-SHIFT-ENTER
 
Upvote 0

Forum statistics

Threads
1,213,537
Messages
6,114,216
Members
448,554
Latest member
Gleisner2

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top