Large Function with Multiple Criteria Question, Ranking

UrbanJungleFashion

New Member
Joined
Oct 14, 2014
Messages
17
Hey Everyone!

Since there isn't a RankIf function I'm having an issue creating a ranking statement based off an IF statement in combination with a Large Function.

Here is what my goal is:
To find the largest variance for each territory using an If/Large function. I'm not sure if should be using an index match as well.

Example:
A B C
[TABLE="width: 192"]
<colgroup><col width="64" span="3" style="width:48pt"> </colgroup><tbody>[TR]
[TD="width: 64"]Location[/TD]
[TD="width: 64"]Territory[/TD]
[TD="width: 64"] Var[/TD]
[/TR]
[TR]
[TD]0001[/TD]
[TD]484[/TD]
[TD="class: xl69, align: right"]38%[/TD]
[/TR]
[TR]
[TD]0002[/TD]
[TD]521[/TD]
[TD="class: xl69, align: right"]67%[/TD]
[/TR]
[TR]
[TD]0003[/TD]
[TD]803[/TD]
[TD="class: xl69, align: right"]17%[/TD]
[/TR]
[TR]
[TD]0004[/TD]
[TD]484[/TD]
[TD="class: xl69, align: right"]97%[/TD]
[/TR]
[TR]
[TD]0005[/TD]
[TD]484[/TD]
[TD="class: xl69, align: right"]15%[/TD]
[/TR]
[TR]
[TD]0006[/TD]
[TD]521[/TD]
[TD="class: xl69, align: right"]24%[/TD]
[/TR]
[TR]
[TD]0007[/TD]
[TD]803[/TD]
[TD="class: xl69, align: right"]33%[/TD]
[/TR]
[TR]
[TD]0008[/TD]
[TD]803[/TD]
[TD="class: xl69, align: right"]47%[/TD]
[/TR]
[TR]
[TD]0009[/TD]
[TD]521[/TD]
[TD="class: xl69, align: right"]3%[/TD]
[/TR]
[TR]
[TD]0010[/TD]
[TD]484[/TD]
[TD="class: xl69, align: right"]19%[/TD]
[/TR]
</tbody>[/TABLE]


Ideally this would be the results:
[TABLE="width: 128"]
<colgroup><col width="64" span="2" style="width:48pt"> </colgroup><tbody>[TR]
[TD="width: 64"]484[/TD]
[TD="class: xl71, width: 64, align: right"]97%[/TD]
[/TR]
[TR]
[TD]521[/TD]
[TD="class: xl71, align: right"]67%[/TD]
[/TR]
[TR]
[TD]803[/TD]
[TD="class: xl71, align: right"]33%
[/TD]
[/TR]
</tbody>[/TABLE]

Can someone help me with the correct statement?

