Data Validation List showing blanks

VBAotter

New Member
Joined
Mar 3, 2023
Messages
1
Office Version
  1. 2016
Platform
  1. Windows
I have a data validation list which worked great at first. I have it set for all of column A. Now I had to delete some rows, and now those rows show as blanks in the drop down despite having the ignore blanks box checked. How do I fix this? Why is this happening? Please and thank you! Excel 2016 Windows
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
those rows show as blanks in the drop down despite having the ignore blanks box checked
The ignore blanks box is not for ignoring blanks in the list.

Suppose with the sample sheet below, the original Data Validation was set to $F$1:$F$10 but now that range includes blank cells that you want to exclude.
For your excel version, create a list without blanks as shown in column G and put the formula shown in H1. You can then hide columns G:H if you want.
Set up your Data Validation as shown instead of $F$1:$F$10

23 03 04.xlsm
ABFGH
1aa$G$1:$G$7
2bb
3d
4dg
5h
6i
7gj
8h 
9i 
10j 
DV List
Cell Formulas
RangeFormula
H1H1=ADDRESS(ROW(G1),COLUMN(G1))&":"&ADDRESS(ROW(G1)+COUNTIF(G1:G10,"?*")-1,COLUMN(G1))
G1:G10G1=IFERROR(INDEX(F:F,AGGREGATE(15,6,ROW(F$1:F$10)/(F$1:F$10<>""),ROWS(G$1:G1))),"")
Cells with Data Validation
CellAllowCriteria
A1List=INDIRECT($H$1)


Then the drop-down looks like this

1677916919661.png
 
Upvote 0

Forum statistics

Threads
1,214,648
Messages
6,120,725
Members
448,987
Latest member
marion_davis

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