RE: different plan with insert/select

  • From: Noveljic Nenad <nenad.noveljic@xxxxxxxxxxxx>
  • To: Noveljic Nenad <nenad.noveljic@xxxxxxxxxxxx>, "jlewisoracle@xxxxxxxxx" <jlewisoracle@xxxxxxxxx>, "ORACLE-L (oracle-l@xxxxxxxxxxxxx)" <oracle-l@xxxxxxxxxxxxx>
  • Date: Wed, 24 Jun 2020 21:06:03 +0000

The insert/select execution plan is as follows:

---------------------------------------------------------------------------+-----------------------------------+
| Id  | Operation                              | Name                      | 
Rows  | Bytes | Cost  | Time      |
---------------------------------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT                       |                           |    
   |       |  275M |           |
| 1   |  LOAD TABLE CONVENTIONAL               | ICR_DAT_BEWEGUNG_FKR      |    
   |       |       |           |
| 2   |   COUNT                                |                           |    
   |       |       |           |
| 3   |    MERGE JOIN OUTER                    |                           |   
68G |   44T |  275M | 102:33:29 |
| 4   |     MERGE JOIN OUTER                   |                           |   
31K |   20M |  141K |  00:03:04 |
| 5   |      HASH JOIN RIGHT OUTER             |                           |   
31K |   20M |   15K |  00:00:21 |
| 6   |       TABLE ACCESS FULL                | ALL_DIL_BOERSENPLATZ      |  
2348 |   94K |     8 |  00:00:01 |
| 7   |       HASH JOIN RIGHT OUTER            |                           |   
31K |   18M |   15K |  00:00:21 |
| 8   |        TABLE ACCESS FULL               | ALL_DIL_GVF               |  
250K | 2754K |  1424 |  00:00:02 |
| 9   |        HASH JOIN                       |                           |   
31K |   18M |   13K |  00:00:18 |
| 10  |         INDEX RANGE SCAN               | PK_ICR_MIT_BOOKKIND       |   
220 |  4400 |     3 |  00:00:01 |
| 11  |         TABLE ACCESS FULL              | ICR_WRK_BEWEGUNG_FKR      |  
118K |   66M |   13K |  00:00:18 |
| 12  |      BUFFER SORT                       |                           |    
 1 |    13 |  141K |  00:03:04 |
| 13  |       VIEW                             | VW_LAT_7AEC37A2           |    
 1 |    13 |     4 |  00:00:01 |
| 14  |        HASH JOIN                       |                           |    
 1 |    28 |     4 |  00:00:01 |
| 15  |         NESTED LOOPS                   |                           |    
 1 |    28 |     4 |  00:00:01 |
| 16  |          NESTED LOOPS                  |                           |    
 1 |    28 |     4 |  00:00:01 |
| 17  |           STATISTICS COLLECTOR         |                           |    
   |       |       |           |
| 18  |            TABLE ACCESS BY INDEX ROWID | ALL_DIL_WAEHRUNG_KURS     |    
 1 |    14 |     2 |  00:00:01 |
| 19  |             INDEX RANGE SCAN           | PK_ALL_DIL_WAEHRUNG_KURS  |    
 1 |       |     1 |  00:00:01 |
| 20  |           INDEX RANGE SCAN             | PK_ALL_DIL_WAEHRUNG_KURS  |    
 1 |       |     1 |  00:00:01 |
| 21  |          TABLE ACCESS BY INDEX ROWID   | ALL_DIL_WAEHRUNG_KURS     |    
 1 |    14 |     2 |  00:00:01 |
| 22  |         TABLE ACCESS BY INDEX ROWID    | ALL_DIL_WAEHRUNG_KURS     |    
 1 |    14 |     2 |  00:00:01 |
| 23  |          INDEX RANGE SCAN              | PK_ALL_DIL_WAEHRUNG_KURS  |    
 1 |       |     1 |  00:00:01 |
| 24  |     BUFFER SORT                        |                           | 
2225K |       |  275M | 102:33:29 |
| 25  |      VIEW                              | VW_LAT_7AEC37A2           | 
2225K |       |  8974 |  00:00:12 |
| 26  |       FILTER                           |                           |    
   |       |       |           |
| 27  |        HASH JOIN RIGHT OUTER           |                           | 
2225K |  124M |  8974 |  00:00:12 |
| 28  |         TABLE ACCESS FULL              | ALL_DIL_BEWEGUNG          |  
319K | 6386K |  6527 |  00:00:09 |
| 29  |         INDEX RANGE SCAN               | ALL_DIL_STEX_ORDER_LINK_PK| 
1324K |   48M |     3 |  00:00:01 |
---------------------------------------------------------------------------+-----------------------------------+
Query Block Name / Object Alias (identified by operation id):
------------------------------------------------------------
1 - SEL$981CF1E7
6 - SEL$981CF1E7         / "BP"@"SEL$8"
8 - SEL$981CF1E7         / "IGV"@"SEL$6"
10 - SEL$981CF1E7         / "ICR_MIT_BOOKKIND"@"SEL$1"
11 - SEL$981CF1E7         / "P"@"SEL$1"
13 - SEL$BB1798A6         / "from$_subquery$_020"@"SEL$5"
14 - SEL$BB1798A6
15 - SEL$BB1798A6
18 - SEL$BB1798A6         / "VON"@"SEL$3"
19 - SEL$BB1798A6         / "VON"@"SEL$3"
20 - SEL$BB1798A6         / "NACH"@"SEL$3"
21 - SEL$BB1798A6         / "NACH"@"SEL$3"
22 - SEL$BB1798A6         / "NACH"@"SEL$3"
23 - SEL$BB1798A6         / "NACH"@"SEL$3"
25 - SEL$8DB738D0         / "from$_subquery$_023"@"SEL$14"
26 - SEL$8DB738D0
28 - SEL$8DB738D0         / "BOL"@"SEL$11"
29 - SEL$8DB738D0         / "OL"@"SEL$12"

