Monday Jul 22, 2013

Follow up on "Same Select..."

A follow up on the case of "Same SELECT used in an INSERT has different Execution Plan"

The query has the following predicate :

CH.CONTACTDATETIME > SYSDATE-5

The testcase I have has table,column,index statistics from 27-jun-2013.

If I run *today* the insert with the SYSDATE clause on my testcase with stats from 27-jun-2013 then I get a very poor cardinality estimation on access to CH because the stats reflect data there is little or no data present from after 27-jun-2013. This makes the CBO choose a poor execution plan, which is the one with only one DTP.
If in contrast I change the query to have :

CH.CONTACTDATETIME>to_date('22-JUN-13')

Then the cardinality estimation is closer to reality and the CBO chooses the better execution plan than has DISTINCT PLACEMENT transformation in step 7 and 15, where before it was only happening in step 7.

-----------------------------------------------------------------
Id|Operation                        |Name            |Rows |Cost
-----------------------------------------------------------------
 0|INSERT STATEMENT                |                 |     | 313K
 1|LOAD TABLE CONVENTIONAL         |                 |     |    
 2| HASH JOIN OUTER                |                 |   2 | 313K
 3|  VIEW                          |                 |   1 |2771
 4|   SORT UNIQUE                  |                 |   1 |2771
 5|    NESTED LOOPS                |                 |     |    
 6|     NESTED LOOPS               |                 |   1 |2770
 7|      VIEW                      |VW_DTP_BD4C95A1  | 524 |2238
 8|       SORT UNIQUE              |                 | 524 |2238
 9|        TABLE ACCESS FULL       |DL               | 636K|1776
10|      INDEX RANGE SCAN          |I_T              |   1 |   2
11|     TABLE ACCESS BY INDEX ROWID|T                |   1 |   2
12|  VIEW                          |                 |1940 | 310K
13|   SORT UNIQUE                  |                 |1940 | 310K
14|    HASH JOIN                   |                 |1940 | 310K
15|     VIEW                       |VW_DTP_22D53B8E  | 524 |2238
16|      SORT UNIQUE               |                 | 524 |2238
17|       TABLE ACCESS FULL        |DL               | 636K|1776
18|     PARTITION RANGE ITERATOR   |                 |1728K| 307K
19|      TABLE ACCESS FULL         |CH               |1728K| 307K
----------------------------------------------------------------- 


Since the query relies heavily on that SYSDATE predicate then there are a couple of possible options :

1) Use SQL Plan Management to fix the execution plan to have the DTP in step 7 and 15.
2) Before executing the insert, make sure the table CH has fresh statistics that reflect the latest data inserted in the table.
    For example, If this is done daily then you will have to do it daily.

Thursday Jul 18, 2013

Migrated Rows and PDML

Recently I have seen a raising trend of issues about chained rows so this post is to show a not so obvious side effect. 
I see no reason to explain what a chained row is and examples of them as in the internet there are very good postings that talk about them
Migrated Rows is just a special case of chained rows.
I am going to use a similar testcase as the article to show my point.
Similar table, just bigger columns as the standard block size nowdays is 8k.

EMB11203> cat setup.sql
drop table  row_mig_chain_demo;
CREATE TABLE row_mig_chain_demo (
  x int PRIMARY KEY,
  a CHAR(2000),
  b CHAR(2000),
  c CHAR(2000),
  d CHAR(2000),
  e CHAR(2000)
);
EMB11203> cat data.sql
var pk number;
begin
 select nvl(max(x),0) into :pk from row_mig_chain_demo;
end;
/
Prompt just in case I want to add more, I just re-execute the script.
INSERT INTO row_mig_chain_demo (x)
select rownum+:pk from dual connect by rownum <= 100;
COMMIT;
Prompt migrate the rows.
UPDATE row_mig_chain_demo SET a = rownum, b = rownum, c = rownum;
commit;
analyze table ROW_MIG_CHAIN_DEMO compute statistics;

The script creates 100 rows and migrates 99 of them

SQL> select  table_name,num_rows,blocks,CHAIN_CNT
  2  from user_tables where table_name='ROW_MIG_CHAIN_DEMO';
