SELECT

The SELECT statement is a form of query.

Invocation

This statement can be used in an application program using the CLI functions or issued through the CLP.

Syntax

                         .-,--------------.
                         V                |
>>-SELECT--+----------+----| selectItem |-+--FROM--------------->
           '-DISTINCT-'
 
   .-,----------------------------------------.
   V                                          |
>----table-name--+--------------------------+-+----------------->
                 '-+----+--correlation-name-'
                   '-AS-'
 
>--+-----------------------------+------------------------------>
   '-WHERE--| search_condition |-'
 
>--+----------------------------------------------+------------->
   |           .-,------------------------------. |
   |           V                                | |
   '-GROUP BY----+---------------+--column-name-+-'
                 '-table-name--.-'
 
>--+----------------------------------------------------------------+-->
   |             .-,--------------.                                 |
   |             V                |                                 |
   '-ORDER BY--+---simple-integer-+-------------------------------+-'
               | .-,--------------------------------------------. |
               | V                                              | |
               '---+---------------+--column-name--+----------+-+-'
                   '-table-name--.-'               '-+-ASC--+-'
                                                     '-DESC-'
 
>--+-----------------------+-----------------------------------><
   '-LIMIT--simple-integer-'
 
selectItem:
 
|--+-*----------------------------------------+-----------------|
   +-COUNT--(--+-| expression |-+--)----------+
   |           '-*--------------'             |
   +-AVG--(----| expression |----)------------+
   +-SUM--(----| expression |----)------------+
   +-MIN--(----| expression |----)------------+
   +-MAX--(----| expression |----)------------+
   +-MOD--(-| expression |-,-| expression |-)-+
   +-LENGTH--(--| expression |--)-------------+
   +-RTRIM--(--| expression |--)--------------+
   +-LCASE--(--| expression |--)--------------+
   '-UCASE--(--| expression |--)--------------'
 
search_condition:
 
   .------------------------------------------------.
   V                                                |
|----+--------------------------------------------+-+-----------|
     '-+-AND-+--+-----+--+-| predicate |--------+-'
       '-OR--'  '-NOT-'  '-| search_condition |-'
 
predicate:
 
                             (1)
|--+-| basic predicate |-+--------------------------------------|
   +-| IN predicate |----+
   +-| LIKE predicate |--+
   '-| NULL predicate |--'
 
basic predicate:
 
|--| expression |--+-=---+--| expression |----------------------|
                   +- <>-+
                   +- <--+
                   +->---+
                   +- <=-+
                   +- >=-+
                   '-||--'
 
IN predicate:
 
                                .-,--------------.
                                V                |
|--| expression |--+-----+--IN----| expression |-+--------------|
                   '-NOT-'
 
LIKE predicate:
 
|--| expression |--+-----+--LIKE--| expression |----------------|
                   '-NOT-'
 
NULL predicate:
 
|--| expression |--IS--+-----+--NULL----------------------------|
                       '-NOT-'
 
expression:
 
   .-operator-----------------------------------.
   V                                            |
|----+----+--+-literal------------------------+-+---------------|
     +- +-+  +-+---------------+--column-name-+
     '- --'  | '-table-name--.-'              |
             +-special register---------------+
             '-function-----------------------'
 
operator:
 
|--+- /-+-------------------------------------------------------|
   +- *-+
   +- +-+
   '- --'
 
 

Anmerkungen:

  1. BLOB expressions are allowed only in NULL predicates.

Description

selectItem
*
Specifies all columns. If * is specified, it must be the only select item.
COUNT(*)
The COUNT function returns the number of rows or values in a set of rows or values. The argument of COUNT(*) is a set of rows. The result is the number of rows in the set. A row that includes only NULL values is included in the count.
expression
The expression can be a literal, column name, function, or special register. Valid functions are: COUNT, AVG, SUM, MIN, MAX, MOD, LENGTH, and RTRIM.

Arithmetic operations on CHAR, VARCHAR, BLOB(n), DATE, TIME, and TIMESTAMP data types are not supported.

