Publishers of technology books, eBooks, and videos for creative people

Home > Articles

  • Print
  • + Share This
This chapter is from the book

This chapter is from the book

Grouping Rows with GROUP BY

To this point, I’ve used aggregate functions to summarize all the values in a column or just those values that matched a WHERE search condition. You can use the GROUP BY clause to divide a table into logical groups (categories) and calculate aggregate statistics for each group.

An example will clarify the concept. Listing 6.9 uses GROUP BY to count the number of books that each author wrote (or co-wrote). In the SELECT clause, the column au_id identifies each author, and the derived column num_books counts each author’s books. The GROUP BY clause causes num_books to be calculated for every unique au_id instead of only once for the entire table. Figure 6.9 shows the result. In this example, au_id is called the grouping column.

Listing 6.9 List the number of books each author wrote (or co-wrote). See Figure 6.9 for the result.

SELECT
    au_id,
    COUNT(*) AS "num_books"
  FROM title_authors
  GROUP BY au_id;

Figure 6.9Figure 6.9 Results of Listing 6.9.


The GROUP BY clause’s important characteristics are:

  • The GROUP BY clause comes after the WHERE clause and before the ORDER BY clause.

  • Grouping columns can be column names or derived columns.

  • Every nonaggregate column in the SELECT clause must appear in the GROUP BY clause. This statement is illegal because pub_id isn’t in the GROUP BY clause:

    SELECT type,  pub_id , COUNT(*) 
      FROM titles
      GROUP BY type;             --Illegal

    Because the GROUP BY can return only one row for each value of type, there’s no way to return multiple values of pub_id that are associated with any particular value of type.

  • If the SELECT clause contains a complex nonaggregate expression (more than just a simple column name), the GROUP BY expression must match the SELECT expression exactly.

  • Specify multiple grouping columns in the GROUP BY clause to nest groups. Data is summarized at the last specified group.

  • If a grouping column contains a null, that row becomes a group in the result. If a grouping column contains more than one null, the nulls are put into a single group. A group that contains multiple nulls doesn’t imply that the nulls equal one another.

  • Use a WHERE clause in a query containing a GROUP BY clause to eliminate rows before grouping occurs.

  • You can’t use a column alias in the GROUP BY clause, though table aliases are allowed as qualifiers; see “Creating Table Aliases with AS” in Chapter 7.

  • Without an ORDER BY clause, groups returned by GROUP BY aren’t in any particular order. To sort the result of Listing 6.9 by the descending number of books, for example, add the clause ORDER BY “num_books” DESC.

To group rows:

  • Type:

    SELECT columns 
      FROM table
      [WHERE search_condition] 
      GROUP BY grouping_columns
      HAVING search_condition]
      [ORDER BY sort_columns];

    columns and grouping_columns are one or more comma-separated column names, and table is the name of the table that contains columns and grouping_columns. The nonaggregate columns that appear in columns also must appear in grouping_columns. The order of the column names in grouping_columns determines the grouping levels, from the highest to the lowest level of grouping.

    The GROUP BY clause restricts the rows of the result; only one row appears for each distinct value in the grouping column or columns. Each row in the result contains summary data related to the specific value in its grouping columns.

    If the statement includes a WHERE clause, the DBMS groups values after it applies search_condition to the rows in table. If the statement includes an ORDER BY clause, the columns in sort_columns must be drawn from those in columns. The WHERE and ORDER BY clauses are covered in “Filtering Rows with WHERE” and “Sorting Rows with ORDER BY” in Chapter 4. HAVING, which filters grouped rows, is covered in the next section.

Listing 6.10 and Figure 6.10 show the difference between COUNT(expr) and COUNT(*) in a query that contains GROUP BY. The table publishers contains one null in the column state (for publisher P03 in Germany). Recall from “Counting Rows with COUNT()” earlier in this chapter that COUNT(expr) counts non-null values and COUNT(*) counts all values, including nulls. In the result, GROUP BY recognizes the null and creates a null group for it. COUNT(*) finds (and counts) the one null in the column state. But COUNT(state) contains a zero for the null group because COUNT(state) finds only a null in the null group, which it excludes from the count—hence, the zero.

Listing 6.10 This query illustrates the difference between COUNT(expr) and COUNT(*) in a GROUP BY query. See Figure 6.10 for the result.

SELECT
    state,
    COUNT(state) AS "COUNT(state)",
    COUNT(*)     AS "COUNT(*)"
  FROM publishers
  GROUP BY state;

Figure 6.10Figure 6.10 Results of Listing 6.10.

If a nonaggregate column contains nulls, using COUNT(*) rather than COUNT(expr) can produce misleading results. Listing 6.11 and Figure 6.11 show summary sales statistics for each type of book. The sales value for one of the biographies is null, so COUNT(sales) and COUNT(*) differ by 1. The average calculation in the fifth column, SUM/COUNT(sales), is consistent mathematically, whereas the sixth-column average, SUM/COUNT(*), is not. I’ve verified the inconsistency with AVG(sales) in the final column. (Recall a similar situation in Listing 6.8 in “Aggregating Distinct Values with DISTINCT” earlier in this chapter.)

Listing 6.11 For mathematically consistent results, use COUNT(expr), rather than COUNT(*), if expr contains nulls. See Figure 6.11 for the result.

SELECT
    type,
    SUM(sales) AS "SUM(sales)",
    COUNT(sales) AS "COUNT(sales)",
    COUNT(*) AS "COUNT(*)",
    SUM(sales)/COUNT(sales)
      AS "SUM/COUNT(sales)",
    SUM(sales)/COUNT(*)
      AS "SUM/COUNT(*)",
    AVG(sales) AS "AVG(sales)"
  FROM titles
  GROUP BY type;

