Summary

To make XLOOKUP display a blank cell when a lookup result is blank, you can use a formula based on LET, XLOOKUP, and the IF function. In the example shown, the formula in cell H9 is:

=LET(x,XLOOKUP(G9,B5:B16,D5:D16),IF(x="","",x))

Because the lookup result in cell D9 is empty, the final result is an empty string (""). By contrast, a standard XLOOKUP formula in cell H5 returns nothing, which displays as "0-Jan-00".

Explanation 

When XLOOKUP can't find a value in a lookup array, it returns an #N/A error. You can use the IFNA function or IFERROR function to trap this error and return a different result. However, when the result is an empty cell, XLOOKUP does not throw an error. Instead, XLOOKUP returns an empty result, which behaves like a zero. This can make it look like the lookup result has a value even though the original cell is empty.

In this example, the goal is to trap an empty lookup result from the XLOOKUP function and display the result as an empty cell. For example, in the worksheet shown, the formula in cell H5 is:

=XLOOKUP(G5,B5:B16,D5:D16)

Because H5 is formatted as a date, and because the result comes from cell D9 (which is empty) the result from XLOOKUP behaves like zero and displays as "0-Jan-00". The goal is to display a blank cell, as seen in cell H9, which contains a modified XLOOKUP formula.

Without LET

One way to solve this problem is with the IF function and two XLOOKUP function calls like this:

=IF(XLOOKUP(G5,B5:B16,D5:D16)="","",XLOOKUP(G5,B5:B16,D5:D16))

Translation: If the result from XLOOKUP is nothing, then return an empty string (""), otherwise, return the result from XLOOKUP.

The structure of the formula is redundant, since the XLOOKUP function appears twice, but the formula itself will work fine, and the same idea can be used with older functions like VLOOKUP.

With LET

One way to eliminate the second instance of XLOOKUP in the formula is to use the LET function. The LET function makes it possible to declare named variables in a formula. With LET, the same formula can be written like this:

=LET(x,XLOOKUP(G9,B5:B16,D5:D16),IF(x="","",x))

Translation: create a variable named "x" and use the result from XLOOKUP to assign a value to x. If x is empty, then return an empty string (""). Otherwise, return the value of x.

The result is the same but notice this streamlined version of the formula only uses the XLOOKUP function one time.

Multiple values

Because the IF function will process each item in an array separately, you can use the same pattern above to handle multiple results like this:

=LET(results,XLOOKUP(G9,B5:B16,C5:E16),IF(results="","",results))

The return array in this formula covers three columns, so XLOOKUP will return 3 values in an array. Each value in the array is processed separately by the IF function. The variable name "results" is entirely arbitrary.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.