From f05a5e0003edfec027ee10d09082667036862e1c Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Tue, 8 Nov 2022 18:25:03 -0500 Subject: [PATCH] Doc: improve tutorial section about grouped aggregates. Commit fede15417 introduced FILTER by jamming it into the existing example introducing HAVING, which seems pedagogically poor to me; and it added no information about what the keyword actually does. Not to mention that the claimed output didn't match the sample data being used in this running example. Revert that and instead make an independent example using FILTER. To help drive home the point that it's a per-aggregate filter, we need to use two aggregates not just one; for consistency expand all the examples in this segment to do that. Also adjust the example using WHERE ... LIKE so that it'd produce nonempty output with this sample data, and show that output. Back-patch, as the previous patch was. (Sadly, v10 is now out of scope.) Discussion: https://postgr.es/m/166794307526.652.9073408178177444190@wrigleys.postgresql.org --- doc/src/sgml/query.sgml | 65 +++++++++++++++++++++++++++++++---------- 1 file changed, 49 insertions(+), 16 deletions(-) diff --git a/doc/src/sgml/query.sgml b/doc/src/sgml/query.sgml index 8243bf51af..59962d6e85 100644 --- a/doc/src/sgml/query.sgml +++ b/doc/src/sgml/query.sgml @@ -706,40 +706,39 @@ SELECT city FROM weather HAVING Aggregates are also very useful in combination with GROUP - BY clauses. For example, we can get the maximum low - temperature observed in each city with: + BY clauses. For example, we can get the number of readings + and the maximum low temperature observed in each city with: -SELECT city, max(temp_lo) +SELECT city, count(*), max(temp_lo) FROM weather GROUP BY city; - city | max ----------------+----- - Hayward | 37 - San Francisco | 46 + city | count | max +---------------+-------+----- + Hayward | 1 | 37 + San Francisco | 2 | 46 (2 rows) which gives us one output row per city. Each aggregate result is computed over the table rows matching that city. We can filter these grouped - rows using HAVING and the output count using - FILTER: + rows using HAVING: -SELECT city, max(temp_lo), count(*) FILTER (WHERE temp_lo < 30) +SELECT city, count(*), max(temp_lo) FROM weather GROUP BY city HAVING max(temp_lo) < 40; - city | max | count ----------+-----+------- - Hayward | 37 | 5 + city | count | max +---------+-------+----- + Hayward | 1 | 37 (1 row) @@ -749,12 +748,18 @@ SELECT city, max(temp_lo), count(*) FILTER (WHERE temp_lo < 30) names begin with S, we might do: -SELECT city, max(temp_lo), count(*) FILTER (WHERE temp_lo < 30) +SELECT city, count(*), max(temp_lo) FROM weather WHERE city LIKE 'S%' -- - GROUP BY city - HAVING max(temp_lo) < 40; + GROUP BY city; + + + city | count | max +---------------+-------+----- + San Francisco | 2 | 46 +(1 row) + @@ -791,6 +796,34 @@ SELECT city, max(temp_lo), count(*) FILTER (WHERE temp_lo < 30) because we avoid doing the grouping and aggregate calculations for all rows that fail the WHERE check. + + + Another way to select the rows that go into an aggregate + computation is to use FILTER, which is a + per-aggregate option: + + +SELECT city, count(*) FILTER (WHERE temp_lo < 45), max(temp_lo) + FROM weather + GROUP BY city; + + + + city | count | max +---------------+-------+----- + Hayward | 1 | 37 + San Francisco | 1 | 46 +(2 rows) + + + FILTER is much like WHERE, + except that it removes rows only from the input of the particular + aggregate function that it is attached to. + Here, the count aggregate counts only + rows with temp_lo below 45; but the + max aggregate is still applied to all rows, + so it still finds the reading of 46. +