-
Notifications
You must be signed in to change notification settings - Fork 9.1k
Optimized Locking - Transaction ID (TID) Locking internals sample #1453
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
Open
segovoni
wants to merge
11
commits into
microsoft:master
Choose a base branch
from
segovoni:sgovoni/samples/features/optimized-locking
base: master
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
+212
−4
Open
Changes from all commits
Commits
Show all changes
11 commits
Select commit
Hold shift + click to select a range
24f7666
Initial commit create-configure-optimizedlocking-db.sql
segovoni 0b3cc1c
Initial commit of Optimized Locking TID sample README
segovoni d6ec888
Merge branch 'microsoft:master' into sgovoni/samples/features/optimiz…
segovoni 5d9a858
Add examples and output to optimized-locking README.md
segovoni e4ddffc
Add Optimized Locking section
segovoni 5f8d3d8
Simplify and enhance optimized-locking README.md
segovoni 51b0993
Cosmetic care
segovoni 6378609
Update Twitter to X
segovoni bcf3bdc
Enhance README with grammar corrections, clearer explanations, and be…
segovoni e928c61
Improve OptimizedLocking database setup script
segovoni 7a3e49a
Enhance features README with Optimized Locking details and fix typo
segovoni File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
161 changes: 161 additions & 0 deletions
161
samples/features/optimized-locking/transaction-id-locking/README.md
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,161 @@ | ||
| <!-- Always leave the MS logo --> | ||
|  | ||
|
|
||
| # Optimized Locking: Transaction ID (TID) locking internals | ||
|
|
||
| This sample describes how to read and interpret the Transaction ID (TID) stored in row data pages. | ||
|
|
||
| ## Background | ||
|
|
||
| Optimized Locking is a database engine feature designed to reduce the memory used for lock management, decrease the phenomenon known as lock escalation, and increase workload concurrency. | ||
|
|
||
| Optimized Locking depends on two technologies that have long been part of the SQL Server engine: | ||
| - [Accelerated Database Recovery (ADR)](https://learn.microsoft.com/sql/relational-databases/accelerated-database-recovery-concepts) is a required prerequisite for enabling Optimized Locking | ||
| - [Read Committed Snapshot Isolation (RCSI)](https://learn.microsoft.com/sql/t-sql/statements/set-transaction-isolation-level-transact-sql) is not a strict requirement, but allows full benefit from Optimized Locking | ||
|
|
||
| Optimized Locking is based on two key mechanisms: | ||
| - Transaction ID (TID) locking | ||
| - Lock After Qualification (LAQ) | ||
|
|
||
| ### What is the Transaction ID (TID)? | ||
|
|
||
| The Transaction ID (TID) is a unique transaction identifier. | ||
|
|
||
| When a [row-versioning based isolation level](https://learn.microsoft.com/en-us/sql/relational-databases/sql-server-transaction-locking-and-row-versioning-guide#Row_versioning) is active, or when [Accelerated Database Recovery (ADR)](https://learn.microsoft.com/sql/relational-databases/accelerated-database-recovery-concepts) is enabled, every row in the database internally contains a transaction identifier. | ||
|
|
||
| The TID is stored on disk in the additional 14 bytes that are associated with each row when features such as RCSI or ADR are enabled. | ||
|
|
||
| Every transaction that modifies a row tags that row with its own TID, so each row in the database is labeled with the last TID that modified it. | ||
|
|
||
| ### Contents | ||
|
|
||
| [About this sample](#about-this-sample)<br/> | ||
| [Before you begin](#before-you-begin)<br/> | ||
| [Run this sample](#run-this-sample)<br/> | ||
| [Sample Details](#sample-details)<br/> | ||
| [Disclaimers](#disclaimers)<br/> | ||
| [Related links](#related-links)<br/> | ||
|
|
||
| <a name=about-this-sample></a> | ||
| ## About this sample | ||
|
|
||
| - **Applies to:** SQL Server 2025 (or higher) | ||
| - **Key features:** Optimized Locking | ||
| - **Workload:** No workload related to this sample | ||
| - **Programming Language:** T-SQL | ||
| - **Authors:** [Sergio Govoni](https://www.linkedin.com/in/sgovoni/) | [Microsoft MVP Profile](https://mvp.microsoft.com/mvp/profile/c7b770c0-3c9a-e411-93f2-9cb65495d3c4) | [Blog](https://segovoni.medium.com/) | [GitHub](https://github.com/segovoni) | [X](https://twitter.com/segovoni) | ||
|
|
||
| <a name=before-you-begin></a> | ||
| ## Before you begin | ||
|
|
||
| To run this sample, you need the following prerequisites. | ||
|
|
||
| **Software prerequisites:** | ||
|
|
||
| 1. SQL Server 2025 (or higher) | ||
|
|
||
| <a name=run-this-sample></a> | ||
| ## Run this sample | ||
|
|
||
| ### Setup code | ||
|
|
||
| 1. Download [create-configure-optimizedlocking-db.sql](sql-scripts/create-configure-optimizedlocking-db.sql) T-SQL script from sql-scripts folder | ||
| 2. Verify that a database named OptimizedLocking does not already exist in your SQL Server instance | ||
| 3. Execute create-configure-optimizedlocking-db.sql script on your SQL Server instance | ||
| 4. Run the commands described in the sample details section | ||
|
|
||
| <a name=sample-details></a> | ||
| ## Sample Details | ||
|
|
||
| Currently, the only way to read the TID of a row is by using the `DBCC PAGE` command. | ||
|
|
||
| Let's consider the table dbo.TelemetryPacket, with the schema defined in the following T-SQL code snippet. | ||
|
|
||
| ```sql | ||
| USE [OptimizedLocking] | ||
| GO | ||
|
|
||
| CREATE TABLE dbo.TelemetryPacket | ||
| ( | ||
| PacketID INT IDENTITY(1, 1) | ||
| ,Device CHAR(8000) DEFAULT ('Something') | ||
| ); | ||
| GO | ||
| ``` | ||
|
|
||
| The table schema is designed so that each row occupies exactly one data page. | ||
|
|
||
| Insert three rows with default values into the dbo.TelemetryPacket table. Note that this is done in a single transaction. | ||
|
|
||
| ```sql | ||
| BEGIN TRANSACTION | ||
| INSERT INTO dbo.TelemetryPacket DEFAULT VALUES; | ||
| INSERT INTO dbo.TelemetryPacket DEFAULT VALUES; | ||
| INSERT INTO dbo.TelemetryPacket DEFAULT VALUES; | ||
| COMMIT | ||
| ``` | ||
|
|
||
| Let's explore the content of the dbo.TelemetryPacket table, enriched with the PageId column, which shows the result of the undocumented function sys.fn_PhysLocFormatter. Use this function to correlate the rows returned by the `SELECT` with their physical location on disk. | ||
|
|
||
| ```sql | ||
| USE [OptimizedLocking] | ||
| GO | ||
|
|
||
| SELECT | ||
| * | ||
| ,PageId = sys.fn_PhysLocFormatter(%%physloc%%) | ||
| FROM | ||
| dbo.TelemetryPacket; | ||
| ``` | ||
|
|
||
| The output is similar to the following, except for the values in the PageId column. | ||
|
|
||
| | PageId | PacketID | Device | | ||
| | ----------- | --------- | --------- | | ||
| | (1:2456:0) | 1 | Something | | ||
| | (1:2457:0) | 2 | Something | | ||
| | (1:2458:0) | 3 | Something | | ||
|
|
||
| Each value in the PageId column follows the format **(FileID:PageID:SlotID)** and represents the physical location of the data. | ||
|
|
||
| Let's examine the row where PacketID equals 1. The value (1:2456:0) is composed of three parts separated by ":". Here is what each part represents: | ||
| - **1** - the numeric identifier of the database file (FileID) | ||
| - **2456** - the page number within the file (PageID) | ||
| - **0** - the slot number on the page (SlotID) | ||
|
|
||
| Use the `DBCC PAGE` command to inspect the TID of page 2456. | ||
|
|
||
| ```sql | ||
| -- Enable trace flag for DBCC PAGE output | ||
| DBCC TRACEON(3604); | ||
| GO | ||
|
|
||
| DBCC PAGE ('OptimizedLocking', 1, 2456, 3); | ||
| ``` | ||
|
|
||
| The value of the unique TID that modified the row with PacketID equal to 1 is in the **Version Information** section, under the **Transaction Timestamp** attribute, as shown in the following sample data. | ||
|
|
||
| ```sql | ||
| Version Information = | ||
| Transaction Timestamp: 985 | ||
| Version Pointer: Null | ||
|
|
||
| Slot 0 Column 1 Offset 0x4 Length 4 Length (physical) 4 | ||
| PacketID = 1 | ||
| Slot 0 Column 2 Offset 0x8 Length 8000 Length (physical) 8000 | ||
| Device = Something� | ||
| ``` | ||
|
|
||
| TID 985 represents the identifier of the transaction that inserted the rows; every subsequent change to the table rows will update the TID. | ||
|
|
||
| <a name=disclaimers></a> | ||
| ## Disclaimers | ||
|
|
||
| The code included in this sample is not intended to be a set of best practices on how to build scalable enterprise grade applications. This is beyond the scope of this sample. | ||
|
|
||
| > **Note:** The `DBCC PAGE` command is undocumented and intended for troubleshooting and diagnostic purposes only. It should not be used in production environments without proper understanding and testing. | ||
|
|
||
| <a name=related-links></a> | ||
| ## Related Links | ||
|
|
||
| - [Optimized locking](https://learn.microsoft.com/sql/relational-databases/performance/optimized-locking) | ||
46 changes: 46 additions & 0 deletions
46
...mized-locking/transaction-id-locking/sql-scripts/create-configure-optimizedlocking-db.sql
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,46 @@ | ||
| ------------------------------------------------------------------------ | ||
| -- Run this script on a SQL Server 2025 instance (or higher) to -- | ||
| -- create a database named OptimizedLocking if it doesn't exist -- | ||
| ------------------------------------------------------------------------ | ||
|
|
||
| USE [master]; | ||
| GO | ||
|
|
||
| CREATE DATABASE [OptimizedLocking]; | ||
| GO | ||
|
|
||
| ALTER DATABASE [OptimizedLocking] SET COMPATIBILITY_LEVEL = 170; | ||
| ALTER DATABASE [OptimizedLocking] SET RECOVERY SIMPLE; | ||
| ALTER DATABASE [OptimizedLocking] SET PAGE_VERIFY CHECKSUM; | ||
| ALTER DATABASE [OptimizedLocking] SET ACCELERATED_DATABASE_RECOVERY = ON; | ||
| ALTER DATABASE [OptimizedLocking] SET READ_COMMITTED_SNAPSHOT ON; | ||
| ALTER DATABASE [OptimizedLocking] SET OPTIMIZED_LOCKING = ON; | ||
| GO | ||
|
|
||
| USE [OptimizedLocking] | ||
| GO | ||
|
|
||
| IF NOT EXISTS ( | ||
| SELECT | ||
| [name] | ||
| FROM | ||
| sys.filegroups | ||
| WHERE | ||
| (is_default = 1) | ||
| AND ([name] = N'PRIMARY') | ||
| ) | ||
| BEGIN | ||
| ALTER DATABASE [OptimizedLocking] MODIFY FILEGROUP [PRIMARY] DEFAULT; | ||
| END; | ||
|
|
||
| SELECT | ||
| [name] AS DatabaseName | ||
| ,is_accelerated_database_recovery_on AS [ADR Enabled] | ||
| ,is_read_committed_snapshot_on AS [RCSI Enabled] | ||
| ,is_optimized_locking_on AS [Optimized Locking Enabled] | ||
| FROM | ||
| sys.databases | ||
| WHERE | ||
| [name] = N'OptimizedLocking'; | ||
|
|
||
| PRINT 'OptimizedLocking database created and configured successfully.'; |
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
You don't need to use DBCC commands to get the TID information when there is a transaction lock. DBCC commands are not supported in Azure SQL Database also. It is desirable for samples to work on all platforms.
The sys.dm_tran_locks DMV exposes the TID locks as a new resource type = XACT. See the DMV documentation for more details on the exact scenarios.
You can instead do: