Commit fc434cb2 authored by dwentzel's avatar dwentzel

First public version of PerformanceCollector

parent f4562e12
IF SCHEMA_ID('PerformanceCollector') IS NULL
BEGIN
PRINT 'Creating PerformanceCollector schema'
EXEC ('CREATE SCHEMA PerformanceCollector;');
END
GO
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.AdHocPlanCacheBloat '
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('PerformanceCollector.AdHocPlanCacheBloat') IS NULL
BEGIN
Create table PerformanceCollector.AdHocPlanCacheBloat
( CurrTime datetime
, ServerName varchar(200)
, [QueryText] nvarchar(max)
, size_in_bytes bigint
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
--blow the table away and recreate it.
IF NOT EXISTS (select * from sys.objects where object_id = object_id('PerformanceCollector.BlockAndWaitStats'))
BEGIN
CREATE TABLE PerformanceCollector.BlockAndWaitStats
(ObjId bigint identity(1,1) not null --key
,CurrTime datetime NOT NULL --time of the block/wait.
,spid smallint NOT NULL --SPID
,BlockingSpid smallint NOT NULL --SPID of the session that is blocking the request. 0 is not blocked. -2 is orphaned
--dist transaction, -4 is undetermined due to state transitions
,IsHeadBlocker bit NOT NULL --finds any blocking tasks that are not themselves blocked.
,DBName varchar(50) NULL --database against which the request arrived
,waittime bigint NULL --total wait time for this wait type, in ms, inclusive of signal_wait_time.
,wait_type varchar(60) NULL --name of the wait type, ie LCK_M_X, WRITELOG, NETWORKIO,etc
,wait_resource varchar(512) NULL --if the request is blocked then what is it waiting on, ie db:file:objectid
,status varchar(30) NOT NULL --status of the request (running, runnable, sleeping, suspended, etc)
,CommandType varchar(32) NOT NULL --type of command (DBCC, SELECT, INSERT, BACKUP LOG, etc)
,cpu_ms int NULL --CPU used (in ms) at the request level
,physical_io bigint NULL
,SQLText varchar(MAX) NULL --text of the request
,program_name varchar(256) NOT NULL --from what application
,hostname varchar(256) NULL --who made the call
,login_name varchar(128) NOT NULL --SQL Server login name under which the session is currently executing.
,last_batch datetime NOT NULL --Timestamp when the request arrived.
,open_tran smallint NOT NULL --number of open transactions for the request
,tran_iso_level smallint NULL --transaction isolation level of the request
,statement_start_offset int NULL --used to calculate StatementText in the API view
,statement_end_offset int NULL
,TransactionName nvarchar(256) NULL
)
END;
GO
IF NOT EXISTS (SELECT 1 from SYS.INDEXES where name='BlockAndWaitStats_CL' and object_id = object_id('PerformanceCollector.BlockAndWaitStats'))
CREATE Clustered INDEX BlockAndWaitStats_CL ON PerformanceCollector.BlockAndWaitStats(CurrTime)
GO
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.BufferStats '
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('PerformanceCollector.BufferStats') IS NULL
BEGIN
Create table PerformanceCollector.BufferStats
( CurrTime datetime
, ServerName varchar(200)
, DbName varchar(200)
, ObjectName varchar(200)
, index_id int
, BufferSizeMB bigint
, BufferCount bigint
, CompressionType varchar(200)
, TypeDesc varchar(200)
, [Rows] bigint
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
\ No newline at end of file
IF OBJECT_ID('PerformanceCollector.Config') IS NULL
BEGIN
CREATE TABLE PerformanceCollector.Config(
ConfigSetting varchar(40) NOT NULL,
ConfigInstance varchar(128) NULL,
ConfigValueInt int NULL,
ConfigValueText varchar(4000) NULL
)
END
GO
/*
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- DBA_PM_ProcsPrev '
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('DBA_PM_ProcsPrev') IS NULL
BEGIN
CREATE TABLE DBA_PM_ProcsPrev(
Spid smallint NOT NULL,
HostProcess int NOT NULL,
Ecid smallint NOT NULL,
IsActive smallint NOT NULL,
login sysname NULL,
status varchar(30) NULL,
dbname sysname NULL,
HostName varchar(128) NULL,
Cmd varchar(16) NULL,
appl varchar(128) NULL,
Open_Tran smallint NULL,
blking smallint NOT NULL,
blkby smallint NULL,
blklvl smallint NOT NULL,
waittime bigint NULL,
waittype binary(2) NULL,
lastwaittype varchar(64) NULL,
waitresource varchar(512) NULL,
cpu bigint NULL,
Physical_io bigint NULL,
memusage int NULL,
now datetime NOT NULL,
login_time datetime NULL,
last_batch datetime NULL,
SinceLastBatch numeric(14, 3) NULL,
sql_handle binary(20) NOT NULL,
stmt_start int NOT NULL,
stmt_end int NOT NULL,
current_sp int NULL,
curdbid smallint NULL,
curstmt varchar(255) NULL,
delay int NOT NULL,
inputbuffer varchar(4000) NOT NULL
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
--SQL2005 Changes (255) -> (4000)
PRINT 'Altering inputbuffer...'
ALTER TABLE DBA_PM_ProcsPrev ALTER COLUMN inputbuffer varchar(4000) NOT NULL
PRINT 'Altering curstmt...'
ALTER TABLE DBA_PM_ProcsPrev ALTER COLUMN curstmt varchar(255) NULL
-- int -> bigint
PRINT 'Altering waittime...'
ALTER TABLE DBA_PM_ProcsPrev ALTER COLUMN waittime bigint NULL
PRINT 'Altering CPU...'
ALTER TABLE DBA_PM_ProcsPrev ALTER COLUMN CPU bigint NULL
-- numeric(10,3) -> numeric(14,3)
if exists (select top 1 * from syscolumns where OBJECT_NAME(id)='DBA_PM_ProcsPrev' and name='last_since')
BEGIN
PRINT 'Altering last_since...'
ALTER TABLE DBA_PM_ProcsPrev ALTER COLUMN last_since numeric(14, 3) NULL
END
-- clprocess -> HostProcess
if exists (select top 1 * from syscolumns where OBJECT_NAME(id)='DBA_PM_ProcsPrev' and name='clprocess')
exec sp_rename 'DBA_PM_ProcsPrev.clprocess', 'HostProcess','COLUMN'
-- active -> IsActive
if exists (select top 1 * from syscolumns where OBJECT_NAME(id)='DBA_PM_ProcsPrev' and name='active')
exec sp_rename 'DBA_PM_ProcsPrev.active', 'IsActive','COLUMN'
-- physio -> Physical_io
if exists (select top 1 * from syscolumns where OBJECT_NAME(id)='DBA_PM_ProcsPrev' and name='physio')
exec sp_rename 'DBA_PM_ProcsPrev.physio', 'Physical_io','COLUMN'
-- last_Since -> SinceLastBatch
if exists (select top 1 * from syscolumns where OBJECT_NAME(id)='DBA_PM_ProcsPrev' and name='last_since')
exec sp_rename 'DBA_PM_ProcsPrev.last_since', 'SinceLastBatch','COLUMN'
-- host -> HostName
if exists (select top 1 * from syscolumns where OBJECT_NAME(id)='DBA_PM_ProcsPrev' and name='host')
exec sp_rename 'DBA_PM_ProcsPrev.host', 'HostName','COLUMN'
-- Command -> cmd
if exists (select top 1 * from syscolumns where OBJECT_NAME(id)='DBA_PM_ProcsPrev' and name='Command')
exec sp_rename 'DBA_PM_ProcsPrev.Command', 'Cmd','COLUMN'
-- opntrn -> Open_Tran
if exists (select top 1 * from syscolumns where OBJECT_NAME(id)='DBA_PM_ProcsPrev' and name='opntrn')
exec sp_rename 'DBA_PM_ProcsPrev.opntrn', 'Open_Tran','COLUMN'
-- bit -> smallint
PRINT 'Altering IsActive...'
ALTER TABLE DBA_PM_ProcsPrev ALTER COLUMN IsActive smallint NOT NULL
END
GO
*/
\ No newline at end of file
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.DeadlockSnapshot'
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF NOT EXISTS (select * from sys.objects where object_id = object_id('PerformanceCollector.DeadlockSnapshot'))
BEGIN
Create table PerformanceCollector.DeadlockSnapshot (
DeadlockSnapshotId int not null identity(1,1),
ServerName varchar(200),
DeadlockGraph varchar(max) not null,
DeadlockGraphCheckSum int not null,
CurrTime datetime not null constraint DBA_PM_DeadlockSnapshot_Default_CurrTime default getdate(),
DeadlockTime datetime null,
DeadlockSummary varchar(512) null,
DeadlockGraphXML XML NULL,
VictimSpid INT NULL,
SurvivorSpid INT NULL,
VictimInputBuffer nvarchar(4000),
SurvivorInputBuffer nvarchar(4000) NULL
)
;
END;
GO
if not exists (select 1 from sys.indexes where name = 'DeadlockSnapshot_pk' and object_id('PerformanceCollector.DeadlockSnapshot')= object_id)
Alter table PerformanceCollector.DeadlockSnapshot add constraint DeadlockSnapshot_pk primary key (DeadlockSnapshotId)
ELSE
PRINT 'INDEX DeadlockSnapshot_pk already exists...'
GO
if not exists (select 1 from sys.indexes where name = 'DeadlockSnapshot_NDX' and object_id('PerformanceCollector.DeadlockSnapshot')= object_id)
create index DeadlockSnapshot_NDX on PerformanceCollector.DeadlockSnapshot (DeadlockGraphCheckSum)
ELSE
PRINT 'INDEX DeadlockSnapshot_NDX already exists...'
GO
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.IOStalls'
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('PerformanceCollector.IOStalls') IS NULL
BEGIN
CREATE TABLE PerformanceCollector.IOStalls
( CurrTime DATETIME NOT NULL
, ServerName varchar(200)
, DbName varchar(200)
, FileType varchar(100)
, io_mb decimal (18,6)
, io_stall_ms decimal (18,6)
, io_stall_pct decimal (18,6)
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.IndexBlocking '
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('PerformanceCollector.IndexBlocking') IS NULL
BEGIN
Create table PerformanceCollector.IndexBlocking
( CurrTime datetime
, ServerName varchar(200)
, DbName varchar(200)
, ObjDetails varchar(200)
, Block_Waittime_ms bigint
, index_id int
, partition_number int
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
IF OBJECT_ID('PerformanceCollector.MissingIndexes') IS NULL
BEGIN
Create table PerformanceCollector.MissingIndexes
( CurrTime datetime,
TotalCost bigint,
TableName nvarchar(4000),
EqualityColumns varchar(4000),
InequalityColumns varchar(4000),
IncludedColumns varchar(4000)
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
IF OBJECT_ID('PerformanceCollector.MissingIndexesFromQueryPlansDtls') IS NULL
BEGIN
Create table PerformanceCollector.MissingIndexesFromQueryPlansDtls
( CurrTime datetime,
TotalCost bigint,
TableName nvarchar(4000),
EqualityColumns varchar(4000),
InequalityColumns varchar(4000),
IncludedColumns varchar(4000)
)
END
GO
IF OBJECT_ID('PerformanceCollector.MissingIndexesFromQueryPlansSummary') IS NULL
BEGIN
Create table PerformanceCollector.MissingIndexesFromQueryPlansSummary
( CurrTime datetime,
TotalCost bigint,
TableName nvarchar(4000),
EqualityColumns varchar(4000),
InequalityColumns varchar(4000),
IncludedColumns varchar(4000)
)
END
GO
IF NOT EXISTS (select * from sys.objects WHERE object_id = object_id('PerformanceCollector.PageLifeExpectancies'))
BEGIN
CREATE TABLE PerformanceCollector.PageLifeExpectancies (
CurrTime DATETIME NOT NULL
, ServerName varchar(200)
, ObjectName varchar(200)
, CounterName varchar(200)
, InstanceName varchar(200)
, CounterValue bigint
);
END
GO
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.PerfCounters '
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('PerformanceCollector.PerfCounters') IS NULL
BEGIN
Create table PerformanceCollector.PerfCounters
( CurrTime datetime NOT NULL
, ServerName varchar(200) NOT NULL
, object_name varchar(256) NOT NULL
, counter_name varchar(256) NOT NULL
, cntr_value bigint NOT NULL
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
IF NOT EXISTS (SELECT 1 from sys.indexes where name='PerfCnt_CL' and object_id = object_id('PerformanceCollector.PerfCounters'))
CREATE Clustered INDEX PerfCnt_CL ON PerformanceCollector.PerfCounters(CurrTime, object_name, counter_name)
GO
\ No newline at end of file
IF OBJECT_ID('PerformanceCollector.PerfCountersPrev') IS NULL
BEGIN
Create table PerformanceCollector.PerfCountersPrev
( CurrTime datetime NOT NULL
, object_name varchar(256) NOT NULL
, counter_name varchar(256) NOT NULL
, instance_name varchar(256) NULL
, cntr_value bigint NOT NULL
, cntr_type int NOT NULL
)
END
GO
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.PlanCacheMetrics '
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('PerformanceCollector.PlanCacheMetrics') IS NULL
BEGIN
Create table PerformanceCollector.PlanCacheMetrics
( CurrTime datetime
, ServerName varchar(200)
, DBName varchar(200)
, SPName varchar(200)
, ExecutionCount bigint
, CallsPerSecond bigint
, TotalWorkerTime bigint
, TotalElapsedTime bigint
, AvgElapsedTime bigint
, AvgWorkerTime bigint
, TotalLogicalReads bigint
, AvgLogicalReads bigint
, TotalPhysicalReads bigint
, AvgPhysicalReads bigint
, TotalLogicalWrites bigint
, AvgLogicalWrites bigint
, CachedTime datetime
, RowNumber int
, Metric varchar(200)
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.PlanTypeStats '
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('PerformanceCollector.PlanTypeStats') IS NULL
BEGIN
Create table PerformanceCollector.PlanTypeStats
( CurrTime datetime
, ServerName varchar(200)
, PLAN_TYPE varchar(100)
, PLAN_NUMBERS bigint
, SIZE_MB bigint
, USE_COUNT bigint
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.PossibleBadIndexes '
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF OBJECT_ID('PerformanceCollector.PossibleBadIndexes') IS NULL
BEGIN
CREATE TABLE PerformanceCollector.PossibleBadIndexes(
CurrTime datetime NOT NULL,
ServerName varchar(200) NULL,
DBName varchar(200) NULL,
TableName varchar(200) NULL,
IndexName varchar(200) NULL,
index_id int,
TotalWrites bigint,
TotalReads bigint,
Difference bigint
)
END
ELSE BEGIN
PRINT 'Running ALTERs if needed.'
END
GO
IF OBJECT_ID('PerformanceCollector.SpidsKilled') IS NULL
BEGIN
CREATE TABLE PerformanceCollector.SpidsKilled(
[CurrTime] [datetime] NOT NULL,
[spid] [smallint] NOT NULL,
Sts varchar(2000) NULL
CONSTRAINT [DBA_PM_SpidsKilledPK] PRIMARY KEY CLUSTERED
( [CurrTime] ASC, [spid] ASC )
WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
)
END
ELSE BEGIN
Print 'Table already exists, performing Alters (if required)...'
END
GO
IF OBJECT_ID('PerformanceCollector.TempDbLogWatch') IS NULL
BEGIN
CREATE TABLE PerformanceCollector.TempDbLogWatch(
CurrTime DATETIME NOT NULL,
ServerName varchar(200),
[transaction_id] [bigint] NOT NULL,
[name] [nvarchar](32) NOT NULL,
[transaction_begin_time] [datetime] NOT NULL,
[ActvSS] [int] NULL,
[TotUsedPages] [bigint] NULL,
[transaction_type] [int] NOT NULL,
[database_id] [int] NULL,
[DBName] [nvarchar](128) NULL,
[database_transaction_begin_time] [datetime] NULL,
[database_transaction_log_bytes_used] [bigint] NULL,
[database_transaction_log_bytes_reserved] [bigint] NULL,
[session_id] [int] NULL,
[scheduler_id] [int] NULL,
[is_user_transaction] [bit] NULL,
[blocked] [smallint] NULL,
[waittime] [bigint] NULL,
[lastwaittype] [nchar](32) NULL,
[cpu] [int] NULL,
[physical_io] [bigint] NULL,
[last_batch] [datetime] NULL,
[cmd] [nchar](16) NULL,
[loginame] [nchar](128) NULL,
[stmt_start] [int] NULL,
[stmt_end] [int] NULL,
[program_name] [nchar](128) NULL,
[SQLStuff] [nvarchar](max) NULL,
[UserPageUsed] [bigint] NULL,
[IntrnPageUsed] [bigint] NULL,
[SessUserPage] [bigint] NULL,
[SessIntrnPage] [bigint] NULL,
[TaskUserObjAllocPg] [bigint] NULL,
[TaskUserObjDeAllocPg] [bigint] NULL,
[TaskIntrnObjAllocPg] [bigint] NULL,
[TaskIntrnObjDeAllocPg] [bigint] NULL,
[SessUserObjAllocPg] [bigint] NULL,
[SessUserObjDeallocPg] [bigint] NULL,
[SessIntrnObjAllocPg] [bigint] NULL,
[SessIntrnDeallocPg] [bigint] NULL,
[exec_context_id] [int] NULL
)
END
GO
IF OBJECT_ID('PerformanceCollector.TempDbUsage') IS NULL
BEGIN
CREATE TABLE PerformanceCollector.TempDbUsage(
CurrTime DATETIME NOT NULL,
ServerName varchar(200),
SessionId smallint,
InternalObjectAllocMBSpace decimal(27,6),
InternalObjectDeallocMBSpace decimal(27,6),
Text nvarchar(max),
StatementText nvarchar(max),
QueryPlan XML
);
END
GO
IF NOT EXISTS (select * from sys.objects where object_id = object_id('[PerformanceCollector].[Version]'))
BEGIN
CREATE TABLE PerformanceCollector.Version(
[Id] [varchar](25) NOT NULL,
[ApplyDTime] [datetime] NOT NULL,
[CntcName] [varchar](30) NULL,
[LastCngText] [varchar](500) NULL
) ON [PRIMARY]
END;
GO
--view API into DBA_PM_WaitAndBlockMonitor
IF EXISTS (select * from sys.objects WHERE object_id = object_id('PerformanceCollector.BlockAndWaitMonitor'))
BEGIN
DROP VIEW PerformanceCollector.BlockAndWaitMonitor
END;
GO
CREATE VIEW PerformanceCollector.BlockAndWaitMonitor
AS
SELECT
b.ObjId, b.CurrTime, b.spid, b.BlockingSpid,b.IsHeadBlocker, SUBSTRING(@@SERVERNAME,1,40) AS ServerName, b.DBName,b.waittime, b.wait_type, b.wait_resource,
b.status, b.CommandType,b.cpu_ms,b.physical_io,
DATEDIFF(ms,COALESCE(b.last_batch,b.CurrTime),b.CurrTime)AS ElapsedMS,
--total time since request arrival
left( SUBSTRING(b.SQLText, (b.statement_start_offset/2)+1, --actual statement within the batch that is executing. Is not guaranteed to always be accurate
abs(((CASE b.statement_end_offset WHEN -1 THEN DATALENGTH(b.SQLText)
ELSE b.statement_end_offset END - b.statement_start_offset)/2) + 1))
, 1500) AS StatementText,
b.SQLText,
b.program_name,b.hostname,b.login_name,b.last_batch,b.open_tran,
CASE b.tran_iso_level
WHEN 1 THEN 'ReadUncommitted'
WHEN 2 THEN 'ReadCommitted'
WHEN 3 THEN 'Repeatable'