Spreadsheet Functions

This section contains descriptions of the Spreadsheet functions together with an example.

За да пристапите до оваа наредба...

Вметни - Функција - Категорија Табеларни пресметки


[text/scalc/01/func_error_type.xhp#error_type_head not found].

Returns a number representing a specific Error type, or the error value #N/A, if there is no error.

STYLE

Applies a style to the cell containing the formula.

ADDRESS

Returns a cell address (reference) as text, according to the specified row and column numbers. You can determine whether the address is interpreted as an absolute address (for example, $A$1) or as a relative address (as A1) or in a mixed form (A$1 or $A1). You can also specify the name of the sheet.

For interoperability the ADDRESS and INDIRECT functions support an optional parameter to specify whether the R1C1 address notation instead of the usual A1 notation should be used.

In ADDRESS, the parameter is inserted as the fourth parameter, shifting the optional sheet name parameter to the fifth position.

In INDIRECT, the parameter is appended as the second parameter.

In both functions, if the argument is inserted with the value 0, then the R1C1 notation is used. If the argument is not given or has a value other than 0, then the A1 notation is used.

In case of R1C1 notation, ADDRESS returns address strings using the exclamation mark '!' as the sheet name separator, and INDIRECT expects the exclamation mark as sheet name separator. Both functions still use the dot '.' sheet name separator with A1 notation.

When opening documents from ODF 1.0/1.1 format, the ADDRESS functions that show a sheet name as the fourth parameter will shift that sheet name to become the fifth parameter. A new fourth parameter with the value 1 will be inserted.

When storing a document in ODF 1.0/1.1 format, if ADDRESS functions have a fourth parameter, that parameter will be removed.

note

Do not save a spreadsheet in the old ODF 1.0/1.1 format if the ADDRESS function's new fourth parameter was used with a value of 0.


note

The INDIRECT function is saved without conversion to ODF 1.0/1.1 format. If the second parameter was present, an older version of Calc will return an error for that function.


Syntax

ADDRESS(Row; Column [; Abs [; A1 [; "Sheet"]]])

row represents the row number for the cell reference

column represents the column number for the cell reference (the number, not the letter)

abs determines the type of reference:

1: absolute ($A$1)

2: row reference type is absolute; column reference is relative (A$1)

3: row (relative); column (absolute) ($A1)

4: relative (A1)

A1 (optional) - if set to 0, the R1C1 notation is used. If this parameter is absent or set to another value than 0, the A1 notation is used.

sheet represents the name of the sheet. It must be placed in double quotes.

Example:

ADDRESS(1; 1; 2; "Sheet2") returns the following: Sheet2.A$1

If the formula above is in cell B2 of current sheet, and the cell A1 in sheet 2 contains the value -6, you can refer indirectly to the referenced cell using a function in B2 by entering =ABS(INDIRECT(B2)). The result is the absolute value of the cell reference specified in B2, which in this case is 6.

AREAS

Returns the number of individual ranges that belong to a multiple range. A range can consist of contiguous cells or a single cell.

The function expects a single argument. If you state multiple ranges, you must enclose them into additional parentheses. Multiple ranges can be entered using the semicolon (;) as divider, but this gets automatically converted to the tilde (~) operator. The tilde is used to join ranges.

Syntax

AREAS(Reference)

Reference represents the reference to a cell or cell range.

Example

=AREAS(A1:B3;F2;G1) returns 3, as it is a reference to three cells and/or areas.

=AREAS(All) returns 1 if you have defined an area named All under Data - Define Range.

CHOOSE

Uses an index to return a value from a list of up to 30 values.

Syntax

CHOOSE(Index; Value 1 [; Value 2 [; ... [; Value 30]]])

Index is a reference or number between 1 and 30 indicating which value is to be taken from the list.

Value 1, Value 2, ..., Value 30 is the list of values entered as a reference to a cell or as individual values.

Example

=CHOOSE(A1; B1; B2; B3; "Today"; "Yesterday"; "Tomorrow"), for example, returns the contents of cell B2 for A1 = 2; for A1 = 4, the function returns the text "Today".

COLUMN

Returns the column number of a cell reference. If the reference is a cell the column number of the cell is returned; if the parameter is a cell area, the corresponding column numbers are returned in a single-row array if the formula is entered as an array formula. If the COLUMN function with an area reference parameter is not used for an array formula, only the column number of the first cell within the area is determined.

Syntax

COLUMN([Reference])

Reference is the reference to a cell or cell area whose first column number is to be found.

If no reference is entered, the column number of the cell in which the formula is entered is found. LibreOffice Calc automatically sets the reference to the current cell.

Example

=COLUMN(A1) equals 1. Column A is the first column in the table.

=COLUMN(C3:E3) equals 3. Column C is the third column in the table.

=COLUMN(D3:G10) returns 4 because column D is the fourth column in the table and the COLUMN function is not used as an array formula. (In this case, the first value of the array is always used as the result.)

{=COLUMN(B2:B7)} and =COLUMN(B2:B7) both return 2 because the reference only contains column B as the second column in the table. Because single-column areas have only one column number, it does not make a difference whether or not the formula is used as an array formula.

=COLUMN() returns 3 if the formula was entered in column C.

{=COLUMN(Rabbit)} returns the single-row array (3, 4) if "Rabbit" is the named area (C1:D3).

COLUMNS

Returns the number of columns in the given reference.

Syntax

COLUMNS(array)

array is the reference to a cell range whose total number of columns is to be found. The argument can also be a single cell.

Example

=COLUMNS(B5) returns 1 because a cell only contains one column.

=COLUMNS(A1:C5) equals 3. The reference comprises three columns.

=COLUMNS(Rabbit) returns 2 if "Rabbit" is the named range (C1:D3).

DDE

Returns the result of a DDE-based link. If the contents of the linked range or section changes, the returned value will also change. You must reload the spreadsheet or choose Edit - Links to see the updated links. Cross-platform links, for example from a LibreOffice installation running on a Windows machine to a document created on a Linux machine, are not allowed.

Syntax

DDE("Server"; "File"; "Range" [; Mode])

Server is the name of a server application. LibreOffice applications have the server name "soffice".

File is the complete file name, including path specification.

Range is the area containing the data to be evaluated.

Mode is an optional parameter that controls the method by which the DDE server converts its data into numbers.

Mode

Effect

0 or missing

Number format from the "Default" cell style

1

Data are always interpreted in the standard format for US English

2

Data are retrieved as text; no conversion to numbers


Example

=DDE("soffice";"c:\office\document\data1.ods";"sheet1.A1") reads the contents of cell A1 in sheet1 of the LibreOffice Calc spreadsheet data1.ods.

=DDE("soffice";"c:\office\document\motto.odt";"Today's motto") returns a motto in the cell containing this formula. First, you must enter a line in the motto.odt document containing the motto text and define it as the first line of a section named Today's Motto (in LibreOffice Writer under Insert - Section). If the motto is modified (and saved) in the LibreOffice Writer document, the motto is updated in all LibreOffice Calc cells in which this DDE link is defined.

ERRORTYPE

Returns the number corresponding to an error value occurring in a different cell. With the aid of this number, you can generate an error message text.

If an error occurs, the function returns a logical or numerical value.

note

The Status Bar displays the predefined error code from LibreOffice if you click the cell containing the error.


Syntax

ERRORTYPE(Reference)

Reference contains the address of the cell in which the error occurs.

Example

If cell A1 displays Err:518, the function =ERRORTYPE(A1) returns the number 518.

Technical information

This function is not part of the Open Document Format for Office Applications (OpenDocument) Version 1.3. Part 4: Recalculated Formula (OpenFormula) Format standard. The name space is

ORG.OPENOFFICE.ERRORTYPE

GETPIVOTDATA

The GETPIVOTDATA function returns a result value from a pivot table. The value is addressed using field and item names, so it remains valid if the layout of the pivot table changes.

Syntax

Two different syntax definitions can be used:

GETPIVOTDATA(TargetField; pivot table[; Field 1; Item 1][; ... [Field 126; Item 126]])

or

GETPIVOTDATA(pivot table; Constraints)

The second syntax is assumed if exactly two parameters are given, of which the first parameter is a cell or cell range reference. The first syntax is assumed in all other cases. The Function Wizard shows the first syntax.

First Syntax

TargetField is a string that selects one of the pivot table's data fields. The string can be the name of the source column, or the data field name as shown in the table (like "Sum - Sales").

pivot table is a reference to a cell or cell range that is positioned within a pivot table or contains a pivot table. If the cell range contains several pivot tables, the table that was created last is used.

If no Field n / Item n pairs are given, the grand total is returned. Otherwise, each pair adds a constraint that the result must satisfy. Field n is the name of a field from the pivot table. Item n is the name of an item from that field.

If the pivot table contains only a single result value that fulfills all of the constraints, or a subtotal result that summarizes all matching values, that result is returned. If there is no matching result, or several ones without a subtotal for them, an error is returned. These conditions apply to results that are included in the pivot table.

If the source data contains entries that are hidden by settings of the pivot table, they are ignored. The order of the Field/Item pairs is not significant. Field and item names are not case-sensitive.

If no constraint for a filter is given, the field's selected value is implicitly used. If a constraint for a filter is given, it must match the field's selected value, or an error is returned. Filters are the fields at the top left of a pivot table, populated using the "Filters" area of the pivot table layout dialog. From each filter, an item (value) can be selected, which means only that item is included in the calculation.

Subtotal values from the pivot table are only used if they use the function "auto" (except when specified in the constraint, see Second Syntax below).

Second Syntax

NOM is the nominal interest.

Constraints is a space-separated list. Entries can be quoted (single quotes). The whole string must be enclosed in quotes (double quotes), unless you reference the string from another cell.

One of the entries can be the data field name. The data field name can be left out if the pivot table contains only one data field, otherwise it must be present.

Each of the other entries specifies a constraint in the form Field[Item] (with literal characters [ and ]), or only Item if the item name is unique within all fields that are used in the pivot table.

A function name can be added in the form Field[Item;Function], which will cause the constraint to match only subtotal values which use that function. The possible function names are Sum, Count, Average, Max, Min, Product, Count (Numbers only), StDev (Sample), StDevP (Population), Var (Sample), and VarP (Population), case-insensitive.

HLOOKUP

Searches for a value and reference to the cells below the selected area. This function verifies if the first row of an array contains a certain value. The function returns then the value in a row of the array, named in the Index, in the same column.

The search supports wildcards or regular expressions. With regular expressions enabled, you can enter "all.*", for example to find the first location of "all" followed by any characters. If you want to search for a text that is also a regular expression, you must either precede every regular expression metacharacter or operator with a "\" character, or enclose the text into \Q...\E. You can switch the automatic evaluation of wildcards or regular expression on and off in - LibreOffice Calc - Calculate.

warning

When using functions where one or more arguments are search criteria strings that represents a regular expression, the first attempt is to convert the string criteria to numbers. For example, ".0" will convert to 0.0 and so on. If successful, the match will not be a regular expression match but a numeric match. However, when switching to a locale where the decimal separator is not the dot makes the regular expression conversion work. To force the evaluation of the regular expression instead of a numeric expression, use some expression that can not be misread as numeric, such as ".[0]" or ".\0" or "(?i).0".


Syntax

HLOOKUP(Lookup; Array; Index [; SortedRangeLookup])

For an explanation on the parameters, see: VLOOKUP (columns and rows are exchanged)

Handling of Empty Cells

Example

Suppose we have built a small database table occupying the cell range A1:DO4 and containing basic information about 118 chemical elements. The first column contains the row headings “Element”, “Symbol”, “Atomic Number”, and “Relative Atomic Mass”. Subsequent columns contain the relevant information for each of the elements, ordered left to right by atomic number. For example, cells B1:B4 contain “Hydrogen”, “H”, “1” and “1.008”, while cells DO1:DO4 contain “Oganesson”, “Og”, “118”, and “294”.

A

B

C

D

...

DO

1

Element

Hydrogen

Helium

Lithium

...

Oganesson

2

Symbol

H

He

Li

...

Og

3

Atomic Number

1

2

3

...

118

4

Relative Atomic Mass

1.008

4.0026

6.94

...

294


=HLOOKUP("Lead"; $A$1:$DO$4; 2; 0) returns “Pb”, the symbol for lead.

=HLOOKUP("Gold"; $A$1:$DO$4; 3; 0) returns 79, the atomic number for gold.

=HLOOKUP("Carbon"; $A$1:$DO$4; 4; 0) returns 12.011, the relative atomic mass of carbon.

HYPERLINK

When you click a cell that contains the HYPERLINK function, the hyperlink opens.

If you use the optional CellValue parameter, the formula locates the URL, and then displays the text or number.

tip

To open a hyperlinked cell with the keyboard, select the cell, press F2 to enter the Edit mode, move the cursor in front of the hyperlink, press Shift+F10, and then choose Open Hyperlink.


Syntax

HYPERLINK("URL" [; CellValue])

URL specifies the link target. The optional CellValue parameter is the text or a number that is displayed in the cell and will be returned as the result. If the CellValue parameter is not specified, the URL is displayed in the cell text and will be returned as the result.

The number 0 is returned for empty cells and matrix elements.

Example

=HYPERLINK("http://www.example.org") displays the text "http://www.example.org" in the cell and executes the hyperlink http://www.example.org when clicked.

=HYPERLINK("http://www.example.org";"Click here") displays the text "Click here" in the cell and executes the hyperlink http://www.example.org when clicked.

=HYPERLINK("http://www.example.org";12345) displays the number 12345 and executes the hyperlink http://www.example.org when clicked.

=HYPERLINK($B4) where cell B4 contains http://www.example.org. The function adds http://www.example.org to the URL of the hyperlink cell and returns the same text which is used as formula result.

=HYPERLINK("http://www.";"Click ") & "example.org" displays the text Click example.org in the cell and executes the hyperlink http://www.example.org when clicked.

=HYPERLINK("#Sheet1.A1";"Go to top") displays the text Go to top and jumps to cell Sheet1.A1 in this document.

=HYPERLINK("file:///C:/writer.odt#Specification";"Go to Writer bookmark") displays the text "Go to Writer bookmark", loads the specified text document and jumps to bookmark "Specification".

=HYPERLINK("file:///C:/Documents/";"Open Documents folder") displays the text "Open Documents folder" and shows the folder contents using the standard file manager in your operating system.

INDEX

INDEX returns a reference, a value or an array of values from a reference range, specified by row and column index number or array of row and array of columns index numbers, and an optional range index.

INDEX() returns a reference if the argument is one or more references. When used in a cell in the form =INDEX(), the reference is resolved and the values displayed. When INDEX() is used in arguments of other functions, =FUNCTION(INDEX()...), the function gets the reference passed that was returned by INDEX(). Returning a reference is different from returning an array of values for functions that handles them differently.

Syntax

INDEX(Reference [; [Row] [; [Column] [; Range]]])

Reference is a reference, entered either directly or by specifying a range name. If the reference consists of multiple ranges, you must enclose the list of references or range names in parentheses, or either use the tilde (~) range concatenation operator or define a named range with multiple areas.

Row (optional) represents the row or the array of row indexes of the reference range, for which to return a value. In case of zero or omitted (no specific row) all referenced rows are returned.

Column (optional) represents the column or array of column indexes of the reference range, for which to return a value. In case of zero or omitted (no specific column) all referenced columns are returned.

note

If Row, Column or both are omitted or defined as arrays of indexes, the INDEX function must be entered as an array function.


Range (optional) represents the index of the subrange if referring to a multiple range, default is 1.

Example

{=INDEX({1,3,5;7,9,10},{2;1},1)} return a 2 row array containing 7 and 1. The row index {2;1} pick row 2 then row 1. The columns index 1 picks the first column.

{=INDEX(D3:G12,{1;2;3;4},{3,1})} return a 4 rows by 2 columns array. The row index array {1;2;3;4} picks rows 3 to 6 and {3;1} picks the third (F) and first column (D). Columns 1 and 3 of the source reference are swapped in the resulting array.

=INDEX(Prices;4;1) returns the value from row 4 and column 1 of the database range defined in Data - Define as Prices.

=INDEX(SumX;4;1) returns the value from the range SumX in row 4 and column 1 as defined in Sheet - Named Ranges and Expressions - Define.

{=INDEX(A1:B6;1)} returns the values of the first row of A1:B6. Enter the formula as an array formula.

{=INDEX(A1:B6;0;1)} returns the values of the first column of A1:B6. Enter the formula as an array formula.

=INDEX(A1:B6;1;1) indicates the value in the upper-left of the A1:B6 range.

{=INDEX((A1:B6;C1:D6);0;0;2)} returns the values of the second range C1:D6 of the multiple range. Enter the formula as an array formula.

INDIRECT

Returns the reference specified by a text string. This function can also be used to return the area of a corresponding string.

This function is always recalculated whenever a recalculation occurs.

For interoperability the ADDRESS and INDIRECT functions support an optional parameter to specify whether the R1C1 address notation instead of the usual A1 notation should be used.

In ADDRESS, the parameter is inserted as the fourth parameter, shifting the optional sheet name parameter to the fifth position.

In INDIRECT, the parameter is appended as the second parameter.

In both functions, if the argument is inserted with the value 0, then the R1C1 notation is used. If the argument is not given or has a value other than 0, then the A1 notation is used.

In case of R1C1 notation, ADDRESS returns address strings using the exclamation mark '!' as the sheet name separator, and INDIRECT expects the exclamation mark as sheet name separator. Both functions still use the dot '.' sheet name separator with A1 notation.

When opening documents from ODF 1.0/1.1 format, the ADDRESS functions that show a sheet name as the fourth parameter will shift that sheet name to become the fifth parameter. A new fourth parameter with the value 1 will be inserted.

When storing a document in ODF 1.0/1.1 format, if ADDRESS functions have a fourth parameter, that parameter will be removed.

note

Do not save a spreadsheet in the old ODF 1.0/1.1 format if the ADDRESS function's new fourth parameter was used with a value of 0.


note

The INDIRECT function is saved without conversion to ODF 1.0/1.1 format. If the second parameter was present, an older version of Calc will return an error for that function.


Syntax

INDIRECT(Ref [; A1])

ref represents a reference to a cell or an area (in text form) for which to return the contents.

A1 (optional) - if set to 0, the R1C1 notation is used. If this parameter is absent or set to another value than 0, the A1 notation is used.

note

If you open an Excel spreadsheet that uses indirect addresses calculated from string functions, the sheet addresses will not be translated automatically. For example, the Excel address in INDIRECT("[filename]sheetname!"&B1) is not converted into the Calc address in INDIRECT("filename#sheetname."&B1).


Example

=INDIRECT(A1) equals 100 if A1 contains C108 as a reference and cell C108 contains a value of 100.

=SUM(INDIRECT("a1:" & ADDRESS(1;3))) totals the cells in the area of A1 up to the cell, whose address is defined by row 1 and column 3. Therefore, area A1:C1 is totaled.

LOOKUP

Returns the contents of a cell either from a one-row or one-column range. Optionally, the assigned value (of the same index) is returned in a different column and row. As opposed to VLOOKUP and HLOOKUP, search and result vector may be at different positions; they do not have to be adjacent. Additionally, the search vector for the LOOKUP must be sorted ascending, otherwise the search will not return any usable results.

note

If LOOKUP cannot find the search criterion, it matches the largest value in the search vector that is less than or equal to the search criterion.


The search supports wildcards or regular expressions. With regular expressions enabled, you can enter "all.*", for example to find the first location of "all" followed by any characters. If you want to search for a text that is also a regular expression, you must either precede every regular expression metacharacter or operator with a "\" character, or enclose the text into \Q...\E. You can switch the automatic evaluation of wildcards or regular expression on and off in - LibreOffice Calc - Calculate.

warning

When using functions where one or more arguments are search criteria strings that represents a regular expression, the first attempt is to convert the string criteria to numbers. For example, ".0" will convert to 0.0 and so on. If successful, the match will not be a regular expression match but a numeric match. However, when switching to a locale where the decimal separator is not the dot makes the regular expression conversion work. To force the evaluation of the regular expression instead of a numeric expression, use some expression that can not be misread as numeric, such as ".[0]" or ".\0" or "(?i).0".


Syntax

LOOKUP(Lookup; SearchVector [; ResultVector])

Lookup is the value of any type to be looked for; entered either directly or as a reference.

Search vector is the single-row or single-column area to be searched.

result_vector is another single-row or single-column range from which the result of the function is taken. The result is the cell of the result vector with the same index as the instance found in the search vector.

Handling of Empty Cells

Example

=LOOKUP(A1; D1:D100;F1:F100) searches the corresponding cell in range D1:D100 for the number you entered in A1. For the instance found, the index is determined, for example, the 12th cell in this range. Then, the contents of the 12th cell are returned as the value of the function (in the result vector).

MATCH

Returns the relative position of an item in an array that matches a specified value. The function returns the position of the value found in the lookup_array as a number.

Syntax

MATCH(Search; LookupArray [; Type])

Search is the value which is to be searched for in the single-row or single-column array.

lookup_array is the reference searched. A lookup array can be a single row or column, or part of a single row or column.

Type may take the values 1, 0, or -1. If Type = 1 or if this optional parameter is missing, it is assumed that the first column of the search array is sorted in ascending order. If Type = -1 it is assumed that the column in sorted in descending order. This corresponds to the same function in Microsoft Excel.

If Type = 0, only exact matches are found. If the search criterion is found more than once, the function returns the index of the first matching value. Only if Type = 0 can you search for regular expressions (if enabled in calculation options) or wildcards (if enabled in calculation options).

If Type = 1 or the third parameter is missing, the index of the last value that is smaller or equal to the search criterion is returned. For Type = -1, the index of the last value that is larger or equal is returned.

The search supports wildcards or regular expressions. With regular expressions enabled, you can enter "all.*", for example to find the first location of "all" followed by any characters. If you want to search for a text that is also a regular expression, you must either precede every regular expression metacharacter or operator with a "\" character, or enclose the text into \Q...\E. You can switch the automatic evaluation of wildcards or regular expression on and off in - LibreOffice Calc - Calculate.

warning

When using functions where one or more arguments are search criteria strings that represents a regular expression, the first attempt is to convert the string criteria to numbers. For example, ".0" will convert to 0.0 and so on. If successful, the match will not be a regular expression match but a numeric match. However, when switching to a locale where the decimal separator is not the dot makes the regular expression conversion work. To force the evaluation of the regular expression instead of a numeric expression, use some expression that can not be misread as numeric, such as ".[0]" or ".\0" or "(?i).0".


Example

=MATCH(200; D1:D100) searches the area D1:D100, which is sorted by column D, for the value 200. As soon as this value is reached, the number of the row in which it was found is returned. If a higher value is found during the search in the column, the number of the previous row is returned.

OFFSET

Returns the value of a cell offset by a certain number of rows and columns from a given reference point.

This function is always recalculated whenever a recalculation occurs.

Syntax

OFFSET(Reference; Rows; Columns [; Height [; Width]])

Reference is the cell from which the function searches for the new reference.

Rows is the number of cells by which the reference was corrected up (negative value) or down.

Rows is the number of cells by which the reference was corrected up (negative value) or down.

Height is the optional vertical height for an area that starts at the new reference position.

Width is the optional horizontal width for an area that starts at the new reference position.

Arguments Rows and Columns must not lead to zero or negative start row or column.

Arguments Height and Width must not lead to zero or negative count of rows or columns.

In the LibreOffice Calc functions, parameters marked as "optional" can be left out only when no parameter follows. For example, in a function with four parameters, where the last two parameters are marked as "optional", you can leave out parameter 4 or parameters 3 and 4, but you cannot leave out parameter 3 alone.

Example

=OFFSET(A1; 2; 2) returns the value in cell C3 (A1 moved by two rows and two columns down). If C3 contains the value 100 this function returns the value 100.

=OFFSET(B2:C3;1;1) returns a reference to B2:C3 moved down by 1 row and one column to the right (C3:D4).

=OFFSET(B2:C3;-1;-1) returns a reference to B2:C3 moved up by 1 row and one column to the left (A1:B2).

=OFFSET(B2:C3;0;0;3;4) returns a reference to B2:C3 resized to 3 rows and 4 columns (B2:E4).

=OFFSET(B2:C3;1;0;3;4) returns a reference to B2:C3 moved down by one row resized to 3 rows and 4 columns (B3:E5).

=SUM(OFFSET(A1; 2; 2; 5; 6)) determines the total of the area that starts in cell C3 and has a height of 5 rows and a width of 6 columns (area=C3:H7).

note

If Width or Height are given, the OFFSET function returns a cell range reference. If Reference is a single cell reference and both Width and Height are omitted, a single cell reference is returned.


ROW

Returns the row number of a cell reference. If the reference is a cell, it returns the row number of the cell. If the reference is a cell range, it returns the corresponding row numbers in a one-column Array if the formula is entered as an array formula. If the ROW function with a range reference is not used in an array formula, only the row number of the first range cell will be returned.

Syntax

ROW([Reference])

Reference is a cell, an area, or the name of an area.

If you do not indicate a reference, the row number of the cell in which the formula is entered will be found. LibreOffice Calc automatically sets the reference to the current cell.

Example

=ROW(B3) returns 3 because the reference refers to the third row in the table.

{=ROW(D5:D8)} returns the single-column array (5, 6, 7, 8) because the reference specified contains rows 5 through 8.

=ROW(D5:D8) returns 5 because the ROW function is not used as array formula and only the number of the first row of the reference is returned.

{=ROW(A1:E1)} and =ROW(A1:E1) both return 1 because the reference only contains row 1 as the first column in the table. (Because single-row areas only have one row number it does not make any difference whether or not the formula is used as an array formula.)

=ROW() returns 3 if the formula was entered in row 3.

{=ROW(Rabbit)} returns the single-column array (1, 2, 3) if "Rabbit" is the named area (C1:D3).

ROWS

Returns the number of rows in a reference or array.

Syntax

ROWS(array)

array is the reference or named area whose total number of rows is to be determined.

Example

=Rows(B5) returns 1 because a cell only contains one row.

=ROWS(A10:B12) returns 3.

=ROWS(Rabbit) returns 3 if "Rabbit" is the named area (C1:D3).

SHEET

Returns the sheet number of either a reference or a string representing a sheet name. If you do not enter any parameters, the result is the sheet number of the spreadsheet containing the formula.

Syntax

SHEET([Reference])

Reference is optional and is the reference to a cell, an area, or a sheet name string.

Example

=SHEET(Sheet2.A1) returns 2 if Sheet2 is the second sheet in the spreadsheet document.

=SHEET("Sheet3") returns 3 if Sheet3 is the third sheet in the spreadsheet document.

SHEETS

Determines the number of sheets in a reference. If you do not enter any parameters, it returns the number of sheets in the current document.

Syntax

SHEETS([Reference])

Reference is the reference to a sheet or an area. This parameter is optional.

Example

=SHEETS(Sheet1.A1:Sheet3.G12) returns 3 if Sheet1, Sheet2, and Sheet3 exist in the sequence indicated.

VLOOKUP

Vertical search with reference to adjacent cells to the right. This function checks if a specific value is contained in the first column of an array. The function then returns the value in the same row of the column named by Index. If the Sorted parameter is omitted or set to TRUE or one, it is assumed that the data is sorted in ascending order. In this case, if the exact Lookup is not found, the last value that is smaller than the criterion will be returned. If Sorted is set to FALSE or zero, an exact match must be found, otherwise the error Error: Value Not Available will be the result. Thus with a value of zero the data does not need to be sorted in ascending order.

The search supports wildcards or regular expressions. With regular expressions enabled, you can enter "all.*", for example to find the first location of "all" followed by any characters. If you want to search for a text that is also a regular expression, you must either precede every regular expression metacharacter or operator with a "\" character, or enclose the text into \Q...\E. You can switch the automatic evaluation of wildcards or regular expression on and off in - LibreOffice Calc - Calculate.

warning

When using functions where one or more arguments are search criteria strings that represents a regular expression, the first attempt is to convert the string criteria to numbers. For example, ".0" will convert to 0.0 and so on. If successful, the match will not be a regular expression match but a numeric match. However, when switching to a locale where the decimal separator is not the dot makes the regular expression conversion work. To force the evaluation of the regular expression instead of a numeric expression, use some expression that can not be misread as numeric, such as ".[0]" or ".\0" or "(?i).0".


Syntax

=VLOOKUP(Lookup; Array; Index [; SortedRangeLookup])

Lookup is the value of any type looked for in the first column of the array.

Array is the reference, which is to comprise at least as many columns as the number passed in Index argument.

index is the number of the column in the array that contains the value to be returned. The first column has the number 1.

SortedRangeLookup is an optional parameter that indicates whether the first column in the array contains range boundaries instead of plain values. In this mode, the lookup returns the value in the row with first column having value equal to or less than Lookup. E.g., it could contain dates when some tax value had been changed, and so the values represent starting dates of a period when a specific tax value was effective. Thus, searching for a date that is absent in the first array column, but falls between some existing boundary dates, would give the lower of them, allowing to find out the data being effective to the searched date. Enter the Boolean value FALSE or zero if the first column is not a range boundary list. When this parameter is TRUE or not given, the first column in the array must be sorted in ascending order. Sorted columns can be searched much faster and the function always returns a value, even if the search value was not matched exactly, if it is greater than the lowest value of the sorted list. In unsorted lists, the search value must be matched exactly. Otherwise the function will return #N/A with message: Error: Value Not Available.

Handling of Empty Cells

Example

You want to enter the number of a dish on the menu in cell A1, and the name of the dish is to appear as text in the neighboring cell (B1) immediately. The Number to Name assignment is contained in the D1:E100 array. D1 contains 100, E1 contains the name Vegetable Soup, and so forth, for 100 menu items. The numbers in column D are sorted in ascending order; thus, the optional Sorted parameter is not necessary.

Enter the following formula in B1:

=VLOOKUP(A1; D1:E100; 2)

As soon as you enter a number in A1 B1 will show the corresponding text contained in the second column of reference D1:E100. Entering a nonexistent number displays the text with the next number down. To prevent this, enter FALSE as the last parameter in the formula so that an error message is generated when a nonexistent number is entered.

Please support us!