Home > Articles

This chapter is from the book

Measuring Latch and Mutex Contention

As with most contention scenarios, the wait interface and time model provide the best way to determine the extent of any contention that might exist. Time spent in latch or mutex sleeps is recorded in V$SYSTEM_EVENT and similar tables and usually is the primary indication that a problem exists.

However, be aware that the wait interface records only latch sleeps; latch misses do not result in a wait being recorded, even though they might consume CPU (if the session spins on the latch). Therefore, latch misses should be considered to be a lesser but still important aspect of latch contention.

Prior to Oracle Database 10g, a single latch free wait event was recorded for all latch sleeps. From Oracle 10g onward, certain latches now have their own event—such as latch: cache buffers chains. Not all latches have their own event, though, and those that do not continue to be included in the latch free wait.

Mutex waits are represented by waits such as library cache: mutex X, which represents a wait on an exclusive library cache mutex.

To break out mutex and latch waits and compare them to other high-level wait categories, we could issue a query such as that shown in Listing 16.1.

Listing 16.1 Latch Wait Times

SQL> WITH system_event AS
  2    (SELECT CASE WHEN (event LIKE '%latch%'  or event
  3                       LIKE '%mutex%' or event like 'cursor:%')
  4                THEN event  ELSE wait_class
  5                END wait_type, e.*
  6       FROM v$system_event e)
  7  SELECT wait_type,SUM(total_waits) total_waits,
  8         round(SUM(time_waited_micro)/1000000,2) time_waited_seconds,
  9         ROUND(  SUM(time_waited_micro)
 10               * 100
 11               / SUM(SUM(time_waited_micro)) OVER (), 2) pct
 12  FROM (SELECT  wait_type, event, total_waits, time_waited_micro
 13        FROM    system_event e
 14        UNION
 15        SELECT   'CPU', stat_name, NULL, VALUE
 16        FROM v$sys_time_model
 17        WHERE stat_name IN ('background cpu time', 'DB CPU')) l
 18  WHERE wait_type <> 'Idle'
 19  GROUP BY wait_type
 20  ORDER BY 4 DESC
 21  /

WAIT_TYPE                          TOTAL_WAITS TIME_WAITED_SECONDS    PCT
--------------------------------- ------------ ------------------- ------
CPU                                                       1,494.63  69.26
latch: shared pool                   1,066,478              426.20  19.75
latch free                              93,672              115.66   5.36
wait list latch free                       336               58.91   2.73
User I/O                                 9,380               27.28   1.26
latch: cache buffers chains              2,058                8.74    .40
Other                                       50                7.26    .34
System I/O                               6,166                6.37    .30
cursor: pin S                              235                3.05    .14
Concurrency                                 60                3.11    .14
library cache: mutex X                 257,469                2.52    .12

Of course, this query reports all waits since the database first started. To get a view over a specific period of time, you would need to run the query twice and compare totals. We can also observe the ongoing state of these statistics in the Oracle Cloud Control, in third-party tools such as Toad, or by using Automatic Workload Repository (AWR) or Statspack reports.

Identifying Individual Latches

If we’re lucky, the latch that is responsible for whatever latch contention exists will be identified by its specific wait event—latch: cache buffers chains, for instance. However, this won’t always be the case; some latches are included in the general-purpose latch free event, and some might be recorded against the event wait list latch free.

The wait list latch free event relates to Oracle’s latch wait posting algorithm. Oracle implements a latch wait list that allows sessions sleeping on a latch to be woken when the latch becomes available. When a session sleeps on a latch, it normally places itself on the latch wait list and is woken by the session that releases the latch. If there’s heavy contention on the wait list, then the wait list latch free event may occur.

If the specific latch waits are being obscured by these general-purpose latch free events, then you may need to examine V$LATCH, which includes latch statistics for each specific latch. The V$LATCH view records the number of gets, misses, sleeps, and wait times for each latch. The query in Listing 16.2 interrogates this view to identify the latches with the most sleeps and wait times.

Listing 16.2 Latch Miss Statistics

SQL> WITH latch AS (
  2   SELECT name,
  3          ROUND(gets * 100 / SUM(gets) OVER (), 2) pct_of_gets,
  4          ROUND(misses * 100 / SUM(misses) OVER (), 2) pct_of_misses,
  5          ROUND(sleeps * 100 / SUM(sleeps) OVER (), 2) pct_of_sleeps,
  6          ROUND(wait_time * 100 / SUM(wait_time) OVER (), 2)
  7                   pct_of_wait_time
  8     FROM v$latch)
  9  SELECT *
 10  FROM latch
 11  WHERE pct_of_wait_time > .1 OR pct_of_sleeps > .1
 12  ORDER BY pct_of_wait_time DESC;

                               Pct of Pct of Pct of    Pct of
NAME                             Gets Misses Sleeps Wait Time
------------------------------ ------ ------ ------ ---------
cache buffers chains            99.59  99.91  70.59     89.75
shared pool                       .07    .03  16.69      7.78
session allocation                .18    .05  11.39      1.88
row cache objects                 .07    .00    .78       .24
simulator lru latch               .01    .00    .31       .18
parameter table management        .00    .00    .08       .14
channel operations parent latc    .00    .00    .16       .02

