<<Back to DB Administration Main Page
Understanding the Oracle Database Technical Architecture in Detail
A high level architecture of non multi tenant (classical) oracle database is explained hereDetail explanation of Database Buffer Cache is presented here
Database Shared Pool in Details:
What is Shared Pool?shared pool is nothing but a meta data cache. The shared pool is used for caching complex objects describing where the data is stored and how it relates to other data and how it can be retrieved. Its a memory component located in oracle database SGA. The shared pool is basically the 2nd largest memory area in SGA after Database buffer Cache. You can configure the shared pool size using shared_pool_size initialization parameter
What is the Purpose of Shared Pool?
The purpose of shared pool is to cache various types of program data.
For Example
Parsed SQL (cursor)
Execution Plan of a SQL
optimizer stats
etc...etc..
Because of the nature of data shared pool stores, it is involved in almost every operation that occurs in the database. Since every operation that occurs in the database access the shared pool, to speedup the shared pool access it is further divided into several sub components as shown below.
Library Cache
The library cache is a shared pool memory structure that stores executable SQL and PL/SQL code and control structures such as locks and library cache handles. In other words it is a library of ready-to-execute SQL statements. In a shared server architecture, the library cache also contains private SQL areas (otherwise private SQL areas resides in process's PGA itself).
Private SQL area
Each session issuing a SQL statement has a private SQL area in its PGA. Each user that submits the same statement has a private SQL area pointing to the same shared SQL area. Thus, many private SQL areas in separate PGAs can be associated with the same shared SQL area.
Shared SQL Areas
As the name suggest, whatever stored in this area is shared among many users/sessions.
Shared SQL Areas contains:
Parsed SQL (cursors)
Frequently used PL/SQL: Executable representation of PL/SQL packages ,procedures and functions etc
Other Type of Objects: that is needed to parse and execute SQL statements including tables, ,indexes, types, methods classes etc.
Execution plan of SQLs
NOTE: Only one shared SQL area exists for a unique statement.
Data Dictionary CacheThe data dictionary cache stores various information like table definition, index information, referential integrity, user information and other metadata. Oracle database uses these metadata very frequently eg to parse a SQL statement.
NOTE: Oracle internally controls the size of Library and dictionary cache. As the overall shared pool changes in size, so does the dictionary and library cache.
Server Result Cache
SQL result cache
Cache recently executed Query Results, which lets Oracle skip the subsequent execution part of the SQL and returns the result directly from result cache improving the performance. Are you worried about the result cache returning incorrect data? Not at all. Oracle automatically invalidates data stored in the result cache if any of the underlying components are modified.
PL/SQL Function Result Cache
Function results can be cached and is system-wide available to all sessions. Changes to dependent objects automatically invalidate the cache
Reserved Pool:
Oracle usages Reserved Pool to allocate a large chunk (over 4 KB) of contiguous memory in the shared pool. For large allocations, Oracle Database attempts to allocate space in the shared pool in the following order:
- From the unreserved part of the shared pool.
- From the reserved pool.
- From memory
Size of the reserved pool can be configured using SHARED_POOL_RESERVED_SIZE initialization parameter. The default value for the SHARED_POOL_RESERVED_SIZE parameter is 5% (controlled by hidden parameter _shared_pool_reserved_pct ) of the SHARED_POOL_SIZE parameter. The default minimum reserved pool allocation is 4,400 bytes ( controlled by hidden parameter _shared_pool_reserved_min_alloc)
Allocation and Reuse of Memory in the Shared Pool
- The first thing you need to know is that Oracle requires contiguous space to satisfy each memory request. Memory is allocated in the form of chunks. A request for 4k chunk can not be fulfilled by 3K chunk +1K chunk, but must be 4K chunk. Most memory allocation is done in 1K and 4K chunks, although there are many smaller unit of allocation is also used
- The database allocates shared pool memory when a new SQL statement is parsed. The memory size depends on the complexity of the statement.
- Oracle database follows the LRU algorithm to age out the item from shared pool to free up the space.
The database also removes a shared SQL area from the shared pool in the following circumstances:
- If statistics are gathered for a table, table cluster, or index, then by default the database gradually removes all shared SQL areas that contain statements referencing the analyzed object after a period of time.
- If a schema object is referenced in a SQL statement, and if this object is later modified by a DDL statement
- If you change the global database name, then the database removes all information from the shared pool.
- You can use the ALTER SYSTEM FLUSH SHARED_POOL statement to manually remove all information in the shared pool.
Technical Implementation of Oracle Shared Pool
As we know Oracle requires a lot of different memory (chunk) sizes in the shared pool, Oracle uses the durations to "group" these different kinds of memory requests. Starting with Oracle 9.2 the shared pool can be divided into sub-pools and starting with Oracle 10g R2 each sub-pool may also be split-up into four durations (which has been reduced to 2 durations with Oracle 12c). The hidden parameter "_kghdsidx_count" (value of which is internally calculated by oracle depending CPU count and shared pool size) controls how much sub-pools should be created. Durations are created automatically if ASMM or AMM is used, which sets the hidden parameter "_enable_shared_pool_durations" to TRUE.Shared pool implementation with Oracle version >= 10.2 and <12
Shared pool implementation with Oracle version >= 12
COL KSPPINM FOR a40
COL KSPPSTVL FOR a20
COL KSPPDESC FOR a80
SET LINE 200
SELECT ksppinm, ksppstvl, ksppdesc
FROM x$ksppi a, x$ksppsv b
WHERE a.indx = b.indx
AND SUBSTR (ksppinm, 1, 1) = '_'
AND a.ksppinm IN ('_kghdsidx_count', '_enable_shared_pool_durations');
Below is the output from 12.1.0.2
Using the below query you can confirm that the shared pool is divided into 2 sub pools
SQL> SELECT DECODE(kghlushrpool,0,'Java Pool',1,'Shared Pool') AS pool, kghluidx
num_subpool FROM x$kghlu;
POOL NUM_SUBPOOL
--------------------------------- -----------
Shared Pool 2
Shared Pool 1
By performing a heap dump of level 2 we can even verify that the Shared pool is divided into sub pool and duration is enabled. I have 2 sub pools with each with 2 durations (0,3) as you can see in the screenshot below
SQL> oradebug setmypid
Statement processed.
SQL> oradebug tracefile_name
/u01/app/oracle/diag/rdbms/orcl/orcl/trace/orcl_ora_350055.trc
SQL> oradebug dump heapdump 2
Statement processed.
$ grep -i "sga heap" /u01/app/oracle/diag/rdbms/orcl/orcl/trace/orcl_ora_350055.trc
If you will deep dive in the trace file of heap dump you will get to know where the shared pool memory is allocated how much and why. The lines that start with “Chunk” identify chunks of memory in the granule. Each chunk shows its starting address and size in bytes
For Example KGLH0 Kernel General Library Heap 0 storing environment, statistics and bind variables stored at address a700005e0 with size of 4096 bytes KQR (Kernal Query Rowcache) PO (Parent Object) stored in a size if 1072 bytes. SQLA (SQL Area) stored in 20480 bytes 5 x 4096 an so on....
Processing Oradebug command 'dump heapdump 2'
KGH Latch Directory Information
ldir state: 2 last allocated slot: 187
Slot [ 1] Latch: 0x1444e05848 Index: 2 Flags: 3 State: 2 next: (nil)
...............
HEAP DUMP heap name="sga heap" desc=0x600013d0
extent sz=0x4d3a8 alt=272 het=32767 rec=9 flg=130 opc=0
parent=(nil) owner=(nil) nex=(nil) xsz=0x68018 heap=(nil)
fl2=0x60, nex=(nil)
pdb id=1
ds for latch 1: 0x60064348 0x60068c50
ds for latch 2: 0x6006e098 0x600729a0
reserved granule count 0 (granule size 268435456)
******************************************************
HEAP DUMP heap name="sga heap(1,0)" desc=0x60064348
extent sz=0xfe0 alt=272 het=32767 rec=9 flg=130 opc=0
parent=(nil) owner=(nil) nex=(nil) xsz=0x10000000 heap=(nil)
fl2=0x20, nex=(nil), dsxvers=1, dsxflg=0x0
dsx first ext=0x1450000000
dsx empty ext bytes=0 subheap rc link=0x14500000b8,0x14500000b8
pdb id=1
latch set 1 of 2
durations enabled for this heap
reserved granules for root 0 (granule size 268435456)
EXTENT 0 addr=0xa70000000
Chunk a70000058 sz= 248 freeable "KGLDA "
Chunk a70000150 sz= 240 freeable "KGLDA "
Chunk a70000240 sz= 384 recrPT030 "KGLHD " latch=(nil)
Chunk a700003c0 sz= 544 recrPT021 "KGLHD " latch=(nil)
Chunk a700005e0 sz= 4096 recrUR021 "KGLH0^e329e33c " latch=(nil)
ds 53aeb0700 sz= 4096 ct= 1
Chunk a700015e0 sz= 144 free " "
Chunk a70001670 sz= 1072 recrUT005 "KQR PO " latch=0xb1eb13d8
Chunk a70001aa0 sz= 4096 recrPR007 "KGLH0^347a0496 " latch=(nil)
ds 5a75e91f0 sz= 4096 ct= 1
..................
Chunk a7001a678 sz= 1072 recrUR005 "KQR PO " latch=0xb1eb13d8
Chunk a7009b220 sz= 576 recrPT056 "KQR SO " latch=(nil)
.................
Chunk 65cbc8730 sz= 4096 freeableU "SQLA^b6955f1c " ds=0x778fd78d8
Chunk 65cbc9730 sz= 4096 recrUT011 "SQLA^18943aa4 " latch=(nil)
ds 59e334b58 sz= 20480 ct= 5
652b00028 sz= 4096
652b01028 sz= 4096
652b02028 sz= 4096
652b03028 sz= 4096
Chunk 65cbca730 sz= 936 freeableU "KGLA^93fddbf6 " ds=0x5a4415e08
Chunk 65cbcaad8 sz= 3856 free " "
You can query V$SQL to find out which SQL is stored in a particular memory chunk using query below
SQL > select child_number,child_address,sql_text from v$sql where hash_value =
to_number('18943aa4', 'XXXXXXXXXXXXXXXX');
You can even perform the level 2 granule dump and see how the shared pool is arranged in memory.
SQL> oradebug setmypid
Statement processed.
SQL> oradebug tracefile_name
/u01/app/oracle/diag/rdbms/orcl/orcl/trace/orcl_ora_267550.trc
SQL> oradebug dump dump_all_comp_granules 2
Statement processed.
$ grep -i "sga heap(" /u01/app/oracle/diag/rdbms/orcl/orcl/trace/orcl_ora_267550.trc
Address 0xd0000000 to 0xe0000000 in sga heap(1,0) (idx=1, dur=1)
Address 0xc0000000 to 0xd0000000 in sga heap(1,0) (idx=1, dur=1)
Address 0xb0000000 to 0xc0000000 in sga heap(2,0) (idx=2, dur=1)
Address 0xa0000000 to 0xb0000000 in sga heap(2,0) (idx=2, dur=1)
..........................................................
Address 0x210000000 to 0x220000000 in sga heap(1,3) (idx=1, dur=4)
Address 0x200000000 to 0x210000000 in sga heap(2,0) (idx=2, dur=1)
Address 0x1f0000000 to 0x200000000 in sga heap(2,3) (idx=2, dur=4)
..........................................................
Orcale require shared pool latches to work with shared pool eg. to pin/unpin an object , allocate memory chunk etc etc.. Although the number of shared pool latches are hardcoded into oracle, the one actually used depends on the number of sub pools. There is always 1 shared pool latch for each sub pool.
SQL> SELECT child#, gets
FROM v$latch_children
WHERE name = 'shared pool'
ORDER BY child#;
CHILD# GETS
---------- ----------
1 2805101061
2 3892790786
3 390
4 390
5 390
6 390
7 390
7 rows selected.
Since the shared pool in my case is divided into 2 sub pools only 2 latches are active.
By now you would have probably understand why Oracle split-up the shared pool in this way. Basically there were two reasons
- The first reason is scalability - Oracle has one shared pool latch per sub-pool which makes various operations like shared pool memory allocation or linked list modifications much more scalable reducing the shared pool latch contention.
- The second reason is to avoid memory fragmentation as a consequence ORA-04031 errors
Who is the top 10 Consumer of Shared Pool
SELECT *FROM ( SELECT con_id, name, bytes / POWER (1024, 2) MB
FROM v$sgastat
WHERE pool = 'shared pool'
ORDER BY bytes DESC)
WHERE ROWNUM < 11;
View Related to Shared Pool
v$db_object_cach viewv$librarycache;
v$rowcache
v$shared_pool_advice
V$SQL
v$SQL_AREA
v$OPEN_CURSORS
v$sgastat
v$sqlstat
V$SQL_SHARED_CURSOR
v$sgainfo
v$shared_pool_reserved;
init Parameters related to shared pool
session_cached_cursorscursor_space_for_time
cursor_sharing
Comments
Post a Comment