Database Functions

This section deals with functions used with data organized as one row of data for one record.

Note Icon

The Database category may be confused with a database integrated in Collabora Office. However, there is no connection between a database in Collabora Office and the Database category in Collabora Office Calc.


Example Data:

The following data will be used in some of the function description examples:

The range A1:E10 lists the children invited to Joe's birthday party. The following information is given for each entry: column A shows the name, B the grade, then age in years, distance to school in meters and weight in kilograms.

A

B

C

D

E

1

Name

Grade

Age

Distance to School

Weight

2

Andy

3

9

150

40

3

Betty

4

10

1000

42

4

Charles

3

10

300

51

5

Daniel

5

11

1200

48

6

Eva

2

8

650

33

7

Frank

2

7

300

42

8

Greta

1

7

200

36

9

Harry

3

9

1200

44

10

Irene

2

8

1000

42

11

12

13

Name

Grade

Age

Distance to School

Weight

14

>600

15

16

DCOUNT

5


The formula in cell B16 is =DCOUNT(A1:E10;D1;A13:E14)

Database Function Parameters:

The following items are the parameter definitions for all database functions:

Database is the cell range defining the database.

DatabaseField specifies the column where the function operates on after the search criteria of the first parameter is applied and the data rows are selected. It is not related to the search criteria itself. For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

SearchCriteria is the cell range containing search criteria. If you write several criteria in one row they are connected by AND. If you write the criteria in different rows they are connected by OR. Empty cells in the search criteria range will be ignored.

Choose - Collabora Office Calc - Calculate to define how Collabora Office Calc acts when searching for identical entries.

See also the Wiki page about Conditional Counting and Summation.

DAVERAGE

