Home > Articles

Using DB2 Functions

This chapter is from the book

This chapter is from the book

Chapter 3: Using DB2 Functions

In this Chapter

  • Column Functions

  • Scalar Functions

  • The RAISE_ERROR Function

  • MQSeries Built-in Functions

  • XML Publishing Built-in Functions

  • Built-in Function Guidelines

Two types of built-in functions can be applied to data in a DB2 table using SQL: column functions and scalar functions. You can use these functions to further simplify the requirements of complex data access.

NOTE

DB2 also provides the capability for users to create their own functions. This capability, called user-defined functions, is discussed in-depth in Chapter 4, "Using DB2 User-Defined Functions and Data Types."

Functions are called by specifying the function name and any required operands. A built-in function can be used any place an expression can be used (with some exceptions).

Column Functions

Column functions compute, from a group of rows, a single value for a designated column or expression. This provides the capability to aggregate data, thereby enabling you to perform statistical calculations across many rows with one SQL statement. To fully appreciate the column functions, you must understand SQL's set-level processing capabilities.

This list shows some rules for the column functions:

  • Column functions can be executed only in SELECT statements.

  • A column function must be specified for an explicitly named column or expression.

  • Each column function returns only one value for the set of selected rows.

  • If you apply a column function to one column in a SELECT statement, you must apply column functions to any other columns specified in the same SELECT statement, unless you also use the GROUP BY clause.

  • Use GROUP BY to apply a column function to a group of named columns. Any other column named in the SELECT statement must be operated on by a column function.

  • The result of any column function (except the COUNT and COUNT_BIG functions) will have the same data type as the column to which it was applied. The COUNT function returns an integer number; COUNT_BIG returns a decimal number.

  • The result of any column function (except the COUNT and COUNT_BIG functions) can be null. COUNT and COUNT_BIG always return a numeric result.

  • Columns functions will not return a SQLCODE of +100 if the predicate specified in the WHERE clause finds no data. Instead, a null is returned. For example, consider the following SQL statement:

  • SELECT  MAX(SALARY)
    FROM   DSN8810.EMP
    WHERE  EMPNO = '999999';
  • There is no employee with an EMPNO of '999999' in the DSN8810.EMP table. This statement therefore returns a null for the MAX(SALARY). Of course, this does not apply to COUNT and COUNT_BIG, both of which always return a value, never a null.

  • When using the AVG, MAX, MIN, STDDEV, SUM, and VARIANCE functions on nullable columns, all occurrences of null are eliminated before applying the function.

  • You can use the DISTINCT keyword with all column functions to eliminate duplicates before applying the given function. DISTINCT has no effect, however, on the MAX and MIN functions.

  • You can use the ALL keyword to indicate that duplicates should not be eliminated. ALL is the default.

A column function can be specified in a WHERE clause only if that clause is part of a subquery of a HAVING clause. Additionally, every column name specified in the expression of the column function must be a correlated reference to the same group.

The column functions are AVG, COUNT, COUNT_BIG, MAX, MIN, STDDEV, SUM, and VARIANCE.

The AVG Function

The AVG function computes the average of the values for the column or expression specified as an argument. This function operates only on numeric arguments. The following example calculates the average salary of each department:

SELECT  WORKDEPT, AVG(SALARY)
FROM   DSN8810.EMP
GROUP BY WORKDEPT;

The AVG function is the preferred method of calculating the average of a group of values. Although an average, in theory, is nothing more than a sum divided by a count, DB2 may not return equivalent values for AVG(COL_NAME) and SUM(COL_NAME)/COUNT(*). The reason is that the COUNT function will count all rows regardless of value, whereas SUM ignores nulls.

The COUNT Function

The COUNT function counts the number of rows in a table, or the number of distinct values for a given column. It can operate, therefore, at the column or row level. The syntax differs for each. To count the number of rows in the EMP table, issue this SQL statement:

SELECT  COUNT(*)
FROM   DSN8810.EMP;

It does not matter what values are stored in the rows being counted. DB2 will simply count the number of rows and return the result. To count the number of distinct departments represented in the EMP table, issue the following

SELECT  COUNT(DISTINCT WORKDEPT)
FROM   DSN8810.EMP;

The keyword DISTINCT is not considered an argument of the function. It simply specifies an operation to be performed before the function is applied. When DISTINCT is coded, duplicate values are eliminated.

