See if this gives you an idea:
<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 /></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=";">Starting Inventory</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;">2</td><td style="text-align: right;;"></td><td style=";">Price</td><td style=";">Small</td><td style=";">Medium</td><td style=";">Large</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Blue Long Sleeve Shirt</td><td style="text-align: right;;">30</td><td style="text-align: right;;">8</td><td style="text-align: right;;">9</td><td style="text-align: right;;">7</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Red Long Sleeve Shirt</td><td style="text-align: right;;">30</td><td style="text-align: right;;">9</td><td style="text-align: right;;">10</td><td style="text-align: right;;">8</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></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></tr><tr ><td style="color: #161120;text-align: center;">7</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;">8</td><td style=";">Sales Sheet</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;">9</td><td style=";">Item Purchased</td><td style=";">Size</td><td style=";">Quantity</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style=";">Blue Long Sleeve Shirt</td><td style=";">Small</td><td style="text-align: right;;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style=";">Red Long Sleeve Shirt</td><td style=";">Medium</td><td style="text-align: right;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style=";">Red Long Sleeve Shirt</td><td style=";">Small</td><td style="text-align: right;;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">13</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;">14</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;">15</td><td style=";">Current Inventory</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;">16</td><td style="text-align: right;;"></td><td style=";">Price</td><td style=";">Small</td><td style=";">Medium</td><td style=";">Large</td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style=";">Blue Long Sleeve Shirt</td><td style="text-align: right;;">30</td><td style="text-align: right;;">5</td><td style="text-align: right;;">9</td><td style="text-align: right;;">7</td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style=";">Red Long Sleeve Shirt</td><td style="text-align: right;;">30</td><td style="text-align: right;;">5</td><td style="text-align: right;;">8</td><td style="text-align: right;;">8</td></tr></tbody></table><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style="background-color: #E0E0F0;text-align: center;color: #161120"><th><b>Sheet1</b></th></tr></td></thead></table><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">C17</th><td style="text-align:left">=INDEX(<font color="Blue">$C$3:$E$4,MATCH(<font color="Red">$A17,$A$3:$A$4,0</font>),MATCH(<font color="Red">C$16,$C$2:$E$2,0</font>)</font>)-SUMPRODUCT(<font color="Blue">--(<font color="Red">$A$10:$A$12=$A17</font>),--(<font color="Red">$B$10:$B$12=C$16</font>),$C$10:$C$12</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">D17</th><td style="text-align:left">=INDEX(<font color="Blue">$C$3:$E$4,MATCH(<font color="Red">$A17,$A$3:$A$4,0</font>),MATCH(<font color="Red">D$16,$C$2:$E$2,0</font>)</font>)-SUMPRODUCT(<font color="Blue">--(<font color="Red">$A$10:$A$12=$A17</font>),--(<font color="Red">$B$10:$B$12=D$16</font>),$C$10:$C$12</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">E17</th><td style="text-align:left">=INDEX(<font color="Blue">$C$3:$E$4,MATCH(<font color="Red">$A17,$A$3:$A$4,0</font>),MATCH(<font color="Red">E$16,$C$2:$E$2,0</font>)</font>)-SUMPRODUCT(<font color="Blue">--(<font color="Red">$A$10:$A$12=$A17</font>),--(<font color="Red">$B$10:$B$12=E$16</font>),$C$10:$C$12</font>)</td></tr></tbody></table></td></tr></table><br />