Try;
<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 /><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><th>J</th><th>K</th><th>L</th><th>M</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;;">DATE</td><td style="font-weight: bold;;">COUNT</td><td style="font-weight: bold;;">COST</td><td style="font-weight: bold;;">DATE</td><td style="font-weight: bold;;">COUNT</td><td style="font-weight: bold;;">COST</td><td style="font-weight: bold;;">DATE</td><td style="font-weight: bold;;">COUNT</td><td style="font-weight: bold;;">COST</td><td style="text-align: right;;"></td><td style=";">Which Row?</td><td style="text-align: right;;">3</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">1/1/2011</td><td style="text-align: right;;">5</td><td style="text-align: right;;">$50 </td><td style="text-align: right;;">1/1/2010</td><td style="text-align: right;;">4</td><td style="text-align: right;;">$60 </td><td style="text-align: right;;">1/1/2009</td><td style="text-align: right;;">3</td><td style="text-align: right;;">$70 </td><td style="text-align: right;;"></td><td style=";">Which Column?</td><td style="text-align: right;;">7</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">1/2/2011</td><td style="text-align: right;;">10</td><td style="text-align: right;;">$100 </td><td style="text-align: right;;">1/2/2010</td><td style="text-align: right;;">9</td><td style="text-align: right;;">$90 </td><td style="text-align: right;;">1/2/2009</td><td style="text-align: right;;">8</td><td style="text-align: right;;">$80 </td><td style="text-align: right;;"></td><td style=";">Lookup Date</td><td style="text-align: right;;">1/2/2009</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="font-weight: bold;;">DATE</td><td style="font-weight: bold;;">COUNT</td><td style="font-weight: bold;;">COST</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">1/2/2009</td><td style="text-align: right;;">8</td><td style="text-align: right;;">80</td></tr></tbody></table><p style="width:3.6em;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">Sheet1</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>Worksheet 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">K6</th><td style="text-align:left">=L3</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">L6</th><td style="text-align:left">=INDEX(<font color="Blue">A1:I1100,L1,L2+1</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">M6</th><td style="text-align:left">=INDEX(<font color="Blue">A1:I1100,L1,L2+2</font>)</td></tr></tbody></table></td></tr></table><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">L1</th><td style="text-align:left">{=SMALL(<font color="Blue">IF(<font color="Red">A2:I1000=L3,ROW(<font color="Green">A2:I1000</font>)</font>),1</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">L2</th><td style="text-align:left">{=SMALL(<font color="Blue">IF(<font color="Red">A2:I1000=L3,COLUMN(<font color="Green">A2:I1000</font>)</font>),1</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 />