Oracle SQL
  • LICENSE

When bloggers get it wrong – part 2

Posted on May 4, 2017 by Roger MacNicol Posted in adaptive serial direct path reads, oracle, SmartScan, trace, troubleshooting 1 Comment

In Part 2 we are going to look at making use of the trace events that show what was discussed in Part 1. 
NB: Oracle no longer adds new numeric trace events, going forward new trace events use the Unified Tracing Service whose grammer is much simpler. The elements we need are:

trace[[x.]y] disk = [ lowest | low | medium | high | highest ]

For example Table Scan tracing is in the DATA hierachy:

[1] DATA
[2] KDS    “Kernel Data Scan”
[3] KDSFTS  “Full Table Scan”
[3] KDSRID  “RowID”

‘trace[KDSFTS] disk low’ – only trace full table scans
‘trace[KDSRID] disk low’ – only trace fetch by rowid
‘trace[KDS.*] disk low’ – trace both table scans and fetch by rowid
NB: don’t use ‘lowest’ with KDS – it is used for memory tracing only

Tracing Full Table Scans: KDSFTS

At the beginning of a granule we see if it is possible to use Turbo Scan (which is a prerequisite for using Exadata Smart Scan) and the data object number being scanned:

kdst_mode(): kdst_mode_possible: 1 fastPathFetch: 1 
kdst_mode(): push_complex: 1 sage_push: 0 pred_split: 0 objd_ktid: 78768

If we can use Turbo Scan, we see the initialization of the row source and the sql_id and text of the query:

kdsirsf(): not DR|DW td: 0x7fb2a16245e0 flag: 0x1080008 heap: 1

The trace also told us this was not an ABTC scan (see further down this entry)
NB: several scans may be interleaved so use the ‘td’ address to follow the scan of interest:

kdsirsf(): kcb_clone on td: 0x7fb2a16245e0 parent: 0x7fb2a16245f8 child: 0x7fb2a1624c70

Dumping sqltext for sqlid: dch22s8kyzgp8
kxsDumpSqlTextFromSQLID SQL= select sum(S_ACCTBAL) from supplier

This is important because it enables us to tie the trace into the SQL v$ views. The scan then starts:

kdsttgr: start td 0x7fb2a16245e0 for 32767 rows at slot 0 blkrows 0
kdstf000010100001000km -> FCO ROWP RSET ARR

First we see the extent map to be scanned get loaded, the start rdba of each extent, and the number of blocks in the extent: 

map with 10 extents
Ext: 0, dba: 0x140000e, len: 3, skp: 0
Ext: 1, dba: 0x1400011, len: 4, skp: 0

Second, we will see each block in turn get fetched, since extent 0 started at rdba  0x140000e, we will see 0x140000e, 0x140000e, 0x1400010 get fetched in order etc 
Since this is a serial scan, it will be followed by extent 1 (a PQ granule would have had the extents sorted by rdba)

kdst_fetch0(): req tsn: 5 dba: 0x140000e dsf: 0x1 dsf2: 0x0
kdst_fetch0(): req tsn: 5 dba: 0x140000f dsf: 0x100001 dsf2: 0x4000

Finally when all the blocks have been consumed we will see the scan  terminate:

kdsers(): ending td: 0x7fb2a16245e0
kdsers(): kcb_endscan on td: 0x7fb2a16245e0

Tracing the decision to use buffer cache or direct read

To understand the decisoin whether to use buffer cache or direct read for a scan, you need to enable tracing for buffer cache decision making:

alter session set events ‘10358 trace name context forever, level 2’;
alter session set events ‘trace [NSMTIO] disk highest‘; 

The Medium Table Threshold (MTT) 

Our query against the Supplier table starts with “Is Small Table”?
Our table has 1689 blocks, the buffer cache has space for 13,512 blocks, and the Small Table Threshold is therefore 270 blocks:

kcbism: islarge 1 next 0 nblks 1689 type 2, bpid 3, kcbisdbfc 0 kcbnhl 1024  kcbstt 270  keep_nb 0 kcbnbh 13512 kcbnwp 1

Clearly this isn’t a small table; so “Is Medium Table”? Well, 1689 blocks is greater than 1/10 of the buffer cache i.e. 1,351 blocks so it isn’t medium:

kcbimd: nblks 1689 kcbstt 270 kcbpnb 1351 bpid 3 kcbisdbfc 0 is_medium 0

So “Is Very Large Object”? Well it’s small enough relative to the buffer cache to be worth costing out so its not large:

kcbivlo: nblks 1689 vlot 500 pnb 13512 kcbisdbfc 0 is_large 0

NSMTIO shows the decision (but we don’t give any internal details of the cost model used). Here we see the “Direct Path Check” shows the cost model predicted using Direct Read would be best and that we need to force a check point.

NSMTIO: qertbFetch:[MTT < OBJECT_SIZE < VLOT]: Checking cost to read from caches(local/remote)
 and checking storage reduction factors (OLTP/EHCC Comp)
NSMTIO: kcbdpc: DirectRead: tsn: 5, objd: 79042, objn: 79042 ckpt: 1, nblks: 1689, ntcache: 0, ntdist:0

