Database Table Reference

LibreOffice Calc lets you reference data in Database tables by using a special notation, a โ€œdatabase table referenceโ€, for cell references inside the table. This special notation aims to improve the readability of formulas that reference cells inside a database table.

Database tables

Spreadsheet "tables" are defined by database ranges (Data - Define Range). In addition to the name of the database, the following is mandatory for using database table references:

แƒ›แƒแƒ’แƒแƒšแƒ˜แƒ—แƒ˜

The table below contains values used in examples later on in this document.

A

B

C

D

1

แƒกแƒแƒฎแƒ”แƒšแƒ˜

แƒ แƒ”แƒ’แƒ˜แƒแƒœแƒ˜

แƒ’แƒแƒงแƒ˜แƒ“แƒ•แƒ”แƒ‘แƒ˜

แƒกแƒขแƒแƒŸแƒ˜

2

Smith

แƒ“แƒแƒกแƒแƒ•แƒšแƒ”แƒ—แƒ˜

21

5

3

Jones

แƒแƒฆแƒ›แƒแƒกแƒแƒ•แƒšแƒ”แƒ—แƒ˜

23

11

4

Johnson

แƒแƒฆแƒ›แƒแƒกแƒแƒ•แƒšแƒ”แƒ—แƒ˜

9

7

5

Taylor

แƒ“แƒแƒกแƒแƒ•แƒšแƒ”แƒ—แƒ˜

34

11

6

Brown

แƒแƒฆแƒ›แƒแƒกแƒแƒ•แƒšแƒ”แƒ—แƒ˜

23

15

7

Walker

แƒแƒฆแƒ›แƒแƒกแƒแƒ•แƒšแƒ”แƒ—แƒ˜

12

4

8

Edwards

East

15

12

9

Thomas

แƒ“แƒแƒกแƒแƒ•แƒšแƒ”แƒ—แƒ˜

17

10

10

Wilson

แƒ“แƒแƒกแƒแƒ•แƒšแƒ”แƒ—แƒ˜

31

3

11

แƒฏแƒแƒ›แƒ”แƒ‘แƒ˜

2

185

8.67


The cell range A1:D11 was defined as the database range "myData ". The options Contains column labels and Contains totals row were checked when defining the database range.

Referencing data in tables

A database table reference has the form name of database_range[โ€ฆ]. The part inside the square brackets can be a reserved reference keyword, a field name in square brackets, or a combination of the two.

In cases where a single keyword or a single field name is used, use single brackets instead of double brackets.

แƒ›แƒแƒ’แƒแƒšแƒ˜แƒ—แƒ˜

myData[#Headers] instead of myData[[#Headers]] or myData[Region] instead of myData[[Region]].

Reserved reference keywords

แƒกแƒแƒ™แƒ•แƒแƒœแƒซแƒ แƒกแƒ˜แƒขแƒงแƒ•แƒ

แƒ’แƒแƒ›แƒแƒงแƒ”แƒœแƒ”แƒ‘แƒ

แƒ›แƒแƒ’แƒแƒšแƒ˜แƒ—แƒ˜

[#Headers]

The keyword [#Headers] references the row of field names (column labels). It is the first row of the database range.

If the database range has no labels row defined (Contains columns row), a #REF! error is generated.

The expression myData[#Headers] references the cells A1:D1.

[#Data]

The keyword [#Data] references the data records of the database range, excluding the column label row and the totals row.

The short form myData[] can be used as well.

The expression myData[#Data] references the cell rectangle A2:D10.

[#Totals]

The keyword [#Totals] references the row of totals. It is the last row of the database range.

If the database range has no line of totals defined (Contains totals row), a #REF! error is generated.

The expression myData[#Totals] references the cells A11:D11.

[#All]

The keyword [#All] references the entire database range including column labels and totals.

The expression myData[#All] references the cells A1:D11.

[#This Row]

This keyword describes an implicit intersection.

If the expression myData[#This Row] is used in a formula in cell F2, it references A2:D2. If the same expression is used in a formula in cell F5, it references A5:D5.


Field name in square brackets

To reference the array of all values in the records that belong to the same field, use the form [field name]. The referenced cell range does not include label and totals.

แƒ›แƒแƒ’แƒแƒšแƒ˜แƒ—แƒ˜

The expression myData[[Region]] or its simplified form myData[Region] references the cells B2:B10. If the database range has no label row, generic labels like Column1, Column2 can be used.

แƒจแƒ”แƒœแƒ˜แƒจแƒ•แƒœแƒ˜แƒก แƒฎแƒแƒขแƒฃแƒšแƒ

In Microsoft Excel, if the formula cell belongs to the table, then the name of the table may be omitted. For example, the formula =SUM(myData[Sales]) in cell C11 could be written as =SUM([Sales]). Omission of the table name is not yet possible in Calc.


Combinations

Columns and data records

To reference a combination of the column labels and data records, use the format [#Headers];[#Data] or [#Headers],[#Data], where the separator is the same separator as for function parameters that is defined in Tools - Options - Calc - Formula - Separators.

Data records and total row

To reference a combination of data records and totals row, use [#Data];[#Totals]. For example, myData[[#Data];[#Totals]] references the cells A2:D11.

A combination like [#Headers];[#Totals] is not possible as that would result in two disjoint cell rectangles.

Adjacent columns

To reference several adjacent columns, use the range operator โ€œ:โ€. For example, the formula myData[[Name]:[Sales]] addresses the cells A2:C10.

Non-adjacent columns

The use of non-adjacent columns is not possible since it would reference two separate cell rectangles.

Field name and keyword

The reference via field name and the use of a reference keyword can be combined. First state the keyword, then the function separator, and last the field name in brackets. For example, myData[[#Totals];[Sales]] references the cell C11.

Please support us!

Please support us!