- Overview of Latch and Mutex Architecture
- Measuring Latch and Mutex Contention
- Latch and Mutex Scenarios
- Intractable Latch Contention
- Summary
Latch and Mutex Scenarios
Along with these generic methods of associating latch waits with SQLs and segments, there are diagnostic techniques specific to certain types of latch contention. We look at these as we discuss specific latch/mutex wait scenarios in the sections that follow.
Library Cache Mutex Waits
The library cache is the part of the shared pool in which cached definitions of SQL, PL/SQL, and Java classes are held. Modifications to the library cache are protected by library cache mutexes. Prior to Oracle Database 10g Release 2, they were protected by library cache latches.
Oracle maintains a cache of SQL statements in the shared pool. If a matching SQL is found in the shared pool, then most of the overhead of parsing a statement can be avoided. Such a parse is called a soft parse. If no matching SQL is found, a hard parse must be performed.
The most common reason to acquire a library cache mutex in exclusive mode is to add a new entry to the cache. This happens, for instance, when we parse a new SQL statement. Oracle looks for a matching entry in the cache, and if one is not found (a “miss”), it acquires the relevant mutex and inserts the new entry. Failing to obtain the mutex will result in a library cache: mutex X wait.
The most common cause of library cache mutex contention is excessive hard parsing caused by a failure to use bind variables in application code. For example, in the following Java snippet, a SQL statement object is created, executed, and discarded:
Statement s=oracleConnection.createStatement(); s.execute("UPDATE sh.customers SET cust_valid = 'Y'"+ " WHERE cust_id = 1"); s.close();
If your application does nothing but execute a single SQL, then this code is probably okay. But it’s common for a SQL statement to be executed more than once, selecting or modifying different rows with each execution. This next Java snippet issues an UPDATE statement once for every customer ID held in the custIdList array:
1 for (int custId : custIdList) { 2 Statement stmt = oracleConnection.createStatement(); 3 stmt.execute("UPDATE sh.customers SET cust_valid = 'Y'" 4 + " WHERE cust_id = " + custId); 5 stmt.close(); 6 }
The loop starting on line 1 iterates through an array of CUST_ID values. We create a statement object (line 2) and then construct and execute an UPDATE statement once for each customer in the list. We concatenate the custId from the list into the SQL string on line 3.
This code will work, of course, but each UPDATE statement will need to be parsed as well as executed. This parse overhead can be significant. Furthermore, because each SQL is unique (it includes the hardcoded custId), we’re unlikely to find a matching SQL in the shared pool. Therefore, a hard parse—one in which no matching SQL is found in the shared pool—will be required.
The next code snippet shows the bind variable technique in Java. The SQL statement is created as a PreparedStatement and includes a bind variable—identified as :custId—which acts as a placeholder for the parameters to the SQL. The variable is assigned a value on line 5 prior to each execution on line 6:
1 PreparedStatement stmt = oracleConnection.prepareStatement( 2 "UPDATE sh.customers SET cust_valid = 'Y'" 3 + " WHERE cust_id = :custId"); 4 for (int custId : custIdList) { 5 stmt.setInt(1, custId); 6 stmt.execute(); 7 }
Using the bind variable technique radically reduces the parse overhead of SQL execution, and in particular, it reduces the amount of library cache mutex contention.
To identify the SQLs that are causing the most hard parses, we need to find those SQLs that are identical other than for the values of literals. These SQLs will show up in V$SQL as SQLs with the same value for FORCE_MATCHING_SIGNATURE, as shown in Listing 16.5.
Listing 16.5 Finding SQLs That Are Not Using Bind Variables
SQL> WITH force_matches AS 2 (SELECT force_matching_signature, 3 COUNT( * ) matches, 4 MAX(sql_id || child_number) max_sql_child, 5 DENSE_RANK() OVER (ORDER BY COUNT( * ) DESC) 6 ranking 7 FROM v$sql 8 WHERE force_matching_signature <> 0 9 AND parsing_schema_name <> 'SYS' 10 GROUP BY force_matching_signature 11 HAVING COUNT( * ) > 5) 12 SELECT sql_id, matches, parsing_schema_name schema, sql_text 13 FROM v$sql JOIN force_matches 14 ON (sql_id || child_number = max_sql_child) 15 WHERE ranking <= 10 16 ORDER BY matches DESC; SQL_ID MATCHES SCHEMA ------------- ---------- -------------------- SQL_TEXT ------------------------------------------------------------------ gzxu5hs6sk4s9 13911 OPSG select max(data) from log_data where id=717.91
The query reveals that there were 13,911 instances of a SQL statement that was identical except for the value of a variable—a variable that could have been represented by a bind variable.
Ideally, applications should make use of bind variables whenever possible by changing the application code, as outlined earlier in this section. However, it’s not always easy or possible to rewrite an application to use bind variables. Therefore, Oracle provides a mechanism for imposing bind variables transparently; when the parameter CURSOR_SHARING is set to FORCE or SIMILAR, then Oracle can replace a statement such as this:
SELECT MAX(data) FROM log_data WHERE id=717.91
with a statement like this:
SELECT MAX(data) FROM log_data WHERE id=:"SYS_B_0"
Oracle will then substitute the appropriate values into the system-generated bind variables (value 717.91 would be assigned in the previous example), and the library cache miss will be avoided. As we saw earlier, this behavior reduces parse overhead—since Oracle can retrieve the already parsed version from the shared pool—and it also reduces mutex contention, since Oracle doesn’t have to acquire the mutex in exclusive mode if the matching SQL is found.
Library Cache Pin
The library cache pin wait is not strictly a latch or mutex wait, but it often shows up in similar circumstances. A library cache pin is required whenever an object in the library cache is to be executed, parsed, or reparsed. The library cache pin is acquired in exclusive mode if, for instance, the execution plan for a SQL statement needs to be changed or a PL/SQL package is modified or recompiled. The library cache pin is acquired in exclusive mode by the sessions executing the object.
The session wanting to modify the object will attempt to acquire the library cache pin in exclusive mode; sessions executing the object will be holding a shared library cache pin.
Excessive waits on the library cache pin may suggest that PL/SQL packages are being recompiled during periods of heavy concurrent execution. If possible, schedule recompilation during maintenance windows.
Shared Pool Latch
The primary purpose of shared pool latches is to control access to the shared pool memory map. Sessions that are looking for free space in the shared pool for a new SQL statement or PL/SQL package will need to acquire shared pool latches, and many Oracle internal operations (resizing the shared pool for instance) will acquire these latches as well.
Excessive hard parsing—the primary cause of library cache mutex contention—generally results in shared pool latch contention as well, because the constant allocation of “one-off” SQL statements will fragment the shared pool and require continual deallocation of old statements. This will show up as waits for the latch: shared pool event.
Shared pool fragmentation has other deleterious side effects, including ORA-4031 errors (“unable to allocate x bytes of shared memory”) and excessive shared pool memory consumption. Over the years, a variety of techniques have been employed to combat this fragmentation:
- Some sites flush the shared pool periodically using the ALTER SYSTEM FLUSH SHARED_POOL command.
- Setting a minimum size for the shared pool when using automatic SGA memory management is almost always a good idea but particularly if shared pool latch contention is present. Using automatic SGA memory management can exacerbate fragmentation issues, since the memory management algorithms are not always able to predict or measure the degree of fragmentation that will result from continual resizing.
- Pinning large but infrequently executed PL/SQL packages in the shared pool—using DBMS_SHARED_POOL—might help reduce fragmentation by preventing large objects moving in and out of memory.
- The SHARED_POOL_RESERVED_SIZE parameter controls the amount of shared pool reserved for large memory allocations. In some instances, increasing the size of this parameter may reduce pressure on the shared pool latch by reducing the amount of time it takes to find large, contiguous chunks of memory
Cache Buffers Chains Latch
A cache buffer chain (CBC) is a doubly linked list of buffer headers pointing to buffers in the buffer cache that hash to a common value. There are a number of CBC latches, each latch protecting multiple cache buffer chains.
When a session needs to access a buffer in the buffer cache, it must acquire a CBC latch on the “chain” that contains that buffer. Contention for this latch results in waits for the latch: cache buffers chains event.
The amount of time it takes to access a block in memory is very small, and there are a large number of CBC latches. Nevertheless, cache buffers chains latch contention can become significant on systems with very high logical read rates, especially if these logical reads concentrate on a small number of blocks. Another possible cause is the creation of long buffer hash chains caused by multiple consistent read copies of an individual buffer.
Ironically, cache buffers chains latch contention often occurs on systems that are almost perfectly optimized in every other respect: in order to get the very high logical read rates necessary to induce cache buffers chains contention, the system typically needs to minimize all other forms of contention and waits, such as IO, parsing, and locking.
High logical read rates and the resulting CBC latch contention can, however, be the result of poorly tuned SQL as well. For example, a nested loops join that uses an unselective index may scan the same set of blocks on the inner table many times over. These blocks will then become “hot” and may be the subject of latch contention. Tuning the SQL by creating a more selective index will reduce the redundant logical reads and reduce the latch contention as well as improve the performance of the SQL concerned.
The mapping of cache buffers to cache buffers chains latches is based on an Oracle hashing algorithm, and the number of blocks per latch can vary significantly. If you want to examine the configuration of your cache buffers chains latches, the query in Listing 16.6—which you must run as SYS—will reveal the latch to buffer ratios.
Listing 16.6 Revealing the CBC Latch to Buffer Ratio
SQL> SELECT COUNT(DISTINCT l.addr) cbc_latches, 2 SUM(COUNT( * )) buffers, 3 MIN(COUNT( * )) min_buffer_per_latch, 4 MAX(COUNT( * )) max_buffer_per_latch, 5 ROUND(AVG(COUNT( * ))) avg_buffer_per_latch 6 FROM v$latch_children l 7 JOIN 8 x$bh b 9 ON (l.addr = b.hladdr) 10 WHERE name = 'cache buffers chains' 11 GROUP BY l.addr; CBC Latch Buffer Cache Min Buffer Max Buffer Avg Buffer Count Buffers Per Latch Per Latch Per Latch ---------- ------------ ---------- ---------- ---------- 8192 89386 3 46 11
On this database, an average of 11 blocks was associated with each latch, but some latches protected as few as 3 or as many as 46 blocks.
The chance that contention for a cache buffers chains latch is a result of two hot blocks being mapped to the same latch is pretty small, and while you can attempt to change the number of latches using undocumented Oracle parameters (such as _db_block_hash_buckets), the chances that you’ll relieve latch contention by doing so are not good.
Each latch exposes its individual statistics into the view V$LATCH_CHILDREN. You can link these latches to the buffers they protect by examining the view X$BH (which, unfortunately, you can only do as the SYS user). The query in Listing 16.7 joins the two tables to identify the segments that are most heavily associated with cache buffers chains latch sleeps.
Listing 16.7 Identifying Segments with High CBC Latch Sleeps
SQL> WITH cbc_latches AS 2 (SELECT addr, name, sleeps, 3 rank() over(order by sleeps desc) ranking 4 FROM v$latch_children 5 WHERE name = 'cache buffers chains') 6 SELECT owner, object_name,object_type, 7 COUNT(distinct l.addr) latches, 8 SUM(tch) touches 9 FROM cbc_latches l JOIN x$bh b 10 ON (l.addr = b.hladdr) 11 JOIN dba_objects o 12 ON (b.obj = o.object_id) 13 WHERE l.ranking <=100 14 GROUP BY owner, object_name,object_type 15 ORDER BY sum(tch) DESC; OWNER OBJECT_NAME OBJECT_TYP LATCHES TOUCHES ------------ -------------------- ---------- ---------- ------------ OPSG LOG_DATA TABLE 103 1,149
This query shows that the top 100 cache buffers chains latches are all associated with the LOG_DATA table and that it is probably the high rates of logical I/O against this table that are the root cause of the cache buffers chains latch contention we are experiencing.
Finding the segment involved in cache buffers chains contention is a good first step, but where do we go from here? There are a couple of possibilities:
- If the cache buffers chains contention is associated with an index, then you could consider reimplementing the table as a hash cluster and use a hash key lookup rather than a B-tree index lookup. B-tree indexes often become associated with cache buffers chains contention, because index root and branch blocks tend to be accessed more frequently than index leaf blocks or table blocks. If we use a hash cluster lookup instead, this potential for cache buffers chains latch contention is eliminated. If the B-tree index is part of a nested loops join, then a hash join might similarly relieve pressure on the index blocks.
- At the risk of belaboring the point, is there any way to reduce the logical I/O rate? Review and tune SQL that accesses the table: perhaps a judicious index or two could reduce the logical I/O demand. Perhaps Oracle client-side caching (CLIENT_RESULT_CACHE_SIZE parameter) or the Oracle server-side result set cache could be used to reduce the logical I/O rate.
- If there are multiple hot rows within the same hot block, explore options for splitting these rows across multiple blocks. Partitioning the table and its indexes can be an attractive option, especially since it requires no changes to application code.
Other Latch Scenarios
Cache buffers chains latches and library cache mutexes are the most commonly encountered forms of latch/mutex contention. However, other forms of latch contention arise from time to time. Here are some of the other latches that you might encounter:
- Cache buffers lru chain latch: This latch controls access to the LRU (least recently used) list in the buffer cache. Buffers move up and down this list as they are accessed and, once they reach the cold end of the list, are eventually flushed out of the pool. Contention for this latch is generally associated with cache buffers chains latch contention and will generally respond to a similar resolution. However, while the cache buffers chains latch is most sensitive to hot blocks, the cache buffers lru chains latch is more heavily utilized when new blocks are introduced into the buffer cache.
- Simulator lru latch: This latch controls access to the “virtual” LRU list that Oracle uses to work out the effect of increasing or decreasing the size of the buffer cache. This information is used to populate the DB_CACHE_ADVICE tables and to perform automatic memory management. Contention for this latch can occur under similar circumstances as for the cache buffers chains and cache buffers lru chains latches and may mask contention for those latches. Setting DB_CACHE_ADVICE to OFF will usually eliminate this contention but may merely shift the contention to the cache buffers chains latch. Note also that contention on this latch was associated with some Oracle bugs in early versions of Oracle 11.
- Redo allocation latch: This latch serializes entries to the redo log buffers and private “strands,” both of which buffer I/O to the redo logs. This latch—and the related redo copy latch—were often implicated in latch contention issues in earlier versions of Oracle. However, Oracle made significant changes to redo handling in Oracle Database 9i and 10g, parallelizing redo generation, creating multiple independent buffers, and introducing private buffer strands. As a result, redo-related latch contention issues are rarely reported today. You may see some contention for the redo allocation latch when there are very high levels of concurrent DML activity. However, it’s unlikely to dominate overall performance, since such high levels of DML generally create substantial I/O-related waits.
- Session allocation and process allocation latches: These latches are often involved during the creation of a new session and, in the case of process allocation, associated server process. Contention on these latches will often be seen if there is a very high rate of logon/logoff to the database. Oracle is not really optimized for sessions that connect, issue a single SQL, and then disconnect; performance will usually be better when sessions stay connected and issue multiple SQLs. Using application server connection pools is advisable if you see this sort of contention, and you might see some relief if you configure the database for multithreaded server connections.
- kks stats latch: This latch seems to be associated with mutex operations—one might speculate that it is involved in maintaining mutex sleep statistics. Some contention on this latch seems to be associated with other mutex contention scenarios. If you see this latch in conjunction with mutex waits, you should probably try resolving the mutex issue first with the hope of curing contention for this latch as well.
- In-memory undo latch: This latch is associated with Oracle’s relatively new in-memory undo (IMU) structures in which information formerly maintained in rollback (undo) segments is held in memory. Some contention for the in-memory undo latch might be the cost you have to pay for the reduction in redo generation and undo segment I/O that the new algorithm provides. However, some users have suggested turning in-memory undo off by adjusting the undocumented parameter _in_memory_undo or increasing the value of the PROCESSES parameter, which controls the default number of IMU latches.
- Result cache (RC) latch: This latch protects the creation and deletion of result sets in the result set cache. Contention for the latch occurs if multiple sessions attempt to simultaneously create cached result sets. Result sets in the result set cache should generally be restricted to a relatively small number of infrequently executing SQLs.