Largest Amount within a specific time period

superfb

Active Member
Joined
Oct 5, 2011
Messages
255
Office Version
  1. 2007
Platform
  1. Windows
Hi Guys

Im trying to figure out the largest amounts for a specific time frame, so the aim is to type in a date, and i the formula automatically populates the top 10 amounts in that time frame.

Regards
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
<br /><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 /></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></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;text-align: center;;">Dates</td><td style="font-weight: bold;text-align: center;;">Values</td><td style="font-weight: bold;text-align: center;;"></td><td style="font-weight: bold;text-align: center;;">Start_Date</td><td style="font-weight: bold;text-align: center;;">End_Date</td><td style="font-weight: bold;text-align: center;;"></td><td style="font-weight: bold;text-align: center;;">Top 10</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: center;;">8/5/2010</td><td style="text-align: center;;">1</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #FFFF99;;">8/25/2010</td><td style="text-align: center;background-color: #FFFF99;;">11/8/2010</td><td style="text-align: center;;">1</td><td style="text-align: center;background-color: #FFFF00;;">55</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: center;;">8/10/2010</td><td style="text-align: center;;">100</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">2</td><td style="text-align: center;background-color: #FFFF00;;">20</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;">8/15/2010</td><td style="text-align: center;;">3</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">3</td><td style="text-align: center;background-color: #FFFF00;;">19</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;">8/20/2010</td><td style="text-align: center;;">4</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;background-color: #FFFF00;;">18</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;background-color: #FFFF99;;">8/25/2010</td><td style="text-align: center;background-color: #FFFF99;;">5</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">5</td><td style="text-align: center;background-color: #FFFF00;;">17</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;background-color: #FFFF99;;">8/30/2010</td><td style="text-align: center;background-color: #FFFF99;;">6</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">6</td><td style="text-align: center;background-color: #FFFF00;;">16</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: center;background-color: #FFFF99;;">9/4/2010</td><td style="text-align: center;background-color: #FFFF00;;">55</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">7</td><td style="text-align: center;background-color: #FFFF00;;">15</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: center;background-color: #FFFF99;;">9/9/2010</td><td style="text-align: center;background-color: #FFFF99;;">8</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">8</td><td style="text-align: center;background-color: #FFFF00;;">14</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: center;background-color: #FFFF99;;">9/14/2010</td><td style="text-align: center;background-color: #FFFF99;;">9</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">9</td><td style="text-align: center;background-color: #FFFF00;;">13</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: center;background-color: #FFFF99;;">9/19/2010</td><td style="text-align: center;background-color: #FFFF99;;">10</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">10</td><td style="text-align: center;background-color: #FFFF00;;">12</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: center;background-color: #FFFF99;;">9/24/2010</td><td style="text-align: center;background-color: #FFFF99;;">11</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: center;background-color: #FFFF99;;">9/29/2010</td><td style="text-align: center;background-color: #FFFF00;;">12</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: center;background-color: #FFFF99;;">10/4/2010</td><td style="text-align: center;background-color: #FFFF00;;">13</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: center;background-color: #FFFF99;;">10/9/2010</td><td style="text-align: center;background-color: #FFFF00;;">14</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: center;background-color: #FFFF99;;">10/14/2010</td><td style="text-align: center;background-color: #FFFF00;;">15</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: center;background-color: #FFFF99;;">10/19/2010</td><td style="text-align: center;background-color: #FFFF00;;">16</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style="text-align: center;background-color: #FFFF99;;">10/24/2010</td><td style="text-align: center;background-color: #FFFF00;;">17</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="text-align: center;background-color: #FFFF99;;">10/29/2010</td><td style="text-align: center;background-color: #FFFF00;;">18</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="text-align: center;background-color: #FFFF99;;">11/3/2010</td><td style="text-align: center;background-color: #FFFF00;;">19</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">21</td><td style="text-align: center;background-color: #FFFF99;;">11/8/2010</td><td style="text-align: center;background-color: #FFFF00;;">20</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">22</td><td style="text-align: center;;">11/13/2010</td><td style="text-align: center;;">21</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">23</td><td style="text-align: center;;">11/18/2010</td><td style="text-align: center;;">200</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">24</td><td style="text-align: center;;">11/23/2010</td><td style="text-align: center;;">23</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr></tbody></table><br /><br /><table 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">G2</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F2</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G3</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F3</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G4</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F4</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G5</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F5</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G6</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F6</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G7</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F7</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G8</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F8</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G9</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F9</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G10</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F10</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G11</th><td style="text-align:left">{=LARGE(<font color="Blue">IF(<font color="Red">Dates>=Start_Date,IF(<font color="Green">Dates<=End_Date,Values</font>)</font>),F11</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 /><table 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>Workbook Defined Names</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">Name</th><th style="text-align:left">Refers To</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">Dates</th><td style="text-align:left">=Sheet2!$A$2:$A$24</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">End_Date</th><td style="text-align:left">=Sheet2!$E$2</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">Start_Date</th><td style="text-align:left">=Sheet2!$D$2</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">Values</th><td style="text-align:left">=Sheet2!$B$2:$B$24</td></tr></tbody></table></td></tr></table><br />


Video: LARGE IF
 
Upvote 0
Cheers for the reply

instead of the dates being 01/09/2011 - can it still be picked up in this format Sept-11?

Thanks
 
Upvote 0
yes, you would have to modify the formula to replace Start_Date and End_Date with a calculation that takes the Month and Year of the date cell and calculates the first and last date of the month.

Have a go at that yourself - its the best way to learn.

Hints:

the first day of the month is always 01/MM/YYYY
the last day of the month is always the day before 01/MM+1/YYYY (but watch out for year changes!)
 
Upvote 0
Thanks for the feedback, it doesnt seem to be working for me - do you think this has something to do witht he format?
 
Upvote 0
Assuming that "Sep-11" is a formatted date - presumably 1st of that month - (it'll show you in the formula bar) then you can still use the same formula that AlphaFrog suggested, are you looking for largest values in a single month or in another period?

What isn't working - can you post the formula you tried - what result did you get, an error or incorrect values returned?
 
Upvote 0

Forum statistics

Threads
1,224,568
Messages
6,179,595
Members
452,927
Latest member
whitfieldcraig

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