HAVING
Just as a WHERE
clause limits the rows in a dataset to those that meet the search condition, so the HAVING
sub-clause imposes restrictions on the aggregated rows in a grouped set.HAVING
is optional, and can only be used in conjunction with GROUP BY
.
The condition(s) in the HAVING
clause can refer to:
-
Any aggregated column in the select list.This is the most widely used case.
-
Any aggregated expression that is not in the select list, but allowed in the context of the query.This is sometimes useful too.
-
Any column in the
GROUP BY
list.While legal, it is more efficient to filter on these non-aggregated data at an earlier stage: in theWHERE
clause. -
Any expression whose value doesn’t depend on the contents of the dataset (like a constant or a context variable).This is valid but not useful, because it will either suppress the entire set or leave it untouched, based on conditions that have nothing to do with the set itself.
A HAVING
clause can not contain:
-
Non-aggregated column expressions that are not in the
GROUP BY
list. -
Column positions.An integer in the
HAVING
clause is just an integer, not a column position. -
Column aliases –- not even if they appear in the
GROUP BY
clause!
Examples
Building on our earlier examples, this could be used to skip small groups of students:
select class,
count(*) as num_boys,
avg(age) as boys_avg_age
from students
where sex = 'M'
group by class
having count(*) >= 5;
To select only groups that have a minimum age spread:
select class,
count(*) as num_boys,
avg(age) as boys_avg_age
from students
where sex = 'M'
group by class
having max(age) - min(age) > 1.2;
Notice that if you’re interested in this information, you’ll likely also include min(age)
and max(age)
— or the expression “max(age) - min(age)
”.
To include only 3rd classes:
select class,
count(*) as num_boys,
avg(age) as boys_avg_age
from students
where sex = 'M'
group by class
having class starting with '3';
Better would be to move this condition to the WHERE
clause:
select class,
count(*) as num_boys,
avg(age) as boys_avg_age
from students
where sex = 'M' and class starting with '3'
group by class;