Home > Articles > Data > SQL Server

Options Affecting SQL Server Locking Behavior

Sometimes, you might have a need to alter SQL Server's default locking behavior. There are multiple ways to achieve that objective. This article explores the query hints and SET options that can also be used to alter the way SQL Server locks resources.
Like this article? We recommend

Another article in this series, "Details of Locking," discussed the SQL Server locking behavior. We also showed you how to override the default behavior through changing the default TRANSACTION ISOLATION LEVEL. In this article, we discuss a few other options that let you change the default behavior if needed. Please keep in mind, though, that SQL Server is a great product, and it usually makes the best locking decisions on its own. If you experience problems that you think are due to locking, try rewriting your stored procedures, re-evaluate your indexing strategy, and consider changing your data model first. Then, if you have used all other resources to no avail, you might try to use the locking hints and SET options discussed in this article as a last resort.

Tuning Queries Through Locking Hints

The query hints instruct the SQL Server engine to acquire and release locks in a fashion different from the default behavior. In fact, the term query hint is a great understatement. One usually thinks of a "hint" as a friendly suggestion that can be accepted or rejected, and is supposed to be helpful. Query hints, on the other hand, are more of a directive rather than a suggestion. SQL Server has no choice—after I instruct the query optimizer to use a hint, it will adhere to my order as a faithful servant. SQL Server won't debate my suggestion or call me a "bonehead," even if executing the query with my hint is a horrible idea. Therefore, I recommend testing your queries thoroughly with and without using the hints prior to deploying your application in the production environment.

After such a "glowing" introduction, you might think that the locking hints are available just to cause you major headaches. That is not entirely true. Occasionally, you can see a great improvement in your application performance due to using the locking hints, so please don't get discouraged just yet! After all, it never hurts to know and test various alternatives, and go with the best option.

The majority of the locking hints are used with the SELECT statements. A good example of when you might want to use a NOLOCK hint is when you run a report that doesn't have to be 100% accurate. If such a report affects the tables that are being modified, chances are your SELECT statement will have to wait until the other transactions complete. If you use NOLOCK, your query won't have to wait; it will read the uncommitted records. Therefore, your report will be generated much more quickly.

Occasionally, you might find the locking hints useful with the INSERT, UPDATE, and DELETE statements. For instance, if you want to be absolutely sure that no one can modify records while your UDPATE statement is running, you can use the UPDLOCK hint. By default, SQL Server takes shared locks first and then escalates them to UPDLOCK when it's ready to commit an UPDATE transaction. Using UPDLOCK will override such behavior to guarantee that data will be exclusively locked for the duration of the transaction.

Recall from the previous article that locking is a tradeoff between concurrency and the resources used. I've seen an application that used the ROWLOCK hint with every INSERT, UPDATE, and DELETE statement. The idea was to convince SQL Server to lock individual rows each time, thereby reducing locking contingency. Keep in mind that if SQL Server doesn't have enough resources to satisfy your query, it will have to wait until such resources become available. If your query hogs every byte of memory available to SQL Server, then the server will not have enough memory for other tasks. Therefore, consider the pros and cons of using the ROWLOCK hint carefully.

Table 1 lists each available locking hint, discusses its functionality, and tells you which statements support this hint. Keep in mind that using a locking hint that is not supported with a particular statement doesn't generate an error; rather, it has no effect. For instance, you can use NOLOCK with an UPDATE, but SQL Server will ignore that hint—locks will still be acquired. In a similar manner, you can use XLOCK hint with UPDATE, but it won't make any difference.

Table 1 Locking hints available in SQL Server 2000.

Locking Hint

Description

Allowed with

HOLDLOCK

Holds the shared locks on the range read, or modified for the duration of the transaction or statement. Overrides the default behavior, which is to release the locks as soon as the data page has been read. HOLDLOCK is equivalent to the SERIALIZABLE transaction isolation level.

SELECT, INSERT, UPDATE, DELETE

NOLOCK

Does not honor shared or exclusive locks. NOLOCK is equivalent to the READ UNCOMMITED transaction isolation level.

SELECT

PAGLOCK

Forces the transaction to use page-level locks instead of escalating to table-level locks.

SELECT, INSERT, UPDATE, DELETE

READCOMMITTED

Equivalent to the READ COMMITTED transaction isolation level, which is the default behavior of SQL Server.

SELECT, INSERT, UPDATE, DELETE

READUNCOMMITTED

Same as NOLOCK. Equivalent to the READ UNCOMMITTED transaction isolation level.

SELECT

REPEATABLEREAD

Equivalent to the REPEATABLE READ transaction isolation level, which disallows dirty reads, but allows phantoms.

SELECT, INSERT, UPDATE, DELETE

ROWLOCK

Forces the transaction to use row-level locking instead of the page- or table-level locking that would otherwise be used.

SELECT, INSERT, UPDATE, DELETE

SERIALIZABLE

Equivalent to the SERIALIZABLE transaction isolation level and the HOLDLOCK hint. Holds the shared locks for the duration of the transaction or statement.

SELECT, INSERT, UPDATE, DELETE

TABLOCK

Forces SQL Server to use a table-level lock instead of row- or page-level locks. If used with HOLDLOCK, then the lock will be held until the transaction completes. Otherwise, the lock is released as soon as the data is read. For SELECT statements, this hint forces shared table locks. Using this hint with other statements (such as INSERT, UPDATE, or DELETE) will initiate exclusive table lock.

SELECT, INSERT, UPDATE, DELETE

TABLOCKX

Places an exclusive lock on the entire table, thereby disabling any other users from reading or writing to the table.

SELECT, INSERT, UDPATE, DELETE

UPDLOCK

Places an update lock for the duration of the statement or transaction. This guarantees that data is not changed since it was read.

SELECT, INSERT, UPDATE, DELETE

XLOCK

Places an exclusive lock until the end of the transaction. If specified with TABLOCK or PAGLOCK, it will lock the appropriate level.

SELECT


The syntax for using the locking hints is very simple. You add the WITH keyword to the FROM clause, and include a locking hint in the parentheses that follow. For example, the following statement returns a few columns from the sales table in the pubs database without honoring any shared or exclusive locks.

SELECT    stor_id, 
       ord_num, 
       qty 
FROM  sales 		
WITH (NOLOCK)
WHERE payterms = 'Net 30'

The following statement gives all employees who started before the first of the year a 20% raise, and forces SQL Server to use the page-level locks instead of escalating to a single table-level lock:

UPDATE    employee 
SET      salary = salary * 1.20
FROM  employee 
    WITH (PAGLOCK)
WHERE start_date < '1/1/2002'

Please note that the locking hints and the transaction isolation levels might conflict with each other. When this happens, SQL Server honors the more restrictive of the two. For instance, the following query holds the locks on the employee table, even though the isolation level instructs SQL Server to ignore the locks:

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED 
GO
BEGIN TRANSACTION

    SELECT * FROM employee WITH (HOLDLOCK)

COMMIT TRANSACTION

Also, note that you can specify multiple locking hints in the same query. For instance, the following group of statements instructs SQL Server to hold a table-level lock for the duration of the transaction:

BEGIN TRAN

    SELECT fname AS first_name, 
       minit AS middle_initial, 
          lname AS last_name
    FROM  employee
       WITH (TABLOCK, HOLDLOCK)
COMMIT

The conflicting locking hints generates an error, as shown in the following statement:

SELECT * 
FROM Employee 
WITH (HOLDLOCK, NOLOCK)

Result:
Server: Msg 1047, Level 15, State 1, Line 10
Conflicting locking hints specified.

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