create table t_target ( id number(*, 0) not null, pkey number(*, 0) not null, filler varchar2(500) ) --segment creation immediate partition by range (pkey) --interval (1) ( partition pkey_0 values less than (1) , partition pkey_1 values less than (2) , partition pkey_2 values less than (3) , partition pkey_3 values less than (4) ); create table t_source compress as select 1 as id, rpad('x', 100) as filler from (select /*+ cardinality(1e3) */ null from dual connect by level <= 1e3), (select /*+ cardinality(1e0) */ null from dual connect by level <= 1e0) union all select 1 as id, rpad('y', 100) as filler from dual; -- Run this again once the DML statement below got started exec dbms_stats.gather_table_stats(null, 't_source', no_invalidate=>false) exec dbms_stats.gather_table_stats(null, 't_target', no_invalidate=>false) ---------------------------------------------------------------------------------------------------------------------------------- -- INSERT example -- -- Run above DBMS_STATS calls or any other command that invalidates the cursor during execution to force re-start of the cursor -- ---------------------------------------------------------------------------------------------------------------------------------- set echo on timing on time on -- alter session set tracefile_identifier = 'insert_restart'; -- alter session set events '10046 trace name context forever, level 12'; -- exec sys.dbms_monitor.session_trace_enable(waits => true, binds => true/*, plan_stat => 'all_executions'*/) insert /* append */ into t_target (id, pkey, filler) select * from ( select /*+ use_hash(a b) no_eliminate_oby */ a.id, 1 as pkey, a.filler from t_source a, t_source b where a.id = b.id and ( regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') or (b.filler = rpad('y', 100) and a.filler = rpad('y', 100)) ) order by a.id ) union all select * from ( select /*+ use_hash(a b) no_eliminate_oby */ a.id, 2 as pkey, a.filler from t_source a, t_source b where a.id = b.id and ( regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') or (b.filler = rpad('y', 100) and a.filler = rpad('y', 100)) ) order by a.id ) union all select * from ( select /*+ use_hash(a b) no_eliminate_oby */ a.id, 3 as pkey, a.filler from t_source a, t_source b where a.id = b.id and ( regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') or (b.filler = rpad('y', 100) and a.filler = rpad('y', 100)) ) order by a.id ) ; -- exec sys.dbms_monitor.session_trace_disable ---------------------------------------------------------------------------------------------------------------------------------- -- MERGE example -- -- Run above DBMS_STATS calls or any other command that invalidates the cursor during execution to force re-start of the cursor -- ---------------------------------------------------------------------------------------------------------------------------------- set echo on timing on time on merge /* append */ into t_target t using ( select * from ( select /*+ use_hash(a b) no_eliminate_oby */ a.id, 1 as pkey, a.filler from t_source a, t_source b where a.id = b.id and ( regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') or (b.filler = rpad('y', 100) and a.filler = rpad('y', 100)) ) order by a.id ) union all select * from ( select /*+ use_hash(a b) no_eliminate_oby */ a.id, 2 as pkey, a.filler from t_source a, t_source b where a.id = b.id and ( regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') or (b.filler = rpad('y', 100) and a.filler = rpad('y', 100)) ) order by a.id ) union all select * from ( select /*+ use_hash(a b) no_eliminate_oby */ a.id, 3 as pkey, a.filler from t_source a, t_source b where a.id = b.id and ( regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i') --or regexp_replace(a.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') != regexp_replace(b.filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'm') or (b.filler = rpad('y', 100) and a.filler = rpad('y', 100)) ) order by a.id ) ) s on (s.id = t.id) when not matched then insert (id, pkey, filler) values (s.id, s.pkey, s.filler) ;The idea of the test case is to maximise the time until each UNION ALL branch produces data to insert by performing an inefficient HASH JOIN (that in fact generates a Cartesian product and needs to apply a costly REGEXP filter on that huge intermediate result) and forcing a sort on the join result, so rows will only be handed over to the parent operations until all rows were processed in the join operation - and each branch generates data for a different partition of the target table. Typically it should take several seconds per branch to execute (if you need more time just un-comment the additional REGEXP_REPLACE filters), so you should have plenty of time to cause the invalidation from another session. This means during the execution of each branch invalidating the cursor (for example by executing either of the two DBMS_STATS calls on the source or target table using NO_INVALIDATE=>FALSE) will lead to a re-start of the statement at the next attempt to write into a new target partition, possibly rolling back rows already inserted into other partitions.
Consistent?
8 hours ago