Installing and Configuring SQL Server 2012 Distributed Replay

This blog post is the first in a series of posts that will cover how to install, configure, and use the new Distributed Replay Utility in SQL Server 2012.  The distributed replay utility can be used to assess the impact of changes and upgrades by replaying workload activity against a test environment based on a replay trace captured from the current production SQL Server environment.  Prior to SQL Server 2012, two features existed that provided replay capabilities for performance benchmarking and stress testing SQL Server based on a replay workload; SQL Server Profiler trace replay and RML Utilities.  Unlike these two tools, Distributed Replay is not limited to replaying events from a single computer, which allows you to drive higher loads against the test environment to better simulate mission-critical workloads by driving load from multiple clients concurrently.

This blog post will show how to configure a Distributed Replay Controller, using a dedicated server named SQL2012-DRU, and two Distributed Replay Clients using dedicated servers named SQL2012-DRU1 and SQL2012-DRU2.  For the purposes of performing an actual replay using Distributed Replay in another post, a separate server named SQL2012-DB1 with the Database Engine Services and the AdventureWorks2008R2 database installed on it will be used.

Create Replay Service Accounts in Active Directory

The first step in installing and configuring Distributed Replay is to setup the necessary Active Directory service accounts to run the Distributed Replay Client and Distributed Replay Controller under.  For the purposes of service isolation, the Distributed Replay Clients and Distributed Replay Controller will make use of separate Active Directory service Accounts.  For the purposes of this blog post, two different accounts will be created.  The Distributed Replay Client will use the SQLskillsDemos\DRUClientSvcAcct as shown in the below screenshots.

image

The Distributed Replay Controller will use the SQLskillsDemos\DRUCtrlSvcAcct as shown in the below screenshots:

image

Install the Replay Controller

With the service accounts setup in Active Directory, we can begin the installation of our Distributed Replay Controller.  To do this run SQL Server 2012 Setup on the controller and perform a SQL Server Feature Installation.  On the Feature Selection page select the Distributed Replay Client feature.

image

On the Server Configuration page set the Service Account credentials to the previously created Active Directory account for the client; in this case SQLSKILLSDEMOS\DRUCtrlSvcAcct.

image

On the Distributed Replay Controller page, click the Add button and search directory services for the client service account previous created in Active Directory; in this case SQLSKILLSDEMOS\DRUClientSvcAcct.

image

Finish the installation and then close SQL Server Setup.

Install the Replay Clients

With the service accounts setup in Active Directory, we can begin the installation of our Distributed Replay Client machines.  To do this run SQL Server 2012 Setup on each of the clients to be configured and perform a SQL Server Feature Installation.  On the Feature Selection page select the Distributed Replay Client feature.

image

On the Server Configuration page set the Service Account credentials to the previously created Active Directory account for the client.  In this case SQLSKILLSDEMOS\DRUClientSvcAcct.

image

On the Distributed Replay Client page, type in the name of the server that you previously installed the Distributed Replay Controller service on in the Controller Name box.

image

Finish the installation and then close SQL Server Setup.

Configure the Windows Firewall for the Services

In order for the Distributed Replay Clients (SQL2012-DRU1 and SQL2012-DRU2) to connect and register with the Distributed Replay Controller, in this case SQL2012-DRU, the firewall must be configured to allow inbound connections for the DReplayClient.exe application on each of the client machines, as well as for the DReplayController.exe application on the Distributed Replay Controller.  To do this, firewall rules need to be added through the use of the Windows Firewall with Advanced Security snapin, available through Start | Administrative Tools | Windows Firewall with Advanced Security, or through the use of NETSH command line statement executions (detailed later in this blog post). 

To add a new firewall rule for the DReplay Client using the Windows Firewall with Advanced Security snapin, Right-Click on Inbound Rules and click on the New Rule menu item.  Specify Program for the Rule Type and click Next.

image

