Full partition-wise joins can occur if two tables that are co-partitioned on the same key are joined in a query. The tables can be co-partitioned at the partition level, or at the subpartition level, or at a combination of partition and subpartition levels. Reference partitioning is an easy way to guarantee co-partitioning. Full partition-wise joins can be executed serially and in parallel.
For more information about partition-wise joins, refer to Partitioning for Availability, Manageability, and Performance.
The following example shows a full partition-wise join on the orders
and order_items
tables, in which the order_items
table is reference-partitioned.
CREATE TABLE orders ( order_id NUMBER(12) NOT NULL , order_date DATE NOT NULL , order_mode VARCHAR2(8) , order_status VARCHAR2(1) , CONSTRAINT orders_pk PRIMARY KEY (order_id) ) PARTITION BY RANGE (order_date) ( PARTITION p_before_jan_2006 VALUES LESS THAN (TO_DATE('01-JAN-2006','dd-MON-yyyy')) , PARTITION p_2006_jan VALUES LESS THAN (TO_DATE('01-FEB-2006','dd-MON-yyyy')) , PARTITION p_2006_feb VALUES LESS THAN (TO_DATE('01-MAR-2006','dd-MON-yyyy')) , PARTITION p_2006_mar VALUES LESS THAN (TO_DATE('01-APR-2006','dd-MON-yyyy')) , PARTITION p_2006_apr VALUES LESS THAN (TO_DATE('01-MAY-2006','dd-MON-yyyy')) , PARTITION p_2006_may VALUES LESS THAN (TO_DATE('01-JUN-2006','dd-MON-yyyy')) , PARTITION p_2006_jun VALUES LESS THAN (TO_DATE('01-JUL-2006','dd-MON-yyyy')) , PARTITION p_2006_jul VALUES LESS THAN (TO_DATE('01-AUG-2006','dd-MON-yyyy')) , PARTITION p_2006_aug VALUES LESS THAN (TO_DATE('01-SEP-2006','dd-MON-yyyy')) , PARTITION p_2006_sep VALUES LESS THAN (TO_DATE('01-OCT-2006','dd-MON-yyyy')) , PARTITION p_2006_oct VALUES LESS THAN (TO_DATE('01-NOV-2006','dd-MON-yyyy')) , PARTITION p_2006_nov VALUES LESS THAN (TO_DATE('01-DEC-2006','dd-MON-yyyy')) , PARTITION p_2006_dec VALUES LESS THAN (TO_DATE('01-JAN-2007','dd-MON-yyyy')) ) PARALLEL; CREATE TABLE order_items ( order_id NUMBER(12) NOT NULL , product_id NUMBER NOT NULL , quantity NUMBER NOT NULL , sales_amount NUMBER NOT NULL , CONSTRAINT order_items_orders_fk FOREIGN KEY (order_id) REFERENCES orders(order_id) ) PARTITION BY REFERENCE (order_items_orders_fk) PARALLEL;
A typical data warehouse query would scan a large amount of data. In the underlying execution plan, the columns Rows
, Bytes
, Cost (%CPU)
, Time
, and TQ
have been removed.
EXPLAIN PLAN FOR SELECT o.order_date , sum(oi.sales_amount) sum_sales FROM orders o , order_items oi WHERE o.order_id = oi.order_id AND o.order_date BETWEEN TO_DATE('01-FEB-2006','DD-MON-YYYY') AND TO_DATE('31-MAY-2006','DD-MON-YYYY') GROUP BY o.order_id , o.order_date ORDER BY o.order_date; --------------------------------------------------------------------------------------------- | Id | Operation | Name | Pstart| Pstop |IN-OUT| PQ Distrib | --------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | | | | | | 1 | PX COORDINATOR | | | | | | | 2 | PX SEND QC (ORDER) | :TQ10001 | | | P->S | QC (ORDER) | | 3 | SORT GROUP BY | | | | PCWP | | | 4 | PX RECEIVE | | | | PCWP | | | 5 | PX SEND RANGE | :TQ10000 | | | P->P | RANGE | | 6 | SORT GROUP BY | | | | PCWP | | | 7 | PX PARTITION RANGE ITERATOR| | 3 | 6 | PCWC | | |* 8 | HASH JOIN | | | | PCWP | | |* 9 | TABLE ACCESS FULL | ORDERS | 3 | 6 | PCWP | | | 10 | TABLE ACCESS FULL | ORDER_ITEMS | 3 | 6 | PCWP | | --------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 8 - access("O"."ORDER_ID"="OI"."ORDER_ID") 9 - filter("O"."ORDER_DATE"<=TO_DATE(' 2006-05-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))