Purpose
The statement is used to perform set operations on the results of multiple SELECT queries.
Limitations and considerations
Set operators have the same precedence. If an SQL statement contains multiple set operators, OceanBase Database will calculate them from left to right unless parentheses are used to specify the order of operations.
Each set operator can operate only on the result set of a
SELECTstatement, and the result sets must have the same number of columns and data types.
Syntax
select_stmt
{UNION | UNION ALL | MINUS | EXCEPT | INTERSECT} select_stmt
[, {UNION | UNION ALL | MINUS | EXCEPT | INTERSECT} select_stmt ...]
[ORDER BY order_by_condition_list]
[LIMIT limit_clause];
Parameters
| Parameter | Description |
|---|---|
| select_stmt | The SELECT statement to perform set operations on. For more information about the SELECT statement, see SELECT. |
| UNION | The operator used to merge the result sets of two SELECT statements into one set, and remove duplicate rows. |
| UNION ALL | The operator used to merge the result sets of two SELECT statements into one set without removing duplicate rows. |
| MINUS | EXCEPT | The operator used to return the rows in the result set of the preceding SELECT statement that are not in the result set of the following SELECT statement. MINUS is synonymous with EXCEPT. |
| INTERSECT | The operator used to return the intersection of the result sets of two SELECT statements, and remove duplicate rows. |
| ORDER BY order_by_condition_list | The clause used to specify the order of the rows after set operations are performed. |
| LIMIT limit_clause | The clause used to specify the number of rows to return after set operations are performed. |
Examples
Create tables
test_tbl1andtest_tbl2.CREATE TABLE test_tbl1 (col1 INT, col2 INT); CREATE TABLE test_tbl2 (col1 INT, col2 INT);Insert test data into tables
test_tbl1andtest_tbl2.INSERT INTO test_tbl1 VALUES (1, 1), (2, 2), (4, 4); INSERT INTO test_tbl2 VALUES (2, 2), (3, 3), (5, 5);
Select the data from the
col1andcol2columns of tablestest_tbl1andtest_tbl2, and merge the results into one set using theUNION ALLoperator. Duplicate rows are retained.SELECT col1, col2 FROM test_tbl1 UNION ALL SELECT col1, col2 FROM test_tbl2;The return result is as follows:
+------+------+ | col1 | col2 | +------+------+ | 1 | 1 | | 2 | 2 | | 4 | 4 | | 2 | 2 | | 3 | 3 | | 5 | 5 | +------+------+ 6 rows in setSelect the data from the
col1andcol2columns of tablestest_tbl1andtest_tbl2, and merge the results into one set using theUNIONoperator. Duplicate rows are removed.SELECT col1, col2 FROM test_tbl1 UNION SELECT col1, col2 FROM test_tbl2;The return result is as follows:
+------+------+ | col1 | col2 | +------+------+ | 1 | 1 | | 2 | 2 | | 4 | 4 | | 3 | 3 | | 5 | 5 | +------+------+ 5 rows in setSelect the data from the
col1andcol2columns of tablestest_tbl1andtest_tbl2, and return the intersection of the two sets. That is, return the duplicate rows in thecol1andcol2columns oftest_tbl1andtest_tbl2.SELECT col1, col2 FROM test_tbl1 INTERSECT SELECT col1, col2 FROM test_tbl2;The return result is as follows:
+------+------+ | col1 | col2 | +------+------+ | 2 | 2 | +------+------+ 1 row in setSelect the data from the
col1andcol2columns oftest_tbl1, and exclude the data from thecol1andcol2columns oftest_tbl2. That is, return the rows intest_tbl1that do not exist intest_tbl2.SELECT col1, col2 FROM test_tbl1 EXCEPT SELECT col1, col2 FROM test_tbl2;The return result is as follows:
+------+------+ | col1 | col2 | +------+------+ | 1 | 1 | | 4 | 4 | +------+------+ 2 rows in setObtain the data from the
col1andcol2columns oftest_tbl1andtest_tbl2, merge the data, sort the merged data in descending order bycol1, and return the first three rows.SELECT col1, col2 FROM test_tbl1 UNION SELECT col1, col2 FROM test_tbl2 ORDER BY col1 DESC LIMIT 3;The return result is as follows:
+------+------+ | col1 | col2 | +------+------+ | 5 | 5 | | 4 | 4 | | 3 | 3 | +------+------+ 3 rows in set