|
 |
|
Tuning Oracle SQL subqueries
Oracle Database Tips by Donald BurlesonDecember 2, 2015
|
Tuning Oracle SQL subqueries
For a full treatment of tuning Oracle subqueries see my book "Oracle
Tuning: The Definitive Reference", or our
training in advanced SQL
Tuning.
Types of subqueries
A subquery is a condition
where an SQL query is ?nested? or placed inside another SQL query. The ISO
99 SQL standard allows for SQL queries to be embedded inside other SQL
statements in several ways.
?
SQL queries can be placed inside the SELECT clause (scalar
subqueries)
?
inside the FROM clause (in-line views), and
?
inside the WHERE clause (basic subqueries).
Subqueries can be used
almost any place where an expression can be used, but for tuning purposes,
consider a divide and conquer approach using separate queries:
?
CASE expressions
?
SELECT statements
?
VALUES clauses of INSERT statements
?
WHERE clauses
?
ORDER BY clauses
In general, you can
tune subqueries with subquery un-nesting and some use the WITH clause or global
temporary tables to tune subqueries.
General subquery tuning tips
Subquery performance has
always been problematic for Oracle queries, and Oracle introduced global
temporary tables to allow subqueries to be executed independently of the outer
query, a powerful technique where you can hypercharge Oracle performance by
re-writing subqueries to use temporary tables
But there are other ways to
un-nest subqueries and starting with Oracle 9i, Oracle will automatically
un-nest some sub-queries:
Assuming no restrictions
exist, the optimizer automatically unnests some (but not all) of the
following nested subqueries:
- Uncorrelated IN
subqueries
- IN and EXISTS
correlated subqueries, as long as they do not contain aggregate
functions or a GROUP BY clause
Note:
Prior to Oracle10g there was a bug that caused a huge
execution difference between EXISTS and IN. Starting in 10g release 2
and beyond, Oracle \will automatically rewrite an IN subquery to use the
EXISTS clause.
Assuming no restrictions exist, the
optimizer automatically un-nests some (but not all) of the following nested
subqueries:
-
Uncorrelated IN subqueries
-
IN and EXISTS correlated
subqueries, as long as they do not contain aggregate functions or a
GROUP BY clause
You can enable extended subquery
unnesting by instructing the optimizer to unnest additional types of
subqueries:
-
You can unnest an uncorrelated NOT
IN subquery by specifying the HASH_AJ or MERGE_AJ hint in the subquery.
-
You can unnest other subqueries by
specifying the UNNEST hint in the subquery.
Correlated & noncorrelated subquery tuning
A correlated subquery is
a query whereby the key in the subquery is correlated (using the = operator)
with a column that is selected in the outer query.
A noncorrelated subquery is a
query where the subquery executes independently of the outer query, passing a
result set to the outer query at the end of its execution.
Noncorrelated subqueries
are commonly seen when using the IN, NOT IN, EXISTS, and NOT EXISTS SQL clauses.
A NOT IN subquery:
select
author_last_name
from
author
where
author_key not in
(select author_key from
book_author);
It is not documented, but Oracle can sometimes use an anti-join access path
when using a NOT EXISTS clause.
Tuning by re-writing subqueries
?
Subqueries can often be re-written for faster performance to use a standard outer join,
resulting in faster performance.
?
The WITH clause and global temporary tables can replace subqueries.
Here we tune a subquery by
replacing it with an outer join and a null test:
select
b.book_key
from
book b,
sales s
where
b.book_key = s.book_key(+)
and
s.book_key IS NULL;
Pubs sub-query is less
efficient:
select
e.emp_last_name,
to_char(round((emp_salary/t.totsal)*100,1),'99.9')||'%'
from
emp e,
(select sum(emp_salary) totsal from emp) t;
Subquery is tuned with
a global
temporary table:
create table t1 as
select sum(emp_salary) totsal from emp;
select
e.emp_last_name,
to_char(round((emp_salary/t.totsal)*100,1),'99.9')||'%'
from
emp e,
t1 t;
Tuning anti-join subqueries
In some cases an anti-join (NOT IN, NOT
EXISTS) can be addressed with separate queries using the MINUS operator.
In the absence of an anti-join access path Oracle will usually scan the
first table and execute the subquery as a filter operation once for each
candidate row.
Qualifying NOT IN clauses tend to have
plans that include an anti-join access path.
-
Qualifying NOT EXISTS clauses tend
to get anti-join access paths less frequently. So, if you want an
Anti-join, try a NOT IN instead of a NOT EXISTS or use a hint.
-
In the absence of an anti-join
access path Oracle will usually scan the first table and execute the
subquery as a filter operation once for each candidate row.
If the subquery of a NOT IN clause
returns at least one row with a null value, the entire NOT IN clause
evaluates to false for all rows. This might seem like a bug, but it's not.
You can make NOT IN treat nulls like NOT EXISTS by adding an extra predicate
to the subquery ?AND column IS NOT NULL?.
It is not documented, but Oracle can
sometimes use an anti-join access path when using a NOT EXISTS clause.
Consider the impact on indexing if the
subquery of a NOT IN clause is capable of retrieving a null values. (You
have to use a NVL function, which can disable index usage). If you don't use
an explicit NVL call, Oracle will add it for you implicitly!
Oracle provides the HASH_AJ, MERGE_AJ,
and NL_AJ hints for you to apply to the subquery of a NOT EXISTS or NOT IN
clause to tell Oracle which anti-join access path to use.
Tuning Oracle semi-join
subqueries
Semi-joins are written using EXISTS or
IN, and you could write the query using a regular join:
select
distinct store_name
from
store,
sales
where
sales.store_key=store.store_key
and
quantity > 5000;
Or you can write it using a semi-join!
This query will do less work than the previous one.
Select
store_name
from
store
Where exists
(select * from sales where
sales.store_key=store.store_key And Quantity > 5000);
In this case Oracle will stop processing each store, as soon as the first
sale in the sales key for that store is found. Oracle can perform a
semi-join in a few different ways:
-
Semi-join access path.
-
Conventional join access path followed by a sort to remove duplicate
rows.
-
Scan
of first table with a filter operation against the second table.
Also, for semi-join tuning remember
that
Oracle
transforms the subquery into a join if at all possible.
Oracle
does not consider cost when deciding whether or not to do this
transformation. If the path Oracle is taking doesn't seem the best
path, then you can apply the HASH_SJ, MERGE_SJ, and NL_SJ hints to the
subquery of an EXISTS or IN clause to tell Oracle which semi-join access
path to use. When you see large Cartesian products in your
execution plans, this can be a sign that an semi-join is needed.
Related SQL subquery tuning notes:
 |
If you like Oracle tuning, you
might enjoy my book "Oracle
Tuning: The Definitive Reference", with 950 pages of tuning tips and
scripts.
You can buy it direct from the publisher for 30%-off and get instant
access to the code depot of Oracle tuning scripts. |
|