Share via


Recover to a Log Sequence Number (SQL Server)

This topic is relevant only for databases that are using the full or bulk-logged recovery models.

You can use a log sequence number (LSN) to define the recovery point for a restore operation. However, this is a specialized feature that is intended for tools vendors and is unlikely to be generally useful.

Overview of Log Sequence Numbers

LSNs are used internally during a RESTORE sequence to track the point in time to which data has been restored. When a backup is restored, the data is restored to the LSN corresponding to the point in time at which the backup was taken. Differential and log backups advance the restored database to a later time, which corresponds to a higher LSN.

Every record in the transaction log is uniquely identified by a log sequence number (LSN). LSNs are ordered such that if LSN2 is greater than LSN1, the change described by the log record referred to by LSN2 occurred after the change described by the log record LSN.

The LSN of a log record at which a significant event occurred can be useful for constructing correct restore sequences. Because LSNs are ordered, they can be compared for equality and inequality (that is, <, >, =, <=, >=). Such comparisons are useful when constructing restore sequences.

Note

LSNs are values of data type numeric(25,0). Arithmetic operations (for example, addition or subtraction) are not meaningful and must not be used with LSNs.

[Top]

Viewing LSNs Used by Backup and Restore

The LSN of a log record at which a given backup and restore event occurred is viewable using one or more of the following:

Note

LSNs also appear in some message texts.

Transact-SQL Syntax for Restoring to an LSN

By using a RESTORE statement, you can stop at or immediately before the LSN, as follows:

  • Use the WITH STOPATMARK = 'lsn:<lsn_number>' clause, where lsn:<lsnNumber> is a string that specifies that the log record that contains the specified LSN is the recovery point.

    STOPATMARK roll forwards to the LSN and includes that log record in the roll forward.

  • Use the WITH STOPBEFOREMARK = 'lsn:<lsn_number>' clause, where lsn:<lsnNumber> is a string that specifies that the log record immediately before the log record that contains the specified LSN number is the recovery point.

    STOPBEFOREMARK rolls forward to the LSN and excludes that log record from the roll forward.

Typically, a specific transaction is selected to be included or excluded. Although not required, in practice, the specified log record is a transaction-commit record.

Examples

The following example assumes that the AdventureWorks database has been changed to use the full recovery model.

RESTORE LOG AdventureWorks FROM DISK = 'c:\adventureworks_log.bak' 
WITH STOPATMARK = 'lsn:15000000040000037'
GO

See Also

Reference

RESTORE (Transact-SQL)

Concepts

Apply Transaction Log Backups (SQL Server)

The Transaction Log (SQL Server)