270 lines
7.7 KiB
Markdown
270 lines
7.7 KiB
Markdown
聚集函数
|
|
=========================
|
|
|
|
|
|
|
|
聚合函数对一组值执行计算并返回单一的值。聚合函数忽略空值。聚合函数经常与SELECT语句的GROUP BY子句一同使用。
|
|
|
|
所有聚合函数都具有确定性。任何时候用一组给定的输入值调用它们时,都返回相同的值。
|
|
|
|
在OceanBase的聚合函数中,Value表达式只能出现一个。例如:不支持COUNT(c1, c2),仅支持COUNT(c1)。
|
|
|
|
AVG
|
|
------------
|
|
|
|
**声明**
|
|
|
|
`AVG(([DISTINCT] expr)`
|
|
|
|
**说明**
|
|
|
|
返回指定组中的平均值,空值被忽略。DISTINCT选项可用于返回expr的不同值的平均值。若找不到匹配的行,则AVG()返回NULL。
|
|
|
|
**例子**
|
|
|
|
```javascript
|
|
Oceanbase>select * from oceanbasetest;
|
|
+----+------+------+
|
|
| id | ip | ip2 |
|
|
+----+------+------+
|
|
| 1 | 4 | NULL |
|
|
| 3 | 3 | NULL |
|
|
| 4 | 3 | NULL |
|
|
+----+------+------+
|
|
3 rows in set (0.01 sec)
|
|
|
|
Oceanbase>select avg(ip2), avg(ip), avg(distinct(ip)) from oceanbasetest;
|
|
+----------+---------+-------------------+
|
|
| avg(ip2) | avg(ip) | avg(distinct(ip)) |
|
|
+----------+---------+-------------------+
|
|
| NULL | 3.3333 | 3.5000 |
|
|
+----------+---------+-------------------+
|
|
1 row in set (0.00 sec)
|
|
|
|
Oceanbase>select avg(distinct(ip)),avg(ip),avg(ip2) from oceanbasetest;
|
|
+-------------------+---------+----------+
|
|
| avg(distinct(ip)) | avg(ip) | avg(ip2) |
|
|
+-------------------+---------+----------+
|
|
| 3.5000 | 3.3333 | NULL |
|
|
+-------------------+---------+----------+
|
|
1 row in set (0.00 sec)
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
COUNT
|
|
--------------
|
|
|
|
**声明**
|
|
|
|
`COUNT([DISTINCT] expr)`
|
|
|
|
**说明**
|
|
|
|
COUNT(\[DISTINCT\] expr )返回SELECT语句检索到的行中非NULL值的数目。若找不到匹配的行,则COUNT()返回0。DISTINCT选项可用于返回 expr 的不同值的数目。
|
|
|
|
COUNT(\*)的稍微不同之处在于,它返回检索行的数目,不论其是否包含NULL值。
|
|
|
|
**例子**
|
|
|
|
```javascript
|
|
Oceanbase>select * from oceanbasetest;
|
|
+----+------+------+
|
|
| id | ip | ip2 |
|
|
+----+------+------+
|
|
| 1 | 4 | NULL |
|
|
| 3 | 3 | NULL |
|
|
| 4 | 3 | NULL |
|
|
+----+------+------+
|
|
3 rows in set (0.00 sec)
|
|
|
|
Oceanbase>select count(ip2), count(ip), count(distinct(ip)), count(*) from oceanbasetest;
|
|
+------------+-----------+---------------------+----------+
|
|
| count(ip2) | count(ip) | count(distinct(ip)) | count(*) |
|
|
+------------+-----------+---------------------+----------+
|
|
| 0 | 3 | 2 | 3 |
|
|
+------------+-----------+---------------------+----------+
|
|
1 row in set (0.00 sec)
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
MAX
|
|
------------
|
|
|
|
**声明**
|
|
|
|
`MAX([DISTINCT] expr)`
|
|
|
|
**说明**
|
|
|
|
返回指定数据中的最大值。
|
|
|
|
MAX()的取值可以是一个字符串参数;在这些情况下,它们返回最大字符串值。DISTINCT关键字可以被用来查找 expr的不同值的最大值,这产生的结果与省略DISTINCT 的结果相同。
|
|
|
|
假设表a有三行数据:id=1,num=10;id=2,num=20;id=3,num=30。
|
|
|
|
**例子**
|
|
|
|
```javascript
|
|
Oceanbase>SELECT MAX(num) FROM a;
|
|
+-----------------+
|
|
| MAX(num) |
|
|
+-----------------+
|
|
| 30 |
|
|
+-----------------+
|
|
1 row in set (0.00 sec)
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
MIN
|
|
------------
|
|
|
|
**声明**
|
|
|
|
`MIN([DISTINCT] expr)`
|
|
|
|
**说明**
|
|
|
|
返回指定数据中的最小值。
|
|
|
|
MIN()的取值可以是一个字符串参数;在这些情况下,它们返回最小字符串值。DISTINCT关键字可以被用来查找expr 的不同值的最小值,然而,这产生的结果与省略DISTINCT 的结果相同。
|
|
|
|
假设表a有三行数据:id=1,num=10;id=2,num=20;id=3,num=30。
|
|
|
|
**例子**
|
|
|
|
```javascript
|
|
Oceanbase>SELECT MIN(num) FROM a;
|
|
+----------------+
|
|
| MIN(num) |
|
|
+----------------+
|
|
| 10 |
|
|
+----------------+
|
|
1 row in set (0.00 sec)
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
SUM
|
|
------------
|
|
|
|
**声明**
|
|
|
|
`SUM([DISTINCT] expr)`
|
|
|
|
**说明**
|
|
|
|
返回 expr 的总数。若返回集合中无任何行,则 SUM() 返回NULL。DISTINCT关键字可用于求得 expr 不同值的总和。
|
|
|
|
若找不到匹配的行,则SUM()返回NULL。
|
|
|
|
**例子**
|
|
|
|
```javascript
|
|
Oceanbase>select * from oceanbasetest;
|
|
+------+------+------+
|
|
| id | ip | ip2 |
|
|
+------+------+------+
|
|
| 1 | 4 | NULL |
|
|
| 3 | 3 | NULL |
|
|
| 4 | 3 | NULL |
|
|
+------+------+------+
|
|
3 rows in set (0.00 sec)
|
|
|
|
Oceanbase>select sum(ip2),sum(ip),sum(distinct(ip)) from oceanbasetest;
|
|
+----------+---------+-------------------+
|
|
| sum(ip2) | sum(ip) | sum(distinct(ip)) |
|
|
+----------+---------+-------------------+
|
|
| NULL | 10 | 7 |
|
|
+----------+---------+-------------------+
|
|
1 row in set (0.00 sec)
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
GROUP_CONCAT
|
|
---------------------
|
|
|
|
**声明**
|
|
|
|
`GROUP_CONCAT([DISTINCT] expr)`
|
|
|
|
**说明**
|
|
|
|
该函数返回带有来自一个组的连接的非NULL值的字符串结果。
|
|
|
|
```javascript
|
|
GROUP_CONCAT([DISTINCT] expr [,expr ...]
|
|
[ORDER BY {unsigned_integer | col_name | expr}
|
|
ASC | DESC]
|
|
[SEPARATOR str_val])
|
|
```
|
|
|
|
|
|
|
|
**例子**
|
|
|
|
```javascript
|
|
Oceanbase>select * from book; //表book(书编号,书名,出版社)
|
|
+--------+--------------------------------+-----------------------------+
|
|
| bookid | bookname | publishname |
|
|
+--------+--------------------------------+-----------------------------+
|
|
| 1 | git help | alibaba group publisher |
|
|
| 2 | MySQL性能优化 | 浙江大学图文出版社 |
|
|
| 3 | JAVA编程指南 | 机械工业出版社 |
|
|
| 3 | JAVA编程指南 | 机械工业出版社 |
|
|
| 4 | 大规模分布式存储系统 | 机械工业出版社 |
|
|
+--------+--------------------------------+-----------------------------+
|
|
5 rows in set (0.00 sec)
|
|
|
|
//查找书名信息
|
|
Oceanbase>select group_concat(bookname) from book group by bookname;
|
|
+-----------------------------------+
|
|
| group_concat(bookname) |
|
|
+-----------------------------------+
|
|
| git help |
|
|
| JAVA编程指南,JAVA编程指南 |
|
|
| MySQL性能优化 |
|
|
| 大规模分布式存储系统 |
|
|
+-----------------------------------+
|
|
4 rows in set (0.00 sec)
|
|
|
|
//查找书名信息,书名唯一
|
|
Oceanbase>select group_concat(distinct(bookname)) from book group by bookname;
|
|
+----------------------------------+
|
|
| group_concat(distinct(bookname)) |
|
|
+----------------------------------+
|
|
| git help |
|
|
| JAVA编程指南 |
|
|
| MySQL性能优化 |
|
|
| 大规模分布式存储系统 |
|
|
+----------------------------------+
|
|
4 rows in set (0.01 sec)
|
|
|
|
//查找书名和出版社信息,以书名分组,出版社信息降序排序显示
|
|
Oceanbase>select bookname, group_concat(publishname order by publishname desc separator ';' ) from book group by bookname;
|
|
+--------------------------------+---------------------------------------------------------------------+
|
|
| bookname | group_concat(publishname order by publishname desc separator ';' ) |
|
|
+--------------------------------+---------------------------------------------------------------------+
|
|
| git help | alibaba group publisher |
|
|
| JAVA编程指南 | 机械工业出版社;机械工业出版社 |
|
|
| MySQL性能优化 | 浙江大学图文出版社 |
|
|
| 大规模分布式存储系统 | 机械工业出版社 |
|
|
+--------------------------------+---------------------------------------------------------------------+
|
|
4 rows in set (0.00 sec)
|
|
```
|
|
|
|
|