If DISTINCT is not specified, then ALL is implicitly specified. ALL also can be explicitly specified in the COUNT function. When ALL is specified, duplicate values are not eliminated.

NOTE

The argument of the COUNT function can be of any built-in data type other than a large object: CLOB, DBCLOB, or BLOB. Character string arguments can be no longer 255 bytes and graphic string arguments can be no longer than 127 bytes.

The result of the COUNT function cannot be null. COUNT always returns an INTEGER value greater than or equal to zero.

The COUNT_BIG Function

The COUNT_BIG function is similar to the COUNT function. It counts the number of rows in a table, or the number of distinct values for a given column. However, the COUNT_BIG function returns a result of data type DECIMAL(31,0), whereas COUNT can return a result only as large as the largest DB2 integer value, namely +2,147,483,647.

The COUNT_BIG function works the same as the COUNT function, except it returns a decimal value. Therefore, the example SQL for COUNT is applicable to COUNT_BIG. Simply substitute COUNT_BIG for COUNT. For example, the following statement counts the number of rows in the EMP table (returning a decimal value, instead of an integer):

SELECT  COUNT_BIG(*)
FROM   DSN8810.EMP;

NOTE

The COUNT_BIG function has the same restrictions as the COUNT function. The argument of the COUNT_BIG function can be of any built-in data type other than a large object: CLOB, DBCLOB, or BLOB. Character string arguments can be no longer than 255 bytes and graphic string arguments can be no longer than 127 bytes.

The result of the COUNT_BIG function cannot be null. COUNT_BIG returns a decimal value greater than or equal to zero.

The MAX Function

The MAX function returns the largest value in the specified column or expression. The following SQL statement determines the project with the latest end date:

SELECT  MAX(ACENDATE)
FROM   DSN8810.PROJACT;

NOTE

The result of the MAX function is of the same data type as the column or expression on which it operates.

The argument of the MAX function can be of any built-in data type other than a large object: CLOB, DBCLOB, or BLOB. Character string arguments can be no longer than 255 bytes and graphic string arguments can be no longer than 127 bytes.

A somewhat more complicated example using MAX is shown below. It returns the largest salary paid to a man in department D01:

SELECT MAX(SALARY)
FROM  DSN8810.EMP
WHERE  WORKDEPT = 'D01'
AND   SEX = 'M';

The MIN Function

The MIN function returns the smallest value in the specified column or expression. To retrieve the smallest bonus given to any employee, issue this SQL statement:

SELECT  MIN(BONUS)
FROM   DSN8810.EMP;

NOTE

The result of the MIN function is of the same data type as the column or expression on which it operates.

The argument of the MIN function can be of any built-in data type other than a large object: CLOB, DBCLOB, or BLOB. Character string arguments can be no longer than 255 bytes and graphic string arguments can be no longer than 127 bytes.

The STDDEV Function

The STDDEV function returns the standard deviation of a set of numbers. The standard deviation is calculated at the square root of the variance. For example

SELECT STDDEV(SALARY)
FROM  DSN8810.EMP
WHERE  WORKDEPT = 'D01';

NOTE

The argument of the STDDEV function can be any built-in numeric data type. The resulting standard deviation is a double precision floating-point number.

The SUM Function

The accumulated total of all values in the specified column or expression are returned by the SUM column function. For example, the following SQL statement calculates the total yearly monetary output for the corporation:

SELECT  SUM(SALARY+COMM+BONUS)
FROM   DSN8810.EMP;

This SQL statement adds each employee's salary, commission, and bonus. It then aggregates these results into a single value representing the total amount of compensation paid to all employees.

NOTE

The argument of the SUM function can be any built-in numeric data type. The resulting sum must be within the range of acceptable values for the data type. For example, the sum of an INTEGER column must be within the range –2,147,483,648 to +2,147,483,647. This is because the data type of the result is the same as the data type of the argument values, except:

  • The sum of SMALLINT values returns an INTEGER result.

  • The sum of single precision floating point values returns a double precision floating-point result.

The VARIANCE Function

The VARIANCE function returns the variance of a set of numbers. The result is the biased variance of the set of numbers. The variance is calculated as follows:

VARIANCE = SUM(X**2)/COUNT(X) - (SUM(X)/COUNT(X))**2

NOTE

The argument of the VARIANCE function can be any built-in numeric data type. The resulting variance is a double precision floating-point number.

For brevity and ease of coding, VARIANCE can be shortened to VAR.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020