Re: CTAS running long

From: Jonathan Lewis <jlewisoracle_at_gmail.com>
Date: Thu, 12 May 2022 08:02:00 +0100
Message-ID: <CAGtsp8kCc5KxbdCxFSrz80C=iiApoGAY+tz_ShkFbApmdQy9_g_at_mail.gmail.com>



If you look at the definition in user_lob_partitions for the maxvalue partition you are creating you will find that it's defined as "nocache logging". You could try modifying your create table statement to affect these options, but since you're running with force logging and archivelog enabled I assume you would still generate redo log even if youo set the option to nologging. (Make sure your test system matches the production in this respect - tests on systems running in noarchivelog can behave differently
https://jonathanlewis.wordpress.com/2012/05/28/ch-ch-ch-ch-changes/ )

There's nothing you can do about the huge number of single block reads, but it's possible that setting the basicfile lob to cache - and you might want to allocate a KEEP pool to limit the size of the cache used, and allocate the LOB to it - then POSSIBLY there would be some benefit if Oracle decided to do some prefetching on the segment but I rather doubt it.

If you set the target (securefile) LOB to cache (also consider a separate buffer pool) then you may find that offloading the write to the database writer instead of having the PX servers do direct path MIGHT help with the checkpointing, but the main change you need is simply to have a much larger volume of online redo log files, and possibly larger redo log files.

Regards
Jonathan Lewis

On Sat, 7 May 2022 at 18:37, Lok P <loknath.73_at_gmail.com> wrote:

> Resending as bounced back...
>
> Hi , We are trying to purge data from a non partition table, as part of
> which we are creating an interim table which would be partitioned and that
> will hold the required data and then we will exchange that partition with
> the main table to purge data from the main table.
>
> The issue is that the create interim partitioned table statement which is
> supposed to pick and purge ~60million records from the non partition
> table(TABLE1) is running long. The base/main table (Say TABLE1) is ~91GB in
> size and holds 71million rows and avg_row_len is showing as 1178. The sql
> monitor we captured is as below. It shows almost all time spent on "log
> file switch (checkpoint incomplete)". The interim table creation is running
> in Parallel-32.
>
> Btw we saw while performing CTAS for other tables with even more data we
> didn't see such an issue. And then one thing we noticed is, there exists
> two CLOB columns in this main table(table1 here) which were not there in
> other tables. And the CLOB columns were defined as below. So my question is
> , is this high "log file switch (checkpoint incomplete)" wait event
> happening because of the presence of these clob columns and how can we make
> this interim table creation faster in such a case?
>
> And we have our database in force logging mode and we have data guard
> configuration in place. If we create the interim table as nologging will it
> help here or cause any issue as we have our main non partitioned table is
> created as 'logging' mode?
>
> LOB (CLOB1) STORE AS (
>
> TABLESPACE TBS2
> ENABLE STORAGE IN ROW
> CHUNK 8192
> RETENTION
> NOCACHE
> NOLOGGING
> STORAGE (
> INITIAL 64K
> NEXT 1M
> MINEXTENTS 1
> MAXEXTENTS UNLIMITED
> PCTINCREASE 0
> BUFFER_POOL DEFAULT
> ))
> TABLESPACE TBS2
> PCTUSED 0
> PCTFREE 10
> INITRANS 1
> MAXTRANS 255
> STORAGE (
> INITIAL 64K
> NEXT 1M
> MAXSIZE UNLIMITED
> MINEXTENTS 1
> MAXEXTENTS UNLIMITED
> PCTINCREASE 0
> BUFFER_POOL DEFAULT
> )
> NOLOGGING
> NOCOMPRESS
> NOCACHE
> MONITORING;
>
>
> select group#, thread#, archived, status, BYTES/1024/1024 MB from v$log
>
> GROUP# THREAD# ARCHIVED STATUS MB
>
> 1 1 NO CURRENT 500
>
> 2 1 YES ACTIVE 500
>
> 3 1 YES ACTIVE 500
>
> 4 2 YES INACTIVE 500
>
> 5 2 NO CURRENT 500
>
> 6 2 YES ACTIVE 500
>
>
> CREATE TABLE TABLE_BKP (c1, c2, c3, c4.. c12) parallel 32 partition by
> range (C3) (partition p0 values less than (maxvalue) tablespace TBS1) as (
> select /*+ parallel(t, 32) */ * from TABLE1 t where cre_ts>Sysdate-700)
>
> Global Information
> ------------------------------
> Status : EXECUTING
> Instance ID : 1
> SQL ID : 3rfch2jrrciou
> SQL Execution ID : 16777216
> Execution Started : 05/07/2022 01:47:51
> First Refresh Time : 05/07/2022 01:47:52
> Last Refresh Time : 05/07/2022 02:24:12
> Duration : 2198s
> Module/Action : SQL*Plus/-
>
> Global Stats
>
> =======================================================================================================================================================================
> | Elapsed | Cpu | IO | Application | Concurrency | Cluster |
> Other | Buffer | Read | Read | Write | Write | Uncompressed | Offload
> | Offload |
> | Time(s) | Time(s) | Waits(s) | Waits(s) | Waits(s) | Waits(s) |
> Waits(s) | Gets | Reqs | Bytes | Reqs | Bytes | Bytes | Elig
> Bytes | Returned Bytes |
>
> =======================================================================================================================================================================
> | 70278 | 5941 | 42197 | 0.00 | 10 | 2.32 |
> 22128 | 378M | 40M | 314GB | 544K | 314GB | 6GB | 6GB
> | 632GB |
>
> =======================================================================================================================================================================
>
> SQL Plan Monitoring Details (Plan Hash Value=2463526707)
> ============================================================
> ============================================================
> ============================================================
> ============================================================
> | Id | Operation | Name |
> Rows | Cost | Time | Start | Execs | Rows | Read | Read |
> Write | Write | Mem | Activity | Activity Detail
> | Progress |
> | | | |
> (Estim) | | Active(s) | Active | | (Actual) | Reqs | Bytes |
> Reqs | Bytes | | (%) | (# samples)
> | |
> ============================================================
> ============================================================
> ============================================================
> ============================================================
> | 0 | CREATE TABLE STATEMENT | |
> | | | | 33 | | | |
> | | . | |
> | |
> | 1 | PX COORDINATOR | |
> | | | | 33 | | | |
> | | . | |
> | |
> | 2 | PX SEND QC (RANDOM) | :TQ10000 |
> 44M | 58295 | | | 32 | | | |
> | | . | |
> | |
> | -> 3 | LOAD AS SELECT (HYBRID TSM/HWMB) | TABLE_BKP |
> | | 2201 | +3 | 32 | 0 | 40M | 308GB | 545K
> | 314GB | 65MB | 99.98 | gc cr grant 2-way (4)
> | |
> | | | |
> | | | | | | | |
> | | | | buffer busy waits (1)
> | |
> | | | |
> | | | | | | | |
> | | | | log buffer space (16)
> | |
> | | | |
> | | | | | | | |
> | | | | log file switch (checkpoint incomplete)
> (21981) | |
> | | | |
> | | | | | | | |
> | | | | log file switch completion (30)
> | |
> | | | |
> | | | | | | | |
> | | | | Cpu (4405)
> | |
> | | | |
> | | | | | | | |
> | | | | enq: TX - contention (13)
> | |
> | | | |
> | | | | | | | |
> | | | | ASM IO for non-blocking poll (331)
> | |
> | | | |
> | | | | | | | |
> | | | | cell single block physical read (656)
> | |
> | | | |
> | | | | | | | |
> | | | | direct path read (42447)
> | |
> | | | |
> | | | | | | | |
> | | | | direct path write (2)
> | |
> | -> 4 | OPTIMIZER STATISTICS GATHERING | |
> 44M | 58295 | 2201 | +3 | 32 | 3M | | |
> | | 5MB | 0.01 | Cpu (4)
> | |
> | -> 5 | PX BLOCK ITERATOR | |
> 44M | 58295 | 2201 | +3 | 32 | 3M | | |
> | | . | |
> | |
> | -> 6 | TABLE ACCESS STORAGE FULL | TABLE1 |
> 44M | 58295 | 2201 | +3 | 62 | 3M | 10068 | 6GB |
> | | 225MB | 0.01 | Cpu (5)
> | 100% |
> | | | |
> | | | | | | | |
> | | | | cell smart table scan (2)
> | |
> ============================================================
> ============================================================
> ============================================================
> ============================================================
>

--
http://www.freelists.org/webpage/oracle-l
Received on Thu May 12 2022 - 09:02:00 CEST

Original text of this message