Ranking formula

asad

Well-known Member
Joined
Sep 9, 2008
Messages
1,434
Hello,
I am trying to rank the employees based on the percentage of return ticket sales. But only if they sold more than 2000 tickets. I am unable to work out the formula for this. Can someone her help me on this?

Here is the sample table and Rank is the desired answer.
[TABLE="width: 277"]
<colgroup><col><col><col span="3"></colgroup><tbody>[TR]
[TD]Staff ID[/TD]
[TD]Rank[/TD]
[TD]Tickets Sold[/TD]
[TD]Retrurn Tickets[/TD]
[TD]Percent[/TD]
[/TR]
[TR]
[TD]180[/TD]
[TD]1[/TD]
[TD="align: right"]2866[/TD]
[TD="align: right"]1155[/TD]
[TD="align: right"]40.3%[/TD]
[/TR]
[TR]
[TD]299[/TD]
[TD]2[/TD]
[TD="align: right"]3092[/TD]
[TD="align: right"]1188[/TD]
[TD="align: right"]38.4%[/TD]
[/TR]
[TR]
[TD]168[/TD]
[TD] [/TD]
[TD="align: right"]1370[/TD]
[TD="align: right"]493[/TD]
[TD="align: right"]36.0%[/TD]
[/TR]
[TR]
[TD]178[/TD]
[TD] [/TD]
[TD="align: right"]247[/TD]
[TD="align: right"]87[/TD]
[TD="align: right"]35.2%[/TD]
[/TR]
[TR]
[TD]300[/TD]
[TD] [/TD]
[TD="align: right"]1423[/TD]
[TD="align: right"]490[/TD]
[TD="align: right"]34.4%[/TD]
[/TR]
[TR]
[TD]229[/TD]
[TD] [/TD]
[TD="align: right"]318[/TD]
[TD="align: right"]109[/TD]
[TD="align: right"]34.3%[/TD]
[/TR]
[TR]
[TD]93[/TD]
[TD] [/TD]
[TD="align: right"]1258[/TD]
[TD="align: right"]411[/TD]
[TD="align: right"]32.7%[/TD]
[/TR]
[TR]
[TD]34[/TD]
[TD] [/TD]
[TD="align: right"]614[/TD]
[TD="align: right"]197[/TD]
[TD="align: right"]32.1%[/TD]
[/TR]
[TR]
[TD]160[/TD]
[TD]3[/TD]
[TD="align: right"]3169[/TD]
[TD="align: right"]1010[/TD]
[TD="align: right"]31.9%[/TD]
[/TR]
[TR]
[TD]190[/TD]
[TD]4[/TD]
[TD="align: right"]2743[/TD]
[TD="align: right"]872[/TD]
[TD="align: right"]31.8%[/TD]
[/TR]
[TR]
[TD]32[/TD]
[TD]4[/TD]
[TD="align: right"]3095[/TD]
[TD="align: right"]983[/TD]
[TD="align: right"]31.8%[/TD]
[/TR]
[TR]
[TD]80[/TD]
[TD] [/TD]
[TD="align: right"]890[/TD]
[TD="align: right"]277[/TD]
[TD="align: right"]31.1%[/TD]
[/TR]
[TR]
[TD]223[/TD]
[TD] [/TD]
[TD="align: right"]26[/TD]
[TD="align: right"]8[/TD]
[TD="align: right"]30.8%[/TD]
[/TR]
[TR]
[TD]253[/TD]
[TD]5[/TD]
[TD="align: right"]2003[/TD]
[TD="align: right"]590[/TD]
[TD="align: right"]29.5%[/TD]
[/TR]
[TR]
[TD]120[/TD]
[TD] [/TD]
[TD="align: right"]842[/TD]
[TD="align: right"]245[/TD]
[TD="align: right"]29.1%[/TD]
[/TR]
[TR]
[TD]148[/TD]
[TD] [/TD]
[TD="align: right"]1475[/TD]
[TD="align: right"]418[/TD]
[TD="align: right"]28.3%[/TD]
[/TR]
[TR]
[TD]87[/TD]
[TD] [/TD]
[TD="align: right"]810[/TD]
[TD="align: right"]229[/TD]
[TD="align: right"]28.3%[/TD]
[/TR]
[TR]
[TD]129[/TD]
[TD] [/TD]
[TD="align: right"]1551[/TD]
[TD="align: right"]434[/TD]
[TD="align: right"]28.0%[/TD]
[/TR]
[TR]
[TD]156[/TD]
[TD]6[/TD]
[TD="align: right"]2205[/TD]
[TD="align: right"]607[/TD]
[TD="align: right"]27.5%[/TD]
[/TR]
[TR]
[TD]166[/TD]
[TD] [/TD]
[TD="align: right"]1896[/TD]
[TD="align: right"]508[/TD]
[TD="align: right"]26.8%[/TD]
[/TR]
[TR]
[TD]247[/TD]
[TD] [/TD]
[TD="align: right"]559[/TD]
[TD="align: right"]148[/TD]
[TD="align: right"]26.5%[/TD]
[/TR]
[TR]
[TD]114[/TD]
[TD] [/TD]
[TD="align: right"]435[/TD]
[TD="align: right"]115[/TD]
[TD="align: right"]26.4%[/TD]
[/TR]
[TR]
[TD]191[/TD]
[TD] [/TD]
[TD="align: right"]781[/TD]
[TD="align: right"]203[/TD]
[TD="align: right"]26.0%[/TD]
[/TR]
</tbody>[/TABLE]