TABLE_NAME                       NUM_ROWS     BLOCKS  CHAIN_CNT
------------------------------ ---------- ---------- ----------
ROW_MIG_CHAIN_DEMO                    100        103         99


So, first interesting thing. Why I used ANALYZE instead of DBMS_STATS ?
Because DBMS_STATS does not collect CHAIN_CNT.
In May 2008 an internal bug was opened to request that DBMS_STATS collects CHAIN_CNT and it is still waiting to be implemented, so while I wait I'll use ANALYZE to collect it.
The CBO was enhanced in 10.2.0.3 to take CHAIN_CNT in its cost calculations so if you feel that it would be good for DBMS_STATS to implement the collection of CHAIN_CNT drop Optimizer Development a line 
Second, why 99 and not all were migrated ?
because the update on the first row updated only 3 columns with combined length of 6000 which still fits in the block.

The insert placed all the rows in the same block and the update migrated the rest.
The following query shows that the head piece is still in the same block.

set pagesize 200 lines 180
select x,DBMS_ROWID.ROWID_RELATIVE_FNO (rowid) , dbms_rowid.ROWID_BLOCK_NUMBER (rowid)
from row_mig_chain_demo
order by 2,3
         X DBMS_ROWID.ROWID_RELATIVE_FNO(ROWID) DBMS_ROWID.ROWID_BLOCK_NUMBER(ROWID)
---------- ------------------------------------ ------------------------------------
         1                                    4                               248213
         2                                    4                               248213
         3                                    4                               248213
...         
       100                                    4                               248213         

A block dump shows all but the first row to be migrated.

Start dump data blocks tsn: 4 file#:4 minblk 248213 maxblk 248215
Block dump from cache:
Dump of buffer cache at level 4 for tsn=4 rdba=17025429
BH (0x6a3884b8) file#: 4 rdba: 0x0103c995 (4/248213) class: 1 ba: 0x6bcc4000
...
===============
tsiz: 0x1f98
hsiz: 0xda
pbl: 0x2b017976ba64
     76543210
flag=--------
ntab=1
nrow=100                               <-- 100 rows.
...
block_row_dump:
tab 0, row 0, @0x5c1
tl: 6015 fb: --H-FL-- lb: 0x1  cc: 4   <-- Head, First and Last Piece
...
tab 0, row 1, @0x5b8
tl: 9 fb: --H----- lb: 0x1  cc: 0      <-- Only the head
nrid:  0x0103c996.0                    <-- Where is the next piece.
tab 0, row 2, @0x5af
tl: 9 fb: --H----- lb: 0x1  cc: 0
nrid:  0x0103c997.0
....
tab 0, row 99, @0x246
tl: 9 fb: --H----- lb: 0x1  cc: 0
nrid:  0x0103ed84.0
end_of_block_dump
Dump of buffer cache at level 4 for tsn=4 rdba=17025430
BH (0x6a30e928) file#: 4 rdba: 0x0103c996 (4/248214) class: 1 ba: 0x6b048000
...
===============
tsiz: 0x1f80
hsiz: 0x14
pbl: 0x2b017976ba7c
     76543210
flag=--------
ntab=1
nrow=1                                <-- 1 row
...
block_row_dump:
tab 0, row 0, @0x7fb
tl: 6021 fb: ----FL-- lb: 0x2  cc: 4  <-- First and Last Piece
hrid: 0x0103c995.1                    <-- Where is the head 


Everything is setup so now to experiment.
every where I looked in the internet everyone talked about queries so I thought a good opportunity to show the effect of the migrated rows over a DML.
So I will use a Serial UPDATE and a Parallel UPDATE.

EMB11203> cat sdml.sql
update row_mig_chain_demo
set a=rowid||'-'||to_char(sysdate,'yyyymmddhh24miss')
/
EMB11203> cat pdml.sql
alter session enable parallel dml;
alter session force parallel query;
update /*+ parallel */row_mig_chain_demo
set a=rowid||'-'||to_char(sysdate,'yyyymmddhh24miss')
/
EMB11203> cat d.sql
set pages 2000 lines 180
SELECT a.name, b.value value_QC
  FROM v$statname a, v$mystat b
 WHERE a.statistic# = b.statistic#
   AND lower(a.name) = 'table fetch continued row';
