The twelve functions in the Database category help you to analyse a simple database that occupies a rectangular spreadsheet area comprising columns and rows, with the data organized as one row for each record. The header cell of each column displays the name of the column and that name usually reflects the contents of each cell in that column.
The functions in the Database category take three arguments as follows:
Database. The cell range of the database.
DatabaseField. The column containing the data to be used in the function’s calculations.
SearchCriteria. The cell range of a separate area of the spreadsheet containing search criteria.
These arguments are described more fully below.
All functions have the same outline concept of operation. The first logical step is to use the specified SearchCriteria to identify the subset of records in the Database that are to be used during subsequent calculations. The second step is to extract the data values and perform the calculations associated with the specific function (average, sum, product, and so on). The values processed are those in the DatabaseField column of the selected records.
Calc treats dates and logical values (TRUE and FALSE) as numeric when calculating with these functions.
The following argument definitions apply for all functions in the Database category:
Database specifies the range of cells occupied by the database table. The first row of the range contains the field names, and subsequent rows are records with corresponding field values.
One way of defining the range of cells is to enter the cell reference for the upper left-hand cell, followed by a colon (:), and then the lower right-hand cell reference. An example might be A1:E10.
The Database argument may also be specified by passing the name of a named range or database range. Using a meaningful name to define the cell range can enhance formula readability and document maintenance. If the name does not match the name of a defined range, Calc reports a #NAME? error.
Other errors that might be reported as a result of an invalid Database argument are #VALUE! and Err:504 (error in parameter list).
DatabaseField specifies the column which the function will use for its calculations after the search criteria have been applied and the data rows have been selected. It is not related to the search criteria.
Specify the DatabaseField argument in any of the following ways:
The DatabaseField argument is optional for the DCOUNT and DCOUNTA functions but it is required for the other ten Database functions.
SearchCriteria specifies the range of cells containing search criteria. Like Database, its first row is also field names, and subsequent rows are conditions for related fields. The Database and SearchCriteria areas need not be adjacent, or even on the same sheet.
One way of defining the range of cells is to enter the cell reference for the upper left-hand cell, followed by a colon (:), and then the lower right-hand cell reference. For example, A13:B14. The cell range may also be specified by passing the name of a defined named range or database range. If the name does not match the name of a defined range, Calc reports a #NAME? error.
Err:504 (error in parameter list) may also be reported as a result of an invalid SearchCriteria argument.
The contents of the SearchCriteria area are described in more detail in the next section.
The number of columns occupied by the SearchCriteria area need not be the same as the width of the Database area. All headings that appear in the first row of SearchCriteria must be identical to headings in the first row of Database. However, not all headings in Database need appear in the first row of SearchCriteria, while a heading in Database can appear multiple times in the first row of SearchCriteria.
Search criteria are entered into the cells of the second and subsequent rows of the SearchCriteria area, below the row containing headings. Blank cells within the SearchCriteria area are ignored.
Create criteria in the cells of the SearchCriteria area using the comparison operators <, <=, =, <>, >=, and >. = is assumed if a cell is not empty but does not start with a comparison operator.
If you write several criteria in one row, they are connected by AND. If you write several criteria in different rows, they are connected by OR.
Criteria can be created using wildcards, providing that wildcards have been enabled via the Enable wildcards in formulas option on the Tools - Options - Office Calc - Calculate dialogue box. When interoperability with Microsoft Excel is important for your spreadsheet, this option should be enabled.
Even more powerful criteria can be created using regular expressions, providing that regular expressions have been enabled via the Enable regular expressions in formulae option on the Tools - Options - Office Calc - Calculate dialogue box.
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".
Another setting that affects how the search criteria are handled is the Search criteria = and <> must apply to whole cells option on the Tools - Options - Office Calc - Calculate dialogue box. This option controls whether the search criteria you set for the Database functions must match the whole cell exactly. When interoperability with Microsoft Excel is important for your spreadsheet, this option should be enabled.
The following table provides an example database table that is utilised to demonstrate how to use the functions in the Database category. The cell range A1:E10 contains fictitious information about the guests invited to Joe's birthday party. The following information is given for each guest - name, school grade, age in years, distance to school in metres, and weight in kilograms.
A | B | C | D | E | |
---|---|---|---|---|---|
1 | Name | Grade | Age | Distance | 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 |
The following six examples use the database table above, combined with different search criteria areas.
| | A | B | C | D | E | | | ---- | -------- | --------- | ------- | ------------ | ---------- | | 12 | Name | Grade | Age | Distance | Weight | | 13 | | | | >600 | | | 14 | | | | | |
As in this simple example, it is sometimes desirable (but not essential) to place the search criteria area directly under the database table, with the columns of the two areas vertically aligned. Blank entries in the search criteria area are ignored. With the above example database table and this search criteria area, insert the formula =DCOUNT(A1:E10;;A12:E14) into an empty cell elsewhere in the sheet to count how many of Joe’s guests travel further than 600 meters to school. The value 5 is returned (counting Betty, Daniel, Eva, Harry, and Irene).
Note also that the formula =DCOUNT(A1:E10;;D12:D13) returns exactly the same value, demonstrating that it is only necessary for the search criteria area to contain relevant column headings.
| | A | B | C | D | E | | | ---- | - | ------- | --------- | - | | | 12 | | Age | Grade | | | | 13 | | >7 | 2 | | | | 14 | | | | | |
In this example the search criteria area contains only two headings and these are not vertically aligned with the corresponding headings in the example database table. Since there are two conditions in the same row, these are connected by AND. With the above example database table and this search criteria area, insert the formula =DCOUNT(A1:E10;;B12:C13) into an empty cell elsewhere in the sheet to count how many of Joe’s guests are in grade 2 and greater than 7 years old. The value 2 is returned (counting Eva and Irene).
| | A | B | C | D | E | | | ---- | - | ------- | - | - | | | 12 | | Age | | | | | 13 | | 9 | | | | | 14 | | 10 | | | |
In this example the search criteria area contains only one heading. Since there are two conditions in consecutive rows, these are connected by OR. With the above example database table and this search criteria area, insert the formula =DCOUNT(A1:E10;;B12:B14) into an empty cell elsewhere in the sheet to count how many of Joe’s guests are either 9 or 10 years old. The value 4 is returned (counting Andy, Betty, Charles, and Harry).
| | A | B | C | D | E | | | ---- | - | ------- | ------- | - | | | 12 | | Age | Age | | | | 13 | | >=8 | <=10 | | | | 14 | | | | | |
In this example the search criteria area contains two occurrences of the same heading. Since there are two conditions in the same row, these are connected by AND. With the above example database table and this search criteria area, insert the formula =DCOUNT(A1:E10;;B12:C13) into an empty cell elsewhere in the sheet to count how many of Joe’s guests are aged between 8 and 10 (inclusive). The value 6 is returned (counting Andy, Betty, Charles, Eva, Harry, and Irene).
| | A | B | C | D | E | | | ---- | -------- | - | - | - | | | 12 | Name | | | | | | 13 | F* | | | | | | 14 | | | | | |
This simple example shows the use of wildcards. For this example to work as intended, select to enable wildcards at Tools - Options - Office Calc - Calculate. With the above example database table and this search criteria area, insert the formula =DCOUNT(A1:E10;;A12:A13) into an empty cell elsewhere in the sheet to count how many of Joe’s guests have names that begin with the letter “F”. The value 1 is returned (counting Frank).
| | A | B | C | D | E | | | ---- | ---------- | - | - | - | | | 12 | Name | | | | | | 13 | [ABC].* | | | | | | 14 | | | | | |
This simple example shows the use of regular expressions. For this example to work as intended, select to enable regular expressions at Tools - Options - Office Calc - Calculate. With the above example database table and this search criteria area, insert the formula =DCOUNT(A1:E10;;A12:A13) into an empty cell elsewhere in the sheet to count how many of Joe’s guests have names that begin with the letters “A”, “B”, or “C”. The value 3 is returned (counting Andy, Betty, and Charles).
DAVERAGE calculates the average of the numeric values in the cells (fields) of the specified column, for all rows (database records) that match the specified search criteria. Non-numeric values in those cells are ignored.
Returns a #DIV/0! error if no records match the specified search criteria, or if there are no numeric values in the cells of the specified column for the matching records.
DAVERAGE(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell D13 which should contain ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DAVERAGE(A1:E10; "Distance"; A12:E13) into an empty cell elsewhere in the sheet to calculate the average distance in meters travelled to school by Joe’s party guests. The value 666.67 is returned.
DCOUNT counts the number of cells (fields) of the specified column that contain numeric values, for all rows (database records) that match the specified search criteria. However, if no column is specified, DCOUNT returns the count of all records that match the specified search criteria irrespective of their contents.
DCOUNT(Database; [DatabaseField]; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell D13 which should contain ">600" (this search criterion will match records in the database table that have a value greater than 600 in the Distance column).
Insert the formula =DCOUNT(A1:E10;; A12:E13) into an empty cell elsewhere in the sheet to calculate how many of Joe’s party guests travel further than 600 meters to school. The value 5 is returned.
The same result is obtained if you use the formula =DCOUNT(A1:E10; "Distance"; A12:E13), because all entries in the Distance column are numeric. However, if you use the formula =DCOUNT(A1:E10; "Name"; A12:E13), the value 0 is returned because all entries in the Name column are non-numeric.
DCOUNTA counts the number of cells (fields) of the specified column that are not blank, for all rows (database records) that match the specified search criteria. Blank cells of the specified column are not counted. However, if no column is specified, DCOUNTA returns the count of all records that match the specified search criteria irrespective of their contents.
DCOUNTA(Database; [DatabaseField]; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell D13 which should contain ">600" (this search criterion will match records in the database table that have a value greater than 600 in the Distance column).
Insert the formula =DCOUNTA(A1:E10;; A12:E13) into an empty cell elsewhere in the sheet to calculate how many of Joe’s party guests travel further than 600 meters to school. The value 5 is returned.
The same result is obtained if you use the formula =DCOUNTA(A1:E10; "Distance"; A12:E13) or the formula =DCOUNTA(A1:E10; "Name"; A12:E13). The latter case reflects that in contrast to DCOUNT, DCOUNTA counts both numeric and alphanumeric values in the column indicated by the DatabaseField argument.
DGET returns the contents of the cell (field) of the specified column, for the single row (database record) that matches the specified search criteria.
Calc reports Err:502 (invalid argument) if multiple matches are found, or a #VALUE! error (wrong data type) if no matches are found. A #VALUE! error is also reported if a single match is found but the relevant cell is empty.
DGET(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell C13 which should contain "11" (this search criterion will match records in the database table that have a value of 11 in the Age column).
Insert the formula =DGET(A1:E10; "Name"; A12:E13) into an empty cell elsewhere in the sheet to find the name of Joe’s party guest who is age 11. The name Daniel is returned.
If you change the value in cell C13 to “10”, then the formula =DGET(A1:E10; "Name"; A12:E13) returns an invalid argument error (Err:502). The reflects that multiple records match the specified criterion (both Betty and Charles are age 10).
DMAX calculates the maximum value across the cells (fields) of the specified column that contain numeric values, for all rows (database records) that match the specified search criteria. Blank cells or cells containing non-numeric characters are not included.
Returns 0 if no matches are found, or if there are no non-zero numeric values in the cells of the specified column for the matching records.
DMAX(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell D13 which should contain ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DMAX(A1:E10; "Distance"; A12:E13) into an empty cell elsewhere in the sheet to find the maximum distance in meters that any of Joe’s party guests travel to school. The value 1200 is returned.
DMIN calculates the minimum value across the cells (fields) of the specified column that contain numeric values, for all rows (database records) that match the specified search criteria. Blank cells or cells containing non-numeric characters are not included.
Returns 0 if no matches are found, or if there are no non-zero numeric values in the cells of the specified column for the matching records.
DMIN(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell D13 which should contain ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DMIN(A1:E10; "Distance"; A12:E13) into an empty cell elsewhere in the sheet to find the minimum distance in meters that any of Joe’s party guests travel to school. The value 150 is returned.
DPRODUCT calculates the product of all numeric values in the cells (fields) of the specified column, for all rows (database records) that match the specified search criteria. Blank cells or cells containing non-numeric characters are not included.
Returns 0 if no matches are found, or if there are no numeric values in the cells of the specified column for the matching records.
DPRODUCT(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell C13 which should contain ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DPRODUCT(A1:E10; "Age"; A12:E13) into an empty cell elsewhere in the sheet to calculate the product of the ages in years of Joe’s party guests. The value 279417600 is returned.
DSTDEV calculates the sample standard deviation based on the numeric values in the cells (fields) of the specified column, for all rows (database records) that match the specified search criteria. Non-numeric values are ignored.
Returns a #NUM! error if exactly one record matches the specified search criteria, or if there is only one numeric value in the cells of the specified column for the matching records.
Returns 0 if no matches are found, or if there are no numeric values in the cells of the specified column for the matching records.
DSTDEV(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:D13 are blank and that cell E13 contains ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DSTDEV(A1:E10; "Weight"; A12:E13) into an empty cell elsewhere in the sheet to calculate the sample standard deviation of the weights in kg of Joe’s party guests. The value 5.5 is returned.
DSTDEVP calculates the population standard deviation based on the numeric values in the cells (fields) of the specified column, for all rows (database records) that match the specified search criteria. Non-numeric values are ignored.
Returns a #NUM! error if no records match the specified search criteria, or if there are no numeric values in the cells of the specified column for the matching records.
DSTDEVP(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:D13 are blank and that cell E13 contains ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DSTDEVP(A1:E10; "Weight"; A12:E13) into an empty cell elsewhere in the sheet to calculate the population standard deviation of the weights in kg of Joe’s party guests. The value 5.18545 is returned.
DSUM calculates the sum of all numeric values in the cells (fields) of the specified column, for all rows (database records) that match the specified search criteria. Blank cells or cells containing non-numeric characters are not included.
Returns 0 if no matches are found, or if there are no numeric values in the cells of the specified column for the matching records.
DSUM(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell D13 which should contain ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DSUM(A1:E10; "Distance"; A12:E13) into an empty cell elsewhere in the sheet to find the total distance in meters that all of Joe’s party guests travel to school. The value 6000 is returned.
DVAR calculates the sample variance based on the numeric values in the cells (fields) of the specified column, for all rows (database records) that match the specified search criteria. Non-numeric values are ignored.
Returns a #NUM! error if exactly one record matches the specified search criteria, or if there is only one numeric value in the cells of the specified column for the matching records.
Returns 0 if no matches are found, or if there are no numeric values in the cells of the specified column for the matching records.
DVAR(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell D13 which should contain ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DVAR(A1:E10; "Distance"; A12:E13) into an empty cell elsewhere in the sheet to find the sample variance of the distances in meters that Joe’s party guests travel to school. The value 193125 is returned.
DVARP calculates the population variation based on the numeric values in the cells (fields) of the specified column, for all rows (database records) that match the specified search criteria. Non-numeric values are ignored.
Returns a #NUM! error if no records match the specified search criteria, or if there are no numeric values in the cells of the specified column for the matching records.
DVARP(Database; DatabaseField; SearchCriteria)
The example database table giving information about the guests invited to Joe’s birthday party (described above) should occupy cells A1:E10. The content of cells A12:E12 should be identical to the header labels for the database table in cells A1:E1. Make sure that cells A13:E13 are blank, except for cell D13 which should contain ">0" (this search criterion is intended to match all records in the database table).
Insert the formula =DVARP(A1:E10; "Distance"; A12:E13) into an empty cell elsewhere in the sheet to find the population variance of the distances in meters that Joe’s party guests travel to school. The value 171666.67 is returned.