literal
A literal can be a value of data type INTEGER, SMALLINT, DECIMAL, CHAR(n), VARCHAR(n), BLOB(n), DATE, TIME, and TIMESTAMP.
table-name
Identifies the table containing the column that you are querying.
.
Separator in the two-part column identifier, table-name.column-name.
column-name
Identifies the column that you are querying.
COUNT(expression)
The argument of COUNT(expression) is a set of rows. The function is applied to the set of rows derived from the argument values by the elimination of null values. The result is the number of non-null values in the set, including duplicates.
AVG(expression)
The AVG(expression) function returns the average of the values of expression. The argument values must be numbers and their sum must be within the range of the data type of the result. The function is applied to the set of values derived from the argument values by the elimination of null values. The result can be null.
SUM(expression)
The SUM(expression) function returns the sum of the values of expression. The argument values must be numbers and their sum must be within the range of the data type of the result. The function is applied to the set of values derived from the argument values by the elimination of null values.
MIN(expression)
The MIN(expression) function returns the minimum value in the set of values of expression. The argument values can be of any built-in type other than a BLOB. The function is applied to the set of values derived from the argument values by the elimination of null values.
MAX(expression)
The MAX(expression) function returns the maximum value in the set of values of expression. The argument values can be of any built-in type other than a BLOB. The function is applied to the set of values derived from the argument values by the elimination of null values.
MOD(expression, expression)
The MOD(expression, expression) function returns the remainder of the first argument divided by the second argument. The result is negative only if the first argument is negative.

The first and second arguments can be either SMALLINT or INTEGER.

The result of the function is SMALLINT if both arguments are SMALLINT; otherwise, it is an INTEGER. The result can be null; if any argument is null, the result is the null value.

(expression || expression)
The (expression || expression) returns the concatenation of two string arguments. The two arguments must be compatible types.

The result of the function is a string. Its length is sum of the lengths of the two arguments. If the argument can be null, the result can be null; if the argument is null, the result is the null value.

LENGTH(expression)

The LENGTH(expression) function returns the length of a value.

The argument can be an expression that returns a value of the following built-in data types:

  • VARCHAR
  • CHAR
  • BLOB

The result of the function is an integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.

The result is the length of the argument. The length of a varying-length string is the actual length, not the maximum length.

The length of a BLOB is the number of bytes used to represent the value.

Consider a VARCHAR(50) column named ADDRESS with a value of '895 Don Mills Road'. LENGTH(ADDRESS) returns the value 18.

RTRIM(expression)

The RTRIM(expression) function removes blanks from the end of the string.

The argument can be a CHAR or VARCHAR data type.

The result data type of the function is always VARCHAR.

The length parameter of the returned type is the same as the length parameter of the argument data type.

The actual length of the result for character strings is the length of the string-expression minus the number of bytes removed for blank characters. The actual length of the result for graphic strings is the length (in number of double byte characters) of string-expression minus the number of double byte blank characters removed. If all of the characters are removed, the result is an empty, varying-length string (length is zero).

If the argument can be null, the result can be null; if the argument is null, the result is the null value.

Consider a CHAR(50) column named NAME with a value of 'Cliff '. RTRIM(NAME) returns 'Cliff'. LENGTH(RTRIM(NAME)) returns 5.

LCASE / UCASE

The LCASE or LOWER function returns a string in which all the SBCS characters have been converted to lowercase characters. That is, the characters A-Z will be translated to the characters a-z, and characters with diacritical marks will be translated to their lowercase equivalents if they exist.

The argument must be an expression whose value is a CHAR or VARCHAR data type.

The result of the function has the same data type and length attribute as the argument. If the argument can be null, the result can be null; if the argument is null, the result is the null value.

Ensure that the characters in the value of column JOB in the EMPLOYEE table are returned in lowercase characters. For example:

SELECT LCASE(JOB)
     FROM EMPLOYEE
     WHERE EMPNO = '000020';
special register
The special registers CURRENT DATE, CURRENT TIME, and CURRENT TIMESTAMP can be used to produce the current date, time, and timestamp.
FROM
The FROM clause specifies an intermediate result table.

If one table-reference is specified, the intermediate result table is simply the result of that table-reference. If more than one table-reference is specified, the intermediate result table consists of all possible combinations of the rows of the specified table-references (the Cartesian product). Each row of the result is a row from the first table-reference concatenated with a row from the second table-reference, concatenated in turn with a row from the third, and so on. The number of rows in the result is the product of the number of rows in all the individual table-references. A maximum of 20 tables can be specified in the FROM clause.

table-name
Each table-name specified as a table-reference must identify an existing table.
AS
Identifies the table definition.
correlation-name
Each correlation-name is defined as a designator of the immediately preceding table-name. If a correlation name is specified for a table, any qualified reference to a column of the table must use the correlation name rather than the table name. If the same table-name is specified twice, at least one specification should be followed by a correlation-name. The correlation-name is used to qualify references to the columns of the table. As a qualifier, a correlation name can be used to avoid ambiguity or to establish a correlated reference. It can also be used merely as a shorter name for a table.
WHERE
Specifies a condition that selects the rows. The clause can be omitted or a search condition specified. If the clause is omitted, all rows of the table are selected.
search_condition
A search_condition specifies a condition that is true, false, or unknown about a given row.

