How do I create an IF Statement that contains a data validation option

jkitterm

New Member
Joined
Nov 2, 2017
Messages
12
I am filling out a list of capabilities that have sub-capabilities.
A2 is the Capabilty Name
A3 is the Sub-Capability name
B2 is drop down list (data validation ) with selections of "Yes", "No", or "N/A"
In B3 I am trying to create an IF Statement where if B2="YES" then I am presented with a drop down list (Yes, No, or N/A)to select from for B3 or if it is not Yes then leave the cell blank.

B2B3
A1CapabilityYes/No
A2VoiceYes
A3Voice Skills Based RoutingYes
A4IVRYes
A5IVR Call RoutingYes
A6IVR Skills Based routingNo
A7Automated SurveysNo
A8Surveys (IVR)
A9Surveys (Web/email/text)

<tbody>
</tbody>

I would think the IF statement would look something like this but I am not sure what the syntax is to have it present a drop down list:
=IF( A2="Yes", drop down list,IF(A2="No", "", IF(A2="N/A", "","")))
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
Copy and paste this macro into the worksheet code module. Do the following: right click the tab for your sheet and click 'View Code'. Paste the macro into the empty code window that opens up. Close the code window to return to your sheet. Make a selection in B2.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("B2")) Is Nothing Then Exit Sub
    Dim Choices As String
    Choices = "Yes, No, N/A"
    If Target = "Yes" Then
        Range("B3").Select
        With Selection.Validation
            .Delete
            .Add Type:=xlValidateList, _
            AlertStyle:=xlValidAlertStop, Operator:= _
            xlBetween, Formula1:=Choices
            .IgnoreBlank = True
            .InCellDropdown = True
            .InputTitle = ""
            .ErrorTitle = ""
            .InputMessage = ""
            .ErrorMessage = ""
            .ShowInput = True
            .ShowError = True
        End With
    Else
        Range("B3").Select
        With Selection.Validation
            .Delete
        End With
    End If
End Sub
 
Upvote 0
Mumps, thanks for this but I can not have any macros in this spreadsheet (nor am I that familiar with using macros)
Would you know the equivalent formula syntax for this?
Thanks again.
 
Upvote 0
I am not aware of any formula that will insert a validation list into a cell. If you just want to try the macro to see how it works, just follow my instructions in Post #2 .
 
Upvote 0
Mumps, Inserted the code you provided. It works when B2 is "Yes". However, when B2 is either "No" or "N/A" the value of B3 remains what it was before (it doesn't go to blank)
 
Upvote 0
Try this version:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("B2")) Is Nothing Then Exit Sub
    Dim Choices As String
    Choices = "Yes, No, N/A"
    If Target = "Yes" Then
        Range("B3").Select
        With Selection.Validation
            .Delete
            .Add Type:=xlValidateList, _
            AlertStyle:=xlValidAlertStop, Operator:= _
            xlBetween, Formula1:=Choices
            .IgnoreBlank = True
            .InCellDropdown = True
            .InputTitle = ""
            .ErrorTitle = ""
            .InputMessage = ""
            .ErrorMessage = ""
            .ShowInput = True
            .ShowError = True
        End With
    Else
        Range("B3").Select
        With Selection.Validation
            .Delete
        End With
        Range("B3").ClearContents
    End If
End Sub
 
Upvote 0
That worked.
Now, what would the syntax be if there are two or multiple sub-capabilities (B3 and B4 and B5) under the Capability

I see - Range("B3").Select - which is where I would presume the change would be made.
 
Upvote 0
I'm not sure what you mean. Could you please explain in detail, step-by-step, referring to specific cells.
 
Upvote 0
So just like you previously did but now there are two sub-cells instead of just one which need to change based upon B2.

If B2 ="Yes" I would want a drop down in in B3 and in B4. B2 is "No" or "N/A" I would want B3 and B4 to be blank

Hope that makes sense.
****** id="cke_pastebin" style="position: absolute; top: 0px; width: 1px; height: 1px; overflow: hidden; left: -1000px;">
B2B3
A1CapabilityYes/No
A2VoiceYes
A3Voice Skills Based RoutingYes
A4IVRYes
A5IVR Call RoutingYes
A6IVR Skills Based routingNo
A7Automated SurveysNo
A8Surveys (IVR)
A9Surveys (Web/email/text)

<tbody>
</tbody>
</body>
 
Upvote 0
Give this a try:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("B2")) Is Nothing Then Exit Sub
    Dim Choices As String
    Choices = "Yes, No, N/A"
    If Target = "Yes" Then
        Range("B3:B4").Select
        With Selection.Validation
            .Delete
            .Add Type:=xlValidateList, _
            AlertStyle:=xlValidAlertStop, Operator:= _
            xlBetween, Formula1:=Choices
            .IgnoreBlank = True
            .InCellDropdown = True
            .InputTitle = ""
            .ErrorTitle = ""
            .InputMessage = ""
            .ErrorMessage = ""
            .ShowInput = True
            .ShowError = True
        End With
    Else
        Range("B3:B4").Select
        With Selection.Validation
            .Delete
        End With
        Range("B3:B4").ClearContents
    End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,920
Messages
6,122,272
Members
449,075
Latest member
staticfluids

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