Let’s make the buffer cache much bigger to make MTT bigger than the table to see the tracing for that. With space for 28,368 blocks in the cache, MTT is now 2,836 blocks, and STT is therefore 567 blocks so we see the is_medium check set to true

kcbism:  islarge 1 next 0 nblks 1689 type 2, bpid 3, kcbisdbfc 0 kcbnhl 2048 kcbstt 567
               keep_nb 0 kcbnbh 28368 kcbnwp 1
kcbimd: nblks 1689 kcbstt 567 kcbpnb 2836 bpid 3 kcbisdbfc 0 is_medium 1

So is it worth it to “Cache Medium Table”? This has to factor in such things as the current state of the cache and the aging of the current contents, and whether the entire database can be cached (kcbisdbfc):

kcbcmt1: scann age_diff adjts last_ts nbuf nblk has_val kcbisdbfc 0 8168 0 28368 1689 0 0
kcbivlo: nblks 1689 vlot 500 pnb 28368 kcbisdbfc 0 is_large 0

NSMTIO: qertbFetch:[MTT < OBJECT_SIZE < VLOT]: Checking cost to read from caches(local/remote) and checking storage reduction factors (OLTP/EHCC Comp)
NSMTIO: kcbdpc: DirectRead: tsn: 5, objd: 79042, objn: 79042 ckpt: 1, nblks: 1689, ntcache: 0, ntdist:0

and here we see that even though the table is smaller than 10% of the buffer cache, the current state of the buffer cache meant that it was not worth caching and so we will still use Direct Read.

Forcing Buffer Cache scan using ABTC

Since we couldn’t get our scan to use the buffer cache, lets try using Automatuc Big Table Caching by setting the system parameter: DB_BIG_TABLE_CACHE_PERCENT_TARGET=50. Now we see it costing Serial DW scan:

kcbism: islarge 1 next 0 nblks 1689 type 2, bpid 3, kcbisdbfc 0 kcbnhl 2048 kcbstt 567 keep_nb 0 kcbnbh 28368 kcbnwp 1
kcbivlo: nblks 1689 vlot 500 pnb 28368 kcbisdbfc 0 is_large 0

The difference is that now we look at the object’s temperature and here the ABTC policy returns that the table should be cached (ABTC policy is true) and we no longer choose Direct Read.:

NSMTIO: kcbimd: serial DW scan <0.5, 79042> nblks 1689 policy 1 imc 0 pq 0)
NSMTIO: kcbimd: serial DW cache scan <0.5, 79042> nblks 1689 pq
NSMTIO: qertbFetch: NoDirectRead:[- STT < OBJECT_SIZE < MTT]: Obect’s size: 1689 (blocks), Threshold: MTT(2836 blocks)

abtc direct path reads oracle Roger MacNicol SmartScan
« When bloggers get it wrong – part 1
What’s new in 12.2 CELLMEMORY Part 1 »
photo Sayan Malakshinov

Oracle ACE Pro Oracle ACE Pro

DEVVYOracle Database Developer Choice Award winner

Oracle performance tuning expert

UK / Cambridge

LinkedIn   Twitter
sayan@orasql.org

Recent Posts

  • CBO and Partial indexing
  • Slow index access “COL=:N” where :N is NULL
  • Where does the commit or rollback happen in PL/SQL code?
  • :1 and SP2-0553: Illegal variable name “1”.
  • ORA exceptions that can’t be caught by exception handler

Recent Comments

  • Oracle SGA 값을 증가 시킬 때 발생 장애 원인 – DBA의 정석 on Example of controlling “direct path reads” decision through SQL profile hints (index_stats/table_stats)
  • Oracle SQL | Oracle diagnostic events — Cheat sheet on Where does the commit or rollback happen in PL/SQL code?
  • Functions & Subqueries | Oracle Scratchpad on Deterministic function vs scalar subquery caching. Part 3
  • Materialized views state turns into compilation_error after refresh - kranar.top - Answering users questions... on Friday prank: select from join join join
  • Exadata Catalogue | Oracle Scratchpad on When bloggers get it wrong – part 1
  • Exadata Catalogue | Oracle Scratchpad on Serial Scans failing to offload
  • lateral join – decorrelation gone wrong – svenweller on Lateral view decorrelation(VW_DCL) causes wrong results with rownum
  • 255 column catalogue | Oracle Scratchpad on Intra-block row chaining optimization in 12.2
  • 255 column catalogue | Oracle Scratchpad on row pieces, 255 columns, intra-block row chaining in details
  • opt_estimate catalogue | Oracle Scratchpad on Correct syntax for the table_stats hint

Blogroll

  • Alex Fatkulin
  • Alexander Anokhin
  • Andrey Nikolaev
  • Charles Hooper
  • Christian Antognini
  • Coskan Gundogar
  • David Fitzjarrell
  • Igor Usoltsev
  • Jonathan Lewis
  • Karl Arao
  • Mark Bobak
  • Martin Bach
  • Martin Berger
  • Neil Chandler
  • Randolf Geist
  • Richard Foote
  • Riyaj Shamsudeen
  • Tanel Poder
  • Timur Akhmadeev
  • Valentin Nikotin

Meta

  • Log in
  • Entries feed
  • Comments feed
  • WordPress.org
©Sayan Malakshinov. Oracle SQL