On the Program page, click Browse and navigate to C:\Program Files (x86)\Microsoft SQL Server\110\Tools\DReplayClient and select the DReplayClient.exe executable.

image

On the Action page select the option Allow the connection and then click Next.

image

On the Profile page, select the appropriate network profiles/locations for the environment, generally Domain would be sufficient for most corporate domains, and then click Next.

image

Finally provide a Name for the rule and click Finish to make the firewall changes.

image

To setup the firewall rule for the Distributed Replay Controller, follow the same steps but instead of selecting the DReplayClient folder and DReplayClient.exe application, select the DReplayController folder and DReplayController.exe application

image

These rules can also be added using NETSH from the command line using the following commands:

NETSH advfirewall firewall add rule name="Allow DReplay Client" dir=in program="C:\Program Files (x86)\Microsoft SQL Server\110\Tools\DReplayClient\DReplayClient.exe" action=allow

NETSH advfirewall firewall add rule name="Allow DReplay Controller" dir=in program="C:\Program Files (x86)\Microsoft SQL Server\110\Tools\DReplayController\DReplayController.exe" action=allow

Start the Services and Verify Client Registrations

The final step in the process of installing and configuring SQL Server 2012 Distributed Replay is to start the services and verify that the Distributed Replay Clients register with the Distributed Replay Controller correctly.  To do this start the “Distributed Replay Controller” service from the Services.msc snap-in or from the command line using NET START on the controller server.  Then start the “Distributed Replay Client” service on from the Services.msc snap-in or from the command line using NET START on each of the client machines.  As each of the client services starts, verify that the client was able to successfully register itself with the controller by reading the log file, which is located in the following path:

C:\Program Files (x86)\Microsoft SQL Server\110\Tools\DReplayClient\Log

What you want to see in the DReplay Client Log file is:

2011-11-09 00:41:09:162 OPERATIONAL  [Client Service]      Microsoft SQL Server Distributed Replay Client – 11.0.1440.19.
2011-11-09 00:41:09:162 OPERATIONAL  [Client Service]      (c) Microsoft Corporation.
2011-11-09 00:41:09:162 OPERATIONAL  [Client Service]      All rights reserved.
2011-11-09 00:41:09:178 OPERATIONAL  [Client Service]      Current edition is: [Enterprise Evaluation Edition].
2011-11-09 00:41:09:178 OPERATIONAL  [Common]              Initializing dump support.
2011-11-09 00:41:09:178 OPERATIONAL  [Common]              Dump support is ready.
2011-11-09 00:41:09:193 OPERATIONAL  [Client Service]      Windows service "Microsoft SQL Server Distributed Replay Client" has started under service account "SQLSKILLSDEMOS\DRUClientSvcAcct". Process ID is 2928.
2011-11-09 00:41:09:193 OPERATIONAL  [Client Service]      Time Zone: Eastern Standard Time.
2011-11-09 00:41:09:193 OPERATIONAL  [Client Service]      Controller name is "SQL2012-DRU".
2011-11-09 00:41:09:193 OPERATIONAL  [Client Service]      Working directory is "C:\Program Files (x86)\Microsoft SQL Server\110\Tools\DReplayClient\WorkingDir".
2011-11-09 00:41:09:193 OPERATIONAL  [Client Service]      Result directory is "C:\Program Files (x86)\Microsoft SQL Server\110\Tools\DReplayClient\ResultDir".
2011-11-09 00:41:09:193 OPERATIONAL  [Client Service]      Heartbeat Frequency(ms): 3000
2011-11-09 00:41:09:193 OPERATIONAL  [Client Service]      Heartbeats Before Timeout: 3
2011-11-09 00:41:09:367 OPERATIONAL  [Client Service]      Registered with controller "SQL2012-DRU".

What you don’t want to see in the DReplay Client Log file is:

