Data Validation Drop-Down List - Named Range and Additional Options

Tashat

Board Regular
Joined
Jan 12, 2005
Messages
135
Office Version
  1. 365
Platform
  1. Windows
Hi All

I have a drop-down list in data validation which links to a dynamic named range. However, I also want to add another option in the drop-down list "N/A". I don't want this option in the dynamic named range, because the "N/A" option only applies to this particular drop down list. Is there a formula I can type into the source box in the Data Validation menu to allow this?

I've tried
Excel Formula:
=OrganisationListSort,"N/A"
but Excel doesn't like that.

OrganisationListSort is the dynamic named range

1636451632455.png
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
I'm not sure about doing it directly in the DV Source box but could this work for you?

Use a formula like I have in column L to make a new dynamic list of the members of OrganisationListSort and "N/A" then set up your DV for this particular cell as I have shown in M1

21 11 09.xlsm
LM
1a
2b
3c
4d
5e
6N/A
7
DVwithNA
Cell Formulas
RangeFormula
L1:L6L1=FILTERXML("<p><c>"&TEXTJOIN("</c><c>",1,OrganisationListSort,"N/A")&"</c></p>","//c")
Dynamic array formulas.
Cells with Data Validation
CellAllowCriteria
M1List=L1#


1636453221407.png
 
Upvote 0
Solution
I'm not sure about doing it directly in the DV Source box but could this work for you?

Use a formula like I have in column L to make a new dynamic list of the members of OrganisationListSort and "N/A" then set up your DV for this particular cell as I have shown in M1

21 11 09.xlsm
LM
1a
2b
3c
4d
5e
6N/A
7
DVwithNA
Cell Formulas
RangeFormula
L1:L6L1=FILTERXML("<p><c>"&TEXTJOIN("</c><c>",1,OrganisationListSort,"N/A")&"</c></p>","//c")
Dynamic array formulas.
Cells with Data Validation
CellAllowCriteria
M1List=L1#


View attachment 50810
Perfect solution once again! Thank you very much. XML is definitely something new for me to learn. I have however discovered that it doesn't like Organisation Names with special characters like & in it.

Thank you so much.
 
Upvote 0
I have however discovered that it doesn't like Organisation Names with special characters like & in it.
Try this instead

Excel Formula:
=FILTERXML("<p><c>"&SUBSTITUTE(TEXTJOIN("</c><c>",1,OrganisationListSort,"N/A"),"&","&amp;")&"</c></p>","//c")

1636456538911.png
 
Upvote 0

Forum statistics

Threads
1,212,927
Messages
6,110,733
Members
448,294
Latest member
jmjmjmjmjmjm

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