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 


 

 

 


 

 

 
 

Benchmark showing the difference in performance of  complex SQL subqueries rewritten with intermediate tables

Oracle Database Tips by Donald BurlesonAugust 29,  2015

See here, how to re-write complex SQL using temporary tables and the WITH clause.

Hypercharging SQL by restructuring complex queries using intermediate results

Here is an actual performance comparison of equivalent queries:
SQL> --*********************************************
SQL> -- Using subqueries
SQL> --*********************************************
SQL>
SQL> select
  2       store_name,
  3       sum(quantity)                                                  store_sales,
  4       (select sum(quantity) from sales)/(select count(*) from store) avg_sales
  5  from
  6       store  s,
  7       sales  sl
  8  where
  9       s.store_key = sl.store_key
 10  having
 11       sum(quantity) > (select sum(quantity) from sales)/(select count(*) from store)
 12  group by
 13       store_name
 14  ;
                                                                                            
                                                                                                                        
----------------------------------------------------------------------------------------------                         
| Id  | Operation                      | Name        | Rows  | Bytes | Cost (%CPU)| Time     |                         
----------------------------------------------------------------------------------------------                         
|   0 | SELECT STATEMENT               |             |     1 |    31 |     4  (25)| 00:00:01 |                         
|   1 |  SORT AGGREGATE                |             |     1 |     4 |            |          |                         
|   2 |   TABLE ACCESS FULL            | SALES       |   100 |   400 |     2   (0)| 00:00:01 |                         
|   3 |    SORT AGGREGATE              |             |     1 |       |            |          |                         
|   4 |     INDEX FULL SCAN            | SYS_C003999 |    10 |       |     1   (0)| 00:00:01 |                         
|*  5 |  FILTER                        |             |       |       |            |          |                         
|   6 |   HASH GROUP BY                |             |     1 |    31 |     4  (25)| 00:00:01 |                         
|   7 |    NESTED LOOPS                |             |   100 |  3100 |     3   (0)| 00:00:01 |                         
|   8 |     TABLE ACCESS FULL          | SALES       |   100 |   900 |     2   (0)| 00:00:01 |                          
|   9 |     TABLE ACCESS BY INDEX ROWID| STORE       |     1 |    22 |     1   (0)| 00:00:01 |                         
|* 10 |      INDEX UNIQUE SCAN         | SYS_C003999 |     1 |       |     0   (0)| 00:00:01 |                          
|  11 |   SORT AGGREGATE               |             |     1 |     4 |            |          |                         
|  12 |    TABLE ACCESS FULL           | SALES       |   100 |   400 |     2   (0)| 00:00:01 |                         
|  13 |     SORT AGGREGATE             |             |     1 |       |            |          |                         
|  14 |      INDEX FULL SCAN           | SYS_C003999 |    10 |       |     1   (0)| 00:00:01 |                         
----------------------------------------------------------------------------------------------                         
                                                                                                                       
                                                                                       
        113  consistent gets                                                                                           
 

SQL> --*********************************************
SQL> -- Using CTAS
SQL> --*********************************************
 
SQL> create table t1 as select sum(quantity) all_sales from sales;
 
Table created.
 
SQL> create table t2 as select count(*) nbr_stores from store;
 
Table created.
 
SQL> create table t3 as select store_name, sum(quantity) store_sales from store natural join sales group by store_name;
 
Table created.
 
SQL>
SQL> select
  2    store_name
  3    from
  4    t1,
  5    t2,
  6    t3
  7    where
  8    store_sales > (all_sales / nbr_stores);
                                                                                     
                                                                                                                        
------------------------------------------------------------------------------                                         
| Id  | Operation             | Name | Rows  | Bytes | Cost (%CPU)| Time     |                                         
------------------------------------------------------------------------------                                         
|   0 | SELECT STATEMENT      |      |     1 |    61 |     6   (0)| 00:00:01 |                                         
|   1 |  NESTED LOOPS         |      |     1 |    61 |     6   (0)| 00:00:01 |                                         
|   2 |   MERGE JOIN CARTESIAN|      |     1 |    26 |     4   (0)| 00:00:01 |                                         
|   3 |    TABLE ACCESS FULL  | T1   |     1 |    13 |     2   (0)| 00:00:01 |                                         
|   4 |    BUFFER SORT        |      |     1 |    13 |     2   (0)| 00:00:01 |                                          
|   5 |     TABLE ACCESS FULL | T2   |     1 |    13 |     2   (0)| 00:00:01 |                                         
|*  6 |   TABLE ACCESS FULL   | T3   |     1 |    35 |     2   (0)| 00:00:01 |                                          
------------------------------------------------------------------------------                                         
                                                                                                                                                                                                      
         30  consistent gets             
     

 
SQL> --*********************************************
SQL> -- Using the WITH clause
SQL> --*********************************************
SQL>
SQL> with
  2  number_stores as
  3       (select count(*) nbr_stores from store),
  4  total_sales as
  5       (select sum(quantity) all_sales from sales),
  6  store_sales as
  7       (select store_name, sum(quantity) sales from store natural join sales group by store_name)
  8  select
  9       store_name
 10  from
 11       number_stores,
 12       total_sales,
 13       store_sales
 14  where
 15       sales > (all_sales / nbr_stores);
                                                                                      
                                                                                                                       
-----------------------------------------------------------------------------------------------                        
| Id  | Operation                       | Name        | Rows  | Bytes | Cost (%CPU)| Time     |                        
-----------------------------------------------------------------------------------------------                        
|   0 | SELECT STATEMENT                |             |     1 |    61 |     7  (15)| 00:00:01 |                        
|   1 |  NESTED LOOPS                   |             |     1 |    61 |     7  (15)| 00:00:01 |                        
|   2 |   NESTED LOOPS                  |             |     1 |    26 |     3   (0)| 00:00:01 |                        
|   3 |    VIEW                         |             |     1 |    13 |     1   (0)| 00:00:01 |                        
|   4 |     SORT AGGREGATE              |             |     1 |       |            |          |                        
|   5 |      INDEX FULL SCAN            | SYS_C003999 |    10 |       |     1   (0)| 00:00:01 |                        
|   6 |    VIEW                         |             |     1 |    13 |     2   (0)| 00:00:01 |                        
|   7 |     SORT AGGREGATE              |             |     1 |     4 |            |          |                        
|   8 |      TABLE ACCESS FULL          | SALES       |   100 |   400 |     2   (0)| 00:00:01 |                        
|*  9 |   VIEW                          |             |     1 |    35 |     4  (25)| 00:00:01 |                        
|  10 |    SORT GROUP BY                |             |    10 |   310 |     4  (25)| 00:00:01 |                        
|  11 |     NESTED LOOPS                |             |   100 |  3100 |     3   (0)| 00:00:01 |                        
|  12 |      TABLE ACCESS FULL          | SALES       |   100 |   900 |     2   (0)| 00:00:01 |                        
|  13 |      TABLE ACCESS BY INDEX ROWID| STORE       |     1 |    22 |     1   (0)| 00:00:01 |                        
|* 14 |       INDEX UNIQUE SCAN         | SYS_C003999 |     1 |       |     0   (0)| 00:00:01 |                        
-----------------------------------------------------------------------------------------------                        
                                                                                                                       
                                                                                          
        109  consistent gets      





 

 

��  
 
 
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 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational