New course: Introduction to Query Store

Our first new course of the year, and our 50th online training course with Pluralsight!!

Erin’s latest Pluralsight course has been published – SQL Server: Introduction to Query Store – and is just over three hours long. It’s based on her very popular user group and conference session, but much expanded with lots of cool demos.

The modules are:

  • Introduction
  • Defining Query Store
  • Implementing Query Store
  • Installing SQL Server 2016
  • Forcing Plans with Query Store
  • Practical Uses of Query Store

Check it out here.

We now have 150 hours of SQLskills online training available (see all our 50 courses here), all for as little as $29/month through Pluralsight (including more than 5,000 other developer and IT training courses). That’s unbeatable value that you can’t afford to ignore.

Enjoy!

What are LOGMGR_RESERVE_APPEND waits?

Last week I was sent an email question about the cause of LOGMGR_RESERVE_APPEND waits, and in Monday’s Insider newsletter I wrote a short explanation. It’s a very unusual wait to see as the highest wait on a server, and in fact it’s very unusual to see it at all.

It happens when a thread is generating a log record and needs to write it into a log block, but there’s no space in the log to do so. The thread first tries to grow the log, and if it fails, and the database is in the simple recovery mode, then it waits for 1 second to see if log clearing/truncation can happen in the meantime and free up some space. (Note that when I say ‘simple recovery mode’, this also includes a database in full or bulk_logged, but where a full backup has not been taken – i.e. the database is operating in what’s called pseudo-simple.)

It’s the fact that the database needs to be in the simple recovery mode and have no space available that makes this wait type very unusual to see.

An example call stack is on SQL Server 2014 (captured using this mechanism):

SOS_Task::PostWait+9e
SOS_Task::Sleep+149
SQLServerLogMgr::ReserveAndAppend+2cf
XdesRMReadWrite::GenerateLogRec+615
PageRef::InsertRows+2594
HeapPageRef::Insert+45a
HeapFragment::Update+3f7
HeapDataSetSession::InsertRowInternal+3444
DatasetSession::InsertRow+163
RowsetNewSS::InsertRow+26
CValRow::SetDataX+5b
CEsExec::GeneralEval4+e7
CQScanUpdateNew::GetRow+43d
CQueryScan::GetRow+81
CXStmtQuery::ErsqExecuteQuery+36d
CXStmtDML::XretDMLExecute+31c
CXStmtDML::XretExecute+ad
CMsqlExecContext::ExecuteStmts<1,1>+427
CMsqlExecContext::FExecute+a43
CSQLSource::Execute+86c

Here’s a scenario that shows it happening. First I’ll create the database with a fixed size log, set it to simple recovery mode, and create a table that will generate large log records for inserts:

CREATE DATABASE [Company] ON PRIMARY (
    NAME = N'Company_data',
    FILENAME = N'D:\SQLskills\Company_data.mdf')
LOG ON (
    NAME = N'Company_log',
    FILENAME = N'C:\SQLskills\Company_log.ldf',
    SIZE = 2MB,
    FILEGROWTH = 0MB);
GO
USE [Company];
GO
ALTER DATABASE [Company] SET RECOVERY SIMPLE;
GO
CREATE TABLE [BigRows] ([c1] INT IDENTITY, [c2] CHAR (8000) DEFAULT 'a');
GO

And then in two other windows, run the following code:

USE [Company];
GO
SET NOCOUNT ON;
GO

WHILE (1 = 1)
BEGIN
	INSERT INTO [BigRows] DEFAULT VALUES;
END;
GO

And within a few seconds, you’ll see LOGMGR_RESERVE_APPEND waits happening (using my waits script). Here’s an example (with a few columns removed for brevity):

