Using UDFs in Data Validation List

RatExcel

Board Regular
Joined
Aug 24, 2014
Messages
222
Hello,

I've created UDF that returns array of unique values from selected range.
It works perfectly when entered in worksheet cell. When I hit F9 it displays all unque values as array.
I wanted to use this function as source for Data Validation List but I get error "A named range you specified cannot be found"
When I go to Name Manager and add new named range and then try to put it as source in Data Validation I get error "The Source currently evaluates to an error. Do you want to countinue?".
Can anyone help me with this? Is it posssible to apply such function in Data Validation?
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Is it posssible to apply such function in Data Validation?

Unfortunately no. You can only use an actual range or a literal comma delimited string (i.e. not the result of a formula of any kind).
 
Upvote 0
Great, I didn't know about comma delimited string option. So basiclly I can wrote some on change event code that when change in specific range occurs it will trigger my UNIQUE function for that range, convert the result array into comma delimited string and using VBA apply it as data validation formula source. Sounds like an option.
 
Upvote 0
Check out the below Example...

Before running Macroname: Update_DV Select cell A1 - go to Data Validation - Select Allow: List, Source: MyTrio

then proceed... Hope this helps... Jim

Excel 2012
A
B
C
D
E
F
G
H
I
J
K
L
1
MyTrio
2
Peter
3
Paul
4
Mary
5
Paul
6
Mary
7
Peter
8
Paul
9
10

<TBODY>
</TBODY>
Sheet1

Code:
Sub Update_DV()
    sLr = Range("D" & Rows.Count).End(xlUp).Row
    Range("G:G").ClearContents
    Range("A1").ClearContents
    Range("D1:D" & sLr).AdvancedFilter Action:=xlFilterCopy, CopyToRange _
        :=Range("G1"), Unique:=True
    With Range("G1")
        .Select
        .Delete Shift:=xlUp
    End With
    dLr = Range("G" & Rows.Count).End(xlUp).Row
    On Error Resume Next
    ActiveWorkbook.Names.Add Name:="MyTrio", RefersToR1C1:="=Sheet1!R1C7:R" & dLr & "C7"
    On Error GoTo 0
    
End Sub
 
Last edited:
Upvote 0
Code:
Private Sub Worksheet_BeforeDoubleClick(ByVal Target As Range, Cancel As Boolean)
    Columns(Target.Column).SpecialCells(2).AdvancedFilter xlFilterCopy, , Cells(1, 100), True
    Cells(1, 100).CurrentRegion.Name = "snb_000"
    
    Cells(20, 1).Validation.Add 3, , , Join([transpose(snb_000)], ",")
    Cells(1, 100).CurrentRegion.ClearContents
End Sub
 
Upvote 0
Corectify from Jim May. Source below requires an "=" sign before the range name.


Allow: List, Source: =MyTrio
 
Upvote 0
Just bear in mind that if you use a string, you're limited to about 255 characters.
 
Upvote 0
That limitation only applies to the saving of the validation list.
The next time you open the file you will have to add the validation rule to the cell again.
 
Upvote 0
True - as long as you remember to clear them or are ok with risking a corrupt workbook, you can use a longer string. Using a range is easier.
 
Upvote 0

Forum statistics

Threads
1,214,383
Messages
6,119,198
Members
448,874
Latest member
Lancelots

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