DAVERAGE returns the average of the values of all cells (fields) in all rows (database records) that match the specified search criteria.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DAVERAGE(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

To find the average weight of all children of the same age in the above example (scroll up, please), enter the following formula in B16:

=DAVERAGE(A1:E10;"Weight";A13:E14)

In row 14, under Age, enter 7, 8, 9, and so on, one after the other. The average weight of all children of the same age appears.

DCOUNT

DCOUNT counts the number of rows (records) in a database that match the specified search criteria and contain numerical values in the DatabaseField column.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DCOUNT(Database; [DatabaseField]; SearchCriteria)

If the DatabaseField argument is omitted, DCOUNT returns the count of all records that satisfy Criteria. For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

In the example above (scroll up, please), we want to know how many children have to travel more than 600 meters to school. The result is to be stored in cell B16. Set the cursor in cell B16. Enter the formula =DCOUNT(A1:E10;D1;A13:E14) in B16. The Function Wizard helps you to input ranges.

Database is the range of data to be evaluated, including its headers: in this case A1:E10. DatabaseField specifies the column for the search criteria: in this case, the column with the numerical distance values. SearchCriteria is the range where you can enter the search parameters: in this case, A13:E14.

To learn how many children in second grade are over 7 years of age, delete the entry >600 in cell D14 and enter 2 in cell B14 under Grade, and enter >7 in cell C14 to the right. The result is 2. Two children are in second grade and over 7 years of age. As both criteria are in the same row, they are connected by AND.

DCOUNTA

DCOUNTA counts the number of rows (records) in a database that match the specified search conditions, and contain numeric or alphanumeric values.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DCOUNTA(Database; [DatabaseField]; SearchCriteria)

If the DatabaseField argument is omitted, DCOUNTA returns the count of all records that satisfy Criteria. For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

In the example above (scroll up, please), you can search for the number of children whose name starts with an E or a subsequent letter. Edit the formula in B16 to read =DCOUNTA(A1:E10;"Name";A13:E14). Delete the old search criteria and enter >=E under Name in field A14. The result is 5. If you now delete all number values for Greta in row 8, the result changes to 4. Row 8 is no longer included in the count because it does not contain any values. The name Greta is text, not a value. Note that the DatabaseField parameter must point to a column that can contain values.

DGET

DGET returns the contents of the referenced cell in a database which matches the specified search criteria. In case of an error, the function returns either #VALUE! for no row found, or Err502 for more than one cell found.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DGET(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

In the above example (scroll up, please), we want to determine what grade a child is in, whose name was entered in cell A14. The formula is entered in cell B16 and differs slightly from the earlier examples because only one column (one database field) can be entered for DatabaseField. Enter the following formula:

=DGET(A1:E10;"Grade";A13:E14)

Enter the name Frank in A14, and you see the result 2. Frank is in second grade. Enter "Age" instead of "Grade" and you will get Frank's age.

Or enter the value 11 in cell C14 only, and delete the other entries in this row. Edit the formula in B16 as follows:

=DGET(A1:E10;"Name";A13:E14)

Instead of the grade, the name is queried. The answer appears at once: Daniel is the only child aged 11.

DMAX

DMAX returns the maximum content of a cell (field) in a database (all records) that matches the specified search conditions.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DMAX(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

To find out how much the heaviest child in each grade weighed in the above example (scroll up, please), enter the following formula in B16:

=DMAX(A1:E10;"Weight";A13:E14)

Under Grade, enter 1, 2, 3, and so on, one after the other. After entering a grade number, the weight of the heaviest child in that grade appears.

DMIN

DMIN returns the minimum content of a cell (field) in a database that matches the specified search criteria.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DMIN(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

To find the shortest distance to school for the children in each grade in the above example (scroll up, please), enter the following formula in B16:

=DMIN(A1:E10;"Distance to School";A13:E14)

In row 14, under Grade, enter 1, 2, 3, and so on, one after the other. The shortest distance to school for each grade appears.

DPRODUCT

DPRODUCT multiplies all cells of a data range where the cell contents match the search criteria.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DPRODUCT(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

With the birthday party example above (scroll up, please), there is no meaningful application of this function.

DSTDEV

DSTDEV calculates the standard deviation of a population based on a sample, using the numbers in a database column that match the given conditions. The records are treated as a sample of data. That means that the children in the example represent a cross section of all children. Note that a representative result can not be obtained from a sample of less than one thousand.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DSTDEV(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

To find the standard deviation of the weight for all children of the same age in the example (scroll up, please), enter the following formula in B16:

=DSTDEV(A1:E10;"Weight";A13:E14)

In row 14, under Age, enter 7, 8, 9, and so on, one after the other. The result shown is the standard deviation of the weight of all children of this age.

DSTDEVP

DSTDEVP calculates the standard deviation of a population based on all cells of a data range which match the search criteria. The records from the example are treated as the whole population.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DSTDEVP(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

To find the standard deviation of the weight for all children of the same age at Joe's birthday party (scroll up, please), enter the following formula in B16:

=DSTDEVP(A1:E10;"Weight";A13:E14)

In row 14, under Age, enter 7, 8, 9, and so on, one after the other. The result is the standard deviation of the weight for all same-aged children whose weight was checked.

DSUM

DSUM returns the total of all cells in a database field in all rows (records) that match the specified search criteria.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DSUM(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

To find the length of the combined distance to school of all children at Joe's birthday party (scroll up, please) who are in second grade, enter the following formula in B16:

=DSUM(A1:E10;"Distance to School";A13:E14)

Enter 2 in row 14 under Grade. The sum (1950) of the distances to school of all the children who are in second grade is displayed.

DVAR

DVAR returns the variance of all cells of a database field in all records that match the specified search criteria. The records from the example are treated as a sample of data. A representative result cannot be obtained from a sample population of less than one thousand.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DVAR(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

To find the variance of the weight of all children of the same age of the above example (scroll up, please), enter the following formula in B16:

=DVAR(A1:E10;"Weight";A13:E14)

In row 14, under Age, enter 7, 8, 9, and so on, one after the other. You will see as a result the variance of the weight values for all children of this age.

DVARP

DVARP calculates the variance of all cell values in a database field in all records that match the specified search criteria. The records are from the example are treated as an entire population.

The search supports regular expressions. 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 precede every character with a "\" character. You can switch the automatic evaluation of regular expression on and off in - Collabora Office Calc - Calculate.

Syntax

DVARP(Database; DatabaseField; SearchCriteria)

For the DatabaseField parameter you can enter a reference to a header cell or a number to specify the column within the Database area, starting with 1. To reference a column by means of the literal column header name, place quotation marks around the header name.

Example

To find the variance of the weight for all children of the same age at Joe's birthday party (scroll up, please), enter the following formula in B16:

=DVARP(A1:E10;"Weight";A13:E14)

In row 14, under Age, enter 7, 8, 9, and so on, one after the other. The variance of the weight values for all children of this age attending Joe's birthday party appears.