Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
Applies to:
SQL Server
This topic describes how to add and remove a persistent log buffer to a database in SQL Server 2016 (13.x) and above using Transact-SQL.
Requires the ALTER
permission on the database.
To configure a persistent memory device in Linux.
To configure a persistent memory device in Windows.
The volume or the mount point for the new log file must be formatted with DAX enabled (NTFS) or mounted with the DAX option (XFS/EXT4).
Use the following syntax to add a persistent log buffer to an existing database. The syntax differs depending on the version of SQL Server.
ALTER DATABASE [DB] SET PERSISTENT_LOG_BUFFER = ON (DIRECTORY_NAME = 'path-to-directory-on-a-DAX-volume');
For example:
ALTER DATABASE WideWorldImporters SET PERSISTENT_LOG_BUFFER = ON (DIRECTORY_NAME = 'F:\SQLTLog');
The name of the persistent log file buffer is generated automatically. The size of the file is always 20 megabytes.
ALTER DATABASE [DB] ADD LOG FILE
(
NAME = [DAXlogLogicalName],
FILENAME = 'path-to-log-file-on-a-DAX-volume',
SIZE = 20 MB
);
For example:
ALTER DATABASE WideWorldImporters ADD LOG FILE
(
NAME = wwi_log2,
FILENAME = 'F:\SQLTLog\wwi_log2.pldf',
SIZE = 20 MB
);
The log buffer file on the DAX volume will be sized at 20 megabytes regardless of the size specified with the ALTER DATABASE ADD LOG FILE
command.
To safely remove a persistent log buffer, the database must be placed in single user mode in order to drain the persistent log buffer.
When you remove a persistent log buffer, the log buffer file on disk is deleted.
The syntax differs depending on the version of SQL Server.
ALTER DATABASE [DB] SET PERSISTENT_LOG_BUFFER = OFF;
For example:
ALTER DATABASE WideWorldImporters SET PERSISTENT_LOG_BUFFER = OFF;
ALTER DATABASE [DB] SET SINGLE_USER;
ALTER DATABASE [DB] REMOVE FILE [DAXlogLogicalName];
ALTER DATABASE [DB] SET MULTI_USER;
For example:
ALTER DATABASE WideWorldImporters SET SINGLE_USER;
ALTER DATABASE WideWorldImporters REMOVE FILE wwi_log2;
ALTER DATABASE WideWorldImporters SET MULTI_USER;
Transparent Data Encryption (TDE) is not compatible with persistent log buffer.
Availability Groups can only use this feature on secondary replicas due to the requirement by the log reader agent for standard log writing semantics on the primary. However, a small log file must be created on all nodes (ideally on DAX volumes or mounts). In the event of a failover, the persistent log buffer path must exist, in order for the failover to be successful.
Caution
If the persistent log buffer path or file isn't present during an Availability Group failover event, or database startup, the database enters a RECOVERY PENDING
state until the issue is resolved.
When both persistent log buffer and Hybrid Buffer Pool are enabled, along with the start up trace flag 809, Hybrid Buffer Pool will operate in what is known as Direct Write mode.
Normal restore conditions apply. If persistent log buffer is restored to a DAX volume or mount, it continues to function. If the log is restored to a non-DAX disk volume, it can be safely removed using the ALTER DATABASE REMOVE FILE
command.
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayTraining
Module
Understand write-ahead logging - Training
Azure Database for PostgreSQL is an ACID compliant database service. Write-ahead logging ensures changes are both atomic and durable (the A and D in ACID). Changes are first written to the log before they're committed to the database. In this module, you learn how Azure Database for PostgreSQL implements write-ahead logging, and how the log can be used for replication and logical decoding.
Documentation
Hybrid buffer pool - SQL Server
See how the hybrid buffer pool makes persistent memory devices accessible via the memory bus. Turn this SQL Server feature on or off, and view best practices.
ALTER SERVER CONFIGURATION (Transact-SQL) - SQL Server
ALTER SERVER CONFIGURATION (Transact-SQL)
Buffer Pool Extension - SQL Server
Learn about buffer pool extension and its benefits, which include improved I/O throughput. View best practices to follow when turning on this feature.