2011-11-09 00:40:50:207 OPERATIONAL  [Client Service]      Microsoft SQL Server Distributed Replay Client – 11.0.1440.19.
2011-11-09 00:40:50:223 OPERATIONAL  [Client Service]      (c) Microsoft Corporation.
2011-11-09 00:40:50:223 OPERATIONAL  [Client Service]      All rights reserved.
2011-11-09 00:40:50:223 OPERATIONAL  [Client Service]      Current edition is: [Enterprise Evaluation Edition].
2011-11-09 00:40:50:223 OPERATIONAL  [Common]              Initializing dump support.
2011-11-09 00:40:50:239 OPERATIONAL  [Common]              Dump support is ready.
2011-11-09 00:40:50:239 OPERATIONAL  [Client Service]      Windows service "Microsoft SQL Server Distributed Replay Client" has started under service account "SQLSKILLSDEMOS\DRUClientSvcAcct". Process ID is 776.
2011-11-09 00:40:50:239 OPERATIONAL  [Client Service]      Time Zone: Eastern Standard Time.
2011-11-09 00:40:50:239 OPERATIONAL  [Client Service]      Controller name is "SQL2012-DRU".
2011-11-09 00:40:50:239 OPERATIONAL  [Client Service]      Working directory is "C:\Program Files (x86)\Microsoft SQL Server\110\Tools\DReplayClient\WorkingDir".
2011-11-09 00:40:50:239 OPERATIONAL  [Client Service]      Result directory is "C:\Program Files (x86)\Microsoft SQL Server\110\Tools\DReplayClient\ResultDir".
2011-11-09 00:40:50:239 OPERATIONAL  [Client Service]      Heartbeat Frequency(ms): 3000
2011-11-09 00:40:50:239 OPERATIONAL  [Client Service]      Heartbeats Before Timeout: 3
2011-11-09 00:40:50:476 CRITICAL     [Client Service]     [0xC8100013] Failed to register with controller SQL2012-DRU.

If the client fails to register, and the controller name is correct, you need to verify first that the firewall rules have been established for the client to allow the appropriate inbound connections from the controller service and that the firewall rules have been established for the controller to allow the appropriate inbound connections from the client services.  If this all checks out, you need to go troubleshoot the permissions and setup of the services in the environment, which I’ll cover in a later post.

Capturing InfoMessage Output (PRINT, RAISERROR) from SQL Server using PowerShell

Tonight, a question was asked on the #sqlhelp tag on Twitter about how to capture all of the output from a stored procedures execution, to include the informational and error message outputs that may be returned by using PRINT or RAISERROR in the code.  This was a problem I ran into in the past with C# and the way you do it in .NET is to handle the InfoMessage Event for the SqlConnection object using a SqlInfoMessageEventHandler in your code.  The same thing can be done in PowerShell to have these messages written out to the output of a scripts execution.

$conn = New-Object System.Data.SqlClient.SqlConnection "Server=.\LAB1;Database=tempdb;Integrated Security=SSPI;";
$conn.Open();

## Standard default connection with no EventHandler
$cmd = $conn.CreateCommand();
$cmd.CommandText = "PRINT ‘This is the message from the PRINT statement’";
$res = $cmd.ExecuteNonQuery();
$cmd.CommandText = "RAISERROR(‘This is the message from the RAISERROR statement’, 10, 1)"; 
$res = $cmd.ExecuteNonQuery();
$conn.Close();

## Attach the InfoMessage Event Handler to the connection to write out the messages
$handler = [System.Data.SqlClient.SqlInfoMessageEventHandler] {param($sender, $event) Write-Host $event.Message };
$conn.add_InfoMessage($handler);
$conn.FireInfoMessageEventOnUserErrors = $true;

$conn.Open();

$cmd = $conn.CreateCommand();
$cmd.CommandText = "PRINT ‘This is the message from the PRINT statement’";
$res = $cmd.ExecuteNonQuery();
$cmd.CommandText = "RAISERROR(‘This is the message from the RAISERROR statement’, 10, 1)"; 
$res = $cmd.ExecuteNonQuery();
$conn.Close();