Thank You!
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
[TABLE="class: grid, width: 192"]
<tbody>[TR]
[TD="width: 64, bgcolor: transparent"][/TD]
[TD="width: 64, bgcolor: transparent"]A
[/TD]
[TD="width: 64, bgcolor: transparent"]B
[/TD]
[TD="width: 64, bgcolor: transparent"]C
[/TD]
[/TR]
[TR]
[TD="width: 64, bgcolor: transparent"]1
[/TD]
[TD="width: 64, bgcolor: transparent"]location
[/TD]
[TD="width: 64, bgcolor: transparent"]Territory
[/TD]
[TD="width: 64, bgcolor: transparent"]var
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]2
[/TD]
[TD="bgcolor: transparent, align: right"]1
[/TD]
[TD="bgcolor: transparent, align: right"]484
[/TD]
[TD="bgcolor: transparent, align: right"]38%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]3
[/TD]
[TD="bgcolor: transparent, align: right"]2
[/TD]
[TD="bgcolor: transparent, align: right"]521
[/TD]
[TD="bgcolor: transparent, align: right"]67%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]4
[/TD]
[TD="bgcolor: transparent, align: right"]3
[/TD]
[TD="bgcolor: transparent, align: right"]803
[/TD]
[TD="bgcolor: transparent, align: right"]17%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]5
[/TD]
[TD="bgcolor: transparent, align: right"]4
[/TD]
[TD="bgcolor: transparent, align: right"]484
[/TD]
[TD="bgcolor: transparent, align: right"]97%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]6
[/TD]
[TD="bgcolor: transparent, align: right"]5
[/TD]
[TD="bgcolor: transparent, align: right"]484
[/TD]
[TD="bgcolor: transparent, align: right"]15%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]7
[/TD]
[TD="bgcolor: transparent, align: right"]6
[/TD]
[TD="bgcolor: transparent, align: right"]521
[/TD]
[TD="bgcolor: transparent, align: right"]24%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]8
[/TD]
[TD="bgcolor: transparent, align: right"]7
[/TD]
[TD="bgcolor: transparent, align: right"]803
[/TD]
[TD="bgcolor: transparent, align: right"]33%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]9
[/TD]
[TD="bgcolor: transparent, align: right"]8
[/TD]
[TD="bgcolor: transparent, align: right"]803
[/TD]
[TD="bgcolor: transparent, align: right"]47%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]10
[/TD]
[TD="bgcolor: transparent, align: right"]9
[/TD]
[TD="bgcolor: transparent, align: right"]521
[/TD]
[TD="bgcolor: transparent, align: right"]3%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]11
[/TD]
[TD="bgcolor: transparent, align: right"]10
[/TD]
[TD="bgcolor: transparent, align: right"]484
[/TD]
[TD="bgcolor: transparent, align: right"]19%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]12
[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]13
[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]14
[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]15
[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent, align: right"]484
[/TD]
[TD="bgcolor: transparent, align: right"]97%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]16
[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent, align: right"]521
[/TD]
[TD="bgcolor: transparent, align: right"]67%
[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]17
[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent, align: right"]803
[/TD]
[TD="bgcolor: transparent, align: right"]47%
[/TD]
[/TR]
</tbody>[/TABLE]

In C15 try This is an array formula and must be commited with Control+Shift+Enter. If done correctly Excel will put {} around the formula.
Code:
=MAX(IF($B$2:$B$11=B15,$C$2:$C$11,0))
 
Last edited:
Upvote 0
Thank You!

that worked perfectly! I didn't even consider the max function!

[TABLE="class: grid, width: 192"]
<tbody>[TR]
[TD="width: 64, bgcolor: transparent"][/TD]
[TD="width: 64, bgcolor: transparent"]A[/TD]
[TD="width: 64, bgcolor: transparent"]B[/TD]
[TD="width: 64, bgcolor: transparent"]C[/TD]
[/TR]
[TR]
[TD="width: 64, bgcolor: transparent"]1[/TD]
[TD="width: 64, bgcolor: transparent"]location[/TD]
[TD="width: 64, bgcolor: transparent"]Territory[/TD]
[TD="width: 64, bgcolor: transparent"]var[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]2[/TD]
[TD="bgcolor: transparent, align: right"]1[/TD]
[TD="bgcolor: transparent, align: right"]484[/TD]
[TD="bgcolor: transparent, align: right"]38%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]3[/TD]
[TD="bgcolor: transparent, align: right"]2[/TD]
[TD="bgcolor: transparent, align: right"]521[/TD]
[TD="bgcolor: transparent, align: right"]67%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]4[/TD]
[TD="bgcolor: transparent, align: right"]3[/TD]
[TD="bgcolor: transparent, align: right"]803[/TD]
[TD="bgcolor: transparent, align: right"]17%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]5[/TD]
[TD="bgcolor: transparent, align: right"]4[/TD]
[TD="bgcolor: transparent, align: right"]484[/TD]
[TD="bgcolor: transparent, align: right"]97%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]6[/TD]
[TD="bgcolor: transparent, align: right"]5[/TD]
[TD="bgcolor: transparent, align: right"]484[/TD]
[TD="bgcolor: transparent, align: right"]15%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]7[/TD]
[TD="bgcolor: transparent, align: right"]6[/TD]
[TD="bgcolor: transparent, align: right"]521[/TD]
[TD="bgcolor: transparent, align: right"]24%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]8[/TD]
[TD="bgcolor: transparent, align: right"]7[/TD]
[TD="bgcolor: transparent, align: right"]803[/TD]
[TD="bgcolor: transparent, align: right"]33%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]9[/TD]
[TD="bgcolor: transparent, align: right"]8[/TD]
[TD="bgcolor: transparent, align: right"]803[/TD]
[TD="bgcolor: transparent, align: right"]47%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]10[/TD]
[TD="bgcolor: transparent, align: right"]9[/TD]
[TD="bgcolor: transparent, align: right"]521[/TD]
[TD="bgcolor: transparent, align: right"]3%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]11[/TD]
[TD="bgcolor: transparent, align: right"]10[/TD]
[TD="bgcolor: transparent, align: right"]484[/TD]
[TD="bgcolor: transparent, align: right"]19%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]12[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]13[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]14[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]15[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent, align: right"]484[/TD]
[TD="bgcolor: transparent, align: right"]97%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]16[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent, align: right"]521[/TD]
[TD="bgcolor: transparent, align: right"]67%[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"]17[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent, align: right"]803[/TD]
[TD="bgcolor: transparent, align: right"]47%[/TD]
[/TR]
</tbody>[/TABLE]

In C15 try This is an array formula and must be commited with Control+Shift+Enter. If done correctly Excel will put {} around the formula.
Code:
=MAX(IF($B$2:$B$11=B15,$C$2:$C$11,0))
 
Upvote 0
Change the 0 at the end to a large negative number and It will return the largest variance even if it is negative (as long as it is not smaller then the large negative number).
Code:
=MAX(IF($B$2:$B$11=B15,$C$2:$C$11,[COLOR=#ff0000]-999999[/COLOR]))
 
Upvote 0
I think this my be what you actually want. With this if a territory is -1,-6,-7 it will return -7%
Code:
=IF(H15=I15,MIN(IF($B$2:$B$11=B15,$C$2:$C$11,0)),MAX(IF($B$2:$B$11=B15,$C$2:$C$11,0)))
 
Upvote 0

Forum statistics

Threads
1,225,149
Messages
6,183,194
Members
453,151
Latest member
Lizamaison

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