Returns space usage information for the transaction log.
Note
All transaction log files are combined.
Column name
Data type
Description
database_id
smallint
Database ID.
In Azure SQL Database, the values are unique within a single database or an elastic pool, but not within a logical server.
total_log_size_in_bytes
bigint
The size of the log
used_log_space_in_bytes
bigint
The occupied size of the log
used_log_space_in_percent
real
The occupied size of the log as a percent of the total log size
log_space_in_bytes_since_last_backup
bigint
The amount of space used since the last log backup Applies to: SQL Server 2014 (12.x) and later, SQL Database.
Permissions
On SQL Server and SQL Managed Instance, requires VIEW SERVER STATE permission.
On SQL Database Basic, S0, and S1 service objectives, and for databases in elastic pools, the server admin account, the Microsoft Entra admin account, or membership in the ##MS_ServerStateReader##server role is required. On all other SQL Database service objectives, either the VIEW DATABASE STATE permission on the database, or membership in the ##MS_ServerStateReader## server role is required.
Permissions for SQL Server 2022 and later
Requires VIEW SERVER PERFORMANCE STATE permission on the server.
Examples
A. Determine the amount of free log space in tempdb
The following query returns the total free log space in megabytes (MB) available in tempdb.
USE tempdb;
GO
SELECT
(total_log_size_in_bytes - used_log_space_in_bytes)*1.0/1024/1024 AS [free log space in MB]
FROM sys.dm_db_log_space_usage;
Learn how to monitor SQL Server transaction log size, shrink the log, enlarge a log, optimize the tempdb log growth rate, and control transaction log growth.
Learn about the transaction log. Every SQL Server database records all transactions and database modifications that you need if there's a system failure.