Browse Source

Adding files for SQL Performance Baseline

Amit Banerjee 9 years ago
parent
commit
cc39eb19a0

+ 208 - 0
SQL-Performance-Baseline/CREATECollectionJob.sql

@@ -0,0 +1,208 @@
+
+USE [msdb]
+GO
+EXEC msdb.dbo.sp_set_sqlagent_properties @email_save_in_sent_folder=1, 
+		@alert_replace_runtime_tokens=1, 
+		@use_databasemail=1
+GO
+
+/****** Object:  Job [DBA - Performance Statistics]    Script Date: 12/10/2014 2:15:35 PM ******/
+BEGIN TRANSACTION
+DECLARE @ReturnCode INT
+SELECT @ReturnCode = 0
+/****** Object:  JobCategory [Database Maintenance]    Script Date: 12/10/2014 2:15:35 PM ******/
+IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'PerfMon Collection' AND category_class=1)
+BEGIN
+EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'PerfMon Collection'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+
+END
+
+DECLARE @jobId BINARY(16)
+EXEC @ReturnCode =  msdb.dbo.sp_add_job @job_name=N'DBA - PerfMon Counter Collection', 
+		@enabled=1, 
+		@notify_level_eventlog=2, 
+		@notify_level_email=0, 
+		@notify_level_netsend=0, 
+		@notify_level_page=0, 
+		@delete_level=0, 
+		@description=N'Collect performance counters for SQL Server baselining', 
+		@category_name=N'PerfMon Collection', 
+		@owner_login_name=N'sa', @job_id = @jobId OUTPUT
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+/****** Object:  Step [Get PerfMon data]    Script Date: 12/10/2014 2:15:35 PM ******/
+EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Get PerfMon data', 
+		@step_id=1, 
+		@cmdexec_success_code=0, 
+		@on_success_action=1, 
+		@on_success_step_id=0, 
+		@on_fail_action=2, 
+		@on_fail_step_id=0, 
+		@retry_attempts=0, 
+		@retry_interval=0, 
+		@os_run_priority=0, @subsystem=N'CmdExec', 
+		@command=N'C:\WINDOWS\system32\WindowsPowerShell\v1.0\powershell.exe C:\Scripts\Get-SQLPerfCounters.ps1 -S $(ESCAPE_NONE(SRVR))', 
+		@flags=32
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Every 5 Minutes', 
+		@enabled=1, 
+		@freq_type=4, 
+		@freq_interval=1, 
+		@freq_subday_type=4, 
+		@freq_subday_interval=5, 
+		@freq_relative_interval=0, 
+		@freq_recurrence_factor=0, 
+		@active_start_date=20140903, 
+		@active_end_date=99991231, 
+		@active_start_time=0, 
+		@active_end_time=235959, 
+		@schedule_uid=N'c469be3f-e33b-4a9e-a02f-4a70db2012bd'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+COMMIT TRANSACTION
+GOTO EndSave
+QuitWithRollback:
+    IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
+EndSave:
+
+GO
+
+USE [msdb]
+GO
+
+/****** Object:  Job [DBA - Load Session Status per minute]    Script Date: 2/1/2016 11:08:14 AM ******/
+BEGIN TRANSACTION
+DECLARE @ReturnCode INT
+SELECT @ReturnCode = 0
+/****** Object:  JobCategory [DBA]    Script Date: 2/1/2016 11:08:14 AM ******/
+IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'DBA' AND category_class=1)
+BEGIN
+EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'DBA'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+
+END
+
+DECLARE @jobId BINARY(16)
+EXEC @ReturnCode =  msdb.dbo.sp_add_job @job_name=N'DBA - Load Session Status per minute', 
+		@enabled=1, 
+		@notify_level_eventlog=0, 
+		@notify_level_email=0, 
+		@notify_level_netsend=0, 
+		@notify_level_page=0, 
+		@delete_level=0, 
+		@description=N'This job runs every minutes to capture the status of all the sessions running on the instance and loads it in the dbo.Sessionstatus table in dba_local', 
+		@category_name=N'DBA', 
+		@owner_login_name=N'sa', @job_id = @jobId OUTPUT
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+/****** Object:  Step [Load Session Status]    Script Date: 2/1/2016 11:08:15 AM ******/
+EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Load Session Status', 
+		@step_id=1, 
+		@cmdexec_success_code=0, 
+		@on_success_action=1, 
+		@on_success_step_id=0, 
+		@on_fail_action=2, 
+		@on_fail_step_id=0, 
+		@retry_attempts=0, 
+		@retry_interval=0, 
+		@os_run_priority=0, @subsystem=N'TSQL', 
+		@command=N'exec dbo.spLoadSessionStatus', 
+		@database_name=N'dba_local', 
+		@flags=0
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Load Session status per min', 
+		@enabled=1, 
+		@freq_type=4, 
+		@freq_interval=1, 
+		@freq_subday_type=4, 
+		@freq_subday_interval=1, 
+		@freq_relative_interval=0, 
+		@freq_recurrence_factor=0, 
+		@active_start_date=20150817, 
+		@active_end_date=99991231, 
+		@active_start_time=0, 
+		@active_end_time=235959, 
+		@schedule_uid=N'9b226349-52b8-4e4a-8219-ef062a524757'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+COMMIT TRANSACTION
+GOTO EndSave
+QuitWithRollback:
+    IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
+EndSave:
+
+GO
+
+
+/****** Object:  Job [Load SystemHealthSession]    Script Date: 7/26/2016 12:26:37 PM ******/
+BEGIN TRANSACTION
+DECLARE @ReturnCode INT
+SELECT @ReturnCode = 0
+/****** Object:  JobCategory [DBA]    Script Date: 7/26/2016 12:26:37 PM ******/
+IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'DBA' AND category_class=1)
+BEGIN
+EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'DBA'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+
+END
+
+DECLARE @jobId BINARY(16)
+EXEC @ReturnCode =  msdb.dbo.sp_add_job @job_name=N'Load SystemHealthSession', 
+		@enabled=1, 
+		@notify_level_eventlog=0, 
+		@notify_level_email=0, 
+		@notify_level_netsend=0, 
+		@notify_level_page=0, 
+		@delete_level=0, 
+		@description=N'This job load the system health session xel trace files to tables in dba_local every morning at 2AM', 
+		@category_name=N'DBA', 
+		@owner_login_name=N'sa', @job_id = @jobId OUTPUT
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+/****** Object:  Step [Load SystemHealthSession]    Script Date: 7/26/2016 12:26:38 PM ******/
+EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Load SystemHealthSession', 
+		@step_id=1, 
+		@cmdexec_success_code=0, 
+		@on_success_action=1, 
+		@on_success_step_id=0, 
+		@on_fail_action=2, 
+		@on_fail_step_id=0, 
+		@retry_attempts=0, 
+		@retry_interval=0, 
+		@os_run_priority=0, @subsystem=N'TSQL', 
+		@command=N'exec dbo.spLoadSystemHealthSession', 
+		@database_name=N'dba_local', 
+		@flags=0
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Daily 2AM', 
+		@enabled=1, 
+		@freq_type=4, 
+		@freq_interval=1, 
+		@freq_subday_type=1, 
+		@freq_subday_interval=0, 
+		@freq_relative_interval=0, 
+		@freq_recurrence_factor=0, 
+		@active_start_date=20160726, 
+		@active_end_date=99991231, 
+		@active_start_time=20000, 
+		@active_end_time=235959, 
+		@schedule_uid=N'7507f377-9fe9-46b5-ba54-0b3a20965091'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
+IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
+COMMIT TRANSACTION
+GOTO EndSave
+QuitWithRollback:
+    IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
+EndSave:
+
+GO
+
+
+

+ 104 - 0
SQL-Performance-Baseline/CREATEDATABASE.sql

@@ -0,0 +1,104 @@
+USE [master]
+GO
+
+/****** Object:  Database [dba_local]    Script Date: 12/10/2014 2:12:24 PM ******/
+CREATE DATABASE [dba_local] ON  PRIMARY 
+( NAME = N'dba_local', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\DATA\dba_local.mdf' , SIZE = 10240MB , MAXSIZE = UNLIMITED, FILEGROWTH = 0)
+ LOG ON 
+( NAME = N'dba_local_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\DATA\dba_local_log.LDF' , SIZE = 1024MB , MAXSIZE = 2048GB , FILEGROWTH = 0)
+GO
+
+ALTER DATABASE [dba_local] SET COMPATIBILITY_LEVEL = 100
+GO
+
+IF (1 = FULLTEXTSERVICEPROPERTY('IsFullTextInstalled'))
+begin
+EXEC [dba_local].[dbo].[sp_fulltext_database] @action = 'enable'
+end
+GO
+
+ALTER DATABASE [dba_local] SET ANSI_NULL_DEFAULT ON 
+GO
+
+ALTER DATABASE [dba_local] SET ANSI_NULLS ON 
+GO
+
+ALTER DATABASE [dba_local] SET ANSI_PADDING ON 
+GO
+
+ALTER DATABASE [dba_local] SET ANSI_WARNINGS ON 
+GO
+
+ALTER DATABASE [dba_local] SET ARITHABORT ON 
+GO
+
+ALTER DATABASE [dba_local] SET AUTO_CLOSE OFF 
+GO
+
+ALTER DATABASE [dba_local] SET AUTO_CREATE_STATISTICS ON 
+GO
+
+ALTER DATABASE [dba_local] SET AUTO_SHRINK OFF 
+GO
+
+ALTER DATABASE [dba_local] SET AUTO_UPDATE_STATISTICS ON 
+GO
+
+ALTER DATABASE [dba_local] SET CURSOR_CLOSE_ON_COMMIT OFF 
+GO
+
+ALTER DATABASE [dba_local] SET CURSOR_DEFAULT  GLOBAL 
+GO
+
+ALTER DATABASE [dba_local] SET CONCAT_NULL_YIELDS_NULL ON 
+GO
+
+ALTER DATABASE [dba_local] SET NUMERIC_ROUNDABORT OFF 
+GO
+
+ALTER DATABASE [dba_local] SET QUOTED_IDENTIFIER ON 
+GO
+
+ALTER DATABASE [dba_local] SET RECURSIVE_TRIGGERS OFF 
+GO
+
+ALTER DATABASE [dba_local] SET  DISABLE_BROKER 
+GO
+
+ALTER DATABASE [dba_local] SET AUTO_UPDATE_STATISTICS_ASYNC OFF 
+GO
+
+ALTER DATABASE [dba_local] SET DATE_CORRELATION_OPTIMIZATION OFF 
+GO
+
+ALTER DATABASE [dba_local] SET TRUSTWORTHY OFF 
+GO
+
+ALTER DATABASE [dba_local] SET ALLOW_SNAPSHOT_ISOLATION OFF 
+GO
+
+ALTER DATABASE [dba_local] SET PARAMETERIZATION SIMPLE 
+GO
+
+ALTER DATABASE [dba_local] SET READ_COMMITTED_SNAPSHOT OFF 
+GO
+
+ALTER DATABASE [dba_local] SET HONOR_BROKER_PRIORITY OFF 
+GO
+
+ALTER DATABASE [dba_local] SET RECOVERY SIMPLE 
+GO
+
+ALTER DATABASE [dba_local] SET  MULTI_USER 
+GO
+
+ALTER DATABASE [dba_local] SET PAGE_VERIFY CHECKSUM  
+GO
+
+ALTER DATABASE [dba_local] SET DB_CHAINING OFF 
+GO
+
+ALTER DATABASE [dba_local] SET  READ_WRITE 
+GO
+
+

+ 521 - 0
SQL-Performance-Baseline/CREATEOBJECTS.sql

@@ -0,0 +1,521 @@
+USE [dba_local]
+GO
+
+/****** Object:  Table [dbo].[Sessionstatus]    Script Date: 2/1/2016 11:33:43 AM ******/
+SET ANSI_NULLS ON
+GO
+
+SET QUOTED_IDENTIFIER ON
+GO
+
+IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[Sessionstatus]') AND type in (N'U'))
+              BEGIN
+                     DROP TABLE dbo.[Sessionstatus]
+                     PRINT 'Table Sessionstatus exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
+              END
+
+IF NOT EXISTS (SELECT * FROM sys.objects WHERE OBJECT_ID = OBJECT_ID(N'[Sessionstatus]') AND TYPE IN (N'U'))
+BEGIN
+CREATE TABLE [dbo].[Sessionstatus](
+       [DateCaptured] [datetime] NULL,
+       [dbname] [nvarchar](100) NULL,
+       [status] [nvarchar](50) NULL,
+       [waittype] [nvarchar](100) NULL,
+       [waittime] [bigint] NULL,
+       [sessioncnt] [int] NULL,
+       [opentran] [int] NULL
+) ON [PRIMARY]
+PRINT 'Table Sessionstatus created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
+END
+GO
+
+
+DECLARE @is2012 bit
+
+BEGIN TRY
+       IF((SELECT CAST(REPLACE(LEFT(CAST(SERVERPROPERTY('ProductVersion') AS varchar(10)),2),'.','') AS int)) = 11)
+              SET @is2012 = 1
+       ELSE 
+              SET @is2012 = 0
+
+       IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[PerformanceCounterList]') AND type in (N'U'))
+              BEGIN
+                     DROP TABLE [PerformanceCounterList]
+                     PRINT 'Table PerformanceCounterList exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
+              END
+
+       IF NOT EXISTS (SELECT * FROM sys.objects WHERE OBJECT_ID = OBJECT_ID(N'[PerformanceCounterList]') AND TYPE IN (N'U'))
+              BEGIN
+                     CREATE TABLE [PerformanceCounterList](
+                           [counter_name] [VARCHAR](500) NOT NULL,
+                           [is_captured_ind] [BIT] NOT NULL,
+                     CONSTRAINT [PK_PerformanceCounterList] PRIMARY KEY CLUSTERED 
+                     (
+                           [counter_name] ASC
+                     )WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON, FILLFACTOR = 100) ON [PRIMARY]
+                     ) ON [PRIMARY]
+                     
+                     ALTER TABLE [PerformanceCounterList] ADD  CONSTRAINT [DF_PerformanceCounterList_is_captured_ind]  DEFAULT ((1)) FOR [is_captured_ind]
+                     
+                     PRINT 'Table PerformanceCounterList created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
+              END
+
+       IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[PerformanceCounter]') AND type in (N'U'))
+              BEGIN
+                     DROP TABLE [PerformanceCounter]
+                     PRINT 'Table PerformanceCounter exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
+              END
+
+       IF NOT EXISTS (SELECT * FROM sys.objects WHERE OBJECT_ID = OBJECT_ID(N'[PerformanceCounter]') AND TYPE IN (N'U'))
+              BEGIN
+                     CREATE TABLE [PerformanceCounter](
+                           [CounterName] [VARCHAR](250) NOT NULL,
+                           [CounterValue] [VARCHAR](250) NOT NULL,
+                           [DateSampled] [DATETIME] NOT NULL,
+                     CONSTRAINT [PK_PerformanceCounter] PRIMARY KEY CLUSTERED 
+                     (
+                           [CounterName] ASC,
+                           [DateSampled] ASC
+                     )WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON, FILLFACTOR = 80) ON [PRIMARY]
+                     ) ON [PRIMARY]
+                     
+                     PRINT 'Table PerformanceCounter created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
+              END
+
+       IF  EXISTS (SELECT * FROM sys.views WHERE object_id = OBJECT_ID(N'[vPerformanceCounter]'))
+              BEGIN
+                     DROP VIEW [vPerformanceCounter]
+                     PRINT 'View vPerformanceCounter exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping view'
+              END
+
+       IF (@is2012 = 0)
+              BEGIN
+                     IF NOT EXISTS (SELECT * FROM sys.views WHERE OBJECT_ID = OBJECT_ID(N'[vPerformanceCounter]'))
+                           BEGIN
+                                  EXEC dbo.sp_executesql @statement = N'
+                                  CREATE VIEW [vPerformanceCounter]
+                                  AS
+                                  SELECT * FROM
+                                  (SELECT CounterName, CounterValue, DateSampled
+                                  FROM PerformanceCounter) AS T1
+                                  PIVOT
+                                  (
+                                  MAX(CounterValue)
+                                  FOR CounterName IN ([logicaldisk(_total)\avg. disk queue length],
+                                                                     [logicaldisk(_total)\avg. disk sec/read],
+                                                                     [logicaldisk(_total)\avg. disk sec/transfer],
+                                                                     [logicaldisk(_total)\avg. disk sec/write],
+                                                                     [logicaldisk(_total)\current disk queue length],
+                                                                     [memory\available mbytes],
+                                                                     [paging file(_total)\% usage],
+                                                                     [paging file(_total)\% usage peak],
+                                                                     [processor(_total)\% privileged time],
+                                                                     [processor(_total)\% processor time],
+                                                                     [process(sqlservr)\% privileged time],
+                                                                     [process(sqlservr)\% processor time],
+                                                                     [sql statistics\batch requests/sec],
+                                                                     [sql statistics\sql compilations/sec],
+                                                                     [sql statistics\sql re-compilations/sec],
+                                                                     [general statistics\user connections],
+                                                                     [buffer manager\page life expectancy],
+                                                                     [buffer manager\buffer cache hit ratio],
+                                                                     [memory manager\target server memory (kb)],
+                                                                     [memory manager\total server memory (kb)],
+                                                                     [buffer manager\checkpoint pages/sec],
+                                                                     [buffer manager\free pages],
+                                                                     [buffer manager\lazy writes/sec],
+                                                                     [transactions\free space in tempdb (kb)])
+                                  ) AS PT;
+                                  '
+                                  PRINT 'View vPerformanceCounter created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
+                           END 
+                     ELSE PRINT 'View vPerformanceCounter already exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
+              END
+       ELSE
+              BEGIN
+                     IF NOT EXISTS (SELECT * FROM sys.views WHERE OBJECT_ID = OBJECT_ID(N'[vPerformanceCounter]'))
+                           BEGIN
+                                  EXEC dbo.sp_executesql @statement = N'
+                                  CREATE VIEW [vPerformanceCounter]
+                                  AS
+                                  SELECT * FROM
+                                  (SELECT CounterName, CounterValue, DateSampled
+                                  FROM PerformanceCounter) AS T1
+                                  PIVOT
+                                  (
+                                  MAX(CounterValue)
+                                  FOR CounterName IN ([logicaldisk(_total)\avg. disk queue length],
+                                                                     [logicaldisk(_total)\avg. disk sec/read],
+                                                                    [logicaldisk(_total)\avg. disk sec/transfer],
+                                                                     [logicaldisk(_total)\avg. disk sec/write],
+                                                                     [logicaldisk(_total)\current disk queue length],
+                                                                     [memory\available mbytes],
+                                                                     [paging file(_total)\% usage],
+                                                                     [paging file(_total)\% usage peak],
+                                                                     [processor(_total)\% privileged time],
+                                                                     [processor(_total)\% processor time],
+                                                                     [process(sqlservr)\% privileged time],
+                                                                     [process(sqlservr)\% processor time],
+                                                                     [sql statistics\batch requests/sec],
+                                                                     [sql statistics\sql compilations/sec],
+                                                                     [sql statistics\sql re-compilations/sec],
+                                                                     [general statistics\user connections],
+                                                                     [buffer manager\page life expectancy],
+                                                                     [buffer manager\buffer cache hit ratio],
+                                                                     [memory manager\target server memory (kb)],
+                                                                     [memory manager\total server memory (kb)],
+                                                                     [buffer manager\checkpoint pages/sec],
+                                                                     [buffer manager\lazy writes/sec],
+                                                                     [transactions\free space in tempdb (kb)])
+                                  ) AS PT;
+                                  '
+                                  PRINT 'View vPerformanceCounter created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
+                           END 
+                     ELSE PRINT 'View vPerformanceCounter already exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
+              END
+
+       SET NOCOUNT ON
+
+       DECLARE @perfStr VARCHAR(100)
+       DECLARE @instStr VARCHAR(100)
+
+       SELECT @instStr = @@SERVICENAME
+       --SET @instStr = 'NI1'
+
+       IF(@instStr = 'MSSQLSERVER')
+              SET @perfStr = '\SQLServer'
+       ELSE 
+              SET @perfStr = '\MSSQL$' + @instStr
+
+       TRUNCATE TABLE PerformanceCounterList
+       PRINT 'Truncated table PerformanceCounterList'
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Memory\Pages/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Memory\Pages Input/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Memory\Available MBytes',1)
+              
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Processor(_Total)\% Processor Time',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Processor(_Total)\% Privileged Time',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Process(sqlservr)\% Privileged Time',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Process(sqlservr)\% Processor Time',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Paging File(_Total)\% Usage',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Paging File(_Total)\% Usage Peak',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\PhysicalDisk(_Total)\Avg. Disk sec/Read',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\PhysicalDisk(_Total)\Avg. Disk sec/Write',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\PhysicalDisk(_Total)\Disk Reads/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\PhysicalDisk(_Total)\Disk Writes/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\System\Processor Queue Length',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\System\Context Switches/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Page life expectancy',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Buffer cache hit ratio',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Checkpoint Pages/Sec',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Lazy Writes/Sec',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Page Reads/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Page Writes/Sec',0)
+
+       IF (@is2012 = 0)
+              INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+              VALUES        (@perfStr + ':Buffer Manager\Free Pages',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Page Lookups/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Free List Stalls/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Readahead pages/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Database Pages',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Target Pages',0)
+                     
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Total Pages',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        (@perfStr + ':Buffer Manager\Stolen Pages',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':General Statistics\User Connections',1)
+                     
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':General Statistics\Processes blocked',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':General Statistics\Logins/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':General Statistics\Logouts/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Memory Manager\Memory Grants Pending',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Memory Manager\Total Server Memory (KB)',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Memory Manager\Target Server Memory (KB)',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Memory Manager\Granted Workspace Memory (KB)',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Memory Manager\Maximum Workspace Memory (KB)',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Memory Manager\Memory Grants Outstanding',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':SQL Statistics\Batch Requests/sec',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':SQL Statistics\SQL Compilations/sec',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':SQL Statistics\SQL Re-Compilations/sec',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':SQL Statistics\Auto-Param Attempts/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Locks(_Total)\Lock Waits/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Locks(_Total)\Lock Requests/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Locks(_Total)\Lock Timeouts/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Locks(_Total)\Number of Deadlocks/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Locks(_Total)\Lock Wait Time (ms)',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Locks(_Total)\Average Wait Time (ms)',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Latches\Total Latch Wait Time (ms)',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Latches\Latch Waits/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Latches\Average Latch Wait Time (ms)',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Access Methods\Forwarded Records/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Access Methods\Full Scans/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Access Methods\Page Splits/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Access Methods\Index Searches/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Access Methods\Workfiles Created/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Access Methods\Worktables Created/Sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Access Methods\Table Lock Escalations/sec',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Cursor Manager by Type(_Total)\Active cursors',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Transactions\Longest Transaction Running Time',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Transactions\Free Space in tempdb (KB)',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES (@perfStr + ':Transactions\Version Store Size (KB)',0)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\LogicalDisk(*)\Avg. Disk Queue Length',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\LogicalDisk(*)\Avg. Disk sec/Read',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\LogicalDisk(*)\Avg. Disk sec/Transfer',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\LogicalDisk(*)\Avg. Disk sec/Write',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\LogicalDisk(*)\Current Disk Queue Length',1)
+
+       INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
+       VALUES        ('\Paging File(*)\*',1)
+
+       PRINT 'Inserts to table PerformanceCounterList completed'
+
+       IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[ClearPerfCtrHistory]') AND type in (N'P', N'PC'))
+              BEGIN
+                     DROP PROCEDURE [ClearPerfCtrHistory]
+                     PRINT 'Stored Procedure ClearPerfCtrHistory exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping stored procedure'
+              END
+
+       IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[ClearPerfCtrHistory]') AND type in (N'P', N'PC'))
+              BEGIN
+                     EXEC dbo.sp_executesql @statement = N'
+
+                     CREATE PROCEDURE [ClearPerfCtrHistory]
+                           @old_date     INT = 180
+                     AS
+
+                     --******************************************************************************************************
+                     --*    Created date : September 2014
+                     --* Purpose:         Clears out performance counter history  
+                     --*
+                     --* Usage:        EXEC ClearPerfCtrHistory: procedure can be called with no parameters and default 
+                     --*                                                                 180 day history will be used
+                     --*                       
+                     --*                                             --OR-- specify the optional parameter below to customize history duration
+                     --*
+                     --*             EXEC ClearBackupHistory
+                     --*                         @old_date              --number of days of history to delete
+                     --*
+                     --*****************************************************************************************************
+
+                     SET NOCOUNT ON
+                     SET XACT_ABORT ON
+
+                     BEGIN TRY
+
+                           IF EXISTS(SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N''[PerformanceCounter]'') AND type in (N''U''))
+                                  BEGIN
+                                         DELETE dbo.PerformanceCounter 
+                                         WHERE DateSampled < DATEADD(dd,-@old_date, dateadd(dd, datediff(dd,0, GETDATE()),0))
+                                  END
+
+                     END TRY
+                     BEGIN CATCH
+
+                           IF (XACT_STATE()) != 0
+                                  ROLLBACK TRANSACTION;
+                            
+                           DECLARE @errMessage varchar(MAX)
+                           SET @errMessage = ''Stored procedure '' + OBJECT_NAME(@@PROCID) + '' failed with error '' + CAST(ERROR_NUMBER() AS VARCHAR(20)) + ''. '' + ERROR_MESSAGE() 
+                           RAISERROR (@errMessage, 16, 1)
+                                  
+                     END CATCH
+                     '
+                     PRINT 'Stored procedure ClearPerfCtrHistory created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) 
+              END
+END TRY
+BEGIN CATCH
+       DECLARE @errMessage varchar(MAX) = ERROR_MESSAGE()
+       PRINT @errMessage
+       
+       IF EXISTS(SELECT 1 FROM master.sys.databases WHERE name = 'dba_local')
+              AND EXISTS (SELECT 1 FROM dba_local.sys.objects WHERE name = N'install_usp_logevent' AND type in (N'P', N'PC'))
+                     BEGIN
+                           EXEC [dba_local].[dbo].[install_usp_logevent] @errMessage
+                     END
+END CATCH
+
+GO
+
+
+
+/****** Object:  StoredProcedure [dbo].[spLoadSessionStatus]    Script Date: 2/1/2016 10:56:17 AM ******/
+
+ IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[spLoadSessionStatus]') AND type in (N'P', N'PC'))
+              BEGIN
+                     DROP PROCEDURE dbo.[spLoadSessionStatus]
+                     PRINT 'Procedure spLoadSessionStatus exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
+              END;
+IF  NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[spLoadSessionStatus]') AND type in (N'P', N'PC'))
+			BEGIN
+				EXEC dbo.sp_executesql @statement = N'CREATE PROC [dbo].[spLoadSessionStatus] 
+				AS
+				BEGIN
+				delete from dbo.Sessionstatus where DateCaptured < DATEADD(dd,-5,getdate());
+				INSERT INTO dbo.Sessionstatus
+				SELECT Getdate() as "Date Captured", DB_NAME(database_id) as "Database Name" ,status,wait_type,SUM(wait_time) as [Wait in ms],COUNT(r.session_id) as [Session Count],SUM(open_transaction_count) as [Open Transactions]
+				from  sys.dm_exec_requests r  
+				where 
+				r.blocking_session_id = 0 and r.status NOT IN (''suspended'',''background'') 
+				group by status,DB_NAME(database_id),wait_type
+
+				UNION ALL
+
+				SELECT Getdate() as "Date Captured", DB_NAME(database_id) as "Database Name" ,status,wait_type, SUM(wait_time) as [Wait in ms], COUNT(r.session_id) as [Session Count],SUM(open_transaction_count) as [Open Transactions]
+				from  sys.dm_exec_requests r  
+				where 
+				r.blocking_session_id = 0 and r.status = ''suspended''
+				group by status,DB_NAME(database_id),wait_type
+
+				UNION ALL
+
+				SELECT Getdate() as "Date Captured", DB_NAME(database_id) as "Database Name",''blocked'',wait_type, SUM(wait_time) as [Wait in ms],COUNT(r.session_id) as [Session Count],SUM(open_transaction_count) as [Open Transactions]
+				from  sys.dm_exec_requests r  
+				where 
+				-- r.session_id > 50 and 
+				r.blocking_session_id <> 0
+				GROUP BY DB_NAME(database_id),wait_type
+
+				UNION ALL
+
+				SELECT Getdate() as "Date Captured", DB_NAME(database_id) as "Database Name",s.status,s.lastwaittype , SUM(s.waittime) as [Wait in ms],COUNT(s.spid) as [Session Count],SUM(s.open_tran) as [Open Transactions]
+				from  sys.sysprocesses s  left join sys.dm_exec_requests r
+				on s.spid = r.session_id
+				where 
+				r.session_id is NULL 
+				GROUP BY DB_NAME(database_id),s.status,s.lastwaittype
+				END';
+			PRINT 'Procedure spLoadSessionStatus created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
+		END
+GO
+

+ 778 - 0
SQL-Performance-Baseline/CreateSystemhealthDBAndSchema.sql

@@ -0,0 +1,778 @@
+/**************************
+ This Sample Code is provided for the purpose of illustration only and is not intended to be used in a production environment. THIS SAMPLE CODE AND ANY RELATED INFORMATION ARE PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE IMPLIED WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A PARTICULAR PURPOSE. We grant You a nonexclusive, royalty-free right to use and modify the Sample Code and to reproduce and distribute the object code form of the Sample Code, provided that You agree: (i) to not use Our name, logo, or trademarks to market Your software product in which the Sample Code is embedded; (ii) to include a valid copyright notice on Your software product in which the Sample Code is embedded; and (iii) to indemnify, hold harmless, and defend Us and Our suppliers from and against any claims or lawsuits, including attorneys’ fees, that arise or result from the use or distribution of the Sample Code.
+ Author: Denzil Ribeiro
+ Date: Jan 6, 2013
+ Description:
+ This T-SQL script extracts information found in the System Health Session and puts them into a permanent tables in a database you create
+*/
+/*
+use master
+go
+drop database XEvents_ImportSystemHealth
+go
+
+
+Create Database XEvents_ImportSystemHealth
+go
+Alter Database XEvents_ImportSystemHealth SET RECOVERY SIMPLE;
+USE [XEvents_ImportSystemHealth]
+GO
+*/
+/****** Object:  StoredProcedure [dbo].[sp_ImportXML]    Script Date: 1/25/2013 3:39:13 PM ******/
+use dba_local
+GO
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[sp_ImportXML]
+@path_to_health_session nvarchar(4000)
+as
+If object_id('tbl_XEImport') is not null
+	drop table tbl_XEImport
+select [object_name] ,CAST(event_data AS XML)  as c1
+into tbl_XEImport
+from sys.fn_xe_file_target_read_file(@path_to_health_session,NULL,NULL,NULL)
+
+create index ind_xeImport on tbl_XEImport(object_name)
+
+If object_id('tbl_ServerDiagnostics') is not null
+	drop table tbl_ServerDiagnostics
+	select c1.value('(event/data[@name="component"]/text)[1]', 'varchar(100)') as SdComponent,c1  
+	into tbl_ServerDiagnostics
+	from tbl_XEImport
+	where object_name = 'sp_server_diagnostics_component_result'
+/*
+else
+select c1.value('(event/data[@name="component"]/value)[1]', 'varchar(100)') as SdComponent,c1  
+	into tbl_ServerDiagnostics
+	from tbl_XEImport 
+	where object_name = 'component_health_result'
+*/
+--create index ind_ServerDiagnostics on tbl_ServerDiagnostics(SdComponent)
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadComponentSummary]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadComponentSummary]
+@UTDDateDiff int
+as
+if object_id('tbl_Summary') is not null
+drop table tbl_Summary
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as timestamp,
+	 c1.value('(event/data[@name="component"]/text)[1]', 'varchar(100)') as component_name,
+	 c1.value('(event/data[@name="state"]/text)[1]', 'varchar(100)') as [component_state]
+/*
+     CASE c1.value('(event/data[@name="component"]/text)[1]', 'varchar(100)')
+		WHEN '' then  c1.value('(event/data[@name="component"]/text)[1]', 'varchar(100)')
+		ELSE c1.value('(event/data[@name="component"]/value)[1]', 'varchar(100)')
+	 END as component_name,
+	 CASE c1.value('(event/data[@name="state"]/text)[1]', 'varchar(100)') 
+	   WHEN '' then c1.value('(event/data[@name="state"]/text)[1]', 'varchar(100)') 
+	   ELSE c1.value('(event/data[@name="state_desc"]/value)[1]', 'varchar(100)') 
+	  END as [component_state]
+*/
+into tbl_Summary
+FROM tbl_ServerDiagnostics 
+
+CREATE NONCLUSTERED INDEX [Ind_TblSummary] ON [dbo].[tbl_Summary]
+(
+	[timestamp] ASC
+)WITH (SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ONLINE = OFF) ON [PRIMARY]
+
+
+GO
+/****** Object:  StoredProcedure [dbo].[spLoadConnectivity_ring_buffer]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[spLoadConnectivity_ring_buffer]
+@UTDDateDiff int
+as
+if object_id('tbl_connectivity_ring_buffer') is not null
+drop table tbl_connectivity_ring_buffer
+
+  select 
+   c1.value('(./event/@timestamp)[1]', 'datetime') as utctimestamp,
+  	DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+              c1.value('(./event/data[@name="type"]/text)[1]', 'varchar(100)') AS [Type],
+              c1.value('(./event/data[@name="id"]/value)[1]', 'bigint') as record_id,
+			  c1.value('(./event/data[@name="source"]/text)[1]', 'varchar(20)') as source,
+			  c1.value('(./event/data[@name="session_id"]/value)[1]', 'int') as session_id,
+			  c1.value('(./event/data[@name="os_error"]/value)[1]', 'bigint') as os_error,
+			  c1.value('(./event/data[@name="sni_error"]/value)[1]', 'bigint') as sni_error,
+			  c1.value('(./event/data[@name="sni_consumer_error"]/value)[1]', 'bigint') as sni_consumer_error,
+			  c1.value('(./event/data[@name="state"]/value)[1]', 'int') as [state],
+			  c1.value('(./event/data[@name="port"]/value)[1]', 'int') as port,
+			  c1.value('(./event/data[@name="remote_port"]/value)[1]', 'int') as remote_port,
+			  c1.value('(./event/data[@name="tds_input_buffer_error"]/value)[1]', 'bigint') as tds_inputbuffererror,
+			  c1.value('(./event/data[@name="total_login_time_ms"]/value)[1]', 'bigint') as total_login_time_ms,
+			  c1.value('(./event/data[@name="login_task_enqueued_ms"]/value)[1]', 'bigint') as login_task_enqueued_ms,
+			  c1.value('(./event/data[@name="network_writes_ms"]/value)[1]', 'bigint') as network_writes_ms,
+			  c1.value('(./event/data[@name="network_reads_ms"]/value)[1]', 'bigint') as network_reads_ms,
+			  c1.value('(./event/data[@name="ssl_processing_ms"]/value)[1]', 'bigint') as ssl_processing_ms,
+			  c1.value('(./event/data[@name="sspi_processing_ms"]/value)[1]', 'bigint') as sspi_processing_ms,
+			  c1.value('(./event/data[@name="login_trigger_and_resource_governor_processing_ms"]/value)[1]', 'bigint') as login_trigger_and_resource_governor_processing_ms,
+			  c1.value('(./event/data[@name="connection_id"]/value)[1]', 'varchar(50)') as connection_id,
+			  c1.value('(./event/data[@name="connection_peer_id"]/value)[1]', 'varchar(50)') as connection_peer_id,
+			  c1.value('(./event/data[@name="local_host"]/value)[1]', 'varchar (50)') as local_host,
+			  c1.value('(./event/data[@name="remote_host"]/value)[1]', 'varchar (50)') as remote_host,
+			  c1.value('(./event/data[@name="SessionIsKilled"]/value)[1]', 'smallint') as SessionIsKilled
+	into tbl_connectivity_ring_buffer
+	from tbl_XEImport where  object_name =  'connectivity_ring_buffer_recorded'              
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadErrorRecorded]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadErrorRecorded]
+@UTDDateDiff int
+as
+if object_id('tbl_errors') is not null
+drop table tbl_errors
+select 
+			c1.value('(./event/@timestamp)[1]', 'datetime') as utctimestamp,
+			DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+			c1.value('(./event/data[@name="session_id"])[1]', 'int') as session_id,
+			c1.value('(./event/data[@name="database_id"])[1]', 'int') as database_id,
+			c1.value('(./event/data[@name="error_number"])[1]', 'int') as [error_number],
+			c1.value('(./event/data[@name="severity"])[1]', 'int') as severity,
+			c1.value('(./event/data[@name="state"])[1]', 'int') as [state],
+			c1.value('(./event/data[@name="category"]/text)[1]', 'nvarchar(100)') as category,
+			c1.value('(./event/data[@name="destination"]/text)[1]', 'nvarchar(100)') as destination,
+			c1.value('(./event/data[@name="message"])[1]', 'nvarchar(1000)') as message
+
+into tbl_errors		
+from tbl_XEImport
+where object_name like 'error_reported'
+GO
+
+/****** Object:  StoredProcedure [dbo].[SpLoadIO_SUBSYSTEMComponent]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadIO_SUBSYSTEMComponent]
+@UTDDateDiff int
+as
+if object_id('tbl_IO_SUBSYSTEM') is not null
+drop table tbl_IO_SUBSYSTEM
+select 
+     c1.value('(./event/@timestamp)[1]', 'datetime') as UTCtimestamp,
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as timestamp,
+     c1.value('(event/data[@name="component"]/text)[1]', 'varchar(100)') as [component_name],
+	 c1.value('(event/data[@name="state"]/text)[1]', 'varchar(100)') as [component_state],
+	 c1.value('(event/data[@name="data"]/value/ioSubsystem/@ioLatchTimeouts)[1]','int') as [ioLatchTimeouts],
+	 c1.value('(event/data[@name="data"]/value/ioSubsystem/@intervalLongIos)[1]','int') as [intervalLongIos],
+ 	 c1.value('(event/data[@name="data"]/value/ioSubsystem/@totalLongIos)[1]','int') as [totalLongIos],	 
+	 c1.value('(event/data[@name="data"]/value/ioSubsystem/longestPendingRequests/pendingRequest[1]/@duration)[1]','bigint') as [longestPendingRequests_duration],
+	 c1.value('(event/data[@name="data"]/value/ioSubsystem/longestPendingRequests/pendingRequest[1]/@filePath)[1]','nvarchar(500)') as [longestPendingRequests_filePath],
+	 c1.value('(event/data[@name="data"]/value/ioSubsystem/longestPendingRequests/pendingRequest[1]/@offset)[1]','bigint') as [longestPendingRequests_offset],
+	 c1.value('(event/data[@name="data"]/value/ioSubsystem/longestPendingRequests/pendingRequest[1]/@handle)[1]','nvarchar(20)') as [longestPendingRequests_handle]
+into tbl_IO_SUBSYSTEM
+FROM tbl_ServerDiagnostics 
+where SdComponent = 'IO_SUBSYSTEM'
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadQueryProcessing]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadQueryProcessing]
+@UTDDateDiff int
+as
+if object_id('tbl_QUERY_PROCESSING') is not null
+drop table [tbl_QUERY_PROCESSING]
+select 
+			c1.value('(./event/@timestamp)[1]', 'datetime') as utctimestamp,
+			DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+			 c1.value('(event/data[@name="component"]/text)[1]', 'varchar(100)') as [component_name],
+			c1.value('(event/data[@name="state"]/text)[1]', 'varchar(100)') as [component_state],
+			c1.value('(./event//data[@name="data"]/value/queryProcessing/@maxWorkers)[1]', 'int') as maxworkers,
+			c1.value('(./event//data[@name="data"]/value/queryProcessing/@workersCreated)[1]', 'int') as workerscreated,
+			c1.value('(./event//data[@name="data"]/value/queryProcessing/@tasksCompletedWithinInterval)[1]', 'int') as tasksCompletedWithinInterval,
+			c1.value('(./event//data[@name="data"]/value/queryProcessing/@oldestPendingTaskWaitingTime)[1]', 'bigint') as oldestPendingTaskWaitingTime,
+			c1.value('(./event//data[@name="data"]/value/queryProcessing/@pendingTasks)[1]', 'int') as pendingTasks,
+			c1.value('(./event//data[@name="data"]/value/queryProcessing/@hasUnresolvableDeadlockOccurred)[1]', 'int') as hasUnresolvableDeadlockOccurred,
+			c1.value('(./event//data[@name="data"]/value/queryProcessing/@hasDeadlockedSchedulersOccurred)[1]', 'int') as hasDeadlockedSchedulersOccurred,
+			c1.value('(./event//data[@name="data"]/value/queryProcessing/@trackingNonYieldingScheduler)[1]', 'varchar(10)') as trackingNonYieldingScheduler
+into [tbl_QUERY_PROCESSING]			
+from tblQryProcessingXmlOutput
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadQueryProcessingComponent]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadQueryProcessingComponent]
+@UTDDateDiff int
+as
+-- Import the XML
+If object_id('tblQryProcessingXmlOutput') is not null
+	drop table tblQryProcessingXmlOutput
+CREATE TABLE [dbo].[tblQryProcessingXmlOutput](
+	[c1] [xml] NULL
+) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
+
+insert into tblQryProcessingXmlOutput (c1)
+select c1 as snodes 
+FROM tbl_ServerDiagnostics 
+where SdComponent = 'QUERY_PROCESSING'
+	
+	
+-- Call individual Pieces
+exec SpLoadQueryProcessingComponent_TopWaits @UTDDateDiff
+exec SpLoadQueryProcessing @UTDDateDiff
+exec SpLoadQueryProcessingComponent_Blocking @UTDDateDiff
+--exec SpLoadQueryProcessingComponent_HighCPU @UTDDateDiff
+--exec SpLoadQueryProcessingComponent_QueryWaits @UTDDateDiff
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadQueryProcessingComponent_Blocking]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadQueryProcessingComponent_Blocking]
+@UTDDateDiff int
+as
+if object_id('tbl_BlockingXeOutput') is not null
+drop table tbl_BlockingXeOutput
+select
+	 [utctimestamp],[timestamp],
+	 c1.value('(blocked-process-report/blocking-process/process/inputbuf)[1]', 'nvarchar(max)') as [blocking_process],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@spid)[1]', 'int') as [blocking_process_id],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@ecid)[1]', 'int') as [blocking_process_ecid],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@status)[1]', 'varchar(100)') as [blocking_process_status],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@isolationlevel)[1]', 'varchar(200)') as [blocking_process_isolationlevel],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@lastbatchstarted)[1]', 'datetime') as [blocking_process_lastbatchstarted],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@lastbatchcompleted)[1]', 'datetime') as [blocking_process_lastbatchcompleted],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@lastattention)[1]', 'datetime') as [blocking_process_lastattention],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@trancount)[1]', 'int') as [blocking_process_trancount],
+	 c1.value('(blocked-process-report/blocking-process/process[1]/@xactid)[1]', 'bigint') as [blocking_process_xactid],
+	 c1.value('(/blocked-process-report/blocking-process/process[1]/@clientapp)[1]', 'nvarchar(100)') as [blocking_process_clientapp],
+	 c1.value('(/blocked-process-report/blocking-process/process[1]/@hostname)[1]', 'nvarchar(100)') as [blocking_process_hostname],
+	 c1.value('(/blocked-process-report/blocking-process/process[1]/@loginname)[1]', 'nvarchar(100)') as [blocking_process_loginname],
+	 c1.value('(/blocked-process-report/blocking-process/process[1]/@waitresource)[1]', 'nvarchar(200)') as [blocking_process_wait_resource],
+
+	 c1.value('(/blocked-process-report/blocked-process/process/inputbuf)[1]', 'nvarchar(max)') as [blocked_process],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@spid)[1]', 'int') as [blocked_process_id],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@ecid)[1]', 'int') as [blocked_process_ecid],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@status)[1]', 'varchar(100)') as [blocked_process_status],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@waitresource)[1]', 'nvarchar(200)') as [blocked_process_wait_resource],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@lockMode)[1]', 'char(5)') as [blocked_process_lockMode],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@waittime)[1]', 'nvarchar(200)') as [blocked_process_wait_time],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@lastbatchstarted)[1]', 'datetime') as [blocked_process_lastbatchstarted],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@lastbatchcompleted)[1]', 'datetime') as [blocked_process_lastbatchcompleted],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@lastattention)[1]', 'datetime') as [blocked_process_lastattention],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@clientapp)[1]', 'nvarchar(100)') as [blocked_process_clientapp],
+	 c1.value('(/value/blocked-process-report/blocked-process/process[1]/@hostname)[1]', 'nvarchar(100)') as [blocked_process_hostname],
+	 c1.value('(/blocked-process-report/blocked-process/process[1]/@loginname)[1]', 'nvarchar(100)') as [blocked_process_loginname]
+	 --T.bpnodes.value('(event/data[@name="blocked_process"]/value/blocked-process-report/blocking-process/process/executionstack/frame[1]/@sqlhandle)[1]', 'nvarchar(max)') as [blocking_process_sqlhandle]
+into tbl_BlockingXeOutput
+FROM 
+(
+select c1.value('(event/@timestamp)[1]','datetime') as [utctimestamp]
+		,DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp]
+		,T.blk.query( '.') as c1 from tblQryProcessingXmlOutput
+CROSS APPLY c1.nodes('./event/data[@name="data"]/value/queryProcessing/blockingTasks/blocked-process-report') as T(blk) 
+) as T1
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadQueryProcessingComponent_TopWaits]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadQueryProcessingComponent_TopWaits]
+@UTDDateDiff int
+as
+if object_id('tbl_OS_WAIT_STATS_byDuration') is not null
+drop table tbl_OS_WAIT_STATS_byDuration
+
+CREATE TABLE [dbo].[tbl_OS_WAIT_STATS_byDuration](
+	[UTCtimestamp] [datetime] NULL,
+	[timestamp] [datetime] NULL,
+	[wait_type] [varchar](47) NULL,
+	[waiting_tasks_count] [bigint] NULL,
+	[avg_wait_time_ms] [bigint] NULL,
+	[max_wait_time_ms] [bigint] NULL
+) ON [PRIMARY]
+ALTER TABLE [dbo].[tbl_OS_WAIT_STATS_byDuration] ADD [wait_category]  AS (case when [wait_type] like 'LCK%' then 'Locks' when [wait_type] like 'PAGEIO%' then 'Page I/O Latch' when [wait_type] like 'PAGELATCH%' then 'Page Latch (non-I/O)' when [wait_type] like 'LATCH%' then 'Latch (non-buffer)' when [wait_type] like 'IO_COMPLETION' then 'I/O Completion' when [wait_type] like 'ASYNC_NETWORK_IO' then 'Network I/O (client fetch)' when [wait_type]='CMEMTHREAD' OR [wait_type]='SOS_RESERVEDMEMBLOCKLIST' OR [wait_type]='RESOURCE_SEMAPHORE' then 'Memory' when [wait_type] like 'RESOURCE_SEMAPHORE_%' then 'Compilation' when [wait_type] like 'MSQL_XP' then 'XProc' when [wait_type] like 'WRITELOG' then 'Writelog' when [wait_type]='FT_IFTS_SCHEDULER_IDLE_WAIT' OR [wait_type]='WAITFOR' OR [wait_type]='EXECSYNC' OR [wait_type]='XE_TIMER_EVENT' OR [wait_type]='XE_DISPATCHER_WAIT' OR [wait_type]='WAITFOR_TASKSHUTDOWN' OR [wait_type]='WAIT_FOR_RESULTS' OR [wait_type]='SNI_HTTP_ACCEPT' OR [wait_type]='SLEEP_TEMPDBSTARTUP' OR [wait_type]='SLEEP_TASK' OR [wait_type]='SLEEP_SYSTEMTASK' OR [wait_type]='SLEEP_MSDBSTARTUP' OR [wait_type]='SLEEP_DCOMSTARTUP' OR [wait_type]='SLEEP_DBSTARTUP' OR [wait_type]='SLEEP_BPOOL_FLUSH' OR [wait_type]='SERVER_IDLE_CHECK' OR [wait_type]='RESOURCE_QUEUE' OR [wait_type]='REQUEST_FOR_DEADLOCK_SEARCH' OR [wait_type]='ONDEMAND_TASK_QUEUE' OR [wait_type]='LOGMGR_QUEUE' OR [wait_type]='LAZYWRITER_SLEEP' OR [wait_type]='KSOURCE_WAKEUP' OR [wait_type]='FSAGENT' OR [wait_type]='CLR_MANUAL_EVENT' OR [wait_type]='CLR_AUTO_EVENT' OR [wait_type]='CHKPT' OR [wait_type]='CHECKPOINT_QUEUE' OR [wait_type]='BROKER_TO_FLUSH' OR [wait_type]='BROKER_TASK_STOP' OR [wait_type]='BROKER_TRANSMITTER' OR [wait_type]='BROKER_RECEIVE_WAITFOR' OR [wait_type]='BROKER_EVENTHANDLER' OR [wait_type]='DBMIRROR_EVENTS_QUEUE' OR [wait_type]='DBMIRROR_DBM_EVENT' OR [wait_type]='DBMIRRORING_CMD' OR [wait_type]='DBMIRROR_WORKER_QUEUE' then 'IGNORABLE' else [wait_type] end)
+Create clustered index [tbl_OS_WAIT_STATS_byDuration_Clus] on [tbl_OS_WAIT_STATS_byDuration](timestamp)
+
+
+INSERT INTO [dbo].[tbl_OS_WAIT_STATS_byDuration]
+           ([UTCtimestamp]
+		    ,[timestamp]
+           ,[wait_type]
+           ,[waiting_tasks_count]
+           ,[avg_wait_time_ms]
+           ,[max_wait_time_ms])
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[1]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[1]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[1]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[1]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[2]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[2]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[2]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[2]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[3]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[3]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[3]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[3]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[4]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[4]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[4]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[4]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[5]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[5]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[5]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[5]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL 
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[6]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[6]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[6]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[6]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[7]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[7]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[7]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[7]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[8]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[8]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[8]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[8]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[9]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[9]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[9]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[9]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[10]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[10]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[10]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/nonPreemptive/byCount/wait[10]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[1]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[1]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[1]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[1]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[2]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[2]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[2]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[2]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[3]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[3]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[3]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[3]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[4]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[4]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[4]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[4]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[5]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[5]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[5]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[5]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL 
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[6]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[6]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[6]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[6]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[7]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[7]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[7]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[7]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[8]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[8]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[8]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[8]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[9]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[9]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[9]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[9]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+UNION ALL
+select 
+     c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+     c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[10]/@waitType)[1]','varchar(47)') as [waitType],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[10]/@waits)[1]','bigint') as [waits],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[10]/@averageWaitTime)[1]','bigint') as [averageWaitTime],
+	 c1.value('(event/data[@name="data"]/value/queryProcessing/topWaits/preemptive/byCount/wait[10]/@maxWaitTime)[1]','bigint') as [maxWaitTime]
+FROM tblQryProcessingXmlOutput
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadResourceComponent]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadResourceComponent]
+@UTDDateDiff int
+as
+if object_id('tbl_Resource') is not null
+	drop table tbl_Resource
+select 
+			c1.value('(./event/@timestamp)[1]', 'datetime') as UTCtimestamp,
+			DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+			c1.value('(./event//data[@name="state"]/text)[1]', 'varchar(20)') as State,
+			c1.value('(./event//data[@name="data"]/value/resource/@lastNotification)[1]', 'nvarchar(100)') as lastNotification,
+			c1.value('(./event//data[@name="data"]/value/resource/@outOfMemoryExceptions)[1]', 'tinyint') as outOfMemoryExceptions,
+			c1.value('(./event//data[@name="data"]/value/resource/@isAnyPoolOutOfMemory)[1]', 'tinyint') as isAnyPoolOutOfMemory,
+			c1.value('(./event//data[@name="data"]/value/resource/@processOutOfMemoryPeriod)[1]', 'tinyint') as processOutOfMemoryPeriod,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="Available Physical Memory"]/@value)[1]', 'bigint') as available_physical_memory,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="Available Virtual Memory"]/@value)[1]', 'bigint') as available_virtual_memory,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="Available Paging File"]/@value)[1]', 'bigint') as available_paging_file,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="Working Set"]/@value)[1]', 'bigint') as working_set,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="Percent of Committed Memory in WS"]/@value)[1]', 'bigint') as percent_workingset_committed,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="Page Faults"]/@value)[1]', 'bigint') as page_faults,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="System physical memory high"]/@value)[1]', 'bigint') as sys_physical_memory_high,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="System physical memory low"]/@value)[1]', 'bigint') as sys_physical_memory_low,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="Process physical memory low"]/@value)[1]', 'bigint') as process_phyiscal_memory_low,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Process/System Counts"]/entry[@description="Process virtual memory low"]/@value)[1]', 'bigint') as process_virtual_memory_low,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="VM Reserved"]/@value)[1]', 'bigint') as vm_reserved_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="VM Committed"]/@value)[1]', 'bigint') as vm_committed_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Locked Pages Allocated"]/@value)[1]', 'bigint') as locked_pages_allocated_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Large Pages Allocated"]/@value)[1]', 'bigint') as large_pages_allocated_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Target Committed"]/@value)[1]', 'bigint') as target_committed_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Current Committed"]/@value)[1]', 'bigint') as current_committed_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Pages Allocated"]/@value)[1]', 'bigint') as Pages_allocated_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Pages Reserved"]/@value)[1]', 'bigint') as pages_reserved_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Pages Free"]/@value)[1]', 'bigint') as pages_free_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Pages In Use"]/@value)[1]', 'bigint') as pages_in_use_kb,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Page Alloc Potential"]/@value)[1]', 'bigint') as page_alloc_potential,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="NUMA Growth Phase"]/@value)[1]', 'int') as numa_growth_phase,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Last OOM Factor"]/@value)[1]', 'int') as last_oom_factor,
+			c1.value('(./event//data[@name="data"]/value/resource/memoryReport[@name="Memory Manager"]/entry[@description="Last OS Error"]/@value)[1]', 'int') as last_os_error
+into tbl_Resource
+FROM  tbl_ServerDiagnostics
+where SdComponent = 'RESOURCE'
+
+
+GO
+/****** Object:  StoredProcedure [dbo].[spLoadSchedulerMonitor]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create Procedure [dbo].[spLoadSchedulerMonitor]
+@UTDDateDiff int
+as
+if object_id('tbl_scheduler_monitor') is not null
+drop table tbl_scheduler_monitor
+select 
+			c1.value('(./event/@timestamp)[1]', 'datetime') as UTCtimestamp,
+			DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+			c1.value('(./event/data[@name="id"])[1]', 'int') as [id],
+			c1.value('(./event/data[@name="process_utilization"])[1]', 'int') as process_utilization,
+			c1.value('(./event/data[@name="system_idle"])[1]', 'int') as system_idle,
+			c1.value('(./event/data[@name="user_mode_time"])[1]', 'bigint') as user_mode_time,
+			c1.value('(./event/data[@name="kernel_mode_time"])[1]', 'bigint') as kernel_mode_time,
+			c1.value('(./event/data[@name="working_set_delta"])[1]', 'numeric(24,0)') as working_set_delta,
+			c1.value('(./event/data[@name="memory_utilization"])[1]', 'int') as memory_utilization
+into tbl_scheduler_monitor			
+from tbl_XEImport
+where object_name like 'scheduler_monitor_system_health_ring_buffer_recorded'
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadSecurityRingBuffer]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadSecurityRingBuffer]
+@UTDDateDiff int
+as
+if object_id('tbl_security_ring_buffer') is not null
+drop table [tbl_security_ring_buffer]
+select 
+			c1.value('(./event/@timestamp)[1]', 'datetime') as utctimestamp,
+			DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+			c1.value('(./event/data[@name="id"])[1]', 'int') as id,
+			c1.value('(./event/data[@name="session_id"])[1]', 'int') as session_id,
+			c1.value('(./event/data[@name="error_code"])[1]', 'bigint') as [error_code],
+			c1.value('(./event/data[@name="api_name"])[1]', 'nvarchar(100)') as api_name,
+			c1.value('(./event/data[@name="calling_api_name"])[1]', 'nvarchar(100)') as calling_api_name
+
+into [tbl_security_ring_buffer]
+from tbl_XEImport
+where object_name like 'security_error_ring_buffer_recorded'
+
+GO
+/****** Object:  StoredProcedure [dbo].[SpLoadSYSTEMComponent]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[SpLoadSYSTEMComponent]
+@UTDDateDiff int
+as
+if object_id('tbl_SYSTEM') is not null
+drop table tbl_SYSTEM
+select 
+	 c1.value('(event/@timestamp)[1]','datetime') as [UTCtimestamp],
+	 DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as timestamp,
+	 c1.value('(event/data[@name="component"]/text)[1]', 'varchar(100)') as [component_name],
+	 c1.value('(event/data[@name="state"]/text)[1]', 'varchar(100)') as [component_state],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@spinlockBackoffs)[1]', 'int') as [spinlockBackoffs],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@sickSpinlockTypeAfterAv)[1]', 'varchar(100)') as [sickSpinlockTypeAfterAv],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@latchWarnings)[1]', 'int') as [latchWarnings],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@isAccessViolationOccurred)[1]', 'int') as [isAccessViolationOccurred],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@writeAccessViolationCount)[1]', 'int') as [writeAccessViolationCount],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@totalDumpRequests)[1]', 'int') as [totalDumpRequests],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@intervalDumpRequests)[1]', 'int') as [intervalDumpRequests],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@nonYieldingTasksReported)[1]', 'int') as [nonYieldingTasksReported],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@pageFaults)[1]', 'bigint') as [pageFaults],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@systemCpuUtilization)[1]', 'int') as [systemCpuUtilization],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@sqlCpuUtilization)[1]', 'int') as [sqlCpuUtilization],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@BadPagesDetected)[1]', 'int') as [BadPagesDetected],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@BadPagesFixed)[1]', 'int') as [BadPagesFixed],
+	 c1.value('(event/data[@name="data"]/value/system[1]/@LastBadPageAddress)[1]', 'nvarchar(30)') as [LastBadPageAddress]
+into tbl_SYSTEM	  
+FROM tbl_ServerDiagnostics 
+where SdComponent = 'SYSTEM'
+GO
+
+
+/****** Object:  StoredProcedure [dbo].[spLoadWaitQueries]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[spLoadWaitQueries]
+@UTDDateDiff int
+as
+if object_id('tbl_waitqueries') is not null
+drop table tbl_waitqueries
+SELECT
+c1.value('(./event/@timestamp)[1]', 'datetime') as utctimestamp,
+DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp],
+c1.value('(/event/data[@name="wait_type"]/text)[1]', 'varchar(50)') as WaitType,
+c1.value('(/event/data[@name="duration"]/value)[1]', 'bigint') as Duration,
+c1.value('(/event/data[@name="signal_duration"]/value)[1]', 'bigint') as signal_duration,
+c1.value('(/event/action[@name="session_id"]/value)[1]', 'int') as Session_ID,
+c1.value('(/event/action[@name="sql_text"]/value)[1]', 'varchar(max)') as sql_text
+into tbl_waitqueries
+FROM tbl_XEImport
+where object_name like  'wait_info%'
+GO
+
+
+
+
+/****** Object:  StoredProcedure [dbo].[spLoadDeadlockReport]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[spLoadDeadlockReport]
+@UTDDateDiff int
+as
+if object_id('tbl_DeadlockReport') is not null
+drop table tbl_DeadlockReport
+SELECT
+c1.value('(./event/@timestamp)[1]', 'datetime') as utctimestamp,
+DATEADD(mi,@UTDDateDiff,c1.value('(./event/@timestamp)[1]', 'datetime')) as [timestamp]
+, *
+into tbl_DeadlockReport
+FROM tbl_XEImport
+where object_name like  'xml_deadlock_report'
+GO
+
+
+
+
+/****** Object:  StoredProcedure [dbo].[spLoadSystemHealthSession]    Script Date: 1/25/2013 3:39:13 PM ******/
+SET ANSI_NULLS ON
+GO
+SET QUOTED_IDENTIFIER ON
+GO
+Create procedure [dbo].[spLoadSystemHealthSession]
+@path_to_health_session nvarchar(4000) = NULL ,
+@UTDDateDiff int = 0
+as
+
+if object_id('tbl_ImportStatus') is not null
+drop table tbl_ImportStatus
+Create table tbl_ImportStatus
+( StepName varchar(100),
+  Status varchar(20),
+  Starttime datetime
+)
+insert into tbl_ImportStatus Values('Load System Health Session','Processing',getdate())
+
+DECLARE @filename varchar(8000) ;
+IF (SUBSTRING(CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)),1,CHARINDEX('.',CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)))-1) >= 11)
+BEGIN
+
+	If ( @path_to_health_session is null or @path_to_health_session ='')
+	begin
+		SET @UTDDateDiff = DATEDIFF(mi,GETUTCDATE(),GETDATE())
+	-- Fetch information about the XEL file location
+	
+		SELECT @filename = CAST(target_data as XML).value('(/EventFileTarget/File/@name)[1]', 'varchar(8000)')
+		FROM sys.dm_xe_session_targets
+		WHERE target_name = 'event_file' and event_session_address = (select address from sys.dm_xe_sessions where name = 'system_health')
+		SET @path_to_health_session = SUBSTRING(@filename,1,CHARINDEX('system_health',@filename,1)-1) + 'system_health*.xel'
+		select @path_to_health_session,@filename, @UTDDateDiff
+	end
+
+	insert into tbl_ImportStatus Values('Importing XEL file','Processing',getdate())
+	exec sp_ImportXML @path_to_health_session 
+	
+	insert into tbl_ImportStatus Values('Load Scheduler Monitor','Processing',getdate())
+	exec spLoadSchedulerMonitor @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Load Resource Server Health Component','Processing',getdate())
+	exec SpLoadResourceComponent @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Load IO_Subsystem Server Health Component','Processing',getdate())
+	exec SpLoadIO_SUBSYSTEMComponent @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Load System Server Health Component','Processing',getdate())
+	exec SpLoadSYSTEMComponent @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Load System Health Summary','Processing',getdate())
+	exec SpLoadComponentSummary @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Load Query_Processing Server Health Component','Processing',getdate())
+	exec SpLoadQueryProcessingComponent @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Load Security Ring Buffer','Processing',getdate())
+	exec SpLoadSecurityRingBuffer @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Load Errors Recorded','Processing',getdate())
+	exec SpLoadErrorRecorded @UTDDateDiff
+	
+	insert into tbl_ImportStatus Values('Wait Queries','Processing',getdate())
+	exec spLoadWaitQueries @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Connectivity Ring Buffer','Processing',getdate())
+	exec spLoadConnectivity_ring_buffer @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Deadlock Report','Processing',getdate())
+	exec [spLoadDeadlockReport] @UTDDateDiff
+
+	insert into tbl_ImportStatus Values('Import Finished','Done',getdate())
+end
+Else 
+  select 'Not a supported Server version: ' + @@version
+
+GO
+
+/********** TODO
+CREATE INDEXES to improve performance
+
+****************/
+
+
+
+select 'Process System Health Session fom a SQL instance' as ImportMethod, 'Exec spLoadSystemHealthSession' as Example
+Union all
+select 'Process System Health XEL files from a UNC' as ImportMethod, 'exec spLoadSystemHealthSession @path_to_health_session=''D:\XELFiles\system_health*.xel'',@UTDDateDiff=-6' as Example
+
+/*
+exec spLoadSystemHealthSession @path_to_health_session='D:\XELFiles\system_health*.xel',@UTDDateDiff=-6
+Exec spLoadSystemHealthSession
+*/
+
+