Drilling into Segments and SQLs

Determining the latches associated with contention is usually not enough to identify the root cause. We most likely need to identify the SQLs and segments involved.

If you have an Oracle diagnostic pack license, then you can query the Active Session History (ASH) and/or AWR tables to identify the SQLs and segments associated with particular wait conditions. The query in Listing 16.3 identifies entries in the ASH table associated with latch contention.

Listing 16.3 Finding Latch Contention with ASH

SQL> l
  1  WITH ash_query AS (
  2       SELECT event, program,
  3              h.module, h.action,   object_name,
  4              SUM(time_waited)/1000 reltime, COUNT( * ) waits,
  5              username, sql_text,
  6               RANK() OVER (ORDER BY COUNT(*) DESC) AS wait_rank
  7        FROM  v$active_session_history h
  8        JOIN  dba_users u  USING (user_id)
  9        LEFT OUTER JOIN dba_objects o
 10             ON (o.object_id = h.current_obj#)
 11        LEFT OUTER JOIN v$sql s USING (sql_id)
 12       WHERE (event LIKE '%latch%' or event like '%mutex%')
 13       GROUP BY event,program, h.module, h.action,
 14           object_name,  sql_text, username)
 15  SELECT event,module, username,  object_name, waits,
 16           sql_text
 17  FROM ash_query
 18  WHERE wait_rank < 11
 19* ORDER BY wait_rank
SQL> /

EVENT                     MODULE       USERNAME OBJECT_NAME       WAITS
------------------------- ------------ -------- ------------ ----------
SQL_TEXT
------------------------------------------------------------
library cache: mutex X    SQL*Plus     OPSG                          13

latch: shared pool        SQL*Plus     OPSG                           8

latch: shared pool        SQL*Plus     OPSG     LT_SALES_PK           3
 begin     latch_test(10000,10000,1000000,10000);  end;

library cache: mutex X    SQL*Plus     OPSG     LT_SALES_PK           2

library cache: mutex X    SQL*Plus     OPSG     LT_SALES              1
 begin     latch_test(10000,1,10000,10000);  end;

latch: shared pool        SQL*Plus     OPSG                           1
SELECT  quantity_sold , amount_sold FROM lt_sales t539564 WH
ERE id BETWEEN 124410 AND 360759

latch: shared pool        SQL*Plus     OPSG                           1
SELECT  quantity_sold , amount_sold FROM lt_sales t539571 WH
ERE id BETWEEN 512313 AND 825315

library cache: mutex X    SQL*Plus     OPSG                           1
SELECT  quantity_sold , amount_sold FROM lt_sales t539563 WH
ERE id BETWEEN 698302 AND 392634

latch: shared pool        SQL*Plus     OPSG     LT_SALES_PK           1
SELECT  quantity_sold , amount_sold FROM lt_sales t539555 WH
ERE id BETWEEN 387009 AND 268338

If you don’t have a Diagnostic Pack license, then you can indirectly identify the SQLs by focusing on those SQLs with the highest concurrency wait times. The concurrency wait class includes most commonly encountered latch and mutex waits, although it also includes some internal locks and buffer waits. However, if you’re encountering high rates of latch contention, it’s a fair bet that the SQLs with the highest concurrency waits are the ones you want to look at.

Listing 16.4 pulls out the SQLs with the highest concurrency waits.

Listing 16.4 Identifying High Contention SQL

SQL> WITH sql_conc_waits AS
  2      (SELECT sql_id, SUBSTR(sql_text, 1, 80) sql_text,
  3              concurrency_wait_time/1000 con_time_ms,
  4              elapsed_time,
  5              ROUND(concurrency_wait_Time * 100 /
  6                  elapsed_time, 2) con_time_pct,
  7              ROUND(concurrency_wait_Time* 100 /
  8                  SUM(concurrency_wait_Time) OVER (), 2) pct_of_con_time,
  9              RANK() OVER (ORDER BY concurrency_wait_Time DESC) ranking
 10         FROM v$sql
 11        WHERE elapsed_time > 0)
 12  SELECT sql_text, con_time_ms, con_time_pct,
 13         pct_of_con_time
 14  FROM sql_conc_waits
 15  WHERE ranking <= 10
 16  ORDER BY ranking  ;

                                                       SQL Conc    % Tot
SQL Text                                 Conc Time(ms)    Time% ConcTime
---------------------------------------- ------------- -------- --------
DECLARE job BINARY_INTEGER := :job; next           899    18.41    44.21
_date DATE := :mydate;  broken BOOLEAN :

select max(data) from log_data where id<           472      .01    23.18
:id

begin   query_loops ( run_seconds=>120 ,           464      .01    22.80
 hi_val =>1000 ,                    use_

update sys.aud$ set action#=:2, returnco           143    75.46     7.02
de=:3, logoff$time=cast(SYS_EXTRACT_UTC
(

As expected the SQL that generated the latch waits is found (the second and third entries are from a job that generated the latch waits). However, other SQLs—associated with waits for certain internal Oracle locks—are also shown. You’ll need to exercise judgment to determine which SQLs are most likely associated with your latch waits.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020