sys.dm_db_log_info (Transact-SQL)

THIS TOPIC APPLIES TO:yesSQL Server (starting with 2017)noAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Returns VLF information of the transaction log files. (All log files are combined in the table output). Each row in the output represents a VLF in the transaction log and provides information relevant to that VLF in the log.

Syntax

sys.dm_db_log_info ( database_id )  

Arguments

database_id | NULL | DEFAULT
Is the ID of the database. database_id is int. Valid inputs are the ID number of a database, NULL, or DEFAULT. The default is NULL. NULL and DEFAULT are equivalent values in the context of current database.

Specify NULL to return VLF information of the current database.

The built-in function DB_ID can be specified. When using DB_ID without specifying a database name, the compatibility level of the current database must be 90 or greater.

Table Returned

Column name Data type Description
database_id int Database ID.
file_id smallint File id of the transaction log.
vlf_begin_offset bigint Offset location of the VLF from the beginning of the transaction log file.
vlf_size_mb float VLF size in MB rounded to 2 decimal places.
vlf_sequence_number bigint VLF sequence number in the created order. Used to uniquely identify VLFs in log file.
vlf_active bit Indicates whether VLF is in use or not.
0 - vlf is not in use.
1 - VLF is active.
vlf_status int Status of the VLF. Possible values include
0 - VLF is inactive
1 - vlf is initialized but unused
2 - VLF is active.
vlf_parity tinyint Parity of VLF.Used internally to determine the end of log within a VLF.
vlf_first_lsn nvarchar(48) LSN of the first log record in the VLF.
vlf_create_lsn nvarchar(48) LSN of the log record that created the VLF.

Remarks

The sys.dm_db_log_info dynamic management function replaces the DBCC LOGINFO statement.

Permissions

Requires the VIEW DATABASE STATE permission in the database.

Examples

A. Determing databases in a SQL Server instance with high number of VLFs

The following query determines the databases with more than 100 VLFs in the log files, which can affect the database startup, restore, and recovery time.

SELECT name,count(l.database_id) as 'vlf_count' from sys.databases s
cross apply sys.dm_db_log_info(s.database_id) l
group by name
having count(l.database_id)> 100

B. Determing the status of last VLF in transaction log before shrinking the log file

The following query can be used to determine the status of last VLF before running shrinkfile on transaction log to determine if transaction log can shrink.

USE <database name>
GO

SELECT top 1 DB_NAME(database_id) as "Database Name",file_id,vlf_size_mb,vlf_sequence_number, vlf_active, vlf_status
from sys.dm_db_log_info(DEFAULT)
order by vlf_sequence_number desc

See Also

Dynamic Management Views and Functions (Transact-SQL)
Database Related Dynamic Management Views (Transact-SQL)
sys.dm_db_log_space_usage