@ -708,40 +708,39 @@ SELECT city FROM weather
<indexterm><primary>HAVING</primary></indexterm>
<indexterm><primary>HAVING</primary></indexterm>
Aggregates are also very useful in combination with <literal>GROUP
Aggregates are also very useful in combination with <literal>GROUP
BY</literal> clauses. For example, we can get the maximum low
BY</literal> clauses. For example, we can get the number of readings
temperature observed in each city with:
and the maximum low temperature observed in each city with:
<programlisting>
<programlisting>
SELECT city, max(temp_lo)
SELECT city, count(*), max(temp_lo)
FROM weather
FROM weather
GROUP BY city;
GROUP BY city;
</programlisting>
</programlisting>
<screen>
<screen>
city | max
city | count | max
---------------+-----
---------------+-------+-----
Hayward | 37
Hayward | 1 | 37
San Francisco | 46
San Francisco | 2 | 46
(2 rows)
(2 rows)
</screen>
</screen>
which gives us one output row per city. Each aggregate result is
which gives us one output row per city. Each aggregate result is
computed over the table rows matching that city.
computed over the table rows matching that city.
We can filter these grouped
We can filter these grouped
rows using <literal>HAVING</literal> and the output count using
rows using <literal>HAVING</literal>:
<literal>FILTER</literal>:
<programlisting>
<programlisting>
SELECT city, max(temp_lo), count(*) FILTER (WHERE temp_lo < 30 )
SELECT city, count(*), max(temp_lo )
FROM weather
FROM weather
GROUP BY city
GROUP BY city
HAVING max(temp_lo) < 40;
HAVING max(temp_lo) < 40;
</programlisting>
</programlisting>
<screen>
<screen>
city | max | count
city | count | max
---------+-----+ -------
---------+-------+ -----
Hayward | 37 | 5
Hayward | 1 | 37
(1 row)
(1 row)
</screen>
</screen>
@ -751,12 +750,18 @@ SELECT city, max(temp_lo), count(*) FILTER (WHERE temp_lo < 30)
names begin with <quote><literal>S</literal></quote>, we might do:
names begin with <quote><literal>S</literal></quote>, we might do:
<programlisting>
<programlisting>
SELECT city, max(temp_lo), count(*) FILTER (WHERE temp_lo < 30 )
SELECT city, count(*), max(temp_lo )
FROM weather
FROM weather
WHERE city LIKE 'S%' -- <co id="co.tutorial-agg-like"/>
WHERE city LIKE 'S%' -- <co id="co.tutorial-agg-like"/>
GROUP BY city
GROUP BY city;
HAVING max(temp_lo) < 40;
</programlisting>
</programlisting>
<screen>
city | count | max
---------------+-------+-----
San Francisco | 2 | 46
(1 row)
</screen>
<calloutlist>
<calloutlist>
<callout arearefs="co.tutorial-agg-like">
<callout arearefs="co.tutorial-agg-like">
<para>
<para>
@ -793,6 +798,34 @@ SELECT city, max(temp_lo), count(*) FILTER (WHERE temp_lo < 30)
because we avoid doing the grouping and aggregate calculations
because we avoid doing the grouping and aggregate calculations
for all rows that fail the <literal>WHERE</literal> check.
for all rows that fail the <literal>WHERE</literal> check.
</para>
</para>
<para>
Another way to select the rows that go into an aggregate
computation is to use <literal>FILTER</literal>, which is a
per-aggregate option:
<programlisting>
SELECT city, count(*) FILTER (WHERE temp_lo < 45), max(temp_lo)
FROM weather
GROUP BY city;
</programlisting>
<screen>
city | count | max
---------------+-------+-----
Hayward | 1 | 37
San Francisco | 1 | 46
(2 rows)
</screen>
<literal>FILTER</literal> is much like <literal>WHERE</literal>,
except that it removes rows only from the input of the particular
aggregate function that it is attached to.
Here, the <literal>count</literal> aggregate counts only
rows with <literal>temp_lo</literal> below 45; but the
<literal>max</literal> aggregate is still applied to all rows,
so it still finds the reading of 46.
</para>
</sect1>
</sect1>