The post list a simple example of updating a table.
Updating without any hints
No surprise here, a simple full table scan happens.
SQL> update bigtable set OBJECT_TYPE='abc'; Execution Plan ---------------------------------------------------------- Plan hash value: 898092282 ------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------- | 0 | UPDATE STATEMENT | | 9854 | 78832 | 50 (2)| 00:00:01 | | 1 | UPDATE | BIGTABLE | | | | | | 2 | TABLE ACCESS FULL| BIGTABLE | 9854 | 78832 | 50 (2)| 00:00:01 | -------------------------------------------------------------------------------Updating with parallel hint
Only the query portion gets parallelized.
SQL> update /*+ parallel */ bigtable set OBJECT_TYPE='abc'; Execution Plan ---------------------------------------------------------- Plan hash value: 1905498248 --------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | --------------------------------------------------------------------------------------------------------------- | 0 | UPDATE STATEMENT | | 9854 | 78832 | 27 (0)| 00:00:01 | | | | | 1 | UPDATE | BIGTABLE | | | | | | | | | 2 | PX COORDINATOR | | | | | | | | | | 3 | PX SEND QC (RANDOM)| :TQ10000 | 9854 | 78832 | 27 (0)| 00:00:01 | Q1,00 | P->S | QC (RAND) | | 4 | PX BLOCK ITERATOR | | 9854 | 78832 | 27 (0)| 00:00:01 | Q1,00 | PCWC | | | 5 | TABLE ACCESS FULL| BIGTABLE | 9854 | 78832 | 27 (0)| 00:00:01 | Q1,00 | PCWP | | --------------------------------------------------------------------------------------------------------------- Note ----- - automatic DOP: Computed Degree of Parallelism is 2 - PDML is disabled in current sessionThe notes indicate Auto DOP of 2 was used but parallel DML (PDML) was not used.
Updating with enable parallel dml hint
SQL> update /*+ ENABLE_PARALLEL_DML */ bigtable set OBJECT_TYPE='abc'; Execution Plan ---------------------------------------------------------- Plan hash value: 898092282 ------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------- | 0 | UPDATE STATEMENT | | 9854 | 78832 | 50 (2)| 00:00:01 | | 1 | UPDATE | BIGTABLE | | | | | | 2 | TABLE ACCESS FULL| BIGTABLE | 9854 | 78832 | 50 (2)| 00:00:01 | ------------------------------------------------------------------------------- Note ----- - PDML disabled because object is not decorated with parallel clauseNothing is parallelized. Reason is mentioned in the notes "object is not decorated with parallel clause".
Updating with enable parallel dml and parallel hint
SQL> update /*+ ENABLE_PARALLEL_DML parallel */ bigtable set OBJECT_TYPE='abc'; Execution Plan ---------------------------------------------------------- Plan hash value: 1693571574 --------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | --------------------------------------------------------------------------------------------------------------- | 0 | UPDATE STATEMENT | | 9854 | 78832 | 27 (0)| 00:00:01 | | | | | 1 | PX COORDINATOR | | | | | | | | | | 2 | PX SEND QC (RANDOM) | :TQ10000 | 9854 | 78832 | 27 (0)| 00:00:01 | Q1,00 | P->S | QC (RAND) | | 3 | UPDATE | BIGTABLE | | | | | Q1,00 | PCWP | | | 4 | PX BLOCK ITERATOR | | 9854 | 78832 | 27 (0)| 00:00:01 | Q1,00 | PCWC | | | 5 | TABLE ACCESS FULL| BIGTABLE | 9854 | 78832 | 27 (0)| 00:00:01 | Q1,00 | PCWP | | --------------------------------------------------------------------------------------------------------------- Note ----- - automatic DOP: Computed Degree of Parallelism is 2Update statement now sits under the parallel coordinator. Notes indicate degree of parallelism used.
The degree of parallelism could be explicitly stated in the parallel clause along with the enable parallel dml.
SQL> update /*+ ENABLE_PARALLEL_DML parallel(4) */ bigtable set OBJECT_TYPE='abc'; Execution Plan ---------------------------------------------------------- Plan hash value: 1693571574 --------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | --------------------------------------------------------------------------------------------------------------- | 0 | UPDATE STATEMENT | | 9854 | 78832 | 14 (0)| 00:00:01 | | | | | 1 | PX COORDINATOR | | | | | | | | | | 2 | PX SEND QC (RANDOM) | :TQ10000 | 9854 | 78832 | 14 (0)| 00:00:01 | Q1,00 | P->S | QC (RAND) | | 3 | UPDATE | BIGTABLE | | | | | Q1,00 | PCWP | | | 4 | PX BLOCK ITERATOR | | 9854 | 78832 | 14 (0)| 00:00:01 | Q1,00 | PCWC | | | 5 | TABLE ACCESS FULL| BIGTABLE | 9854 | 78832 | 14 (0)| 00:00:01 | Q1,00 | PCWP | | --------------------------------------------------------------------------------------------------------------- Note ----- - Degree of Parallelism is 4 because of hint