166 lines
		
	
	
		
			5.0 KiB
		
	
	
	
		
			Markdown
		
	
	
	
	
	
			
		
		
	
	
			166 lines
		
	
	
		
			5.0 KiB
		
	
	
	
		
			Markdown
		
	
	
	
	
	
集合 
 | 
						|
=======================
 | 
						|
 | 
						|
 | 
						|
 | 
						|
数据库中的集合操作可以把多个查询的结果组合成一个结果集。集合操作主要包含:
 | 
						|
 | 
						|
* UNION
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
<!-- -->
 | 
						|
 | 
						|
* INTERSECT
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
<!-- -->
 | 
						|
 | 
						|
* EXCEPT/MINUS在Ocenabase中,我们同时支持EXCEPT与MINUS,这两者的语义是相同的。这里需要注意的是参加集合操作的各查询结果的列数必须相同,对应的数据类型也必须兼容。对与UNION来说用户可以指定UNION的属性为ALL和DISTINCT/UNIQUE。分别代表集合可重复,和集合不可重复。而其它几种集合操作是不能指定ALL属性的(它们只有DISTINCT属性)。所有的集合操作默认的属性是DISTINCT。在Oceanbase中,集合操作中可以指定order by和 limit子句,但是不允许其他子句的出现,如下图所示
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
```javascript
 | 
						|
OceanBase (root@test)> create table t1(a int primary key, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.16 sec)
 | 
						|
OceanBase (root@test)> create table t2(a int primary key, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.10 sec)
 | 
						|
--支持union语句中出现order by和limit子句
 | 
						|
OceanBase (root@test)> (select * from t1 union all select * from t2) order by a limit 10;
 | 
						|
Empty set (0.02 sec)
 | 
						|
--不支持union语句中出现除order by和limit子句的其他子句,比如group by
 | 
						|
OceanBase (root@test)> OceanBase (root@test)> (select * from t1 union all select * from t2) group by a limit 10;
 | 
						|
ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your OceanBase version for the right syntax to use near 'OceanBase (root@test)> (select * from t1 union all select * from t2) group by a ' at line 1
 | 
						|
```
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
UNION 例子 
 | 
						|
-----------------
 | 
						|
 | 
						|
该例子获取t1和t2中所有不重复的行。
 | 
						|
 | 
						|
```javascript
 | 
						|
OceanBase (root@test)> create table t1(a int, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.12 sec)
 | 
						|
OceanBase (root@test)> create table t2(a int, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.11 sec)
 | 
						|
OceanBase (root@test)> insert into t1 values (1,1,1),(2,2,2),(3,3,3);
 | 
						|
Query OK, 3 rows affected (0.07 sec)
 | 
						|
Records: 3  Duplicates: 0  Warnings: 0
 | 
						|
OceanBase (root@test)> insert into t2 values (2,2,2),(3,3,3),(4,4,4);
 | 
						|
Query OK, 3 rows affected (0.02 sec)
 | 
						|
Records: 3  Duplicates: 0  Warnings: 0
 | 
						|
OceanBase (root@test)> select * from t1 union select * from t2;
 | 
						|
+------+------+------+
 | 
						|
| a    | b    | c    |
 | 
						|
+------+------+------+
 | 
						|
|    1 |    1 |    1 |
 | 
						|
|    2 |    2 |    2 |
 | 
						|
|    3 |    3 |    3 |
 | 
						|
|    4 |    4 |    4 |
 | 
						|
+------+------+------+
 | 
						|
4 rows in set (0.01 sec)
 | 
						|
```
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
UNION All 例子 
 | 
						|
---------------------
 | 
						|
 | 
						|
该例子获取t1和t2中的所有行,不进行去重。
 | 
						|
 | 
						|