The result of a search_condition is derived by applying the specified logical operators (AND, OR, NOT) to the result of each specified predicate. A predicate compares two values. If logical operators are not specified, the result of the search condition is the result of the specified predicate.

Search conditions within parentheses are evaluated first. If the order of evaluation is not specified by parentheses, NOT is applied before AND, and AND is applied before OR. The order in which operators at the same precedence level are evaluated is undefined to allow for optimization of search conditions.

The search_condition is applied to each row of the table, and the selected rows are those for which the result of the search_condition is true.

Each column-name in the search condition must identify a column of the table.

NOT
If NOT is specified, the result of the predicate is reversed.
expression
The expression can be a literal, column name, special register, or function.

Arithmetic operations on CHAR, VARCHAR, BLOB(n), DATE, TIME and TIMESTAMP data types are not supported.

literal
A literal can be a value of data type INTEGER, SMALLINT, DECIMAL, CHAR(n), VARCHAR(n), BLOB(n), DATE, TIME, or TIMESTAMP.
table-name
Identifies the table containing the column that is an operand of the predicate.
.
Separator in the two-part column identifier, table-name.column-name.
column-name
Identifies the column that is an operand of the predicate.
special register
Identifies the special register that is an operand of the predicate. The special registers CURRENT DATE, CURRENT TIME, and CURRENT TIMESTAMP can be used to produce the current date, time, and timestamp.
function
Can include LCASE, UCASE, MOD, LENGTH, and RTRIM functions.
operator
Can be any of the following operators:

=
Equal to.

<>
Not equal to.

<
Less than.

>
Greater than.

<=
Less than or equal to.

>=
Greater than or equal to.

||
Returns the concatenation of two string arguments.

LIKE
Matches one character string. Use a single-byte character-set (SBCS) underscore to refer to one SBCS character. Use a double-byte character-set (DBCS) underscore to refer to one DBCS character. For example, the condition WHERE PART_NUMBER LIKE '_0' returns all 2-digit part numbers ending in 0 (20, 30, and 40, for example). Use a percent (either SBCS or DBCS) to refer to a string of zero or more SBCS or DBCS characters. For example, the condition WHERE DEPT_NUMBER LIKE '2%' returns all department numbers beginning with the number 2 (20, 27, or 234, for example).

NOT LIKE
Does not have at least one of the same characters.

IN
Matches a collection of values. The IN predicate compares a value with a collection of values.

Examples:

SELECT lname, fname FROM emp WHERE state IN ('CA', 'AZ', 'OR');

SELECT c1 FROM t1 WHERE c1*5-6 IN (mod(c2,2)+5,c3+4/2);

NOT IN
Does not match a collection of values. The NOT IN predicate compares a value with a collection of values.

Examples:

SELECT empid FROM emp WHERE city NOT IN ('San Jose', 'Morgan Hill', 'Santa Clara');

IS NULL
Contains the null value.

IS NOT NULL
Does not contain the null value.
AND
If specified, the logical operator AND is applied to the result of each specified predicate.
OR
If specified, the logical operator OR is applied to the result of each specified predicate.
GROUP BY
Specifies an intermediate result table that consists of a grouping of the rows of R. R is the result of the previous clause of the subselect.
ORDER BY
Specifies an ordering of the rows of the result table.
column-name
Usually identifies a column of the result table. In this case, column-name must be the column name of a named column in the select list.
simple-integer
Must be greater than 0 and not greater than the number of columns in the result table. The integer n identifies the n-th column of the result table.
ASC
Uses the values of the column in ascending order.
DESC
Uses the values of the column in descending order.
LIMIT simple-integer
Limits the number of rows to be returned to the application to the first n number of rows in the answer set where n is an integer. Must be greater than 0.
Relational operators
Can be one of the following operators

+
Add

-
Subtract

*
Multiple

/
Divide by

Rules

BLOB data type columns cannot be used in GROUP BY, ORDER BY, and DISTINCT clauses.

Notes

Examples

Example 1: Select the employees (EMPNO and LASTNAME) from the EMPLOYEE table who were hired after 01/01/1980 and put them in order of their last name (LASTNAME).

SELECT EMPNO, LASTNAME FROM EMPLOYEE
 WHERE HIREDATE > '01/01/1980'
 ORDER BY LASTNAME

Example 2: Compute the average salary for each department in the EMPLOYEE table.

SELECT DEPT, AVG(SALARY) FROM EMPLOYEE
 GROUP BY DEPT

Example 3: Compute the maximum sales volume for each sales region, and display the results by region, in order of highest to lowest sales volume.

SELECT REGION, MAX(SALES_VOL) FROM SALES
 GROUP BY REGION ORDER BY 2 DESC

Zugehörige Referenzen