Files
oceanbase/docs/docs-cn/7.developer-guide-1/2.connect-to-the-oceanbase-database/6.query-table-data/6.use-operators-and-functions-in-queries/7.use-aggregate-functions-in-queries.md
2022-02-10 14:51:49 +08:00

3.4 KiB

查询中使用聚合函数

聚合函数扫描一组记录,然后返回单行记录。这组记录可以是一个表或者视图、或者一个子查询的结果。OceanBase 支持的聚合函数详情请参考手册《OceanBase SQL参考(MySQL模式)》。

聚合函数通常跟 GROUP BY 子句一起使用,按照一个或多个列的值分组,然后每组返回单笔记录。

示例:分组统计每个仓库的销售额

MySQL 租户中,聚合函数跟 GROUP BY 子句一起使用的时候,对 select_list 里的列没有要求。这个可能会导致结果集很奇怪。如果要求 select_list 里的列跟 GROUP BY 子句中的列保持一致,需要设置 MySQL 命令行下的 sql_mode 为 'ONLY_FULL_GROUP_BY'。SQL 查询如下:

obclient> SELECT ol_w_id
    , count(*)              order_count
    , sum(ol_amount)            sum_amount
    , round(avg(ol_amount),2)   avg_amount
    , min(ol_amount)            min_amount
    ,max(ol_amount)             max_amount
FROM ordl
GROUP BY ol_w_id  
ORDER BY ol_w_id ;

+---------+-------------+------------+------------+------------+------------+
| ol_w_id | order_count | sum_amount | avg_amount | min_amount | max_amount |
+---------+-------------+------------+------------+------------+------------+
|       1 |         297 |  917174.33 |    3088.13 |       0.00 |    9876.11 |
|       2 |         329 | 1153354.23 |    3505.64 |       0.00 |    9979.34 |
+---------+-------------+------------+------------+------------+------------+
2 rows in set (0.01 sec)

obclient> SELECT ol_w_id, ol_d_id
    ,  count(*)                 order_count
    , sum(ol_amount)            sum_amount
    , round(avg(ol_amount),2)   avg_amount
    , min(ol_amount)            min_amount
    , max(ol_amount)            max_amount 
FROM ordl  
GROUP BY ol_w_id  
ORDER BY ol_w_id
;

+---------+---------+-------------+------------+------------+------------+------------+
| ol_w_id | ol_d_id | order_count | sum_amount | avg_amount | min_amount | max_amount |
+---------+---------+-------------+------------+------------+------------+------------+
|       1 |       1 |         297 |  917174.33 |    3088.13 |       0.00 |    9876.11 |
|       2 |       1 |         329 | 1153354.23 |    3505.64 |       0.00 |    9979.34 |
+---------+---------+-------------+------------+------------+------------+------------+
2 rows in set (0.00 sec)

obclient> show variables like '%sql_mode%';
+---------------+-------------------------------------------------------+
| Variable_name | Value                                                 |
+---------------+-------------------------------------------------------+
| sql_mode      | PIPES_AS_CONCAT,STRICT_TRANS_TABLES,STRICT_ALL_TABLES |
+---------------+-------------------------------------------------------+
1 row in set (0.00 sec)

obclient> SET SESSION sql_mode='STRICT_ALL_TABLES,ONLY_FULL_GROUP_BY';                                                                                                                                    Query OK, 0 rows affected (0.00 sec)


obclient> SELECT ol_w_id, ol_d_id
    , count(*)                  order_count
    , sum(ol_amount)            sum_amount
    , round(avg(ol_amount),2)   avg_amount
    , min(ol_amount)            min_amount
    , max(ol_amount)            max_amount 
FROM ordl  
GROUP BY ol_w_id  
ORDER BY ol_w_id
;

ERROR 1055 (42000): 'tpccdb.ordl.ol_d_id' is not in GROUP BY
obclient>