Create dynamic dropdown with no 0 entries

Tom_T

New Member
Joined
Oct 12, 2021
Messages
3
Office Version
  1. 365
Platform
  1. Windows
Hi

I'm trying to make a dropdown list that removes selected entries and doesn't show any 0 entries.
Someone on reddit posted the following:

Untitled.png


Selections are done in column C with the dropdown list configured as =$H$6#
When an items is selected it is removed from the dropdown list.

The original code had the COUNTIF as C6:C11 and that worked great but didn't use all of the available dropdown options, I want to be able to select all options.
When I do that I get the #CALC! message, which then appears in the dropdown list.

Does anyone know how to do this correctly, so the cell in C can be empty or a value from the dropdown.

Thanks
 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
14,559
Office Version
  1. 365
Platform
  1. Windows
The countif ranges are the wrong way around, it should be COUNTIF(F6:F14,C6:C18)
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,937
Office Version
  1. 365
Platform
  1. Windows
Hi & welcome to MrExcel.
Do you mean that you simply want to get rid of the #Calc error?
 
Last edited:

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,937
Office Version
  1. 365
Platform
  1. Windows
@jasonb75 wouldn't putting it that way give a #Value error?
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,937
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

If you do just want to get rid of the error, you can use
Excel Formula:
=SORT(FILTER(F6:F14,COUNTIFS(C6:C18,F6:F14)=0,""))
which will leave you a blank value in the drop down.
 

Tom_T

New Member
Joined
Oct 12, 2021
Messages
3
Office Version
  1. 365
Platform
  1. Windows
If you do just want to get rid of the error, you can use
Excel Formula:
=SORT(FILTER(F6:F14,COUNTIFS(C6:C18,F6:F14)=0,""))
which will leave you a blank value in the drop down.
This does help but only if F6:F14 contain data. If I change this to F6:F100 then I get lots of 0 entries in the dropdown list which I'm trying to avoid.
Is there any way to do that ?

Thanks
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,937
Office Version
  1. 365
Platform
  1. Windows
This does help but only if F6:F14 contain data. If I change this to F6:F100 then I get lots of 0 entries in the dropdown list which I'm trying to avoid.
Then why didn't you say so to start with? ;)
You can use
Excel Formula:
=SORT(FILTER(F6:F100,(COUNTIFS(C6:C18,F6:F100)=0)*(F6:F100<>""),""))
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,937
Office Version
  1. 365
Platform
  1. Windows
Glad we could help & thanks for the feedback.
 

Forum statistics

Threads
1,148,145
Messages
5,745,049
Members
423,917
Latest member
Frank1931

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
Top