SELECT a.name, b.value value_system
  FROM v$statname a, v$sysstat b
 WHERE a.statistic# = b.statistic#
   AND lower(a.name) = 'table fetch continued row';

The update will modify only the first column of all 100 rows but since the column is CHAR there is not going to be any change in their allocated space.

First Test, the serial UDPATE

SQL> @d
NAME                                                               VALUE_QC
---------------------------------------------------------------- ----------
table fetch continued row                                                 0
NAME                                                             VALUE_SYSTEM
---------------------------------------------------------------- ------------
table fetch continued row                                                 482
SQL> @sdml
100 rows updated.
SQL> @d
NAME                                                               VALUE_QC
---------------------------------------------------------------- ----------
table fetch continued row                                                 0
NAME                                                             VALUE_SYSTEM
---------------------------------------------------------------- ------------
table fetch continued row                                                 482
SQL> commit;
Commit complete.
SQL> @d
NAME                                                               VALUE_QC
---------------------------------------------------------------- ----------
table fetch continued row                                                 0
NAME                                                             VALUE_SYSTEM
---------------------------------------------------------------- ------------
table fetch continued row                                                 482
Why did I query the statistics before and after the commit ? the answer will be evident in the PDML test. The execution plan shows a full scan and the expectation is that multiblock reads will be done and sure enough the 10046 shows it.

It is interesting that the first IO is a single block read but later all are multiblock.
So far , all that was promised is there, the full table scan is not affected by the migrated rows.

Now the Parallel Update

NAME                                                               VALUE_QC
---------------------------------------------------------------- ----------
table fetch continued row                                                 0

NAME                                                             VALUE_SYSTEM
---------------------------------------------------------------- ------------
table fetch continued row                                                 602
SQL> @pdml
Session altered.

Session altered.

100 rows updated.
SQL> @d
NAME                                                               VALUE_QC
---------------------------------------------------------------- ----------
table fetch continued row                                                 0

NAME                                                             VALUE_SYSTEM
---------------------------------------------------------------- ------------
table fetch continued row                                                 700
SQL> commit;
Commit complete.
SQL> @d
NAME                                                               VALUE_QC
---------------------------------------------------------------- ----------
table fetch continued row                                                98

NAME                                                             VALUE_SYSTEM
---------------------------------------------------------------- ------------
table fetch continued row                                                 700


To answer a previous question, why I get the statistics before and after the commit ?
The reason is that it appears the statistics of the slaves are not updated to the Query Coordinator (QC) until the transaction is over
but they are updated in the system-wide statistics and as it shows, 98 "table fetch continued row" (TFCR) operations were done.
98 is a strange number as there are 99 migrated rows.

The execution plan shows the Full Table Scan too so why the Parallel UPDATE did TFCR when the Serial did not ?

The explanation given by development is that some operations , in particular PDMLs, in order to avoid some deadlock scenarios the slaves need to do head piece scan while serial does a row piece scan.

Why do I care if it is a head piece scan vs row piece scan done ?

Because a Head piece scan reads the entire row, this means accessing all the blocks where the row pieces resides to get then all, and the worst part is that it has to be resolved immediately, cannot be deferred as the pieces are found by the multiblock read so the head piece scan does single block reads to look for the pieces.

The 10046 of the slaves shows those single block reads.

This is particulary bad in Exadata as customers like to have very wide tables (more than 255 columns which are automatically chained) and like to do PDML.

In Exadata system, the waitevent will be 'cell single block physical read'.

There is hope though, smart scan can cope with some cases of chained rows as long as the head and pieces are within the 1MB boundary of the IO but do not temp your luck and do your best to not produce chained or migrated rows, it is in everyones best interest.

Thursday Jul 11, 2013

More parses in 12c ?

More parses in 12.1 ?

