Re: Re: Re: segment covers more blocks than needed

From: <l.flatz_at_bluewin.ch>
Date: Wed, 29 Jan 2020 12:04:34 +0100 (CET)
Message-ID: <716993538.17839.1580295874423_at_bluewin.ch>


Hi Jonathan,

it is a underestimate.
Find the runtimestats below. The Statement has not finished. It would go on for hours. The missestimate is in line 5, the real number of rows is 20. Runtime Stats does not reflect it, because Statement Needs to run longer. Sorry for the mess, I can not set a fixed font in the web email Interface.

Thanks

Lothar


| Id  | Operation                     | Name             | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  |
---------------------------------------------------------------------------------------------------------------------

| 0 | SELECT STATEMENT | | 1 | | 0 |00:00:00.01 | 0 | 0 |
| 1 | HASH GROUP BY | | 1 | 1 | 0 |00:00:00.01 | 0 | 0 |
| 2 | NESTED LOOPS | | 1 | 1 | 0 |00:00:00.01 | 0 | 0 |
| 3 | NESTED LOOPS | | 1 | 1 | 0 |00:00:00.01 | 0 | 0 |
| 4 | MERGE JOIN CARTESIAN | | 1 | 1 | 0 |00:00:00.01 | 0 | 0 |
|* 5 | TABLE ACCESS FULL | TABLE1 | 1 | 1 | 1 |00:00:00.01 | 15 | 0 |
| 6 | BUFFER SORT | | 1 | 468M| 0 |00:00:00.01 | 0 | 0 |
| 7 | PARTITION RANGE ALL | | 1 | 468M| 418M|00:03:26.59 | 2616K| 2613K|
| 8 | TABLE ACCESS FULL | TABLE2 | 841 | 468M| 418M|00:03:23.68 | 2616K| 2613K|
|* 9 | INDEX UNIQUE SCAN | TABLE2_PK | 0 | 1 | 0 |00:00:00.01 | 0 | 0 | |* 10 | TABLE ACCESS BY INDEX ROWID| TABLE2 | 0 | 1 | 0 |00:00:00.01 | 0 | 0 | ---------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):


 
   5 - filter(("VERS"."DWH_VALID_TO">SYSDATE_at_! AND "VERS"."DWH_VALID_FROM"<=SYSDATE@!))
   9 - access("HEAD"."DWH_HEAD_ID"="VERS"."DWH_HEAD_ID")
       filter("H"."FK_PARTNER_ID"="HEAD"."DWH_HEAD_ID")
  10 - filter("HEAD"."DWH_UNLOAD_DATE" IS NULL)
 

Note


  • dynamic statistics used: dynamic sampling (level=4)

----Ursprüngliche Nachricht----
Von : jonathan_at_jlcomp.demon.co.uk
Datum : 29/01/2020 - 11:49 (MZ)
An : l.flatz_at_bluewin.ch
Cc : Oracle-L_at_freelists.org
Betreff : Re: Re: segment covers more blocks than needed

Lothar,

Can you give an example of exactly what you mean by bad estimates. Is it a significant over-estimate, or a zero estimate, or one of the "guess" figures ?

Regards
Jonathan Lewis



From: l.flatz_at_bluewin.ch <l.flatz_at_bluewin.ch> Sent: 29 January 2020 10:38
To: Jonathan Lewis
Cc: Oracle-L_at_freelists.org
Subject: Re: Re: segment covers more blocks than needed

Hi Jonathan,

thanks for the explaination.
I have tested the Segment and indeed the populated blocks are somewhere in the extent and not at the start of the Segment. Where I think Things goes wrong is that the blocks at the start of the Segment are even considered for dynamic sampling. I believe the dynamic sampling arrives at the Conclusion that the segement is empty. We have tested with serveral Levels of dynamic sampling . Anything below 3 works, because DS is not done. Any Level between 3-6 Fails to generate a correct estimate. I wonder why empty blocks are not ignored by DS. Can you shed some light on it?

