- 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. |