Some customers upgrading from 11.2.0.3 to 12.1 might get alarmed because they see a spike in total number of parse count.
But not to worry, it is not a problem in 12.1. The problem is in 11.2.0.3.

Lets take the following example :

select a.name, b.value 
   from v$statname a, v$mystat b 
  where a.statistic# =  b.statistic# 
    and ( a.name like '%parse count%' 
       or a.name like 'session cursor cache%') 
    and value>0; 

 begin 
 for n in 1..100 loop 
 begin 
   execute immediate 'alter session set optimizer_goal=choose'; 
 exception 
  when others then 
  null; 
 end; 
 end loop; 
 end; 

 select a.name, b.value 
   from v$statname a, v$mystat b 
  where a.statistic# =  b.statistic# 
    and ( a.name like '%parse count%' 
       or a.name like 'session cursor cache%') 
    and value>0; 

I got the output of the queries and put them side by side in each version.

NAME                            11.1 VALUE   11.2 VALUE   12.1 VALUE
-----------------------------   ----------   ----------   ----------
session cursor cache hits                2            3            1
session cursor cache count               3           10           10
parse count (total)                     12           11           12
parse count (hard)                                    1   

PL/SQL procedure successfully completed.

NAME                            11.1 VALUE   11.2 VALUE   12.1 VALUE
-----------------------------   ----------   ----------   ----------
session cursor cache hits                3            3            1
session cursor cache count               4           11           11
parse count (total)                    114           13          114
parse count (hard)                     100          101          100
parse count (failures)                                           100


Notice the number of "parse count (total)" in 11.2 is less than "parse count (hard)" which makes no sense since "parse count (total)" should include Hard , Soft and Failed parses.

This might sound like an extreme case but there are other soft parsing scenarios that also reproduce this oddity.

For customers moving from 11.1 to 11.2.0.3 it might have looked as an improvement that there were less parses in total and then moving from 11.2.0.3 to 12.1 they would probably notice the spike and raise concerns.

So do not be alarmed, 12.1 does not do more parses, nor 11.2.0.3 does less parses, it is just a bug in the instrumentation of the stats, specifically :

Bug 13837105  statistics "parse count (total)" and "session cursor cache hits" miscounted [ID 13837105.8]

Tuesday Jul 02, 2013

Same SELECT used in an INSERT has different execution plan

A customer complained that a query and its INSERT counterpart had different execution plans, and of course, the INSERT was slower.

First lets look at the SELECT :

SELECT ua_tr_rundatetime, 
       ua_ch_treatmentcode, 
       ua_tr_treatmentcode, 
       ua_ch_cellid, 
       ua_tr_cellid 
FROM   (SELECT DISTINCT CH.treatmentcode AS UA_CH_TREATMENTCODE, 
                        CH.cellid        AS UA_CH_CELLID 
        FROM    CH, 
                DL 
        WHERE  CH.contactdatetime > SYSDATE - 5 
               AND CH.treatmentcode = DL.treatmentcode) CH_CELLS, 
       (SELECT DISTINCT T.treatmentcode AS UA_TR_TREATMENTCODE, 
                        T.cellid        AS UA_TR_CELLID, 
                        T.rundatetime   AS UA_TR_RUNDATETIME 
        FROM    T, 
                DL 
        WHERE  T.treatmentcode = DL.treatmentcode) TRT_CELLS 
WHERE  CH_CELLS.ua_ch_treatmentcode(+) = TRT_CELLS.ua_tr_treatmentcode; 



The query has 2 DISTINCT subqueries. 
The execution plan shows one with DISTICT Placement transformation applied and not the other.
The view in Step 5 has the prefix VW_DTP which means DISTINCT Placement.

