<br />Sheet1<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 /></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></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;"></td><td style=";">Item 1</td><td style=";">Item 2</td><td style=";">Item 3</td><td style=";">Item 4</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">7/10/2011</td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td><td style="text-align: right;;">3</td><td style="text-align: right;;">4</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">7/11/2011</td><td style="text-align: right;;">2</td><td style="text-align: right;;">3</td><td style="text-align: right;;">4</td><td style="text-align: right;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">7/12/2011</td><td style="text-align: right;background-color: #FFFF99;;">3</td><td style="text-align: right;background-color: #FFFF99;;">2</td><td style="text-align: right;background-color: #FFFF99;;">4</td><td style="text-align: right;background-color: #FFFF99;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">7/13/2011</td><td style="text-align: right;;">4</td><td style="text-align: right;;">3</td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">7/14/2011</td><td style="text-align: right;;">4</td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td><td style="text-align: right;;">3</td></tr></tbody></table>
<br />Sheet2<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 /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</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;;">Rank</td><td style="font-weight: bold;;">Item</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">7/12/2011</td><td style="text-align: right;;">1</td><td style="background-color: #FFFF99;;">Item 4</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;">2</td><td style="background-color: #FFFF99;;">Item 2</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;">3</td><td style="background-color: #FFFF99;;">Item 1</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;">4</td><td style="background-color: #FFFF99;;">Item 3</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>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">C2</th><td style="text-align:left">=INDEX(<font color="Blue">Sheet1!$B$1:$E$1,1,MATCH(<font color="Red">B2,OFFSET(<font color="Green">Sheet1!$B$1:$E$1,MATCH(<font color="Purple">$A$2,Sheet1!$A$2:$A$6</font>),0</font>),0</font>)</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C3</th><td style="text-align:left">=INDEX(<font color="Blue">Sheet1!$B$1:$E$1,1,MATCH(<font color="Red">B3,OFFSET(<font color="Green">Sheet1!$B$1:$E$1,MATCH(<font color="Purple">$A$2,Sheet1!$A$2:$A$6</font>),0</font>),0</font>)</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C4</th><td style="text-align:left">=INDEX(<font color="Blue">Sheet1!$B$1:$E$1,1,MATCH(<font color="Red">B4,OFFSET(<font color="Green">Sheet1!$B$1:$E$1,MATCH(<font color="Purple">$A$2,Sheet1!$A$2:$A$6</font>),0</font>),0</font>)</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C5</th><td style="text-align:left">=INDEX(<font color="Blue">Sheet1!$B$1:$E$1,1,MATCH(<font color="Red">B5,OFFSET(<font color="Green">Sheet1!$B$1:$E$1,MATCH(<font color="Purple">$A$2,Sheet1!$A$2:$A$6</font>),0</font>),0</font>)</font>)</td></tr></tbody></table></td></tr></table><br />