Find Top 3 and Add Values to the Right

mcnealfbm

New Member
Joined
Jul 12, 2004
Messages
33
I have a very simple table. In it there are 4 rounds, I need to find the top 3 rounds (first deteremined by Rank, then by Points) When the top 3 of the 4 are picked, I need to add the points together. So in the example below, the top 3 are round 1 (Rank 1), round 4 (Rank 1) and round 2 (Rank #2 but it is the higher of the #2 rank). There could be a 1 in all four rounds or no 1's. The formula needs to populate in cell to the right of the table. So in this example the final score would be 291. 99+95+97.

Thanks!
Excel Workbook
BCDEFGHIN
4ROUND 1ROUND 2ROUND 3ROUND 4
5RankPointsRankPointsRankPointsRankPointsPoints for Best 3 Ranks
6199297296195
Sheet1
Excel 2007
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Maybe this array formula (use Ctrl+Shift+Enter and not only Enter):

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;">ROUND 1</td><td style="text-align: center;;"></td><td style="text-align: center;;">ROUND 2</td><td style="text-align: center;;"></td><td style="text-align: center;;">ROUND 3</td><td style="text-align: center;;"></td><td style="text-align: center;;">ROUND 4</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;">Rank</td><td style="text-align: center;;">Points</td><td style="text-align: center;;">Rank</td><td style="text-align: center;;">Points</td><td style="text-align: center;;">Rank</td><td style="text-align: center;;">Points</td><td style="text-align: center;;">Rank</td><td style="text-align: center;;">Points</td><td style="text-align: center;;">Points for Best 3 Ranks</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;;">1</td><td style="text-align: center;;">99</td><td style="text-align: center;;">2</td><td style="text-align: center;;">97</td><td style="text-align: center;;">2</td><td style="text-align: center;;">96</td><td style="text-align: center;;">1</td><td style="text-align: center;;">95</td><td style="text-align: center;;">291</td></tr></tbody></table><p style="width:4.2em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet11</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">I6</th><td style="text-align:left">{=SUM(<font color="Blue">IF(<font color="Red">A5:G5="Rank",IF(<font color="Green">A6:G6=1,B6:H6</font>)</font>)</font>)+MAX(<font color="Blue">IF(<font color="Red">A5:G5="Rank",IF(<font color="Green">A6:G6=2,B6:H6</font>)</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
Markmzz
 
Upvote 0
Interesting! What does Ctrl-Shift-Enter do to the formula other than the {} brackets?

Also the formula didn't quite work. If the rank were all #1 for all four rounds it adds all 4 numbers together and I need it to find the top 3 scores total. It determines the top 3 first by rank then value.

Thanks for the start though. I'm looking at it to see if I can modify it. I just didn't understand what the ctrl-shift-enter does for it.

Frances
 
Upvote 0
Interesting! What does Ctrl-Shift-Enter do to the formula other than the {} brackets?

Also the formula didn't quite work. If the rank were all #1 for all four rounds it adds all 4 numbers together and I need it to find the top 3 scores total. It determines the top 3 first by rank then value.

Thanks for the start though. I'm looking at it to see if I can modify it. I just didn't understand what the ctrl-shift-enter does for it.

Frances

Try this:

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;">ROUND 1</td><td style="text-align: center;;"></td><td style="text-align: center;;">ROUND 2</td><td style="text-align: center;;"></td><td style="text-align: center;;">ROUND 3</td><td style="text-align: center;;"></td><td style="text-align: center;;">ROUND 4</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;">Rank</td><td style="text-align: center;;">Points</td><td style="text-align: center;;">Rank</td><td style="text-align: center;;">Points</td><td style="text-align: center;;">Rank</td><td style="text-align: center;;">Points</td><td style="text-align: center;;">Rank</td><td style="text-align: center;;">Points</td><td style="text-align: center;;">Points for Best 3 Ranks</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;;">1</td><td style="text-align: center;;">99</td><td style="text-align: center;;">1</td><td style="text-align: center;;">97</td><td style="text-align: center;;">1</td><td style="text-align: center;;">96</td><td style="text-align: center;;">1</td><td style="text-align: center;;">95</td><td style="text-align: right;;">292</td></tr></tbody></table><p style="width:4.2em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet12</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">I6</th><td style="text-align:left">{=SUM(<font color="Blue">LARGE(<font color="Red">(<font color="Green">A5:G5="Rank"</font>)*(<font color="Green">A6:G6=1</font>)*(<font color="Green">B6:H6</font>),{1,2,3}</font>)</font>)+
IF(<font color="Blue">SUM(<font color="Red">(<font color="Green">A5:G5="Rank"</font>)*(<font color="Green">A6:G6=1</font>)</font>)>2,0,SUM(<font color="Red">LARGE(<font color="Green">(<font color="Purple">A5:G5="Rank"</font>)*(<font color="Purple">A6:G6=2</font>)*(<font color="Purple">B6:H6</font>),CHOOSE(<font color="Purple">SUM(<font color="Teal">(<font color="#FF00FF">A5:G5="Rank"</font>)*(<font color="#FF00FF">A6:G6=2</font>)</font>),,1,{1,2},{1,2,3}</font>)</font>)</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
To understand Ctrl+Shift+Enter look at this:

http://www.mrexcel.com/archive/Formulas/4633.html

Markmzz
 
Upvote 0

Forum statistics

Threads
1,224,505
Messages
6,179,147
Members
452,891
Latest member
JUSTOUTOFMYREACH

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