A scalar subquery returns
one value for one column. As such, it is useful for aggregate queries.
Here is an example of
a scalar subquery in the HAVING clause.
The example uses the
Employees and Depts tables that were used in Examples of Correlated Subqueries.select dept, count(emp_name)
from mybase.employees e
group by dept
having dept in (select deptno from mybase.depts);
It is a simple request:
count the number of employees in the Employees table, group the count
by department, and return information only about departments having
a matching value in the Deptno column of the Depts table.
Number of Employees by Department
Here is an example of
a scalar subquery that is specified in the SELECT statement.
select d.deptno,
d.deptname,
d.manager,
(select count (*) from employees e
where e.dept = d.deptno and
e.pos <> 'Manager') as Employees
from depts d;
The subquery counts
the number of records in the Employees table, removes employee records
that belong to managers, and then returns an aggregate value for each
department code that has a match in both tables. That is, one value
is returned for each department. It is also a correlated subquery.
Number of Employees by Manager
Here is an example of
a scalar subquery in the WHERE clause:
select *
from depts d
where (select COUNT(*) FROM employees e
WHERE d.deptno = e.dept
and e.pos <> 'Manager') > 1;
As in the previous example,
the subquery counts all of the rows in Employees table minus those
that describe a manager and correlates them to the DeptNo column of
the Depts table. However, the WHERE clause further qualifies the query
to retrieve information only about departments that have more than
one employee.
Departments with More Than One Employee
Here is an example of
a scalar subquery in the INSERT statement. This example uses data
from the Densities example table, which has a column named Population.
A new table, Summary, is created and populated with aggregated values
from Densities table’s Population column.
For more information
about the Densities table, see Densities.
create table summary (
sum_pop double having format comma12.,
max_pop double having format comma12.,
min_pop double having format comma12.,
avg_pop double having format comma12.
);
insert into summary (
sum_pop,
max_pop,
min_pop,
avg_pop)
values (
(select sum(population) from densities),
(select max(population) from densities),
(select min(population) from densities),
(select avg(population) from densities)
);
select * from summary;
Each subquery in the
INSERT statement is a scalar subquery. Each subquery returns one value
(the sum, maximum, minimum, and average values) from the data in one
column, Population, to populate the new table.
Content of the Summary Table