Unlike in select, SEL$8DB738D0 is a lateral correlated subquery. This is the 
one causing problems. Obviously, the ansi-join transformation produces 
different result in both cases.

Curiously, there are two lateral subqueries carrying the same name: 
VW_LAT_7AEC37A2, even though they don't have anything in common.

The decorrelation was bypassed for SEL$8DB738D0:

DCL: Checking validity of lateral view decorrelation SEL$8DB738D0 (#0)
DCL: Bypassed: view has non-well-formed predicate
DCL: Failed decorrelation validity for lateral view block SEL$8DB738D0 (#0)

Find below the definition of the lateral subquery SEL$8DB738D0 from the 
optimizer trace:

LATERAL( (SELECT "OL"."ORDER_ID" "ORDER_ID_0","OL"."LINK_TYPE_C" 
"LINK_TYPE_C_1" FROM "TRL_OWNER_1"."ALL_DIL_STEX_ORDER_LINK" 
"OL","TRL_OWNER_1"."ALL_DIL_BEWEGUNG" "BOL" WHERE 
"OL"."ORDER_ID"="P"."GVF_GVF_ID" AND "OL"."LINK_TYPE_C"='exec_exec_doc_id_list' 
AND ("P"."T_ORDER_TYP_C"='stex_buy_secondary_dvp' OR 
"P"."T_ORDER_TYP_C"='stex_sell_secondary_rvp') AND 
"OL"."REL_ORDER_ID"="BOL"."GVF_ID"(+) AND 
"BOL"."BOOK_KIND_C"(+)='trade_asset'))(+) "from$_subquery$_023"

The reason for bypassing could be the OR in the predicate (according to Dominic 
Brook's article https://orastory.wordpress.com/category/ansi/).

I removed 'OR "P"."T_ORDER_TYP_C"' which resolved this issue, but had to 
rewrite the query with UNION as this is the join predicate of the outer table. 
The insert/select now looks ugly but it runs within 12s instead of 2+ hours.

I'll try to figure out which boundary condition triggered creating the second 
lateral subquery.

Best regards,

Nenad

http://nenadnoveljic.com/blog/

____________________________________________________
Please consider the environment before printing this e-mail.
Bitte denken Sie an die Umwelt, bevor Sie dieses E-Mail drucken.

<html xmlns="http://www.w3.org/1999/xhtml";>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=iso-8859-1">
<style type="text/css">p { font-family: Arial;font-size:9pt }</style>
</head>
<body>
<p>
<br>Important Notice</br>
<br />
This message is intended only for the individual named. It may contain 
confidential or privileged information. If you are not the named addressee you 
should in particular not disseminate, distribute, modify or copy this e-mail. 
Please notify the sender immediately by e-mail, if you have received this 
message by mistake and delete it from your system.<br />
Without prejudice to any contractual agreements between you and us which shall 
prevail in any case, we take it as your authorization to correspond with you by 
e-mail if you send us messages by e-mail. However, we reserve the right not to 
execute orders and instructions transmitted by e-mail at any time and without 
further explanation.<br />
E-mail transmission may not be secure or error-free as information could be 
intercepted, corrupted, lost, destroyed, arrive late or incomplete. Also 
processing of incoming e-mails cannot be guaranteed. All liability of Vontobel 
Holding Ltd. and any of its affiliates (hereinafter collectively referred to as 
"Vontobel Group") for any damages resulting from e-mail use is excluded. You 
are advised that urgent and time sensitive messages should not be sent by 
e-mail and if verification is required please request a printed version.</br>
Please note that all e-mail communications to and from the Vontobel Group are 
subject to electronic storage and review by Vontobel Group. Unless stated to 
the contrary and without prejudice to any contractual agreements between you 
and Vontobel Group which shall prevail in any case, e-mail-communication is for 
informational purposes only and is not intended as an offer or solicitation for 
the purchase or sale of any financial instrument or as an official confirmation 
of any transaction.<br />
The legal basis for the processing of your personal data is the legitimate 
interest to develop a commercial relationship with you, as well as your consent 
to forward you commercial communications. You can exercise, at any time and 
under the terms established under current regulation, your rights. If you 
prefer not to receive any further communications, please contact your client 
relationship manager if you are a client of Vontobel Group or notify the sender.
Please note for an exact reference to the affected group entity the corporate 
e-mail signature.
For further information about data privacy at Vontobel Group please consult <a 
href="https://www.vontobel.com";>www.vontobel.com</a>.<br />
</p>
</body>
</html>

Other related posts: