Friday, November 18, 2016

Query for Change Data Capture (CDC) tables and columns

Real quickly, I was in need of a query that would give me a listing of the tables and columns involved in Change Data Capture (CDC). I wanted to see the tracked columns in one column to the right of the table name so I utilized FOR XML PATH. Below is what I came up with.

SELECT OBJECT_NAME(source_object_id) [Table Name],
      (SELECT name + ',' FROM sys.columns SC WHERE SC.object_id = CT.object_id AND name NOT LIKE '__$%' FOR XML PATH('')) [Columns],
 capture_instance,
 supports_net_changes,
 filegroup_name
 FROM CDC.change_tables CT


It's certainly not perfect but it should give you a good start if you are ever in need of such a query.

Tuesday, February 23, 2016

List of Users Who Recently Changed Their Password

There may come a time when you need to generate a list of SQL logins and the last time their password was changed. By using the LOGINPROPERTY of the name in sys.server_principals we can generate such a list.

Note: This will only work with SQL logins.

The following query will generate the results below.

SELECT  SP.name
            ,LOGINPROPERTY(SP.name,N'PasswordLastSetTime') 'LastPWReset'
FROM    sys.server_principals SP
WHERE   SP.[type] = 'S'

Thursday, January 14, 2016

Using Extended Events to Find the Actual Execution Plan for a Table Valued Function

While finding the estimated Execution Plan for a Table Valued Function (TVF) isn’t all that difficult, getting to the actual Execution Plan is somewhat of a challenge. Take this example from the AdventureWorks database.
SELECT * FROM ufnGetContactInformation(3)
By clicking on the Display Estimated Execution Plan we get the following:

Estimated:

To get the actual plan, make sure the following option is selected and execute the query.

Actual:

While the estimated gives us all kinds of information, the actual plan keeps the underlying operations hidden in favor of a Clustered Index Scan and a TVF operator. This isn’t very useful when it comes to troubleshooting performance issues especially if your query has multi-table joins to the TVF.
Thankfully, this is where Extended Events (EE) comes into play. By using EE, we can capture the Post Execution Showplan that will give us the actual full plan behind the Clustered Index Scan and TVF operators.
We’ll use the following code to setup the EE:
CREATE EVENT SESSION QueryPlanForTVF ON SERVER
ADD EVENT sqlserver.query_post_execution_showplan (
    ACTION (sqlserver.database_name,sqlserver.plan_handle,sqlserver.sql_text)
    WHERE  (sqlserver.session_nt_user = N'<Your User Name>'))
ADD TARGET package0.ring_buffer
WITH (MAX_MEMORY = 4096 KB
     ,EVENT_RETENTION_MODE = ALLOW_SINGLE_EVENT_LOSS
     ,MAX_DISPATCH_LATENCY = 30 SECONDS
     ,MAX_EVENT_SIZE = 0 KB
     ,MEMORY_PARTITION_MODE = NONE
     ,TRACK_CAUSALITY = OFF
     ,STARTUP_STATE = OFF);
GO

NOTE: This EE can several decrease performance if used on a high transaction environment. It is not recommended to use this in a production environment.
This session will capture the Showplan XML event, as well as the database name, plan handle, and SQL text of the query. The session is filtered on whatever name you choose (I used my NT login name). Finally, the session sends its output to the ring buffer so we can watch it live in SSMS.
Once the session has been created and turned on, right click on the EE and choose the “Watch Live Data” option.

And the following window will open in SSMS.

Now, in another SSMS window, we’ll execute the query with the TVF again and see the following data flow into the live data viewer.

By clicking on the Query Plan tab, we’ll finally see the full execution plan. Since this TVF has several code blocks in it, there are several plans, but I’ll only show the main one here with the knowledge there are several plans.

Check out the following posts for further reading on using Extended Events and the Query_Post_Execution_Showplan event:
Impact of the query_post_execution_showplan Extended Event in SQL Server 2012
Getting Started with Extended Events in SQL Server 2012

