Documentation/How Tos/Calc: HLOOKUP function

From Apache OpenOffice Wiki
Jump to: navigation, search


HLOOKUP

Returns a value from a table row, in the column found by lookup in the first row.

Syntax:

HLOOKUP(lookupvalue; datatable; rowindex; mode)

lookupvalue is a value (number, text or logical value) to look up in the top row of the range/array datatable. When a value is matched in the top row, HLOOKUP returns the corresponding value (in the same column) in the rowindexth row of datatable, where rowindex = 1 is the top row.
If mode is 0 or FALSE, the top row of datatable may be unordered, and the first exact match is found (searching left to right).
If mode is 1 or TRUE, or is omitted, the top row of datatable must be sorted, with numbers in ascending order appearing before text values in alphabetic order. Firstly an exact match is sought; if there is more than one exact match, the one found is not necessarily the leftmost. If there is no exact match, the position to the left of where value would appear in the top row is found; the #N/A error results if that position is not in the table.
HLOOKUP will find exact matches treating lookupvalue as a regular expression, if regular expressions are enabled on the Tools - Options - OpenOffice.org Calc - Calculate dialog. This only makes sense, and should only be used, if mode is 0 or FALSE.
If 'Search criteria + and <> must apply to whole cells' is enabled on the Tools - Options - OpenOffice.org Calc - Calculate dialog, lookupvalue must match the whole text in the cell; if not, it can match just part of the text.
Matching is always case-insensitive - the case setting on the Tools - Options - OpenOffice.org Calc - Calculate dialog does not apply.

Examples:

In these examples, cells A1, B1, C1, D1, E1 contain 3, 5, cat, mat, matter, and cells A2, B2, C2, D2, E2 contain A, B, C, D, E.

Calc hlookup example.png

HLOOKUP(3; A1:E2; 2; 0)

returns A. Cell A1 in the top row matches 3. The contents of the corresponding cell on the 2nd row (that is, A2) are returned. The top row happens to be sorted, but this is not necessary in mode 0.

HLOOKUP(4; A1:E2; 2; 0)

returns #N/A. There is no match for 4.

HLOOKUP("CAT"; A1:E2; 2; 0)

returns C. The difference between lower and upper case is ignored, so CAT matches cat.

HLOOKUP("m.t"; A1:E2; 2; 0)

returns D if regular expressions are enabled (and #N/A if not). The dot '.' stands for 'any single character' in a regular expression, so m.t matches mat.

HLOOKUP(".at"; A1:E2; 2; 0)

returns C if regular expressions are enabled. cat matches; so does mat, but the leftmost match is always found in mode 0.

HLOOKUP("at"; A1:E2; 2; 0)

returns #N/A if 'Search criteria + and <> must apply to whole cells' is enabled and C otherwise. at does not match any whole cell contents, but it matches part of cat.

HLOOKUP(3; A1:E2; 2; 1)

returns A. Cell A1 in the top row matches 3. The top row must be sorted in mode 1, with text coming after numbers. matter follows mat because although the first letters are the same, matter has more letters.

HLOOKUP(4; A1:E2; 2; 1)

returns A. 4 would appear between 3 and 5 in the top row, so the position to the left is found.

HLOOKUP(1; A1:E2; 2; 1)

returns #N/A. 1 would appear before 3 in the top row, and there is no position to the left of that in the table.

HLOOKUP(7; A1:E2; 2; 1)

returns B. 7 would appear between 5 and cat in the top row, so the position to the left is found.

HLOOKUP("apple"; A1:E2; 2; 1)

returns B. apple would appear between 5 and cat in the top row, so the position to the left is found.

HLOOKUP("mate"; A1:E2; 2; 1)

returns D. mate would appear between mat and matter in the top row, so the position to the left is found.

HLOOKUP("rat"; A1:E2; 2; 1)

returns E. rat would appear after matter in the top row, so the position to the left is found.

See also:

CHOOSE, INDEX, LOOKUP, MATCH, OFFSET, VLOOKUP

PROB

Regular Expressions in Calc

Spreadsheet functions

Issues:

  • The case sensitivity behaviour is discussed in issue 71000
Personal tools