The bold code region above creates the EventHandler so that it writes the Message out to the host and then adds the handler to the InfoMessage Event for the connection.  The last line of code specifies for the event to fire on lower priority user errors as well.

Extended Events Changes in SQL Server 2012 – Event XML for XML data elements

While working on validating my demos for the 24 Hours of PASS and my PASS Summit 2011 Precon – Extended Events Deep Dive, I noticed a significant, and breaking change to the Event XML output for the raw event data in the ring_buffer and file_target in SQL Server Denali.  In SQL Server 2008 and 2008R2, the Event XML represented the output of XML data elements differently than in SQL Server Denali CTP3.  A good example of this is the xml_deadlock_report output, which I previously discussed in my SQL Server Central article,

In SQL Server 2008 and 2008R2, the query to retrieve the deadlock graph from the system_health session was (excluding the work around that was included in the original article since the xml_deadlock_report was fixed in a later Cumulative Update and the latest Service Pack for SQL Server 2008 and 2008 R2).

SELECT 
    CAST(event_data.value('(data/value)[1]', 'varchar(max)')) AS XML) AS DeadlockGraph 
FROM 
(   SELECT XEvent.query('.') AS event_data 
    FROM 
    (   -- Cast the target_data to XML 
        SELECT CAST(target_data AS XML) AS TargetData 
        FROM sys.dm_xe_session_targets AS st 
        INNER JOIN sys.dm_xe_sessions AS s 
            ON s.address = st.event_session_address 
        WHERE name = N'system_health' 
          AND target_name = N'ring_buffer' 
    ) AS Data 
    -- Split out the Event Nodes 
    CROSS APPLY TargetData.nodes ('RingBufferTarget/event[@name="xml_deadlock_report"]') AS XEventData (XEvent)   
) AS tab (event_data);

If you run this same code in SQL Server Denali CTP3, the output will not be the xml_deadlock_report but instead the textual data that was included in the sub-nodes of the value node for the xml_deadlock_report events in the target.  This unfortunately has broken a number of my scripts that were initially written for SQL Server 2008 and 2008R2 that expect the XML output as text in the value element as follows:

<event name="xml_deadlock_report" package="sqlserver" id="123" version="1" timestamp="2011-09-15T23:29:02.851Z"> 
  <data name="xml_report"> 
    <type name="unicode_string" package="package0" /> 
    <value>&lt;deadlock-list&gt; 
&lt;victim-list&gt; 
  &lt;victimProcess id="process806e2088"/&gt; 
  &lt;process-list&gt; 
   &lt;process id="process806e2088" taskpriority="0" logused="10000" waitresource="DATABASE: 15 " waittime="1477" schedulerid="2" kpid="3720" status="suspended" spid="57" sbid="0" ecid="0" priority="0" trancount="1" lastbatchstarted="2011-09-15T19:29:01.370" lastbatchcompleted="2011-09-15T19:27:21.193" clientapp="Microsoft SQL Server Management Studio – Query" hostname="SQL2K8R2-IE2" hostpid="4464" loginname="SQLSKILLSDEMOS\administrator" isolationlevel="read committed (2)" xactid="68641" currentdb="15" lockTimeout="4294967295" clientoption1="671090784" clientoption2="390200"&gt; 
    &lt;executionStack&gt; 
     &lt;frame procname="" line="1" sqlhandle="0x01000100721ac42240ff1285000000000000000000000000"&gt; 
     &lt;/frame&gt; 
    &lt;/executionStack&gt; 
    &lt;inputbuf&gt; 