--------------------------------------------------------------------
| Id  | Operation                    | Name            | Cost (%CPU)
--------------------------------------------------------------------
|   0 | SELECT STATEMENT             |                 |   272K(100)
|*  1 |  HASH JOIN OUTER             |                 |   272K  (1)
|   2 |   VIEW                       |                 |  4408   (1)
|   3 |    HASH UNIQUE               |                 |  4408   (1)
|*  4 |     HASH JOIN                |                 |  4407   (1)
|   5 |      VIEW                    | VW_DTP_48BAF62C |  1660   (2)
|   6 |       HASH UNIQUE            |                 |  1660   (2)
|   7 |        TABLE ACCESS FULL     | DL              |  1644   (1)
|   8 |      TABLE ACCESS FULL       | T               |  2744   (1)
|   9 |   VIEW                       |                 |   267K  (1)
|  10 |    HASH UNIQUE               |                 |   267K  (1)
|* 11 |     HASH JOIN                |                 |   267K  (1)
|  12 |      PARTITION RANGE ITERATOR|                 |   266K  (1)
|* 13 |       TABLE ACCESS FULL      | CH              |   266K  (1)
|  14 |      TABLE ACCESS FULL       | DL              |  1644   (1)
--------------------------------------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

   1 - SEL$1
   2 - SEL$AF418D5F / TRT_CELLS@SEL$1
   3 - SEL$AF418D5F
   5 - SEL$F6AECEDE / VW_DTP_48BAF62C@SEL$48BAF62C
   6 - SEL$F6AECEDE
   7 - SEL$F6AECEDE / DL@SEL$3
   8 - SEL$AF418D5F / T@SEL$3
   9 - SEL$2        / CH_CELLS@SEL$1
  10 - SEL$2
  13 - SEL$2        / CH@SEL$2
  14 - SEL$2        / DL@SEL$2

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("CH_CELLS"."UA_CH_TREATMENTCODE"="TRT_CELLS"."UA_TR_TREATMENTCODE")
   4 - access("T"."TREATMENTCODE"="ITEM_1")
  11 - access("CH"."TREATMENTCODE"="DL"."TREATMENTCODE")
  13 - filter("CH"."CONTACTDATETIME">SYSDATE@!-5)


The outline shows PLACE_DISTINCT(@"SEL$3" "DL"@"SEL$3")
indicating that the QB3 is the one that got the transformation.

Outline Data
-------------

  /*+
      BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('11.2.0.3')
      DB_VERSION('11.2.0.3')
      ALL_ROWS
      OUTLINE_LEAF(@"SEL$2")
      OUTLINE_LEAF(@"SEL$F6AECEDE")
      OUTLINE_LEAF(@"SEL$AF418D5F")
PLACE_DISTINCT(@"SEL$3" "DL"@"SEL$3")
      OUTLINE_LEAF(@"SEL$1")
      OUTLINE(@"SEL$48BAF62C")
      OUTLINE(@"SEL$3")
      NO_ACCESS(@"SEL$1" "TRT_CELLS"@"SEL$1")
      NO_ACCESS(@"SEL$1" "CH_CELLS"@"SEL$1")
      LEADING(@"SEL$1" "TRT_CELLS"@"SEL$1" "CH_CELLS"@"SEL$1")
      USE_HASH(@"SEL$1" "CH_CELLS"@"SEL$1")
      FULL(@"SEL$2" "CH"@"SEL$2")
      FULL(@"SEL$2" "DL"@"SEL$2")
      LEADING(@"SEL$2" "CH"@"SEL$2" "DL"@"SEL$2")
      USE_HASH(@"SEL$2" "DL"@"SEL$2")
      USE_HASH_AGGREGATION(@"SEL$2")
      NO_ACCESS(@"SEL$AF418D5F" "VW_DTP_48BAF62C"@"SEL$48BAF62C")
      FULL(@"SEL$AF418D5F" "T"@"SEL$3")
      LEADING(@"SEL$AF418D5F" "VW_DTP_48BAF62C"@"SEL$48BAF62C" "T"@"SEL$3")
      USE_HASH(@"SEL$AF418D5F" "T"@"SEL$3")
      USE_HASH_AGGREGATION(@"SEL$AF418D5F")
      FULL(@"SEL$F6AECEDE" "DL"@"SEL$3")
      USE_HASH_AGGREGATION(@"SEL$F6AECEDE")
      END_OUTLINE_DATA
  */


