CREATEOBJECTS.sql 31 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588
  1. USE [dba_local]
  2. GO
  3. /****** Object: Table [dbo].[Sessionstatus] Script Date: 2/1/2016 11:33:43 AM ******/
  4. SET ANSI_NULLS ON
  5. GO
  6. SET QUOTED_IDENTIFIER ON
  7. GO
  8. IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[Sessionstatus]') AND type in (N'U'))
  9. BEGIN
  10. DROP TABLE dbo.[Sessionstatus]
  11. PRINT 'Table Sessionstatus exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
  12. END
  13. IF NOT EXISTS (SELECT * FROM sys.objects WHERE OBJECT_ID = OBJECT_ID(N'[Sessionstatus]') AND TYPE IN (N'U'))
  14. BEGIN
  15. CREATE TABLE [dbo].[Sessionstatus](
  16. [DateCaptured] [datetime] NULL,
  17. [dbname] [nvarchar](100) NULL,
  18. [status] [nvarchar](50) NULL,
  19. [waittype] [nvarchar](100) NULL,
  20. [waittime] [bigint] NULL,
  21. [sessioncnt] [int] NULL,
  22. [opentran] [int] NULL
  23. ) ON [PRIMARY]
  24. PRINT 'Table Sessionstatus created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
  25. END
  26. GO
  27. DECLARE @is2012 bit
  28. BEGIN TRY
  29. IF((SELECT CAST(REPLACE(LEFT(CAST(SERVERPROPERTY('ProductVersion') AS varchar(10)),2),'.','') AS int)) = 11)
  30. SET @is2012 = 1
  31. ELSE
  32. SET @is2012 = 0
  33. IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[PerformanceCounterList]') AND type in (N'U'))
  34. BEGIN
  35. DROP TABLE [PerformanceCounterList]
  36. PRINT 'Table PerformanceCounterList exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
  37. END
  38. IF NOT EXISTS (SELECT * FROM sys.objects WHERE OBJECT_ID = OBJECT_ID(N'[PerformanceCounterList]') AND TYPE IN (N'U'))
  39. BEGIN
  40. CREATE TABLE [PerformanceCounterList](
  41. [counter_name] [VARCHAR](500) NOT NULL,
  42. [is_captured_ind] [BIT] NOT NULL,
  43. CONSTRAINT [PK_PerformanceCounterList] PRIMARY KEY CLUSTERED
  44. (
  45. [counter_name] ASC
  46. )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [PRIMARY]
  47. ) ON [PRIMARY]
  48. ALTER TABLE [PerformanceCounterList] ADD CONSTRAINT [DF_PerformanceCounterList_is_captured_ind] DEFAULT ((1)) FOR [is_captured_ind]
  49. PRINT 'Table PerformanceCounterList created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
  50. END
  51. IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[PerformanceCounter]') AND type in (N'U'))
  52. BEGIN
  53. DROP TABLE [PerformanceCounter]
  54. PRINT 'Table PerformanceCounter exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
  55. END
  56. IF NOT EXISTS (SELECT * FROM sys.objects WHERE OBJECT_ID = OBJECT_ID(N'[PerformanceCounter]') AND TYPE IN (N'U'))
  57. BEGIN
  58. CREATE TABLE [PerformanceCounter](
  59. [CounterName] [VARCHAR](250) NOT NULL,
  60. [CounterValue] [VARCHAR](250) NOT NULL,
  61. [DateSampled] [DATETIME] NOT NULL,
  62. CONSTRAINT [PK_PerformanceCounter] PRIMARY KEY CLUSTERED
  63. (
  64. [CounterName] ASC,
  65. [DateSampled] ASC
  66. )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
  67. ) ON [PRIMARY]
  68. PRINT 'Table PerformanceCounter created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
  69. END
  70. IF EXISTS (SELECT * FROM sys.views WHERE object_id = OBJECT_ID(N'[vPerformanceCounter]'))
  71. BEGIN
  72. DROP VIEW [vPerformanceCounter]
  73. PRINT 'View vPerformanceCounter exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping view'
  74. END
  75. IF (@is2012 = 0)
  76. BEGIN
  77. IF NOT EXISTS (SELECT * FROM sys.views WHERE OBJECT_ID = OBJECT_ID(N'[vPerformanceCounter]'))
  78. BEGIN
  79. EXEC dbo.sp_executesql @statement = N'
  80. CREATE VIEW [vPerformanceCounter]
  81. AS
  82. SELECT * FROM
  83. (SELECT CounterName, CounterValue, DateSampled
  84. FROM PerformanceCounter) AS T1
  85. PIVOT
  86. (
  87. MAX(CounterValue)
  88. FOR CounterName IN ([logicaldisk(_total)\avg. disk queue length],
  89. [logicaldisk(_total)\avg. disk sec/read],
  90. [logicaldisk(_total)\avg. disk sec/transfer],
  91. [logicaldisk(_total)\avg. disk sec/write],
  92. [logicaldisk(_total)\current disk queue length],
  93. [memory\available mbytes],
  94. [paging file(_total)\% usage],
  95. [paging file(_total)\% usage peak],
  96. [processor(_total)\% privileged time],
  97. [processor(_total)\% processor time],
  98. [process(sqlservr)\% privileged time],
  99. [process(sqlservr)\% processor time],
  100. [sql statistics\batch requests/sec],
  101. [sql statistics\sql compilations/sec],
  102. [sql statistics\sql re-compilations/sec],
  103. [general statistics\user connections],
  104. [buffer manager\page life expectancy],
  105. [buffer manager\buffer cache hit ratio],
  106. [memory manager\target server memory (kb)],
  107. [memory manager\total server memory (kb)],
  108. [buffer manager\checkpoint pages/sec],
  109. [buffer manager\free pages],
  110. [buffer manager\lazy writes/sec],
  111. [transactions\free space in tempdb (kb)])
  112. ) AS PT;
  113. '
  114. PRINT 'View vPerformanceCounter created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
  115. END
  116. ELSE PRINT 'View vPerformanceCounter already exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
  117. END
  118. ELSE
  119. BEGIN
  120. IF NOT EXISTS (SELECT * FROM sys.views WHERE OBJECT_ID = OBJECT_ID(N'[vPerformanceCounter]'))
  121. BEGIN
  122. EXEC dbo.sp_executesql @statement = N'
  123. CREATE VIEW [vPerformanceCounter]
  124. AS
  125. SELECT * FROM
  126. (SELECT CounterName, CounterValue, DateSampled
  127. FROM PerformanceCounter) AS T1
  128. PIVOT
  129. (
  130. MAX(CounterValue)
  131. FOR CounterName IN ([logicaldisk(_total)\avg. disk queue length],
  132. [logicaldisk(_total)\avg. disk sec/read],
  133. [logicaldisk(_total)\avg. disk sec/transfer],
  134. [logicaldisk(_total)\avg. disk sec/write],
  135. [logicaldisk(_total)\current disk queue length],
  136. [memory\available mbytes],
  137. [paging file(_total)\% usage],
  138. [paging file(_total)\% usage peak],
  139. [processor(_total)\% privileged time],
  140. [processor(_total)\% processor time],
  141. [process(sqlservr)\% privileged time],
  142. [process(sqlservr)\% processor time],
  143. [sql statistics\batch requests/sec],
  144. [sql statistics\sql compilations/sec],
  145. [sql statistics\sql re-compilations/sec],
  146. [general statistics\user connections],
  147. [buffer manager\page life expectancy],
  148. [buffer manager\buffer cache hit ratio],
  149. [memory manager\target server memory (kb)],
  150. [memory manager\total server memory (kb)],
  151. [buffer manager\checkpoint pages/sec],
  152. [buffer manager\lazy writes/sec],
  153. [transactions\free space in tempdb (kb)])
  154. ) AS PT;
  155. '
  156. PRINT 'View vPerformanceCounter created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
  157. END
  158. ELSE PRINT 'View vPerformanceCounter already exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
  159. END
  160. SET NOCOUNT ON
  161. DECLARE @perfStr VARCHAR(100)
  162. DECLARE @instStr VARCHAR(100)
  163. SELECT @instStr = @@SERVICENAME
  164. --SET @instStr = 'NI1'
  165. IF(@instStr = 'MSSQLSERVER')
  166. SET @perfStr = '\SQLServer'
  167. ELSE
  168. SET @perfStr = '\MSSQL$' + @instStr
  169. TRUNCATE TABLE PerformanceCounterList
  170. PRINT 'Truncated table PerformanceCounterList'
  171. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  172. VALUES ('\Memory\Pages/sec',0)
  173. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  174. VALUES ('\Memory\Pages Input/sec',0)
  175. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  176. VALUES ('\Memory\Available MBytes',1)
  177. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  178. VALUES ('\Processor(_Total)\% Processor Time',1)
  179. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  180. VALUES ('\Processor(_Total)\% Privileged Time',1)
  181. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  182. VALUES ('\Process(sqlservr)\% Privileged Time',1)
  183. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  184. VALUES ('\Process(sqlservr)\% Processor Time',1)
  185. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  186. VALUES ('\Paging File(_Total)\% Usage',0)
  187. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  188. VALUES ('\Paging File(_Total)\% Usage Peak',0)
  189. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  190. VALUES ('\PhysicalDisk(_Total)\Avg. Disk sec/Read',0)
  191. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  192. VALUES ('\PhysicalDisk(_Total)\Avg. Disk sec/Write',0)
  193. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  194. VALUES ('\PhysicalDisk(_Total)\Disk Reads/sec',0)
  195. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  196. VALUES ('\PhysicalDisk(_Total)\Disk Writes/sec',0)
  197. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  198. VALUES ('\System\Processor Queue Length',0)
  199. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  200. VALUES ('\System\Context Switches/sec',0)
  201. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  202. VALUES (@perfStr + ':Buffer Manager\Page life expectancy',1)
  203. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  204. VALUES (@perfStr + ':Buffer Manager\Buffer cache hit ratio',1)
  205. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  206. VALUES (@perfStr + ':Buffer Manager\Checkpoint Pages/Sec',1)
  207. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  208. VALUES (@perfStr + ':Buffer Manager\Lazy Writes/Sec',1)
  209. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  210. VALUES (@perfStr + ':Buffer Manager\Page Reads/Sec',0)
  211. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  212. VALUES (@perfStr + ':Buffer Manager\Page Writes/Sec',0)
  213. IF (@is2012 = 0)
  214. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  215. VALUES (@perfStr + ':Buffer Manager\Free Pages',1)
  216. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  217. VALUES (@perfStr + ':Buffer Manager\Page Lookups/Sec',0)
  218. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  219. VALUES (@perfStr + ':Buffer Manager\Free List Stalls/sec',0)
  220. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  221. VALUES (@perfStr + ':Buffer Manager\Readahead pages/sec',0)
  222. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  223. VALUES (@perfStr + ':Buffer Manager\Database Pages',0)
  224. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  225. VALUES (@perfStr + ':Buffer Manager\Target Pages',0)
  226. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  227. VALUES (@perfStr + ':Buffer Manager\Total Pages',0)
  228. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  229. VALUES (@perfStr + ':Buffer Manager\Stolen Pages',0)
  230. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  231. VALUES (@perfStr + ':General Statistics\User Connections',1)
  232. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  233. VALUES (@perfStr + ':General Statistics\Processes blocked',0)
  234. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  235. VALUES (@perfStr + ':General Statistics\Logins/Sec',0)
  236. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  237. VALUES (@perfStr + ':General Statistics\Logouts/Sec',0)
  238. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  239. VALUES (@perfStr + ':Memory Manager\Memory Grants Pending',0)
  240. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  241. VALUES (@perfStr + ':Memory Manager\Total Server Memory (KB)',1)
  242. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  243. VALUES (@perfStr + ':Memory Manager\Target Server Memory (KB)',1)
  244. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  245. VALUES (@perfStr + ':Memory Manager\Granted Workspace Memory (KB)',0)
  246. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  247. VALUES (@perfStr + ':Memory Manager\Maximum Workspace Memory (KB)',0)
  248. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  249. VALUES (@perfStr + ':Memory Manager\Memory Grants Outstanding',0)
  250. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  251. VALUES (@perfStr + ':SQL Statistics\Batch Requests/sec',1)
  252. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  253. VALUES (@perfStr + ':SQL Statistics\SQL Compilations/sec',1)
  254. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  255. VALUES (@perfStr + ':SQL Statistics\SQL Re-Compilations/sec',1)
  256. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  257. VALUES (@perfStr + ':SQL Statistics\Auto-Param Attempts/sec',0)
  258. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  259. VALUES (@perfStr + ':Locks(_Total)\Lock Waits/sec',0)
  260. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  261. VALUES (@perfStr + ':Locks(_Total)\Lock Requests/sec',0)
  262. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  263. VALUES (@perfStr + ':Locks(_Total)\Lock Timeouts/sec',0)
  264. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  265. VALUES (@perfStr + ':Locks(_Total)\Number of Deadlocks/sec',0)
  266. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  267. VALUES (@perfStr + ':Locks(_Total)\Lock Wait Time (ms)',0)
  268. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  269. VALUES (@perfStr + ':Locks(_Total)\Average Wait Time (ms)',0)
  270. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  271. VALUES (@perfStr + ':Latches\Total Latch Wait Time (ms)',0)
  272. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  273. VALUES (@perfStr + ':Latches\Latch Waits/sec',0)
  274. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  275. VALUES (@perfStr + ':Latches\Average Latch Wait Time (ms)',0)
  276. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  277. VALUES (@perfStr + ':Access Methods\Forwarded Records/Sec',0)
  278. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  279. VALUES (@perfStr + ':Access Methods\Full Scans/Sec',0)
  280. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  281. VALUES (@perfStr + ':Access Methods\Page Splits/Sec',0)
  282. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  283. VALUES (@perfStr + ':Access Methods\Index Searches/Sec',0)
  284. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  285. VALUES (@perfStr + ':Access Methods\Workfiles Created/Sec',0)
  286. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  287. VALUES (@perfStr + ':Access Methods\Worktables Created/Sec',0)
  288. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  289. VALUES (@perfStr + ':Access Methods\Table Lock Escalations/sec',0)
  290. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  291. VALUES (@perfStr + ':Cursor Manager by Type(_Total)\Active cursors',0)
  292. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  293. VALUES (@perfStr + ':Transactions\Longest Transaction Running Time',0)
  294. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  295. VALUES (@perfStr + ':Transactions\Free Space in tempdb (KB)',1)
  296. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  297. VALUES (@perfStr + ':Transactions\Version Store Size (KB)',0)
  298. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  299. VALUES ('\LogicalDisk(*)\Avg. Disk Queue Length',1)
  300. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  301. VALUES ('\LogicalDisk(*)\Avg. Disk sec/Read',1)
  302. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  303. VALUES ('\LogicalDisk(*)\Avg. Disk sec/Transfer',1)
  304. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  305. VALUES ('\LogicalDisk(*)\Avg. Disk sec/Write',1)
  306. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  307. VALUES ('\LogicalDisk(*)\Current Disk Queue Length',1)
  308. INSERT INTO PerformanceCounterList(counter_name,is_captured_ind)
  309. VALUES ('\Paging File(*)\*',1)
  310. PRINT 'Inserts to table PerformanceCounterList completed'
  311. IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[ClearPerfCtrHistory]') AND type in (N'P', N'PC'))
  312. BEGIN
  313. DROP PROCEDURE [ClearPerfCtrHistory]
  314. PRINT 'Stored Procedure ClearPerfCtrHistory exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping stored procedure'
  315. END
  316. IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[ClearPerfCtrHistory]') AND type in (N'P', N'PC'))
  317. BEGIN
  318. EXEC dbo.sp_executesql @statement = N'
  319. CREATE PROCEDURE [ClearPerfCtrHistory]
  320. @old_date INT = 180
  321. AS
  322. --******************************************************************************************************
  323. --* Created date : September 2014
  324. --* Purpose: Clears out performance counter history
  325. --*
  326. --* Usage: EXEC ClearPerfCtrHistory: procedure can be called with no parameters and default
  327. --* 180 day history will be used
  328. --*
  329. --* --OR-- specify the optional parameter below to customize history duration
  330. --*
  331. --* EXEC ClearBackupHistory
  332. --* @old_date --number of days of history to delete
  333. --*
  334. --*****************************************************************************************************
  335. SET NOCOUNT ON
  336. SET XACT_ABORT ON
  337. BEGIN TRY
  338. IF EXISTS(SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N''[PerformanceCounter]'') AND type in (N''U''))
  339. BEGIN
  340. DELETE dbo.PerformanceCounter
  341. WHERE DateSampled < DATEADD(dd,-@old_date, dateadd(dd, datediff(dd,0, GETDATE()),0))
  342. END
  343. END TRY
  344. BEGIN CATCH
  345. IF (XACT_STATE()) != 0
  346. ROLLBACK TRANSACTION;
  347. DECLARE @errMessage varchar(MAX)
  348. SET @errMessage = ''Stored procedure '' + OBJECT_NAME(@@PROCID) + '' failed with error '' + CAST(ERROR_NUMBER() AS VARCHAR(20)) + ''. '' + ERROR_MESSAGE()
  349. RAISERROR (@errMessage, 16, 1)
  350. END CATCH
  351. '
  352. PRINT 'Stored procedure ClearPerfCtrHistory created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100))
  353. END
  354. END TRY
  355. BEGIN CATCH
  356. DECLARE @errMessage varchar(MAX) = ERROR_MESSAGE()
  357. PRINT @errMessage
  358. IF EXISTS(SELECT 1 FROM master.sys.databases WHERE name = 'dba_local')
  359. AND EXISTS (SELECT 1 FROM dba_local.sys.objects WHERE name = N'install_usp_logevent' AND type in (N'P', N'PC'))
  360. BEGIN
  361. EXEC [dba_local].[dbo].[install_usp_logevent] @errMessage
  362. END
  363. END CATCH
  364. GO
  365. /****** Object: StoredProcedure [dbo].[spLoadSessionStatus] Script Date: 2/1/2016 10:56:17 AM ******/
  366. IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[spLoadSessionStatus]') AND type in (N'P', N'PC'))
  367. BEGIN
  368. DROP PROCEDURE dbo.[spLoadSessionStatus]
  369. PRINT 'Procedure spLoadSessionStatus exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
  370. END;
  371. IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[spLoadSessionStatus]') AND type in (N'P', N'PC'))
  372. BEGIN
  373. EXEC dbo.sp_executesql @statement = N'CREATE PROC [dbo].[spLoadSessionStatus]
  374. AS
  375. BEGIN
  376. delete from dbo.Sessionstatus where DateCaptured < DATEADD(dd,-5,getdate());
  377. INSERT INTO dbo.Sessionstatus
  378. 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]
  379. from sys.dm_exec_requests r
  380. where
  381. r.blocking_session_id = 0 and r.status NOT IN (''suspended'',''background'')
  382. group by status,DB_NAME(database_id),wait_type
  383. UNION ALL
  384. 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]
  385. from sys.dm_exec_requests r
  386. where
  387. r.blocking_session_id = 0 and r.status = ''suspended''
  388. group by status,DB_NAME(database_id),wait_type
  389. UNION ALL
  390. 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]
  391. from sys.dm_exec_requests r
  392. where
  393. -- r.session_id > 50 and
  394. r.blocking_session_id <> 0
  395. GROUP BY DB_NAME(database_id),wait_type
  396. UNION ALL
  397. 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]
  398. from sys.sysprocesses s left join sys.dm_exec_requests r
  399. on s.spid = r.session_id
  400. where
  401. r.session_id is NULL
  402. GROUP BY DB_NAME(database_id),s.status,s.lastwaittype
  403. END';
  404. PRINT 'Procedure spLoadSessionStatus created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping table'
  405. END
  406. GO
  407. IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[spGetPerfCountersFromPowerShell]') AND type in (N'P', N'PC'))
  408. BEGIN
  409. DROP PROCEDURE dbo.[spGetPerfCountersFromPowerShell]
  410. PRINT 'Procedure spGetPerfCountersFromPowerShell exists on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' dropping procedure'
  411. END;
  412. IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[spGetPerfCountersFromPowerShell]') AND type in (N'P', N'PC'))
  413. BEGIN
  414. EXEC dbo.sp_executesql @statement = N'
  415. -- =============================================
  416. -- Author: Adrian Sullivan, [email protected]
  417. -- Create date: 2016/12/12
  418. -- Description: Taking away the need for PS1 files and script folder
  419. -- Update: Guilaumme Kierfer
  420. -- Update date: 2017/04/18
  421. -- Description: Update to handle named instance
  422. -- =============================================
  423. CREATE PROCEDURE [dbo].[spGetPerfCountersFromPowerShell]
  424. AS
  425. BEGIN
  426. DECLARE @syscounters NVARCHAR(4000)
  427. SET @syscounters=STUFF((SELECT DISTINCT '''''','''''' +LTRIM([counter_name])
  428. FROM [dba_local].[dbo].[PerformanceCounterList]
  429. WHERE [is_captured_ind] = 1 FOR XML PATH('''')), 1, 2, '''')+''''''''
  430. DECLARE @cmd NVARCHAR(4000)
  431. DECLARE @syscountertable TABLE (id INT IDENTITY(1,1), [output] VARCHAR(500))
  432. DECLARE @syscountervaluestable TABLE (id INT IDENTITY(1,1), [value] VARCHAR(500))
  433. SET @cmd = ''C:\WINDOWS\system32\WindowsPowerShell\v1.0\powershell.exe "& get-counter -counter ''+ @syscounters +'' | Select-Object -ExpandProperty Readings"''
  434. INSERT @syscountertable
  435. EXEC master..xp_cmdshell @cmd
  436. declare @sqlnamedinstance sysname
  437. declare @networkname sysname
  438. if (select CHARINDEX(''\'',@@SERVERNAME)) = 0
  439. begin
  440. INSERT [dba_local].[dbo].[PerformanceCounter] (CounterName, CounterValue, DateSampled)
  441. SELECT REPLACE(REPLACE(REPLACE(ct.[output],''\\''+@@SERVERNAME+''\'',''''),'' :'',''''),''sqlserver:'','''')[CounterName] , CONVERT(varchar(20),ct2.[output]) [CounterValue], GETDATE() [DateSampled]
  442. FROM @syscountertable ct
  443. LEFT OUTER JOIN (
  444. SELECT id - 1 [id], [output]
  445. FROM @syscountertable
  446. WHERE PATINDEX(''%[0-9]%'', LEFT([output],1)) > 0
  447. ) ct2 ON ct.id = ct2.id
  448. WHERE ct.[output] LIKE ''\\%''
  449. ORDER BY [CounterName] ASC
  450. end
  451. else
  452. begin
  453. select @networkname=RTRIM(left(@@SERVERNAME, CHARINDEX(''\'', @@SERVERNAME) - 1))
  454. select @sqlnamedinstance=RIGHT(@@SERVERNAME,CHARINDEX(''\'',REVERSE(@@SERVERNAME))-1)
  455. INSERT [dba_local].[dbo].[PerformanceCounter] (CounterName, CounterValue, DateSampled)
  456. SELECT REPLACE(REPLACE(REPLACE(ct.[output],''\\''+@networkname+''\'',''''),'' :'',''''),''mssql$''+@sqlnamedinstance+'':'','''')[CounterName] , CONVERT(varchar(20),ct2.[output]) [CounterValue], GETDATE() [DateSampled]
  457. FROM @syscountertable ct
  458. LEFT OUTER JOIN (
  459. SELECT id - 1 [id], [output]
  460. FROM @syscountertable
  461. WHERE PATINDEX(''%[0-9]%'', LEFT([output],1)) > 0
  462. ) ct2 ON ct.id = ct2.id
  463. WHERE ct.[output] LIKE ''\\%''
  464. ORDER BY [CounterName] ASC
  465. END
  466. END';
  467. PRINT 'Procedure spGetPerfCountersFromPowerShell created on server ' + CAST(SERVERPROPERTY('ServerName') AS VARCHAR(100)) + ' '
  468. END
  469. GO