m82labs 2017-09-12T12:38:05+00:00 https://m82labs.com Mark Wilkinson mark@m82labs.com Automation Basics with Powershell and CMS 2017-09-12T00:00:00+00:00 https://m82labs.com/cms-posh Retrieving servers from a Central Management Server using PowerShell. <p>As a DBA I use PowerShell every day. If it can be automated, I will automate it. In my environment I have 300+ instances to keep track of and maintain. When you manage that many instances, it’s important to have a “source of truth” for a full list of your instances. This is where Central Management Server (CMS) comes in. The combination of PowerShell and CMS is a powerful one. In this post we’ll explore a PowerShell function I wrote to retrieve servers from my CMS server.</p> <p>I want to thank Rob Sewell (<a href="https://sqldbawithabeard.com/">WWW</a>/<a href="https://twitter.com/sqldbawithbeard">Twitter</a>) for hosting this months T-SQL Tuesday! If you are interested in learning more about T-SQL Tuesday, take a look at Rob’s <a href="https://sqldbawithabeard.com/2017/09/05/tsql2sday-94-lets-get-all-posh/">post</a>, and check out the <a href="https://twitter.com/hashtag/tsql2sday?f=realtime&amp;src=hash">#tsql2sday</a> hashtag on Twitter.</p> <blockquote> <p>Central Management Server is an old feature, and easy to configure in Management Studio. CMS allows you to create a list of your instances on a central server. You can group your instances and, in Management Studio, run queries across multiple instances at a time. To learn more about CMS, head over to: <a href="https://docs.microsoft.com/en-us/sql/ssms/register-servers/create-a-central-management-server-and-server-group">Microsoft Docs</a>.</p> </blockquote> <h1 id="get-cmshosts">Get-CmsHosts</h1> <p><code class="highlighter-rouge">Get-CmsHosts</code> is a function I wrote as part of a custom PowerShell module we maintain internally at my employer. It is simple to use, but is the base of most automation projects I work on.</p> <h3 id="simple-example">Simple Example</h3> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="nb">PS</span>&gt; Get-CmsHosts -SqlInstance <span class="s1">'srv-'</span> -CmsInstance srv-mycms-01</code></pre></figure> <p>This example will connect to <code class="highlighter-rouge">srv-mycms-01</code> and return a distinct list of instance host names registered with that CMS server that start with the string <code class="highlighter-rouge">srv-</code>. This output can then be piped to other commands:</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="nb">PS</span>&gt; Get-CmsHosts -SqlInstance <span class="s1">'srv-'</span> -CmsInstance srv-mycms-01 | % <span class="o">{</span> Invoke-SqlCmd -Query <span class="s1">'exec dbo.MyProc'</span> -ServerInstance <span class="nv">$_</span> <span class="o">}</span></code></pre></figure> <p>In this example <code class="highlighter-rouge">%</code> is short-hand for <code class="highlighter-rouge">ForEach</code>. This will iterate through the list of instances and store the name of the current instance in a temporary variable <code class="highlighter-rouge">$_</code>. We then use that variable to run <code class="highlighter-rouge">Invoke-SqlCmd</code>. You can already see how useful this can be.</p> <h3 id="specific-versions">Specific Versions</h3> <p>It is common to use this function when we are remotely upgrading instances. In this specific use case it is very important that you only run the upgrade or patch on SQL Server running a specific version.</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="nb">PS</span>&gt; Get-CmsHosts -Version <span class="s1">'13.0.1605.1'</span> -CmsInstance srv-mycms-01</code></pre></figure> <p>This command will only return instances running version 13.0.1605.1 (2016 RTM) of SQL Server.</p> <blockquote> <p>When using <code class="highlighter-rouge">-Version</code>, try to filter using the name as well. In order to get the version of the instance the function will connect to each one and run a query. If you have a lot of instances, this will take a lot of time.</p> </blockquote> <h3 id="list-of-databases">List of Databases</h3> <p>Sometimes you might need to run a query of PowerShell cmdlet against all of the databases in on a given server, or group of servers. Using the <code class="highlighter-rouge">-EnumDatabases</code> you can do this:</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="nb">PS</span>&gt; Get-CmsHosts -SqlInstance srv-server-01 -CmsInstance srv-mycms-01 -EnumDatabases | % <span class="o">{</span> <span class="nv">$CurrServer</span> <span class="o">=</span> <span class="nv">$_</span> <span class="nv">$CurrDatabases</span> <span class="o">=</span> <span class="nv">$_</span>.Databases <span class="nv">$CurrDatabases</span> | % <span class="o">{</span> Invoke-SqlCmd -Query <span class="s1">'exec dbo.MyProc'</span> -Database <span class="nv">$_</span> -ServerInstance <span class="nv">$CurrServer</span> <span class="o">}</span> <span class="o">}</span></code></pre></figure> <p><code class="highlighter-rouge">EnumDatabases</code> will enumerate the databases on any instances that are returned. In the above example we are running <code class="highlighter-rouge">dbo.MyProc</code> against each instance, and each database on that instance, returned by the call to Cms-Hosts. When using <code class="highlighter-rouge">EnumDatabases</code> the list of databases on the instance is queried and returned with the instance. This means each instance returned by the function will have two members. One named <code class="highlighter-rouge">Name</code> that holds the name of the instance. And another named <code class="highlighter-rouge">Databases</code> that holds the list of databases. Besides upgrades, this can also be useful for tasks like setting database owners, or checking/applying a security configuration.</p> <h1 id="configuration-and-other-options">Configuration and Other Options</h1> <p>You can avoid having to pass in the <code class="highlighter-rouge">CmsInstance</code> parameter if you simply set an OS level environment variable named <code class="highlighter-rouge">SQL_CMS</code> that holds the name of your CMS instance. If you want to test this, the first example could be re-written to shows it’s use of the environment variable:</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="nb">PS</span>&gt; <span class="nv">$env</span>:SQL_CMS <span class="o">=</span> <span class="s1">'srv-mycms-01'</span> <span class="nb">PS</span>&gt; Get-CmsHosts -SqlInstance <span class="s1">'srv-'</span></code></pre></figure> <p>While CMS can be very useful, it isn’t always available, especially if you are testing your scripts on your local computer while disconnected from the network. For cases like this, and to keep your scripts consistent, you can pass a file path to the <code class="highlighter-rouge">SqlInstance</code> parameter. the file should contain a single instance name per line. If the function sees that a file was passed in, it will use the file contents instead of connecting to the CMS. All the other parameters still work as expected.</p> <h1 id="get-the-script">Get the Script!</h1> <p>PowerShell and CMS are a combination I use for almost all of my automation tasks. Grab a copy of the function and see what you can use it for. If you have any suggestions, or want to submit updates, please leave comments here or issue a pull request on GitHub.</p> <p>You can get your copy of Get-CmsHosts at my Github repo: <a href="https://raw.githubusercontent.com/m82labs/post_scripts/master/PowerShell/Get-CMSHosts.ps1">Post Scripts</a></p> Handling SQL Agent Job Failures 2017-08-30T00:00:00+00:00 https://m82labs.com/Handling-Job-Failures Quiet down your noisy job failure alerts and gain new functionality. <p>Hopefully you don’t experience a lot of job failures. But when multiple high-frequency jobs start failing, your inbox can get overloaded. Besides being annoying, an inbox full of job failure emails can make it hard to sift out the signal from the noise. In this post we’ll walk through a system that I have used to monitor job failures on 100’s of instances running 150+ jobs a piece, many of which run every 5 minutes.</p> <h2 id="overview">Overview</h2> <p>At it’s core, the system has three components: a stored procedure, a SQL Agent job, and a table. The table stores job failure details. The agent job executes a procedure to copy job failure details to the table, and cleans up the job history table in MSDB.</p> <h3 id="the-table">The Table</h3> <p>The table is simple, and holds the information you would expect:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="p">[</span><span class="n">DBA</span><span class="p">]</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">TABLE</span> <span class="p">[</span><span class="n">Maintenance</span><span class="p">].[</span><span class="n">JobFailureArchive</span><span class="p">]</span> <span class="p">(</span> <span class="n">JobFailureArchiveID</span> <span class="n">INT</span> <span class="k">IDENTITY</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">1</span><span class="p">)</span> <span class="k">NOT</span> <span class="k">NULL</span><span class="p">,</span> <span class="n">JobID</span> <span class="n">UNIQUEIDENTIFIER</span> <span class="k">NOT</span> <span class="k">NULL</span><span class="p">,</span> <span class="n">JobName</span> <span class="n">SYSNAME</span> <span class="k">NOT</span> <span class="k">NULL</span><span class="p">,</span> <span class="n">RunDate</span> <span class="n">DATETIME</span> <span class="k">NOT</span> <span class="k">NULL</span><span class="p">,</span> <span class="n">StepID</span> <span class="n">INT</span> <span class="k">NOT</span> <span class="k">NULL</span><span class="p">,</span> <span class="n">OutcomeText</span> <span class="n">NVARCHAR</span><span class="p">(</span><span class="mi">4000</span><span class="p">)</span> <span class="k">NOT</span> <span class="k">NULL</span><span class="p">,</span> <span class="n">RunDurationSec</span> <span class="n">INT</span> <span class="k">NOT</span> <span class="k">NULL</span><span class="p">,</span> <span class="n">LogDateGMT</span> <span class="n">DATETIME</span> <span class="k">NOT</span> <span class="k">NULL</span><span class="p">,</span> <span class="c1">-- Date and time the record was added</span> <span class="k">CONSTRAINT</span> <span class="n">PK_JobFailureArchive</span> <span class="k">PRIMARY</span> <span class="k">KEY</span> <span class="n">CLUSTERED</span> <span class="p">(</span> <span class="n">JobFailureArchiveID</span> <span class="p">)</span> <span class="k">WITH</span> <span class="p">(</span> <span class="n">FILLFACTOR</span> <span class="o">=</span> <span class="mi">100</span> <span class="p">),</span> <span class="k">INDEX</span> <span class="n">IX_JobFailureArchive_RunDate</span> <span class="n">NONCLUSTERED</span> <span class="p">(</span> <span class="n">RunDate</span><span class="p">,</span> <span class="n">JobName</span> <span class="p">)</span> <span class="k">WITH</span> <span class="p">(</span> <span class="n">FILLFACTOR</span> <span class="o">=</span> <span class="mi">100</span> <span class="p">)</span> <span class="p">);</span> <span class="k">GO</span></code></pre></figure> <blockquote> <p>Throughout the rest of this post I will be using the <code class="highlighter-rouge">DBA</code> database. This is a database I create on any instance I manage. I use it to store any objects I need to perform monitoring and troubleshooting tasks. I also tend to break out my objects by schema, in these examples I will be using the <code class="highlighter-rouge">Maintenance</code> schema.</p> </blockquote> <h3 id="the-procedure">The Procedure</h3> <p>The procedure copies job failure data from the <code class="highlighter-rouge">dbo.sysjobhistory</code> table in <code class="highlighter-rouge">MSDB</code> to the <code class="highlighter-rouge">JobFailureArchive</code> table. Before it does this, the procedure scans the <code class="highlighter-rouge">JobFailureArchive</code> table to determine the date of the most recent job failure it had captured.</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="p">[</span><span class="n">DBA</span><span class="p">]</span> <span class="k">GO</span> <span class="c1">----------------------------------------------------------------------------------</span> <span class="c1">-- Procedure Name: Maintenance.ArchiveFailedJobs</span> <span class="c1">--</span> <span class="c1">-- Desc: Archives failed job details before purging job history.</span> <span class="c1">--</span> <span class="c1">-- Parameters:</span> <span class="c1">--</span> <span class="c1">-- Auth: Mark Wilkinson (@m82labs)</span> <span class="c1">-- Date: 2017.08.20</span> <span class="c1">----------------------------------------------------------------------------------</span> <span class="k">CREATE</span> <span class="k">OR</span> <span class="k">ALTER</span> <span class="k">PROCEDURE</span> <span class="p">[</span><span class="n">Maintenance</span><span class="p">].[</span><span class="n">ArchiveFailedJobs</span><span class="p">]</span> <span class="k">AS</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">lastFailure</span> <span class="n">DATETIME</span> <span class="c1">-- Last time a failure was captured</span> <span class="c1">-- Get the most recent job failure recorded.</span> <span class="k">SET</span> <span class="o">@</span><span class="n">lastFailure</span> <span class="o">=</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="k">ISNULL</span><span class="p">(</span><span class="k">MAX</span><span class="p">(</span><span class="n">RunDate</span><span class="p">),</span><span class="s1">'19000101'</span><span class="p">)</span> <span class="k">AS</span> <span class="n">MaxRunDate</span> <span class="k">FROM</span> <span class="n">Maintenance</span><span class="p">.</span><span class="n">JobFailureArchive</span> <span class="p">)</span> <span class="c1">-- Insert new job failures</span> <span class="k">INSERT</span> <span class="k">INTO</span> <span class="n">Maintenance</span><span class="p">.</span><span class="n">JobFailureArchive</span> <span class="p">(</span> <span class="n">JobID</span><span class="p">,</span> <span class="n">JobName</span><span class="p">,</span> <span class="n">RunDate</span><span class="p">,</span> <span class="n">StepID</span><span class="p">,</span> <span class="n">OutcomeText</span><span class="p">,</span> <span class="n">RunDuration</span> <span class="p">)</span> <span class="k">SELECT</span> <span class="n">sj</span><span class="p">.</span><span class="n">job_id</span><span class="p">,</span> <span class="n">sj</span><span class="p">.</span><span class="n">name</span><span class="p">,</span> <span class="n">msdb</span><span class="p">.</span><span class="n">dbo</span><span class="p">.</span><span class="n">agent_datetime</span><span class="p">(</span><span class="n">jh</span><span class="p">.</span><span class="n">run_date</span><span class="p">,</span><span class="n">jh</span><span class="p">.</span><span class="n">run_time</span><span class="p">),</span> <span class="n">jh</span><span class="p">.</span><span class="n">step_id</span><span class="p">,</span> <span class="n">jh</span><span class="p">.</span><span class="n">message</span><span class="p">,</span> <span class="p">(</span><span class="n">jh</span><span class="p">.</span><span class="n">run_duration</span> <span class="o">/</span> <span class="mi">10000</span> <span class="o">*</span> <span class="mi">60</span> <span class="o">*</span> <span class="mi">60</span><span class="p">)</span> <span class="o">+</span> <span class="p">(</span><span class="n">jh</span><span class="p">.</span><span class="n">run_duration</span> <span class="o">/</span> <span class="mi">100</span> <span class="o">%</span> <span class="mi">100</span> <span class="o">*</span> <span class="mi">60</span><span class="p">)</span> <span class="o">+</span> <span class="p">(</span><span class="n">jh</span><span class="p">.</span><span class="n">run_duration</span> <span class="o">%</span> <span class="mi">100</span> <span class="p">)</span> <span class="k">As</span> <span class="n">RunDurationSec</span><span class="p">,</span> <span class="n">GETUTCDATE</span><span class="p">()</span> <span class="k">FROM</span> <span class="n">msdb</span><span class="p">.</span><span class="n">dbo</span><span class="p">.</span><span class="n">sysjobhistory</span> <span class="k">AS</span> <span class="n">jh</span> <span class="k">INNER</span> <span class="k">JOIN</span> <span class="n">msdb</span><span class="p">.</span><span class="n">dbo</span><span class="p">.</span><span class="n">sysjobs</span> <span class="k">AS</span> <span class="n">sj</span> <span class="k">ON</span> <span class="n">jh</span><span class="p">.</span><span class="n">job_id</span> <span class="o">=</span> <span class="n">sj</span><span class="p">.</span><span class="n">job_id</span> <span class="k">WHERE</span> <span class="n">jh</span><span class="p">.</span><span class="n">run_status</span> <span class="o">=</span> <span class="mi">0</span> <span class="c1">-- Just get failures</span> <span class="k">AND</span> <span class="n">jh</span><span class="p">.</span><span class="n">step_id</span> <span class="o">&lt;&gt;</span> <span class="mi">0</span> <span class="c1">-- Skip the '0' step that gives us summary info</span> <span class="k">AND</span> <span class="n">msdb</span><span class="p">.</span><span class="n">dbo</span><span class="p">.</span><span class="n">agent_datetime</span><span class="p">(</span><span class="n">jh</span><span class="p">.</span><span class="n">run_date</span><span class="p">,</span><span class="n">jh</span><span class="p">.</span><span class="n">run_time</span><span class="p">)</span> <span class="o">&gt;</span> <span class="o">@</span><span class="n">lastFailure</span><span class="p">;</span></code></pre></figure> <h3 id="alerting">Alerting</h3> <p>How you approach alerting is up to you, but you have a lot of different options. In my environment I query the <code class="highlighter-rouge">JobFailureArchive</code> table via a Nagios service check. You could do the same thing with any monitoring solution that allows you to add custom queries. No matter which direction you take, writing a query to get the job failure details is simple:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">TOP</span><span class="p">(</span><span class="mi">1</span><span class="p">)</span> <span class="k">WITH</span> <span class="n">TIES</span> <span class="n">JobName</span><span class="p">,</span> <span class="n">Rundate</span><span class="p">,</span> <span class="n">StepID</span><span class="p">,</span> <span class="n">OutcomeText</span><span class="p">,</span> <span class="n">RunDurationSec</span> <span class="k">FROM</span> <span class="n">DBA</span><span class="p">.</span><span class="n">Maintenance</span><span class="p">.</span><span class="n">JobFailureArchive</span> <span class="k">ORDER</span> <span class="k">BY</span> <span class="n">LogDateGMT</span></code></pre></figure> <p>Since we are storing the date the records are added to the table, this query will always return the latest set of failures. This is a simple example, but the possibilities are endless:</p> <ul> <li>Send the results of this query via database mail</li> <li>Join with <code class="highlighter-rouge">dbo.sysjobs</code> and <code class="highlighter-rouge">dbo.syscategories</code>, alerting on different thresholds per job category</li> <li>Extend the <code class="highlighter-rouge">TOP (1)</code> to include multiple capture periods and alert on average failures per capture</li> </ul> <h3 id="configuring-the-sql-agent-job">Configuring the SQL Agent Job</h3> <p>A SQL Agent job is the last component that ties everything together. At it’s simplest the job executes the procedure in the example above. This will get your job failures into the archive table, but there is more this job can do.</p> <p>Since we are archiving job failures, we can clean up job history in MSDB more aggressively. To do this, add another step to the agent job that executes the following (which limits job history to a rolling 24 hours):</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">DECLARE</span> <span class="o">@</span><span class="n">OldestJob</span> <span class="n">DATETIME</span> <span class="o">=</span> <span class="n">DATEADD</span><span class="p">(</span><span class="k">day</span><span class="p">,</span><span class="o">-</span><span class="mi">1</span><span class="p">,</span><span class="n">GETDATE</span><span class="p">())</span> <span class="k">EXEC</span> <span class="n">msdb</span><span class="p">.</span><span class="n">dbo</span><span class="p">.</span><span class="n">sp_purge_jobhistory</span> <span class="o">@</span><span class="n">oldest_date</span> <span class="o">=</span> <span class="o">@</span><span class="n">OldestJob</span><span class="p">;</span></code></pre></figure> <p>Reducing the size of the <code class="highlighter-rouge">sysjobhistory</code> table can have a lot of benefits including: quicker restore times on MSDB, more responsive SSMS when viewing job history, and a reduction in contention when writing to a busy <code class="highlighter-rouge">sysjobhistory</code> table.</p> <p>You could also add a step to send an email alert when new job failures are inserted. Database mail is a rabbit hole we aren’t going to explore in this post. If you do plan on using this job to alert, start by reading through the resources at the bottom of this page. Specifically the one by Jes Borland on sending query results using database mail.</p> <p>The article on using tokens in agent jobs is also a good read. Using tokens you can find job failures inserted since the job started executing:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">JobName</span><span class="p">,</span> <span class="n">Rundate</span><span class="p">,</span> <span class="n">StepID</span><span class="p">,</span> <span class="n">OutcomeText</span><span class="p">,</span> <span class="n">RunDurationSec</span> <span class="k">FROM</span> <span class="n">DBA</span><span class="p">.</span><span class="n">Maintenance</span><span class="p">.</span><span class="n">JobFailureArchive</span> <span class="k">WHERE</span> <span class="n">LogDateGMT</span> <span class="o">&gt;=</span> <span class="n">msdb</span><span class="p">.</span><span class="n">dbo</span><span class="p">.</span><span class="n">agent_datetime</span><span class="p">(</span><span class="err">$</span><span class="p">(</span><span class="n">ESCAPE_SQUOTE</span><span class="p">(</span><span class="n">STRTDT</span><span class="p">)),</span> <span class="err">$</span><span class="p">(</span><span class="n">ESCAPE_SQUOTE</span><span class="p">(</span><span class="n">STRTTM</span><span class="p">)))</span> <span class="k">ORDER</span> <span class="k">BY</span> <span class="n">LogDateGMT</span></code></pre></figure> <p>The system function <code class="highlighter-rouge">msdb.dbo.agent_datetime</code> converts the date and time format used by SQL Agent into a standard datetime. The tokens <code class="highlighter-rouge">$(ESCAPE_SQUOTE(STRTDT))</code> and <code class="highlighter-rouge">$(ESCAPE_SQUOTE(STRTTM))</code>, will return the date and time the job started executing. Combined with Jes’s post this could be all you need for job failure alerts.</p> <blockquote> <p>If this job fails for any reason you will stop receiving notifications for <strong>any</strong> job failures. Make sure to configure this job to alert via email if it fails!</p> </blockquote> <h3 id="powershell-bonus-feature">PowerShell (Bonus Feature!)</h3> <p>One nice thing about having job failure data in a dedicated table is that it is easy to query. You can also give normal users access to the data without having to put them in special agent roles or granting them access to system databases. Below is a PowerShell function you, or your users, could use to retrieve job failures based on several criteria:</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="k">function </span>Get-SqlJobFailures <span class="o">{</span> <span class="cm">&lt;# .SYNOPSIS Retrieves job failure details from the given instance .PARAMETER SqlInstance (Accepts values from the pipeline) Instance we are getting job failures from .PARAMETER JobName All or part of the job name you are interested in .PARAMETER Newest The number of results to return based on date .PARAMETER Since The oldest date to show in the results .PARAMETER SearchString This parameter can be used to search the error output #&gt;</span> <span class="o">[</span><span class="na">CmdletBinding</span><span class="o">()]</span> <span class="k">param</span><span class="o">(</span> <span class="o">[</span>Parameter<span class="o">(</span><span class="nv">Mandatory</span><span class="o">=</span><span class="nv">$true</span>,ValueFromPipeline<span class="o">=</span><span class="nv">$true</span><span class="o">)]</span> <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$SqlInstance</span>, <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$JobName</span> <span class="o">=</span> <span class="s1">''</span>, <span class="o">[</span><span class="kt">int</span><span class="o">]</span><span class="nv">$Newest</span> <span class="o">=</span> 10000, <span class="o">[</span>datetime]<span class="nv">$Since</span> <span class="o">=</span> <span class="s1">'2017-01-01'</span>, <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$SearchString</span> <span class="o">)</span> <span class="k">BEGIN</span> <span class="o">{</span> <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$GetFailures_Query</span> <span class="o">=</span> @<span class="s2">" SELECT TOP(</span><span class="k">$(</span><span class="nv">$Newest</span><span class="k">)</span><span class="s2">) @@SERVERNAME AS ServerName, JobName, Rundate, StepID, OutcomeText, RunDurationSec FROM DBA.Maintenance.JobFailureArchive WHERE rundate &gt;= '</span><span class="k">$(</span><span class="nv">$Since</span>.ToString<span class="o">(</span><span class="s1">'yyyMMdd HH:mm'</span><span class="k">)</span><span class="s2">)' AND JobName LIKE '%</span><span class="k">$(</span><span class="nv">$JobName</span><span class="k">)</span><span class="s2">%' </span><span class="k">$(</span> <span class="k">if</span><span class="o">(</span><span class="nv">$SearchString</span><span class="k">)</span><span class="s2">{ "</span>AND OutcomeText LIKE <span class="s1">'%$($SearchString)%'</span><span class="s2">" }) ORDER BY RunDate DESC; "</span>@ <span class="nv">$data</span> <span class="o">=</span> @<span class="o">()</span> <span class="o">}</span> <span class="k">PROCESS</span> <span class="o">{</span> <span class="nb">Write-Host</span> <span class="s2">"Testing connection to </span><span class="k">$(</span><span class="nv">$SqlInstance</span><span class="k">)</span><span class="s2">: "</span> -NoNewline <span class="k">try</span> <span class="o">{</span> Test-Connection -ComputerName <span class="nv">$SqlInstance</span> -Count 1 -Quiet -ErrorAction Stop | <span class="nb">Out-Null Write-Host</span> <span class="s2">"success"</span> -ForegroundColor Green <span class="o">}</span> <span class="k">catch</span> <span class="o">{</span> <span class="nb">Write-Host</span> <span class="s2">"error - </span><span class="k">$(</span><span class="nv">$_</span>.Exception.Message<span class="k">)</span><span class="s2">"</span> -ForegroundColor Red <span class="k">throw</span> <span class="o">}</span> <span class="nb">Write-Host</span> <span class="s2">"Getting job failure data: "</span> -NoNewline <span class="k">try</span> <span class="o">{</span> Invoke-Sqlcmd -Query <span class="nv">$GetFailures_Query</span> -ServerInstance <span class="nv">$SqlInstance</span> -Database master | % <span class="o">{</span> <span class="nv">$data</span> +<span class="o">=</span> <span class="nv">$_</span> <span class="o">}</span> <span class="nb">Write-Host</span> <span class="s2">"done"</span> -ForegroundColor Green <span class="o">}</span> <span class="k">catch</span> <span class="o">{</span> <span class="nb">Write-Host</span> <span class="s2">"error - </span><span class="k">$(</span><span class="nv">$_</span>.Exception.Message<span class="k">)</span><span class="s2">"</span> -ForegroundColor Red <span class="k">throw</span> <span class="o">}</span> <span class="o">}</span> <span class="k">END</span> <span class="o">{</span> <span class="k">if</span> <span class="o">(</span> <span class="nv">$data</span> <span class="o">)</span> <span class="o">{</span> <span class="k">return</span> <span class="k">$(</span><span class="nv">$data</span> | <span class="nb">Sort-Object</span> -Property ServerName, RunDate<span class="k">)</span> <span class="o">}</span> <span class="o">}</span> <span class="o">}</span></code></pre></figure> <p>If you are not familiar with PowerShell I recommend giving it a try. It has become an indispensable tool for my day to day tasks. The power of this function comes when you run it across multiple instances:</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="nb">PS</span>&gt; @<span class="o">(</span><span class="s1">'sql-instance-01'</span>, <span class="sb">`</span> <span class="s1">'sql-instance-02'</span>, <span class="sb">`</span> <span class="s1">'sql-instance-03'</span> <span class="o">)</span> | Get-SqlJobFailures -Newest 15 | Out-Gridview</code></pre></figure> <p>This will get the 15 most recent job failures for the three instances listed, and display them in a graphical grid view.</p> <h2 id="final-thoughts">Final Thoughts</h2> <p>Writing job failures to a user table seems like a simple idea, but you’ll be surprised how much you use it. We only scratched the surface in this post, I would love to hear what other uses you find for this.</p> <h2 id="resources">Resources</h2> <ul> <li><a href="https://docs.microsoft.com/en-us/sql/ssms/agent/use-tokens-in-job-steps">Use Tokens in Job Steps</a> - Microsoft Docs</li> <li><a href="https://www.brentozar.com/archive/2014/10/send-query-results-sql-server-agent-job/">Email Query Results Using a SQL Server Agent Job</a> - Jes Borland via BrentOzar.com</li> <li><a href="https://www.nagios.com/">Nagios</a> - Nagios Home Page</li> </ul> Managing the SQL Server Error Log 2017-07-13T00:00:00+00:00 https://m82labs.com/managing-errorlog We typically think of error logs as somewhere to go to find issues, but what if your error logs ARE the issue? <p>We typically think of error logs as somewhere to go to find issues, but what if your error logs ARE the issue? Like most anything else in SQL Server, if you neglect your error logs you can run into trouble. Even on a low-traffic SQL Server instance, a bad piece of code, or a hardware issue, could easily fill your error logs, and with the introduction of Hekaton in SQL Server 2014, the SQL Server error log started getting a lot more data pumped into it than you might have been used to before. What this means for the DBA is that you can quickly start filling your main system drive (if your SQL install and error logs are in the default location) with massive error logs. So what questions should you be answering about error logs to make sure you don’t run into problems?</p> <ol> <li>Where are SQL Error Logs stored?</li> <li>How long are error logs kept?</li> <li>How much space do I need for error logs?</li> </ol> <h2 id="where-are-sql-error-logs-stored">Where are SQL Error Logs Stored?</h2> <p>The quickest way to answer this question is to run a simple query:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">SERVERPROPERTY</span><span class="p">(</span><span class="s1">'ErrorLogFileName'</span><span class="p">)</span></code></pre></figure> <p>This will return the full path of your current error log. By default this will be located under <code class="highlighter-rouge">C:\Program Files\Microsoft SQL Server\</code>.</p> <p>The location of your logs can be easily changed by adding a startup parameter to the SQL Server service in configuration manager. Simply adding a <code class="highlighter-rouge">-e</code> parameter, followed by the desired error log path, will change the path error logs are written to on next service restart. If for example you had a dedicated drive and directory, <code class="highlighter-rouge">E:\Logs</code>, that you wanted to write your error logs to, you would add the following startup parameter: <code class="highlighter-rouge">-eE:\LOGS</code>.</p> <blockquote> <p>When adding new startup parameters, it is important to remember that parameters are semi-colon delimited.`</p> </blockquote> <h2 id="how-long-are-error-logs-kept">How Long are Error Logs Kept?</h2> <p>This question can depend on what, if any, maintenance is being done on your error logs. If you cycle error logs nightly (via a SQL Agent job that executes <code class="highlighter-rouge">EXEC sp_cycle_errorlog</code>), you can check the number of SQL error logs that will be kept before re-using the files to determine roughly how many days worth of logs would be kept.</p> <p>To find the number of error logs that are kept, navigate to the ‘SQL Server Logs’ node in the object explorer in Management Studio, right click, and select ‘Configure’.</p> <p><img src="/public/images/ConfigureLogFiles01.png" alt="Statistic Histogram" /></p> <p>From here you can adjust the number of error log files to retain.</p> <p><img src="/public/images/ConfigureLogFiles02.png" alt="Statistic Histogram" /></p> <p>If you don’t currently do such maintenance it can be hard to say. A new error log is created every time the SQL Server service restarts, or the <code class="highlighter-rouge">sp_cycle_errorlog</code> procedure is executed. If your instances don’t normally restart there is no real limit to how large the file can get, and therefore, how far back the error log history goes.</p> <blockquote> <p>If you plan on cycling your logs nightly, and configuring a max number of logs, you should keep in mind that there is a hard limit of 99 files. If you want to keep 90 days worth of logs so you set the number of files to 90, but have 10 restarts within those 90 days, some of your log files will be lost.</p> </blockquote> <h2 id="how-much-space-do-i-need-for-error-logs">How Much Space do I Need for Error Logs?</h2> <p>As stated above, there isn’t a practical limit to the size of the error log so the space required for error logs depends on the number of files you keep, how often the error log is cycled, and (if you are using SQL Server 2012+) whether or not a maximum error log file size has been set.</p> <p>You can check to see if a limit has been set by checking:</p> <p>For SQL Server 2012:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="p">[</span><span class="n">master</span><span class="p">];</span> <span class="k">GO</span> <span class="k">EXEC</span> <span class="n">xp_instance_regread</span> <span class="n">N</span><span class="s1">'HKEY_LOCAL_MACHINE'</span><span class="p">,</span> <span class="n">N</span><span class="s1">'Software</span><span class="se">\M</span><span class="s1">icrosoft</span><span class="se">\M</span><span class="s1">SSQLServer</span><span class="se">\M</span><span class="s1">SSQLServer'</span><span class="p">,</span> <span class="n">N</span><span class="s1">'ErrorLogSizeInKb'</span><span class="p">;</span> <span class="k">GO</span></code></pre></figure> <p>For SQL Server 2014+</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="p">[</span><span class="n">master</span><span class="p">];</span> <span class="k">GO</span> <span class="k">EXEC</span> <span class="n">xp_instance_regread</span> <span class="n">N</span><span class="s1">'HKEY_LOCAL_MACHINE'</span><span class="p">,</span> <span class="n">N</span><span class="s1">'SOFTWARE</span><span class="se">\M</span><span class="s1">icrosoft</span><span class="se">\M</span><span class="s1">icrosoft SQL Server</span><span class="se">\M</span><span class="s1">SSQL12.MSSQLSERVER</span><span class="se">\M</span><span class="s1">SSQLServer'</span><span class="p">,</span> <span class="n">N</span><span class="s1">'ErrorLogSizeInKb'</span><span class="p">;</span> <span class="k">GO</span></code></pre></figure> <blockquote> <p>This key could change, so you may have to open up the registry editor (<code class="highlighter-rouge">regedit</code>) to search for this key if the above commands don’t work for you.</p> </blockquote> <p>Changing this value is just as easy. Instead of executing an <code class="highlighter-rouge">xp_instance_regread</code>, we execute <code class="highlighter-rouge">xp_instance_regwrite</code>:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="p">[</span><span class="n">master</span><span class="p">];</span> <span class="k">GO</span> <span class="k">EXEC</span> <span class="n">xp_instance_regwrite</span> <span class="n">N</span><span class="s1">'HKEY_LOCAL_MACHINE'</span><span class="p">,</span> <span class="n">N</span><span class="s1">'SOFTWARE</span><span class="se">\M</span><span class="s1">icrosoft</span><span class="se">\M</span><span class="s1">icrosoft SQL Server</span><span class="se">\M</span><span class="s1">SSQL12.MSSQLSERVER</span><span class="se">\M</span><span class="s1">SSQLServer'</span><span class="p">,</span> <span class="n">N</span><span class="s1">'ErrorLogSizeInKb'</span> <span class="n">REG_DWORD</span><span class="p">,</span> <span class="mi">1073741824</span><span class="p">;</span> <span class="c1">-- 1GB</span> <span class="k">GO</span></code></pre></figure> <blockquote> <p>These commands all assume you are using the default instance. To try this with different versions of SQL Server and named instances, you would have to replace the <code class="highlighter-rouge">MSSQL12</code> above with the version you are currently running (<code class="highlighter-rouge">MSSQL13</code> for SQL Server 2016), and <code class="highlighter-rouge">.MSSQLSERVER</code> with the name of named instance.</p> </blockquote> <h2 id="final-thoughts">Final Thoughts</h2> <p>Error log management can be an important part of managing any SQL Server. Left to their own devices, error logs can become enormous, making it harder for you to open them for troubleshooting purposes, and potentially leading to a full system drive. Cycling the log on a daily or weekly basis, and setting a sane limit on the number of files can go a long way towards keeping these files under control.</p> Getting Started with In-Memory OLTP: Reducing TempDB Contention 2017-06-21T00:00:00+00:00 https://m82labs.com/tempdb-contention Reducing TempDB contention with memory optimized table variables. <p>Everyone loves the temporary table. temporary tables can be very useful when trying to execute complex operations, or get around optimizer quirks. But what happens if you love them a little too much? In this post we’ll go through some common tempdb latch contention scenarios you might only see under extremely heavy load, and how you can use memory-optimized table variables to remove or reduce this contention.</p> <blockquote> <p>In-Memory OLTP is a new technology that requires some research before implementation, but hopefully this post gets you interested enough to give it a try.</p> </blockquote> <h2 id="tempdb-latch-contention">Tempdb Latch Contention</h2> <p>In my environment we have a highly concurrent workload and make heavy use of tempdb. In the past we have run into the common tempdb contention issues most people run into, PFS/SGAM contention. This was easy to fix by adding more tempdb files, but after a change in workload patterns we started seeing contention in a new place: the base system tables in tempdb.</p> <blockquote> <p>For more information on troubleshooting PFS/SGAM contention in tempdb, please refer to this post by Jonathan Kehayias: <a href="https://www.simple-talk.com/sql/database-administration/optimizing-tempdb-configuration-with-sql-server-2012-extended-events/">Optimizing tempdb configuration with SQL Server 2012 Extended Events</a></p> </blockquote> <h2 id="understanding-whats-happening">Understanding Whats Happening</h2> <p>Before you can understand why this contention occurs, it is important to get a basic understanding of what happens in SQL Server when you create a temporary table. Whenever you create a temporary table, entries are made in various system tables in tempdb just as if you were creating a normal table in a user database, and in many cases the temporary table definition is cached.</p> <p>Cached tables are stored in <code class="highlighter-rouge">tempdb.sys.tables</code> with a hex value in place of the name they were given when they were created. When you create a table that is already in cache, a simple rename operation occurs instead of an insert into the system tables. This will be important to understand later, and this is about all we are going to cover in this post regarding temporary table caching.</p> <blockquote> <p>Temporary table caching is a complex topic that is outside the scope of this post, but is covered beautifully by Paul White in his post <a href="http://sqlblog.com/blogs/paul_white/archive/2012/08/17/temporary-object-caching-explained.aspx">Temporary Table Caching Explained</a></p> </blockquote> <p>If you create a temporary table then query <code class="highlighter-rouge">tempdb.sys.tables</code> you will see a list of cached objects (named with a hex value) as well as an entry for the temporary table you just created:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="c1">--== Create a table</span> <span class="k">CREATE</span> <span class="k">TABLE</span> <span class="o">#</span><span class="n">Test</span> <span class="p">(</span> <span class="n">ID</span> <span class="n">INT</span> <span class="p">);</span> <span class="c1">--== See all the tables</span> <span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">tempdb</span><span class="p">.</span><span class="n">sys</span><span class="p">.</span><span class="n">tables</span><span class="p">;</span> <span class="c1">--== See just our table</span> <span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">tempdb</span><span class="p">.</span><span class="n">sys</span><span class="p">.</span><span class="n">tables</span> <span class="k">WHERE</span> <span class="n">name</span> <span class="k">LIKE</span> <span class="s1">'#Test%'</span><span class="p">;</span></code></pre></figure> <p>If you also query <code class="highlighter-rouge">tempdb.sys.columns</code> for the associated <code class="highlighter-rouge">object_id</code>, you will see what you would expect in a standard user database, a list of columns for your temporary table. Where we get into trouble is when we are creating these temporary tables at an extremely high rate. A quick query will show you why:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">tempdb</span><span class="p">;</span> <span class="k">GO</span> <span class="k">EXEC</span> <span class="n">sp_help</span> <span class="s1">'sys.sysschobjs'</span><span class="p">;</span> <span class="k">GO</span></code></pre></figure> <blockquote> <p><em>sp_help</em> is quite possibly the most under-appreciated system stored procedure on your instances. I highly recommend playing around with it to see what you can find.</p> </blockquote> <p>Running the above query will give you valuable details about the system base table <code class="highlighter-rouge">sys.sysschobjs</code>, the base table for <code class="highlighter-rouge">sys.tables</code>. An interesting thing to note is that there are 4 indexes on this table, one of which is a non-clustered index that leads with the <code class="highlighter-rouge">name</code> column, and another that leads with a <code class="highlighter-rouge">TINYINT</code> column named <code class="highlighter-rouge">nsclass</code>. In situations where you have potentially hundreds of client requests attempting to create a temporary table it is very possible to start seeing contention on this table. Below I will show you how to reproduce this contention, and how to investigate any live contention you might see on your own instances.</p> <h2 id="creating-latch-contention">Creating Latch Contention</h2> <p>To recreate this sort of contention we are going to use the OSTRESS command line utility (Get it here: <a href="https://support.microsoft.com/en-us/kb/944837">https://support.microsoft.com/en-us/kb/944837</a>). <code class="highlighter-rouge">ostress</code> is a simple command line utility you can use to execute SQL queries using multiple threads. This will need to be installed before continuing on with any of the demos below.</p> <p>To prepare for our contention test we need to create a test database and define a stored procedure that simply creates a temporary table.</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">master</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">DATABASE</span> <span class="n">ContentionTest</span><span class="p">;</span> <span class="k">GO</span> <span class="n">USE</span> <span class="n">ContentionTest</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">PROCEDURE</span> <span class="n">dbo</span><span class="p">.</span><span class="n">Test</span> <span class="k">AS</span> <span class="k">CREATE</span> <span class="k">TABLE</span> <span class="o">#</span><span class="n">Test</span> <span class="p">(</span> <span class="n">Id</span> <span class="n">INT</span><span class="p">,</span> <span class="n">Col1</span> <span class="n">NVARCHAR</span><span class="p">(</span><span class="mi">128</span><span class="p">)</span> <span class="p">);</span> <span class="k">INSERT</span> <span class="k">INTO</span> <span class="o">#</span><span class="n">Test</span> <span class="k">SELECT</span> <span class="mi">1</span><span class="p">,</span><span class="s1">'Test'</span><span class="p">;</span></code></pre></figure> <p>With our procedure defined we can fire up the <code class="highlighter-rouge">RML Cmd Prompt</code> ( now found in your start menu ) and run ostress. Once at the RML prompt, type the following command ( in our example we are running this against a local instance ):</p> <figure class="highlight"><pre><code class="language-shell" data-lang="shell">ostress -Q<span class="s2">"EXEC ContentionTest.dbo.Test;"</span> -n500 -r500 -S<span class="s2">"localhost"</span></code></pre></figure> <blockquote> <p>WARNING: Do not run this test on a production instance. Depending on the configuration of the instance you could quickly exhaust the worker thread pool, making the instance unresponsive.</p> </blockquote> <p>This will fire off 500 threads (-n), each executing our stored procedure 500 times in succession (-r). This test will take a minute to execute, even on a fairly capable machine. While this is happening, lets see if we have any contention. If you need to extend the duration of this command, increasing the <code class="highlighter-rouge">-r</code> value should do the trick.</p> <p>Open SSMS and connect to the instance in question and run the following:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">master</span><span class="p">;</span> <span class="k">GO</span> <span class="k">SELECT</span> <span class="n">es</span><span class="p">.</span><span class="n">session_id</span><span class="p">,</span> <span class="n">es</span><span class="p">.</span><span class="n">login_time</span><span class="p">,</span> <span class="n">er</span><span class="p">.</span><span class="n">wait_type</span><span class="p">,</span> <span class="n">er</span><span class="p">.</span><span class="n">wait_resource</span><span class="p">,</span> <span class="n">er</span><span class="p">.</span><span class="n">command</span><span class="p">,</span> <span class="n">DB_NAME</span><span class="p">(</span><span class="n">er</span><span class="p">.</span><span class="n">database_id</span><span class="p">)</span> <span class="k">AS</span> <span class="n">dbname</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_exec_requests</span> <span class="k">AS</span> <span class="n">er</span> <span class="k">INNER</span> <span class="k">JOIN</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_exec_sessions</span> <span class="k">AS</span> <span class="n">es</span> <span class="k">ON</span> <span class="n">er</span><span class="p">.</span><span class="n">session_id</span> <span class="o">=</span> <span class="n">es</span><span class="p">.</span><span class="n">session_id</span> <span class="k">WHERE</span> <span class="n">es</span><span class="p">.</span><span class="n">is_user_process</span> <span class="o">=</span> <span class="mi">1</span><span class="p">;</span></code></pre></figure> <p>If the test is running properly you will likely see a lot of sessions with a wait type of <code class="highlighter-rouge">PAGELATCH_EX</code>, waiting on some random database page. In my test for example, waits primarily occurred on a wait resource identified as: <code class="highlighter-rouge">2:1:14469</code></p> <p>This can be decoded to mean that we have <code class="highlighter-rouge">PAGELATCH_EX</code> waits on page <code class="highlighter-rouge">14469</code> of file <code class="highlighter-rouge">1</code> in database <code class="highlighter-rouge">2</code> (tempdb). So what’s on this page? Let’s take a look:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">DBCC</span> <span class="n">PAGE</span><span class="p">(</span><span class="mi">2</span><span class="p">,</span><span class="mi">1</span><span class="p">,</span><span class="mi">14469</span><span class="p">,</span><span class="mi">3</span><span class="p">)</span> <span class="k">WITH</span> <span class="n">TABLERESULTS</span><span class="p">;</span></code></pre></figure> <blockquote> <p>Notice we just took the wait resource from the results of the query above, traded out our colons for commas, and added a 3</p> </blockquote> <p>What you’ll typically get back are two result sets depending on the type of page you are looking at. The first result set contains, among other information, the page header. The second is a dump of the actual data on the page. For this example we are interested in the first result set, we are looking for two rows with the following field names: <code class="highlighter-rouge">Metadata: ObjectId</code> and <code class="highlighter-rouge">Metadata: IndexId</code>. In my case I am seeing 34 and 2 respectively.</p> <p>Now that we know the object id of the table we are seeing contention on we can use <code class="highlighter-rouge">sys.objects</code> to look up the table name, and use the index id to see which index this contention is on:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">tempdb</span><span class="p">;</span> <span class="k">GO</span> <span class="k">SELECT</span> <span class="n">name</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">objects</span> <span class="k">WHERE</span> <span class="n">object_id</span> <span class="o">=</span> <span class="mi">34</span><span class="p">;</span></code></pre></figure> <p>If all worked, you should now see that we have contention on the <code class="highlighter-rouge">sysschobjs</code> table. Earlier we discussed using <code class="highlighter-rouge">sp_help</code> to get index details on system tables, if we do that now and look at index 2, we will see the lead column is <code class="highlighter-rouge">nsclass</code> which is a tinyint field. Using a tinyint as a lead column is typically a terrible idea since there is little selectivity on such a narrow field, and this is no exception.</p> <p>This isn’t the only case of contention you might see with system objects related to temporary tables. We ran into a few different contention scenarios with tempdb:</p> <ul> <li>Contention on <code class="highlighter-rouge">sysschobjs</code> again, but on index 3. This index leads with the name of the temporary table and is fairly narrow so you can fit a lot of records on a single index page. Because of this, if you are running lots of concurrent procedures that create temporary tables with the same or similar names, it creates a hot spot on a single page, leading to more contention.</li> <li>Temporary table auto-stats. Statistics objects for all tables (including temporary tables) are stored in the <code class="highlighter-rouge">sys.sysobjvalues</code> table. If you get enough auto-stats generations on temporary tables you can see contention here.</li> </ul> <p>So now you know where your contention is, what can you do about it?</p> <h2 id="reducing-contention-with-in-memory-oltp">Reducing Contention with In-Memory OLTP</h2> <p>SQL Server In-Memory OLTP (or Hekaton) is a new database engine that runs along side of the classic database engine you are used to using. You can query in-memory/memory-optimized objects just like their disk-based counterparts. The major difference is that memory-optimized objects operate using truely optimistic concurrency, allowing you extremely fast, lock-free access to your data. There is a lot to understand when you start out using memory-optimized objects, but it’s fairly easy to get your feet wet with memory-optimized table variables.</p> <h3 id="memory-optimized-table-variables">Memory-Optimized Table Variables</h3> <p>Memory-optimized table variables are just standard table variables that use a user-defined memory-optimized table type. Creating the table type is easy, but in order to do so you will need a memory-optimized filegroup and container in your database.</p> <h4 id="create-the-filegroup">Create the filegroup:</h4> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">ALTER</span> <span class="k">DATABASE</span> <span class="n">ContentionTest</span> <span class="k">ADD</span> <span class="n">FILEGROUP</span> <span class="n">imoltp</span> <span class="k">CONTAINS</span> <span class="n">MEMORY_OPTIMIZED_DATA</span><span class="p">;</span></code></pre></figure> <h4 id="create-the-container">Create the container:</h4> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">ALTER</span> <span class="k">DATABASE</span> <span class="n">ContentionTest</span> <span class="k">ADD</span> <span class="n">FILE</span> <span class="p">(</span> <span class="n">name</span><span class="o">=</span><span class="s1">'imoltp01'</span><span class="p">,</span> <span class="n">filename</span><span class="o">=</span><span class="s1">'c:</span><span class="se">\d</span><span class="s1">ata</span><span class="se">\i</span><span class="s1">moltp'</span> <span class="p">)</span> <span class="k">TO</span> <span class="n">FILEGROUP</span> <span class="n">imoltp</span><span class="p">;</span></code></pre></figure> <h4 id="create-a-schema-and-table-type">Create a schema and table type:</h4> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">ContentionTest</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">SCHEMA</span> <span class="n">MemoryOptimized</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">TYPE</span> <span class="n">MemoryOptimized</span><span class="p">.</span><span class="n">IdTable</span> <span class="k">AS</span> <span class="k">TABLE</span> <span class="p">(</span> <span class="n">Id</span> <span class="n">INT</span><span class="p">,</span> <span class="n">Col1</span> <span class="n">NVARCHAR</span><span class="p">(</span><span class="mi">128</span><span class="p">),</span> <span class="k">PRIMARY</span> <span class="k">KEY</span> <span class="n">NONCLUSTERED</span> <span class="p">(</span><span class="n">Id</span><span class="p">)</span> <span class="p">)</span> <span class="k">WITH</span> <span class="p">(</span><span class="n">MEMORY_OPTIMIZED</span><span class="o">=</span><span class="k">ON</span><span class="p">);</span> <span class="c1">-- &lt;== The magic happens here.</span> <span class="k">GO</span> </code></pre></figure> <blockquote> <p>I created a schema called ‘MemoryOptimized’ to create my table type under. How you organize your objects is your business, but as you start using memory-optimized objects, I highly recommend placing these objects in their own schema just for the sake of clarity.</p> </blockquote> <p>Now that we have our new table type created, we can use it in a procedure:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">ContentionTest</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">PROCEDURE</span> <span class="n">dbo</span><span class="p">.</span><span class="n">Test2</span> <span class="k">AS</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">Test</span> <span class="n">MemoryOptimized</span><span class="p">.</span><span class="n">IdTable</span><span class="p">;</span> <span class="k">INSERT</span> <span class="k">INTO</span> <span class="o">@</span><span class="n">Test</span> <span class="k">SELECT</span> <span class="mi">1</span><span class="p">,</span><span class="s1">'Test'</span><span class="p">;</span></code></pre></figure> <p>And that’s it! Nothing too exciting around the implementation of memory-optimized table variables, but the results are pretty amazing. Let’s run ostress again, using our new procedure, and see what happens to our instance:</p> <figure class="highlight"><pre><code class="language-shell" data-lang="shell">ostress -Q<span class="s2">"EXEC ContentionTest.dbo.Test2;"</span> -n500 -r500 -S<span class="s2">"localhost"</span></code></pre></figure> <p>Now lets run our query to see what’s happening on the instance:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">master</span><span class="p">;</span> <span class="k">GO</span> <span class="k">SELECT</span> <span class="n">es</span><span class="p">.</span><span class="n">session_id</span><span class="p">,</span> <span class="n">es</span><span class="p">.</span><span class="n">login_time</span><span class="p">,</span> <span class="n">er</span><span class="p">.</span><span class="n">wait_type</span><span class="p">,</span> <span class="n">er</span><span class="p">.</span><span class="n">wait_resource</span><span class="p">,</span> <span class="n">er</span><span class="p">.</span><span class="n">command</span><span class="p">,</span> <span class="n">DB_NAME</span><span class="p">(</span><span class="n">er</span><span class="p">.</span><span class="n">database_id</span><span class="p">)</span> <span class="k">AS</span> <span class="n">dbname</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_exec_requests</span> <span class="k">AS</span> <span class="n">er</span> <span class="k">INNER</span> <span class="k">JOIN</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_exec_sessions</span> <span class="k">AS</span> <span class="n">es</span> <span class="k">ON</span> <span class="n">er</span><span class="p">.</span><span class="n">session_id</span> <span class="o">=</span> <span class="n">es</span><span class="p">.</span><span class="n">session_id</span> <span class="k">WHERE</span> <span class="n">es</span><span class="p">.</span><span class="n">is_user_process</span> <span class="o">=</span> <span class="mi">1</span><span class="p">;</span></code></pre></figure> <p>You should now notice that it’s hard to even catch an active session. All pagelatch contention is gone, you’ll even notice that your ostress session finishes MUCH faster. So why did this work? It’s simple: we moved our temporary table operation out of tempdb and into the user database, and on top of that we moved it into a memory-optimized object.</p> <h2 id="final-thoughts">Final Thoughts</h2> <p>The results of this simple change can be dramatic, but before you get carried away and try to convert all of your temporary tables over to memory optimized table types there are a few things to keep in mind about in-memory OLTP, and tempdb contention:</p> <ul> <li> <p>If you are on SQL Server 2014, prior to SP1 CU4, you can run into issues where the XTP checkpoint thread dies and prevents log truncation on the database it belongs to. This can result in your tlogs growing out of control until you take the database offline.</p> </li> <li> <p>You CANNOT remove a memory-optimized filegroup from a database without dropping the entire database.</p> </li> <li> <p>It is highly recommended that you use resource governor to bind any databases that use memory-optimized objects to their own resource pool with memory limits configured. This can prevent a sudden growth of in-memory data from starving the <code class="highlighter-rouge">default</code> pool of memory.</p> </li> <li> <p>While implementing memory-optimized table variables is fairly straight-forward, things can get more complicated when you start using memory-optimized tables. The biggest issue you’ll likely see is that you cannot use cross-database transactions if a memory-optimized table is involved. This was one of the main driving factors when we decided to go with memory-optimized table types over memory-optimized tables.</p> </li> <li> <p>If you are on a version of SQL Server 2016 prior to SP1 CU2, or prior to 2016 RTM CU6, the demos above should work as described. If you have applied those updates the results will be less dramatic. Working with the SQLCAT team on this issue, we discovered a code path in SQL Server 2016 that introduced additional latches when dealing with cached temporary tables. This lead to an almost 100% increase in pagelatch wait types when using standard temporary tables (<a href="https://support.microsoft.com/en-us/help/4013999">KB4013999</a>).</p> </li> </ul> <p>The above list can be a little scary, but it’s all worth it in the end. In-Memory OLTP is here to stay, and the performance gains you can see from it can be very impressive. Make sure you check out the resources below for more details on everything we discussed.</p> <h2 id="resources">Resources</h2> <ul> <li><a href="https://www.simple-talk.com/sql/database-administration/optimizing-tempdb-configuration-with-sql-server-2012-extended-events/">Optimizing tempdb configuration with SQL Server 2012 Extended Events - Jonathan Kehayias</a></li> <li><a href="http://sqlblog.com/blogs/paul_white/archive/2012/08/17/temporary-object-caching-explained.aspx">Temporary Table Caching Explained - Paul White</a></li> <li><a href="https://msdn.microsoft.com/en-us/library/dn465873.aspx">Bind a Database with Memory-Optimized Tables to a Resource Pool - MSDN</a></li> <li><a href="https://msdn.microsoft.com/en-us/library/dn282389.aspx">Estimate Memory Requirements for Memory-Optimized Tables - MSDN</a></li> <li><a href="https://msdn.microsoft.com/en-us/library/dn133186.aspx">In-Memory OLTP (In-Memory Optimization)</a></li> </ul> Monitoring Resource Usage with Resource Governor 2016-09-30T00:00:00+00:00 https://m82labs.com/resource-governor Keep track of resource usage per user or application using Resource Governor. <p>When Resource Governor was first introduced with SQL Server 2008 you could use it to put limits on CPU usage, memory usage, and concurrent requests. In later editions Microsoft also added the ability to limit disk IO, place a hard cap on CPU usage, and control NUMA node affinity. Resource Governor is a great way to ensure no single application or user can completely starve another application or user of their SQL Server resources, but thats not what we are going to focus on today.</p> <p>In this post we’ll go over the basics of getting resource pools and workload groups set up, writing an effective classifier function to spearate your workload into these groups, and finally we’ll talk about using the built-in DMVs to monitor resource usage per resource group and why this is such a cool feature.</p> <p>In the examples below we will be creating a simple Resource Governor configuration for an environment where we have two teams executing requests, each team has two different applications that make these requests. As stated above, while we will discuss some of the surface-level basics of Resource Governor configuration, the goal of this post is to highlight the monitoring capabilities of Resource Governor.</p> <p><sup> Throughout the examples we will be using a database called <code class="highlighter-rouge">DBA</code>. This is a database name I use to store all of my administration scripts, procedures, functions, lookup tables, etc. I create it on every instance I manage and it keeps a nice set of familiar tools close at hand, regardless of which instance I am working on. I highly suggest building your own DBA database. </sup></p> <h2 id="the-basics">The Basics</h2> <p>Before we do anything with Resource Governor we have to make sure it’s turned on:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">is_enabled</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">resource_governor_configuration</span><span class="p">;</span> <span class="k">GO</span></code></pre></figure> <p>If it’s not enabled, it’s simple to turn on:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">ALTER</span> <span class="n">RESOURCE</span> <span class="n">GOVERNOR</span> <span class="n">RECONFIGURE</span><span class="p">;</span> <span class="k">GO</span> </code></pre></figure> <h3 id="resource-pools">Resource Pools</h3> <p>When thinking about Resource Governor, it can be helpful to think of it as a hierarchy of resource filters. At the very top, wide open, you have the whole of your SQL Server, all of the cores, all of the memory, all of the IO. Below that we have resource pools. At the pool level you can set the minimum and maximum CPU, memory, and IO, as well as the NUMA node affinity. The resources in the pool are shared among all session requests classified to a workload group within that pool.</p> <p>Creating a pool is simple:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">CREATE</span> <span class="n">RESOURCE</span> <span class="n">POOL</span> <span class="n">Team01</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="n">RESOURCE</span> <span class="n">POOL</span> <span class="n">Team02</span><span class="p">;</span> <span class="k">GO</span> <span class="k">ALTER</span> <span class="n">RESOURCE</span> <span class="n">GOVERNOR</span> <span class="n">RECONFIGURE</span><span class="p">;</span> <span class="k">GO</span> </code></pre></figure> <p>This creates two unrestricted pools, this will not limit the resources session requests within these pool can use.</p> <p>When creating pools you have a few options for limiting session requests:</p> <ul> <li>Min/Max CPU limits (max CPU is applicable in times of CPU contention <em>only</em>)</li> <li>Hard CPU cap (max CPU that is applicable at all times)</li> <li>Min/Max query execution grant memory (be careful with the min setting on this one, as it reduces the max available memory for other pools)</li> <li>Min/Max IOPS on a per volume basis</li> <li>NUMA node affinity</li> </ul> <p>I could go into great detail on these settings, but I would really just be copying Microsofts own documentation word-for-word, as it is quite concise: <a href="https://msdn.microsoft.com/en-us/library/hh510189.aspx">MSDN</a></p> <p><sup> One side-effect of classifying sessions into Resource Pools, is that each pool has it’s own plan cache. While it may be a bit of overkill, you can use Resource Pools to eleviate bad parameter sniffing issues if you have two applications running similar queries with wildly different parameters. </sup></p> <h3 id="workload-groups">Workload Groups</h3> <p>Following our hierarchy down from the pool level, we get to the workload group. A workload group is restricted to using the resources defined by the pool it belongs to, and adds the additional ability to limit the maximum memory grant per request ( as a percentage of total memory in the pool ), MAXDOP, maximum concurrent requests allowed in the group, and more.</p> <p>Again, creating a workload group is very straight forward, we’ll create 4 groups, one for each application in our two resource pools:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">CREATE</span> <span class="n">WORKLOAD</span> <span class="k">GROUP</span> <span class="n">App01</span> <span class="k">USING</span> <span class="n">Team01</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="n">WORKLOAD</span> <span class="k">GROUP</span> <span class="n">App02</span> <span class="k">USING</span> <span class="n">Team01</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="n">WORKLOAD</span> <span class="k">GROUP</span> <span class="n">App03</span> <span class="k">USING</span> <span class="n">Team02</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="n">WORKLOAD</span> <span class="k">GROUP</span> <span class="n">App04</span> <span class="k">USING</span> <span class="n">Team02</span><span class="p">;</span> <span class="k">GO</span> <span class="k">ALTER</span> <span class="n">RESOURCE</span> <span class="n">GOVERNOR</span> <span class="n">RECONFIGURE</span><span class="p">;</span> <span class="k">GO</span> </code></pre></figure> <p>Like the pools, these workload groups have no limits applied to them, so the groups are only used to classify the workload for reporting purposes.</p> <h3 id="classifier">Classifier</h3> <p>Once the pools and workload groups have been created, we have to write the function to classify our requests into these groups. When writing a classifier it’s <em>very important</em> to remember that this function will be called for every single session, so we want to make it as lean and efficient as possible. The classifier only has one job: based on some condition, return the name of the workload group to assign the current session to.</p> <p>Here is a simple example, this classifier will assign sessions from our four applications into their cooresponding workload groups:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">master</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">FUNCTION</span> <span class="n">dbo</span><span class="p">.</span><span class="n">fnRGClassifier</span> <span class="p">()</span> <span class="k">RETURNS</span> <span class="n">sysname</span> <span class="k">WITH</span> <span class="n">SCHEMABINDING</span> <span class="k">AS</span> <span class="k">BEGIN</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">app_name</span> <span class="n">sysname</span> <span class="o">=</span> <span class="n">APP_NAME</span><span class="p">();</span> <span class="k">RETURN</span> <span class="p">(</span> <span class="k">CASE</span> <span class="k">WHEN</span> <span class="o">@</span><span class="n">app_name</span> <span class="o">=</span> <span class="n">N</span><span class="s1">'Application 01'</span> <span class="k">THEN</span> <span class="n">N</span><span class="s1">'App01'</span> <span class="k">WHEN</span> <span class="o">@</span><span class="n">app_name</span> <span class="o">=</span> <span class="n">N</span><span class="s1">'Application 02'</span> <span class="k">THEN</span> <span class="n">N</span><span class="s1">'App02'</span> <span class="k">WHEN</span> <span class="o">@</span><span class="n">app_name</span> <span class="o">=</span> <span class="n">N</span><span class="s1">'Application 03'</span> <span class="k">THEN</span> <span class="n">N</span><span class="s1">'App03'</span> <span class="k">WHEN</span> <span class="o">@</span><span class="n">app_name</span> <span class="o">=</span> <span class="n">N</span><span class="s1">'Application 04'</span> <span class="k">THEN</span> <span class="n">N</span><span class="s1">'App04'</span> <span class="k">ELSE</span> <span class="k">NULL</span> <span class="k">END</span> <span class="p">)</span> <span class="k">END</span> <span class="k">GO</span> <span class="k">ALTER</span> <span class="n">RESOURCE</span> <span class="n">GOVERNOR</span> <span class="k">with</span> <span class="p">(</span><span class="n">CLASSIFIER_FUNCTION</span> <span class="o">=</span> <span class="n">dbo</span><span class="p">.</span><span class="n">fnRGClassifier</span><span class="p">)</span> <span class="k">ALTER</span> <span class="n">RESOURCE</span> <span class="n">GOVERNOR</span> <span class="n">RECONFIGURE</span> <span class="k">GO</span> </code></pre></figure> <p><sup> Before you get too fancy, just remember, the classifier function has to be schema bound, so you will not be able to access objects outside of <code class="highlighter-rouge">master.dbo</code>. This elimates the posiblity of doing things like accessing lookup tables outside of master, or using in-memory tables or natively compiled functions. </sup></p> <h2 id="resource-governor-dmvs">Resource Governor DMVs</h2> <p>There are a few DMVs available to help you view the configuration of Resource Governor as well as usage statistics on your pools and workload groups. If you want to verify the configuration of what we have done so far, and see whats statistics are available, run these simple statements:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="c1">-- Check the classifier is set properly and that Resource Governor is enabled</span> <span class="k">SELECT</span> <span class="n">OBJECT_NAME</span><span class="p">(</span><span class="n">classifier_function_id</span><span class="p">)</span> <span class="k">AS</span> <span class="n">classifier</span><span class="p">,</span> <span class="n">is_enabled</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">resource_governor_configuration</span><span class="p">;</span> <span class="c1">-- View our pools</span> <span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_resource_governor_resource_pools</span><span class="p">;</span> <span class="c1">-- View our workload groups</span> <span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_resource_governor_workload_groups</span><span class="p">;</span></code></pre></figure> <p><sup> If you simply want to test to make sure your sessions are being properly classified, <code class="highlighter-rouge">sys.dm_exec_sessions</code> has a column called <code class="highlighter-rouge">group_id</code> that you can use to join on <code class="highlighter-rouge">sys.dm_resource_governor_workload_groups</code> to see which group each session has been classified to. </sup></p> <p>From looking at these DMVs it’s pretty obvious how much data is available on your resource pools and workload groups. For those of you not following along, these DMVs allow you to view the following (and more):</p> <ul> <li>Current/total request count</li> <li>Current/total requests queued (if these sessions would violate your limits)</li> <li>Total lock wait time and count</li> <li>Total CPU usage in milliseconds</li> <li>Total resource limit violations</li> <li>Total reads/writes</li> <li>Total read/write IO stalls</li> </ul> <p>Depending on the statistic you want, you can get them at the pool or group level, or in some cases both. You can read more about the available DMVs here: <a href="https://msdn.microsoft.com/en-us/library/bb934218.aspx">MSDN</a></p> <p><sup> In addition to all of this great data, if you impose IO limits at the resource pool level you will also have access to <code class="highlighter-rouge">sys.dm_resource_governor_resource_pool_volumes</code>. This DMV will allow you to dig deep into the IO usage of your pools on a per volume basis. If you are currently running a IO-bound workload, I would highly suggest taking a look at what Resource Governor can offer here. </sup></p> <h2 id="collecting-data">Collecting Data</h2> <p>Now that we know <em>which</em> statistics we can gather, we need to actually start gathering them. While the DMVs for Resource Governor are great, they will only give you an aggregate of the usage information since the last time the statistics were reset, or the last time services were restarted.</p> <p>In most cases it makes sense to store your data in a separate table so you can calculate differentials between two time periods. For our example we are only going to be interested in request counts and CPU usage. For this, we will create the following table:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">DBA</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">TABLE</span> <span class="n">dbo</span><span class="p">.</span><span class="n">ResourceGovernorUsageData</span> <span class="p">(</span> <span class="n">CollectionTimeUTC</span> <span class="n">DATETIME</span><span class="p">,</span> <span class="n">CollectionTimeOffset</span> <span class="n">INT</span><span class="p">,</span> <span class="n">ResourcePool</span> <span class="n">SYSNAME</span><span class="p">,</span> <span class="n">WorkloadGroup</span> <span class="n">SYSNAME</span><span class="p">,</span> <span class="n">RequestCountTotal</span> <span class="n">BIGINT</span><span class="p">,</span> <span class="n">RequestCountDelta</span> <span class="n">BIGINT</span><span class="p">,</span> <span class="n">CPUUsageMSTotal</span> <span class="n">BIGINT</span><span class="p">,</span> <span class="n">CPUUsageMSDelta</span> <span class="n">BIGINT</span><span class="p">,</span> <span class="k">CONSTRAINT</span> <span class="n">PK_ResourceGovernorUsageData</span> <span class="k">PRIMARY</span> <span class="k">KEY</span> <span class="n">CLUSTERED</span> <span class="p">(</span> <span class="n">CollectionTimeUTC</span><span class="p">,</span> <span class="n">ResourcePool</span><span class="p">,</span> <span class="n">WorkloadGroup</span> <span class="p">)</span> <span class="p">)</span></code></pre></figure> <p>With the table created, we will also create a stored procedure to write data to the table, eventually calling the procedure via a scheduled job. The general idea behind the procedure is that it will grab the current statistics, and then read the statistics currently being stored in the table. It will then write the new statistics it gathered, as well as the delta between this run of the procedure and the last. Technically you could just store the aggregated value as it appears in the DMVs, but the query needed to process that data would end up being costly.</p> <p>When writing a procedure like this you have to account for two cases:</p> <ul> <li>The DMV statistics get reset: This would result in a negative delta, as the latest total would be less than the previous</li> <li>The first time you load the data: If you are starting with nothing, there is no delta to store, in which case you have to decide if you want to store a delta of <code class="highlighter-rouge">0</code> or <code class="highlighter-rouge">NULL</code></li> </ul> <p>Here is an example of a procedure we could use to store our data:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">DBA</span><span class="p">;</span> <span class="k">GO</span> <span class="k">CREATE</span> <span class="k">PROCEDURE</span> <span class="n">dbo</span><span class="p">.</span><span class="n">Collect_ResourceGovernorStats</span> <span class="k">AS</span> <span class="p">;</span><span class="k">WITH</span> <span class="n">RGCTE</span> <span class="k">AS</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="n">GETUTCDATE</span><span class="p">()</span> <span class="k">AS</span> <span class="n">now_utc</span><span class="p">,</span> <span class="n">DATEDIFF</span><span class="p">(</span><span class="n">HOUR</span><span class="p">,</span><span class="n">GETUTCDATE</span><span class="p">(),</span><span class="n">GETDATE</span><span class="p">())</span> <span class="k">AS</span> <span class="n">now_offset</span><span class="p">,</span> <span class="n">rgp</span><span class="p">.</span><span class="n">name</span> <span class="k">AS</span> <span class="n">pool_name</span><span class="p">,</span> <span class="n">rgg</span><span class="p">.</span><span class="n">name</span> <span class="k">AS</span> <span class="n">group_name</span><span class="p">,</span> <span class="n">rgg</span><span class="p">.</span><span class="n">total_request_count</span><span class="p">,</span> <span class="n">rgg</span><span class="p">.</span><span class="n">total_cpu_usage_ms</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">resource_governor_resource_pools</span> <span class="k">AS</span> <span class="n">rgp</span> <span class="k">INNER</span> <span class="k">JOIN</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_resource_governor_workload_groups</span> <span class="k">As</span> <span class="n">rgg</span> <span class="k">ON</span> <span class="n">rgp</span><span class="p">.</span><span class="n">pool_id</span> <span class="o">=</span> <span class="n">rgg</span><span class="p">.</span><span class="n">pool_id</span> <span class="p">)</span> <span class="k">INSERT</span> <span class="k">INTO</span> <span class="n">ResourceGovernorUsageData</span> <span class="p">(</span> <span class="n">CollectionTimeUTC</span><span class="p">,</span> <span class="n">CollectionTimeOffset</span><span class="p">,</span> <span class="n">ResourcePool</span><span class="p">,</span> <span class="n">WorkloadGroup</span><span class="p">,</span> <span class="n">RequestCountTotal</span><span class="p">,</span> <span class="n">RequestCountDelta</span><span class="p">,</span> <span class="n">CPUUsageMSTotal</span><span class="p">,</span> <span class="n">CPUUsageMSDelta</span> <span class="p">)</span> <span class="k">SELECT</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">now_utc</span><span class="p">,</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">now_offset</span><span class="p">,</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">group_name</span><span class="p">,</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">pool_name</span><span class="p">,</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">total_request_count</span><span class="p">,</span> <span class="p">(</span> <span class="k">CASE</span> <span class="k">WHEN</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">total_request_count</span> <span class="o">&gt;=</span> <span class="k">ISNULL</span><span class="p">(</span><span class="n">LastRun</span><span class="p">.</span><span class="n">RequestCountTotal</span><span class="p">,</span><span class="mi">0</span><span class="p">)</span> <span class="k">THEN</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">total_request_count</span> <span class="o">-</span> <span class="n">LastRun</span><span class="p">.</span><span class="n">RequestCountTotal</span> <span class="k">ELSE</span> <span class="mi">0</span> <span class="k">END</span> <span class="p">),</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">total_cpu_usage_ms</span><span class="p">,</span> <span class="p">(</span> <span class="k">CASE</span> <span class="k">WHEN</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">total_cpu_usage_ms</span> <span class="o">&gt;=</span> <span class="k">ISNULL</span><span class="p">(</span><span class="n">LastRun</span><span class="p">.</span><span class="n">CPUUsageMSTotal</span><span class="p">,</span><span class="mi">0</span><span class="p">)</span> <span class="k">THEN</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">total_cpu_usage_ms</span> <span class="o">-</span> <span class="n">LastRun</span><span class="p">.</span><span class="n">CPUUsageMSTotal</span> <span class="k">ELSE</span> <span class="mi">0</span> <span class="k">END</span> <span class="p">)</span> <span class="k">FROM</span> <span class="n">RGCTE</span> <span class="k">OUTER</span> <span class="n">APPLY</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="n">TOP</span> <span class="p">(</span><span class="mi">1</span><span class="p">)</span> <span class="n">RequestCountTotal</span><span class="p">,</span> <span class="n">CPUUsageMSTotal</span> <span class="k">FROM</span> <span class="n">ResourceGovernorUsageData</span> <span class="k">AS</span> <span class="n">RGD</span> <span class="k">WHERE</span> <span class="n">RGD</span><span class="p">.</span><span class="n">ResourcePool</span> <span class="o">=</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">pool_name</span> <span class="k">AND</span> <span class="n">RGD</span><span class="p">.</span><span class="n">WorkloadGroup</span> <span class="o">=</span> <span class="n">RGCTE</span><span class="p">.</span><span class="n">group_name</span> <span class="k">ORDER</span> <span class="k">BY</span> <span class="n">CollectionTimeUTC</span> <span class="k">DESC</span> <span class="p">)</span> <span class="k">AS</span> <span class="n">LastRun</span><span class="p">;</span></code></pre></figure> <p>This procedure will take a snapshot of the current resource governor stats (via the CTE), and then subtract the most recent stats from our table and store the new total and the delta. We are also handling our error cases, making sure to throw out our delta if the current aggregated total is not higher than the previous, and also throwing out our data if there is no data in the table to calculate a delta from.</p> <p>Now all you have to do is schedule this procedure to run on a regular basis (I chose to run this every 5 minutes via SQL Agent) and you’ll have a nice high level view of resource consumption on your instance.</p> <h2 id="where-to-go-from-here">Where to Go from Here</h2> <p>For me, this is the really fun part. There is a lot you can do with this data. Even if you just leave the data on the instance and export it to excel for analysis after new code releases it can be a very valuable tool.</p> <p>In my environment I am using a custom PowerShell module to simultaniously write my Resource Governor data to SQL Server as well as Elasticsearch. Once the data is in Elasticsearch I can run aggregations on it, analyse it with Python, and create resource usage dashboards for the various team managers.</p> <p>Look for future posts where I talk about my custom module and provide visual examples of what can be done in Kibana once you get this data into Elasticsearch.</p> I'm Still Here 2016-07-02T00:00:00+00:00 https://m82labs.com/still-here I haven't died, I just have more kids. <p>I’m still here. The only updates I have made to the blog in the past year have been updating my ‘about’ page to note the new addition to our family (which is a great thing!). My last blog post was published two weeks before my daughter was born, and now that her first birthday is coming up I feel like I’m in a good place to start writing again. Writing technical blog posts is such a departure from my day-to-day work that it can be hard to get “in the zone”, especially with a new baby (now fully mobile toddler) around the house.</p> <p>That being said, I did get a lot of things done during my break from writing for my blog. I wanted to post some of those things here in case it’s of interest to anyone out there.</p> <h3 id="passcard">PassCard</h3> <p>PassCard is a secure password system I came up with years ago that I just now got around to putting up on GitHub. PassCard creates a keycard you can carry around and use to create complex passwords using simple words. It’s reusable, and as long as you remember your generation password, you can can easily regenerate and print copies of your card if your first one goes through the wash. Check out the project on GitHub and get some more details on this project: <a href="https://github.com/m82labs/passcard">https://github.com/m82labs/passcard</a></p> <h3 id="murrow">Murrow</h3> <p>I am a huge Linux nerd and love the older web technologies like RSS. These two interests, combined with a love of Python, lead to Murrow. Murrow is a console-based RSS aggregator written in Python 3. This is an educational project, but it has been a lot of fun and I use it every day. Murrow has some neat features (for a console app) like read-time estimates based on your actual read times of past articles, and <a href="http://getpocket.com">pocket</a> integration. Check out the project here: <a href="https://github.com/m82labs/murrow">https://github.com/m82labs/murrow</a></p> <h3 id="elasticsearch">Elasticsearch</h3> <p>No, I haven’t contributed anything to the great Elasticsearch project, but I have been using it a lot. Expect to see future posts making a lot of use of Elasticsearch and Kibana to visualize performance data from SQL Server and create dashboards.</p> <h2 id="whats-next">What’s Next?</h2> <p>News posts! I expect to finish up a post on Resource Governor in the next week or less, as well as a longer post outlining some tips and tricks for managing multiple SQL Server instances. Even though it has been a year, I do plan to at least write a follow-up to my popular MariaDB backup post covering some of the advanced options and usage.</p> MariaDB Backups for the SQL Server DBA 2015-07-02T00:00:00+00:00 https://m82labs.com/Mariadb_backups Learn to do backups, the MariaDB way. <p>As a DBA your most important job is making sure you don’t lose your data in the case of catastrophic failure. Why should that be any different when your data is stored in a system you don’t know very well?</p> <p>With the plethora of database systems available today most DBAs will find themselves supporting more than just SQL Server. This will be the first in a series of posts that will explore backup and restore options in a variety of relational and non-relational systems from the perspective of a SQL Server DBA. While this series will not be comprehensive by any means (there are 10+ engine options for MariaDB alone) I will try to cover the most common use cases for each system.</p> <h2 id="prerequisites">Prerequisites</h2> <p>This post, and really the whole series, is going to assume that you have some experience on the Linux command line and that you have access to a lab environment where you can follow along. While some of the systems in this series <strong>can</strong> run on Windows, they weren’t typically designed with it in mind. If you have not used Linux I highly suggest you spin up a VM and give it a try. All the command examples given are going to be executed on an Ubuntu Linux box, but the commands should work in any distribution.</p> <h2 id="mariadb-and-the-xtradb-storage-engine">MariaDB and the XtraDB Storage Engine</h2> <p>MariaDB is a DBMS designed to be a drop-in replacement for MySQL, even using the same binary and config file names. It was developed as a fork of MySQL by some of the original developers after concerns arose when MySQL was purchased by Oracle. For the most part, MariaDB is almost 100% compatible with existing MySQL code.</p> <p><sup>For more details on the incompatibilities, check out the <a href="https://mariadb.com/kb/en/mariadb/mariadb-vs-mysql-compatibility/">MariaDB website</a>.</sup></p> <p>MariaDB can use a variety of storage engines depending on what you are using it for. For example, if you are looking for a traditional ACID-compliant RDBMS like SQL Server you can use the XtraDB engine, if you are looking for an in-memory database the MEMORY storage engine might be a good fit, if you need to query data from CSV, XML, or JSON files you can use the CONNECT engine . Depending on your needs you can even mix it up and use different engines for different tables. All of these options can make it an extremely flexible solution, and at a price of $FREE, it’s worth giving it a try.</p> <p>For the rest of this post we are going to focus on the default storage engine for MariaDB, XtraDB. XtraDB is a high-performance, backwards-compatible, fork of InnoDB developed by <a href="https://www.percona.com/software/percona-server/percona-xtradb">Percona</a>. It’s important to note that XtraDB is compatible with both MySQL and MariaDB, so this post can work for either.</p> <h2 id="xtrabackup-and-innobackupex">XtraBackup and Innobackupex</h2> <p>Xtrabackup is a tool developed by Percona to perform non-locking backups of your database. It’s a little confusing at first, but Xtrabackup is only part of the story, what you will be spending the most time with is Innobackupex. Innobackupex is a Perl wrapper script that calls Xtrabackup and adds a lot of nice functionality like automatically time-stamping your backups (more on this later). There are more options for backing up your data than just Xtrabackup/Innobackupex, but for the SQL Server DBA this option should seem the most familiar.</p> <p><sup> There are many other options when taking backups on a MariaDB or MySQL instance. I chose to cover xtrabackup in this post because it will likely be the most familiar for the typical SQL Server DBA, it gives you a lot of flexible backup options, and it allows you to take online backups with a minimal amount of setup. </sup></p> <h3 id="before-you-run-a-backup">Before You Run a Backup</h3> <p>Before you run your first backup you need to ensure you have the following:</p> <h4 id="1-add-backup-system-users-to-the-mysql-group">1. Add backup system users to the <code class="highlighter-rouge">mysql</code> group.</h4> <p>Any users that need to perform backups should be added to this group. To add the <code class="highlighter-rouge">m82labs</code> user to it (you’ll want to add your own user for this example) execute the following:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo usermod -G mysql -a m82labs</code></pre></figure> <p>You’ll also need to make some changes to the permissions on your MariaDB data file directories for this to work properly (here we assume your data directory is <code class="highlighter-rouge">/var/lib/mysql</code>):</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>find /var/lib/mysql -type d -exec sudo chmod 750 <span class="o">{}</span> <span class="se">\;</span></code></pre></figure> <p>These changes will give the <code class="highlighter-rouge">mysql</code> user full access to the files, users in the <code class="highlighter-rouge">mysql</code> group get read and execute (read allows us to read the file for backup, execute allows us to traverse the directories), and anyone else gets no permissions at all.</p> <p><sup> Linux permissons can be confusing at first, I highly recommend reading up on using <code class="highlighter-rouge">chmod</code> to get a good understanding of how to set permissions. Check the <a href="#resources"><em>Resources</em></a> section at the bottom of the post for more information on using <code class="highlighter-rouge">chmod</code>. </sup></p> <p>We will also need to make some changes to how MariaDB create directories for new databases so we don’t have to manually change permissions each time we create a new database. To do this you will need to modify the <code class="highlighter-rouge">/etc/init.d/mysql</code> file and add the following lines to the top of the file just below the <code class="highlighter-rouge">INIT INFO</code> header block:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="nv">UMASK_DIR</span><span class="o">=</span>424 <span class="c"># = Evaluates to 750</span> <span class="nb">export </span>UMASK_DIR</code></pre></figure> <p>After this change you will need restart the database service:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo service mysql restart</code></pre></figure> <p>Then log out and log back in for the group membership changes to register.</p> <h4 id="2-a-backup-directory-that-is-owned-by-the-mysql-user">2. A backup directory that is owned by the <code class="highlighter-rouge">mysql</code> user.</h4> <p>Make a new directory and change the permissions and ownership. This ensures that the <code class="highlighter-rouge">mysqld</code> service can write to the directory, and any user in the <code class="highlighter-rouge">mysql</code> group can also manipulate the contents of the directory.</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo mkdir /opt/backups <span class="gp">$ </span>sudo chown -R mysql:mysql /opt/backups <span class="gp">$ </span>sudo chmod -R 770 /opt/backups</code></pre></figure> <h4 id="3-a-database-user-with-the-correct-permissions">3. A database user with the correct permissions.</h4> <p>Typically you should create a dedicated user for backups. Here we’ll assume you named it <code class="highlighter-rouge">backup</code>. Since this user is going to be handling your backups only, it should be safe to assume the user will only connect from the local machine.</p> <p>In MariaDB and MySQL a user isn’t just identified by a username, but also a hostname. As an example, you could create four different <code class="highlighter-rouge">backup</code> users with four different passwords as long as you specified that they all connect from different hosts. Though not recommended in this case, putting a <code class="highlighter-rouge">%</code> in the hostname field will allow the user to connect from any computer.</p> <p>To create the user connect to your MariaDB instance and execute the following statements:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash">CREATE USER <span class="s1">'backup'</span>@<span class="s1">'localhost'</span>; SET PASSWORD FOR <span class="s1">'backup'</span>@<span class="s1">'localhost'</span> <span class="o">=</span> PASSWORD<span class="o">(</span><span class="s1">'SuperSecret'</span><span class="o">)</span>;</code></pre></figure> <p>This creates a user named <code class="highlighter-rouge">backup</code> that can only connect from <code class="highlighter-rouge">localhost</code> with a password of <code class="highlighter-rouge">SuperSecret</code>. This account will need the following permissions:</p> <ul> <li><code class="highlighter-rouge">RELOAD</code></li> <li><code class="highlighter-rouge">LOCK TABLES</code></li> <li><code class="highlighter-rouge">REPLICATION CLIENT</code></li> <li><code class="highlighter-rouge">CREATE TABLESPACE</code></li> <li><code class="highlighter-rouge">PROCESS</code></li> <li><code class="highlighter-rouge">SUPER</code></li> </ul> <p>To <code class="highlighter-rouge">GRANT</code> the required permissions, execute the following:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash">GRANT RELOAD,LOCK TABLES,REPLICATION CLIENT,CREATE TABLESPACE,PROCESS,SUPER ON <span class="k">*</span>.<span class="k">*</span> TO <span class="s1">'backup'</span>@<span class="s1">'localhost'</span>;</code></pre></figure> <p>Now that all of this is set up we can move onto creating some backups.</p> <h3 id="anatomy-of-a-backup">Anatomy of a Backup</h3> <p>Taking backups with <code class="highlighter-rouge">Innobackupex</code> is pretty straight forward:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>innobackupex --user<span class="o">=</span>backup --password<span class="o">=</span><span class="s1">'SuperSecret'</span> /opt/backups</code></pre></figure> <p>This command is simply connecting to your MariaDB instance with the supplied username and password, making a backup, and storing it in the directory you specified. You <em>can</em> supply a host and port if you like, but by default it will attempt to connect to localhost using the port specified in the servers <code class="highlighter-rouge">/etc/mysql/my.cnf</code> file. If no such file exists it will check the <code class="highlighter-rouge">$MYSQL_TCP_PORT</code> environment variable, the <code class="highlighter-rouge">/etc/services</code> file (see more about this file <a href="http://linux.about.com/cs/linux101/g/slshetcslshserv.htm">here</a>), or if all else fails, the default port of <code class="highlighter-rouge">3306</code>.</p> <p>After running the above command you should see a bunch of output on the screen. Assuming you have no errors, lets go check out the <code class="highlighter-rouge">/opt/backups</code> directory and see what we have.</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"> <span class="nv">$ </span>ls -la /opt/backups </code></pre></figure> <p><sup>If you do have errors, run through all the steps again and make sure you didn’t miss anything. Typically errors during a backup are related to permissions.</sup></p> <p>One of the first things you’ll notice about backups from <code class="highlighter-rouge">innobackupex</code> is that your backup is not just a single file, it is an entire directory named with a time stamp. If you run an <code class="highlighter-rouge">ls</code> on that directory you will see several files and sub-directories in it. One of the interesting things about this backup is that it contains ALL the information needed to restore the backup.</p> <p>There is no concept of <code class="highlighter-rouge">msdb</code> in the MariaDB world. All of the information that would normally be found in the various backup related DMVs is available in the files located in your new backup directory. Here is a brief description of what you will find here (visit the <a href="https://www.percona.com/doc/percona-xtrabackup/2.1/xtrabackup-files.html">Percona website</a> for more detail):</p> <ul> <li> <p><strong><em>backup-my.cnf:</em></strong> After a backup is taken it still needs to be “prepared” (more on that later) before it can be used. This config file is used to start a small DB instance to prepare your backup for a restore.</p> </li> <li> <p><strong><em>xtrabackup_checkpoints:</em></strong> This file contains information about the type of backup you took along with the range of LSNs involved in the backup.</p> </li> <li> <p><strong><em>xtrabackup_binary:</em></strong> A copy of the xtrabackup binary used to perform the backup.</p> </li> <li> <p><strong><em>xtrabackup_logfile:</em></strong> This is the equivalent of the transaction log. There are no transaction log-only backups in MariaDB, the transaction log is automatically included when you run a backup.</p> </li> </ul> <h3 id="preparing-your-backups">Preparing Your Backups</h3> <p>Before we get into the details of the various backup types, it is very important that we discuss the process of ‘preparing’ a backup. As we touched on before, preparing a backup gets the backup ready for restoring.</p> <p>When you take a backup it cannot copy all the required files into the backup directory at the exact same moment in time, some files get copied a few seconds after others. Running a <code class="highlighter-rouge">prepare</code> on the backup will get all files point-in-time consistent with each other.</p> <p>The prepare also accomplishes another important thing, it tests your backup. If something is wrong with your backup, the prepare process will fail. Because of this, a lot of people like to run a prepare right after they take a backup. This is a great idea, but as we will discuss below, it’s not always an option.</p> <h3 id="backup-types">Backup Types</h3> <p>You have a lot of options when backing up your MariaDB data. Innobackupex allows you to take full backups, incremental, partial, and compact backups. Each have pros and cons and in the end you have a lot of options for a very flexible backup schedule.</p> <h3 id="full-backup">Full Backup</h3> <p>This is the simplest of the backups, and is still required if you decide to take incremental backups. One thing to note about the full backup is that it is a full <strong><em>instance</em></strong> backup, not just a single DB. That being said, when you take a full backup you can still restore a single database or table from that full backup, it is just a bit of work. This will be discussed in more detail later on.</p> <h4 id="taking-a-full-backup">Taking a Full Backup</h4> <p>Earlier in this post we saw the command for a full backup, but we’ll repeat it here:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>innobackupex --user<span class="o">=</span>backup --password<span class="o">=</span><span class="s1">'SuperSecret'</span> /opt/backups</code></pre></figure> <p>This will create a directory named with the current timestamp in the <code class="highlighter-rouge">/opt/backups/</code> directory. You could take another full immediately after this one is done and it would create another timestamped directory for you.</p> <h4 id="preparing-a-full-backup">Preparing a Full Backup</h4> <p>As we mentioned earlier, the backup has to be prepared before it can be restored. To prepare a backup you simply run the following command:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>innobackupex --user<span class="o">=</span>backup --password<span class="o">=</span><span class="s1">'SuperSecret'</span> --apply-log --use-memory<span class="o">=</span>1G /opt/backups/YourBackupDirectory</code></pre></figure> <p>The <code class="highlighter-rouge">--use-memory</code> parameter is optional, but if you give the prepare process more memory it can definitely speed things up. You’ll have to play with this option to see what works best for your system.</p> <p><sup>Note: This step should be skipped if you plan on doing incremental backups based off of this full backup. In that case you could copy the backup to a different location and attempt a prepare there.</sup></p> <h4 id="restoring-a-full-backup">Restoring a Full Backup</h4> <p>After preparing the backup we can do an actual restore. Since a full backup is a backup of all databases on the instance, the database service needs to be stopped before a restore can begin and all existing data in the data directory needs to be deleted. I would highly recommend creating a “staging” area of sorts to hold the original contents of your data directory <strong>before</strong> you delete it. This way, if something goes wrong with the restore, you can always just copy your original files back over.</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo mkdir /opt/mysql.temp <span class="gp">$ </span>sudo chown mysql:mysql /opt/mysql.temp <span class="gp">$ </span>sudo chmod 770 /opt/mysql.temp</code></pre></figure> <p>To stop the database service and restore the backup:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo service mysql stop <span class="gp">$ </span>sudo mv /var/lib/mysql/<span class="k">*</span> /opt/mysql.temp/ <span class="gp">$ </span>innobackupex --copy-back /opt/backups/YourBackupDirectory</code></pre></figure> <p>This will copy your database files to the empty data directory, now we need to fix ownership issues (the files will be owned by the user that ran the restore) and restart the database service:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo chown -R mysql:mysql /var/lib/mysql <span class="gp">$ </span>sudo service mysql start</code></pre></figure> <p>With any luck you should now have a functional instance based on the backup you restored. Make sure you remember to delete everything from your “staging” area after the restore is complete and well-tested.</p> <h3 id="incremental-backup">Incremental Backup</h3> <p>Xtrabackup supports <strong>true incremental backups</strong>. Unlike SQL Servers differential backups, which store the changes made since the last full backup, incremental backups store the changes made since the last incremental backup.</p> <h4 id="taking-an-incremental-backup">Taking an Incremental Backup</h4> <p>The first step in taking incremental backups is to take a full backup to base your incremental on. For our purposes lets assume we already have a full backup from our steps above at the following path: <code class="highlighter-rouge">/opt/backups/2015-06-28_13-42-58/</code></p> <p>To take an incremental you would issue the following command:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>innobackupex --user<span class="o">=</span>backup --password<span class="o">=</span><span class="s1">'SuperSecret'</span> --incremental /opt/backups --incremental-basedir<span class="o">=</span>/opt/backups/2015-06-28_13-42-58/</code></pre></figure> <p>The key to this command is the <code class="highlighter-rouge">--incremental-basedir</code> parameter. This tells innobackupex to base the incremental off of whatever backup is in the directory specified. If you recall from earlier, each backup folder contains a file named <code class="highlighter-rouge">xtrabackup_checkpoints</code>, this file tells innobackupex which LSN to start it’s incremental backup at.</p> <p>After running this command you will have just another timestamped directory in your backups directory. To find your incremental backups you could execute a command like this:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>find /opt/backups -type f | xargs grep incremental</code></pre></figure> <p>You should see output similar to this:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash">/opt/backups/2015-06-28_15-10-37/xtrabackup_checkpoints:backup_type <span class="o">=</span> incremental</code></pre></figure> <p>From here you can continue taking incremental backups, each one based off of the previous incremental, for example the next incremental would have a <code class="highlighter-rouge">--incremental-basedir</code> of <code class="highlighter-rouge">/opt/backups/2015-06-28_15-10-37/</code>. There is also an option available to base your incremental simply on a known LSN. We aren’t really going to go into any detail here, but it would do roughly the same operations as basing it off of an existing backup, except you have to manually specify the starting LSN via the <code class="highlighter-rouge">--incremental-lsn</code> parameter.</p> <h4 id="preparing-an-incremental-backup">Preparing an Incremental Backup</h4> <p>Preparing an incremental backup is a little different than preparing a full backup. Earlier we mentioned that if you choose to take incremental backups you <strong>cannot</strong> prepare your backups right after you take them. The reason for this is that when preparing an incremental backup, all incremental backups need to be applied to the base full backup before anything can be prepared.</p> <p>This process is very similar to the concept of restoring differential backups and transaction logs in SQL Server, you don’t want your subsequent restores to go through recovery until all backups are applied.</p> <p>To begin we need to apply our logs to the base full backup we initially created:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>innobackupex --user<span class="o">=</span>backup --password<span class="o">=</span><span class="s1">'SuperSecret'</span> --apply-log --redo-only /opt/backups/2015-06-28_13-42-58/</code></pre></figure> <p>This brings the full backup to a state where all logs have been applied, but uncommitted transactions have <strong>NOT</strong> been rolled back.</p> <p>Now we start applying out incremental backups:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>innobackupex --user<span class="o">=</span>backup --password<span class="o">=</span><span class="s1">'SuperSecret'</span> --apply-log --redo-only /opt/backups/2015-06-28_13-42-58/ --incremental-dir<span class="o">=</span>/opt/backups/2015-06-28_15-10-37/</code></pre></figure> <p>If we had more incremental backups we would continue to execute this command, changing the <code class="highlighter-rouge">--incremental-dir</code> parameter to apply each incremental backup <strong><em>in the order they were taken</em></strong>. When you get to your final incremental to apply, you need to omit the <code class="highlighter-rouge">--redo-only</code> option, but if you forget, it’s no big deal, the server will handle it automatically.</p> <p>Once all of your incremental backups are applied, we need to prepare the final backup. This statement needs to be run on the directory the base full backup resides in, the one we based all of our incrementals on:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>innobackupex --user<span class="o">=</span>backup --password<span class="o">=</span><span class="s1">'SuperSecret'</span> --apply-log --use-memory<span class="o">=</span>1G /opt/backups/2015-06-28_13-42-58/</code></pre></figure> <p>Now just as before we can go through the steps of restoring a full backup.</p> <p>Stop the service, remove the old data files, and copy the new data files:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo service mysql stop <span class="gp">$ </span>sudo rm -rf /var/lib/mysql/<span class="k">*</span> <span class="gp">$ </span>innobackupex --copy-back /opt/backups/YourBackupDirectory</code></pre></figure> <p>Now we fix any ownership issues and restart the service:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo chown -R mysql:mysql /var/lib/mysql <span class="gp">$ </span>sudo service mysql start</code></pre></figure> <h3 id="compact-backups">Compact Backups</h3> <p>The compact backup isn’t so much a <em>type</em> of backup as an option when you are taking backups. A compact backup does not include any secondary index pages, a secondary index in MariaDB is analogous to a non-clustered index in SQL Server.</p> <p>It’s important to understand that a compact backup <strong>does</strong> include the metadata needed to recreate the indexes, but it <strong>does not</strong> include the actual index pages themselves. What that means is that you can reduce your backup size while still retaining the ability to rebuild your secondary indexes at a later time.</p> <p>The compact backup can potentially be much smaller than a standard backup depending on the number of secondary indexes you have. This has two obvious benefits: less space required per backup, and less time to actually perform the backup. Like all things in life and computers though, you are trading space and time <strong>NOW</strong> for space and time <strong>LATER</strong>. When you need to restore a compact backup, you will need to rebuild the indexes, which will take time and consume additional space.</p> <p>You can take a compact backup by adding the <code class="highlighter-rouge">--compact</code> option to either a full or incremental backup. When you create a compact backup the <code class="highlighter-rouge">compact</code> flag will be set to <code class="highlighter-rouge">1</code> in the <code class="highlighter-rouge">xtrabackup_checkpoints</code> file in the backup directory. If you want to find you compact backups you can run this command:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>find /opt/backups -type f | xargs grep -B 4 <span class="s1">'compact = 1'</span></code></pre></figure> <p>You should see output similar to this:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash">/opt/backups/2015-06-29_16-10-04/xtrabackup_checkpoints-backup_type <span class="o">=</span> full-backuped /opt/backups/2015-06-29_16-10-04/xtrabackup_checkpoints-from_lsn <span class="o">=</span> 0 /opt/backups/2015-06-29_16-10-04/xtrabackup_checkpoints-to_lsn <span class="o">=</span> 1644288 /opt/backups/2015-06-29_16-10-04/xtrabackup_checkpoints-last_lsn <span class="o">=</span> 1644288 /opt/backups/2015-06-29_16-10-04/xtrabackup_checkpoints:compact <span class="o">=</span> 1 -- /opt/backups/2015-06-29_16-11-11/xtrabackup_checkpoints-backup_type <span class="o">=</span> incremental /opt/backups/2015-06-29_16-11-11/xtrabackup_checkpoints-from_lsn <span class="o">=</span> 1644288 /opt/backups/2015-06-29_16-11-11/xtrabackup_checkpoints-to_lsn <span class="o">=</span> 1644288 /opt/backups/2015-06-29_16-11-11/xtrabackup_checkpoints-last_lsn <span class="o">=</span> 1644288 /opt/backups/2015-06-29_16-11-11/xtrabackup_checkpoints:compact <span class="o">=</span> 1</code></pre></figure> <h4 id="preparing-and-restoring-a-compact-backup">Preparing and Restoring a Compact Backup</h4> <p>Preparing and restoring a compact backup is simple. To prepare the backup you would prepare the backup as usual but include the <code class="highlighter-rouge">--rebuild-indexes</code> option.</p> <p>In the case of a full backup there is only a single step involved in preparing the backup, so the <code class="highlighter-rouge">--rebuild-indexes</code> option would be included in that step. When preparing incremental backups the <code class="highlighter-rouge">--rebuild-indexes</code> option should only be included in the final step of the prepare, once you are applying the final incremental backup to the full, base, backup.</p> <p>Once the index rebuilds are complete, and the logs are applied, your backup will be full-size, as if you have taken a normal (non-compact) backup, so make sure you have enough space before you start the prepare process. At this point you can restore the backup as usual via the <code class="highlighter-rouge">--copy-back</code> option discussed earlier.</p> <p><sup> Compact can be a great way to save space and reduce the amount of time it takes to create a backup. While compact is great, </sup></p> <h3 id="table-or-database-specific-restores">Table or Database-Specific Restores</h3> <p>Now what if you only wanted to restore a single database? Well, that gets a bit tougher. If you want to do this level of restore you need to make sure the <code class="highlighter-rouge">innodb_file_per_table</code> option is enabled. If you are using MariaDB 5.5 or greater this is on by default.</p> <p><sup>Technically you cannot restore a single database from a prepared backup, but what you can do is restore each of the tables in the database, effectively restoring the entire database.</sup></p> <h4 id="the-restore-process">The Restore Process</h4> <p>For the examples below lets assume we want to restore a database creatively named <code class="highlighter-rouge">mydatabase</code>. We will walk through the steps to restore a single table named <code class="highlighter-rouge">OneofMyTables</code>. To restore a specific database, you would need to go through this process for each table in that database.</p> <p>The first step in this process is to export all (yes all) of the tables from your prepared backup:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>innobackupex --apply-log --export /opt/backups/YourBackupDirectory</code></pre></figure> <p>Now, in the database you want to restore the tables to you will have to drop the old table and recreate it:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="n">USE</span> <span class="n">mydatabase</span><span class="p">;</span> <span class="k">DROP</span> <span class="k">TABLE</span> <span class="n">OneOfMyTables</span><span class="p">;</span> <span class="k">CREATE</span> <span class="k">TABLE</span> <span class="n">OneOfMyTables</span> <span class="p">(</span> <span class="n">MyColumn</span> <span class="n">INT</span> <span class="p">);</span></code></pre></figure> <p>Then we need to discard the tablespace for each table:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">ALTER</span> <span class="k">TABLE</span> <span class="n">OneOfMyTables</span> <span class="n">DISCARD</span> <span class="n">TABLESPACE</span><span class="p">;</span></code></pre></figure> <p>Now we need to remove the existing data files and copy the <code class="highlighter-rouge">OneOfMyTables.ibd</code> and <code class="highlighter-rouge">OneOfMyTables.exp</code> files from our backup to our data directory:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span><span class="nb">cd</span> /var/lib/mysql/mydatabase/ <span class="gp">$ </span>sudo rm -rf OneOfMyTables.<span class="k">*</span> <span class="gp">$ </span>sudo cp /opt/backups/YourBackupDirectory/mydatabase/OneOfMyTables.exp . <span class="gp">$ </span>sudo cp /opt/backups/YourBackupDirectory/mydatabase/OneOfMyTables.ibd .</code></pre></figure> <p>Since you are executing these commands as a user, we’ll need to change the file ownership back so MariaDB can read the files. This step can wait until all of your table export files have been copied over:</p> <figure class="highlight"><pre><code class="language-bash" data-lang="bash"><span class="gp">$ </span>sudo chown -R mysql:mysql /var/lib/mysql/mydatabase/</code></pre></figure> <p>Executing this statement from within the <code class="highlighter-rouge">mydatabase</code> database:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">ALTER</span> <span class="k">TABLE</span> <span class="n">mydatabase</span><span class="p">.</span><span class="n">OneOfMyTables</span> <span class="n">IMPORT</span> <span class="n">TABLESPACE</span><span class="p">;</span></code></pre></figure> <p>Now you should be all set. The table should be available to query and it should contain the data from the backup.</p> <h4 id="foreign-key-considerations">Foreign Key Considerations</h4> <p>If you are dealing with tables that have foreign key constraints, it is up to you to make sure all related tables are imported in a consistent state. If you are importing a table that is used by other tables for foreign key look-ups, you will need to disable foreign key checks before you drop the original table:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SET</span> <span class="n">FOREIGN_KEY_CHECKS</span><span class="o">=</span><span class="mi">0</span><span class="p">;</span></code></pre></figure> <p>Once the table has been completely imported you can turn your foreign key checks back on:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SET</span> <span class="n">FOREIGN_KEY_CHECKS</span><span class="o">=</span><span class="mi">1</span><span class="p">;</span></code></pre></figure> <p>From this point <strong>forward</strong> your foreign key constraints will function as usual, but there is a caveat here. If the data you imported violates a foreign key constraint you will not know until you try to manipulate the record that violates the constraint. MariaDB has no built-in mechanism to recheck your foreign key constraints. Interestingly, some adventurous users have written scripts and tools to take care of this, I am not going to cover those scripts here but I will include a link the <a href="#resources"><strong><em>Resources</em></strong></a> section.</p> <h4 id="thoughts-on-table-imports">Thoughts on Table Imports</h4> <p>Table imports are kind of a clunky process, but it’s still a pretty cool feature. It’s worth going over this a few times with some test data to get a good understanding of the steps involved. There are some good scripts people have written to attempt to automate this process, but it’s always useful learning how to do it by hand.</p> <h3 id="partial-backup">Partial Backup</h3> <p>Partial backups are a special type of backup that allow you to backup specific tables or databases instead of backing up everything. While this sounds great, it has it’s drawbacks.</p> <h4 id="taking-a-partial-backup">Taking a Partial Backup</h4> <p>There are three ways you can take a partial backup. Each method is defined by a different option:</p> <ul> <li> <p><strong><em>- -include:</em></strong> This is the most flexible and the most complex to use. The <code class="highlighter-rouge">--include</code> option identifies which tables to backup via regular expression (regex). In our <code class="highlighter-rouge">mydatabase.OneOfMyTables</code> example from above we might specify a regex of <code class="highlighter-rouge">^mydatabase[.]OneOfMyTables$</code>. If we wanted to grab the whole database we might use <code>^mydatabase[.]*</code>. If you are familiar with regex you can see the flexibility here, if you are not I suggest reading up on it.</p> </li> <li> <p><strong><em>- -tables-file:</em></strong> This option takes a text file as an argument, this text file contains a fully qualified table per line (database.table).</p> </li> <li> <p><strong><em>- -databases:</em></strong> This option takes a space separated list of database names and/or fully qualified table names OR a text file containing a list with one database and/or fully qualified table per line.</p> </li> </ul> <p>All of these options will result in a backup that looks pretty much like all the other backups you have seen so far, the only difference is that instead of seeing one directory per database, you will see one directory per database that was specified and one database directory per table that was specified. For example, if you used the <code class="highlighter-rouge">--databases</code> option and passed it <code class="highlighter-rouge">TestDB TestDB01.SomeTable</code> you would see a directory for <code class="highlighter-rouge">TestDB</code> and a directory for <code class="highlighter-rouge">TestDB01</code>.</p> <h4 id="preparing-and-restoring-a-partial-backup">Preparing and Restoring a Partial Backup</h4> <p>Unfortunately restoring a partial backup can really only be done via the export and import table process we discussed above in the <em>Table or Database-Specific Restores</em> section. The only other option is to restore ONLY the partial backup and wipe out the rest of your data. This could be useful in some limited situations.</p> <p>As mentioned, you <strong><em>can</em></strong> restore a partial backup using the same methods you would use to restore a full backup, but the following must be true:</p> <ul> <li>The <code class="highlighter-rouge">mysql</code> database was included in the partial backup</li> <li>Your data directory must be empty</li> </ul> <p>If those conditions are met, you can restore a partial backup by following the steps for preparing and restoring (via <code class="highlighter-rouge">--copy-back</code>) a full backup.</p> <h2 id="final-thoughts">Final Thoughts</h2> <p>Overall you have a lot of options when using Perconas Xtrabackup software, but as I was told by a user on the #mysql IRC channel “it’s not exactly polished”. This article really just scratches the surface when it comes to your backup and restore options, Xtrabackup is just one piece of software to accomplish this.</p> <p>If you are interested in diving in a little deeper you’ll find a lot people doing things like maintaining a replica slave specifically for executing backups, other people are using LVM or SAN snapshots to take backups, while some are still able to use the <code class="highlighter-rouge">mysqldump</code> utility to literally dump the sql scripts needed to rebuild the schema of the instance and populate the tables with data.</p> <p>Whatever your needs are you should be able to find a backup process that works for you in the MariaDB/MySQL world. Compared to SQL Server you might find that some of it takes a little more work, or a little more time to get used to, but in the end you should still be more than able to effectively backup the data you have been charged with protecting.</p> <h2 id="coming-soon">Coming Soon</h2> <p>We covered a lot in this post, but there is still more to cover! Keep an eye out for the the second post in this series where we will dive into some more advanced backup and restore options, including streaming compressed backups and encrypted backups.</p> <h2 id="thanks">Thanks</h2> <p>Special thanks to Anthony E. Nocentino @ <a href="http://centinosystems.com">centinosystems.com</a> for proof-reading this post and offering some suggestions! Anthony is the Enterprise Architect at Centino Systems, you can find him on twitter: <a href="https://twitter.com/nocentino">@nocentino</a></p> <h2 id="resources">Resources</h2> <p><a name="resources"></a></p> <p>Below is a list of websites and other places you can find more information on MariaDB, MySQL, Percona, and Linux:</p> <ul> <li>#mysql, #maria, and #percona on <a href="https://freenode.net">Freenode</a> IRC. #mysql being the most active channel</li> <li><a href="https://www.percona.com/doc/percona-xtrabackup/2.1/innobackupex/innobackupex_script.html">Percona Innobackupex Documentation</a> @ percona.com</li> <li><a href="https://mariadb.com/kb/en/">MariaDB Knowledge Base</a> @ mariadb.com</li> <li><a href="http://stackoverflow.com/questions/2250775/force-innodb-to-recheck-foreign-keys-on-a-table-tables">Force InnoDB to recheck foreign keys on a table/tables?</a> @ stackoverflow.com</li> <li><a href="http://www.opsschool.org/en/latest/unix_101.html">Unix Fundamentals 101</a> @ opsschool.org</li> <li><a href="https://www.digitalocean.com/community/tutorials/an-introduction-to-linux-permissions">An Introduction to Linux Permissions</a> @ digitalocean.com</li> <li><a href="https://en.wikipedia.org/wiki/Chmod">chmod</a> @ en.wikipedia.org</li> </ul> Retrieving Deadlock Graphs with PowerShell 2015-06-09T00:00:00+00:00 https://m82labs.com/Retrieving_Deadlock_Graphs_with_PowerShell How to retrieve and store deadlocks graphs using PowerShell. <p>Before we dive into some extended events and PowerShell fun I want to say thanks to Jes Borland (<a href="http://blogs.lessthandot.com/index.php/author/grrlgeek/">WWW</a>/<a href="https://twitter.com/grrl_geek">Twitter</a>) for hosting this months T-SQL Tuesday! If you are interested in learning more about T-SQL Tuesday, take a look at Jes’s <a href="http://blogs.lessthandot.com/index.php/uncategorized/youre-invited-to-t-sql-tuesday-67-extended-events/">post</a>, and check out the <a href="https://twitter.com/hashtag/tsql2sday?f=realtime&amp;src=hash">#tsqltuesday</a> hashtag on Twitter.</p> <h2 id="system-health">System Health</h2> <p>Extended Events can be intimidating to start working with. You have to choose which events you want to capture, how you want to store it, and how you want to filter it. Scrolling through the available event list alone can be a little overwhelming. Thankfully SQL Server ships with the handy <code class="highlighter-rouge">system_health</code> extended event (XE going forward) session already set up and running.</p> <p>The system health XE session has an <strong>amazing</strong> amount of information in it. Do you have some long-waiting tasks? Check system health. Need CPU history? Check system health. Connection errors? Check system health. Sev 20+ errors? Check system health. There’s a lot more information available in this XE session, but for now we are just going to focus on one: deadlocks.</p> <h2 id="viewing-deadlocks-in-system-health">Viewing Deadlocks in System Health</h2> <p>Before we query system health for deadlocks, let’s take a look at it in SSMS. Getting there is pretty simple, once connected to an instance via the object explorer, just go to <em>Management</em> &gt; <em>Extended Events</em> &gt; <em>Sessions</em> &gt; <em>system_health</em>:</p> <p><img src="/public/images/SSMS_SystemHealth.png" alt="System Health XE" /></p> <p>To view the session data, double-click on <em>package0.event_file</em>. Once it opens up you’ll see the default layout, which include two columns <strong>name</strong> and <strong>timestamp</strong>. The <strong>name</strong> column contains the name of the event type that was captured, and the <strong>timestamp</strong> tells you when it happened, single-clicking on any of these events will show more detail at the bottom of the window:</p> <p><img src="/public/images/SSMS_SystemHealth-01.png" alt="System Health Event File" /></p> <p>In this case we found a deadlock graph, and as you can see the beginning of the deadlock XML is shown. If you now click on the ‘Deadlock’ tab, you can see the graphical representation of the deadlock:</p> <p><img src="/public/images/SSMS_SystemHealth-02.png" alt="System Health Event File" /></p> <p>When looking at your system health session using SSMS, make sure you also take advantage of it’s filtering capabilites, you can filter on both the timestamp and event name. To set up a filter just click on the ‘Filters…’ button in the toolbar at the top of the window. Below you can see how I would set up a filter to just show deadlocks (this test system only has a single deadlock):</p> <p><img src="/public/images/SSMS_SystemHealth-03.png" alt="System Health Event File" /></p> <p>I highly recommend taking a look around at some other events and see what you can find. There is a lot of documentation out there on system health, so find something interesting in yours and google it. You’ll be surprised how much information is available.</p> <h2 id="querying-deadlocks-from-system-health">Querying Deadlocks From System Health</h2> <p>Writing queries to get data out of extended events sessions can get complicated fast. To keep things simple we are going to use the <strong>ring buffer</strong> target for our queries. This isn’t always the best approach, but for our purposes it will work. If you were going to set something up to grab deadlock graphs on a regular basis in a production environment I would recommend, without hesitation, that you do the work of querying the <strong>file target</strong>. To learn more about this process, check the resources section at the end of this post for a great article from Jonathan Kehayias.</p> <p>Here is a simple script to grab deadlock graphs:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">DECLARE</span> <span class="o">@</span><span class="n">system_health</span> <span class="n">XML</span> <span class="c1">-- Copy ring buffer into an XML variable</span> <span class="k">SELECT</span> <span class="o">@</span><span class="n">system_health</span> <span class="o">=</span> <span class="k">CAST</span><span class="p">(</span><span class="n">xet</span><span class="p">.</span><span class="n">target_data</span> <span class="k">AS</span> <span class="n">XML</span><span class="p">)</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_xe_session_targets</span> <span class="n">xet</span> <span class="k">INNER</span> <span class="k">JOIN</span> <span class="n">sys</span><span class="p">.</span><span class="n">dm_xe_sessions</span> <span class="n">xe</span> <span class="k">ON</span> <span class="n">xe</span><span class="p">.</span><span class="n">address</span> <span class="o">=</span> <span class="n">xet</span><span class="p">.</span><span class="n">event_session_address</span> <span class="k">WHERE</span> <span class="n">xe</span><span class="p">.</span><span class="n">name</span> <span class="o">=</span> <span class="s1">'system_health'</span> <span class="k">AND</span> <span class="n">xet</span><span class="p">.</span><span class="n">target_name</span> <span class="o">=</span> <span class="s1">'ring_buffer'</span> <span class="c1">-- Get the time stamp and deadlock graph</span> <span class="k">SELECT</span> <span class="n">xed</span><span class="p">.</span><span class="n">value</span><span class="p">(</span><span class="s1">'@timestamp'</span><span class="p">,</span><span class="s1">'datetime'</span><span class="p">),</span> <span class="n">xed</span><span class="p">.</span><span class="n">query</span><span class="p">(</span><span class="s1">'.'</span><span class="p">)</span> <span class="k">FROM</span> <span class="o">@</span><span class="n">system_health</span><span class="p">.</span><span class="n">nodes</span><span class="p">(</span><span class="s1">'RingBufferTarget/event[@name="xml_deadlock_report"]'</span><span class="p">)</span> <span class="k">AS</span> <span class="n">XEventData</span><span class="p">(</span><span class="n">xed</span><span class="p">)</span></code></pre></figure> <p>We have a few things going here:</p> <ul> <li>First we copy data from the ring buffer directly into an XML variable. This simple operation can speed up XML parsing tremendously</li> <li>Next we use the <code class="highlighter-rouge">nodes()</code> method of the XML variable to extract all event elements with an event name of <code class="highlighter-rouge">xml_deadlock_report</code></li> </ul> <p>The <code class="highlighter-rouge">nodes()</code> method is an important thing to understand when dealing with XML data like that found in extended events sessions. Basically <code class="highlighter-rouge">nodes()</code> is a function that returns XML elements as row data. What this means is that when you select <code class="highlighter-rouge">FROM</code> it, each row is an independent lump of XML data. In the above query our call to <code class="highlighter-rouge">nodes()</code> will return one row per <code class="highlighter-rouge">xml_deadlock_report</code> event that has been captured.</p> <p>To extract useful information we are using the <code class="highlighter-rouge">value</code> and <code class="highlighter-rouge">query</code> methods. <code class="highlighter-rouge">value</code> takes the name of an attribute (timestamp in this case) or the path to a sub-element, and converts the value into the datatype specified. <code class="highlighter-rouge">query</code> takes an XQuery and returns an XML object, in our case we are specifying ‘.’ which just means ‘return everything’.</p> <p>If you have never written XQuery before I suggest downloading <a href="https://xpathvisualizer.codeplex.com/">XPath Visualizer</a>. With this tool you can open an XML deadlock graph (or a query plan for that matter) and immediately see the effects of an XQuery:</p> <p><img src="/public/images/SSMS_SystemHealth-04.png" alt="System Health - XPath Visualizer" /></p> <h2 id="querying-with-powershell">Querying with PowerShell</h2> <p>So with all of that out of the way, lets do what we set out to do from the start. We already have the query to get our XML deadlock graphs, now we are going to combine it with a little PowerShell.</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="c1"># ==== Deadlock Test Script ---------------------------------------------------</span> <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$instance</span> <span class="o">=</span> <span class="s1">'localhost'</span> <span class="c1"># ====-------------------------------------------------------------------------</span> <span class="c1"># ==== Set up the script ------------------------------------------------------</span> <span class="nv">$get_deadlocks</span> <span class="o">=</span> <span class="s1">' DECLARE @system_health XML -- Copy ring buffer into an XML variable SELECT @system_health = CAST(xet.target_data AS XML) FROM sys.dm_xe_session_targets xet INNER JOIN sys.dm_xe_sessions xe ON xe.address = xet.event_session_address WHERE xe.name = ''system_health'' AND xet.target_name = ''ring_buffer'' -- Get the time stamp and deadlock graph SELECT xed.value(''@timestamp'',''datetime'') AS timestamp, xed.query(''.'') As deadlockReport FROM @system_health.nodes(''RingBufferTarget/event[@name="xml_deadlock_report"]'') AS XEventData(xed); '</span> <span class="c1"># ==== Run the prepared script, output to object ------------------------------</span> <span class="nv">$results</span> <span class="o">=</span> Invoke-Sqlcmd -ServerInstance <span class="nv">$instance</span> -Query <span class="nv">$get_deadlocks</span> <span class="c1"># ==== Output to screen -------------------------------------------------------</span> <span class="nv">$results</span> | <span class="nb">Format-Table</span> -AutoSize <span class="c1"># ====-------------------------------------------------------------------------</span></code></pre></figure> <p>At this point you have your timestamp and the XML deadlock graph. Now all we need to do is write this out to a file. With PowerShell this is pretty trivial using the <code class="highlighter-rouge">Out-File</code> cmdlet. We simply loop through the results, create a unique file name, then save it.</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell">... <span class="k">Foreach</span><span class="o">(</span> <span class="nv">$result</span> <span class="k">IN</span> <span class="nv">$results</span> <span class="o">)</span> <span class="o">{</span> <span class="c1"># Generate a output file path</span> <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$timestring</span> <span class="o">=</span> <span class="s1">'{0:yyyyMMdd-HHmmssfff}'</span> -f <span class="o">[</span>datetime]<span class="nv">$result</span>.timestamp <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$outfile</span> <span class="o">=</span> <span class="s2">"</span><span class="nv">$outpath$instance_$timestring</span><span class="s2">-"</span> + <span class="o">((</span>Get-Random<span class="o">)</span> % 100<span class="o">)</span>.ToString<span class="o">()</span> + <span class="s2">"_deadlock.xdl"</span> <span class="nb">Write-Host</span> <span class="s2">"Writing file: </span><span class="nv">$outfile</span><span class="s2">"</span> <span class="k">try</span> <span class="o">{</span> <span class="nb">Out-File</span> -InputObject <span class="o">(</span><span class="nv">$result</span>.deadlockReport<span class="o">)</span> -FilePath <span class="nv">$outfile</span> <span class="o">}</span> <span class="k">catch</span> <span class="o">{</span> <span class="nb">Write-Host</span> <span class="s2">"Writing file </span><span class="nv">$outfile</span><span class="s2"> failed: </span><span class="nv">$_</span><span class="s2">"</span> <span class="o">}</span> <span class="o">}</span> ...</code></pre></figure> <p>Cool, now if you go check you output directory (we used C:\temp), you should see some deadlock graph <code class="highlighter-rouge">XDL</code> files in there. Double-clicking on one should open it in SSMS for you to view, but in our case it just returns an error:</p> <p><img src="/public/images/SSMS_SystemHealth-05.png" alt="System Health - XPath Visualizer" /></p> <p>If you open your deadlock graph in a text editor, you’ll see that the XML ends kind of abruptly:</p> <figure class="highlight"><pre><code class="language-xml" data-lang="xml">... <span class="nt">&lt;/frame&gt;&lt;/executionStack&gt;&lt;inputbuf&gt;</span> Proc [Database Id = 11 Object Id = 665274371] <span class="nt">&lt;/inputbuf&gt;&lt;/process&gt;&lt;/process-list&gt;&lt;resource-list&gt;&lt;keylock</span> <span class="na">hobtid=</span></code></pre></figure> <p>So it looks like our file was truncated. But why would that be? The answer lies in the <code class="highlighter-rouge">Invoke-SqlCmd</code> cmdlet. By default it only allows a maximum of 4000 characters per column to be returned. Luckily we can override this behavior using the ` -MaxCharLength` parameter. I was unable to find a max value for this parameter, but I find using a very large number works just fine:</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell">... <span class="c1"># ==== Run the prepared script, output to object ------------------------------</span> <span class="nv">$results</span> <span class="o">=</span> Invoke-Sqlcmd -ServerInstance <span class="nv">$instance</span> -Query <span class="nv">$get_deadlocks</span> -MaxCharLength 1000000 ...</code></pre></figure> <p>Now when we run our script and try to open one of our deadlock files we should be able to view both the graph and XML data in SSMS.</p> <p>Here is our final script:</p> <figure class="highlight"><pre><code class="language-powershell" data-lang="powershell"><span class="c1"># ==== Deadlock Test Script ---------------------------------------------------</span> <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$instance</span> <span class="o">=</span> <span class="s1">'instance_name'</span> <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$outpath</span> <span class="o">=</span> <span class="s1">'C:\temp\'</span> <span class="c1"># ====-------------------------------------------------------------------------</span> <span class="c1"># ==== Set up the script, then replace the variables --------------------------</span> <span class="nv">$get_deadlocks</span> <span class="o">=</span> <span class="s1">' DECLARE @system_health XML -- Copy ring buffer into an XML variable SELECT @system_health = CAST(xet.target_data AS XML) FROM sys.dm_xe_session_targets xet INNER JOIN sys.dm_xe_sessions xe ON xe.address = xet.event_session_address WHERE xe.name = ''system_health'' AND xet.target_name = ''ring_buffer'' -- Get the time stamp and deadlock graph SELECT xed.value(''@timestamp'',''datetime'') AS timestamp, xed.query(''.'') As deadlockReport FROM @system_health.nodes(''RingBufferTarget/event[@name="xml_deadlock_report"]'') AS XEventData(xed); '</span> <span class="c1"># ==== Run the prepared script, output to object ------------------------------</span> <span class="nv">$results</span> <span class="o">=</span> Invoke-Sqlcmd -ServerInstance <span class="nv">$instance</span> -Query <span class="nv">$get_deadlocks</span> -MaxCharLength 1000000 <span class="c1"># ==== Output to screen -------------------------------------------------------</span> <span class="nv">$results</span> | <span class="nb">Format-Table</span> -AutoSize <span class="c1"># ====-------------------------------------------------------------------------</span> <span class="k">Foreach</span><span class="o">(</span> <span class="nv">$result</span> <span class="k">IN</span> <span class="nv">$results</span> <span class="o">)</span> <span class="o">{</span> <span class="c1"># Generate a output file path</span> <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$timestring</span> <span class="o">=</span> <span class="s1">'{0:yyyyMMdd-HHmmssfff}'</span> -f <span class="o">[</span>datetime]<span class="nv">$result</span>.timestamp <span class="o">[</span><span class="kt">string</span><span class="o">]</span><span class="nv">$outfile</span> <span class="o">=</span> <span class="s2">"</span><span class="nv">$outpath$instance_$timestring</span><span class="s2">-"</span> + <span class="o">((</span>Get-Random<span class="o">)</span> % 100<span class="o">)</span>.ToString<span class="o">()</span> + <span class="s2">"_deadlock.xdl"</span> <span class="nb">Write-Host</span> <span class="s2">"Writing file: </span><span class="nv">$outfile</span><span class="s2">"</span> <span class="k">try</span> <span class="o">{</span> <span class="nb">Out-File</span> -InputObject <span class="o">(</span><span class="nv">$result</span>.deadlockReport<span class="o">)</span> -FilePath <span class="nv">$outfile</span> <span class="o">}</span> <span class="k">catch</span> <span class="o">{</span> <span class="nb">Write-Host</span> <span class="s2">"Writing file </span><span class="nv">$outfile</span><span class="s2"> failed: </span><span class="nv">$_</span><span class="s2">"</span> <span class="o">}</span> <span class="o">}</span></code></pre></figure> <h2 id="final-thoughts">Final Thoughts</h2> <p>This post was inspired by situations I ran into when trying to get XML data off of SQL Server and onto a file share. Hopefully this post helps you avoid some of the issues I ran into. We covered the basics here; there is still a lot of work that could be done to improve this and make it something you might want to run in a production environment. If you wanted to use this in your environment I would suggest looking into the following:</p> <ul> <li><strong>Using parameters in PowerShell</strong> This would allow you to pass in an instance name and output file path.</li> <li><strong>Using the asynchronous file target</strong> This is a much more efficient method of getting data out of system health, especially if you use the offset method described in the sqlskills.com article below.</li> </ul> <h2 id="resources">Resources</h2> <p><a href="https://www.sqlskills.com/blogs/jonathan/an-xevent-a-day-6-of-31-targets-week-asynchronous_file_target/">An XEvent a Day (6 of 31) – Targets Week – asynchronous_file_target</a> @ www.sqlskills.com</p> <p><a href="https://technet.microsoft.com/en-us/magazine/jj554301.aspx">Windows PowerShell: Defining Parameters</a> @ technet.microsoft.com</p> <p><a href="https://msdn.microsoft.com/en-us/library/ms191474%28v=sql.110%29.aspx">query() Method (xml Data Type)</a> @ msdn.microsoft.com</p> <p><a href="https://msdn.microsoft.com/en-us/library/ms178030%28v=sql.110%29.aspx">value() Method (xml Data Type)</a> @ msdn.microsoft.com</p> Reduce SQL Agent Job Overlaps 2015-04-22T00:00:00+00:00 https://m82labs.com/reduce_agent_job_overlap Could overlapping jobs be slowing you down? <p>When you notice a performance issue on an instance, what is your first instinct? I would say the majority of DBAs would start looking at the user and application processes the were running against the instance. While it’s a pretty safe bet to make, how do you know you’re not a part of the problem?</p> <p>When was the last time you looked at your SQL Agent jobs? Do you have any jobs with overlapping execution times? I’m not just talking about jobs using the same schedule, but jobs that overlap every tenth execution, or every fourth. If you have one or two instances to manage it can be a trivial task to check this out, there are even a few pieces of software that can help. But what if you manage 100+ instances, with 100 jobs each? In this post we’ll go over a custom built solution developed just for such a case.</p> <h3 id="overview">Overview</h3> <p>The general concept is straight forward: We will calculate and add a delay to the execution of each job in such a way that we get the least amount of overlapping executions. We do this by getting all job execution data for a 24 hour period and then we add a small (ever increasing) delay to each job until we reach the lowest level of overlaps possible. This delay information is then stored in a table on the instance and is used by a ‘Delay’ step added to each job to delay job execution by the amount specified.</p> <h3 id="the-moving-parts">The Moving Parts</h3> <p>There are a few moving parts to this solution:</p> <ul> <li>[JobDelay] table</li> <li>[AddJobDelay] stored procedure</li> <li>[GetJobData] stored procedure</li> <li>Overlap Checker C# console app</li> </ul> <p><strong>JobDelay Table</strong>: This table stores the job name and an integer representing the number of seconds to delay each execution of the job.</p> <p><strong>AddJobDelay Stored Procedure</strong>: This procedure loops through all jobs on the instance and adds a new ‘Delay’ step as the first step of the job. This step executes the following code:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">DECLARE</span> <span class="o">@</span><span class="n">delay</span> <span class="n">INT</span> <span class="o">=</span> <span class="k">NULL</span><span class="p">;</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">waitfor</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">8</span><span class="p">);</span> <span class="k">SELECT</span> <span class="o">@</span><span class="n">delay</span> <span class="o">=</span> <span class="n">delay_sec</span> <span class="k">FROM</span> <span class="n">JobDelay</span> <span class="k">WHERE</span> <span class="n">job_name</span> <span class="o">=</span> <span class="s1">'[job name goes here]'</span> <span class="k">SET</span> <span class="o">@</span><span class="n">waitfor</span> <span class="o">=</span> <span class="k">LEFT</span><span class="p">(</span><span class="n">DATEADD</span><span class="p">(</span><span class="k">second</span><span class="p">,</span><span class="k">ISNULL</span><span class="p">(</span><span class="o">@</span><span class="n">delay</span><span class="p">,</span><span class="mi">0</span><span class="p">),</span><span class="k">CAST</span><span class="p">(</span><span class="s1">'00:00:00'</span> <span class="k">AS</span> <span class="n">TIME</span><span class="p">)),</span><span class="mi">8</span><span class="p">);</span> <span class="n">WAITFOR</span> <span class="n">DELAY</span> <span class="o">@</span><span class="n">waitfor</span><span class="p">;</span></code></pre></figure> <p>Because I didn’t want to have to keep track of job ids, this solution requires that you use unique job names. Which is arguably something you should be doing anyhow.</p> <p><strong>GetJobData Stored Procedure</strong>: This procedure returns one row for every job execution scheduled for the next 24 hours. Currently it does not pay attention to the time of day that a job can run (coming in a future version) it just assumes all jobs execute on a 24 hour schedule. As an example, if a job executes every 15 minutes, you would see 96 rows for this job. Along with executions, this proc also determines the average duration for the job (minus the delay step), this is very important later in the process.</p> <p><strong>Overlap Checker</strong>: This is a C# console app that takes the data from the <code class="highlighter-rouge">GetJobData</code> stored procedure and calculates the optimal delay for each job. Here is an overview of what this program is doing (with as little detail as I can muster):</p> <ol> <li>Get job information via `GetJobData` stored procedure</li> <li>For each unique job in the result set: <ul> <li>Get all the job executions for the current job, including the start and estimated end time for each execution.</li> <li>Get all execution times for all other jobs on the instance, getting the start and estimated end time, taking into account any delays that have already been calulcated.</li> <li>For each execution of the current job, check for overlaps with the rest of the executions.</li> <li>If there are any overlaps, store the overlap count and add a small delay to each execution of the current job.</li> <li>Check for overlaps again, if there are fewer overlaps (but more than zero), store the delay temporarily and repeat the previous step.</li> <li>Continue looping until we get to 0 overlaps, OR our delay has reached 50% of the interval between job executions. For example, if a job executes every 10 minutes, the delay would never be longer than 5 minutes. Because we are only storing the delay amount if the overlap count lowers, we should end up with the least amount of delay for the least amount of overlaps.</li> </ul> </li> <li>Once all delays are calculated, they are inserted into the `JobDelay` table on the instance.</li> </ol> <h3 id="assumptionslimitations">Assumptions/Limitations</h3> <p>In order for this to work we have to operate under a few assumptions:</p> <ul> <li>Jobs don’t need to execute <em>exactly</em> when they were defined to run</li> <li>There is currently enough job history data in <code class="highlighter-rouge">msdb</code> to be considered representative of a typical day</li> <li>We don’t care about reducing overlaps of jobs that execute every minute, or every twelve hours.</li> </ul> <p>Limitations:</p> <ul> <li>All jobs must be uniquely named</li> <li>Jobs with multiple schedules are currently ignored</li> </ul> <h3 id="outcome-and-thoughts">Outcome and Thoughts</h3> <p>Overall this solution has worked great. We saw an overall CPU reduction and “smoothing” effect on CPU spikes. I did doubt the effects at first, but turning the delays off quickly proved me wrong. Most jobs never see a delay more than 10-100 seconds, and overall this process only takes ~1 minute to execute per instance.</p> <p>There was a big focus on getting execution times down on the application portion of this because I wanted to be able to run it directly on the instance. The initial version of this solution relied on pure TSQL and took ~45 minutes to execute, subsequent iterations used PowerShell which got it down to ~15 miuntes, and finally C# which got the execution times down to 30-45 seconds on average. Because of the amount of looping that occurs, moving this into a C# app was the right thing to do.</p> <h3 id="future-plans">Future Plans</h3> <p><strong>Exclusions</strong>: The case has not yet come up where we need a job excluded from getting a delay assigned to it, but it is bound to happen. To accommodate this I will eventually be adding an exclusions table to each instance. It will likely be replicated or kept in sync between instances in some other fashion (I’m all about centralized management).</p> <p><strong>Move More Into The App</strong>: I may also look into moving even more of the processing work into the C# app, currently I am using some CTE magic to extrapolate the job execution times based on the start date and execution interval, but this could easily be done in the app, and with less CPU overhead.</p> <p><strong>Multiple Schedule Support</strong>: Eventually I want to add support for jobs with multiple schedules. To be honest it was something I didn’t think about until the end, and in our environment we don’t have many jobs using multiple schedules.</p> <p><strong>Support For Execution Periods</strong>: <strike>If a job is set to run every 15 minutes between 9am and 5pm, the overlap checker still treats it like it executes every 15 minutes all day long. This isn't an issue in my current environment but I will be adding support for this in future versions.</strike> <strong>THIS FUNCTIONALITY HAS BEEN ADDED</strong></p> <p>Eventually this code will be incorporated into a bigger project to create a central job management system (similar features to the MSX/TSX framework currently available on EE, but not requiring EE). When that happens it will open up the option to run this across an entire environment, this would allow you to reduce overlap on IO/CPU/Network intensive jobs across all instances to reduce load on your SAN, and network. Stay tuned for updates!</p> <h3 id="the-code">The Code</h3> <p>I created a new GitHub repo for this project. All code is available there, along with a README that walks you through installation. Keep an eye on this repo for changes: <a href="https://github.com/m82labs/overlap_checker">https://github.com/m82labs/overlap_checker</a></p> Untangling Dynamic SQL 2015-04-07T00:00:00+00:00 https://m82labs.com/Untangle-Dynamic Dynamic SQL can still be readable. <p>There’s a lot to be said for readability in code. Whenever you’re writing code you should be thinking about readability. Performance is always important, and obviously you want the code to be functionally correct, but if it’s not readable and maintainable you might as well not even write it.</p> <h3 id="dynamic-sql">Dynamic SQL</h3> <p>Dynamic SQL can be challenging to read and challenging to write. I’m not sure I’ve ever met a developer that likes to maintain someone else’s dynamic SQL. But there is something you can do about it, and it might even make dynamic SQL a little bit fun.</p> <p>Here is an example of some dynamic SQL code:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">DECLARE</span> <span class="o">@</span><span class="k">SQL</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="k">MAX</span><span class="p">)</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">ProductID</span> <span class="n">INT</span> <span class="o">=</span> <span class="mi">492</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">MinQuantity</span> <span class="n">INT</span> <span class="o">=</span> <span class="mi">2</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">MaxQuantity</span> <span class="n">INT</span> <span class="o">=</span> <span class="mi">15</span> <span class="k">SET</span> <span class="o">@</span><span class="k">SQL</span> <span class="o">=</span> <span class="s1">'SELECT Product.Name, Product.ProductNumber, '</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">)</span> <span class="o">+</span> <span class="s1">' ProductInventory.LocationID, '</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">)</span> <span class="o">+</span> <span class="s1">' ProductInventory.Quantity, '</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">)</span> <span class="o">+</span> <span class="s1">'</span><span class="se">''</span><span class="s1">'</span> <span class="o">+</span> <span class="k">CONVERT</span><span class="p">(</span><span class="n">VARCHAR</span><span class="p">(</span><span class="mi">32</span><span class="p">),</span><span class="n">GETDATE</span><span class="p">(),</span><span class="mi">121</span><span class="p">)</span> <span class="o">+</span> <span class="s1">'</span><span class="se">''</span><span class="s1"> AS ReportDate '</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">)</span> <span class="o">+</span> <span class="s1">'FROM Production.Product '</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">)</span> <span class="o">+</span> <span class="s1">'JOIN Production.ProductInventory '</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">)</span> <span class="o">+</span> <span class="s1">' ON Product.ProductID = ProductInventory.ProductID '</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">)</span> <span class="o">+</span> <span class="s1">'WHERE 1=1 '</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">)</span> <span class="o">+</span> <span class="k">ISNULL</span><span class="p">(</span><span class="s1">' AND Product.ProductID = '</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span><span class="o">@</span><span class="n">ProductID</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">512</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">),</span><span class="s1">''</span><span class="p">)</span> <span class="o">+</span> <span class="k">ISNULL</span><span class="p">(</span><span class="s1">' AND ProductInventory.Quantity &gt;= '</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span> <span class="o">@</span><span class="n">MinQuantity</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">512</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">),</span> <span class="s1">''</span><span class="p">)</span> <span class="o">+</span> <span class="k">ISNULL</span><span class="p">(</span><span class="s1">' AND ProductInventory.Quantity &lt;= '</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span> <span class="o">@</span><span class="n">MaxQuantity</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">512</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="n">CHAR</span><span class="p">(</span><span class="mi">13</span><span class="p">),</span> <span class="s1">''</span><span class="p">)</span> <span class="k">EXEC</span><span class="p">(</span><span class="o">@</span><span class="k">SQL</span><span class="p">)</span></code></pre></figure> <p>This isn’t likely on your list of queries to run in the future, but it illustrates a point. Dynamic SQL can be ugly. Now, if we follow a few simple formatting guidelines, and add a few instances of REPLACE, we get something much cleaner:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">DECLARE</span> <span class="o">@</span><span class="k">SQL</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="k">MAX</span><span class="p">)</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">ProductID</span> <span class="n">INT</span> <span class="o">=</span> <span class="mi">492</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">MinQuantity</span> <span class="n">INT</span> <span class="o">=</span> <span class="mi">2</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">MaxQuantity</span> <span class="n">INT</span> <span class="o">=</span> <span class="mi">15</span> <span class="k">SET</span> <span class="o">@</span><span class="k">SQL</span> <span class="o">=</span> <span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span> <span class="c1">--=========================================================</span> <span class="s1">' SELECT Product.Name, Product.ProductNumber, ProductInventory.LocationID, ProductInventory.Quantity, "{{Date}}" AS ReportDate --&lt;&lt;-- We use a double-quote FROM Production.Product JOIN Production.ProductInventory ON Product.ProductID = ProductInventory.ProductID WHERE 1=1 {{ProductIDCondition}} {{QuantityGTCondition}} {{QuantityLTCondition}} '</span> <span class="c1">--=========================================================</span> <span class="p">,</span><span class="s1">'{{ProductIDCondition}}'</span><span class="p">,</span><span class="k">ISNULL</span><span class="p">(</span><span class="s1">' AND Product.ProductID = '</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span><span class="o">@</span><span class="n">ProductID</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">512</span><span class="p">)</span> <span class="p">),</span><span class="s1">''</span><span class="p">))</span> <span class="p">,</span><span class="s1">'{{QuantityGTCondition}}'</span><span class="p">,</span><span class="k">ISNULL</span><span class="p">(</span><span class="s1">' AND ProductInventory.Quantity &gt;= '</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span> <span class="o">@</span><span class="n">MinQuantity</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">512</span><span class="p">)</span> <span class="p">),</span> <span class="s1">''</span><span class="p">))</span> <span class="p">,</span><span class="s1">'{{QuantityLTCondition}}'</span><span class="p">,</span><span class="k">ISNULL</span><span class="p">(</span><span class="s1">' AND ProductInventory.Quantity &lt;= '</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span> <span class="o">@</span><span class="n">MaxQuantity</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">512</span><span class="p">)</span> <span class="p">),</span> <span class="s1">''</span><span class="p">))</span> <span class="p">,</span><span class="s1">'{{Date}}'</span><span class="p">,</span><span class="k">CONVERT</span><span class="p">(</span><span class="n">VARCHAR</span><span class="p">(</span><span class="mi">32</span><span class="p">),</span><span class="n">GETDATE</span><span class="p">(),</span><span class="mi">121</span><span class="p">))</span> <span class="p">,</span><span class="s1">'"'</span><span class="p">,</span><span class="s1">'</span><span class="se">''</span><span class="s1">'</span><span class="p">)</span> <span class="c1">--&lt;-- Replace double-quote with a single-quote.</span> <span class="k">EXEC</span><span class="p">(</span><span class="o">@</span><span class="k">SQL</span><span class="p">)</span></code></pre></figure> <h3 id="what-we-did-here">What We Did Here</h3> <ol> <li>Use a single block of SQL with place holders</li> <li>Use double-braced place-holders:</li> <li>Field names/expressions {{fieldName}}</li> <li>Variables/parameters {{@variableName}}</li> <li>Use double quotes in places you would normally use a single quote, then replace at the end. This can make things much easier to look at.</li> </ol> <p>The example above is doing a simple <code class="highlighter-rouge">SELECT</code> from AdventureWorks, which may not be the best use case for this ( Read about why you should be using <code class="highlighter-rouge">sp_executesql</code> here: <a href="http://www.sommarskog.se/dynamic_sql.html">The Curse and Blessings of Dynamic SQL</a> ), but it can be great for maintenance/DBA scripts. I am currently working on a method to script out job creation/modifications using TSQL (blog post coming), here is an example where this formatting really adds clarity to the code:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span> <span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span><span class="k">REPLACE</span><span class="p">(</span> <span class="c1">--=========================================================</span> <span class="s1">' EXEC msdb.dbo.sp_update_schedule @schedule_id={{scheduleID}}, @enabled={{enabled}}, @freq_type={{f_type}}, @freq_interval={{f_interval}}, @freq_subday_type={{f_subday_type}}, @freq_subday_interval={{f_subday_interval}}, @freq_relative_interval={{f_relative_interval}}, @freq_recurrence_factor={{f_rec_factor}}, @active_start_date={{a_start_date}}, @active_end_date={{a_end_date}}, @active_start_time={{a_start_time}}, @active_end_time={{a_end_time}}; '</span> <span class="c1">--=========================================================</span> <span class="p">,</span><span class="s1">'{{scheduleID}}'</span><span class="p">,</span><span class="n">schedule_id</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{enabled}}'</span><span class="p">,</span><span class="n">enabled</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{f_type}}'</span><span class="p">,</span><span class="n">freq_type</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{f_interval}}'</span><span class="p">,</span><span class="n">freq_interval</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{f_subday_type}}'</span><span class="p">,</span><span class="n">freq_subday_type</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{f_subday_interval}}'</span><span class="p">,</span><span class="n">freq_subday_interval</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{f_relative_interval}}'</span><span class="p">,</span><span class="n">freq_relative_interval</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{f_rec_factor}}'</span><span class="p">,</span><span class="n">freq_recurrence_factor</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{a_start_date}}'</span><span class="p">,</span><span class="n">active_start_date</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{a_end_date}}'</span><span class="p">,</span><span class="n">active_end_date</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{a_start_time}}'</span><span class="p">,</span><span class="n">active_start_time</span><span class="p">)</span> <span class="p">,</span><span class="s1">'{{a_end_time}}'</span><span class="p">,</span><span class="n">active_end_time</span><span class="p">)</span> <span class="k">FROM</span> <span class="n">msdb</span><span class="p">.</span><span class="n">dbo</span><span class="p">.</span><span class="n">sysschedules</span> <span class="k">WHERE</span> <span class="n">name</span> <span class="o">=</span> <span class="s1">'MyTestSchedule'</span><span class="p">;</span></code></pre></figure> <h3 id="conclusion">Conclusion</h3> <p>Once you start using this format, it’s hard to do it any other way. I was introduced to a version of this by the great Jeff Moden ( <a href="http://www.sqlservercentral.com/Authors/Articles/Jeff_Moden/80567/">See him @ SQLServerCentral</a> ) and I haven’t looked back since. Not only does this method make your code easier to read, it can also minimize the amount of time you spend hunting down unclosed single quotes, missing spaces, and all the other stuff that makes dynamic SQL so much “fun” to work with.</p> EXISTS Optimizations 2015-02-24T00:00:00+00:00 https://m82labs.com/exists What's the best way to write an EXISTS clause? <p>If you’ve done any amount of SQL development, you’ve probably seen an <code class="highlighter-rouge">EXISTS</code> clause. It might have been part of an <code class="highlighter-rouge">IF</code> statement, or a <code class="highlighter-rouge">WHERE</code> clause, but I’m sure you’ve seen it, and maybe used it yourself. One thing you’ll notice is that all developers have their own way of writing it. Some developers swear by <code class="highlighter-rouge">... EXISTS( SELECT 1 ...</code>, another might use <code class="highlighter-rouge">... EXISTS( SELECT TOP(1) * ...</code>. So what’s the deal? Which method is best?</p> <h3 id="the-setup">The Setup</h3> <p>First things first, lets see some of the different variations of the <code class="highlighter-rouge">EXISTS</code> clause, then we’ll take a look at the execution plans and see what’s going on behind the scenes.</p> <p><sup>*** <em>For these demo scripts we’ll be using the AdventureWorks database.</em></sup></p> <p><sub>Ex. 1: SELECT *</sub></p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">a</span><span class="p">.</span><span class="n">FirstName</span><span class="p">,</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="k">FROM</span> <span class="n">Person</span><span class="p">.</span><span class="n">Person</span> <span class="k">AS</span> <span class="n">a</span> <span class="k">WHERE</span> <span class="k">EXISTS</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">HumanResources</span><span class="p">.</span><span class="n">Employee</span> <span class="k">AS</span> <span class="n">b</span> <span class="k">WHERE</span> <span class="n">a</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="o">=</span> <span class="n">b</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="k">AND</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="o">=</span> <span class="s1">'Johnson'</span> <span class="p">);</span></code></pre></figure> <p><sub>Ex. 2: SELECT TOP(1) *</sub></p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">a</span><span class="p">.</span><span class="n">FirstName</span><span class="p">,</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="k">FROM</span> <span class="n">Person</span><span class="p">.</span><span class="n">Person</span> <span class="k">AS</span> <span class="n">a</span> <span class="k">WHERE</span> <span class="k">EXISTS</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="n">TOP</span><span class="p">(</span><span class="mi">1</span><span class="p">)</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">HumanResources</span><span class="p">.</span><span class="n">Employee</span> <span class="k">AS</span> <span class="n">b</span> <span class="k">WHERE</span> <span class="n">a</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="o">=</span> <span class="n">b</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="k">AND</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="o">=</span> <span class="s1">'Johnson'</span> <span class="p">);</span> <span class="k">GO</span></code></pre></figure> <p><sub>Ex. 3: SELECT TOP(1) with defined column</sub></p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">a</span><span class="p">.</span><span class="n">FirstName</span><span class="p">,</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="k">FROM</span> <span class="n">Person</span><span class="p">.</span><span class="n">Person</span> <span class="k">AS</span> <span class="n">a</span> <span class="k">WHERE</span> <span class="k">EXISTS</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="n">TOP</span><span class="p">(</span><span class="mi">1</span><span class="p">)</span> <span class="n">b</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="k">FROM</span> <span class="n">HumanResources</span><span class="p">.</span><span class="n">Employee</span> <span class="k">AS</span> <span class="n">b</span> <span class="k">WHERE</span> <span class="n">a</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="o">=</span> <span class="n">b</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="k">AND</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="o">=</span> <span class="s1">'Johnson'</span> <span class="p">);</span> <span class="k">GO</span></code></pre></figure> <p><sub>Ex. 4: SELECT 1</sub></p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">a</span><span class="p">.</span><span class="n">FirstName</span><span class="p">,</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="k">FROM</span> <span class="n">Person</span><span class="p">.</span><span class="n">Person</span> <span class="k">AS</span> <span class="n">a</span> <span class="k">WHERE</span> <span class="k">EXISTS</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="mi">1</span> <span class="k">FROM</span> <span class="n">HumanResources</span><span class="p">.</span><span class="n">Employee</span> <span class="k">AS</span> <span class="n">b</span> <span class="k">WHERE</span> <span class="n">a</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="o">=</span> <span class="n">b</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="k">AND</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="o">=</span> <span class="s1">'Johnson'</span> <span class="p">);</span> <span class="k">GO</span></code></pre></figure> <p>I’m sure there are more examples, but this will be enough for our purposes here. Let’s take a look at the plans and io stats for these queries now and see how each performed.</p> <h3 id="the-plans">The Plans</h3> <p>Below is the plan for the first query in our list. Nothing too exciting here:</p> <p><img src="/public/images/Exists-QueryPlan.png" alt="Query Plan" /></p> <h3 id="io-stats">IO Stats</h3> <table> <thead> <tr> <th style="text-align: left">Scan Count</th> <th style="text-align: left">Logical Reads</th> <th style="text-align: left">Physical Reads</th> </tr> </thead> <tbody> <tr> <td style="text-align: left">2</td> <td style="text-align: left">6</td> <td style="text-align: left">0</td> </tr> </tbody> </table> <p>The interesting thing happens when we take a look at the other query plans. Because of optimizations to the <code class="highlighter-rouge">EXISTS</code> clause, all 4 of these queries have an <em>identical</em> execution plan (other that the statement text included in the plan XML of course). From these tests it would seem that the optimizer doesn’t care what you select, it’s just looking at the query predicates to determine if something exists.</p> <p>That sounds fine and good, but what if we make things a little more complicated? Here we are going to create a function that does some pointless work:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">ALTER</span> <span class="k">FUNCTION</span> <span class="n">fnWaitForSomeTime</span><span class="p">(</span> <span class="o">@</span><span class="n">num</span> <span class="n">INT</span> <span class="p">)</span> <span class="k">RETURNS</span> <span class="n">INT</span> <span class="k">AS</span> <span class="k">BEGIN</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">count_num</span> <span class="n">INT</span><span class="p">;</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">loop_i</span> <span class="n">INT</span> <span class="o">=</span> <span class="mi">0</span><span class="p">;</span> <span class="n">WHILE</span> <span class="p">(</span> <span class="o">@</span><span class="n">loop_i</span> <span class="o">&lt;</span> <span class="o">@</span><span class="n">num</span> <span class="p">)</span> <span class="k">BEGIN</span> <span class="k">SET</span> <span class="o">@</span><span class="n">count_num</span> <span class="o">=</span> <span class="p">(</span><span class="k">SELECT</span> <span class="k">COUNT</span><span class="p">(</span><span class="o">*</span><span class="p">)</span> <span class="k">FROM</span> <span class="n">sys</span><span class="p">.</span><span class="n">columns</span><span class="p">);</span> <span class="k">SET</span> <span class="o">@</span><span class="n">loop_i</span> <span class="o">+=</span> <span class="mi">1</span><span class="p">;</span> <span class="k">END</span> <span class="k">RETURN</span> <span class="k">ABS</span><span class="p">(</span><span class="n">CHECKSUM</span><span class="p">(</span><span class="o">@</span><span class="n">count_num</span><span class="p">))</span> <span class="k">END</span></code></pre></figure> <p>To test this function I ran the following:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">TOP</span><span class="p">(</span><span class="mi">1000</span><span class="p">)</span> <span class="n">dbo</span><span class="p">.</span><span class="n">fnWaitForSomeTime</span><span class="p">(</span><span class="mi">10000</span><span class="p">)</span> <span class="k">FROM</span> <span class="n">HumanResources</span><span class="p">.</span><span class="n">Employee</span> <span class="k">AS</span> <span class="n">b</span></code></pre></figure> <p>On my system this ran for 60 seconds before I stopped it. So what happens if we add this to our <code class="highlighter-rouge">EXISTS</code>? What if we also add a CPU heavy <code class="highlighter-rouge">ORDER BY</code>?</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">a</span><span class="p">.</span><span class="n">FirstName</span><span class="p">,</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="k">FROM</span> <span class="n">Person</span><span class="p">.</span><span class="n">Person</span> <span class="k">AS</span> <span class="n">a</span> <span class="k">WHERE</span> <span class="k">EXISTS</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="n">TOP</span><span class="p">(</span><span class="mi">1000</span><span class="p">)</span> <span class="n">dbo</span><span class="p">.</span><span class="n">fnWaitForSomeTime</span><span class="p">(</span><span class="mi">10000</span><span class="p">)</span> <span class="k">FROM</span> <span class="n">HumanResources</span><span class="p">.</span><span class="n">Employee</span> <span class="k">AS</span> <span class="n">b</span> <span class="k">WHERE</span> <span class="n">a</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="o">=</span> <span class="n">b</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="k">AND</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="o">=</span> <span class="s1">'Johnson'</span> <span class="k">ORDER</span> <span class="k">BY</span> <span class="n">HASHBYTES</span><span class="p">(</span><span class="s1">'MD5'</span><span class="p">,</span><span class="k">CAST</span><span class="p">(</span><span class="n">CHECKSUM</span><span class="p">(</span><span class="n">NEWID</span><span class="p">())</span> <span class="k">AS</span> <span class="n">varbinary</span><span class="p">))</span> <span class="p">);</span> <span class="k">GO</span></code></pre></figure> <p>Lets see the plan:</p> <p><img src="/public/images/Exists-QueryPlan.png" alt="Query Plan" /></p> <p>Notice anything familiar? Again we have the exact same plan. If you run this script yourself you’ll see that it also takes the same amount of time to execute as the rest.</p> <p>To take this a little further, lets try something we know shouldn’t work (Thanks <a href="http://sqlstudies.com/about/">Kenneth Fischer</a> for this great example!):</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">SELECT</span> <span class="n">a</span><span class="p">.</span><span class="n">FirstName</span><span class="p">,</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="k">FROM</span> <span class="n">Person</span><span class="p">.</span><span class="n">Person</span> <span class="k">AS</span> <span class="n">a</span> <span class="k">WHERE</span> <span class="k">EXISTS</span> <span class="p">(</span> <span class="k">SELECT</span> <span class="mi">1</span><span class="o">/</span><span class="mi">0</span> <span class="c1">-- &lt;---- What?!</span> <span class="k">FROM</span> <span class="n">HumanResources</span><span class="p">.</span><span class="n">Employee</span> <span class="k">AS</span> <span class="n">b</span> <span class="k">WHERE</span> <span class="n">a</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="o">=</span> <span class="n">b</span><span class="p">.</span><span class="n">BusinessEntityID</span> <span class="k">AND</span> <span class="n">a</span><span class="p">.</span><span class="n">LastName</span> <span class="o">=</span> <span class="s1">'Johnson'</span> <span class="p">);</span> <span class="k">GO</span></code></pre></figure> <p>Again, same plan, same execution time, and no error. This example just further illustrates that the optimizer doesn’t care what you are selecting in an <code class="highlighter-rouge">EXISTS</code> clause, it only cares about the predicate.</p> <h3 id="conclusion">Conclusion</h3> <p>We looked at a few variations of the <code class="highlighter-rouge">EXISTS</code> clause, and then saw how SQL Server handles them. Due to some nice optimizations SQL seems to do the least amount of work possible to check if something exists. This means that it is really up to you and your team to decide which is the most readable.</p> <p>Personally I like to avoid <code class="highlighter-rouge">*</code> whenever I can, even if it doesn’t cause a performance hit, so I tend to use the syntax in example 4 <code class="highlighter-rouge">... EXISTS( SELECT 1 ...</code>.</p> Wanted: A Mentor 2015-02-15T00:00:00+00:00 https://m82labs.com/mentor-me <p>Mark Wilkinson, a budding DBA in Raleigh North Carolina, is looking for a skilled mentor to help him shape his future.</p> <p>Qualified candidates must be able to provide guidance in some of the following areas:</p> <ul> <li>Public speaking</li> <li>Writing for both blogs and books</li> <li>Managing teams</li> <li>Starting a business</li> <li>Time management</li> <li>Mentoring</li> </ul> <p>This is a 2 month position with optional email follow-ups after the term has ended. Works hours are flexible. This is a non-paid position, you will also not qualify for any benefits ( medical, health, dental, etc. ). You will however, get to enjoy the feeling of knowing that you have contributed to the future of an individual that gives back to the community when he can, and will likely go on to mentor future generations.</p> <p>Founded in 1982, in Ypslianti Michigan, Mark Wilkinson is a “jack-of-all-trades” DBA. He has interests in all things development, technology, and databases. Outside of technology his interests include music, food, and playing various imaginary games with his children.</p> <p>As a mentor you will get to see Mark work towards his goals of becoming a senior level DBA, becoming an authoritative voice in the SQL community, and someday, founding a non-profit to train children and teens in technological fields.</p> <p>If you wish to apply for this position, please contact Mark Wilkinson at <a href="mailto:mark@m82labs.com">mark@m82labs.com</a>.</p> <p><sup>* This post is a response to a post by Paul Randal: <a href="http://www.sqlskills.com/blogs/paul/want-mentored/">Want to be mentored by me?</a></sup></p> Visualizing Statistics in SSMS 2014-09-11T00:00:00+00:00 https://m82labs.com/SSMS-Visualization Using the geometry data type to visualize statistics data in SSMS. <h3 id="dbcc-show_statistics">DBCC SHOW_STATISTICS</h3> <p>While it may not be fun, running <a href="http://msdn.microsoft.com/en-us/library/ms174384.aspx">DBCC SHOW_STATISTICS</a> can tell you a lot about how the query optimizer might use a given index, or why certain queries are more susceptible to parameter sniffing.</p> <p>If you are the visual type like myself you have probably taken the output from this command and pasted it into Excel to create a bar chart. This can be an extremely easy way to get a quick look at the statistics to see how evenly the column values are distributed in the B-Tree, but who wants to waste time opening Excel?</p> <p>With the following script you can use SSMS’s built-in drawing capabilities to create a histogram you can view right inside SSMS:</p> <figure class="highlight"><pre><code class="language-sql" data-lang="sql"><span class="k">DECLARE</span> <span class="o">@</span><span class="n">TableName</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">128</span><span class="p">)</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">StatisticsName</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">128</span><span class="p">)</span> <span class="k">SET</span> <span class="o">@</span><span class="n">TableName</span> <span class="o">=</span> <span class="s1">''</span> <span class="k">SET</span> <span class="o">@</span><span class="n">StatisticsName</span> <span class="o">=</span> <span class="s1">''</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">SQLCmd</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">2048</span><span class="p">)</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">ScaleFactor</span> <span class="n">NUMERIC</span><span class="p">(</span><span class="mi">8</span><span class="p">,</span><span class="mi">8</span><span class="p">)</span> <span class="k">DECLARE</span> <span class="o">@</span><span class="n">StatH</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="k">MAX</span><span class="p">)</span> <span class="cm">/* This script will draw a graphical histrogram for the given statistics. Just provide a table name, and the name of the statistics you are interested in and you will get a bar chart of the value distribution. After executing the script, click on the "spatial results" tab to see the chart. */</span> <span class="k">CREATE</span> <span class="k">TABLE</span> <span class="o">#</span><span class="n">histogram</span> <span class="p">(</span> <span class="n">ID</span> <span class="n">INT</span> <span class="k">IDENTITY</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">1</span><span class="p">),</span> <span class="p">[</span><span class="n">RANGE_HI_KEY</span><span class="p">]</span> <span class="n">SQL_VARIANT</span><span class="p">,</span> <span class="p">[</span><span class="n">RANGE_ROWS</span><span class="p">]</span> <span class="n">SQL_VARIANT</span><span class="p">,</span> <span class="p">[</span><span class="n">EQ_ROWS</span><span class="p">]</span> <span class="n">SQL_VARIANT</span><span class="p">,</span> <span class="p">[</span><span class="n">DISTINCT_RANGE_ROWS</span><span class="p">]</span> <span class="n">SQL_VARIANT</span><span class="p">,</span> <span class="p">[</span><span class="n">AVG_RANGE_ROWS</span><span class="p">]</span> <span class="n">SQL_VARIANT</span> <span class="p">)</span> <span class="k">SET</span> <span class="o">@</span><span class="n">SQLCmd</span> <span class="o">=</span> <span class="s1">'DBCC SHOW_STATISTICS ("'</span><span class="o">+</span> <span class="o">@</span><span class="n">TableName</span> <span class="o">+</span> <span class="s1">'","'</span> <span class="o">+</span> <span class="o">@</span><span class="n">StatisticsName</span> <span class="o">+</span> <span class="s1">'") WITH HISTOGRAM'</span> <span class="k">INSERT</span> <span class="k">INTO</span> <span class="o">#</span><span class="n">histogram</span> <span class="k">EXEC</span><span class="p">(</span><span class="o">@</span><span class="n">SQLCmd</span><span class="p">);</span> <span class="c1">--== To keep things visible I scale the RANGE_ROWS value</span> <span class="c1">--== down if needed</span> <span class="k">SET</span> <span class="o">@</span><span class="n">ScaleFactor</span> <span class="o">=</span> <span class="p">(</span><span class="k">SELECT</span> <span class="k">CASE</span> <span class="k">WHEN</span> <span class="k">MAX</span><span class="p">(</span><span class="k">CAST</span><span class="p">(</span><span class="n">RANGE_ROWS</span> <span class="k">AS</span> <span class="n">BIGINT</span><span class="p">)</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span><span class="n">EQ_ROWS</span> <span class="k">AS</span> <span class="n">BIGINT</span><span class="p">))</span> <span class="o">&gt;</span> <span class="mi">100</span> <span class="k">THEN</span> <span class="mi">100</span><span class="p">.</span><span class="mi">0</span><span class="o">/</span><span class="p">(</span><span class="k">MAX</span><span class="p">(</span><span class="k">CAST</span><span class="p">(</span><span class="n">RANGE_ROWS</span> <span class="k">AS</span> <span class="n">BIGINT</span><span class="p">)</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span><span class="n">EQ_ROWS</span> <span class="k">AS</span> <span class="n">BIGINT</span><span class="p">)))</span> <span class="k">ELSE</span> <span class="mi">1</span> <span class="k">END</span> <span class="k">FROM</span> <span class="o">#</span><span class="n">histogram</span><span class="p">)</span> <span class="c1">--== This constructs an enormous string of coordinates, one</span> <span class="c1">--== set per shape:</span> <span class="k">SET</span> <span class="o">@</span><span class="n">StatH</span> <span class="o">=</span> <span class="n">STUFF</span><span class="p">(</span> <span class="p">(</span><span class="k">SELECT</span> <span class="s1">',(('</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span> <span class="n">ID</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">30</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="s1">' 0,'</span> <span class="o">+</span> <span class="c1">-- Bottom left</span> <span class="k">CAST</span><span class="p">(</span> <span class="n">ID</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">30</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="s1">' '</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span> <span class="k">CAST</span><span class="p">(</span><span class="n">RANGE_ROWS</span> <span class="k">AS</span> <span class="n">BIGINT</span><span class="p">)</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span><span class="n">EQ_ROWS</span> <span class="k">AS</span> <span class="n">BIGINT</span><span class="p">)</span> <span class="o">*</span> <span class="o">@</span><span class="n">ScaleFactor</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">30</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="s1">','</span> <span class="o">+</span> <span class="c1">-- Top Left</span> <span class="k">CAST</span><span class="p">(</span> <span class="n">ID</span> <span class="o">+</span> <span class="p">.</span><span class="mi">75</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">30</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="s1">' '</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span> <span class="k">CAST</span><span class="p">(</span><span class="n">RANGE_ROWS</span> <span class="k">AS</span> <span class="n">BIGINT</span><span class="p">)</span> <span class="o">+</span> <span class="k">CAST</span><span class="p">(</span><span class="n">EQ_ROWS</span> <span class="k">AS</span> <span class="n">BIGINT</span><span class="p">)</span> <span class="o">*</span> <span class="o">@</span><span class="n">ScaleFactor</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">30</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="s1">','</span> <span class="o">+</span> <span class="c1">-- Top Right</span> <span class="k">CAST</span><span class="p">(</span> <span class="n">ID</span> <span class="o">+</span> <span class="p">.</span><span class="mi">75</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">30</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="s1">' 0,'</span> <span class="o">+</span> <span class="c1">--Bottom Right</span> <span class="k">CAST</span><span class="p">(</span> <span class="n">ID</span> <span class="k">AS</span> <span class="n">VARCHAR</span><span class="p">(</span><span class="mi">30</span><span class="p">)</span> <span class="p">)</span> <span class="o">+</span> <span class="s1">' 0))'</span> <span class="c1">-- Back to the start, bottom left</span> <span class="k">FROM</span> <span class="o">#</span><span class="n">histogram</span> <span class="k">ORDER</span> <span class="k">BY</span> <span class="n">ID</span> <span class="k">FOR</span> <span class="n">XML</span> <span class="n">PATH</span><span class="p">(</span><span class="s1">''</span><span class="p">)),</span> <span class="mi">1</span><span class="p">,</span> <span class="mi">1</span><span class="p">,</span> <span class="s1">''</span><span class="p">);</span> <span class="c1">--== MULTIPOLYGON allows us to draw multiple shapes from</span> <span class="c1">--== a single string</span> <span class="k">SELECT</span> <span class="n">geometry</span><span class="p">::</span><span class="n">STGeomFromText</span><span class="p">(</span> <span class="s1">'MULTIPOLYGON('</span> <span class="o">+</span> <span class="o">@</span><span class="n">StatH</span> <span class="o">+</span> <span class="s1">')'</span><span class="p">,</span> <span class="mi">0</span> <span class="p">)</span> <span class="k">AS</span> <span class="n">GraphData</span><span class="p">;</span> <span class="c1">--== Dumping the raw histogram data as well</span> <span class="k">SELECT</span> <span class="n">ID</span><span class="p">,</span> <span class="n">RANGE_HI_KEY</span><span class="p">,</span> <span class="n">RANGE_ROWS</span><span class="p">,</span> <span class="n">EQ_ROWS</span> <span class="k">FROM</span> <span class="o">#</span><span class="n">histogram</span><span class="p">;</span> <span class="k">DROP</span> <span class="k">TABLE</span> <span class="o">#</span><span class="n">histogram</span><span class="p">;</span></code></pre></figure> <p>To use the above query simply input the table and statistics you are interested in seeing and execute it, the graphical histogram will appear in the “Spatial Results” tab. For this example we are going to use the AdventureWorks2012 database and take a look at the statistics for the IX_SalesOrderDetail_ProductID on the Sales.SalesOrderDetail table:</p> <p><img src="/public/images/SSMS_Statistics-04.png" alt="Statistic Histogram" /></p> <p>In the image above you can see the “Spatial Results” tab at the top, and the graphical view of the histogram in the results area. Each line in the chart represents a step in the histogram. Using this quick visual tool you can eaily see how “balanced” your histogram is. In cases where it is highly unbalanced, like in the example, queries written that use compare a parameter value to the value in this column could be highly susceptible to poor parameter sniffing.</p> <h3 id="so-how-does-this-all-work">So how does this all work?</h3> <p>The Spatial Results tab shows geometric (spatial) data. Spatial data is great for storing things like map data, but in the end it’s just a collection of connected points on a plane. What the above script is doing is simply plotting out a line for each step in the histogram and drawing it as a narrow box. When all the boxes are arranged next to eachother we end up with a bar chart.</p> <h4 id="further-resources">Further Resources</h4> <p>Statistics are an interesting and important component of SQL Server, below are some resources to help you better understand statistics as well as learn more about displaying spatial data in SSMS.</p> <p><a href="http://www.sqlpassion.at/archive/2014/01/28/inside-the-statistics-histogram-density-vector/">Inside the Statistics Histogram &amp; Density Vector</a> @ www.sqlpassion.at/</p> <p><a href="https://www.simple-talk.com/sql/learn-sql-server/statistics-in-sql-server/">Statistics in SQL Server</a> @ www.simple-talk.com</p> <p><a href="http://sqlmag.com/t-sql/generating-charts-and-drawings-sql-server-management-studio">Generating Charts and Drawings in SQL Server Management Studio</a> @ www.sqlmag.com</p> <p><a href="http://www.brentozar.com/archive/2013/06/the-elephant-and-the-mouse-or-parameter-sniffing-in-sql-server/">The Elephant and the Mouse, or, Parameter Sniffing in SQL Server</a> @ www.brentozar.com</p> What I Learned Giving My First Presentation 2014-05-20T00:00:00+00:00 https://m82labs.com/What-I-Learned-Giving-My-First-Presentation SQL Saturday 292, Detroit - There is a real sense of community in the SQL world, and it really shows at events like this. <h2 id="sql-saturday-292-detroit">SQL Saturday 292: Detroit</h2> <p>Recently I had the privilege of speaking at PASS SQL Saturday #292 in Detroit; I presented a session on the importance of monitoring: <a href="http://sqlsaturday.com/viewsession.aspx?sat=292&amp;sessionid=20890">What Just Happened?</a>. This was my first time presenting to a room of people I had never met before, it was also the first SQL Saturday I had ever attended, and it was a great experience. There is a real sense of community in the SQL world, and it really shows at events like this.</p> <p>Grant Fritchey mentioned this in both of his sessions, but it really needs to be repeated: All of the attendees/volunteers (and most of the speakers) at SQL Saturday are not being paid, and are sacrificing their own free time to teach and learn about SQL Server on a Saturday. As Grant put it, this makes those attendees some of the most valuable people in the market. They are people that are willing to give up some of their own time to better themselves and learn something new.</p> <h3 id="what-i-learnedwhat-worked-for-me">What I Learned/What Worked for Me</h3> <p>My session went better than I could have hoped, I got some great attendee feedback (both positive and constructive) and look forward to speaking at future SQL Saturdays and user group meetings. While preparing for and delivering the presentation, and while listening to other presenters, I learned a lot about what makes for a good session, and what I shouldn’t have wasted my time on.</p> <h4 id="be-gracious">Be Gracious</h4> <p>Thank EVERYBODY. Without everybody at the event, you wouldn’t be there. Every single person at these events is important. Without the hard work of the volunteers and your fellow speakers, there wouldn’t be an event. Without the time sacrifice of your audience, you wouldn’t have anyone to present to. Don’t just remember this in the back of your mind, actually go and thank these people. Shake their hands and thank them.</p> <h4 id="ask-other-speakers-what-to-expect">Ask Other Speakers What to Expect</h4> <p>Ask around and see who the typical audience is in a “beginner” session. I thought I knew, but after starting my presentation I found out I was wrong. I found out that my definition of “beginner” might be a little closer to intermediate. When I started asking questions I was getting fewer raised hands and head nods than I thought I might, this actually made me more excited to present. It was cool to know that some of the attendees were being exposed to brand new concepts in my session. This was unexpected but in my mind it was a bonus.</p> <h4 id="do-your-research">Do Your Research</h4> <p>As I said above, you might have the opportunity to expose people to ideas that are brand new to them; make sure you get it right. While it is perfectly fine to answer a question with “I am not sure, I will have to get back to you on that.” it isn’t perfectly fine to guess and possibly give someone bad information.</p> <h4 id="check-in-with-your-audience">Check in with Your Audience</h4> <p>Get a pulse on your audience from time to time, reel them back into the presentation. Before I would start covering a new topic I would poll the audience to see how many of them were familiar with it. Not only does this bring the attention of the audience back to you, it can also help you determine how you are going to cover the next topic. For example, many of the attendees in my session had never heard of wait statistics, so it wouldn’t make much sense for me to launch right into a discussion of the sys.dm_os_wait_stats DMV without first explaining a bit about what it means when a query is “waiting”.</p> <h4 id="break-things-up">Break Things Up</h4> <p>I am always a fan of well-placed humor, and it can do wonders to revitalize the audience. If humor isn’t your thing, try to get some other type of interaction out of the audience. Ask questions about situations they have been in that are similar to those you are presenting, ask them for guesses “What do you think lock wait types tell us?”, or as I mentioned above just ask them if they are familiar with the concept you are covering.</p> <h4 id="be-prepared">Be Prepared</h4> <p>Get to the venue early. Make sure you have enough time to get everything open and ready. Nobody in the audience wants to watch you fiddle around waiting for SSRS to spool up, or watch you frantically searching your hard drive for that missing demo script. On the same note, make sure you have a backup if your demo doesn’t work. If your demo bombs, at least make sure to have some screen shots to show what the audience would have seen.</p> <h4 id="dont-over-prepare">Don’t Over Prepare</h4> <p>Preparation is great, do as much research as you need. Just don’t try to write down every last word you plan on saying. If you spend time trying to “remember your line” you will likely just end up with a lot of “uh…” and “um…” moments in your presentation. If you instead just focus on KNOWING the topic, you can focus on the facts and worry less about exactley how to say it. Presenting is just talking, but to a larger group of people than you might be used to.</p> <h4 id="be-gracious-1">Be Gracious</h4> <p>No, this isn’t a typo. This is a point that needs to be repeated. THANK EVERYBODY. Thank the attendees when they come in, thank them when they leave, thank them when they ask questions, or when they correct something you just said, thank the volunteers, thank the vendors, thank the local user group president that put it all together… THANK EVERYBODY.</p> <h3 id="now-go-present">Now Go Present</h3> <p>I highly recommend signing up to present a session at your next SQL Saturday, or User Group meeting. Don’t assume your ideas would be “dumb” or “not technical enough”. Attendees come in at every level of expertise possible, from “this is my first day on the job” to “I have been a production DBA for the past 10 years”. Just find a topic you are passionate about and submit it. If you are passionate about something, and you feel like you could contribute to someone else’s understanding of it, submit a session and see what happens.</p>