The 10053 shows there is a comparative of cost with and without the transformation.
This means the transformation belongs to Cost-Based Query Transformations (CBQT).

In SEL$3 the optimization of the query block without the transformation is 6659.73
and with the transformation is 4408.41 so the transformation is kept.

GBP/DP: Checking validity of GBP/DP for query block SEL$3 (#3)
DP: Checking validity of distinct placement for query block SEL$3 (#3)
DP: Using search type: linear
DP: Considering distinct placement on query block SEL$3 (#3)
DP: Starting iteration 1, state space = (5) : (0)
DP: Original query
DP: Costing query block.
DP: Updated best state, Cost = 6659.73
DP: Starting iteration 2, state space = (5) : (1)
DP: Using DP transformation in this iteration.
DP: Transformed query
DP: Costing query block.
DP: Updated best state, Cost = 4408.41
DP: Doing DP on the original QB.
DP: Doing DP on the preserved QB.


In SEL$2 the cost without the transformation is less than with it so it is not kept.

GBP/DP: Checking validity of GBP/DP for query block SEL$2 (#2)
DP: Checking validity of distinct placement for query block SEL$2 (#2)
DP: Using search type: linear
DP: Considering distinct placement on query block SEL$2 (#2)
DP: Starting iteration 1, state space = (3) : (0)
DP: Original query
DP: Costing query block.
DP: Updated best state, Cost = 267936.93
DP: Starting iteration 2, state space = (3) : (1)
DP: Using DP transformation in this iteration.
DP: Transformed query
DP: Costing query block.
DP: Not update best state, Cost = 267951.66


To the same query an INSERT INTO is added and the result is a very different execution plan.

INSERT  INTO cc
               (ua_tr_rundatetime,
                ua_ch_treatmentcode,
                ua_tr_treatmentcode,
                ua_ch_cellid,
                ua_tr_cellid)
SELECT ua_tr_rundatetime,
       ua_ch_treatmentcode,
       ua_tr_treatmentcode,
       ua_ch_cellid,
       ua_tr_cellid
FROM   (SELECT DISTINCT CH.treatmentcode AS UA_CH_TREATMENTCODE,
                        CH.cellid        AS UA_CH_CELLID
        FROM    CH,
                DL
        WHERE  CH.contactdatetime > SYSDATE - 5
               AND CH.treatmentcode = DL.treatmentcode) CH_CELLS,
       (SELECT DISTINCT T.treatmentcode AS UA_TR_TREATMENTCODE,
                        T.cellid        AS UA_TR_CELLID,
                        T.rundatetime   AS UA_TR_RUNDATETIME
        FROM    T,
                DL
        WHERE  T.treatmentcode = DL.treatmentcode) TRT_CELLS
WHERE  CH_CELLS.ua_ch_treatmentcode(+) = TRT_CELLS.ua_tr_treatmentcode;

----------------------------------------------------------
| Id  | Operation                     | Name | Cost (%CPU)
----------------------------------------------------------
|   0 | INSERT STATEMENT              |      |   274K(100)
|   1 |  LOAD TABLE CONVENTIONAL      |      |            
|*  2 |   HASH JOIN OUTER             |      |   274K  (1)
|   3 |    VIEW                       |      |  6660   (1)
|   4 |     SORT UNIQUE               |      |  6660   (1)
|*  5 |      HASH JOIN                |      |  6659   (1)
|   6 |       TABLE ACCESS FULL       | DL   |  1644   (1)
|   7 |       TABLE ACCESS FULL       | T    |  2744   (1)
|   8 |    VIEW                       |      |   267K  (1)
|   9 |     SORT UNIQUE               |      |   267K  (1)
|* 10 |      HASH JOIN                |      |   267K  (1)
|  11 |       PARTITION RANGE ITERATOR|      |   266K  (1)
|* 12 |        TABLE ACCESS FULL      | CH   |   266K  (1)
|  13 |       TABLE ACCESS FULL       | DL   |  1644   (1)
----------------------------------------------------------
Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------
   1 - SEL$1
   3 - SEL$3 / TRT_CELLS@SEL$1
   4 - SEL$3
   6 - SEL$3 / DL@SEL$3
   7 - SEL$3 / T@SEL$3
   8 - SEL$2 / CH_CELLS@SEL$1
   9 - SEL$2
  12 - SEL$2 / CH@SEL$2
  13 - SEL$2 / DL@SEL$2

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("CH_CELLS"."UA_CH_TREATMENTCODE"="TRT_CELLS"."UA_TR_TREATMENTCODE")
   5 - access("T"."TREATMENTCODE"="DL"."TREATMENTCODE")
  10 - access("CH"."TREATMENTCODE"="DL"."TREATMENTCODE")
  12 - filter("CH"."CONTACTDATETIME">SYSDATE@!-5)

Outline Data
-------------
  /*+
      BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('11.2.0.3')
      DB_VERSION('11.2.0.3')
      ALL_ROWS
      OUTLINE_LEAF(@"SEL$2")
      OUTLINE_LEAF(@"SEL$3")
      OUTLINE_LEAF(@"SEL$1")
      OUTLINE_LEAF(@"INS$1")
      FULL(@"INS$1" "CC"@"INS$1")
      NO_ACCESS(@"SEL$1" "TRT_CELLS"@"SEL$1")
      NO_ACCESS(@"SEL$1" "CH_CELLS"@"SEL$1")
      LEADING(@"SEL$1" "TRT_CELLS"@"SEL$1" "CH_CELLS"@"SEL$1")
      USE_HASH(@"SEL$1" "CH_CELLS"@"SEL$1")
      FULL(@"SEL$2" "CH"@"SEL$2")
      FULL(@"SEL$2" "DL"@"SEL$2")
      LEADING(@"SEL$2" "CH"@"SEL$2" "DL"@"SEL$2")
      USE_HASH(@"SEL$2" "DL"@"SEL$2")
      USE_HASH_AGGREGATION(@"SEL$2")
      FULL(@"SEL$3" "DL"@"SEL$3")
      FULL(@"SEL$3" "T"@"SEL$3")
      LEADING(@"SEL$3" "DL"@"SEL$3" "T"@"SEL$3")
      USE_HASH(@"SEL$3" "T"@"SEL$3")
      USE_HASH_AGGREGATION(@"SEL$3")
      END_OUTLINE_DATA
  */

There is no DISTINCT Placement view and no hint.
The 10053 trace shows a new legend "DP: Bypassed: Not SELECT"
implying that this is a transformation that it is possible only for SELECTs.

GBP/DP: Checking validity of GBP/DP for query block SEL$3 (#4) DP: Checking validity of distinct placement for query block SEL$3 (#4) DP: Bypassed: Not SELECT. GBP/DP: Checking validity of GBP/DP for query block SEL$2 (#3) DP: Checking validity of distinct placement for query block SEL$2 (#3) DP: Bypassed: Not SELECT.

In 12.1 (and hopefully in 11.2.0.4 when released) the restriction on applying CBQT to some DMLs and DDLs (like CTAS) is lifted.
This is documented in BugTag Note:10013899.8 Allow CBQT for some DML / DDL
And interestingly enough, it is possible to have a one-off patch in 11.2.0.3.

SQL> select DESCRIPTION,OPTIMIZER_FEATURE_ENABLE,IS_DEFAULT  
  2  from v$system_fix_control where BUGNO='10013899';
DESCRIPTION
----------------------------------------------------------------
OPTIMIZER_FEATURE_ENABLE  IS_DEFAULT
------------------------- ----------
enable some transformations for DDL and DML statements
11.2.0.4                           1


About

I am Abel Macias email, an Oracle support engineer that specialized in Performance that belongs to Exadata Support.
Disclaimer This blog looks to broadcast my experiences while diagnosing performance problems on Oracle's RDBMS, mostly on Exadata.
The views expressed on this blog are my own and do not necessarily reflect the views of Oracle.

Search

Archives
« July 2013
SunMonTueWedThuFriSat
 
1
3
4
5
6
7
8
9
10
12
13
14
15
16
17
19
20
21
23
24
25
26
27
28
29
30
31
   
       
Today