WITH
Clause
The WITH clause may be processed as an inline view or resolved as a
temporary table.
The advantage of the latter is that repeated references to the
subquery may be more efficient as the data is easily retrieved from
the temporary table, rather than being requeried by each reference.
You should assess the performance implications of the WITH clause on
a case-by-case basis.
Using the SCOTT schema, for each employee we want to know how many
other people are in their department. Using an inline view we might
do the following.
SELECT e.ename AS
employee_name,
dc.dept_count AS emp_dept_count
FROM emp e,
(SELECT deptno, COUNT(*) AS dept_count
FROM emp
GROUP BY deptno) dc
WHERE e.deptno =
dc.deptno;
EMPLOYEE_N EMP_DEPT_COUNT
---------- --------------
SMITH
5
ALLEN
6
WARD
6
JONES
5
MARTIN
6
BLAKE
6
CLARK
3
SCOTT
5
KING
3
TURNER
6
ADAMS
5
JAMES
6
FORD
5
MILLER
3
Using a WITH clause this would look like the following:
WITH dept_count AS (
SELECT deptno, COUNT(*)
AS dept_count
FROM emp
GROUP BY deptno)
SELECT e.ename AS
employee_name,
dc.dept_count AS emp_dept_count
FROM emp e,
dept_count dc
WHERE e.deptno =
dc.deptno;
EMPLOYEE_N EMP_DEPT_COUNT
---------- --------------
SMITH
5
ALLEN
6
WARD
6
JONES
5
MARTIN
6
BLAKE
6
CLARK
3
SCOTT
5
KING
3
TURNER
6
ADAMS
5
JAMES
6
FORD
5
MILLER
3
The difference seems rather insignificant here.
What if we also want to pull back each employees manager name and
the number of people in the managers department?
Using the inline view it now looks like this.
SELECT e.ename AS
employee_name,
dc1.dept_count AS emp_dept_count,
m.ename AS manager_name,
dc2.dept_count AS mgr_dept_count
FROM emp e,
(SELECT deptno, COUNT(*) AS dept_count
FROM emp
GROUP BY deptno) dc1,
emp m,
(SELECT deptno, COUNT(*) AS dept_count
FROM emp
GROUP BY deptno) dc2
WHERE e.deptno =
dc1.deptno
AND e.mgr =
m.empno
AND m.deptno
= dc2.deptno;
EMPLOYEE_N EMP_DEPT_COUNT
MANAGER_NA MGR_DEPT_COUNT
---------- --------------
---------- --------------
TURNER
6
BLAKE
6
ALLEN
6
BLAKE
6
WARD
6
BLAKE
6
JAMES
6
BLAKE
6
MARTIN
6
BLAKE
6
FORD
5
JONES
5
SCOTT
5
JONES
5
ADAMS
5
SCOTT
5
SMITH
5
FORD
5
MILLER
3
CLARK
3
CLARK
3
KING
3
JONES
5
KING
3
BLAKE
6
KING
3
Using the WITH clause this would look like the following.
WITH dept_count AS (
SELECT deptno, COUNT(*)
AS dept_count
FROM emp
GROUP BY deptno)
SELECT e.ename AS
employee_name,
dc1.dept_count AS emp_dept_count,
m.ename AS manager_name,
dc2.dept_count AS mgr_dept_count
FROM emp e,
dept_count dc1,
emp m,
dept_count dc2
WHERE e.deptno =
dc1.deptno
AND e.mgr =
m.empno
AND m.deptno
= dc2.deptno;
So we don't need to redefine the same subquery multiple times.
Instead we just use the query name defined in the WITH clause,
making the query much easier to read.
If the contents of the WITH clause is sufficiently complex, Oracle
may decide to resolve the result of the subquery into a global
temporary table. This can make multiple references to the subquery
more efficient. The MATERIALIZE and INLINE optimizer hints can be
used to influence the decision. The undocumented MATERIALIZE hint
tells the optimizer to resolve the subquery as a global temporary
table, while the INLINE hint tells it to process the query inline.
WITH dept_count AS (
SELECT /*+ MATERIALIZE
*/ deptno, COUNT(*) AS dept_count
FROM emp
GROUP BY deptno)
SELECT ...
WITH dept_count AS (
SELECT /*+ INLINE */
deptno, COUNT(*) AS dept_count
FROM emp
GROUP BY deptno)
SELECT ...
Even when there is no repetition of SQL, the WITH clause can
simplify complex queries, like the following example that lists
those departments with above average wages.
WITH
dept_costs AS (
SELECT
dname, SUM(sal) dept_total
FROM emp e, dept d
WHERE
e.deptno = d.deptno
GROUP BY
dname),
avg_cost AS (
SELECT
SUM(dept_total)/COUNT(*) avg
FROM dept_costs)
SELECT *
FROM dept_costs
WHERE dept_total >
(SELECT avg FROM avg_cost)
ORDER BY dname;
DNAME
DEPT_TOTAL
-------------- ----------
RESEARCH
10875
In the previous example, the main body of the query is very
simple, with the complexity hidden in the WITH clause.