Thanks for your help
Asad
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
considering your Tickets sold in column C and % in column E apply below formula in cell B2 rank column

=IF(C2>2000,RANK(E2,$E$2:$E$24),"")

[TABLE="width: 320"]
<colgroup><col width="64" span="5" style="width:48pt"> </colgroup><tbody>[TR]
[TD="class: xl65, width: 64"][TABLE="width: 320"]
<colgroup><col width="64" span="5" style="width:48pt"> </colgroup><tbody>[TR]
[TD="class: xl66, width: 64"]Staff ID[/TD]
[TD="class: xl67, width: 64"]Rank[/TD]
[TD="class: xl66, width: 64"]Tickets Sold[/TD]
[TD="class: xl66, width: 64"]Retrurn Tickets[/TD]
[TD="class: xl66, width: 64"]Percent[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]180[/TD]
[TD="class: xl67, align: right"]1[/TD]
[TD="class: xl66, align: right"]2866[/TD]
[TD="class: xl66, align: right"]1155[/TD]
[TD="class: xl65, width: 64"]40.30%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]299[/TD]
[TD="class: xl67, align: right"]2[/TD]
[TD="class: xl66, align: right"]3092[/TD]
[TD="class: xl66, align: right"]1188[/TD]
[TD="class: xl65, width: 64"]38.40%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]168[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]1370[/TD]
[TD="class: xl66, align: right"]493[/TD]
[TD="class: xl65, width: 64"]36.00%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]178[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]247[/TD]
[TD="class: xl66, align: right"]87[/TD]
[TD="class: xl65, width: 64"]35.20%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]300[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]1423[/TD]
[TD="class: xl66, align: right"]490[/TD]
[TD="class: xl65, width: 64"]34.40%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]229[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]318[/TD]
[TD="class: xl66, align: right"]109[/TD]
[TD="class: xl65, width: 64"]34.30%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]93[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]1258[/TD]
[TD="class: xl66, align: right"]411[/TD]
[TD="class: xl65, width: 64"]32.70%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]34[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]614[/TD]
[TD="class: xl66, align: right"]197[/TD]
[TD="class: xl65, width: 64"]32.10%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]160[/TD]
[TD="class: xl67, align: right"]9[/TD]
[TD="class: xl66, align: right"]3169[/TD]
[TD="class: xl66, align: right"]1010[/TD]
[TD="class: xl65, width: 64"]31.90%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]190[/TD]
[TD="class: xl67, align: right"]10[/TD]
[TD="class: xl66, align: right"]2743[/TD]
[TD="class: xl66, align: right"]872[/TD]
[TD="class: xl65, width: 64"]31.80%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]32[/TD]
[TD="class: xl67, align: right"]10[/TD]
[TD="class: xl66, align: right"]3095[/TD]
[TD="class: xl66, align: right"]983[/TD]
[TD="class: xl65, width: 64"]31.80%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]80[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]890[/TD]
[TD="class: xl66, align: right"]277[/TD]
[TD="class: xl65, width: 64"]31.10%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]223[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]26[/TD]
[TD="class: xl66, align: right"]8[/TD]
[TD="class: xl65, width: 64"]30.80%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]253[/TD]
[TD="class: xl67, align: right"]14[/TD]
[TD="class: xl66, align: right"]2003[/TD]
[TD="class: xl66, align: right"]590[/TD]
[TD="class: xl65, width: 64"]29.50%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]120[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]842[/TD]
[TD="class: xl66, align: right"]245[/TD]
[TD="class: xl65, width: 64"]29.10%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]148[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]1475[/TD]
[TD="class: xl66, align: right"]418[/TD]
[TD="class: xl65, width: 64"]28.30%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]87[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]810[/TD]
[TD="class: xl66, align: right"]229[/TD]
[TD="class: xl65, width: 64"]28.30%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]129[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]1551[/TD]
[TD="class: xl66, align: right"]434[/TD]
[TD="class: xl65, width: 64"]28.00%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]156[/TD]
[TD="class: xl67, align: right"]19[/TD]
[TD="class: xl66, align: right"]2205[/TD]
[TD="class: xl66, align: right"]607[/TD]
[TD="class: xl65, width: 64"]27.50%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]166[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]1896[/TD]
[TD="class: xl66, align: right"]508[/TD]
[TD="class: xl65, width: 64"]26.80%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]247[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]559[/TD]
[TD="class: xl66, align: right"]148[/TD]
[TD="class: xl65, width: 64"]26.50%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]114[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]435[/TD]
[TD="class: xl66, align: right"]115[/TD]
[TD="class: xl65, width: 64"]26.40%[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]191[/TD]
[TD="class: xl67"] [/TD]
[TD="class: xl66, align: right"]781[/TD]
[TD="class: xl66, align: right"]203[/TD]
[TD="class: xl65, width: 64"]26.00%[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[TD="class: xl65, width: 64"][/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:
Upvote 0
Assuming that you want this happen by means of a single formula, in B2 control+shift+enter, not just enter, and copy down:

=IF(C2>2000,SUM(IF(E2<LARGE(IF($C$2:$C$24>2000,$E$2:$E$24,""),ROW(INDIRECT("1:"&SUM(IF($C$2:$C$24>2000,IF(ISNUMBER($E$2:$E$24),1)))))),1))+1,"")
 
Upvote 0
I am not clear as what u r trying to active, but below function will work.

=IF(C2>2000,SUM(IF(E2,$E$2:$E$24,""),ROW(INDIRECT("1:"&SUM(IF($C$2:$C$24>2000,IF(ISNUMBER($E$2:$E$24),1)+1,""))))))

I don't know u r formula has E22000 for what??
 
Upvote 0
Assuming that you want this happen by means of a single formula, in B2 control+shift+enter, not just enter, and copy down:

=IF(C2>2000,SUM(IF(E2<LARGE(IF($C$2:$C$24>2000,$E$2:$E$24,""),ROW(INDIRECT("1:"&SUM(IF($C$2:$C$24>2000,IF(ISNUMBER($E$2:$E$24),1)))))),1))+1,"")

I see the formula is clobberd by the board software due to the presence of a < symbol…

=IF(C2>2000,SUM(IF(E2 < LARGE(IF($C$2:$C$24>2000,$E$2:$E$24,""),ROW(INDIRECT("1:"&SUM(IF($C$2:$C$24>2000,IF(ISNUMBER($E$2:$E$24),1)))))),1))+1,"")
 
Upvote 0
I see the formula is clobberd by the board software due to the presence of a < symbol…

=IF(C2>2000,SUM(IF(E2 < LARGE(IF($C$2:$C$24>2000,$E$2:$E$24,""),ROW(INDIRECT("1:"&SUM(IF($C$2:$C$24>2000,IF(ISNUMBER($E$2:$E$24),1)))))),1))+1,"")
Perfect as always.

You are a true genius Aladin.

Thanks a lot.
 
Upvote 0

Forum statistics

Threads
1,223,894
Messages
6,175,252
Members
452,623
Latest member
Techenthusiast

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