Figure 6.11Figure 6.11 Results of Listing 6.11.

Listing 6.12 and Figure 6.12 show a simple GROUP BY query that calculates the total sales, average sales, and number of titles for each type of book. In Listing 6.13 and Figure 6.13, I’ve added a WHERE clause to eliminate books priced under $13 before grouping. I’ve also added an ORDER BY clause to sort the result by descending total sales of each book type.

Listing 6.12 This simple GROUP BY query calculates a few summary statistics for each type of book. See Figure 6.12 for the result.

SELECT
    type,
    SUM(sales) AS "SUM(sales)",
    AVG(sales) AS "AVG(sales)",
    COUNT(sales) AS "COUNT(sales)"
  FROM titles
  GROUP BY type;

Figure 6.12Figure 6.12 Results of Listing 6.12.

Listing 6.13 Here, I’ve added WHERE and ORDER BY clauses to Listing 6.12 to cull books priced under $13 and sort the result by descending total sales. See Figure 6.13 for the result.

SELECT
    type,
    SUM(sales) AS "SUM(sales)",
    AVG(sales) AS "AVG(sales)",
    COUNT(sales) AS "COUNT(sales)"
  FROM titles
  WHERE price >= 13
  GROUP BY type
  ORDER BY "SUM(sales)" DESC;

Figure 6.13Figure 6.13 Results of Listing 6.13.

Listing 6.14 and Figure 6.14 use multiple grouping columns to count the number of titles of each type that each publisher publishes.

Listing 6.14 List the number of books of each type for each publisher, sorted by descending count within ascending publisher ID. See Figure 6.14 for the result.

SELECT
    pub_id,
    type,
    COUNT(*) AS "COUNT(*)"
  FROM titles
  GROUP BY pub_id, type
  ORDER BY pub_id ASC, "COUNT(*)" DESC;

Figure 6.14Figure 6.14 Results of Listing 6.14.


In Listing 6.15 and Figure 6.15, I revisit Listing 5.31 in “Evaluating Conditional Values with CASE” in Chapter 5. But instead of listing each book categorized by its sales range, I use GROUP BY to list the number of books in each sales range.

Listing 6.15 List the number of books in each calculated sales range, sorted by ascending sales. See Figure 6.15 for the result.

SELECT
    CASE
      WHEN sales IS NULL
        THEN 'Unknown'
      WHEN sales <= 1000
        THEN 'Not more than 1,000'
      WHEN sales <= 10000
        THEN 'Between 1,001 and 10,000'
      WHEN sales <= 100000
        THEN 'Between 10,001 and 100,000'
      WHEN sales <= 1000000
        THEN 'Between 100,001 and 1,000,000'
      ELSE 'Over 1,000,000'
    END
      AS "Sales category",
    COUNT(*) AS "Num titles"
  FROM titles
  GROUP BY
    CASE
      WHEN sales IS NULL
        THEN 'Unknown'
      WHEN sales <= 1000
        THEN 'Not more than 1,000'
      WHEN sales <= 10000
        THEN 'Between 1,001 and 10,000'
      WHEN sales <= 100000
        THEN 'Between 10,001 and 100,000'
      WHEN sales <= 1000000
        THEN 'Between 100,001 and 1,000,000'
      ELSE 'Over 1,000,000'
    END
  ORDER BY MIN(sales) ASC;

Figure 6.15Figure 6.15 Results of Listing 6.15.


TIPS

  • Use the WHERE clause to exclude rows that you don’t want grouped, and use the HAVING clause to filter rows after they have been grouped. For information about HAVING, see the next section.

  • If used without an aggregate function,GROUP BY acts like DISTINCT (Listing 6.16and Figure 6.16). For information about DISTINCT, see “Eliminating Duplicate Rows with DISTINCT” in Chapter 4.

    Listing 6.16 Both of these queries return the same result. See Figure 6.16 for the result.

    SELECT type
      FROM titles
      GROUP BY type;
    
    SELECT DISTINCT type
      FROM titles;

    Figure 6.16Figure 6.16 Results of Listing 6.16.


  • You can use GROUP BY to look for patterns in your data. In Listing 6.17 and Figure 6.17, I’m looking for a relationship between price categories and average sales.

    Listing 6.17 List the average sales for each price, sorted by ascending price. See Figure 6.17 for the result.

    SELECT price, AVG(sales) AS "AVG(sales)"
      FROM titles
      WHERE price IS NOT NULL
      GROUP BY price
      ORDER BY price ASC;

    Figure 6.17Figure 6.17 Results of Listing 6.17.


  • Don’t rely on GROUP BY to sort your result. I recommend that you include ORDER BY whenever you use GROUP BY (even though I’ve omitted ORDER BY in some examples). In some DBMSes, a GROUP BY implies anORDER BY.

  • The multiple values returned by an aggregate function in a GROUP BY query are called vector aggregates. In a query that lacks a GROUP BY clause, the single value returned by an aggregate function is a scalar aggregate.

  • In Microsoft Access, use the Switch() function instead of the CASE expression in Listing 6.15. See the DBMS Tip in “Evaluating Conditional Values with CASE” in Chapter 5.

    MySQL doesn’t allow CASE in a GROUP BY clause. Listing 6.15 won’t run in MySQL.

    Some DBMSes, such as MySQL and PostgreSQL, permit column aliases in the GROUP BY clause.

  • + Share This
  • 🔖 Save To Your Account