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 /></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;">1</td><td style="font-weight: bold;;">Filed1</td><td style="font-weight: bold;;">Filed2</td><td style="font-weight: bold;;">Amount</td><td style="text-align: right;;"></td><td style="font-weight: bold;;">Lookup Value</td><td style="text-align: right;;"></td><td style="font-weight: bold;;">Filed1</td><td style="font-weight: bold;;">Filed2</td><td style="font-weight: bold;;">Amount</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">A</td><td style=";">ASD</td><td style="text-align: right;;">100</td><td style="text-align: right;;"></td><td style="text-align: center;;">A</td><td style="text-align: right;;"></td><td style=";">A</td><td style=";">ASD</td><td style="text-align: right;;">100</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">B</td><td style=";">SDF</td><td style="text-align: right;;">365</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">A</td><td style=";">FGH</td><td style="text-align: right;;">241</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">C</td><td style=";">DFG</td><td style="text-align: right;;">514</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">A</td><td style=";">HJK</td><td style="text-align: right;;">541</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">A</td><td style=";">FGH</td><td style="text-align: right;;">241</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">C</td><td style=";">GHJ</td><td style="text-align: right;;">365</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">A</td><td style=";">HJK</td><td style="text-align: right;;">541</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></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">G2</th><td style="text-align:left">=IF(<font color="Blue">H2="","",$E$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">H2</th><td style="text-align:left">{=IFERROR(<font color="Blue">INDEX(<font color="Red">B$2:B$7,SMALL(<font color="Green">IF(<font color="Purple">$A$2:$A$7=$E$2,ROW(<font color="Teal">$A$2:$A$7</font>)-ROW(<font color="Teal">$A$2</font>)+1</font>),ROWS(<font color="Purple">H$2:H2</font>)</font>)</font>),""</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">I2</th><td style="text-align:left">{=IFERROR(<font color="Blue">INDEX(<font color="Red">C$2:C$7,SMALL(<font color="Green">IF(<font color="Purple">$A$2:$A$7=$E$2,ROW(<font color="Teal">$A$2:$A$7</font>)-ROW(<font color="Teal">$A$2</font>)+1</font>),ROWS(<font color="Purple">I$2:I2</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 />
Copy down...