Regards

Lothar

----Ursprüngliche Nachricht----
Von : jonathan_at_jlcomp.demon.co.uk
Datum : 28/01/2020 - 17:00 (MZ)
An : Oracle-L_at_freelists.org
Betreff : Re: segment covers more blocks than needed

ASSM formats blocks on demand in chunks of 16 consecutive blocks. But the blocks aren't necessarily going to be the ones near the start of the extent (and when I've looked - only in passing - at cases where the segment size is 1MB or 8MB the first 16 blocks seem to be at, or close to, the end of the extent.

The tablescan is then done from the start of segment to the "Low highwater mark (LHWM)" in unit of db_file_multiblock_read_count, then in units of multiples of 16 blocks s between the LHWM and the High highwater mark (HHWM) - where the LHWM is nominally the point up to which the segment is formatted with no unformatted gaps below it. (If you're unlucky Oracle could think that LHWM is right at the start of the segment when it's really thousands of blocks into the segment - but I haven't seen anything that extreme recently).

https://jonathanlewis.wordpress.com/2013/07/30/assm-2/ https://jonathanlewis.wordpress.com/2010/07/19/fragmentation-3/#more-4147

Regards
Jonathan Lewis



From: oracle-l-bounce_at_freelists.org <oracle-l-bounce_at_freelists.org> on behalf of l.flatz_at_bluewin.ch <l.flatz_at_bluewin.ch> Sent: 28 January 2020 15:50
To: Oracle-L_at_freelists.org
Subject: segment covers more blocks than needed

Hi,

I am no classical DBA, thus this question might be trivia for youl. This issue causes serious misestomate when dynamic_sampling >= 4 is used. We got a DWH with many small tables where stats are showing 502 blocks in DBA_TABLES. Empty blocks is 0.
The Point is that there must be blocks which must (almost?) empty. 502 Blocks Matches with the initial size of the Segment. We did a testcase. We created am empty table. No blocks when querying dba_tables of course. After we inserted the first row (deferred_segment_creation = true) , again 502 appeared in dba_tables. DBMS_SPACE features this Output:

L/SQL-Prozedur erfolgreich abgeschlossen. Unformatted Blocks = 486
Unformatted Bytes = 7962624

FS1 Bytes (at least 0 to 25% free space) = 0
FS1 Blocks(at least 0 to 25% free space) = 0
FS2 Bytes (at least 25 to 50% free space)= 0
FS2 Blocks(at least 25 to 50% free space)= 0
FS3 Bytes (at least 50 to 75% free space) = 0
FS3 Blocks(at least 50 to 75% free space) = 0
FS4 Bytes (at least 75 to 100% free space) = 262144
FS4 Blocks(at least 75 to 100% free space)= 16
Full Blocks in segment = 0
Full Bytes in segment = 0

Segment_space_managment is AUTO. Tablespace has a uniform extent. Runtime Stats show 28 buffers on FTS, proving that the HWM is not set after the first block. Avg_row_len is 200. Remember this is only 1 row.

What is going on here?

Regards

Lothar

Full Bytes in segment = 0Full Blocks in segment = 0FS4 Blocks(at least 75 to 100% free space)= 63FS4 Bytes (at least 75 to 100% free space) = 1032192FS3 Blocks(at least 50 to 75% free space) = 1FS3 Bytes (at least 50 to 75% free space) = 16384FS2 Blocks(at least 25 to 50% free space)= 0FS2 Bytes (at least 25 to 50% free space)= 0FS1 Blocks(at least 0 to 25% free space) = 0FS1 Bytes (at least 0 to 25% free space) = 0Unformatted Bytes = 7176192Unformatted Blocks = 438

--
http://www.freelists.org/webpage/oracle-l



--
http://www.freelists.org/webpage/oracle-l



--
http://www.freelists.org/webpage/oracle-l
Received on Wed Jan 29 2020 - 12:04:34 CET

Original text of this message