```javascript
 | 
						|
OceanBase (root@test)> create table t1(a int, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.12 sec)
 | 
						|
OceanBase (root@test)> create table t2(a int, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.11 sec)
 | 
						|
OceanBase (root@test)> insert into t1 values (1,1,1),(2,2,2),(3,3,3);
 | 
						|
Query OK, 3 rows affected (0.07 sec)
 | 
						|
Records: 3  Duplicates: 0  Warnings: 0
 | 
						|
OceanBase (root@test)> insert into t1 values (2,2,2),(3,3,3),(4,4,4);
 | 
						|
Query OK, 3 rows affected (0.02 sec)
 | 
						|
Records: 3  Duplicates: 0  Warnings: 0
 | 
						|
OceanBase (root@test)> select * from t1 union all select * from t2;
 | 
						|
+------+------+------+
 | 
						|
| a    | b    | c    |
 | 
						|
+------+------+------+
 | 
						|
|    1 |    1 |    1 |
 | 
						|
|    2 |    2 |    2 |
 | 
						|
|    3 |    3 |    3 |
 | 
						|
|    2 |    2 |    2 |
 | 
						|
|    3 |    3 |    3 |
 | 
						|
|    4 |    4 |    4 |
 | 
						|
+------+------+------+
 | 
						|
6 rows in set (0.02 sec)
 | 
						|
```
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
INTERSECT 例子 
 | 
						|
---------------------
 | 
						|
 | 
						|
该例子获取同时出现在t1和t2中行,并且去重。
 | 
						|
 | 
						|
```javascript
 | 
						|
OceanBase (root@test)> create table t1(a int, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.12 sec)
 | 
						|
OceanBase (root@test)> create table t2(a int, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.12 sec)
 | 
						|
OceanBase (root@test)> insert into t1 values (1,1,1),(2,2,2),(3,3,3);
 | 
						|
Query OK, 3 rows affected (0.02 sec)
 | 
						|
Records: 3  Duplicates: 0  Warnings: 0
 | 
						|
OceanBase (root@test)> insert into t2 values (2,2,2),(3,3,3),(3,3,3),(4,4,4);
 | 
						|
Query OK, 4 rows affected (0.01 sec)
 | 
						|
Records: 4  Duplicates: 0  Warnings: 0
 | 
						|
OceanBase (root@test)> select * from t1 intersect select * from t2;
 | 
						|
+------+------+------+
 | 
						|
| a    | b    | c    |
 | 
						|
+------+------+------+
 | 
						|
|    2 |    2 |    2 |
 | 
						|
|    3 |    3 |    3 |
 | 
						|
+------+------+------+
 | 
						|
2 rows in set (0.01 sec)
 | 
						|
```
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
 | 
						|
EXCEPT/MINUS 例子 
 | 
						|
------------------------
 | 
						|
 | 
						|
该例子获取出现在t1中,但是不出现在t2中的行,并且去重。
 | 
						|
 | 
						|
```javascript
 | 
						|
OceanBase (root@test)> create table t1(a int, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.12 sec)
 | 
						|
OceanBase (root@test)> create table t2(a int, b int, c int);
 | 
						|
Query OK, 0 rows affected (0.12 sec)
 | 
						|
OceanBase (root@test)> insert into t1 values (1,1,1),(2,2,2),(3,3,3);
 | 
						|
Query OK, 3 rows affected (0.02 sec)
 | 
						|
Records: 3  Duplicates: 0  Warnings: 0
 | 
						|
OceanBase (root@test)> insert into t2 values (2,2,2),(3,3,3),(3,3,3),(4,4,4);
 | 
						|
Query OK, 4 rows affected (0.01 sec)
 | 
						|
Records: 4  Duplicates: 0  Warnings: 0
 | 
						|
OceanBase (root@test)> select * from t1 except select * from t2;
 | 
						|
+------+------+------+
 | 
						|
| a    | b    | c    |
 | 
						|
+------+------+------+
 | 
						|
|    1 |    1 |    1 |
 | 
						|
+------+------+------+
 | 
						|
1 row in set (0.02 sec)
 | 
						|
```
 | 
						|
 | 
						|
 |