Is there a way to "look up" a value in a sheet table from a UDF?

JenniferMurphy

Well-known Member
Joined
Jul 23, 2011
Messages
2,532
Office Version
  1. 365
Platform
  1. Windows
I would like to write a UDF that can "look up" a value in a sheet table if passed the name of the table and the search text. Here's a simplified example of what I would like to do:

Suppose I have this table in Sheet1 containing the scores in a trivia game:

C/RCD
4Amy28
5Brad21
6Chris
35
7Dave12
8Emily19

<tbody>
</tbody>

The range $C$4:$D$8 has the global name "TriviaScores".

I would like to write a UDF that can "look up" a player's score if passed the name of the player and the name of the table.

The UDF needs to be able to be called from any sheet in the workbook, not necessarily the sheet where the table is.

This code seems to work.
Code:
Public Function Trivia(PlayerName As String, TableName As Range) As Variant

Dim Score As Integer
Dim NumRows As Integer
NumRows = TableName.Rows.Count  'The number of columns

Dim Rowi As Integer
For Rowi = 1 To NumRows
  If UCase(PlayerName) = UCase(TableName(Rowi, 1)) Then
    Trivia = CDbl(TableName(Rowi, 2))
    Exit Function
  End If
Next Rowi

Trivia = CVErr(xlErrName)

End Function

For example, if a cell contains the expression,

Code:
=Trivia("Chris","TriviaScores")

The result in that cell would be "35". The "35" needs to be a numeric value (Double).

A few questions:
  1. Is there a more efficient way than looping through each row? These tables are going to have just a few rows (<10).
  2. Do I need the CDbl function? It seems to work without it.
  3. If I change the UDF to Double (from Variant), it returns a Value error instead of the Name error. Why?
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Here is an example of the UDF in action:

C/RCDE
12Brad21D12: =trivia(C12,TriviaTable)
13EMILY19D13: =trivia(C13,TriviaTable)
14dave12D14: =trivia(C14,TriviaTable)
15aMy28D15: =trivia(C15,TriviaTable)
16ChRiS35D16: =trivia(C16,TriviaTable)
17Zeus#NAME?D17: =trivia(C17,TriviaTable)

<tbody>
</tbody>
 
Upvote 0
Well, that wasn't too bad and it seems to work:

Code:
Public Function Trivia2(PlayerName As String, TableName As Range) As Variant

On Error GoTo Error
Trivia2 = Application.WorksheetFunction.VLookup(PlayerName, TableName, 2, False)
Exit Function

Error:
Trivia2 = CVErr(xlErrNA)

End Function

Thanks
 
Upvote 0
Upvote 0
If you use worksheetfunction then you need an error handler, but if you just use Application you dont need the error handler
Code:
Dim Check As Variant
Check = Application.vlookup(...)
If IsError(Check) Then
   MsgBox "not found"
End If
 
Last edited:
Upvote 0
If you use worksheetfunction then you need an error handler, but if you just use Application you dont need the error handler
Code:
Dim Check As Variant
Check = Application.vlookup(...)
If IsError(Check) Then
   MsgBox "not found"
End If

This is very helpful. I just tested it and it appears to work exactly as you describe.

Thank you
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,214,972
Messages
6,122,530
Members
449,088
Latest member
RandomExceller01

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