ALTER DATABASE DemoNCIndex SET MULTI_USER 
    &lt;/inputbuf&gt; 
   &lt;/process&gt; 
   &lt;process id="process469b88" taskpriority="0" logused="10000" waitresource="DATABASE: 15 " waittime="1892" schedulerid="2" kpid="4188" status="suspended" spid="58" sbid="0" ecid="0" priority="0" trancount="0" lastbatchstarted="2011-09-15T19:29:00.957" lastbatchcompleted="2011-09-15T19:29:00.947" clientapp="Microsoft SQL Server Management Studio – Transact-SQL IntelliSense" hostname="SQL2K8R2-IE2" hostpid="4464" loginname="SQLSKILLSDEMOS\administrator" isolationlevel="read committed (2)" xactid="68638" currentdb="15" lockTimeout="4294967295" clientoption1="671088672" clientoption2="128056"&gt; 
    &lt;executionStack&gt; 
     &lt;frame procname="" line="1" sqlhandle="0x010001008af5b714605a1f85000000000000000000000000"&gt; 
     &lt;/frame&gt; 
    &lt;/executionStack&gt; 
    &lt;inputbuf&gt; 
use [DemoNCIndex]    &lt;/inputbuf&gt; 
   &lt;/process&gt; 
  &lt;/process-list&gt; 
  &lt;resource-list&gt; 
   &lt;databaselock subresource="FULL" dbid="15" dbname="" id="lock83168d80" mode="S"&gt; 
    &lt;owner-list&gt; 
     &lt;owner id="process469b88" mode="S"/&gt; 
    &lt;/owner-list&gt; 
    &lt;waiter-list&gt; 
     &lt;waiter id="process806e2088" mode="X" requestType="wait"/&gt; 
    &lt;/waiter-list&gt; 
   &lt;/databaselock&gt; 
   &lt;databaselock subresource="FULL" dbid="15" dbname="" id="lock83168d80" mode="S"&gt; 
    &lt;owner-list&gt; 
     &lt;owner id="process806e2088" mode="S"/&gt; 
     &lt;owner id="process806e2088" mode="S"/&gt; 
    &lt;/owner-list&gt; 
    &lt;waiter-list&gt; 
     &lt;waiter id="process469b88" mode="X" requestType="wait"/&gt; 
    &lt;/waiter-list&gt; 
   &lt;/databaselock&gt; 
  &lt;/resource-list&gt; 
&lt;/deadlock&gt; 
&lt;/deadlock-list&gt; 
</value> 
    <text /> 
  </data> 
</event>

Instead in SQL Server Denali CTP3, the event output is as follows:

<event name="xml_deadlock_report" package="sqlserver" timestamp="2011-09-17T18:49:03.654Z"> 
  <data name="xml_report"> 
    <type name="xml" package="package0" /> 
    <value> 
      <deadlock> 
        <victim-list> 
          <victimProcess id="processf7034a18" /> 
        </victim-list> 
        <process-list> 
          <process id="processf7034a18" taskpriority="0" logused="144" waitresource="RID: 2:1:281:0" waittime="2394" ownerId="162349" transactionname="user_transaction" lasttranstarted="2011-09-17T11:48:48.410" XDES="0xff047120" lockMode="S" schedulerid="2" kpid="692" status="suspended" spid="58" sbid="0" ecid="0" priority="0" trancount="1" lastbatchstarted="2011-09-17T11:49:01.247" lastbatchcompleted="2011-09-17T11:48:48.410" lastattention="2011-09-17T11:39:47.393" clientapp="Microsoft SQL Server Management Studio – Query" hostname="WIN-QSTGAPD63IN" hostpid="3004" loginname="WIN-QSTGAPD63IN\Administrator" isolationlevel="read committed (2)" xactid="162349" currentdb="2" lockTimeout="4294967295" clientoption1="671090784" clientoption2="390200"> 
            <executionStack> 
              <frame procname="adhoc" line="1" sqlhandle="0x02000000303b01237c6994b4eab30fb77cbb5a8e46f2b2540000000000000000000000000000000000000000"> 
SELECT Column2 
FROM TableB    </frame> 
            </executionStack> 
            <inputbuf> 
