>>-+-subselect----+---------------------------------------------> '-(fullselect)-' .---------------------------------------------------. V | >----+-----------------------------------------------+-+------->< | .-DISTINCT-. | '-+-UNION--+----------+-----+--+-subselect----+-' | '-ALL------' | '-(fullselect)-' | .-DISTINCT-. | +-EXCEPT--+----------+----+ | .-DISTINCT-. | '-INTERSECT--+----------+-'
The fullselect is a component of the select-statement and the CREATE VIEW statement.
A fullselect that is enclosed in parenthesis is called a subquery. For example, a subquery can be used in a search condition.
A scalar-fullselect is a fullselect, enclosed in parentheses, that returns a single result row and a single result column. If the result of the fullselect is no rows, then the null value is returned. An error is returned if there is more than one row in the result.
A fullselect specifies a result table. If UNION, EXCEPT, or INTERSECT is not used, the result of the fullselect is the result of the specified subselect.
If the nth column of R1 and the nth column of R2 have the same result column name, then the nth column of the result table has the result column name. If the nth column of R1 and the nth column of R2 do not have the same names, then the result column is unnamed.
Two rows are duplicates if each value in the first is equal to the corresponding value of the second. (For determining duplicates, two null values are considered equal.)
INTERSECT and EXCEPT are not allowed if the query specifies:
If a sort sequence other than *HEX is in effect when the statement that contains the UNION keyword is executed and if the result tables contain columns that are SBCS data, mixed data, or Unicode data, the comparison for those columns is done using weighted values. The weighted values are derived by applying the sort sequence to each value.
UNION, UNION ALL, and INTERSECT are associative set operations. However, when UNION, UNION ALL, EXCEPT, and INTERSECT are used in the same statement, the result depends on the order in which the operations are performed. Operations within parenthesis are performed first. When the order is not specified by parentheses, operations are performed in left-to-right order with the exception that all INTERSECT operations are performed before UNION or EXCEPT operations.
In the following example, the values of tables R1 and R2 are shown on the left. The other headings listed show the values as a result of various set operations on R1 and R2.
R1 | R2 | UNION ALL | UNION | EXCEPT | INTERSECT |
---|---|---|---|---|---|
1 | 1 | 1 | 1 | 2 | 1 |
1 | 1 | 1 | 2 | 5 | 3 |
1 | 3 | 1 | 3 | 4 | |
2 | 3 | 1 | 4 | ||
2 | 3 | 1 | 5 | ||
2 | 3 | 2 | |||
3 | 4 | 2 | |||
4 | 2 | ||||
4 | 3 | ||||
5 | 3 | ||||
3 | |||||
3 | |||||
3 | |||||
4 | |||||
4 | |||||
4 | |||||
5 |
R1 and R2 must have the same number of columns, and the data type of the nth column of R1 must be compatible with the data type of the nth column of R2. Character-string values are compatible with datetime values.
The nth column of the result of UNION, UNION ALL, EXCEPT, or INTERSECT is derived from the nth columns of R1 and R2. The attributes of the result columns are determined using the rules for result columns. For more information see Rules for result data types.
If UNION, INTERSECT, or EXCEPT is specified, no column can be a LOB or DATALINK column.
Select all columns and rows from the EMPLOYEE table.
SELECT * FROM EMPLOYEE
List the employee numbers (EMPNO) of all employees in the EMPLOYEE table whose department number (WORKDEPT) either begins with 'E' or who are assigned to projects in the EMPPROJACT table whose project number (PROJNO) equals 'MA2100', 'MA2110', or 'MA2112'.
SELECT EMPNO FROM EMPLOYEE WHERE WORKDEPT LIKE 'E%' UNION SELECT EMPNO FROM EMPPROJACT WHERE PROJNO IN('MA2100', 'MA2110', 'MA2112')
Make the same query as in example 2, only use UNION ALL so that no duplicate rows are eliminated.
SELECT EMPNO FROM EMPLOYEE WHERE WORKDEPT LIKE 'E%' UNION ALL SELECT EMPNO FROM EMPPROJACT WHERE PROJNO IN('MA2100', 'MA2110', 'MA2112')
Make the same query as in example 2, and, in addition, "tag" the rows from the EMPLOYEE table with 'emp' and the rows from the EMPPROJACT table with 'empprojact'. Unlike the result from example 2, this query may return the same EMPNO more than once, identifying which table it came from by the associated "tag".
SELECT EMPNO, 'emp' FROM EMPLOYEE WHERE WORKDEPT LIKE 'E%' UNION SELECT EMPNO, 'empprojact' FROM EMPPROJACT WHERE PROJNO IN('MA2100', 'MA2110', 'MA2112')
This example of EXCEPT produces all rows that are in T1 but not in T2, with duplicate rows removed.
(SELECT * FROM T1) EXCEPT DISTINCT (SELECT * FROM T2)
If no NULL values are involved, this example returns the same results as:
(SELECT DISTINCT * FROM T1 WHERE NOT EXISTS (SELECT * FROM T2 WHERE T1.C1 = T2.C1 AND T1.C2 = T2.C2 AND...) )
where C1, C2, and so on represent the columns of T1 and T2.
This example of INTERSECT produces all rows that are in both tables T1 and T2, with duplicate rows removed.
(SELECT * FROM T1) INTERSECT DISTINCT (SELECT * FROM T2)
If no NULL values are involved, this example returns the same results as:
(SELECT DISTINCT * FROM T1 WHERE EXISTS (SELECT * FROM T2 WHERE T1.C1 = T2.C1 AND T1.C2 = T2.C2 AND...) )
where C1, C2, and so on represent the columns of T1 and T2.