BIN
SQL-Performance-Baseline/Get-SQLPerfCounters.ps1


+ 106 - 0
SQL-Performance-Baseline/Out-DataTable.ps1

@@ -0,0 +1,106 @@
+#######################
+function Get-Type
+{
+    param($type)
+
+$types = @(
+'System.Boolean',
+'System.Byte[]',
+'System.Byte',
+'System.Char',
+'System.Datetime',
+'System.Decimal',
+'System.Double',
+'System.Guid',
+'System.Int16',
+'System.Int32',
+'System.Int64',
+'System.Single',
+'System.UInt16',
+'System.UInt32',
+'System.UInt64')
+
+    if ( $types -contains $type ) {
+        Write-Output "$type"
+    }
+    else {
+        Write-Output 'System.String'
+        
+    }
+} #Get-Type
+
+#######################
+<#
+.SYNOPSIS
+Creates a DataTable for an object
+.DESCRIPTION
+Creates a DataTable based on an objects properties.
+.INPUTS
+Object
+    Any object can be piped to Out-DataTable
+.OUTPUTS
+   System.Data.DataTable
+.EXAMPLE
+$dt = Get-psdrive| Out-DataTable
+This example creates a DataTable from the properties of Get-psdrive and assigns output to $dt variable
+.NOTES
+Adapted from script by Marc van Orsouw see link
+Version History
+v1.0  - Chad Miller - Initial Release
+v1.1  - Chad Miller - Fixed Issue with Properties
+v1.2  - Chad Miller - Added setting column datatype by property as suggested by emp0
+v1.3  - Chad Miller - Corrected issue with setting datatype on empty properties
+v1.4  - Chad Miller - Corrected issue with DBNull
+v1.5  - Chad Miller - Updated example
+v1.6  - Chad Miller - Added column datatype logic with default to string
+v1.7 - Chad Miller - Fixed issue with IsArray
+.LINK
+http://thepowershellguy.com/blogs/posh/archive/2007/01/21/powershell-gui-scripblock-monitor-script.aspx
+#>
+function Out-DataTable
+{
+    [CmdletBinding()]
+    param([Parameter(Position=0, Mandatory=$true, ValueFromPipeline = $true)] [PSObject[]]$InputObject)
+
+    Begin
+    {
+        $dt = new-object Data.datatable  
+        $First = $true 
+    }
+    Process
+    {
+        foreach ($object in $InputObject)
+        {
+            $DR = $DT.NewRow()  
+            foreach($property in $object.PsObject.get_properties())
+            {  
+                if ($first)
+                {  
+                    $Col =  new-object Data.DataColumn  
+                    $Col.ColumnName = $property.Name.ToString()  
+                    if ($property.value)
+                    {
+                        if ($property.value -isnot [System.DBNull]) {
+                            $Col.DataType = [System.Type]::GetType("$(Get-Type $property.TypeNameOfValue)")
+                         }
+                    }
+                    $DT.Columns.Add($Col)
+                }  
+                if ($property.Gettype().IsArray) {
+                    $DR.Item($property.Name) =$property.value | ConvertTo-XML -AS String -NoTypeInformation -Depth 1
+                }  
+               else {
+                    $DR.Item($property.Name) = $property.value
+                }
+            }  
+            $DT.Rows.Add($DR)  
+            $First = $false
+        }
+    } 
+     
+    End
+    {
+        Write-Output @(,($dt))
+    }
+
+} #Out-DataTable

