Drop-Down box selection -> execute formula -> return answer Help!

Pnasri

New Member
Joined
Jul 14, 2011
Messages
1
Hi All!

I'm trying to create a function in VBA so that when you choose from the drop down box in cell D6 it executes a formula in D7. If you don't mind taking a look at the VBA code I wrote, I know there is something wrong with it (never used VBA)!

Function CalcValue(Target_Product As String)
If Target_Product = "Conventional Hypo" Then
CalcValue = B6 * 5

ElseIf Target_Product = "Safety Hypo" Then
CalcValue = B6 * 18

ElseIf Target_Product = "Syringes" Then
CalcValue = B6 * 38

ElseIf Target_Product = "Autoneedle" Then
CalcValue = B6 * 8

ElseIf Target_Product = "Sharps" Then
CalcValue = (B6 * 16) + (75 * B6)

ElseIf Target_Product = "N" Then
CalcValue = B6 * 95

ElseIf Target_Product = "AutoG" Then
CalcValue = B6 * 46

ElseIf Target_Product = "AutoG BC" Then
CalcValue = B6 * 53

ElseIf Target_Product = "Ste" Then
CalcValue = B6 * 45

ElseIf Target_Product = "Trays" Then
CalcValue = (B6 * 12) + (B6 * 9)

Else
CalcValue = 0
End If

End Function

Also, I found that if I put in a nested "If-Else" function in the cell itself it works, yet Excel'03 only allows me to have 7 variables. I've gotten the nested formula to work for "Conventional Hypo" and "Sharps".

IF(D6="Sharps",(B6*O23+(O20*B6)),IF(D6="Conventional Hypo",(B6*O8)))

set


Thanks for taking a look at this... I wish I knew VBA better!

Pnasri
 
Last edited:

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
Instead of a nested IF formula, you could use the LOOKUP function
Code:
=IF(D6="","",B6*LOOKUP(D6,{"Conventional Hypo","Safety Hypo","Syringes","Autoneedle","Sharps","N","AutoG","AutoG BC","Ste","Trays"}, {5,18,38,8,91,95,46,53,45,21}))

Or use a lookup table and the VLOOKUP function
<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 /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></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;">6</td><td style="text-align: center;;">5</td><td style="text-align: center;;"></td><td style="text-align: center;;">Conventional Hypo</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #FFFF99;;">Conventional Hypo</td><td style="text-align: center;background-color: #FFFF99;;">5</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">25</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #FFFF99;;">Safety Hypo</td><td style="text-align: center;background-color: #FFFF99;;">18</td></tr><tr ><td style="color: #161120;text-align: center;">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;;"></td><td style="text-align: center;background-color: #FFFF99;;">Syringes</td><td style="text-align: center;background-color: #FFFF99;;">38</td></tr><tr ><td style="color: #161120;text-align: center;">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;;"></td><td style="text-align: center;background-color: #FFFF99;;">Autoneedle</td><td style="text-align: center;background-color: #FFFF99;;">8</td></tr><tr ><td style="color: #161120;text-align: center;">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;;"></td><td style="text-align: center;background-color: #FFFF99;;">Sharps</td><td style="text-align: center;background-color: #FFFF99;;">91</td></tr><tr ><td style="color: #161120;text-align: center;">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;background-color: #FFFF99;;">N</td><td style="text-align: center;background-color: #FFFF99;;">95</td></tr><tr ><td style="color: #161120;text-align: center;">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;background-color: #FFFF99;;">AutoG</td><td style="text-align: center;background-color: #FFFF99;;">46</td></tr><tr ><td style="color: #161120;text-align: center;">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;background-color: #FFFF99;;">AutoG BC</td><td style="text-align: center;background-color: #FFFF99;;">53</td></tr><tr ><td style="color: #161120;text-align: center;">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;background-color: #FFFF99;;">Ste</td><td style="text-align: center;background-color: #FFFF99;;">45</td></tr><tr ><td style="color: #161120;text-align: center;">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;background-color: #FFFF99;;">Trays</td><td style="text-align: center;background-color: #FFFF99;;">21</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">D7</th><td style="text-align:left">=IF(<font color="Blue">D6="","",B6*VLOOKUP(<font color="Red">D6,F6:G15,2,0</font>)</font>)</td></tr></tbody></table></td></tr></table><br />

Note the lookup table can be located anywhere.
 
Last edited:
Upvote 0
I agree with AlphaFrog (as usual). There's no need to design and code your own VLOOKUP-type function when Excel already has one.
 
Upvote 0

Forum statistics

Threads
1,224,586
Messages
6,179,730
Members
452,939
Latest member
WCrawford

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