Data Validation - Ignore Blanks Not Working?

cevors

New Member
Joined
Aug 1, 2019
Messages
4
Good evening,

I'm trying to create a drop-down that is essentially generated by an array formula. The range is 15 cells, but the list often has less than 15 values. Is there a way to get the drop-down menu to not have a bunch of blank white space at the bottom with a scrollbar for lists that are shorter than 15? In essence, is there a way to 'ignore blanks' even though the cells have formulas in them?
 

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
The formula is an array formula:
{=IFERROR(INDEX(Lists!$BS$3:$BS$521,SMALL(IF('Loot Council'!$Y$1=Lists!$BR$3:$BR$521,ROW(Lists!$BS$3:$BS$521)-MIN(ROW(Lists!$BS$3:$BS$521))+1,""),ROW()-2)),"")}

So the IFERROR formula displays a blank cell is there is an error -- but is there a way to have the Data Validation ignore the cells that display as blank?
 
Upvote 0
Here is one option for you to consider.
Suppose those 15 cells with formulas are J2:J16, but less actually show values.
In another cell (I have used K1) put this formula. =CELL("Address",J2)&":"&CELL("address",OFFSET(J2,COUNTIF(J2:J16,"?*")-1,0)) (You can hide the column with this formula if you want)
Now, in your Data Validation cell(s), choose for Data Validation: Allow: List -> Source: =INDIRECT($K$1)
 
Upvote 0

Forum statistics

Threads
1,213,507
Messages
6,114,029
Members
448,543
Latest member
MartinLarkin

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