Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

About locking with REORGANIZE #4011

Merged
merged 4 commits into from
Apr 28, 2020
Merged

About locking with REORGANIZE #4011

merged 4 commits into from
Apr 28, 2020

Conversation

rrg92
Copy link
Contributor

@rrg92 rrg92 commented Jan 23, 2020

Original text says that REORGANIZE not block concurrent readers and writers. But is not true.

Use following code to check this:

-- create some test table
create table __reorgtest(c int);

-- create sample nonclustered index
create index x on __reorgtest(c);

-- insert some data
insert into __reorgtest values(2020);
go 1000


-- Open another session and run this (we call Session X):
begin tran;;
alter index x on __reorgtest reorganize;

-- Open another session and run this (we call session Y):
begin tran;;
select count(*) from __reorgtest

-- On this session, check tran_locks! 
select * from sys.dm_tran_locks where request_session_id in (  X,Y ) -- replace and y by sessions id opened above.

-- Current behavior on my tests: Session Y gets blocked by X.
-- THe inverse can be checked: Try start first a select (wth holdlock) or update operation on some row, and try start X(reorganize). Reorganize gets blocked!

Behavior checked on

  • Microsoft SQL Server 2019 (RTM-GDR) (KB4517790) - 15.0.2070.41 (X64) Oct 28 2019 19:56:59 Copyright (C) 2019 Microsoft Corporation Developer Edition (64-bit) on Windows 10 Home Single Language 10.0 (Build 18363: )
  • Microsoft SQL Server 2016 (SP2-CU10) (KB4524334) - 13.0.5492.2 (X64) Oct 4 2019 19:14:08 Copyright (c) Microsoft Corporation Standard Edition (64-bit) on Windows Server 2012 R2 Standard 6.3 (Build 9600: )

Original text says that REORGANIZE not block concurrent readers and writers. But is not true.

Use following code to check this:

```sql
-- create some test table
create table __reorgtest(c int);

-- create sample nonclustered index
create index x on __reorgtest(c);

-- insert some data
insert into __reorgtest values(2020);
go 1000


-- Open another session and run this (we call Session X):
begin tran;;
alter index x on __reorgtest reorganize;

-- Open another session and run this (we call session Y):
begin tran;;
select count(*) from __reorgtest

-- On this session, check tran_locks! 
select * from sys.dm_tran_locks where request_session_id in (  X,Y ) -- replace and y by sessions id opened above.

-- Current behavior on my tests: Session Y gets blocked by X.
-- THe inverse can be checked: Try start first a select (wth holdlock) or update operation on some row, and try start X(reorganize). Reorganize gets blocked!

```


Behavior checked on 
* Microsoft SQL Server 2019 (RTM-GDR) (KB4517790) - 15.0.2070.41 (X64)   Oct 28 2019 19:56:59   Copyright (C) 2019 Microsoft Corporation  Developer Edition (64-bit) on Windows 10 Home Single Language 10.0 <X64> (Build 18363: ) 
* Microsoft SQL Server 2016 (SP2-CU10) (KB4524334) - 13.0.5492.2 (X64)   Oct  4 2019 19:14:08   Copyright (c) Microsoft Corporation  Standard Edition (64-bit) on Windows Server 2012 R2 Standard 6.3 <X64> (Build 9600: )
@PRMerger9
Copy link
Contributor

@rrg92 : Thanks for your contribution! The author(s) have been notified to review your proposed change.

@rothja
Copy link
Contributor

rothja commented Feb 12, 2020

@rrg92 Thanks for the feedback. @pmasl Could you review this change and sign off on it if you approve? Thank you!

@ktoliver
Copy link
Contributor

@pmasl Hi, could you take a look at this PR? Thank you.

@rrg92
Copy link
Contributor Author

rrg92 commented Apr 28, 2020

Hey guys, this PR make some sense?

@ktoliver
Copy link
Contributor

@pmasl Could you review this PR? Thanks.

@pmasl
Copy link
Contributor

pmasl commented Apr 28, 2020

Your test has REORG encapsulated in an open tran. That way anything blocks. The use of REORG as an autocommit statement is done online, which means only the singleton record impacted blocks or is blocked. In summary, your test doesn't represent the intended or real-use case of REORG.

@rrg92
Copy link
Contributor Author

rrg92 commented Apr 28, 2020

Thanks @pmasl !

I opened an Extended events session to check you says and I confirmed that.

This is lock held using begin tran:

image

Last is an Exclusive lock.

Bellow are all lock held into this object without begin tran:

image

No exclusives, just intents and shared!! Nice

I search in SQL docs and not find anything about that fact autocommit mode change this behavior... Do you guess that adding this info into doc is pertinent? I guess most of users don't know this.

@pmasl
Copy link
Contributor

pmasl commented Apr 28, 2020

Locking behavior is different between explicit transactions and auto-commit (aka implicit transactions which is the default) for every (or most) DML and DDL.

If any I'd suggest adding to that note something to the effect of:

"If using explicit transactions instead of the default implicit transaction mode, the locking behavior of REORGANIZE becomes more restrictive. For more information on implicit transactions, see SET IMPLICIT_TRANSACTIONS (Transact-SQL)."

@PRMerger6
Copy link
Contributor

@rrg92 : Thanks for your contribution! The author(s) have been notified to review your proposed change.

@rrg92
Copy link
Contributor Author

rrg92 commented Apr 28, 2020

I changed, putting original text and adding a Note on about the fact of autocommit.

@PRMerger7 PRMerger7 requested a review from pmasl April 28, 2020 23:05
@PRMerger7
Copy link
Contributor

@rrg92 : Thanks for your contribution! The author(s) have been notified to review your proposed change.

@rrg92
Copy link
Contributor Author

rrg92 commented Apr 28, 2020

All done, text will looks like this:

image

@pmasl
Copy link
Contributor

pmasl commented Apr 28, 2020

#sign-off

@PRMerger15
Copy link
Contributor

@ktoliver : Thanks for your contribution! The author(s) have been notified to review your proposed change.

@ktoliver ktoliver merged commit 876fe46 into MicrosoftDocs:live Apr 28, 2020
@rrg92 rrg92 deleted the patch-2 branch April 28, 2020 23:36
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

Successfully merging this pull request may close these issues.

9 participants