This is an observation that came up on the Oracle Developer Forum a couple of days ago, starting life as the fairly common problem:
I have a “select” that runs quickly but when I use in a “create as select” it runs very slowly.
In many cases this simply means that the query was a distributed (or remote) query and the plan changed because the driving site changed from the remote server to the local server. There are a couple of other reasons why the plan used for a query changes when it is used in a CTAS, but distributed DML is the one most commonly seen.
In this example, though, the query was not a distributed query, it was a fully local query. There were three features to the query that were possibly suspect, though:
- “ANSI” syntax
- scalar subqueries in the select list
- redundant “order by” clauses in inline views
The OP had supplied the (horrible) SQL in a text format along with images from the Enterprise Manager SQL Monitor screen showing the two execution plans – and two things were obvious from the plans: first that the simple select had eliminated the scalar subqueries (which were redundant) while the CTAS had kept them in the plan, and secondly most of the elapsed time for the CTAS was spent in lots of executions of the scalar subqueries.
My first thought was that the problem was probably a quirk of how the optimizer translates “ANSI” SQL to Oracle-standard SQL, so I created a model that captured the key features of the problem – starting with 3 tables:
rem rem Script: ctas_scalar_subq.sql rem Author: Jonathan Lewis rem Dated: Dec 2019 rem Purpose: rem rem Last tested rem 19.3.0.0 rem 12.2.0.1 rem 11.2.0.4 rem create table t1 as select * from all_objects where rownum <= 10000 -- > comment to avoid wordpress format issue ; alter table t1 add constraint t1_pk primary key(object_id); create table t2 as select * from t1 ; alter table t2 add constraint t2_pk primary key(object_id); create table t3 as select * from all_objects where rownum <= 500 -- > comment to avoid wordpress format issue ; alter table t3 add constraint t3_pk primary key(object_id); begin dbms_stats.gather_table_stats( ownname => null, tabname => 'T1', method_opt => 'for all columns size 1' ); dbms_stats.gather_table_stats( ownname => null, tabname => 'T2', method_opt => 'for all columns size 1' ); dbms_stats.gather_table_stats( ownname => null, tabname => 'T3', method_opt => 'for all columns size 1' ); end; /
I’m going to use the small t3 table as the target for a simple scalar subquery in the select list of a query that selects some columns from t2; then I’m going to use that query as an inline view in a join to t1 and select some columns from the result. Here’s the starting query that’s going to become an inline view:
select t2.*, ( select t3.object_type from t3 where t3.object_id = t2.object_id ) t3_type from t2 order by t2.object_id ;
And here’s how I join the result to t1:
explain plan for select v2.* from ( select t1.object_id, t1.object_name t1_name, v1.object_name t2_name, t1.object_type t1_type, v1.object_type t2_type from t1 join ( select t2.*, ( select t3.object_type from t3 where t3.object_id = t2.object_id ) t3_type from t2 order by t2.object_id ) v1 on v1.object_id = t1.object_id and v1.object_type = 'TABLE' ) v2 ; select * from table(dbms_xplan.display(null,null,'outline alias'));
The initial t2 query becomes an inline view called v1, and that becomes the second table in a join with t1. I’ve got the table and view in this order because initially the OP had an outer (left) join preserving t1 and I thought that that might be significant, but it turned out that it wasn’t.
Having joined t1 and v1 I’ve selected a small number of columns from the t1 and t2 tables and ignored the column that was generated by the inline scalar subquery. (This may seem a little stupid – but the same problem appears when the inline view is replaced with a stored view, which is a more realistic possibility.) Here’s the resulting execution plan (taken from 11.2.0.4 in this case):
----------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ----------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 476 | 31416 | 45 (12)| 00:00:01 | |* 1 | HASH JOIN | | 476 | 31416 | 45 (12)| 00:00:01 | | 2 | VIEW | | 476 | 15708 | 23 (14)| 00:00:01 | | 3 | SORT ORDER BY | | 476 | 41888 | 23 (14)| 00:00:01 | |* 4 | TABLE ACCESS FULL| T2 | 476 | 41888 | 22 (10)| 00:00:01 | | 5 | TABLE ACCESS FULL | T1 | 10000 | 322K| 21 (5)| 00:00:01 | ----------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("V1"."OBJECT_ID"="T1"."OBJECT_ID") 4 - filter("T2"."OBJECT_TYPE"='TABLE')
I was a little surprised by this plan as I had expected the optimizer to eliminate the in-line “order by” in view v1 – but even when I changed the code to traditional Oracle join syntax the redundant and wasteful sort order by at operaton 3 still took place. (You might note that the data will be reported in an order dictated by the order of the data arriving from the t1 tablescan thanks to the mechanics of a hash join, so the sort is a total waste of effort.)
The plus point, of course, is that the optimizer had been smart enough to eliminate the scalar subquery referencing t3. The value returned from t3 is not needed anywhere in the course of the execution, so it simply disappears.
Now we change from a simple select to a Create as Select (CTAS) which I’ve run, with rowsource execution stats enabled, using Oracle 19.3 for this output:
set serveroutput off set linesize 156 set trimspool on set pagesize 60 alter session set statistics_level = all; create table t4 as select v2.* from ( select t1.object_id, t1.object_name t1_name, v1.object_name t2_name, t1.object_type t1_type, v1.object_type t2_type from t1 join ( select t2.*, ( select t3.object_type from t3 where t3.object_id = t2.object_id ) t3_type from t2 order by t2.object_id ) v1 on v1.object_id = t1.object_id and v1.object_type = 'TABLE' ) v2 ; select * from table(dbms_xplan.display_cursor(null,null,'allstats last')); alter session set statistics_level = typical;
And here’s the run-time execution plan – showing the critical error and statistics to prove that it really happened:
---------------------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Starts | E-Rows | A-Rows | A-Time | Buffers | Writes | OMem | 1Mem | Used-Mem | ---------------------------------------------------------------------------------------------------------------------------------------- | 0 | CREATE TABLE STATEMENT | | 1 | | 0 |00:00:00.01 | 471 | 3 | | | | | 1 | LOAD AS SELECT | T4 | 1 | | 0 |00:00:00.01 | 471 | 3 | 1042K| 1042K| 1042K (0)| | 2 | OPTIMIZER STATISTICS GATHERING | | 1 | 435 | 294 |00:00:00.01 | 414 | 0 | 256K| 256K| 640K (0)| |* 3 | HASH JOIN | | 1 | 435 | 294 |00:00:00.01 | 414 | 0 | 1265K| 1265K| 1375K (0)| | 4 | VIEW | | 1 | 435 | 294 |00:00:00.01 | 234 | 0 | | | | | 5 | TABLE ACCESS BY INDEX ROWID | T3 | 294 | 1 | 50 |00:00:00.01 | 54 | 0 | | | | |* 6 | INDEX UNIQUE SCAN | T3_PK | 294 | 1 | 50 |00:00:00.01 | 4 | 0 | | | | | 7 | SORT ORDER BY | | 1 | 435 | 294 |00:00:00.01 | 234 | 0 | 80896 | 80896 |71680 (0)| |* 8 | TABLE ACCESS FULL | T2 | 1 | 435 | 294 |00:00:00.01 | 180 | 0 | | | | | 9 | TABLE ACCESS FULL | T1 | 1 | 10000 | 10000 |00:00:00.01 | 180 | 0 | | | | ---------------------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 3 - access("V1"."OBJECT_ID"="T1"."OBJECT_ID") 6 - access("T3"."OBJECT_ID"=:B1) 8 - filter("T2"."OBJECT_TYPE"='TABLE')
You’ll notice that the VIEW at operation 4 reports the inline scalar subquery as operations 5 and 6, and the Starts column show that the scalar subquery executes 294 times – which is the number of rows returned by the scan of table t2. Although my first thought was that this was an artefact of the transformation from ANSI to Oracle syntax it turned out that when I modified the two statements to use traditional Oracle syntax the same difference appeared. Finally I re-ran the CTAS after removing the order by clause in the in-line view and the redundant subquery disappeared from the execution plan.
Tiny Geek bit
It’s not immediately obvious why there should be such a difference between the select and the CTAS in this case, but the 10053 trace files do give a couple of tiny clues the CTAS trace file includes the lines:
ORE: bypassed - Top query block of a DML. TE: Bypassed: Top query block of a DML. SQT: SQT bypassed: in a transaction.
The first two suggest that we should expect some cases where DML statement optimise differently from simple queries. The last one is a further indication that differences may appear. (SQT – might this be subquery transformation, it doesn’t appear in the list of abbreviations in the trace file).
Unfortunately the SELECT trace file also included the line:
SQT: SQT bypassed: Disabled by parameter.
So “SQT” – whatever that is – being in or out of a transaction may not have anything to do with the difference.
Summary
There are cases where optimising a select statement is not sufficient as a strategy for optimising a CTAS statement. In this case it looks as if an inline view which was non-mergable (thanks to a redundant order by clause) produced the unexpected side-effect that a completely redundant scalar subquery in the select list of the inline view was executed during the CTAS even though it was transformed out of existence for the simple select.
There are some unexpected performance threats in “cut-and-paste” coding and in re-using stored views if you haven’t checked carefully what they do and how they’re supposed to be used.
Update (Feb 2020)
I’ve just run the test on 19.8 (available here on LiveSQL) and the redundant scalarsubquery is still in the plan.
Comments and related questions are welcome.