377 lines
12 KiB
Markdown
377 lines
12 KiB
Markdown
SELECT
|
|
===========================
|
|
|
|
|
|
|
|
SELECT 的语法相对比较复杂。本节首先会介绍普通的 SELECT 语法结构,然后介绍集合类 SELECT 的语法结构。
|
|
|
|
SIMPLE SELECT
|
|
----------------------
|
|
|
|
### 描述
|
|
|
|
该语句用于查询表中的内容。
|
|
|
|
### 格式
|
|
|
|
```javascript
|
|
simple_select:
|
|
SELECT [/*+ hint statement */] [ALL | DISTINCT | UNIQUE | SQL_CALC_FOUND_ROWS]
|
|
select_expr_list FROM from_list [WHERE condition]
|
|
[GROUP BY group_expression_list [WITH ROLLUP] [HAVING condition]]
|
|
[ORDER BY order_expression_list]
|
|
[limit_clause]
|
|
[FOR UPDATE]
|
|
|
|
select_expr:
|
|
table_name.*
|
|
| table_alias_name.*
|
|
| expr [[AS] column_alias_name]
|
|
|
|
from_list:
|
|
table_reference [, table_reference ...]
|
|
|
|
table_reference:
|
|
simple_table
|
|
| joined_table
|
|
|
|
simple_table:
|
|
table_factor [partition_option] [[AS] table_alias_name]
|
|
| (select_stmt) [AS] table_alias_name
|
|
| (table_reference_list)
|
|
|
|
joined_table:
|
|
table_reference [INNER] JOIN simple_table [join_condition]
|
|
| table_reference outer_join_type JOIN simple_table join_condition
|
|
|
|
partition_option:
|
|
PARTITION (partition_name_list)
|
|
|
|
partition_name_list:
|
|
partition_name [, partition_name ...]
|
|
|
|
outer_join_type:
|
|
{LEFT | RIGHT | FULL} [OUTER]
|
|
|
|
join_condition:
|
|
ON expression
|
|
|
|
condition:
|
|
expression
|
|
|
|
group_expression_list:
|
|
group_expression [, group_expression ...]
|
|
|
|
group_expression:
|
|
expression [ASC | DESC]
|
|
|
|
order_expression_list:
|
|
order_expression [, order_expression ...]
|
|
|
|
order_expression:
|
|
expression [ASC | DESC]
|
|
|
|
limit_clause:
|
|
LIMIT {[offset,] row_count |row_count OFFSET offset}
|
|
```
|
|
|
|
|
|
|
|
### 参数解释
|
|
|
|
|
|
|
|
| 参数 | 描述 |
|
|
|--------------------------------------------------------------------------------------------------------------------------|---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
|
|
| ALL \| DISTINCT \| UNIQUE \| SQL_CALC_FOUND_ROWS | 在数据库表中,可能会包含重复值。 * 指定"DISTINCT",则在查询结果中相同的行只显示一行; * 指定"ALL",则列出所有的行; * 指定"SQL_CALC_FOUND_ROWS",则不输出数据,只返回数据行数; * 不指定时,默认为"ALL"。 |
|
|
| select_expr | 列出要查询的表达式或列名,用","隔开。也可以用"\*"表示所有列。 |
|
|
| AS othername | 为输出字段重新命名。 |
|
|
| FROM table_references | 指名了从哪个表或哪些表中读取数据(支持多表查询)。 |
|
|
| WHERE where_conditions | 可选项,WHERE 字句用来设置一个筛选条件,查询结果中仅包含满足条件的数据。where_conditions 为表达式。 |
|
|
| GROUP BY group_by_list | 用于进行分类汇总。 |
|
|
| HAVING search_confitions | HAVING 字句与 WHERE 字句类似,但是 HAVING 字句可以使用累计函数(如 SUM,AVG 等)。 |
|
|
| ORDER BY order_list order_list : colname \[ASC \| DESC\] \[,colname \[ASC \| DESC\]...\] | 用来按升序(ASC)或者降序(DESC)显示查询结果。不指定 ASC 或者 DESC 时,默认为 ASC。 |
|
|
| \[LIMIT {\[offset,\] row_count \|row_count OFFSET offset}\] | 强制 SELECT 语句返回指定的记录数。 LIMIT 接受一个或两个数字参数。参数必须是一个整数常量。 * 如果给定两个参数,第一个参数指定第一个返回记录行的偏移量,第二个参数指定返回记录行的最大数目。初始记录行的偏移量是 0(而不是 1)。 * 如果只给定一个参数,它表示返回记录行的最大数目,偏移量为0。 |
|
|
| FOR UPDATE | 对查询结果所有行上排他锁,以阻止其他事务的并发修改,或阻止在某些事务隔离级别时的并发读取。 |
|
|
| PARTITION(partition_list) | 指定查询表的分区信息。例如:partition(p0,p1...) |
|
|
|
|
|
|
|
|
### 示例
|
|
|
|
以如下表 a 为例。
|
|
|
|

|
|
|
|
* 从表 a 中读取 name 数据。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT name FROM a;
|
|
```
|
|
|
|
|
|
|
|

|
|
|
|
* 在查询结果中对 name 进行去重处理。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT DISTINCT name FROM a;
|
|
```
|
|
|
|
|
|
|
|