WaitType                       WaitCount Percentage AvgWait_S AvgRes_S AvgSig_S Help/Info URL
------------------------------ --------- ---------- --------- -------- -------- -------------------------------------------------------------------
LOGMGR_RESERVE_APPEND          26        50.78      0.9847    0.9847   0.0000   https://www.sqlskills.com/help/waits/LOGMGR_RESERVE_APPEND
PREEMPTIVE_OS_FLUSHFILEBUFFERS 954       22.14      0.0116    0.0116   0.0000   https://www.sqlskills.com/help/waits/PREEMPTIVE_OS_FLUSHFILEBUFFERS
WRITELOG                       131625    21.63      0.0001    0.0001   0.0000   https://www.sqlskills.com/help/waits/WRITELOG
PAGEIOLATCH_UP                 5841      3.37       0.0003    0.0003   0.0000   https://www.sqlskills.com/help/waits/PAGEIOLATCH_UP

So if you ever see these waits, look for databases using the simple recovery mode where the log is set to have zero or very tiny autogrowth.

Enjoy!

Code to show rolled back transactions after a crash

In Monday’s Insider newsletter I discussed an email question I’d been sent about how to identify the transactions that had rolled back because of a crash, and I said I’d blog some code to do it.

First of all you need to know the time of the crash. We can’t get this exactly (from SQL Server) unless SQL Server decides to shut itself down for some reason (like tempdb corruption) but we can easily get the time that SQL Server restarted, which is good enough, as we just need to know a time that’s after the transactions started before the crash, and before those transactions finished rolling back after a crash. We can get the startup time from the sqlserver_start_time column in the output from sys.dm_os_sys_info.

Then we can search in the transaction log, using the fn_dblog function, for LOP_BEGIN_XACT log records from before the crash point that have a matching LOP_ABORT_XACT log record after the crash point, and with the same transaction ID. This is easy because for LOP_BEGIN_XACT log records, there’s a Begin Time column, and for LOP_ABORT_XACT log records (and, incidentally, for LOP_COMMIT_XACT log records), there’s an End Time column in the TVF output.

And there’s a trick you need to use: to get the fn_dblog function to read log records from before the log clears (by the checkpoints that crash recovery does, in the simple recovery model, or by log backups, in other recovery models), you need to enable trace flag 2537. Now, if do all this too long after crash recovery runs, the log may have overwritten itself and so you won’t be able to get the info you need, but if you’re taking log backups, you could restore a copy of the database to the point just after crash recovery has finished, and then do the investigation.

After that, the tricky part is matching what those transactions were doing back to business operations that your applications were performing. If you don’t name your transactions, that’s going to be pretty hard, as all you’ve got are the generic names that SQL Server gives transactions (like INSERT, DELETE, DROPOBJ). Whatever the reason you might want this information, your applications should be written so they gracefully handle transaction failures and leave the database in a consistent state (as far as your business rules are concerned – of course SQL Server leaves the database in a transactionally-consistent state after a crash).

I’ve written some code and encapsulated it in a proc, sp_SQLskillsAbortedTransactions, which is shown in full at the end of the post. To use it, you go into the context of the database you’re interested in, and just run the proc. It takes care of enabling and disabling the trace flag.

Here’s an example of a crash situation and using the proc.

First I’ll create a table and start a transaction:

USE [master];
GO

IF DATABASEPROPERTYEX (N'Company', N'Version') > 0
BEGIN
    ALTER DATABASE [Company] SET SINGLE_USER WITH ROLLBACK IMMEDIATE;
    DROP DATABASE [Company];
END
GO

CREATE DATABASE [Company];
GO
USE [Company];
GO

CREATE TABLE [test] ([c1] INT, [c2] INT, [c3] INT);
GO
INSERT INTO [test] VALUES (0, 0, 0);
GO

BEGIN TRAN FirstTransaction;
INSERT INTO [Test] VALUES (1, 1, 1);
GO

Now in a second window, I’ll start another transaction, and force the log to flush to disk (as I haven’t generated enough log to have the current log block automatically flush to disk):

USE [Company];
GO

BEGIN TRAN SecondTransaction;
INSERT INTO [Test] VALUES (2, 2, 2);
GO

EXEC sp_flush_log;
GO

And in a third window, I’ll force a crash:

SHUTDOWN WITH NOWAIT;
GO

After restarting the instance, I can use this code to run my proc:

USE [Company];
GO