SELECT Column2 
FROM TableB   </inputbuf> 
          </process> 
          <process id="processf7035168" taskpriority="0" logused="144" waitresource="RID: 2:1:271:0" waittime="7494" ownerId="162369" transactionname="user_transaction" lasttranstarted="2011-09-17T11:48:53.693" XDES="0xf7044dd0" lockMode="S" schedulerid="2" kpid="3244" status="suspended" spid="60" sbid="0" ecid="0" priority="0" trancount="1" lastbatchstarted="2011-09-17T11:48:56.150" lastbatchcompleted="2011-09-17T11:48:53.693" lastattention="1900-01-01T00:00:00.693" clientapp="Microsoft SQL Server Management Studio – Query" hostname="WIN-QSTGAPD63IN" hostpid="3004" loginname="WIN-QSTGAPD63IN\Administrator" isolationlevel="read committed (2)" xactid="162369" currentdb="2" lockTimeout="4294967295" clientoption1="671090784" clientoption2="390200"> 
            <executionStack> 
              <frame procname="adhoc" line="2" stmtstart="4" sqlhandle="0x020000002e8952007a6c36a78a2aa436877a27f57a0725c80000000000000000000000000000000000000000"> 
SELECT Column1 
FROM TableA    </frame> 
            </executionStack> 
            <inputbuf>

SELECT Column1 
FROM TableA   </inputbuf> 
          </process> 
        </process-list> 
        <resource-list> 
          <ridlock fileid="1" pageid="281" dbid="2" objectname="tempdb.dbo.TABLEB" id="lockf7d4ff80" mode="X" associatedObjectId="2161727822326792192"> 
            <owner-list> 
              <owner id="processf7035168" mode="X" /> 
            </owner-list> 
            <waiter-list> 
              <waiter id="processf7034a18" mode="S" requestType="wait" /> 
            </waiter-list> 
          </ridlock> 
          <ridlock fileid="1" pageid="271" dbid="2" objectname="tempdb.dbo.TABLEA" id="lockf7d51380" mode="X" associatedObjectId="2089670228247904256"> 
            <owner-list> 
              <owner id="processf7034a18" mode="X" /> 
            </owner-list> 
            <waiter-list> 
              <waiter id="processf7035168" mode="S" requestType="wait" /> 
            </waiter-list> 
          </ridlock> 
        </resource-list> 
      </deadlock> 
    </value> 
  </data> 
</event>

If you compare the two bold sections to each other you will notice the difference.  In SQL Server 2008 and 2008R2, the value element is XML escaped entirely as text, but in SQL Server Denali CTP3, the value attribute contains a valid XML document as a child node in the XML itself.  This has a significant impact to how you actually access the XML data in Denali CTP3.  To read the XML Document, you have to switch from using the .value() XML function along with a CAST() operation to using a .query() operation on the Event XML specifying the deadlock node as a part of the .query() XPATH for it as shown in the following code example:

SELECT 
    event_data.query('(event/data/value/deadlock)[1]') AS DeadlockGraph 
FROM 
(   SELECT XEvent.query('.') AS event_data 
    FROM 
    (   -- Cast the target_data to XML 
        SELECT CAST(target_data AS XML) AS TargetData 
        FROM sys.dm_xe_session_targets AS st 
        INNER JOIN sys.dm_xe_sessions AS s 
            ON s.address = st.event_session_address 
        WHERE name = N'system_health' 
          AND target_name = N'ring_buffer' 
    ) AS Data 
    -- Split out the Event Nodes 
    CROSS APPLY TargetData.nodes ('RingBufferTarget/event[@name="xml_deadlock_report"]') AS XEventData (XEvent)   
) AS tab (event_data);

This same thing applies to all of the XML data elements including the sqlserver.tsql_stack and sqlserver.tsql_frame Actions.  In addition other actions such as the sqlserver.plan_handle have similar changes that require changing the code to process the Event XML to capture the values being output.