Monday, January 11, 2016

Why Isn’t My Filtered Index Working?

With the introduction of filtered indexes in SQL 2008, DBA’s were finally able to create small, well defined indexes with a simple predicate that would allow queries to search a subset of a rows on a table rather than all the rows on a table. While the technology has been around for some time, I haven’t seen them mentioned too often in forums, blogs or newsletters. That said, just the other day I found an occasion to use a filtered index, and after creating it, was left wondering why the query didn’t take advantage of it.

First, let’s set up our test scenario. We’ll be using the Sales.SalesOrderHeader and Sales.SalesOrderDetail tables in the AdventureWorks database. In this case, I’m getting the Sum of each order during a specified time period while specifying whether or not it was an online order.

Here’s the query:

DECLARE @OnlineFlag BIT = 1
DECLARE @StartDate DATETIME = '7/1/2001'
DECLARE @EndDate DATETIME = '7/31/2002'

SELECT SalesOrderHeader.SalesOrderID,
       SUM(SalesOrderDetail.LineTotal)
  FROM Sales.SalesOrderHeader INNER JOIN Sales.SalesOrderDetail
    ON SalesOrderHeader.SalesOrderID = SalesOrderDetail.SalesOrderID
WHERE SalesOrderHeader.OnlineOrderFlag = @OnlineFlag
   AND SalesOrderHeader.OrderDate BETWEEN @StartDate AND @EndDate
GROUP BY SalesOrderHeader.SalesOrderID

The resulting execution plan:

From here, I thought I might be able to use a filtered index on the OnlineOrderFlag in the SalesOrderHeader table.

Here’s the index creation statement:

CREATE NONCLUSTERED INDEX IX_SalesOrderHeader_OnlineOrderFlagFiltered
    ON Sales.SalesOrderHeader(OrderDate,SalesOrderID,OnlineOrderFlag)
 WHERE OnlineOrderFlag = 1

Note the Where statement, this is where the filter comes in to play. Functions like getdate() or dateadd() are not available to use in this context.

Once the filter is added, I think I’m in business, so I execute the query again and get the following execution plan.

But instead of seeing the use of my shiny new filtered index, the query is still using the Clustered Index Scan in addition to a new warning on the SELECT operator. If I click the operator and check the warnings, Unmatched Indexes is showing True.

This warning is telling me that Parameterization is to blame for the filtered index not being used. From here, I see 3 options.

  1. Remove the parameters and use literals. (not practical)
  2. Use Dynamic SQL
  3. Use OPTION(RECOMPILE) at the bottom of the query.

For the purposes of this exercise, I’ll be using OPTION(RECOMPILE) so that the query can take advantage of the filtered index.

Here the query with the added hint:

DECLARE @OnlineFlag BIT = 1
DECLARE @StartDate DATETIME = '7/1/2001'
DECLARE @EndDate DATETIME = '7/31/2002'

SELECT SalesOrderHeader.SalesOrderID,
       SUM(SalesOrderDetail.LineTotal)
  FROM Sales.SalesOrderHeader INNER JOIN Sales.SalesOrderDetail
    ON SalesOrderHeader.SalesOrderID = SalesOrderDetail.SalesOrderID
WHERE SalesOrderHeader.OnlineOrderFlag = @OnlineFlag
   AND SalesOrderHeader.OrderDate BETWEEN @StartDate AND @EndDate
GROUP BY SalesOrderHeader.SalesOrderID
OPTION (RECOMPILE)

And the resulting execution plan:

This solution for your filtered index may or may not be ideal for you because of the added CPU/Compile time added to each execution of the query. That said, if you have wildly varying parameters for each execution of your query, you may have already added OPTION (RECOMPILE) to deal with issues like parameter sniffing.

Here are some fantastic resources if you would like to read further on Filtered Indexes:

Introduction to SQL Server Filtered Indexes

What You Can (and Can’t) Do With Filtered Indexes

Filtered Indexes: What You Need To Know