EXEC sp_SQLskillsAbortedTransactions;
GO
Begin Time               Transaction Name   Started By       Transaction ID
------------------------ ------------------ ---------------- --------------
2017/01/18 17:09:36:190  FirstTransaction   APPLECROSS\Paul  0000:00000374
2017/01/18 17:09:40:600  SecondTransaction  APPLECROSS\Paul  0000:00000375

Cool eh?

Here’s the code – enjoy!

/*============================================================================
  File:     sp_SQLskillsAbortedTransactions.sql
 
  Summary:  This script cracks the transaction log and shows which
            transactions were rolled back after a crash
 
  SQL Server Versions: 2012 onwards
------------------------------------------------------------------------------
  Written by Paul S. Randal, SQLskills.com
 
  (c) 2017, SQLskills.com. All rights reserved.
 
  For more scripts and sample code, check out 
    http://www.SQLskills.com
 
  You may alter this code for your own *non-commercial* purposes. You may
  republish altered code as long as you include this copyright and give due
  credit, but you must obtain prior permission before blogging this code.
   
  THIS CODE AND INFORMATION ARE PROVIDED "AS IS" WITHOUT WARRANTY OF 
  ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED 
  TO THE IMPLIED WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A
  PARTICULAR PURPOSE.
============================================================================*/
 
USE [master];
GO
 
IF OBJECT_ID (N'sp_SQLskillsAbortedTransactions') IS NOT NULL
    DROP PROCEDURE [sp_SQLskillsAbortedTransactions];
GO
 
CREATE PROCEDURE sp_SQLskillsAbortedTransactions
AS
BEGIN
    SET NOCOUNT ON;

    DBCC TRACEON (2537);
 
    DECLARE @BootTime	DATETIME;
    DECLARE @XactID     CHAR (13);

    SELECT @BootTime = [sqlserver_start_time] FROM sys.dm_os_sys_info;

    IF EXISTS (SELECT * FROM [tempdb].[sys].[objects]
        WHERE [name] = N'##SQLskills_Log_Analysis')
        DROP TABLE [##SQLskills_Log_Analysis];

    -- Get the list of started and rolled back transactions from the log
    SELECT
        [Begin Time],
        [Transaction Name],
        SUSER_SNAME ([Transaction SID]) AS [Started By],
        [Transaction ID],
        [End Time],
        0 AS [RolledBackAfterCrash],
        [Operation]
    INTO ##SQLskills_Log_Analysis
    FROM fn_dblog (NULL, NULL)
    WHERE ([Operation] = 'LOP_BEGIN_XACT' AND [Begin Time] < @BootTime) OR ([Operation] = 'LOP_ABORT_XACT' AND [End Time] > @BootTime);

    DECLARE [LogAnalysis] CURSOR FAST_FORWARD FOR
    SELECT
        [Transaction ID]
    FROM
        ##SQLskills_Log_Analysis;
 
    OPEN [LogAnalysis];
 
    FETCH NEXT FROM [LogAnalysis] INTO @XactID;
 
    WHILE @@FETCH_STATUS = 0
    BEGIN
        IF EXISTS (
            SELECT [End Time] FROM ##SQLskills_Log_Analysis
            WHERE [Operation] = 'LOP_ABORT_XACT' AND [Transaction ID] = @XactID)
        UPDATE ##SQLskills_Log_Analysis SET [RolledBackAfterCrash] = 1
            WHERE [Transaction ID] = @XactID
            AND [Operation] = 'LOP_BEGIN_XACT';

        FETCH NEXT FROM [LogAnalysis] INTO @XactID;
    END;
 
    CLOSE [LogAnalysis];
    DEALLOCATE [LogAnalysis];
 
    SELECT
        [Begin Time],
        [Transaction Name],
        [Started By],
        [Transaction ID]
    FROM ##SQLskills_Log_Analysis
    WHERE [RolledBackAfterCrash] = 1;
 
    DBCC TRACEOFF (2537);

    DROP TABLE ##SQLskills_Log_Analysis;
END
GO
 
EXEC sys.sp_MS_marksystemobject [sp_SQLskillsAbortedTransactions];
GO
 
-- USE [Company]; EXEC sp_SQLskillsAbortedTransactions;