Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 
 

Oracle SQL query rewriting with temporary tables

Oracle Database Tips by Donald Burleson


End users often don't know how difficult a SQL statement might be to code, and a great example is a simple query 'show me all stores with above average sales?.  This would involve only two tables (a STORE and a SALES table), but it's a simple question with a complex answer.  To answer the question "Show me all stores with above average sales?", we must know:

   - How many stores are there?

   - What are the total sales for each store?

   - What are the total sales for all stores?

Here is the ?university? solution, compact and elegant.  Unfortunately, it's hard to understand and also performs very poorly:

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;

Oracle SQL query rewriting for high performance

But what other options do we have?  Oracle introduced Global Temporary Tables (GTT) for removing complex subqueries and allowing us to materialize the intermediate data that we need to solve a complex problem with SQL. 

Here is the same solution with Create Table As Select (CTAS).  It's is easier to understand, and most important, it runs far faster than the ?University? solution:

drop table store_sales;
drop table store_cnt;
drop table store_qty;

create global temporary table store_qty
on commit preserve rows
as select sum(quantity) all_sales from sales;

create global temporary table store_cnt
on commit preserve rows
as select count(*) nbr_stores from store;

create global temporary table store_sales
on commit preserve rows
as select store_name, sum(quantity) store_sales
from store natural join sales group by store_name;

select store_name, store_sales, all_sales / nbr_stores avg_sales
from store_qty, store_cnt, store_sales
where store_sales > (all_sales / nbr_stores);

For more on CTAS and GTT technology, see my notes:

Oracle SQL99 features also allow us to create intermediate materializations with the new ?WITH? clause.  This code is also far faster than the original ?Unversity? solution:

(Note:  You may find a faster execution plan by using Global Temporary tables, depending on your release of Oracle):

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

 

For more details, see my notes:

 
If you like Oracle tuning, you may enjoy the new book "Oracle Tuning: The Definitive Reference", over 900 pages of BC's favorite tuning tips & scripts. 

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


 

   

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.