XLOOKUP

Searches for a value in an array and returns a reference to a cell or range of cells.

XLOOKUP function is a modern and flexible replacement for older functions like VLOOKUP, HLOOKUP, and LOOKUP. XLOOKUP supports approximate and exact matching, wildcards (* ?) or regular expressions for partial matches, and lookups in vertical or horizontal ranges. XLOOKUP can perform a reverse search and offers a fast binary search option when working with large datasets.

Syntaxe

XLOOKUP( [Search criterion] ; Search Array ; Result Array [ ; [ Result if not found ] [ ; [Match Mode] [ ; Search Mode ] ] ] )

Search criterion: (optional) The value of any type to search for in Array. If omitted, XLOOKUP returns blank cells it finds in Search Array.

Search Array: is the reference of the array to search. Array must be a 1-dimensional array and must be contained in one sheet only.

Result Array: is the reference of the array or range to return.

note

If Result Array is a range of cells, the XLOOKUP function must be entered as an array formula.


Result if not found: a text or cell content to return if the Lookup value is not found. If a valid match is not found and Result if not found is omitted, the function returns the #N/A error.

Match Mode: (optional) specifies the match type. Values can be:

Search Mode: (optional) specifies the search mode to use.

warning

Match Mode values 2 and 3 cannot be combined with binary search (Search Mode value 2 or -2).


note

Any of the optional arguments can be omitted. An optional argument requires all preceding separators to be present.


Exemples

Supposons que nous ayons construit une petite table de base de données occupant la plage de cellules A1:DO4 et contenant des informations de base sur 118 éléments chimiques. La première colonne contient les en-têtes de ligne " Élément ", " Symbole ", " Numéro atomique " et " Masse atomique relative ". Les colonnes suivantes contiennent les informations pertinentes pour chacun des éléments, classées de gauche à droite par numéro atomique. Par exemple, les cellules B1:B4 contiennent "Hydrogène", "H", "1" et "1,008", tandis que les cellules DO1:DO4 contiennent "Oganesson", "Og", "118" et "294".

A

B

C

D

...

DO

1

Élément

Hydrogène

Hélium

Lithium

...

Oganesson

2

Symbole

H

He

Li

...

Og

3

Numéro atomique

1

2

3

...

118

4

Masse atomique relative

1.008

4.0026

6.94

...

294


{=XLOOKUP("Atomic Number";A2:A4;A2:DO4)} returns the array

Atomic Number

1

2

3

...

118


{=XLOOKUP("Helium";B1:DO1;B1:DO4)} returns the array

Helium

He

2

4.0026


{=XLOOKUP("Kryptonite";B1:DO1;B1:DO4;"Unknown element")} returns the array {"Unknown element","Unknown element","Unknown element","Unknown element"}.

Informations techniques

tip

This function is available since LibreOffice 24.8.


Cette fonction ne fait pas partie de Open Document Format for Office Applications (OpenDocument) Version 1.3. Partie 4 : Norme de format de formule recalculée (OpenFormula). L'espace de nom est

COM.MICROSOFT.XLOOKUP

Aidez-nous !