BC remote Oracle DBA - Call (800) 766-1884  
Oracle Consulting Oracle Training Development

Remote DBA

Remote DBA Plans  

Remote DBA Service

Remote DBA RAC

   
Remote DBA Oracle Home
Remote DBA Oracle Training
Remote DBA SQL Tuning Consulting
Remote DBA Oracle Tuning Consulting
Remote DBA Data Warehouse Consulting
Remote DBA Oracle Project Management
Remote DBA Oracle Security Assessment
Remote DBA Unix Consulting
Burleson Books
Burleson Articles
Burleson Web Courses
Burleson Qualifications
Oracle Links
Remote DBA Oracle Monitoring
Remote DBA Support Benefits
Remote DBA Plans & Prices
Our Automation Strategy
What We Monitor
Oracle Apps Support
Print Our Brochure
Contact Us (e-mail)
Oracle Job Opportunities
Oracle Consulting Prices





   

 

 

 

Remote DBA services

Remote DBA Support

Remote DBA RAC

Remote DBA Reasons

Remote Oracle Tuning

Remote DBA Links

Oracle DBA Support

Oracle DBA Forum

Oracle Disaster

Oracle Training

Oracle Tuning

Oracle Training

 Remote DBA SQL Server

Remote MSSQL Consulting

Oracle DBA Hosting

Oracle License Negotiation

 

 


 

 

 

 

 
 

Oracle WITH clause to simplify complex SQL



Oracle Tips by Burleson Consulting

Using the WITH clause to simplify complex SQL

Oracle SQL can run faster when complex subqueries are replaced with global temporary tables.  Starting in Oracle9i release 2, there was an incorporation of a subquery factoring utility implemented the SQL-99 WITH clause.  The WITH clause is a tool for materializing subqueries to save Oracle from having to recompute them multiple times.

Also see these notes:

Use of the SQL WITH clause is very similar to the use of Global Temporary Tables (GTT), a technique that is often employed to improve query speed for complex subqueries.  The following are some important notes about the Oracle WITH clause:

§       The SQL WITH clause only works on Oracle 9i release 2 and beyond.

§       Formally, the WITH clause was called subquery factoring.

§       The SQL WITH clause is used when a subquery is executed multiple times.

§       The ANSI WITH clause is also useful for recursive queries, but this feature has not yet been implemented in Oracle SQL.

The following example shows how the Oracle SQL WITH clause works and see how the WITH clause and Global temporary tables can be used to speed up Oracle queries.

All Stores with above average sales

To keep it simple, the following example only references the aggregations once, where the SQL WITH clause is normally used when an aggregation is referenced multiple times in a query. 

The following is an example of a request to see the names of all stores with above average sales.  For each store, the average sales must be compared to the average sales for all stores:

 

The relationship between STORE and SALES

Essentially, the query below accesses the STORE and SALES tables, comparing the sales for each store with the average sales for all stores.  To answer this query, the following information must be available:

§       The total sales for all stores.

§       The number of stores.

§       The sum of sales for each store.

To answer this in a single SQL statement, inline views will be employed along with a subquery inside a HAVING clause:

select
   store_name,
   sum(quantity)                                                  store_sales,
   (select sum(quantity) from sales)/(select count(*) from store) avg_sales
from
   store  s,
   sales  sl
where
   s.store_key = sl.store_key
having
   sum(quantity) > (select sum(quantity) from sales)/(select count(*) from store)
group by
   store_name
;

While this query provides the correct answer, it is difficult to read and complex to execute as it is recomputing the sum of sales multiple times. 

To prevent the unnecessary re-execution of the aggregation (sum(sales)), temporary tables could be created and used to simplify the query. The following steps should be followed:

  • 1.      Create a table named T1 to hold the total sales for all stores.

  • 2.      Create a table named T2 to hold the number of stores. 

  • 3.      Create a table named T3 to hold the store name and the sum of sales for each store.

A fourth SQL statement that uses tables T1, T2, and T3 to replicate the output from the original query should then be written.  The final result will look like this:

create table t1 as
select sum(quantity) all_sales from stores;
 
create table t2 as
select count(*) nbr_stores from stores
 
create table t3 as
select store_name, sum(quantity) store_sales from store natural join sales;
 
 
select
   store_name
from
   t1,
   t2,
   t3
where
   store_sales > (all_sales / nbr_stores)
;

While this is a very elegant solution and easy to understand and has a faster execution time, the SQL-99 WITH clause can be used instead of temporary tables.  The Oracle SQL WITH clause will compute the aggregation once, give it a name, and allow it to be referenced, perhaps multiple times, later in the query.

The SQL-99 WITH clause is very confusing at first because the SQL statement does not begin with the word SELECT.  Instead, the WITH clause is used to start the SQL query, defining the aggregations, which can then be named in the main query as if they were real tables:

WITH
   subquery_name
AS
  (the aggregation SQL statement)
SELECT
  (query naming subquery_name);

 

Retuning to the oversimplified example, the temporary tables should be replaced with the SQL WITH clause:

WITH
  sum_sales      AS
      select /*+ materialize */
      sum(quantity) all_sales from stores
  number_stores  AS
      select /*+ materialize */ 
      count(*) nbr_stores from stores;
  sales_by_store AS
      select /*+ materialize */
      store_name, sum(quantity) store_sales from
      store natural join sales
SELECT
   store_name
FROM
   store,
   sum_sales,
   number_stores,
   sales_by_store
WHERE
   store_sales > (all_sales / nbr_stores)
;

Note the use of the Oracle undocumented materialize hint in the WITH clause.  The Oracle materialize hint is used to ensure that the Oracle CBO materializes the temporary tables that are created inside the WITH clause, and its opposite is the undocumented inline hint.  This is not necessary in Oracle10g, but it helps ensure that the tables are only created one time.

Tip!  Depending on the release of Oracle in use, the global temporary tables (GTT) might be a better solution than the WITH clause because indexes can be created on the GTT for faster performance.

SEE CODE DEPOT FOR FULL SCRIPTS


This is an excerpt from my latest book "Oracle Tuning: The Definitive Reference". 

You can buy it direct from the publisher for 50%-off and get instant access to the code depot of Oracle tuning scripts:

http://www.rampant-books.com/book_1002_oracle_tuning_definitive_reference_2nd_ed.htm

 


Expert Remote DBA

BC is America's oldest and largest Remote DBA Oracle support provider.  Get real Remote DBA experts, call
BC Remote DBA today.

 

 

Remote DBA Service
 

Oracle Tuning Book

 

Advance SQL Tuning Book 

BC Oracle support

Oracle books by Rampant

Oracle monitoring software

 

 

 

 

 

 

BC Remote Oracle Support

Remote DBA

Remote DBA Services

Copyright © 1996 -  2013 by Burleson. All rights reserved.

Oracle® is the registered trademark of Oracle Corporation.



Hit Counter