Summary: in this tutorial, you will learn how to use MySQL GROUP BY
to group rows into groups based on the values of columns or expressions.
Introduction to MySQL GROUP BY clause
The GROUP BY
clause groups rows into summary rows based on column values or expressions. It returns one row for each group and reduces the number of rows in the result set.
The GROUP BY
clause is an optional part of the SELECT
statement. The following illustrates the syntax of the GROUP BY
clause:
SELECT
c1, c2,..., cn, aggregate_function(ci)
FROM
table_name
WHERE
conditions
GROUP BY c1 , c2,...,cn;
Code language: SQL (Structured Query Language) (sql)
In this syntax, you place the GROUP BY
clause after the FROM
and WHERE
clauses. Following the the GROUP BY
keywords, you list the columns or expressions you want to group, separated by commas.
MySQL evaluates the GROUP BY
clause after the FROM
and WHERE
clauses but before the HAVING
, SELECT
, DISTINCT
, ORDER BY
and LIMIT
clauses:
In practice, you often use the GROUP BY
clause with aggregate functions such as SUM
, AVG
, MAX
, MIN
, and COUNT
. The aggregate function that appears in the SELECT
clause provides the information for each group.
MySQL GROUP BY examples
Let’s look at some examples of using the GROUP BY
clause.
1) Basic MySQL GROUP BY example
We’ll use the orders
table in the sample database:
If you want to group the order statuses, you can use the GROUP BY
clause with the status
column in the following query:
SELECT
status
FROM
orders
GROUP BY
status;
Code language: SQL (Structured Query Language) (sql)
Output:
+------------+
| status |
+------------+
| Shipped |
| Resolved |
| Cancelled |
| On Hold |
| Disputed |
| In Process |
+------------+
6 rows in set (0.02 sec)
Code language: SQL (Structured Query Language) (sql)
The output shows that the GROUP BY
clause returns unique occurrences of the values in the status
columns.
It works like the DISTINCT
operator, as demonstrated in the following query:
SELECT
DISTINCT status
FROM
orders;
Code language: SQL (Structured Query Language) (sql)
2) Using MySQL GROUP BY with aggregate functions
In practice, you often use the GROUP BY
clause with an aggregate function to group rows into sets and return a single value for each group.
An aggregate function calculates a set of rows and returns a single value.
For example, to obtain the number of orders in each status, you can use the COUNT
function with the GROUP BY
clause as follows:
SELECT
status,
COUNT(*)
FROM
orders
GROUP BY
status;
Code language: SQL (Structured Query Language) (sql)
+------------+----------+
| status | COUNT(*) |
+------------+----------+
| Shipped | 303 |
| Resolved | 4 |
| Cancelled | 6 |
| On Hold | 4 |
| Disputed | 3 |
| In Process | 6 |
+------------+----------+
6 rows in set (0.01 sec)
Code language: SQL (Structured Query Language) (sql)
See the following orders
and orderdetails
table from the sample database:
To get the total amount of all orders by status, you join the orders
table with the orderdetails
table and use the SUM
function to calculate the total amount:
SELECT
status,
SUM(quantityOrdered * priceEach) AS amount
FROM
orders
INNER JOIN orderdetails USING (orderNumber)
GROUP BY
status;
Code language: SQL (Structured Query Language) (sql)
+------------+------------+
| status | amount |
+------------+------------+
| Shipped | 8865094.64 |
| Resolved | 134235.88 |
| Cancelled | 238854.18 |
| On Hold | 169575.61 |
| Disputed | 61158.78 |
| In Process | 135271.52 |
+------------+------------+
6 rows in set (0.01 sec)
Code language: SQL (Structured Query Language) (sql)
Similarly, the following query returns the order numbers and the total amount of each order.
SELECT
orderNumber,
SUM(quantityOrdered * priceEach) AS total
FROM
orderdetails
GROUP BY
orderNumber;
Code language: SQL (Structured Query Language) (sql)
3) MySQL GROUP BY with expression example
In addition to columns, you can group rows by expressions. The following query calculates the total sales for each year:
SELECT
YEAR(orderDate) AS year,
SUM(quantityOrdered * priceEach) AS total
FROM
orders
INNER JOIN orderdetails USING (orderNumber)
WHERE
status = 'Shipped'
GROUP BY
YEAR(orderDate);
Code language: SQL (Structured Query Language) (sql)
+------+------------+
| year | total |
+------+------------+
| 2003 | 3223095.80 |
| 2004 | 4300602.99 |
| 2005 | 1341395.85 |
+------+------------+
3 rows in set (0.02 sec)
Code language: SQL (Structured Query Language) (sql)
In this example, we used the YEAR
function to extract year data from order date ( orderDate
) and included only orders with shipped
status in the total sales.
Note that the expression in the SELECT
clause must match the one in the GROUP BY
clause.
4) Using MySQL GROUP BY with HAVING clause example
To filter the groups returned by GROUP BY
clause, you use a HAVING
clause.
The following query uses the HAVING
clause to select the total sales of the years after 2003.
SELECT
YEAR(orderDate) AS year,
SUM(quantityOrdered * priceEach) AS total
FROM
orders
INNER JOIN orderdetails USING (orderNumber)
WHERE
status = 'Shipped'
GROUP BY
year
HAVING
year > 2003;
Code language: SQL (Structured Query Language) (sql)
5) Grouping by multiple columns
The following query returns the year, order status, and the total order for each combination of year and order status by grouping rows into groups:
SELECT
YEAR(orderDate) AS year,
status,
SUM(quantityOrdered * priceEach) AS total
FROM
orders
INNER JOIN orderdetails USING (orderNumber)
GROUP BY
year,
status
ORDER BY
year;
Code language: SQL (Structured Query Language) (sql)
Output:
+------+------------+------------+
| year | status | total |
+------+------------+------------+
| 2003 | Cancelled | 67130.69 |
| 2003 | Resolved | 27121.90 |
| 2003 | Shipped | 3223095.80 |
| 2004 | Cancelled | 171723.49 |
| 2004 | On Hold | 23014.17 |
| 2004 | Resolved | 20564.86 |
| 2004 | Shipped | 4300602.99 |
| 2005 | Disputed | 61158.78 |
| 2005 | In Process | 135271.52 |
| 2005 | On Hold | 146561.44 |
| 2005 | Resolved | 86549.12 |
| 2005 | Shipped | 1341395.85 |
+------+------------+------------+
12 rows in set (0.01 sec)
Code language: SQL (Structured Query Language) (sql)
The GROUP BY clause: MySQL vs. SQL standard
The SQL standard does not allow you to use an alias in the GROUP BY
clause whereas MySQL supports this.
For example, the following query extracts the year from the order date. It first uses the year
as an alias of the expression YEAR(orderDate)
and then uses the year
alias in the GROUP BY
clause.
The following query is not valid in SQL standard:
SELECT
YEAR(orderDate) AS year,
COUNT(orderNumber)
FROM
orders
GROUP BY
year;
Code language: SQL (Structured Query Language) (sql)
+------+--------------------+
| year | COUNT(orderNumber) |
+------+--------------------+
| 2003 | 111 |
| 2004 | 151 |
| 2005 | 64 |
+------+--------------------+
3 rows in set (0.00 sec)
Code language: SQL (Structured Query Language) (sql)
The GROUP BY clause vs. DISTINCT clause
If you use the GROUP BY
clause in the SELECT
statement without using aggregate functions, the GROUP BY
clause behaves like the DISTINCT
clause.
The following statement uses the GROUP BY
clause to select the unique states of customers from the customers
table.
SELECT
state
FROM
customers
GROUP BY
state;
Code language: SQL (Structured Query Language) (sql)
+---------------+
| state |
+---------------+
| NULL |
| NV |
| Victoria |
| CA |
| NY |
| PA |
| CT |
...
Code language: SQL (Structured Query Language) (sql)
You can achieve a similar result by using the DISTINCT
clause:
SELECT
DISTINCT state
FROM
customers;
Code language: SQL (Structured Query Language) (sql)
+---------------+
| state |
+---------------+
| NULL |
| NV |
| Victoria |
| CA |
| NY |
| PA |
| CT |
...
Code language: SQL (Structured Query Language) (sql)
Notice that MySQL 8.0 or later removed the implicit sorting for the GROUP BY
clause. Therefore, if you are using earlier versions, you will find that the result set with the GROUP BY
clause is sorted.
Summary
- Use the
GROUP BY
clause to group rows into subgroups.