BIN
SQL-Performance-Baseline/Reporting.zip


+ 66 - 0
SQL-Performance-Baseline/Write-DataTable.ps1

@@ -0,0 +1,66 @@
+#######################
+<#
+.SYNOPSIS
+Writes data only to SQL Server tables.
+.DESCRIPTION
+Writes data only to SQL Server tables. However, the data source is not limited to SQL Server; any data source can be used, as long as the data can be loaded to a DataTable instance or read with a IDataReader instance.
+.INPUTS
+None
+    You cannot pipe objects to Write-DataTable
+.OUTPUTS
+None
+    Produces no output
+.EXAMPLE
+$dt = Invoke-Sqlcmd2 -ServerInstance "Z003\R2" -Database pubs "select *  from authors"
+Write-DataTable -ServerInstance "Z003\R2" -Database pubscopy -TableName authors -Data $dt
+This example loads a variable dt of type DataTable from query and write the datatable to another database
+.NOTES
+Write-DataTable uses the SqlBulkCopy class see links for additional information on this class.
+Version History
+v1.0   - Chad Miller - Initial release
+v1.1   - Chad Miller - Fixed error message
+.LINK
+http://msdn.microsoft.com/en-us/library/30c3y597%28v=VS.90%29.aspx
+#>
+function Write-DataTable
+{
+    [CmdletBinding()]
+    param(
+    [Parameter(Position=0, Mandatory=$true)] [string]$ServerInstance,
+    [Parameter(Position=1, Mandatory=$true)] [string]$Database,
+    [Parameter(Position=2, Mandatory=$true)] [string]$TableName,
+    [Parameter(Position=3, Mandatory=$true)] $Data,
+    [Parameter(Position=4, Mandatory=$false)] [string]$Username,
+    [Parameter(Position=5, Mandatory=$false)] [string]$Password,
+    [Parameter(Position=6, Mandatory=$false)] [Int32]$BatchSize=50000,
+    [Parameter(Position=7, Mandatory=$false)] [Int32]$QueryTimeout=0,
+    [Parameter(Position=8, Mandatory=$false)] [Int32]$ConnectionTimeout=15
+    )
+    
+    $conn=new-object System.Data.SqlClient.SQLConnection
+
+    if ($Username)
+    { $ConnectionString = "Server={0};Database={1};User ID={2};Password={3};Trusted_Connection=False;Connect Timeout={4}" -f $ServerInstance,$Database,$Username,$Password,$ConnectionTimeout }
+    else
+    { $ConnectionString = "Server={0};Database={1};Integrated Security=True;Connect Timeout={2}" -f $ServerInstance,$Database,$ConnectionTimeout }
+
+    $conn.ConnectionString=$ConnectionString
+
+    try
+    {
+        $conn.Open()
+        $bulkCopy = new-object ("Data.SqlClient.SqlBulkCopy") $connectionString
+        $bulkCopy.DestinationTableName = $tableName
+        $bulkCopy.BatchSize = $BatchSize
+        $bulkCopy.BulkCopyTimeout = $QueryTimeOut
+        $bulkCopy.WriteToServer($Data)
+        $conn.Close()
+    }
+    catch
+    {
+        $ex = $_.Exception
+        Write-Error "$ex.Message"
+        continue
+    }
+
+} #Write-DataTable