Showing posts with label TSQL. Show all posts
Showing posts with label TSQL. Show all posts

Tuesday, September 20, 2016

Sometimes I want to run a bunch of statements (like updating a bunch of stats or re-indexing a number of indexes) and I want to reduce the chance that these statements will interfere with other processes in the database. I created a script which loops over each statement to be executed and then checks to see if the database is currently in use (has any "Runnable" processes and if it does, waits until all "Runnable" processes have completed, then runs the statement and then starts over with the next statement.

I know that for many this won't be of value, because your systems are too busy for this to make sense and I also know that a new process could start while I'm running one of my statements, so this isn't fool-proof by any means.
-- ========================================================================
-- Author:  Eric Zierdt
-- Create date: 9/20/2016
-- Description: Checks database for running processes and Runs 
--    series of statements when free and emails when complete
-- ========================================================================


/*********************************************************************
 **  CODE TO CREATE THE TABLE TO STORE THE QUERIES YOU WANT TO RUN **
 *********************************************************************/
/*
IF EXISTS (SELECT * FROM tempdb.dbo.sysobjects WHERE ID = OBJECT_ID(N'tempdb..##TABLE'))
BEGIN
 DROP TABLE ##TABLE
END
CREATE TABLE ##TABLE (ID INT IDENTITY(1,1), Code VARCHAR(MAX),Complete BIT DEFAULT 0)
INSERT INTO ##TABLE
( Code )
VALUES
('UPDATE STATISTICS [Table] [Stat] WITH FULLSCAN')
*/
SET NOCOUNT ON

/*****************************************************************************************
 **  CREATING ##StartTime TABLE TO BE USED IN REMAINING TIME ESTIMATES IN OTHER QUERY. **
 **  SETTING TO GLOBAL TEMP TABLE SO ACCESSABLE IN ANOTHER WINDOW      **
 *****************************************************************************************/
IF EXISTS (SELECT * FROM tempdb.dbo.sysobjects WHERE ID = OBJECT_ID(N'tempdb..##StartTime'))
BEGIN
 DROP TABLE ##StartTime
END
CREATE TABLE ##StartTime (StartTime DATETIME)
INSERT INTO ##StartTime VALUES  ( GETDATE() )
PRINT 'Start Time: ' + CONVERT(VARCHAR(25), GETDATE(), 101) + ' ' + CONVERT(VARCHAR(25), GETDATE(), 108)
GO

/*****************************************************************************************
 **  CREATING ##StartTime TABLE TO BE USED IN REMAINING TIME ESTIMATES IN OTHER QUERY. **
 **  SETTING TO GLOBAL TEMP TABLE SO ACCESSABLE IN ANOTHER WINDOW      **
 *****************************************************************************************/
DECLARE @ID INT
  ,@SQL VARCHAR(MAX)
  ,@StartTime DATETIME = GETDATE()
  ,@EndTime DATETIME
WHILE 
(
 SELECT COUNT(1)
 FROM ##TABLE
 WHERE Complete = 0
) >= 1
BEGIN 
 WHILE 
 (
  /**************************************************************
   **  CHECKING TO SEE IF DATABASE HAS NO 'RUNNABLE' PROCESSES **
   **************************************************************/
  SELECT  COUNT(1)
  FROM    sys.sysprocesses S
  WHERE   status = 'runnable'
    AND DB_NAME(S.dbid) = DB_NAME()
    AND S.spid <> @@SPID
 ) > 0   
 BEGIN   
  WAITFOR DELAY '00:00:05';  ---CHANGE TO MEET YOUR NEEDS; THIS IS SAYING, RETRY EVERY 5 SECONDS TO SEE IF DATABASE IS FREE TO DO WORK
 END
 /*************************************************
  ** NO 'RUNNING' PROCESSES DETECTED, RUN QUERY **
  *************************************************/
 SELECT TOP 1 @ID=ID, @SQL=Code FROM ##TABLE WHERE Complete = 0
 EXEC(@SQL)
 UPDATE ##TABLE SET Complete = 1 WHERE ID = @ID
END

/*********************************************
 ** SET END TIME AND PRINT RUN TIME STATS **
 *********************************************/
SET @EndTime = GETDATE()
PRINT 'End Time: ' + CONVERT(VARCHAR(25), @EndTime, 101) + ' ' + CONVERT(VARCHAR(25), @EndTime, 108)
PRINT 'Run Time: ' + CONVERT(VARCHAR, DATEADD(ms,DATEDIFF(ms,@StartTime,@EndTime),0),108)

/*************
 ** CLEANUP **
 *************/
DROP TABLE ##TABLE
DROP TABLE ##StartTime

/*********************************************
 ** SEND EMAIL NOTIFICATION OF COMPLETION **
 *********************************************/
DECLARE @buffer_memory_used_MB FLOAT
  ,@Body VARCHAR(MAX)
  ,@Subject VARCHAR(255) = 'Auto Run Script Complete'
  ,@To VARCHAR(512) = ''
SET @Body = '

The script has completed processing queries.
Run Time: ' + CONVERT(VARCHAR, DATEADD(ms,DATEDIFF(ms,@StartTime,@EndTime),0),108) + ' ' EXEC msdb.dbo.sp_send_dbmail @recipients = @To , @subject = @Subject , @body = @Body , @body_format = 'HTML'

In another window I will often run this on occasion to get some stats and an idea of how long it will run for:
DECLARE @Completed FLOAT
  ,@CompletedStatements FLOAT
  ,@Total FLOAT
  ,@TotalStatements FLOAT
  ,@PercentComplete FLOAT 
  ,@StartDate DATETIME

SELECT @StartDate=StartTime FROM ##StartTime
DECLARE @RunTime BIGINT = DATEDIFF(SECOND,@StartDate,GETDATE())

SELECT @CompletedStatements = COUNT(1) FROM ##Table WHERE fixed = 1
SELECT @TotalStatements = COUNT(1) FROM ##Table
SELECT @Completed = SUM([RowCount]) FROM ##Table WHERE fixed = 1
SELECT @Total = SUM([RowCount]) FROM ##Table
SELECT @PercentComplete = 100*(@Completed/@Total)
DECLARE @SecondPerRecord FLOAT = CAST(@RunTime AS FLOAT)/@Completed
DECLARE @EstRemainingSeconds BIGINT = @SecondPerRecord*(@Total-@Completed)
SELECT @Total TotalRecords, @Completed CompletedRecords, @TotalStatements as TotalStatements, @CompletedStatements as CompletedStatements, @PercentComplete [% Complete], @RunTime RunTimeSeconds, @SecondPerRecord SecondPerRecord, @EstRemainingSeconds EstRemainingSeconds
  ,@EstRemainingSeconds/60.0 EstRemainingMins, @EstRemainingSeconds/3600.0 EstRemainingHours

Please comment below and let me know if you found value in this post.

Eric

Wednesday, March 9, 2016

Get Fast Rowcount

I came up with this little gem a while ago, I use it when I'm trying to get a rowcount on a large table, where it's so large that it takes a long time for a simple SELECT COUNT(1) FROM xxx to return data.

DECLARE @TableName sysname
SET @TableName = 'TableName'

SELECT SUM(row_count) AS [RowCount]
FROM sys.dm_db_partition_stats
WHERE object_id=OBJECT_ID(@TableName)   
AND (index_id=0 or index_id=1);

Thursday, March 3, 2016

Script - Email on Job Completion

Sometimes I have long running agent jobs (like say a backup job) and I don't want to do work on the server while the specific job is running; so I've come up with a quick and easy script using the sp_send_dbmail ability to monitor for the job completion and then email me. I've done similar things with some manual tasks that take a while (index reindex or update stats) so I am notified when the script completes.

-- ===============================================
-- Author:  Eric Zierdt
-- Create date: 3/3/2016
-- Description: Emails upon agent job completion
-- ===============================================
DECLARE @JOB_NAME SYSNAME = N'AdventureWorks Backup'; -- NAME OF AGENT JOB
 
WHILE EXISTS
(     
 SELECT  1
 FROM    msdb.dbo.sysjobs_view job
 JOIN msdb.dbo.sysjobactivity activity ON job.job_id = activity.job_id
 JOIN msdb.dbo.syssessions session ON session.session_id = activity.session_id
 JOIN ( 
    SELECT   MAX(agent_start_date) AS max_agent_start_date
    FROM     msdb.dbo.syssessions
   ) session_max ON session.agent_start_date = session_max.max_agent_start_date
 WHERE   activity.run_Requested_date IS NOT NULL
   AND activity.stop_execution_date IS NULL
   AND job.name = @JOB_NAME 
   --AND activity.start_execution_date > CAST(GETDATE() AS DATE)
) 
BEGIN      
     WAITFOR DELAY '00:00:45'; -- SET HOW OFTEN YOU WANT YOUR JOB TO CHECK
END 

DECLARE @buffer_memory_used_MB FLOAT
  ,@Body VARCHAR(MAX)
  ,@Subject VARCHAR(255) = 'Job Complete'
  ,@To VARCHAR(512) = 'user@email.com' -- INSERT YOUR EMAIL ADDRESS HERE
SET @Body = '

The monitored job has completed running.' EXEC msdb.dbo.sp_send_dbmail @recipients = @To , @subject = @Subject , @body = @Body , @body_format = 'HTML'

Tuesday, October 13, 2015

Statistic Repository

I have seen posts from many great SQL masters saying that the first thing they do when diagnosing a performance problem is to update the stats or review the stats; I too have seen the power of updated stats, so when an internal customer of mine was having some issues with stats, it became helpful for me to create a Stats Repository to track and monitor changes in statistics.

The idea is, record once a day the stats info on each statistic in a given database, this can be done across servers (Prod, Test, Dev, etc) if you want to compare to see why something runs better on one server and not on another.

The first step is to create a holding table, if you have a DBA database to store maintenance stuff, put it there, but for this post I'll use master:

------------------------------------------------------
-- SETUP STORAGE TABLE TO STORE DAILY STATS DETAILS --
------------------------------------------------------
USE [master]
GO

/****** Object:  Table [dbo].[StatsHistory]  ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

SET ANSI_PADDING ON
GO

CREATE TABLE [dbo].[StatsHistory](
 [ServerName] [sysname] NULL,
 [DatabaseName] [sysname] NULL,
 [TableName] [sysname] NULL,
 [StatName] [sysname] NOT NULL,
 [Updated] [datetime] NULL,
 [TableRows] [int] NULL,
 [RowsSampled] [int] NULL,
 [PercentSampled] [float] NULL,
 [Steps] [int] NULL,
 [Density] [int] NULL,
 [AverageKeyLength] [int] NULL,
 [StringIndex] [varchar](3) NULL,
 [FilterExpression] [varchar](512) NULL,
 [UnfilteredRows] [int] NULL,
 [StatColumns] [varchar](500) NULL,
 [BatchRunID] [int] NULL,
 [CreateDate] [datetime] NULL
) ON [PRIMARY]
The next step is to create a function that will be used to concatenate the columns for the Stat into a list. Because of how sys.stats_columns works, you'll need to put this in every database you want to monitor

-----------------------------------------------------
-- NEEDS TO BE RUN FOR EVERY DB YOU ARE MONITORING --
--     THIS FUNCTION CREATES A LIST OF COLUMNS     --
--       INCLUDED IN THE PASSED IN STATISTIC       --
-----------------------------------------------------

USE []
GO

/****** Object:  UserDefinedFunction [dbo].[StatColumnIDToList]    Script Date: 12/19/2014 10:11:01 ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

-- =============================================
-- Author:  Eric Zierdt
-- Create date: 12/9/2014
-- Description: Converts the ColumnIDs to a List
-- USE: SELECT dbo.StatColumnIDToList(357576312,2)
-- =============================================
CREATE FUNCTION [dbo].[StatColumnIDToList] 
(
 -- Add the parameters for the function here
 @ObjectID INT
 ,@StatsID INT
)
RETURNS VARCHAR(2000)
AS
BEGIN
 -- Declare the return variable here
 DECLARE @List VARCHAR(2000)

 SELECT @List = COALESCE(@List + ',', '') + Cast(SC.column_id As varchar(5))
 FROM sys.stats_columns SC 
 WHERE SC.object_id = @ObjectID AND SC.stats_id = @StatsID

 -- Return the result of the function
 RETURN @List

END
The next step is to create a job which you will schedule to run daily. This job should execute the following code to generate the stat info and insert it into the table we made in step 1:

-- =================================================
-- Author:  Eric Zierdt
-- Create date: 12/9/2014
-- Description: INSERTS STATS DATA INTO REPOSITORY
-- =================================================
DECLARE @ServerName VARCHAR(120)
  ,@DBName VARCHAR(120)
  ,@TableName VARCHAR(120)
  ,@StatName VARCHAR(120)
  ,@SQL VARCHAR(MAX)
  ,@BatchRunID INT
  ,@ColumnList VARCHAR(2000)
  
SELECT @BatchRunID = MAX(BatchRunID)+1
FROM master.dbo.StatsHistory
  

CREATE TABLE #StatsTable (
 ServerName SYSNAME NULL
 ,DatabaseName SYSNAME NULL
 ,TableName SYSNAME NULL
 ,StatName SYSNAME
 ,Updated DATETIME
 ,TableRows INT
 ,RowsSampled INT
 ,PercentSampled AS CAST(RowsSampled AS FLOAT)/CAST(TableRows AS FLOAT)*100 
 ,Steps INT
 ,Density INT
 ,AverageKeyLength INT
 ,StringIndex VARCHAR(3)
 ,FilterExpression VARCHAR(512)
 ,UnfilteredRows INT
 ,StatColumns VARCHAR(500)
 ,BatchRunID INT
 ,CreateDate DATETIME
)

CREATE NONCLUSTERED INDEX [IDX_StatTable_Name] ON #StatsTable
(
 [TableName] ASC
) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF
  , ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [Primary]

DECLARE ZCursor CURSOR LOCAL FAST_FORWARD FOR
(
    SELECT  @@SERVERNAME AS ServerName, DB_NAME() AS DBName, OBJECT_NAME(object_id) AS TableName 
           ,name AS StatName, dbo.StatColumnIDToList(object_id,stats_id)
    FROM    sys.stats
    WHERE   OBJECT_NAME(object_id) NOT LIKE ''sys%''
            AND OBJECT_NAME(object_id) NOT LIKE ''MS%''
            AND OBJECT_NAME(object_id) NOT LIKE ''queue%'' 
            AND OBJECT_NAME(object_id) NOT LIKE ''filestream%'' 
            --AND OBJECT_NAME(object_id) = ''MSdistribution_agents''
)
OPEN ZCursor 
FETCH NEXT FROM ZCursor INTO @ServerName, @DBName, @TableName,@StatName,@ColumnList
 WHILE @@FETCH_STATUS = 0
 BEGIN
  --PRINT @StatName
  SET @SQL = ''DBCC SHOW_STATISTICS ('' + @TableName+ '',"'' + @StatName +''") WITH STAT_HEADER,NO_INFOMSGS ;''
  --PRINT @SQL
  INSERT INTO #StatsTable
  (
   StatName
   ,Updated
   ,TableRows
   ,RowsSampled
   ,Steps
   ,Density
   ,AverageKeyLength
   ,StringIndex
   ,FilterExpression
   ,UnfilteredRows
  )
  EXEC(@SQL)

  UPDATE #StatsTable
  SET TableName = @TableName
   ,DatabaseName = @DBName
   ,ServerName = @ServerName
   ,BatchRunID = @BatchRunID
   ,StatColumns = @ColumnList
   ,CreateDate = GETDATE()
  WHERE TableName IS NULL

  FETCH NEXT FROM ZCursor INTO @ServerName, @DBName, @TableName,@StatName,@ColumnList
 END

CLOSE ZCursor
DEALLOCATE ZCursor

--SELECT * FROM #StatsTable WHERE TableRows <> RowsSampled ORDER BY TableName

INSERT INTO master.dbo.StatsHistory
(
 ServerName
 ,DatabaseName
 ,TableName
 ,StatName
 ,Updated
 ,TableRows
 ,RowsSampled
 ,PercentSampled
 ,Steps
 ,Density
 ,AverageKeyLength
 ,StringIndex
 ,FilterExpression
 ,UnfilteredRows
 ,StatColumns
 ,BatchRunID
 ,CreateDate 
)
SELECT ServerName
  ,DatabaseName
  ,TableName
  ,StatName
  ,Updated
  ,TableRows
  ,RowsSampled
  ,PercentSampled
  ,Steps
  ,Density
  ,AverageKeyLength
  ,StringIndex
  ,FilterExpression
  ,UnfilteredRows
  ,StatColumns
  ,BatchRunID
  ,CreateDate 
FROM #StatsTable

DROP TABLE #StatsTable
Now you can do some fun things with your repository table, like this:

-- =====================================================
-- Author:  Eric Zierdt
-- Create date: 12/9/2014
-- Description: SAMPLE CODE TO QUERY STATS REPOSITORY
-- =====================================================
DECLARE @BatchRunID INT
SELECT  @BatchRunID = MAX(BatchRunID) FROM master.dbo.StatsHistory

/**  SEE ALL STATS **/
SELECT  *
FROM    master.dbo.StatsHistory
WHERE BatchRunID = @BatchRunID

/**  SEE ALL STATS OLDER THAN 1 MONTH  **/
SELECT  *
FROM    master.dbo.StatsHistory
WHERE BatchRunID = @BatchRunID
  AND Updated < DATEADD(MONTH,-1,GETDATE())

/**  SEE ALL NON-FULLSCAN STATS  **/
SELECT  *
FROM    master.dbo.StatsHistory
WHERE BatchRunID = @BatchRunID
  AND PercentSampled < 100


/**  CREATE UPDATE STAT SCRIPT FOR ALL NON-FULLSCAN STATS  **/
SELECT  TableName, StatName, TableRows, PercentSampled, 'UPDATE STATISTICS dbo.' + TableName + ' ' + StatName + ' WITH FULLSCAN --' + CAST(TableRows AS VARCHAR(10)) AS SQLCode
FROM    master.dbo.StatsHistory
WHERE   BatchRunID = @BatchRunID
  AND PercentSampled < 100

Tuesday, August 20, 2013

PowerShell Progress Meter

In many of my past PowerShell scripts, I've included my own home-spun progress report in the results window. I like that a lot, but my mind was blown when I noticed that there is a "Write-Process" cmdlet...with some re-tweaking I made it rock and much more efficient.

So the situation where you would want to use this is if you are looping over a large dataset and it takes a while to bring back results (I often will use PowerShell to hit all the servers I control, get some information about them and return it to me (backup status, if they are VM's, configuration info, etc). It can take 20+ minutes to get to all the servers and it is nice to know how far along the process is; thats where this comes in handy.

Some things to keep in mind...You need to have some resultset to work with, it doesn't have to be a query, but it does have to be some kind of System.Array. After you generate the Array, run this bit of code...I'm calling my array "results":

<################################
 ##  SETUP PROGRESS VARIABLES  ##
 ################################>
$ResultsLen = $results.Length
$LastPercentComplete = 0
[datetime]$DateStart = Get-Date -format G

This sets up some of the variables we will need inside the progress meter. Next, just after you issue your "foreach ($result in $results) {" You run the following code:

<##########################
 ##  RUN PROGRESS METER  ##
 ##########################>
foreach ($result in $results) 
{
 $currentRow++
 $PercentComplete = [math]::floor(($CurrentRow/$ResultsLen)*100)
 [datetime]$DateNow = Get-Date -format G
 $diff = $DateNow-$DateStart
 $DiffSeconds = $diff.TotalSeconds
 $SecondsPerRecord = $DiffSeconds/$currentRow
 $RemainingSeconds = $SecondsPerRecord*($ResultsLen-$currentRow)
 $SecondsPerRecord = [Math]::Round($SecondsPerRecord,2)
 
 Write-Progress -Activity "Investigating Servers..." `
  -PercentComplete $PercentComplete `
  -SecondsRemaining $RemainingSeconds `
  -CurrentOperation "Current Row: $currentRow / $ResultsLen.   Seconds/Record: $SecondsPerRecord   Run Time (seconds): $DiffSeconds" `
  -Status "Please wait."

 Remove-Variable DateNow
 Remove-Variable DiffSeconds
 Remove-Variable SecondsPerRecord
 Remove-Variable RemainingSeconds
}

You don't need to remove your variables, I just like to do it to clean up my code, I do this at the bottom of the script:

Remove-Variable ResultsLen
Remove-Variable currentRow
Remove-Variable LastPercentComplete
Remove-Variable DateStart

Want to see it in action? Take my script and add this to the top of it (creates an array with 10000 items, which should keep the status bar up long enough for you to see):
$results = 1..10000

This looks awesome in PowerGUI, which is what I use for PowerShell Development, it looks a bit funky in the native PS window, but good enough to get you the idea. If you aren't using PowerGUI, give it a shot, it's free. http://www.powergui.org

As always, please leave comments below if you find this useful or have other suggestions. It's nice to know people read these posts.

Thursday, May 23, 2013

LEFT vs RIGHT vs SUBSTRING

Today I want to post something pretty simple, but a Jr. DBA asked me about it so I wanted to put out some quick basic logic. He was confused by how the RIGHT function worked, so I tried to explain it to him, but having a visual proof query helped him out. So, lets review before we look at the code. LEFT([string],n) will display the first n characters of the string starting on the left side of the string RIGHT([string],n) will display the first n characters of the string starting on the right side of the string (or to write this a different way, it will display the last n characters in the string) SUBSTRING([string],s,n) will display n characters of the string starting at position s So lets see this in action, here is my query:
DECLARE @Alpha VARCHAR(26) 
SET @Alpha = 'ABCDEFGHIJKLMNOPQRSTUVWXYZ'
SELECT @Alpha AS Alpha                    -- Display All characters
  , LEFT(@Alpha,5) AS [LEFT(Alpha,5)]               -- Display the first 5 characters from the Left
  , RIGHT(@Alpha, 5) AS [RIGHT(Alpha,5)]              -- Display the first 5 characters from the Right
  , SUBSTRING(@Alpha, 15,5) AS [SUBSTRING(Alpha,15,5)]          -- Display 5 characters staring at postition 15
  , SUBSTRING(@Alpha, CHARINDEX('L',@Alpha),5) AS [SUBSTRING(Alpha, CHARINDEX('L',Alpha),5)]  -- Display 5 characters Starting at "L"
  , RIGHT(@Alpha, CHARINDEX('R',REVERSE(@Alpha))) AS [RIGHT(Alpha, CHARINDEX('R',REVERSE(Alpha)))]       -- Display all Characters starting at the last "R" in the string

I added two additional results to this; the first uses SUBSTRING to return 5 characters, but rather than starting at a position, it uses CHARINDEX() to start at the first occurrence of a given string ("L" in the example above). The second extra result uses the REVERSE() function to start on the right of the string and display all characters back to the first (or last depending on how you look at it) occurrence of a string or character ("R" in my example above). This would be beneficial if you had a windows path to something and you wanted to strip out the file name...say you had the path "c:\Folder1\Folder2\Folder3\Folder4\Folder5\File.ext" All you want is File.ext, so you could write: RIGHT(@Path, CHARINDEX('\',REVERSE(@Path))). Hope that helps someone out...if you found this useful, please post a comment below, and feel free to subscribe or follow me on twitter: @EricZierdt

Monday, October 1, 2012

SQL Saturday 149 Scripts and stuff

Hello everyone,

I had a great time meeting other SQL Server Professionals at SQL Saturday 149 in Minneapolis at the U of M campus, and chatting up with people afterwards at the after party. To those of you who attended my session on Execution Plans, I'd like to say thank you, I hope you took away some useful information; please feel free to email me directly with questions and please connect with me on LinkedIn. I also want to thank you for your feedback on my session; I appreciate the comments, suggestions and observations, it will help me better present in the future.

All the queries that I used in my presentation can be found here: http://ericemployed.blogspot.com/2011/11/sqlsaturday-99-scripts.html

Tuesday, August 28, 2012

SQL Saturday 149 Announcement

I found out that my submission for SQL Saturday 149 was accepted and I will again be presenting at the MN SQL Saturday this year. If you haven't signed up yet and you will be in the Twin Cities MN area on Saturday September 29th, 2012, you are missing out on one of the best SQL Server conferences around. This year, the event will be held at the University of Minnesota - Keller Hall, 200 Union Street SE, Minneapolis, MN 55455. Admittance to this event is free, but they do charge a lunch fee of 10.00 so that they can provide a lunch - not pizza! Please register soon as seating is limited, and let friends and colleages know about the event. You can find out more about this (and register!!) at the event homepage: http://www.sqlsaturday.com/149/eventhome.aspx

Monday, May 14, 2012

Extended Events with a view

So last time I wrote, I talked about my interest in Extended Events; I have been playing with them a bit since then and I came across something that made them so much easier to work with. This is not my own idea, but I wanted to share it as it blew my mind away with how simple it is, yet how I never thought of it. The idea is to take your ugly XQuery code and put it in a view, and to make it even better, create a Schema just for your Extended Events. I created a Schema called "XE" then when I want to get data from an Extended Event, I just have to type SELECT * FROM [XE]. and I let IntelliSense or SQLPrompt fill out the available options. This essentially makes querying Extended Events as easy as using a DMV. So in my last post, we created a Extended Even called "XE_Log_Shrink", If I wanted to implement this idea for this XE, I would do the following: Create the Schema (if I haven't previously done this):
USE [master]
GO
CREATE SCHEMA [XE] AUTHORIZATION [dbo]
GO
Create the View (using the XQuery from my previous post:
USE [master]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

/************************************************************
 * AUTHOR: Eric Zierdt          *
 * CREATED: 05/08/2012          *
 * USAGE: SELECT * FROM [XE].[vw_Log_Shrink]  *
 ************************************************************/
CREATE VIEW [XE].[vw_Log_Shrink]
AS
 
WITH Data
AS (
 SELECT CAST(target_data AS XML) AS TargetData
 FROM sys.dm_xe_session_targets dt
 JOIN  sys.dm_xe_sessions ds ON ds.address = dt.event_session_address
 JOIN  sys.server_event_sessions ss ON ds.Name = ss.Name
 WHERE dt.target_name = 'ring_buffer'
  AND ds.Name = 'XE_Log_Shrink'
)
SELECT  DATEADD(hour,-5,XEventData.XEvent.value('(@timestamp)[1]', 'datetime'))  AS event_timestamp
   ,XEventData.XEvent.value('@name', 'varchar(4000)')       AS event_name
   ,DB_NAME(XEventData.XEvent.value('(data/value)[2]', 'VARCHAR(100)'))  AS DatabaseName
   ,XEventData.XEvent.value('(action/value)[2]', 'VARCHAR(512)')    AS client_hostname
   ,XEventData.XEvent.value('(action/value)[3]', 'VARCHAR(512)')    AS nt_username
   ,XEventData.XEvent.value('(action/value)[6]', 'VARCHAR(512)')    AS username
   ,XEventData.XEvent.value('(action/value)[5]', 'VARCHAR(512)')    AS sql_text
   ,XEventData.XEvent.value('(action/value)[4]', 'VARCHAR(512)')    AS session_id
   ,XEventData.XEvent.value('(action/value)[1]', 'VARCHAR(512)')    AS client_app_name
FROM Data d
CROSS APPLY TargetData.nodes('//RingBufferTarget/event') AS XEventData ( XEvent )

GO

Thats all you have to do, now you can query this like a DMV, just write:
SELECT *
FROM [XE].[vw_Log_Shrink]
WHERE [event_timestamp] > '5/8/2012'
Let me know your thoughts.

Friday, April 20, 2012

Extended Event - Check for Log Shrink and Email

I saw SQL Server MVP Jason Strate give a presentation a year or two ago on Extended Events. One situation I remember him giving was that he was having problems with a log file shrinking every so often; for some reason this caused some issues (auto-grow or something). So he used Extended Events to capture the shrink and get more details on it. This problem sounded interesting to me and I wanted to see if I could generate some code to do this from scratch, this is what I came up with:

First we need to create the Extended Event (hereafter referred to as XE) to capture the log shrink:

IF EXISTS(SELECT * FROM sys.server_event_sessions WHERE name = 'XE_Log_Shrink')
DROP EVENT SESSION XE_Log_Shrink ON SERVER
GO
CREATE EVENT SESSION XE_Log_Shrink ON SERVER -- Session Name
ADD EVENT sqlserver.databases_log_shrink -- Event we want to capture
(
ACTION -- What contents to capture
(
sqlserver.client_app_name
,sqlserver.client_hostname
,sqlserver.nt_username
,sqlserver.session_id
,sqlserver.sql_text
,sqlserver.username
)
)
ADD TARGET package0.ring_buffer WITH (MAX_DISPATCH_LATENCY = 1 SECONDS, STARTUP_STATE = ON) -- The target
GO

ALTER EVENT SESSION XE_Log_Shrink ON SERVER STATE = START


Next to check it, we need to shrink a log (I'll auto grow it again, so I can redo this numerous times if I need to)


USE [AdventureWorks]
GO
DBCC SHRINKFILE (N'AdventureWorks_Log' , 1)
GO

USE [master]
GO
ALTER DATABASE [AdventureWorks] MODIFY FILE ( NAME = N'AdventureWorks_Log', SIZE = 100MB )
GO


Lets check the XE to see if we captured the event:

;WITH Data
AS (
SELECT CAST(target_data AS XML) AS TargetData
FROM sys.dm_xe_session_targets dt
JOIN sys.dm_xe_sessions ds ON ds.address = dt.event_session_address
JOIN sys.server_event_sessions ss ON ds.Name = ss.Name
WHERE dt.target_name = 'ring_buffer'
AND ds.Name = 'XE_Log_Shrink'
)
SELECT DATEADD(hour,-5,XEventData.XEvent.value('(@timestamp)[1]', 'datetime')) AS event_timestamp
,XEventData.XEvent.value('@name', 'varchar(4000)') AS event_name
,DB_NAME(XEventData.XEvent.value('(data/value)[2]', 'VARCHAR(100)')) AS DatabaseName
,XEventData.XEvent.value('(action/value)[2]', 'VARCHAR(512)') AS client_hostname
,XEventData.XEvent.value('(action/value)[3]', 'VARCHAR(512)') AS nt_username
,XEventData.XEvent.value('(action/value)[6]', 'VARCHAR(512)') AS username
,XEventData.XEvent.value('(action/value)[5]', 'VARCHAR(512)') AS sql_text
,XEventData.XEvent.value('(action/value)[4]', 'VARCHAR(512)') AS session_id
,XEventData.XEvent.value('(action/value)[1]', 'VARCHAR(512)') AS client_app_name
FROM Data d
CROSS APPLY TargetData.nodes('//RingBufferTarget/event') AS XEventData ( XEvent )



So, we should see the event now. But lets take it a step further, lets say we want to get emailed when it happens. I've created this stored proc which will check once an hour (this is a variable, you can configure it as you see fit, but keep it under 2 hours or else you'll have to modify my waitfor logic...or you could remove the waitfor logic and just run it from the scheduler in the agent job you setup, just match up the @How_Often variable with how often your job fires)

USE master
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- ===========================================================
-- Author: Eric Zierdt
-- Create date: 4/19/2012
-- Description: Checks for Log Shrinkage and sends email
-- URL: http://ericemployed.blogspot.com
-- Usage: exec Email_On_Log_Shrinkage 60
-- ===========================================================
ALTER PROCEDURE Email_On_Log_Shrinkage
-- Add the parameters for the stored procedure here
@How_Often INT = 60
AS
BEGIN
SET NOCOUNT ON
Start_Code:
--DECLARE @How_Often INT = 60
DECLARE @RowCount INT = 0
,@SQL VARCHAR(MAX) = ''

IF EXISTS (SELECT * FROM tempdb.dbo.sysobjects WHERE ID = OBJECT_ID(N'tempdb..#TempData'))
BEGIN
DROP TABLE #TempData
END

;WITH Data
AS (
SELECT CAST(target_data AS XML) AS TargetData
FROM sys.dm_xe_session_targets dt
JOIN sys.dm_xe_sessions ds ON ds.address = dt.event_session_address
JOIN sys.server_event_sessions ss ON ds.Name = ss.Name
WHERE dt.target_name = 'ring_buffer'
AND ds.Name = 'XE_Log_Shrink'
)
SELECT DATEADD(hour,-5,XEventData.XEvent.value('(@timestamp)[1]', 'datetime')) AS event_timestamp
,XEventData.XEvent.value('@name', 'varchar(4000)') AS event_name
,DB_NAME(XEventData.XEvent.value('(data/value)[2]', 'VARCHAR(100)')) AS DatabaseName
,XEventData.XEvent.value('(action/value)[2]', 'VARCHAR(512)') AS client_hostname
,XEventData.XEvent.value('(action/value)[3]', 'VARCHAR(512)') AS nt_username
,XEventData.XEvent.value('(action/value)[6]', 'VARCHAR(512)') AS username
,XEventData.XEvent.value('(action/value)[5]', 'VARCHAR(512)') AS sql_text
,XEventData.XEvent.value('(action/value)[4]', 'VARCHAR(512)') AS session_id
,XEventData.XEvent.value('(action/value)[1]', 'VARCHAR(512)') AS client_app_name
INTO #TempData
FROM Data d
CROSS APPLY TargetData.nodes('//RingBufferTarget/event') AS XEventData ( XEvent )
WHERE DATEADD(hour,-5,XEventData.XEvent.value('(@timestamp)[1]', 'datetime')) > DATEADD(MINUTE,-1*@How_Often,GETDATE())

SELECT @RowCount = COUNT(1) FROM #TempData
IF @RowCount > 0
BEGIN
PRINT CAST(@RowCount AS VARCHAR(10)) + ' Log Shrink records were found'
SET @SQL = '






'
DECLARE @DBName VARCHAR(120)
,@HostName VARCHAR(120)
,@TimeStamp VARCHAR(120)
,@UserName VARCHAR(120)
,@SQL_Text VARCHAR(120)
DECLARE ZCursor CURSOR FOR
(
SELECT DatabaseName
,client_hostname
,CAST(event_timestamp AS VARCHAR(120)) AS TimeStamp
,username
,sql_text
FROM #TempData
)
OPEN ZCursor
FETCH NEXT FROM ZCursor INTO @DBName,@HostName,@TimeStamp,@UserName,@SQL_Text
WHILE @@FETCH_STATUS = 0
BEGIN
SET @SQL += '



'

FETCH NEXT FROM ZCursor INTO @DBName,@HostName,@TimeStamp,@UserName,@SQL_Text
END

CLOSE ZCursor
DEALLOCATE ZCursor
SET @SQL += '
ServerDatabase NameTime StampClient HostnameUsernameSQL_Text
' + @@SERVERNAME + '' + @DBName + '' + @TimeStamp + '' + @HostName + '' + @UserName + '' + @SQL_Text + '

'
END
ELSE
PRINT 'No Shrinks in the time frame requested'

--PRINT @SQL

EXEC msdb.dbo.sp_send_dbmail
@recipients = '[Your Email Here]',
@body = @SQL,
@subject = 'Log Shrink Detected',
@profile_name = '[Your Profile Name Here]',
@body_format = 'html';

DROP TABLE #TempData

DECLARE @Delay VARCHAR(10)
--,@How_Often INT = 60
IF @How_Often < 60
SET @Delay = '00:' + RIGHT('00' + CAST(@How_Often AS VARCHAR(2)),2) + ':00'
ELSE
SET @Delay = '01:' + RIGHT('00' + CAST(@How_Often-60 AS VARCHAR(2)),2) + ':00'

WAITFOR DELAY @Delay
GOTO Start_Code
END
GO


Then the last step is to call this proc from a agent job. Iif you use the WaitFor logic, I'd still set a schedule to run every hour, just in case it fails...but the more I think about this, the more I prefer not using the WaitFor logic and just running the job every hour; but if the job fails, you won't get emailed.

--Eric

Friday, April 13, 2012

SSRS Queries

I've recently been working with SSRS and needed to write some queries to get more knowledge about what was happening on the server.

One of the first things I wanted to know was what subscriptions had run that did not succeed. This query should be run on the server that hosts your ReportServer Database. I'm running these on SQL Server 2008R2

USE [ReportServer]
--GET THE SERVER NAME
DECLARE @ServerURL VARCHAR(MAX)
SELECT TOP 1 @ServerURL =[MachineName]
FROM [dbo].Keys
WHERE [MachineName] IS NOT NULL

IF CHARINDEX('\',@ServerURL) > 0
SET @ServerURL = LEFT(@ServerURL,CHARINDEX('\',@ServerURL)-1)

SET @ServerURL = 'http://' + @ServerURL + '/Reports/Pages'

--FIND THE NON-SUCCESSFUL SUBSCRIPTIONS
;WITH AgentJobsCTE AS (
SELECT [SJ].job_id
,[SJ].name AS AgentJobName
,[SJS].[command]
,CAST(REPLACE(REPLACE(REPLACE([SJS].[command],'exec [ReportServer].dbo.AddEvent @EventType=''TimedSubscription'', @EventData=''',''),'exec ReportServer.dbo.AddEvent @EventType=''TimedSubscription'', @EventData=''',''), '''', '') AS SYSNAME) AS SubscriptionID
FROM msdb.[dbo].[sysjobs] AS SJ
JOIN msdb.[dbo].[sysjobsteps] AS SJS ON [SJ].[job_id] = [SJS].[job_id]
WHERE SJS.[command] LIKE '%TimedSubscription%'
)
SELECT O.[UserName] AS OwnerName,M.[UserName] AS ModifiedBy,C.[Name] AS ReportName,[AJ].AgentJobName,S.[SubscriptionID],S.[LastStatus],S.[LastRunTime],S.[ModifiedDate],S.[Report_OID]
,@ServerURL + '/SubscriptionProperties.aspx?ItemPath=' + REPLACE(REPLACE(C.Path,'/','%2f'),' ','+') + '&IsDataDriven=False&SubscriptionID=' + CAST(S.[SubscriptionID] AS VARCHAR(MAX)) AS SubscriptionURL
,@ServerURL + '/Report.aspx?ItemPath=' + REPLACE(REPLACE(C.Path,'/','%2f'),' ','+') + '&SelectedTabId=PropertiesTab&SelectedSubTabId=SubscriptionsTab&SortBy=LastExecuted&IsAscending=false' AS ReportURL
FROM [ReportServer].[dbo].[Subscriptions] AS S
JOIN [ReportServer].[dbo].[Users] AS O ON [S].[OwnerID] = [O].[UserID]
JOIN [ReportServer].[dbo].[Users] AS M ON S.[ModifiedByID] = [M].[UserID]
JOIN [ReportServer].[dbo].[Catalog] AS C ON [S].[Report_OID] = [C].[ItemID]
LEFT JOIN [AgentJobsCTE] AJ ON CAST(S.[SubscriptionID] AS SYSNAME) = AJ.[SubscriptionID]
WHERE [LastRunTime] >= '04/02/2012 15:00' --NOT NEEDED, BUT MAKES YOUR LIST SHORTER
AND [LastStatus] NOT LIKE 'Mail sent to%'
AND [LastStatus] NOT LIKE 'The file "%'
--AND [LastStatus] NOT LIKE 'Pending%' --Pending are currently running.
ORDER BY [LastRunTime] DESC



I noticed that I was seeing a number of subscriptions currently running for the same report, many run at the same time. I wrote a query to tell me which subscriptions had the same "report parameter values". This doesn't look at the subscription start time or days of the week, just the parameters...so you'll need to do some investigation (the next query will help with that)
USE [ReportServer]
DECLARE @ServerURL VARCHAR(MAX)
SELECT TOP 1 @ServerURL =[MachineName]
FROM [dbo].Keys
WHERE [MachineName] IS NOT NULL

IF CHARINDEX('\',@ServerURL) > 0
SET @ServerURL = LEFT(@ServerURL,CHARINDEX('\',@ServerURL)-1)

SET @ServerURL = 'http://' + @ServerURL + '/Reports/Pages'

;WITH DuplicateSubscriptions AS (
SELECT C.Name AS ReportName
,CAST(Parameters AS VARCHAR(MAX)) AS Parameters
,[Report_OID]
,C.Path
,COUNT(1) AS [Count]
FROM [ReportServer].[dbo].[Subscriptions] S
JOIN [ReportServer].[dbo].[Catalog] AS C ON [S].[Report_OID] = [C].[ItemID]
LEFT JOIN [dbo].[ReportSchedule] AS RS ON [S].[SubscriptionID] = [RS].[SubscriptionID]
LEFT JOIN [dbo].[Schedule] AS SC ON RS.[ScheduleID] = SC.[ScheduleID]
WHERE (SC.EndDate IS NULL OR (SC.EndDate IS NULL AND SC.[RecurrenceType] <> 1))

GROUP BY CAST(Parameters AS VARCHAR(MAX)),[Report_OID],C.Name,C.Path
HAVING COUNT(1) > 1
)
SELECT *
,@ServerURL + '/Report.aspx?ItemPath=' + REPLACE(REPLACE(Path,'/','%2f'),' ','+') + '&SelectedTabId=PropertiesTab&SelectedSubTabId=SubscriptionsTab&SortBy=LastExecuted&IsAscending=false' AS URL
FROM [DuplicateSubscriptions]
--ORDER BY [ReportName], [Count] DESC
ORDER BY [Count] DESC, [ReportName]



So when you find a possible duplicate subscription in the previous list, get the Report_OID and Parameters field and past them into the variables in this query and execute to see if it needs more investigation. I usually look at the "LastRun" field and see if there are any duplicates in that list. If you need to dig in more, the query provides links to both the subscription webpage and the report management page listing all subscriptions
USE [ReportServer]
-- VIEW ALL (NON EXPIRED) SUBSCRIPTIONS FOR A SPECIFIC REPORT WITH SPECIFIC PARAMETERS
DECLARE @ServerSubscriptionURL VARCHAR(MAX)
SELECT TOP 1 @ServerSubscriptionURL =[MachineName]
FROM [dbo].Keys
WHERE [MachineName] IS NOT NULL

IF CHARINDEX('\',@ServerSubscriptionURL) > 0
SET @ServerSubscriptionURL = LEFT(@ServerSubscriptionURL,CHARINDEX('\',@ServerSubscriptionURL)-1)

SET @ServerSubscriptionURL = 'http://' + @ServerSubscriptionURL + '/Reports/Pages'

DECLARE @ReportID sysname = 'F9999999-888G-7H77-I9I9-000000J00000' -- ReportID from previous query
,@ParameterList VARCHAR(MAX) = '[parameters]'-- Parameters from previous query

SELECT C.Name AS ReportName
,S.[SubscriptionID]
,S.[Description] Descr
,S.[LastRunTime] LastRun
,S.[LastStatus]
--,SC.[EndDate]
--,SC.[RecurrenceType]
,U.[UserName] AS Owner
,@ServerSubscriptionURL + '/SubscriptionProperties.aspx?ItemPath=' + REPLACE(REPLACE(C.Path,'/','%2f'),' ','+') + '&IsDataDriven=False&SubscriptionID=' + CAST(S.[SubscriptionID] AS VARCHAR(MAX)) AS SubscriptionURL
,@ServerSubscriptionURL + '/Report.aspx?ItemPath=' + REPLACE(REPLACE(C.Path,'/','%2f'),' ','+') + '&SelectedTabId=PropertiesTab&SelectedSubTabId=SubscriptionsTab&SortBy=LastExecuted&IsAscending=false' AS ReportURL
FROM [ReportServer].[dbo].[Subscriptions] S
JOIN [ReportServer].[dbo].[Users] AS U ON [S].[OwnerID] = [U].[UserID]
JOIN [ReportServer].[dbo].[Catalog] AS C ON [S].[Report_OID] = [C].[ItemID]
LEFT JOIN [dbo].[ReportSchedule] AS RS ON [S].[SubscriptionID] = [RS].[SubscriptionID]
LEFT JOIN [dbo].[Schedule] AS SC ON RS.[ScheduleID] = SC.[ScheduleID]
WHERE Report_OID = @ReportID
AND CAST(S.Parameters AS VARCHAR(MAX)) = @ParameterList
AND (SC.EndDate IS NULL OR (SC.EndDate IS NULL AND SC.[RecurrenceType] <> 1))
ORDER BY S.Description



But wait, thats not all, some additional interesting queries:
See all currently running reports
SELECT [JobID],[StartDate],[ComputerName],[RequestName],[RequestPath]
,[Description],[Timeout] AS Timeout, DATEDIFF(ss, startdate, GETDATE()) AS SecondsSinceRun
, DATEDIFF(mi, startdate, GETDATE()) AS MinutesSinceRun
,[JobAction],[JobType],[JobStatus]
,'http://[reporturl]/Reports/Pages/Report.aspx?ItemPath=' + REPLACE(REPLACE(RJ.RequestPath,'/','%2f'),' ','+') + '&SelectedTabId=PropertiesTab&SelectedSubTabId=SubscriptionsTab&SortBy=LastExecuted&IsAscending=false' AS ReportURL
FROM [ReportServer].[dbo].[RunningJobs] AS RJ




See the run information for a specific report (comment out the RequestType if you want to see things other than subscriptions)
SELECT *
FROM [ReportServer].[dbo].[ExecutionLog2] AS EL
WHERE [ReportPath] LIKE '%[report name=""]' AND [RequestType] = 'Subscription'
ORDER BY [TimeStart] DESC



View a schedule for a specific Subscription
-- VIEW SCHDULE DATA FOR A SPEICIFC SUBSCRIPTION
SELECT *
FROM [dbo].[Schedule] AS S
JOIN [dbo].[ReportSchedule] AS RS ON [S].[ScheduleID] = [RS].[ScheduleID]
WHERE RS.[SubscriptionID] = '[subscriptionid]'




Ok, one last one, this lets you see all expired (past the end date) and one time subscriptions (useful if you want to clean them up)

-- EXPIRED AND ONE TIME RUN SUBSCRIPTIONS

DECLARE @ServerURL VARCHAR(MAX)
SELECT TOP 1 @ServerURL =[MachineName]
FROM [dbo].Keys
WHERE [MachineName] IS NOT NULL

IF CHARINDEX('\',@ServerURL) > 0
SET @ServerURL = LEFT(@ServerURL,CHARINDEX('\',@ServerURL)-1)

SET @ServerURL = 'http://' + @ServerURL + '/Reports/Pages'

;WITH ExpiredSubscriptions AS
(
SELECT RS.[SubscriptionID], S.[EndDate]
FROM [dbo].[Schedule] AS S
JOIN [dbo].[ReportSchedule] AS RS ON [S].[ScheduleID] = [RS].[ScheduleID]
WHERE S.[EndDate] < GETDATE() OR S.[RecurrenceType] = 1
)
SELECT S.[SubscriptionID]
,C.Name AS ReportName
,S.[Description] Descr
,S.[LastRunTime] LastRun
,ES.[EndDate]
,S.[LastStatus]
,U.[UserName] AS Owner
,@ServerURL + '/SubscriptionProperties.aspx?ItemPath=' + REPLACE(REPLACE(Path,'/','%2f'),' ','+') + '&IsDataDriven=False&SubscriptionID=' + CAST(S.[SubscriptionID] AS VARCHAR(MAX)) AS SubscriptionURL
,@ServerURL + '/Report.aspx?ItemPath=' + REPLACE(REPLACE(Path,'/','%2f'),' ','+') + '&SelectedTabId=PropertiesTab&SelectedSubTabId=SubscriptionsTab&SortBy=LastExecuted&IsAscending=false' AS ReportURL
FROM Subscriptions S
JOIN [dbo].[Users] AS U ON [S].[OwnerID] = [U].[UserID]
JOIN [ReportServer].[dbo].[Catalog] AS C ON [S].[Report_OID] = [C].[ItemID]
JOIN [ExpiredSubscriptions] ES ON S.[SubscriptionID] = ES.[SubscriptionID]
ORDER BY C.[Name], ES.[EndDate] DESC


If you have any other good queries, please drop them in a comment below

Saturday, November 12, 2011

SQLSaturday #99 Scripts

Hello to everyone who finds my blog because of taking my SQLSaturday presentation on Execution Plans. As promised, I'm attaching my scripts.

What are Execution Plans?
The definition I used in my presentation was:
"In simplest terms, Execution Plans are the steps that SQL Server takes in order to return the requested information."


How do I see Execution Plans
For Graphical Execution Plans there are a few ways:
In the Menu Bar choose Query and you can choose either Display Estimated Execution Plan or Include Actual Execution Plan.



Right Click Query Window




Control L (Estimated) / M (Actual)


Or the simplest way, use the two buttons



Plan Type
Graphical, Text, XML
Gets more difficult to read as you go from left to right, but also get more info. i.e. Graphical is easier to read than is Text, which is easier to read than XML, but XML gives more info than Text, which in turn gives more info than Graphical.
Note: I've read that Microsoft is planning on deprecating Text Execution Plan


Permission
sysadmin, dbcreator or db_owner, or be granted the ShowPlan permission:
GRANT SHOWPLAN TO [username]



Reuse
The Optimizer stores plans so it can reuse them, this is removed on server restart or DBCC FREEPROCCACHE



The examples below use AdventureWorks and AdventureWorks2008, available at CodePlex

To start, please turn on Include Actual Execution Plan from any of the above described methods. Next run this query:



/* QUERY 1 */
USE AdventureWorks2008
SELECT *
FROM HumanResources.Employee E


In your results window, you will see a new tab called "Execution Plan", if you click on that, you should see the following. Hovering over the left most object will display the tool tip in this screenshot:



If you right click on any of the objects in this window you can choose Properties and get additional info. I traditionally read from right to left, but you can get important info like "Optimization Level" if you get the properties from the left most (select) object. The most common Optimization Levels are Trivial or Full. This is a trivial plan because there are no where clauses or joins, so the Optimizer can only get this data one way, doing a full table scan.

We discussed the difference between A Scan and a Seek. A Scan means that SQL Server needed to look at every record in the table, where as a Seek means that it can use an index to go directly to the record in question. We likened this to a phone book, if you are looking for the phone number and address for "Sam Smith", a Scan means you have to look at every page and every record even after it already finds a record for Sam Smith, whereas a Seek can go right to the S's at the top of the page and quickly go to the Sam Smith record and stop looking.

We discussed how typically, a scan performs worse than a seek. However if the table is small, and in some other instances, a Scan can be the best option.


Next we ran the following query:


/* QUERY 2 */
USE AdventureWorks
SELECT E.Title
FROM HumanResources.Employee E
WHERE E.EmployeeID = 185


And we saw an Clustered Index Seek this time.





Our next query:

/* QUERY 3 */
USE AdventureWorks
SELECT MiddleName
FROM Person.Contact
WHERE Phone LIKE '11%'


Showed us the "Missing Index" at the top of the Execution Plan


You can right click on this "Missing Index" text and "Missing Index Details" to have it open the suggested index in a new window.

We altered the index slightly (gave it a name and the WITH(Data_Compression=ROW) hint) and ran this:


USE [AdventureWorks]
GO
CREATE NONCLUSTERED INDEX [Contact_IX_Phone] ON [Person].[Contact]
(
[Phone]
)
INCLUDE
(
[MiddleName]
)
WITH(Data_Compression=ROW)
GO


We then re-ran Query 3 and saw that we now have an Index Seek.



For Query 4 we ran:

/* QUERY 4 */
USE AdventureWorks
SELECT E.Title
,C.FirstName
,C.LastName
,M.FirstName AS ManagerFirstName
,M.LastName AS ManagerLastName
,E.ManagerID
FROM HumanResources.Employee E
JOIN Person.Contact C ON E.ContactID = C.ContactID
JOIN Person.Contact M ON E.ManagerID = M.ContactID
WHERE E.ManagerID = 109
AND EXISTS (
SELECT 1
FROM Person.Contact AS C2
WHERE E.ContactID = C2.ContactID
)


Which showed us a Clustered Index Scan on HumanResources.Employee



It didn't state a missing index so we discussed how to come up with our own index.

We started by noticing that ContactID and ManagerID were both being Joined, and that ManagerID was in the WHERE clause, so we created an index on that, also we used INCLUDE (Title) because Title was in the select List:


USE [AdventureWorks]
GO
CREATE NONCLUSTERED INDEX [HR-Employee_IX_EZ1] ON [HumanResources].[Employee]
(
[ContactID] ASC, [ManagerID] ASC
)
INCLUDE ( [Title])
WITH (STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = ON, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION=ROW) ON [PRIMARY]
GO


We did discuss some of the WITH parts, like the use of ONLINE = ON as a hint to try to make this index without causing any locking if possible.

After we ran this, we noted that the Index Scan still existed; we discussed that because the ContactID wasn't part of the WHERE, it should go in the INCLUDE. After making this change and re-running the index we saw it change to a Index Seek (note I'm using the DROP_EXISTING = ON here rather than the DROP statement I used in class).

USE [AdventureWorks]
GO
CREATE NONCLUSTERED INDEX [HR-Employee_IX_EZ1] ON [HumanResources].[Employee]
(
[ManagerID] ASC
)
INCLUDE ( [ContactID], [Title])
WITH (STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = ON, ONLINE = ON, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION=ROW) ON [PRIMARY]
GO






We noted that the when we hover over the Employee object in the above screen shots, that it the Estimated I/O Cost dropped from 0.0075 to 0.00386 after we converted from a SCAN to a SEEK and the Estimated Operator Cost changed from .008 to .004 We acknowledged that these numbers seem small, but if this table explodes and becomes very large, we would expect to see these go up and seeing the costs cut in half is a good thing.




For Query 5 we let the audience try to determine what was wrong and needed to be changed:


/* QUERY 5 */
USE AdventureWorks2008
SELECT SOH.AccountNumber
,S.Name AS StoreName
,SOH.OrderDate
,P.Name AS ProductName
,SOD.OrderQty
,SOD.UnitPrice
,SOD.LineTotal
FROM Sales.SalesOrderHeader SOH
JOIN Sales.SalesOrderDetail SOD ON SOH.SalesOrderID = SOD.SalesOrderID
JOIN Sales.Customer C ON SOH.CustomerID = C.CustomerID
JOIN Sales.Store S ON C.StoreID = S.BusinessEntityID
JOIN Production.Product P ON SOD.ProductID = P.ProductID


We had a big Execution Plan, we discussed that you can click on the [+] symbol at the bottom left of the window to help scroll around:


We all agreed that the Index Scan's had to go. We also introduced the "Key Lookup" object. I discussed how Key Lookups are not good, and indicate that the Optimizer couldn't get the key from the index. After looking at the query, we decided to add a number of indexes:


USE [AdventureWorks2008]
GO
CREATE NONCLUSTERED INDEX [SalesOrderHeader_I01] ON [Sales].[SalesOrderHeader]
(
[SalesOrderID] ASC,
[CustomerID] ASC
)
INCLUDE
(
AccountNumber
,OrderDate
)
WITH (STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF
, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION = ROW) ON [PRIMARY]
GO


USE [AdventureWorks2008]
GO
/****** Object: Index [AK_SalesOrderDetail_rowguid] Script Date: 09/23/2011 14:35:47 ******/
CREATE NONCLUSTERED INDEX [SalesOrderDetail_I01] ON [Sales].[SalesOrderDetail]
(
SalesOrderID ASC
)
INCLUDE
(
ProductID
, OrderQty
,UnitPrice
,LineTotal
)
WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF
, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION = ROW) ON [PRIMARY]
GO



USE [AdventureWorks2008]
GO
CREATE NONCLUSTERED INDEX [Customer_I01] ON [Sales].[Customer]
(
[CustomerID] ASC)
INCLUDE (
[StoreID]
)WITH (STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF
, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION = ROW) ON [PRIMARY]
GO



USE [AdventureWorks2008]
GO
CREATE NONCLUSTERED INDEX [Store_I01] ON [Sales].[Store]
(
[BusinessEntityID] ASC
)
INCLUDE
(
Name
)
WITH (STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF
, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION = ROW) ON [PRIMARY]
GO


This did seem to help, when we compared the Estimated I/O's and CPU's but we still were seeing SCANS.



We scratched our heads and then realized that we didn't have a WHERE clause, so we were pulling every record possible. We added:

WHERE SOH.SalesOrderID = 22

and our Execution Plan looked much, much better.



By this time, I think you can figure out what needs to be done for Query 6:


/* QUERY 6 */
SELECT LineTotal, OrderQty
FROM Sales.SalesOrderDetail s
JOIN Production.Product p ON s.ProductID = p.ProductID
WHERE CarrierTrackingNumber = '4911-403C-98'




Next I showed this query which returns all the Cached plans that SQL Server has ready to go:

SELECT [cp].[refcounts]
, [cp].[usecounts]
, [cp].[objtype]
, [st].[dbid]
, [st].[objectid]
, [st].[text]
, [qp].[query_plan]
FROM sys.dm_exec_cached_plans cp
CROSS APPLY sys.dm_exec_sql_text ( cp.plan_handle ) st
CROSS APPLY sys.dm_exec_query_plan ( cp.plan_handle ) qp ;



Then we moved on to looking at Execution Plans returned as Text (Note remember to turn off "Include Actual Execution Plan"):


/* TEXT PLANS */

SET SHOWPLAN_ALL ON; --TURNS ON Estimated Exececution Plan

USE AdventureWorks2008
SELECT *
FROM HumanResources.Employee E

SET SHOWPLAN_ALL OFF; --TURNS OFF Estimated Exececution Plan



SET STATISTICS PROFILE ON --TURNS ON Actual Exececution Plan
USE AdventureWorks2008
SELECT *
FROM HumanResources.Employee E
SET STATISTICS PROFILE OFF --TURNS OFF Actual Exececution Plan


We saw a bunch of data returned




We next moved on to XML Plans:


/* XML PLANS */
SET SHOWPLAN_XML ON; --TURNS ON Estimated Exececution Plan

USE AdventureWorks2008
SELECT *
FROM HumanResources.Employee E

SET SHOWPLAN_XML OFF; --TURNS OFF Estimated Exececution Plan


SET STATISTICS XML ON --TURNS ON Actual Exececution Plan
USE [AdventureWorks]
SELECT E.Title
,C.FirstName
,C.LastName
FROM HumanResources.Employee E
JOIN Person.Contact C ON E.ContactID = C.ContactID
WHERE E.ManagerID = 185
SET STATISTICS XML OFF --TURNS OFF Actual Exececution Plan




If you click on the returned XML it will open in Graphical Format. If you really want to see it in XML, when viewing a plan in Graphical Format, right click on a blank part of the screen and choose "Show Execution Plan XML"


I had two more pretty awesome queries to show you...the first was one that finds all "Missing Indexes" for all Databases.


SELECT TOP 10 SUBSTRING(mid.statement, 2, (CHARINDEX(']',mid.statement,1)-2)) AS DBName
,mid.statement
,migs.avg_total_user_cost
,migs.avg_user_impact
,migs.user_seeks
,migs.avg_total_user_cost * (migs.avg_user_impact / 100.0)
* (migs.user_seeks + migs.user_scans) AS improvement_measure
,'CREATE INDEX [missing_index_'
+ CONVERT (VARCHAR, mig.index_group_handle) + '_'
+ CONVERT (VARCHAR, mid.index_handle) + '_'
+ LEFT(PARSENAME(mid.statement, 1), 32) + ']' + ' ON ' + mid.statement
+ ' (' + ISNULL(mid.equality_columns, '')
+ CASE WHEN mid.equality_columns IS NOT NULL
AND mid.inequality_columns IS NOT NULL THEN ','
ELSE ''
END + ISNULL(mid.inequality_columns, '') + ')' + ISNULL(' INCLUDE ('
+ mid.included_columns
+ ')', '') AS create_index_statement
,migs.*
,mid.database_id
,mid.[object_id]
FROM sys.dm_db_missing_index_groups mig
INNER JOIN sys.dm_db_missing_index_group_stats migs ON migs.group_handle = mig.index_group_handle
INNER JOIN sys.dm_db_missing_index_details mid ON mig.index_handle = mid.index_handle
WHERE migs.avg_total_user_cost * (migs.avg_user_impact / 100.0)
* (migs.user_seeks + migs.user_scans) > 1
ORDER BY migs.avg_total_user_cost * migs.avg_user_impact * (migs.user_seeks + migs.user_scans) DESC


And a query that can show you indexes which potentially are no longer used:



IF EXISTS (SELECT * FROM tempdb.dbo.sysobjects WHERE ID = OBJECT_ID(N'tempdb..#Temp_UnUsed_Indexes'))
BEGIN
DROP TABLE #Temp_UnUsed_Indexes
END

CREATE TABLE #Temp_UnUsed_Indexes
(
[Server] VARCHAR(100)
, DatabaseName VARCHAR(100)
, TableName VARCHAR(100)
, IndexName VARCHAR(100)
, is_primary_key BIT
, user_seeks INT
, user_scans INT
, user_lookups INT
, user_updates INT
, last_user_seek DATETIME
, last_user_scan DATETIME
, last_user_lookup DATETIME
, last_user_update DATETIME
, system_seeks INT
, system_scans INT
, system_lookups INT
, system_updates INT
, last_system_seek DATETIME
, last_system_scan DATETIME
, last_system_lookup DATETIME
, last_system_update DATETIME
)

SET NOCOUNT ON
DECLARE @Seeks INT = 30
,@Scans INT = 30
,@Lookups INT = 30
,@DBName VARCHAR(MAX)
,@SQL VARCHAR(MAX)

DECLARE ZCursor CURSOR FOR
SELECT NAME --select *
FROM sys.databases
WHERE owner_sid <> 0x01
AND is_read_only = 0
AND user_access = 0
ORDER BY name
OPEN ZCursor
FETCH NEXT FROM ZCursor INTO @DBName
WHILE @@FETCH_STATUS = 0
BEGIN
SET @SQL = '
USE [' + @DBName + ']
DECLARE @Seeks INT = ' + CAST(@Seeks AS VARCHAR(20)) + '
,@Scans INT = ' + CAST(@Scans AS VARCHAR(20)) + '
,@Lookups INT = ' + CAST(@Lookups AS VARCHAR(20)) + '

INSERT INTO #Temp_UnUsed_Indexes
SELECT @@SERVERNAME AS SERVER
, DB_NAME(DDIUS.database_id) AS DatabaseName
, OBJECT_NAME(DDIUS.object_id) AS TableName
, I.name AS IndexName
, I.is_primary_key AS is_primary_key
, DDIUS.user_seeks AS user_seeks
, DDIUS.user_scans AS user_scans
, DDIUS.user_lookups AS user_lookups
, DDIUS.user_updates AS user_updates
, DDIUS.last_user_seek AS last_user_seek
, DDIUS.last_user_scan AS last_user_scan
, DDIUS.last_user_lookup AS last_user_lookup
, DDIUS.last_user_update AS last_user_update
, DDIUS.system_seeks AS system_seeks
, DDIUS.system_scans AS system_scans
, DDIUS.system_lookups AS system_lookups
, DDIUS.system_updates AS system_updates
, DDIUS.last_system_seek AS last_system_seek
, DDIUS.last_system_scan AS last_system_scan
, DDIUS.last_system_lookup AS last_system_lookup
, DDIUS.last_system_update AS last_system_update
FROM sys.dm_db_index_usage_stats AS DDIUS
JOIN sys.indexes AS I ON DDIUS.index_id = I.index_id AND DDIUS.object_id = I.object_id
WHERE database_id = DB_ID()
AND user_seeks <= @Seeks AND user_scans <= @Scans AND user_lookups <= @Lookups
--AND is_primary_key = 0
ORDER BY OBJECT_NAME(DDIUS.object_id), I.name
'
EXEC(@SQL)
-- PRINT @SQL

FETCH NEXT FROM ZCursor INTO @DBName
END
CLOSE ZCursor
DEALLOCATE ZCursor


SELECT *
FROM #Temp_UnUsed_Indexes
WHERE is_primary_key = 0
--AND user_seeks = 0 AND user_scans = 0 AND user_lookups = 0
--AND system_seeks = 0 AND system_scans = 0 AND system_lookups = 0
--AND DatabaseName NOT IN ('MOBILE')
ORDER BY [SERVER]
,DatabaseName
,TableName
,is_primary_key DESC
,IndexName


Remember that the numbers returned are since the last restart or DBCC FREEPROCCACHE so if you did that recently, don't trust these too much. Look at user_seeks, user_scans and user_lookups to see how often users have called this index. As always, do your research, this is a tool to help you identify probable indexes which might be unused.


I want to really thank Grant Fritchey, who literally wrote the book on Execution Plans, check out his stuff, he knows way more than I do about it.
http://www.simple-talk.com/author/grant-fritchey/
http://www.simple-talk.com/sql/performance/execution-plan-basics/
http://Scarydba.com/Resources



Lastly, if you are not already a member of PASS or PASSMN, please signup, it's free and we have monthly meetings where we discuss stuff and show code and talk about new stuff...it's a lot of fun. Also, PASS does something called 24 hours of pass, where they do 24 hourly webinars (over 2 days), for free!!! so sign up and check them out.

Please subscribe to my blog and follow me on Twitter (@EricZierdt).

Comment, or email me any questions.

Thursday, November 10, 2011

New SP_WHO2

A long time ago, I was given a stored proc called "SP_WHOM" which said it was created by "MFrank". SP_WHOM has been a staple in my collection of utilities I use to debug issues on my SQL Servers. I never paid it much mind, until recently, when the thought occurred to me that I knew how to get all of the provided data from SP_WHOM, in an easier way, and I could add some beneficial new fields in the process. So I set out to try to design my own SP_WHOM, so I took at look at the fields provided in the DMV sys.sysprocess All the fields I wanted were in there; so I decided to design my own and this is what I came up with:



USE [master]
GO

SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

/*******************************
** Created By: Eric Zierdt **
** ericzierdt@gmail.com **
** ericemployed.blogspot.com **
*******************************/
CREATE PROCEDURE [dbo].[sp_whom]
AS

SET NOCOUNT ON

IF EXISTS (SELECT * FROM tempdb.dbo.sysobjects WHERE ID = OBJECT_ID(N'tempdb..#RawData'))
BEGIN
DROP TABLE #RawData
END

SELECT SPID
,UPPER(status) AS Status
,LogiName
,HostName
,CASE blocked
WHEN 0 THEN ''
ELSE CAST(blocked AS VARCHAR(5))
END AS BlockedBy
,Open_Tran
,DB_NAME(S.dbid) AS DBName
,CMD AS Command
,Last_Batch
,DATEDIFF(mi,last_batch,GETDATE()) AS RunTimeMins
,DATEDIFF(ss,last_batch,GETDATE()) AS RunTimeSecs
,CPU AS CPU_Time
,Physical_IO AS DiskIO
,Program_Name
,ST.text AS SQL_Text
INTO #RawData
FROM sys.sysprocesses AS S
CROSS APPLY sys.dm_exec_sql_text(S.sql_handle) ST

SELECT *
FROM #RawData R
WHERE spid <> @@SPID
AND status NOT IN ( 'background', 'sleeping' )
UNION
SELECT *
FROM #RawData AS RD
WHERE SPID IN (
SELECT BlockedBy
FROM #RawData AS RD2
WHERE RD2.BlockedBy <> ''
)
ORDER BY SPID

DROP TABLE #RawData

GO



Why are you doing a UNION you might ask? I'm doing it because I want to display only those SPIDS which are not set to "Sleeping" or "Background" status, however...if a SPID is blocked by another SPID, I'd like to display the blocking SPID as well. If I didn't do this and someone opens a transaction, updates records and doesn't close the transaction, their SPID's status will be Sleeping, so you will see that any spid trying to access the record(s) are blocked, but you won't know anything about the SPID doing the blocking.

I'd love feedback, is there something I should add to this to make it more useful? Please follow my blog and leave me some feedback.

P.s. because this is being placed in the master database and has the sp_ prefix you can call this from any database by just executing: "sp_whom" no need for exec or master.. or anything.

Friday, September 16, 2011

Deleting ZZ'd Objects

If you are like me, you have some method or process of checking that a given table/proc/etc. is safe to be dropped prior to dropping it. My current method is to do some checks, see how often stuff is being used, search code, then to rename the object ZZ_. I let the object exist for two weeks as ZZ_ before I finally script it out and drop it.

I decided to write a little script to search out the names of all my ZZ'd objects on a server (specifically User Tables, Procs and Agent Jobs) and store them in a temp table. Next I email the list to my development team offering them one last chance to save the object, and set about scripting it out. The script also creates a DROP script for you to run, so when you are ready, you can just run the script.

Works pretty well. Please comment below on how you facilitate removing old objects, is your method different from mine?




/*******************************
** Created By: Eric Zierdt **
** ericzierdt@gmail.com **
** ericemployed.blogspot.com **
*******************************/
IF object_id('tempdb..#ObjectList') IS NOT NULL
BEGIN
DROP TABLE #ObjectList
END
CREATE TABLE #ObjectList
(
DBName VARCHAR(100)
,ObjectName VARCHAR(100)
,ObjectType VARCHAR(2)
,ObjectType_Desc VARCHAR(100)
)

DECLARE @DBName AS VARCHAR(MAX)
,@SQL AS VARCHAR(MAX)

DECLARE ZCursor CURSOR FOR
SELECT name
FROM sys.databases
WHERE owner_sid <> '0x01'
ORDER BY name
OPEN ZCursor
FETCH NEXT FROM ZCursor
INTO @DBName
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT 'Starting ' + @DBName
SET @SQL = 'USE [' + @DBName + ']
SELECT ''' + @DBName + ''' AS DBName, name,type,type_desc FROM sys.objects WHERE name LIKE ''%%zz%%'' ORDER BY CASE WHEN type = ''U'' THEN 1 ELSE 2 END, name
'
INSERT INTO #ObjectList
( DBName, ObjectName,ObjectType,ObjectType_Desc )
EXEC (@SQL)
FETCH NEXT FROM ZCursor
INTO @DBName
END
CLOSE ZCursor
DEALLOCATE ZCursor

USE msdb
INSERT INTO #ObjectList
( DBName, ObjectName,ObjectType,ObjectType_Desc )
SELECT 'msdb',name,'A','Agent Job'
FROM dbo.sysjobs
WHERE name LIKE '%%zz%'


-- SELECT * FROM #ObjectList

-- RUN THE CODE BELOW TO PRINT OUT THE DROP COMMANDS FOR THE OBJECTS
/*
DECLARE @DBName AS VARCHAR(MAX)
,@SQL AS VARCHAR(MAX)
,@ObjectName AS VARCHAR(MAX)
,@ObjectType AS VARCHAR(2)
,@Job_ID VARCHAR(257)
DECLARE DeleteCursor CURSOR FOR
SELECT DBName, ObjectName,ObjectType FROM #ObjectList --WHERE ObjectType = 'U'
OPEN DeleteCursor
FETCH NEXT FROM DeleteCursor
INTO @DBName,@ObjectName,@ObjectType
WHILE @@FETCH_STATUS = 0
BEGIN
IF @ObjectType = 'U'
BEGIN
SET @SQL = 'DROP TABLE [' + @DBName + '].[dbo].[' + @ObjectName + ']
GO'
END
ELSE IF @ObjectType = 'P'
BEGIN
SET @SQL = 'USE [' + @DBName + ']
DROP PROCEDURE [dbo].[' + @ObjectName + ']
GO'
END
ELSE IF @ObjectType = 'A'
BEGIN
SELECT @Job_ID = job_id FROM msdb.dbo.sysjobs_view WHERE name = N'' + @ObjectName + ''
SET @SQL = 'EXEC msdb.dbo.sp_delete_job @job_id=N''' + @Job_ID + ''', @delete_unused_schedule=1
GO'
END
ELSE
PRINT 'Unknown Object Type Found: [' + @ObjectType + ']'
PRINT @SQL
FETCH NEXT FROM DeleteCursor
INTO @DBName,@ObjectName,@ObjectType
END
CLOSE DeleteCursor
DEALLOCATE DeleteCursor
*/

Thursday, June 16, 2011

Restoring MSDB causes Log Shipping Failures

My situation is as follows, I have created a new Staging Server; we want everything to be as close as possible to our Production OLAP server, including the Job System...how best to do this?

I tired playing around with creating a linked server and copying stuff from msdb from primary to staging, but eventually I ran into problems with ID's and just couldn't make it work, so I decided to simply copy the msdb database from my OLAP server and restore it on my Staging server. Sounds simple right? Well, there were a number of problems that I ran into, specifically with regards to Log Shipping; with some help from Google and Twitter, I was able to resolve the issues and wanted to post the fixes to help any of you that run into the same issues.

FYI, I'm running SQL Server 2008 R2

First Error: Log Shipping jobs show a status of "Suspended" and I can't get them to do anything.
Fix: Thanks to http://www.sqlservercentral.com/Forums/Topic8379-7-1.aspx and user TVR, I found the answer; I needed to run:

use msdb
go
delete from msdb.dbo.syssubsystems
exec msdb.dbo.sp_verify_subsystems 1
go


And Restart the service.

Next problem: Log Shipping Copy's work fine, but Restores fail, saying "Error: Could not find a log backup file that could be applied to secondary database". This time help came from Twitter, where user @AngryPets a.k.a Michael K. Campbell pointed me in the direction of the msdb..log_shipping_monitor_secondary table. It took quite a bit of playing with it and the associated tables to figure out what needed to be reset/changed, but I was finally able to get it to work by doing this:

/*******************************
** Created By: Eric Zierdt **
** ericzierdt@gmail.com **
** ericemployed.blogspot.com **
*******************************/
UPDATE msdb.dbo.log_shipping_monitor_secondary
SET secondary_server = '[Staging_Server_Name]'
, last_restored_file = NULL -- Need to get rid of last restore data
WHERE secondary_server = '[Production_Server_Name]'

UPDATE msdb.dbo.log_shipping_secondary
SET monitor_server = '[Staging_Server_Name]'
WHERE monitor_server = '[Production_Server_Name]'


Simple enough, but took me forever to figure out.

Hope this helps, if so, drop me a comment.

Wednesday, June 8, 2011

Enable/Disable jobs

This post will probably not have mass appeal, but it's something I wrote recently that I find of value. The situation I was working with is that on our OLAP server, we have a number of "Invoke" agent jobs that fire off ever 2 minutes which go out and look to see if we need to process run our ETL's and process our cube. When we are doing releases or work on ETL's we want to disable all the Invoke jobs so they don't start. I'm sure you can think of other situations where this might be necessary outside of cube processing.

So one way to do this (arguably the faster way) is to open your job manager and highlight the invoke jobs and right-click and choose disable. But what if you have a few invokes disabled for one reason or another? You'll have to either remember which ones were disabled, or make a list, and make sure you don't re-enable those when you are done. Or, what if you want to wait for your current Invoke to end before you do the disable (not necessary, but what if), or you want to do it at a specific time of day?

I came up with a script that I put into two agent jobs to facilitate this. These can be scheduled and work pretty well.

The first job, creates a storage table, stores the id's for the enabled jobs, then disables them. (It checks to see if the job exists first and if so, error's out)
/*******************************
** Created By: Eric Zierdt **
** ericzierdt@gmail.com **
** ericemployed.blogspot.com **
*******************************/

IF OBJECT_ID('msdb.dbo.ActiveInvokeJobs') IS NULL
BEGIN
CREATE TABLE FRZ_ADMINDB.dbo.ActiveInvokeJobs (
job_id UNIQUEIDENTIFIER
, [Name] VARCHAR(255)
)
INSERT INTO msdb.dbo.ActiveInvokeJobs
( job_id, [Name])
SELECT job_id
,[Name]
FROM msdb.dbo.sysjobs S
WHERE enabled = 1
AND name LIKE '%invoke%'

 UPDATE msdb.dbo.sysjobs
SET enabled = 0
WHERE job_id IN (
SELECT job_id
FROM msdb.dbo.ActiveInvokeJobs
)
END
ELSE
BEGIN
RAISERROR ('Storage Table Already Exists.',16,1);
END




The next agent job checks to see if the storage table exists, and if so enables the disabled jobs, then deletes the storage table.
/*******************************
** Created By: Eric Zierdt **
** ericzierdt@gmail.com **
** ericemployed.blogspot.com **
*******************************/

IF OBJECT_ID('msdb.dbo.ActiveInvokeJobs') IS NOT NULL
BEGIN
UPDATE msdb.dbo.sysjobs
SET enabled = 1
WHERE job_id IN (
SELECT job_id
FROM msdb.dbo.ActiveInvokeJobs
)

DROP TABLE msdb.dbo.ActiveInvokeJobs

END
ELSE
BEGIN
RAISERROR ('Storage Table Does Not Exist.',16,1);
END

Thursday, April 21, 2011

Getting Object Counts

Recently I was reporting a bug I noticed with a 3rd party tool, the support group asked me to send them "the number of instances, number of databases per instance, total number of tables and total number of indexes." Now I knew the number of instances I was monitoring, and I knew the approximate number of tables (perhaps a good DBA should know this number, not sure...do other DBA's out there with larger servers know the exact number? comment below, I'm interested), but I had no idea how many indexes. So I wrote a little script to give me this number and as I like to do, I'm making it available to the community, hope this helps you...if you find use of it (even years in the future) post below.


/***********************************
** Author: Eric Zierdt **
** Date: 4/21/2011 **
** Email: eric.zierdt@gmail.com **
***********************************/

DECLARE @CountAll AS TABLE (CntName VARCHAR(100), Cnt INT)

/*******************************************
** GET COUNT OF ALL NON-SYSTEM DATABASES **
*******************************************/
INSERT INTO @CountAll
SELECT 'TotalDBs',COUNT(1) AS TotalDBs
FROM sys.databases D
WHERE owner_sid <> '0x01'


/******************************
** GET COUNT OF ALL TABLES **
** FOR NON-SYSTEM DATABASES **
******************************/
DECLARE @CountTable AS TABLE (DB VARCHAR(100),CNT INT)
DECLARE @SQL VARCHAR(MAX)
DECLARE @DBName VARCHAR(128)
SET @DBName = ''
WHILE @DBName < (
SELECT MIN(name)
FROM sys.databases
WHERE name > @DBName
AND name NOT IN ('master','model','msdb','tempdb')
)
BEGIN
SELECT @DBName = MIN(NAME) FROM sys.databases WHERE name > @DBName AND NAME NOT IN ('master','model','msdb','tempdb')
SET @SQL = '
USE [' + @DBName + ']
SELECT ''' + @DBName + ''' AS DBName
,COUNT(1) AS Cnt
FROM sys.tables
'
INSERT INTO @CountTable
EXEC (@SQL)
END

INSERT INTO @CountAll
SELECT 'TotalTables',SUM(CNT) AS TotalTables
FROM @CountTable

/*******************************
** GET COUNT OF ALL INDEXES **
** FOR NON-SYSTEM DATABASES **
*******************************/
DECLARE @IndexTable AS TABLE (DB VARCHAR(100),TableName VARCHAR(100), CNT INT)
SET @DBName = ''
WHILE @DBName < (
SELECT MIN(name)
FROM sys.databases
WHERE name > @DBName
AND name NOT IN ('master','model','msdb','tempdb')
)
BEGIN
SELECT @DBName = MIN(NAME) FROM sys.databases WHERE name > @DBName AND NAME NOT IN ('master','model','msdb','tempdb')
SET @SQL = '
USE [' + @DBName + ']
SELECT ''' + @DBName + ''' AS DBName
,OBJECT_NAME(I.object_id) AS TableName
, COUNT(1) AS Cnt
FROM sys.indexes I
JOIN sys.tables T ON I.object_id = T.object_id
WHERE I.name IS NOT NULL
GROUP BY OBJECT_NAME(I.object_id)
'
--PRINT @SQL
INSERT INTO @IndexTable
EXEC (@SQL)
END

INSERT INTO @CountAll
SELECT 'TotalIndexes',SUM(CNT) AS TotalIndexes
FROM @IndexTable

SELECT *
FROM @CountAll

Thursday, March 31, 2011

GUIDS mess up defragmenting

I'm sure most of you know already that the use of GUIDS or UniqueIdentifiers is messy for doing defragmenting; because they are not sequential, they tend to cause problems for indexes and while you can decrease your FillFactor, I found that I'd rather not defrag an index only to find it at 99% fragmented again within a few hours.

I wrote a little script to help me identify the indexes that have an included column which is of type UniqueIdentifier.


-- CHANGE THE DB TO THE ONE YOU WANT TO SEE INDEXES WITH GUIDS IN THEM

;WITH LIST AS (
SELECT p.object_id
,OBJECT_NAME(p.object_id) AS TableName
,I.name AS IndexName
,C.Name AS ColName
,T.name AS DataType
FROM sys.partitions P
JOIN sysobjects O ON P.object_id = object_id(O.name)
JOIN sys.indexes I ON I.object_id = P.object_id AND I.index_id = P.index_id
JOIN sys.index_columns IC ON p.object_id = IC.object_id AND p.index_id = IC.index_id
JOIN sys.columns C ON P.object_id = C.object_id AND IC.column_id = C.column_id
JOIN sys.types T ON c.system_type_id = T.system_type_id
WHERE T.name = 'uniqueidentifier'
AND P.partition_number = 1
AND O.xtype='U'
)
SELECT DISTINCT *
FROM LIST
ORDER BY TableName,ColName

Thursday, January 6, 2011

Second to last Friday in Month

I was tasked with creating a SQL Agent Job that would run on the 2nd to last Friday every month; but how to do that? The 3rd Friday of every month isn't necessarily the 2nd to last Friday...The Job Scheduler has an option for "LAST" x of the month, but not 2nd to last, so after some thought I decided to write a function that would do it for me. Now, I'm happy to see any comments from people on a better way of doing this, but this is what I came up with, hope it helps you, or spawns some ideas for you.

Before you can implment the main function, you'll need to have a function that returns the first day of a given month, and the last day of a given month....Ok, you probably don't need them as functions, but I like them that way...



SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =====================================================================
-- Author: Eric Zierdt: ericzierdt@gmail.com
-- Create date: 01/12/2010
-- Description: Returns the Last day of the month
-- Usage: SELECT dbo.LastOfMonth(GetDate())
-- =====================================================================
CREATE FUNCTION [dbo].[LastOfMonth]
(
-- Add the parameters for the function here
@DTC DATE -- DateToCheck
)
RETURNS DATE
AS
BEGIN
-- Declare the return variable here
DECLARE @Result DATE

-- Add the T-SQL statements to compute the return value here
SELECT @Result = CAST(DATEADD(d,-1,DATEADD(mm,DATEDIFF(m,0,@DTC)+1, 0)) AS DATE)

-- Return the result of the function
RETURN @Result

END




SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO


-- =====================================================================
-- Author: Eric Zierdt: ericzierdt@gmail.com
-- Create date: 01/12/2010
-- Description: Returns the first day of the month
-- Usage: SELECT dbo.FirstOfMonth(GetDate())
-- =====================================================================
CREATE FUNCTION [dbo].[FirstOfMonth]
(
-- Add the parameters for the function here
@DTC DATE -- DateToCheck
)
RETURNS DATE
AS
BEGIN
-- Declare the return variable here
DECLARE @Result DATE

-- Add the T-SQL statements to compute the return value here
SELECT @Result = CAST(DATEADD(ms,0,DATEADD(mm,DATEDIFF(m,0,@DTC), 0)) AS DATE)

-- Return the result of the function
RETURN @Result

END


And now for the main attraction:



SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

-- =====================================================================
-- Author: Eric Zierdt: ericzierdt@gmail.com
-- Create date: 01/06/2011
-- Description: Returns the Nth last of the given month
-- Usage: SELECT dbo.NthLastDoWOfMonth(GetDate(),6,1)
-- =====================================================================
CREATE FUNCTION [dbo].[NthLastDoWOfMonth]
(
-- Add the parameters for the function here
@MonthToCheck DATE -- MonthToCheck
,@DayOfWeek INT -- 1=Sunday...7=Saturday
,@WeeksFromLast INT-- 0=Last @DayOfWeek of the month, 1=2nd to last @DayOfWeek of the month, etc.
)
RETURNS DATE
AS
BEGIN
DECLARE @DaysInMonth TABLE (DayOfMonth DATE, DayOfWeek INT)

DECLARE @FirstOfMonth DATE
,@LastOfMonth DATE
,@ThisDay DATE
,@Result DATE

SELECT @FirstOfMonth = dbo.FirstOfMonth(@MonthToCheck), @LastOfMonth = dbo.LastOfMonth(@MonthToCheck)
SET @ThisDay = @FirstOfMonth
WHILE @ThisDay <= @LastOfMonth
BEGIN
INSERT INTO @DaysInMonth
SELECT @ThisDay, DATEPART(dw,@ThisDay)
SET @ThisDay = DATEADD(d,1,@ThisDay)
END

;WITH DaysCTE AS (
SELECT DayOfMonth ,ROW_NUMBER() OVER(ORDER BY DayOfMonth) AS 'RowNumber'
FROM @DaysInMonth DIM
WHERE DayOfWeek = @DayOfWeek
)
, MaxRow AS (
SELECT MAX(RowNumber) AS MaxRowNbr
FROM DaysCTE
)
SELECT @Result = DaysCTE.DayOfMonth
FROM DaysCTE, MaxRow
WHERE DaysCTE.RowNumber = MaxRow.MaxRowNbr-@WeeksFromLast

RETURN @Result

END


For some reason I can't figure out, there seems to be a /day tag at the end of the scirpt...it's not in my code, it appears to be in the exact spot as the code stating the end of my SQL...not sure, ignore it.

Tuesday, November 2, 2010

SQLSaturday #58 Presentation

Last Friday I had the opportunity to present a track on Table and index partitioning at SQLSaturday #58 (yes, SQLSaturday on a Friday) in Minnesota.

I had a great time, met a lot of great people and found the entire experience very enjoyable; I want to present more.

I said I'd put my queries up on my blog; so here it is.

Script 1 which was here is how to create a very basic partition and add values to it and move it (create a folder on your c drive called: PartitionDB prior to starting


/**************************************
** Database Partitioning Script **
** Eric Zierdt, W3i **
** http://ericemployed.blogspot.com **
** http://blog.w3i.com **
**************************************/
USE master
GO
CREATE DATABASE PartitionDB ON
PRIMARY(NAME = db_data, FILENAME = 'c:\PartitionDB\db.mdf' ,SIZE = 25MB)
, FILEGROUP FG1( NAME = FG1_data, FILENAME = 'c:\PartitionDB\FG1.ndf' ,SIZE = 25MB)
, FILEGROUP FG2( NAME = FG2_data, FILENAME = 'c:\PartitionDB\FG2.ndf', SIZE = 25MB)
, FILEGROUP FG3( NAME = FG3_data, FILENAME = 'c:\PartitionDB\FG3.ndf', SIZE = 25MB)
, FILEGROUP FG4( NAME = FG4_data, FILENAME = 'c:\PartitionDB\FG4.ndf', SIZE = 25MB)
, FILEGROUP FG5( NAME = FG5_data, FILENAME = 'c:\PartitionDB\FG5.ndf', SIZE = 25MB)
, FILEGROUP FGDefault( NAME = FGDefault_data, FILENAME = 'c:\PartitionDB\FGDefault.ndf', SIZE = 25MB)
LOG ON( NAME = db_log, FILENAME = 'c:\PartitionDB\log.ldf', SIZE = 1MB,FILEGROWTH = 100MB ) ;
GO
USE PartitionDB
GO

CREATE PARTITION FUNCTION EZ_PartitionFunction (INT) AS
RANGE RIGHT FOR VALUES (1000, 2000, 3000, 4000, 5000);

CREATE PARTITION SCHEME EZ_PartitionScheme AS
PARTITION EZ_PartitionFunction TO([FGDefault],[FG1], [FG2], [FG3], [FG4], [FG5])
GO


CREATE TABLE EZ_PartionedTable
( ID int PRIMARY KEY,
Name VARCHAR(50)
)
ON EZ_PartitionScheme(ID)


INSERT INTO EZ_PartionedTable (ID,NAME)
VALUES (1,'Test')
,(1001,'Test')
,(2001,'Test')
,(3001,'Test')
,(4001,'Test')
,(5001,'Test')
,(6001,'Test')
,(7001,'Test')
,(8001,'Test')

USE [master]
GO
ALTER DATABASE [PartitionDB] ADD FILEGROUP [FG6]
GO
ALTER DATABASE [PartitionDB] ADD FILE ( NAME = N'FG6_data', FILENAME = N'C:\PartitionDB\FG6.ndf' , SIZE = 25MB , FILEGROWTH = 5MB )
TO FILEGROUP [FG6]
GO
USE PartitionDB
GO

-- Adding a new Scheme and Function
ALTER PARTITION SCHEME EZ_PartitionScheme NEXT USED [FG6]

ALTER PARTITION FUNCTION EZ_PartitionFunction() SPLIT RANGE (6000)



-- Removing a Scheme and Function
ALTER PARTITION FUNCTION EZ_PartitionFunction() MERGE RANGE (6000)





-- Adding a new Scheme and Function
ALTER PARTITION SCHEME EZ_PartitionScheme NEXT USED [FG6]

ALTER PARTITION FUNCTION EZ_PartitionFunction() SPLIT RANGE (6000)

-- Removing a Scheme and Function out of Sequence
ALTER PARTITION FUNCTION EZ_PartitionFunction ()MERGE RANGE (5000)


ALTER PARTITION SCHEME EZ_PartitionScheme NEXT USED [FG5]

ALTER PARTITION FUNCTION EZ_PartitionFunction() SPLIT RANGE (5000)

USE master
GO



Note that the USE Master at the bottom is so that in the next script (which I had in different files/tabs) when you drop the DB, you don't have an error about someone being connected.

Script 2 was used to demonstrate large volume of data being merged and split and how quickly the data goes from one table to another when you use the ALTER TABLE - SWITCH. When I gave the presentation, I had a subfolder created previously that had a Database with 8 Million rows already created. This wont work over the blog, so you'll need to create the table and dump in the 8M rows yourself....So I'm taking out the part about dropping the table and attaching the other database.


/**************************************
** Database Partitioning Script **
** Eric Zierdt, W3i **
** http://ericemployed.blogspot.com **
** http://blog.w3i.com **
**************************************/

/*** DROP TABLE AND PARTITION ***/
USE PartitionDB
DROP TABLE EZ_PartionedTable
DROP PARTITION SCHEME EZ_PartitionScheme
DROP PARTITION FUNCTION EZ_PartitionFunction
ALTER DATABASE [PartitionDB] REMOVE FILE [FG6_data]
GO
ALTER DATABASE [PartitionDB] REMOVE FILEGROUP [FG6]
GO

/*** CREATE NEW PARTITION FUNCTION BASED ON MILLION RECORDS ***/
CREATE PARTITION FUNCTION EZ_PartitionFunction (INT) AS
RANGE RIGHT FOR VALUES (1000000, 2000000, 3000000, 4000000, 5000000);

/*** CREATE NEW PARTITION SCHEME ***/
CREATE PARTITION SCHEME EZ_PartitionScheme AS
PARTITION EZ_PartitionFunction TO([FGDefault],[FG1], [FG2], [FG3], [FG4], [FG5])
GO

/*** CREATE NEW TABLE ***/
CREATE TABLE EZ_PartionedTable
( ID int NOT NULL IDENTITY (1000000, 1),
Name VARCHAR(50)
)
ON EZ_PartitionScheme(ID)

/*** ADD PK TO TABLE ***/
ALTER TABLE dbo.EZ_PartionedTable ADD CONSTRAINT
PK_EZ_PartionedTable PRIMARY KEY CLUSTERED
(
ID
) WITH( STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON EZ_PartitionScheme(ID)

GO

/*** LOAD 8 MILLION RECORDS...Go get some food, this will take a while... ***/
DECLARE @i INT = 1
WHILE @i <= 8000000
BEGIN
INSERT INTO EZ_PartionedTable (NAME)
VALUES ('Test')
SET @i += 1
END


/*** ADD A NEW FILEGROUP TO THE DATABASE ***/
USE [master]
GO
ALTER DATABASE [PartitionDB] ADD FILEGROUP [FG6]
GO
ALTER DATABASE [PartitionDB] ADD FILE ( NAME = N'FG6_data', FILENAME = N'C:\PartitionDB\FG6.ndf' , SIZE = 25MB , FILEGROWTH = 5MB )
TO FILEGROUP [FG6]
GO
USE PartitionDB
GO



/*** ADD A NEW FILEGROUP TO THE PARTITION ***/
ALTER PARTITION SCHEME EZ_PartitionScheme NEXT USED [FG6]

ALTER PARTITION FUNCTION EZ_PartitionFunction() SPLIT RANGE (6000000)
--NOTE THE LOG WILL GROW SIGNIFIGANTLY (look in your data directory, the log will grow to around 1.2 GB)
--The point of this is to say, that you need to be careful when using SPLIT and MERGE..doing it to a an empty range is ok, but if the range has data, it's dangerous

/*** SHRINK LOG ***/
USE [PartitionDB]
GO
DBCC SHRINKFILE (N'db_log' , 1)
GO

/*** REMOVE FILEGROUP FROM THE PARTITION ***/
ALTER PARTITION FUNCTION EZ_PartitionFunction ()MERGE RANGE (6000000)

/*** SHRINK LOG ***/
USE [PartitionDB]
GO
DBCC SHRINKFILE (N'db_log' , 1)
GO

/*** SHRINK LOG ***/
USE [PartitionDB]
GO
DBCC SHRINKFILE (N'FG6_data' , 25)
GO

/*** CREATE STAGE TABLE FOR SWITCH ***/
CREATE TABLE EZ_PartionedTable_Stage
( ID int NOT NULL IDENTITY (1000000, 1),
Name VARCHAR(50)
)
ON EZ_PartitionScheme(ID)

ALTER TABLE dbo.EZ_PartionedTable_Stage ADD CONSTRAINT
PK_EZ_PartionedTable_Stage PRIMARY KEY CLUSTERED
(
ID
) WITH( STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON EZ_PartitionScheme(ID)
GO

--SHOW View Table Partition Data and explain what SWITCH DOES
ALTER TABLE EZ_PartionedTable SWITCH PARTITION 6 TO EZ_PartionedTable_Stage PARTITION 6

ALTER TABLE EZ_PartionedTable_Stage SWITCH PARTITION 6 TO EZ_PartionedTable PARTITION 6

--SHOW Dropping of data and removing old file group.
ALTER TABLE EZ_PartionedTable SWITCH PARTITION 6 TO EZ_PartionedTable_Stage PARTITION 6
DROP TABLE EZ_PartionedTable_Stage

ALTER DATABASE [PartitionDB] REMOVE FILE [FG6_data]
GO
ALTER DATABASE [PartitionDB] REMOVE FILEGROUP [FG6]
GO

/*** SHRINK LOG ***/
USE [PartitionDB]
GO
DBCC SHRINKFILE (N'FG5_data' , 25)
GO

USE master
GO


Script 3 is a real life example of how my company uses Partitioning. It uses a date based range; and shows the process we use to move and drop the oldest data:


/**************************************
** Database Partitioning Script **
** Eric Zierdt, W3i **
** http://ericemployed.blogspot.com **
** http://blog.w3i.com **
**************************************/

USE master
GO
ALTER DATABASE [PartitionDB] SET SINGLE_USER WITH ROLLBACK IMMEDIATE
GO
USE [master]
GO
DROP DATABASE PartitionDB
GO

/*** CREATE DB WITH FILEGROUP NAMES THAT ARE DATE BASED - AUGUST, SEPTEMBER AND OCTOBER 2010 ***/
CREATE DATABASE PartitionDB ON
PRIMARY(NAME = db_data, FILENAME = 'c:\PartitionDB\db.mdf' ,SIZE = 4MB)
, FILEGROUP TRANDTA_201008 ( NAME = TRANDTA_201008, FILENAME = 'c:\PartitionDB\TRANDTA_201008.ndf' ,SIZE = 25MB)
, FILEGROUP TRANDTA_201009( NAME = TRANDTA_201009, FILENAME = 'c:\PartitionDB\TRANDTA_201009.ndf', SIZE = 25MB)
, FILEGROUP TRANDTA_201010( NAME = TRANDTA_201010, FILENAME = 'c:\PartitionDB\TRANDTA_201010.ndf', SIZE = 25MB)
, FILEGROUP TRANDEFAULT( NAME = TRANDEFAULT_data, FILENAME = 'c:\PartitionDB\FGDefault.ndf', SIZE = 25MB)
LOG ON( NAME = db_log, FILENAME = 'c:\PartitionDB\log.ldf', SIZE = 1MB,FILEGROWTH = 100MB ) ;
GO
USE PartitionDB
GO

/*** MAKE A PARTITION FUNCTION WITH RANGES FOR 08,09,10 2010 ***/
CREATE PARTITION FUNCTION [EZ_PartitionFunction](DATETIME) AS RANGE RIGHT FOR VALUES (
N'2010-08-01'
, N'2010-09-01'
, N'2010-10-01')
GO

/*** BIND THE SCHEME TO THE FUNCTION ***/
CREATE PARTITION SCHEME EZ_PartitionScheme AS
PARTITION EZ_PartitionFunction TO(
[TRANDEFAULT]
, [TRANDTA_201008]
, [TRANDTA_201009]
, [TRANDTA_201010])
GO

/*** CREATE A TABLE AND BIND IT TO THE PARTITION ***/
CREATE TABLE EZ_PartionedTable
( ID int,
DateAdded DATETIME PRIMARY KEY,
Name VARCHAR(50)
)
ON EZ_PartitionScheme(DateAdded)

/*** INSERT SOME DATA INTO THE NEW TABLE, 3 RECORDS PER MONTH ***/
INSERT INTO EZ_PartionedTable (ID,DateAdded, NAME)
VALUES (1,'08/01/2010', 'Test')
,(2,'08/10/2010','Test')
,(3,'08/31/2010','Test')
,(4,'09/01/2010','Test')
,(5,'09/15/2010','Test')
,(6,'09/30/2010 23:59:59','Test')
,(7,'10/01/2010','Test')
,(8,'10/07/2010','Test')
,(9,'10/22/2010','Test')



/*** On around the 25th of each month, we fire off an agent job that calls a
proc that makes a new month filegroup, file, function and scheme ***/
USE [master]
GO
ALTER DATABASE [PartitionDB] ADD FILEGROUP [TRANDTA_201011]
GO
ALTER DATABASE [PartitionDB] ADD FILE ( NAME = N'TRANDTA_201011', FILENAME = N'C:\PartitionDB\TRANDTA_201011.ndf' , SIZE = 25MB , FILEGROWTH = 5MB )
TO FILEGROUP [TRANDTA_201011]
GO
USE PartitionDB
GO

ALTER PARTITION SCHEME EZ_PartitionScheme NEXT USED [TRANDTA_201011]

ALTER PARTITION FUNCTION EZ_PartitionFunction() SPLIT RANGE ('11/01/2010')


/*** INSERT A RECORD FOR OCTOBER AND CHECK THE VIEW PARTITION SCRIPT ***/
INSERT INTO EZ_PartionedTable (ID,DateAdded, NAME)
VALUES (1,'10/31/2010', 'Test')

/*** INSERT A RECORD FOR NOVEMBER AND CHECK THE VIEW PARTITION SCRIPT ***/
INSERT INTO EZ_PartionedTable (ID,DateAdded, NAME)
VALUES (2,'11/01/2010', 'Test')


/*** Within the first few days of the month we verify that the partitions are correct, then we run a proc that does this: ***/
-- MAKE A STAGING TABLE THAT IS EXACTLY THE SAME AS THE MAIN TABLE
CREATE TABLE EZ_PartionedTable_Stage
( ID int,
DateAdded DATETIME PRIMARY KEY,
Name VARCHAR(50)
)
ON EZ_PartitionScheme(DateAdded)

/*** SWITCH OUT THE OLDEST MONTH'S PARTITION DATA TO THE STAGING TABLE ***/
ALTER TABLE EZ_PartionedTable SWITCH PARTITION 2 TO EZ_PartionedTable_Stage PARTITION 2

/**** BCP OUT DATA (NOT SHOWN HERE) ****/

/*** DROP STAGING DATA (AND ALL THE DATA FROM THE OLDEST MONTH WITH IT) ***/
DROP TABLE EZ_PartionedTable_Stage

/*** DROP THE FUNCTION RANGE FOR THE OLDEST MONTH ***/
ALTER PARTITION FUNCTION EZ_PartitionFunction() MERGE RANGE ('8/01/2010')
GO
/*** DROP THE FILEGROUP AND FILE FOR THE OLDEST MONTH ***/
ALTER DATABASE [PartitionDB] REMOVE FILE [TRANDTA_201008]
GO
ALTER DATABASE [PartitionDB] REMOVE FILEGROUP [TRANDTA_201008]
GO


--DMV's that are useful:

SELECT *
FROM sys.partition_functions

SELECT *
FROM sys.partition_schemes
-- Joins to Function on function_id

SELECT *
FROM sys.partition_range_values
-- Joins to Function on function_id

SELECT *
FROM sys.indexes
-- Joins to schemes on data_space_id

SELECT *
FROM sys.data_spaces
-- Joins to indexes on data_space_id

SELECT *
FROM sys.filegroups
-- Joins to indexes on data_space_id


The final script was a script to show how many records are in each filegroup/range; I find it is very useful for me for many different situations.


/**************************************
** Database Partitioning Script **
** Eric Zierdt, W3i **
** http://ericemployed.blogspot.com **
** http://blog.w3i.com **
**************************************/

USE PartitionDB
DECLARE @TableName VARCHAR(150) = '%%'
,@FileGroup VARCHAR(150) = '%%'

SELECT OBJECT_NAME(p.object_id) AS TableName,
i.name AS IndexName,
p.partition_number AS PartitionNumber,
fg.name AS FileGroupName,
prv_left.value AS LowerBoundaryValue,
prv_right.value AS UpperBoundaryValue,
p.rows AS Rows
FROM sys.partitions AS p
JOIN sys.indexes AS i ON i.object_id = p.object_id AND i.index_id = p.index_id
JOIN sys.data_spaces AS ds ON ds.data_space_id = i.data_space_id
JOIN sys.partition_schemes AS ps ON ps.data_space_id = ds.data_space_id
JOIN sys.partition_functions AS pf ON pf.function_id = ps.function_id
JOIN sys.destination_data_spaces AS dds2 ON dds2.partition_scheme_id = ps.data_space_id AND dds2.destination_id = p.partition_number
JOIN sys.filegroups AS fg ON fg.data_space_id = dds2.data_space_id
LEFT JOIN sys.partition_range_values AS prv_left ON ps.function_id = prv_left.function_id AND prv_left.boundary_id = p.partition_number - 1
LEFT JOIN sys.partition_range_values AS prv_right ON ps.function_id = prv_right.function_id AND prv_right.boundary_id = p.partition_number
WHERE OBJECTPROPERTY(p.object_id, 'ISMSShipped') = 0
AND OBJECT_NAME(p.object_id) LIKE @TableName
AND fg.name LIKE @FileGroup
ORDER BY TableName, IndexName, PartitionNumber;

USE master