|
|
|
|
* 从表 a 中查询 id,name,num,然后把 num 列除以2输出,输出的列名为 avg。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT id, name, num/2 AS avg FROM a;
|
|
```
|
|
|
|
|
|
|
|

|
|
|
|
* 从表 a 中根据筛选条件" name = 'a' " ,输出对应的 id 、name 和 num 。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT id, name, num FROM a WHERE name = 'a';
|
|
```
|
|
|
|
|
|
|
|

|
|
|
|
* 从表 a 中查询 id,name,按照 name 分组对 num 求和,并输出。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT id, name, SUM(num) FROM a GROUP BY name;
|
|
```
|
|
|
|
|
|
|
|

|
|
|
|
* 从表 a 中查询 id,name,按照 name 分组对 num 求和,查询 num 总和小于160的行,并输出。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT id, name, SUM(num) as sum FROM a GROUP BY name HAVING SUM(num) < 160;
|
|
```
|
|
|
|
|
|
|
|

|
|
|
|
* 从表 a 中查询 id,name,num,根据 num 按升序(ASC)输出查询结果。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT * FROM a ORDER BY num ASC;
|
|
```
|
|
|
|
|
|
|
|

|
|
|
|
* 从表 a 中查询 id,name,num,根据 num 按降序(DESC)输出查询结果。
|
|
|
|
```javascript
|
|
SELECT * FROM a ORDER BY num DESC;
|
|
```
|
|
|
|

|
|
|
|
* 从表 a 中查询 id,name,num,使用 LIMIT强制从第2行开始,返回表 a 的两行结果。
|
|
|
|
```javascript
|
|
SELECT * FROM a LIMIT 1,2;
|
|
```
|
|
|
|
|
|
|
|

|
|
|
|
|
|
|
|
|
|
|
|
集合类 SELECT
|
|
-------------------
|
|
|
|
### 描述
|
|
|
|
该语句用于对多个 SELECT 查询的结果进行 UNION,MINUS,INTERSECT。
|
|
|
|
### 格式
|
|
|
|
```javascript
|
|
select_clause_set:
|
|
simple_select [ UNION | UNION ALL | EXCEPT | INTERSECT] select_clause_set_left
|
|
[ORDER BY sort_list_columns] [limit_clause]
|
|
select_clause_set_right:
|
|
simple_select |
|
|
select_caluse_set
|
|
```
|
|
|
|
|
|
|
|
### 参数解释
|
|
|
|
|
|
|
|
| 参数 | 描述 |
|
|
|-----------|--------------------------|
|
|
| UNION ALL | 合并两个查询的结果 |
|
|
| UNION | 合并两个查询的结果,并去重 |
|
|
| EXCEPT | 从左查询结果集中去重出现在右查询中的结果,并去重 |
|
|
| INTERSECT | 保留左查询结果集中出现在右查询中的结果,并去重 |
|
|
|
|
|
|
|
|
### 示例
|
|
|
|
以如下两表的数据为例:
|
|
|
|
```javascript
|
|
create table t1 (c1 int, c2 int);
|
|
create table t2 (c1 int, c2 int);
|
|
insert into t1 values (1, -1), (2, -2);
|
|
insert into t2 values (1, 1), (2, -2), (3, 3);
|
|
```
|
|
|
|
|
|
|
|
* 计算 T1, T2 的所有的记录
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT C1, C2 FROM T1 UNION ALL SELECT C1, C2 FROM T2;
|
|
+------+------+
|
|
| C1 | C2 |
|
|
+------+------+
|
|
| 1 | -1 |
|
|
| 2 | -2 |
|
|
| 1 | 1 |
|
|
| 2 | -2 |
|
|
| 3 | 3 |
|
|
+------+------+
|
|
```
|
|
|
|
|
|
|
|
* 计算 T1, T2 的去重后的所有记录
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT C1, C2 FROM T1 UNION SELECT C1, C2 FROM T2;
|
|
+------+------+
|
|
| C1 | C2 |
|
|
+------+------+
|
|
| 1 | -1 |
|
|
| 2 | -2 |
|
|
| 1 | 1 |
|
|
| 3 | 3 |
|
|
+------+------+
|
|
```
|
|
|
|
|
|
|
|
* 计算 T1 和 T2 的交集
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT C1, C2 FROM T1 INTERSECT SELECT C1, C2 FROM T2;
|
|
+------+------+
|
|
| C1 | C2 |
|
|
+------+------+
|
|
| 2 | -2 |
|
|
+------+------+
|
|
```
|
|
|
|
|
|
|
|
* 计算 T1 和 T2 的差集
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT C1, C2 FROM T1 EXCEPT SELECT C1, C2 FROM T2;
|
|
+------+------+
|
|
| C1 | C2 |
|
|
+------+------+
|
|
| 1 | -1 |
|
|
+------+------+
|
|
```
|
|
|
|
|
|
|
|
* 取 T1 和 T2 并集中 C2 排序最大的前两行
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```javascript
|
|
SELECT C1, C2 FROM T1 UNION SELECT C1, C2 FROM T2 ORDER BY C2 DESC LIMIT 2;
|
|
+------+------+
|
|
| C1 | C2 |
|
|
+------+------+
|
|
| 3 | 3 |
|
|
| 1 | 1 |
|
|
+------+------+
|
|
```
|
|
|
|
|
|
|