Having Data Validation List to ignore NA error elements?

thraling

Board Regular
Joined
Sep 22, 2015
Messages
112
Hello,
I have a drop-down list that picks its values from a known range (let's say: "A1:A8").
The problem is that this range has random #N/A that I don't want to display in the list, like:

1
#N/A
25
#N/A
4
#N/A
47
45

In this case I would like my list just to display ("1", "25", "4", "47", "45").
I cannot install plugins. I prefer not to use macros. The errors must anyway be displayed in the source range.

Is there a way?
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Let A2:A9 of Sheet1 house the sample you posted.

In B1 enter:

=COUNT(A2:A9)

if we have to do solely with numbers. Otherwise:

=SUMPRODUCT(1-ISERROR(A2:A9))

In B2 control+shift+enter, not just enter, and copy down:

=IF(ROWS($B$2:B2)>$B$1,"",INDEX($A$2:$A$9,SMALL(IF(1-ISERROR($A$2:$A$9),ROW($A$2:$A$9)-ROW($A$2)+1),ROWS($B$2:B2))))

Now define DVList in FORMULAS | Name Manager as referring to:

=OFFSET(Sheet1!$B$2,0,0,Sheet1!$B$1)

which you can use as list in data validation.
 
Upvote 0
Sorry, I tested it, but I'm having an error in the list:
it shows indeed the right number of elements, but only the 1 is displayed, the others are blank.
For example, if I have a list like
A
B
#N/A
C

it will show ("A", "", "", ""). I don't know where the error can be
 
Upvote 0
Aladin Akyurek

In B2 control+shift+enter, not just enter, and copy down:

=IF(ROWS($B$2:B2)>$B$1,"",INDEX($A$2:$A$9,SMALL(IF(1-ISERROR($A$2:$A$9),ROW($A$2:$A$9)-ROW($A$2)+1),ROWS($B$2:B2))))

This is CSE formula.
 
Upvote 0
Sorry, I tested it, but I'm having an error in the list:
it shows indeed the right number of elements, but only the 1 is displayed, the others are blank.
For example, if I have a list like
A
B
#N/A
C

it will show ("A", "", "", ""). I don't know where the error can be

Sheet1

3
AA
BB
#N/AC
C

<tbody>
</tbody>

In B1 just enter:

=SUMPRODUCT(1-ISERROR(A2:A5))

In B2 control+shift+enter, not just enter, and copy down:

=IF(ROWS($B$2:B2)>$B$1,"",INDEX($A$2:$A$5,SMALL(IF(1-ISERROR($A$2:$A$5),ROW($A$2:$A$5)-ROW($A$2)+1),ROWS($B$2:B2))))

Now define DVList in FORMULAS | Name Manager as referring to:

=OFFSET(Sheet1!$B$2,0,0,Sheet1!$B$1)

Adjust the sheet name to suit.

Test...

Select C1.
Activate Data Validation.
Select List for Allow.
Enter the following in the box for Source...

=DVList

Click OK.

C1 should have a list of A, B, and C to choose from.
 
Upvote 0
Sorry, I missed the "and copy down" part.
Three words, completely different result :)

Thank you again!
 
Upvote 0

Forum statistics

Threads
1,214,592
Messages
6,120,433
Members
448,961
Latest member
nzskater

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