Conditional data validation

hedgie

Board Regular
Joined
Jun 23, 2004
Messages
174
Office Version
  1. 365
Platform
  1. Windows
Can this be done easily? Cell A2 should contain either N/A if the value of A1 is "NO" or the user should be able to select "yes" or "no" in A2 if the value of A1 is "YES".
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Set data validation for cell A1 to 'list' with the list values of "Yes,No"

Somewhere, maybe on another tab (to be hidden) put "N/A" in a cell. Name that cell "List1"

Somewhere on that same tab but the values "Yes", "No" in adjacent cells. Name that 2 cell range "List2"

Then insert a name "Lists" and set the refersto =IF(A1="No",list1,list2)

Then set data validation of A2 to list values '=lists'
 
Upvote 0
Hello hedgie
Here's another idea. Which one to use depends on how the "Yes" / "No" values
are being entered into A1.
First one is for if the entry is being made manually, copy/pasted or via code.
(Works with the Worksheet_Change event.)
Code:
Option Explicit
Option Compare Text

Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Address <> "$A$1" Then Exit Sub
Select Case Target.Value
  Case "No"
    With [A2]
      .Validation.Delete
      .Value = "N/A"
    End With
  Case "Yes"
    [A2] = ""
    With [A2].Validation
    .Delete
    .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, _
      Operator:=xlBetween, Formula1:="Yes, No"
    .IgnoreBlank = True
    .InCellDropdown = True
    End With
  Case Else
    With [A2]
      .Validation.Delete
      .Value = ""
    End With
End Select
End Sub
The second one is for if the value in A1 is not being entered but is actually the
return of a formula.
(Is basically the same but works with the Worksheet_Calculate event.)
Code:
Option Explicit
Option Compare Text

Private Sub Worksheet_Calculate()
Select Case [A1].Value
  Case "No"
    With [A2]
      .Validation.Delete
      .Value = "N/A"
    End With
  Case "Yes"
    [A2] = ""
    With [A2].Validation
    .Delete
    .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, _
      Operator:=xlBetween, Formula1:="Yes, No"
    .IgnoreBlank = True
    .InCellDropdown = True
    End With
  Case Else
    With [A2]
      .Validation.Delete
      .Value = ""
    End With
End Select
In either case you'll only need one or the other and they both get installed the same.
1) Right click the sheet tab and choose View code.
2) Copy/paste the code from here into white pane that is the sheet code module.
3) Press Alt+Q to close the vb editor and get back to your sheet.
 
Upvote 0

Forum statistics

Threads
1,214,587
Messages
6,120,405
Members
448,958
Latest member
Hat4Life

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