forked from soupowertuning/Script_SQLServer_Alerts
-
Notifications
You must be signed in to change notification settings - Fork 0
/
2.1 - Create All Alert Procedures and Jobs.sql
7922 lines (6183 loc) · 277 KB
/
2.1 - Create All Alert Procedures and Jobs.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
/***********************************************************************************************************************************
(C) 2016, autor: Fabricio França Lima
Blog: https://www.fabriciolima.net/blog/
Feedback: suporte@powertuning.com.br
Instagram: @fabriciofrancalima
Twitter: @fabriciodba
Facebook: https://www.facebook.com/fabricio.francalima
Linkedin: https://www.linkedin.com/in/fabriciofrancalima/
Consultoria: comercial@powertuning.com.br
***********************************************************************************************************************************/
USE Traces
GO
IF ( OBJECT_ID('[dbo].[stpAlert_Every_Day]') IS NOT NULL )
DROP PROCEDURE [dbo].stpAlert_Every_Day
GO
CREATE PROCEDURE dbo.stpAlert_Every_Day
AS
BEGIN
select 'O script dos alertas foram melhorados após a criação do vídeo e não precisam mais dessa procedure'
select 'Todos os alertas são chamados pela sp stpAlert_Every_Minute controlados pelas 3 colunas novas criadas em Alert_Paramenter'
END
GO
SET NOCOUNT ON
IF ( OBJECT_ID('[dbo].[HTML_Parameter]') IS NOT NULL )
DROP TABLE [dbo].HTML_Parameter
CREATE TABLE HTML_Parameter (
Company_Link VARCHAR(4000),
Line_Space VARCHAR(4000),
Header VARCHAR(4000))
INSERT INTO HTML_Parameter(Company_Link,Line_Space,Header)
SELECT '<br />
<br />'
+
'<a href="http://www.powertuning.com.br" target=”_blank”>
<img src="https://www.fabriciolima.net/wp-content/uploads/2020/02/logotipo-powertuning-v2.png"
height="150" width="400"/>
</a>',
'<br />
<br />',
'<font color=black bold=true size=5>
<BR /> HEADERTEXT <BR />
</font>'
GO
IF ( OBJECT_ID('dbo.stpSend_Dbmail') IS NOT NULL )
DROP PROCEDURE [dbo].stpSend_Dbmail
GO
CREATE PROCEDURE stpSend_Dbmail @Ds_Profile_Email VARCHAR(200), @Ds_Email VARCHAR(500),@Ds_Subject VARCHAR(500),@Ds_Mail_HTML VARCHAR(MAX),@Ds_BodyFormat VARCHAR(50),@Ds_Importance VARCHAR(50)
AS
EXEC msdb.dbo.sp_send_dbmail
@profile_name = @Ds_Profile_Email,
@recipients = @Ds_Email,
@subject = @Ds_Subject,
@body = @Ds_Mail_HTML,
@body_format = @Ds_BodyFormat,
@importance = @Ds_Importance
GO
GO
IF ( OBJECT_ID('[dbo].[stpExport_Table_HTML_Output]') IS NOT NULL )
DROP PROCEDURE [dbo].stpExport_Table_HTML_Output
GO
CREATE PROCEDURE [dbo].[stpExport_Table_HTML_Output]
@Ds_Tabela [varchar](max),
@Fl_Aplica_Estilo_Padrao BIT = 1,
@Ds_Alinhamento VARCHAR(10) = 'left',
@Ds_OrderBy VARCHAR(MAX) = '',
@Ds_Saida VARCHAR(MAX) OUTPUT
AS
BEGIN
/*
--retirado do código 23/07
table { padding:0; border-spacing: 0; border-collapse: collapse; }
Autor: Dirceu Resende
Post: https://www.dirceuresende.com/blog/como-exportar-dados-de-uma-tabela-do-sql-server-para-html/
*/
SET NOCOUNT ON
DECLARE
@query NVARCHAR(MAX),
@Database sysname,
@Nome_Tabela sysname
IF (LEFT(@Ds_Tabela, 1) = '#')
BEGIN
SET @Database = 'tempdb.'
SET @Nome_Tabela = @Ds_Tabela
END
ELSE BEGIN
SET @Database = LEFT(@Ds_Tabela, CHARINDEX('.', @Ds_Tabela))
SET @Nome_Tabela = SUBSTRING(@Ds_Tabela, LEN(@Ds_Tabela) - CHARINDEX('.', REVERSE(@Ds_Tabela)) + 2, LEN(@Ds_Tabela))
END
SET @query = '
SELECT ORDINAL_POSITION, COLUMN_NAME, DATA_TYPE, CHARACTER_MAXIMUM_LENGTH, NUMERIC_PRECISION, NUMERIC_SCALE
FROM ' + @Database + 'INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_NAME = ''' + @Nome_Tabela + '''
ORDER BY ORDINAL_POSITION'
IF (OBJECT_ID('tempdb..#Colunas') IS NOT NULL) DROP TABLE #Colunas
CREATE TABLE #Colunas (
ORDINAL_POSITION int,
COLUMN_NAME sysname,
DATA_TYPE nvarchar(128),
CHARACTER_MAXIMUM_LENGTH int,
NUMERIC_PRECISION tinyint,
NUMERIC_SCALE int
)
INSERT INTO #Colunas
EXEC(@query)
IF (@Fl_Aplica_Estilo_Padrao = 1)
BEGIN
SET @Ds_Saida = '<html>
<head>
<title>Titulo</title>
<style type="text/css">
table { border: outset 2.25pt; }
thead { background: #0B0B61; }
th { color: #fff; padding: 10px;}
td { padding: 3.0pt 3.0pt 3.0pt 3.0pt; text-align:' + @Ds_Alinhamento + '; }
</style>
</head>';
END
SET @Ds_Saida = ISNULL(@Ds_Saida, '') + '
<table border="1" cellpadding="0">
<thead>
<tr>'
DECLARE @totalColunas INT
SET @totalColunas = (SELECT COUNT(*) FROM #Colunas)
-- Cabeçalho da tabela
DECLARE @contadorColuna INT
SET @contadorColuna = 1
declare
@nomeColuna sysname,
@tipoColuna sysname
WHILE(@contadorColuna <= @totalColunas)
BEGIN
SELECT @nomeColuna = COLUMN_NAME
FROM #Colunas
WHERE ORDINAL_POSITION = @contadorColuna
SET @Ds_Saida = ISNULL(@Ds_Saida, '') + '
<th>' + @nomeColuna + '</th>'
SET @contadorColuna = @contadorColuna + 1
END
SET @Ds_Saida = ISNULL(@Ds_Saida, '') + '
</tr>
</thead>
<tbody>'
-- Conteúdo da tabela
DECLARE @saida VARCHAR(MAX)
SET @query = '
SELECT @saida = (
SELECT '
SET @contadorColuna = 1
WHILE(@contadorColuna <= @totalColunas)
BEGIN
SELECT
@nomeColuna = COLUMN_NAME,
@tipoColuna = DATA_TYPE
FROM
#Colunas
WHERE
ORDINAL_POSITION = @contadorColuna
IF (@tipoColuna IN ('int', 'bigint', 'float', 'numeric', 'decimal', 'bit', 'tinyint', 'smallint', 'integer'))
BEGIN
SET @query = @query + '
ISNULL(CAST([' + @nomeColuna + '] AS VARCHAR(MAX)), '''') AS [td]'
END
ELSE BEGIN
SET @query = @query + '
ISNULL([' + @nomeColuna + '], '''') AS [td]'
END
IF (@contadorColuna < @totalColunas)
SET @query = @query + ','
SET @contadorColuna = @contadorColuna + 1
END
SET @query = @query + '
FROM ' + @Ds_Tabela + (CASE WHEN ISNULL(@Ds_OrderBy, '') = '' THEN '' ELSE '
ORDER BY ' END) + @Ds_OrderBy + '
FOR XML RAW(''tr''), Elements
)'
EXEC tempdb.sys.sp_executesql
@query,
N'@saida NVARCHAR(MAX) OUTPUT',
@saida OUTPUT
-- Identação
SET @saida = REPLACE(@saida, '<tr>', '
<tr>')
SET @saida = REPLACE(@saida, '<td>', '
<td>')
SET @saida = REPLACE(@saida, '</tr>', '
</tr>')
SET @Ds_Saida = ISNULL(@Ds_Saida, '') + @saida
SET @Ds_Saida = ISNULL(@Ds_Saida, '') + '
</tbody>
</table>'
END
GO
GO
IF ( OBJECT_ID('[dbo].[stpRead_Error_log]') IS NOT NULL )
DROP PROCEDURE [dbo].stpRead_Error_log
GO
CREATE PROCEDURE stpRead_Error_log @Actual_Log bit
AS
BEGIN
SET DATEFORMAT YMD
IF (OBJECT_ID('tempdb..##Error_Log_Result') IS NOT NULL)
DROP TABLE ##Error_Log_Result
CREATE TABLE ##Error_Log_Result (
[LogDate] DATETIME,
[ProcessInfo] NVARCHAR(50),
[Text] NVARCHAR(MAX)
)
IF (OBJECT_ID('tempdb..#logF') IS NOT NULL)
DROP TABLE #logF
CREATE TABLE #logF (
[ArchiveNumber] INT,
[LogDate] DATETIME,
[LogSize] INT
)
INSERT INTO #logF
EXEC sp_enumerrorlogs
IF @Actual_Log = 0
BEGIN
DELETE FROM #logF
WHERE ArchiveNumber NOT IN (
SELECT ArchiveNumber
FROM #logF
WHERE (LogDate > DATEADD(hh,-36,GETDATE()) -- many files from 30 hours
OR ArchiveNumber <= 1) --OR two old files to be faster
)
END
ELSE --@Actual_Log = 1 - most recent
BEGIN
DELETE FROM #logF
WHERE ArchiveNumber <> 0
DECLARE @Vl_Parameter_2 int
SELECT @Vl_Parameter_2 = Vl_Parameter_2 FROM [Alert_Parameter] WHERE [Nm_Alert] = 'Slow Disk Every Hour'
DELETE FROM #logF
WHERE LogSize >= @Vl_Parameter_2 * 1024*1024-- just look at small logs
END
DECLARE @lC INT
SELECT @lC = MIN(ArchiveNumber) FROM #logF
WHILE @lC IS NOT NULL
BEGIN
INSERT INTO ##Error_Log_Result
EXEC sp_readerrorlog @lC
SELECT @lC = MIN(ArchiveNumber) FROM #logF
WHERE ArchiveNumber > @lC
END
END
GO
/****** Object: StoredProcedure [dbo].[stpWhoIsActive_Result] Script Date: 20/05/2019 13:23:09 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
IF ( OBJECT_ID('[dbo].[stpWhoIsActive_Result]') IS NOT NULL )
DROP PROCEDURE [dbo].stpWhoIsActive_Result
GO
CREATE PROCEDURE [dbo].[stpWhoIsActive_Result]
AS
BEGIN
IF ( OBJECT_ID('tempdb..#WhoIsActive_Result') IS NOT NULL )
DROP TABLE #WhoIsActive_Result
-- Table with the WhoisActive Result that will be used for all Alert Procedures
CREATE TABLE #WhoIsActive_Result(
[dd hh:mm:ss.mss] VARCHAR(20),
[database_name] VARCHAR(128),
[login_name] VARCHAR(128),
[host_name] VARCHAR(128),
[start_time] datetime,
[status] VARCHAR(30),
[session_id] INT,
[blocking_session_id] INT,
[wait_info] VARCHAR(MAX),
[open_tran_count] INT,
[CPU] VARCHAR(MAX),
[CPU_delta] VARCHAR(MAX),
[reads] VARCHAR(MAX),
[reads_delta] VARCHAR(MAX),
[writes] VARCHAR(MAX),
[sql_command] XML,
[sql_text] XML
)
EXEC [dbo].[sp_whoisactive]
@get_outer_command = 1,
@delta_interval = 1,
@output_column_list = '[dd hh:mm:ss.mss][database_name][login_name][host_name][start_time][status][session_id][blocking_session_id][wait_info][open_tran_count][CPU][CPU_delta][reads][reads_delta][writes][sql_command][sql_text]',
@destination_table = '#WhoIsActive_Result'
ALTER TABLE #WhoIsActive_Result
ALTER COLUMN [sql_command] NVARCHAR(MAX)
UPDATE #WhoIsActive_Result
SET [sql_command] = REPLACE( REPLACE( REPLACE( REPLACE( CAST([sql_command] AS NVARCHAR(4000)), '<?query --', ''), '--?>', ''), '>', '>'), '<', '')
ALTER TABLE #WhoIsActive_Result
ALTER COLUMN [sql_text] NVARCHAR(MAX)
UPDATE #WhoIsActive_Result
SET [sql_text] = REPLACE( REPLACE( REPLACE( REPLACE( CAST([sql_text] AS NVARCHAR(4000)), '<?query --', ''), '--?>', ''), '>', '>'), '<', '')
IF ( OBJECT_ID('tempdb..##WhoIsActive_Result') IS NOT NULL )
DROP TABLE ##WhoIsActive_Result
/*
CREATE TABLE ##WhoIsActive_Result(
[dd hh:mm:ss.mss] VARCHAR(20),
[Database] VARCHAR(128),
[Login] VARCHAR(128),
[Host Name] VARCHAR(128),
[Start Time] varchar(20),
[Status] VARCHAR(30),
[Session ID] INT,
[Blocking Session ID] INT,
[Wait Info] VARCHAR(MAX),
[Open Tran Count] INT,
[CPU] VARCHAR(MAX),
[CPU Delta] VARCHAR(MAX),
[Reads] VARCHAR(MAX),
[Reads Delta] VARCHAR(MAX),
[Writes] VARCHAR(MAX),
[Query] VARCHAR(MAX)
)
insert into ##WhoIsActive_Result
select [dd hh:mm:ss.mss], [database_name], [login_name], [host_name], ISNULL(CONVERT(VARCHAR(20), [start_time], 120), '-') start_time, [status], [session_id], [blocking_session_id],
[wait_info], [open_tran_count], [CPU], [CPU_delta], [reads], [reads_delta], [writes], isnull([sql_command],[sql_text]) Query
from #WhoIsActive_Result
*/
CREATE TABLE ##WhoIsActive_Result(
[dd hh:mm:ss.mss] CHAR(20),
[Database] VARCHAR(128),
[Login] VARCHAR(128),
[Host Name] VARCHAR(128),
[Start Time] varchar(20),
[Status] VARCHAR(30),
[Session ID] INT,
[Blocking Session ID] INT,
[Wait Info] VARCHAR(200),
[Open Tran Count] INT,
[CPU] VARCHAR(200),
[CPU Delta] VARCHAR(200),
[Reads] VARCHAR(200),
[Reads Delta] VARCHAR(200),
[Writes] VARCHAR(200),
[Query] Varchar(300)
)
insert into ##WhoIsActive_Result
select [dd hh:mm:ss.mss], [database_name], [login_name], [host_name], ISNULL(CONVERT(VARCHAR(20), [start_time], 120), '-') start_time, [status], [session_id], [blocking_session_id],
substring([wait_info],1,50), [open_tran_count], [CPU], [CPU_delta], [reads], [reads_delta], [writes], substring(isnull([sql_command],[sql_text]),1,100) Query
from #WhoIsActive_Result
IF NOT EXISTS ( SELECT TOP 1 * FROM ##WhoIsActive_Result )
BEGIN
INSERT INTO ##WhoIsActive_Result
SELECT NULL, NULL, NULL, NULL, NULL, '-', NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL
END
END
GO
USE [Traces]
GO
IF ( OBJECT_ID('[dbo].stpAlert_Index_Fragmentation') IS NOT NULL )
DROP PROCEDURE [dbo].stpAlert_Index_Fragmentation
GO
CREATE PROCEDURE [dbo].stpAlert_Index_Fragmentation
AS
BEGIN
SET NOCOUNT ON
DECLARE @Id_Alert_Parameter SMALLINT, @Fl_Enable BIT, @Fl_Type TINYINT, @Vl_Parameter SMALLINT,@Ds_Email VARCHAR(500),@Ds_Profile_Email VARCHAR(200),@Dt_Now DATETIME,@Vl_Parameter_2 INT,
@Ds_Email_Information_1_ENG VARCHAR(200), @Ds_Email_Information_2_ENG VARCHAR(200), @Ds_Email_Information_1_PTB VARCHAR(200), @Ds_Email_Information_2_PTB VARCHAR(200),
@Ds_Message_Alert_ENG varchar(1000),@Ds_Message_Clear_ENG varchar(1000),@Ds_Message_Alert_PTB varchar(1000),@Ds_Message_Clear_PTB varchar(1000), @Ds_Subject VARCHAR(500)
DECLARE @Company_Link VARCHAR(4000),@Line_Space VARCHAR(4000),@Header_Default VARCHAR(4000),@Header VARCHAR(4000),@Fl_Language BIT,@Final_HTML VARCHAR(MAX),@HTML VARCHAR(MAX)
declare @Ds_Alinhamento VARCHAR(10),@Ds_OrderBy VARCHAR(MAX)
-- Alert information
SELECT @Id_Alert_Parameter = Id_Alert_Parameter,
@Fl_Enable = Fl_Enable,
@Vl_Parameter = Vl_Parameter, -- Minutes,
@Ds_Email = Ds_Email,
@Fl_Language = Fl_Language,
@Ds_Profile_Email = Ds_Profile_Email,
@Vl_Parameter_2 = Vl_Parameter_2, --minute
@Dt_Now = GETDATE(),
@Ds_Message_Alert_ENG = Ds_Message_Alert_ENG,
@Ds_Message_Clear_ENG = Ds_Message_Clear_ENG,
@Ds_Message_Alert_PTB = Ds_Message_Alert_PTB,
@Ds_Message_Clear_PTB = Ds_Message_Clear_PTB,
@Ds_Email_Information_1_ENG = Ds_Email_Information_1_ENG,
@Ds_Email_Information_2_ENG = Ds_Email_Information_2_ENG,
@Ds_Email_Information_1_PTB = Ds_Email_Information_1_PTB,
@Ds_Email_Information_2_PTB = Ds_Email_Information_2_PTB
FROM [dbo].Alert_Parameter
WHERE Nm_Alert = 'Index Fragmentation'
IF @Fl_Enable = 0
RETURN
IF OBJECT_ID('tempdb..#Fragmented_Indexes') IS NOT NULL
DROP TABLE #Fragmented_Indexes
select Nm_Database,Nm_Table,Nm_Index,count(*) [Total Days]
into #Fragmented_Indexes
from vwIndex_Fragmentation_History
where Dt_Log >= dateadd(dd,@Vl_Parameter*-1,cast(getdate() as date))
and Page_Count >= @Vl_Parameter_2
and Avg_Fragmentation_In_Percent > 30 --30% fragmentation
group by Nm_Database,Nm_Table,Nm_Index
--select *
--from #Fragmented_Indexes
--where Total = @Total_Days_Log
if exists (
select null from #Fragmented_Indexes
where [Total Days] >= @Vl_Parameter --value default = 7 days
)
BEGIN -- BEGIN - ALERT
IF ( OBJECT_ID('tempdb..##Email_HTML') IS NOT NULL )
DROP TABLE ##Email_HTML
select Nm_Database [Database], Nm_Table [Table], Nm_Index [Index], [Total Days]
into ##Email_HTML
from #Fragmented_Indexes
where [Total Days] >= @Vl_Parameter --value default = 7 days
-- Get HTML Informations
SELECT @Company_Link = Company_Link,
@Line_Space = Line_Space,
@Header_Default = Header
FROM HTML_Parameter
IF @Fl_Language = 1 --Portuguese
BEGIN
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_1_PTB)
SET @Ds_Subject = REPLACE(@Ds_Message_Alert_PTB,'###1',@Vl_Parameter)+@@SERVERNAME
END
ELSE
BEGIN
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_1_ENG)
SET @Ds_Subject = REPLACE(@Ds_Message_Alert_ENG,'###1',@Vl_Parameter)+@@SERVERNAME
END
EXEC dbo.stpExport_Table_HTML_Output
@Ds_Tabela = '##Email_HTML', -- varchar(max)
@Ds_Alinhamento = 'center',
@Ds_OrderBy = '[Total Days] DESC',
@Ds_Saida = @HTML OUT -- varchar(max)
SET @Final_HTML = @Header + @Line_Space + @HTML + @Line_Space + @Company_Link
EXEC stpSend_Dbmail @Ds_Profile_Email,@Ds_Email,@Ds_Subject,@Final_HTML,'HTML','High'
-- Fl_Type = 1 : ALERT
INSERT INTO [dbo].[Alert] ( [Id_Alert_Parameter], [Ds_Message], [Fl_Type] )
SELECT @Id_Alert_Parameter, @Ds_Subject, 1
END
END
GO
IF ( OBJECT_ID('[dbo].[stpAlert_Cluster_Active_Node]') IS NOT NULL )
DROP PROCEDURE [dbo].stpAlert_Cluster_Active_Node
GO
CREATE PROCEDURE [dbo].stpAlert_Cluster_Active_Node
AS
BEGIN
SET NOCOUNT ON
DECLARE @Id_Alert_Parameter SMALLINT, @Fl_Enable BIT, @Fl_Type TINYINT, @Vl_Parameter SMALLINT,@Ds_Email VARCHAR(500),@Ds_Profile_Email VARCHAR(200),@Dt_Now DATETIME,@Vl_Parameter_2 INT,
@Ds_Email_Information_1_ENG VARCHAR(200), @Ds_Email_Information_2_ENG VARCHAR(200), @Ds_Email_Information_1_PTB VARCHAR(200), @Ds_Email_Information_2_PTB VARCHAR(200),
@Ds_Message_Alert_ENG varchar(1000),@Ds_Message_Clear_ENG varchar(1000),@Ds_Message_Alert_PTB varchar(1000),@Ds_Message_Clear_PTB varchar(1000), @Ds_Subject VARCHAR(500)
DECLARE @Company_Link VARCHAR(4000),@Line_Space VARCHAR(4000),@Header_Default VARCHAR(4000),@Header VARCHAR(4000),@Fl_Language BIT,@Final_HTML VARCHAR(MAX),@HTML VARCHAR(MAX)
declare @Ds_Alinhamento VARCHAR(10),@Ds_OrderBy VARCHAR(MAX)
-- Alert information
SELECT @Id_Alert_Parameter = Id_Alert_Parameter,
@Fl_Enable = Fl_Enable,
@Vl_Parameter = Vl_Parameter, -- Minutes,
@Ds_Email = Ds_Email,
@Fl_Language = Fl_Language,
@Ds_Profile_Email = Ds_Profile_Email,
@Vl_Parameter_2 = Vl_Parameter_2, --minute
@Dt_Now = GETDATE(),
@Ds_Message_Alert_ENG = Ds_Message_Alert_ENG,
@Ds_Message_Clear_ENG = Ds_Message_Clear_ENG,
@Ds_Message_Alert_PTB = Ds_Message_Alert_PTB,
@Ds_Message_Clear_PTB = Ds_Message_Clear_PTB,
@Ds_Email_Information_1_ENG = Ds_Email_Information_1_ENG,
@Ds_Email_Information_2_ENG = Ds_Email_Information_2_ENG,
@Ds_Email_Information_1_PTB = Ds_Email_Information_1_PTB,
@Ds_Email_Information_2_PTB = Ds_Email_Information_2_PTB
FROM [dbo].Alert_Parameter
WHERE Nm_Alert = 'Failover Cluster Active Node'
IF @Fl_Enable = 0
RETURN
declare @Active_Node VARCHAR(200), @Table_Active_Node VARCHAR(200)
select @Active_Node = CONVERT(VARCHAR(100), SERVERPROPERTY('ComputerNamePhysicalNetBIOS'))
SELECT @Table_Active_Node = Nm_Active_server FROM Alert_Cluster_Active_Node
IF @Table_Active_Node <> @Active_Node
BEGIN
IF ( OBJECT_ID('tempdb..##Email_HTML') IS NOT NULL )
DROP TABLE ##Email_HTML
SELECT @Active_Node [Active Node], @Table_Active_Node [Passive Node]
into ##Email_HTML
--FROM Alert_Cluster_Active_Node
UPDATE Alert_Cluster_Active_Node
SET Nm_Active_server = @Active_Node
where Nm_Active_server <> @Active_Node
-- Get HTML Informations
SELECT @Company_Link = Company_Link,
@Line_Space = Line_Space,
@Header_Default = Header
FROM HTML_Parameter
IF @Fl_Language = 1 --Portuguese
BEGIN
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_1_PTB)
SET @Ds_Subject = @Ds_Message_Alert_PTB
END
ELSE
BEGIN
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_1_ENG)
SET @Ds_Subject = @Ds_Message_Alert_ENG
END
EXEC dbo.stpExport_Table_HTML_Output
@Ds_Tabela = '##Email_HTML', -- varchar(max)
@Ds_Alinhamento = 'center',
--@Ds_OrderBy = '[Database Name]',
@Ds_Saida = @HTML OUT -- varchar(max)
-- First Result
SET @Final_HTML = @Header + @Line_Space + @HTML + @Line_Space + @Company_Link
EXEC stpSend_Dbmail @Ds_Profile_Email,@Ds_Email,@Ds_Subject,@Final_HTML,'HTML','High'
-- Fl_Type = 1 : ALERT
INSERT INTO [dbo].[Alert] ( [Id_Alert_Parameter], [Ds_Message], [Fl_Type] )
SELECT @Id_Alert_Parameter, @Ds_Subject, 1
END
END
GO
IF ( OBJECT_ID('[dbo].[stpAlert_CPU_Utilization_MI]') IS NOT NULL )
DROP PROCEDURE [dbo].stpAlert_CPU_Utilization_MI
GO
--[dbo].[stpWhoIsActive_Result]
CREATE PROCEDURE [dbo].[stpAlert_CPU_Utilization_MI]
AS
BEGIN
SET NOCOUNT ON
DECLARE @Id_Alert_Parameter SMALLINT, @Fl_Enable BIT, @Fl_Type TINYINT, @Vl_Parameter SMALLINT,@Ds_Email VARCHAR(500),@Ds_Profile_Email VARCHAR(200),@Dt_Now DATETIME,@Vl_Parameter_2 INT,
@Ds_Email_Information_1_ENG VARCHAR(200), @Ds_Email_Information_2_ENG VARCHAR(200), @Ds_Email_Information_1_PTB VARCHAR(200), @Ds_Email_Information_2_PTB VARCHAR(200),
@Ds_Message_Alert_ENG varchar(1000),@Ds_Message_Clear_ENG varchar(1000),@Ds_Message_Alert_PTB varchar(1000),@Ds_Message_Clear_PTB varchar(1000), @Ds_Subject VARCHAR(500)
DECLARE @Company_Link VARCHAR(4000),@Line_Space VARCHAR(4000),@Header_Default VARCHAR(4000),@Header VARCHAR(4000),@Fl_Language BIT,@Final_HTML VARCHAR(MAX),@HTML VARCHAR(MAX)
declare @Ds_Alinhamento VARCHAR(10),@Ds_OrderBy VARCHAR(MAX)
--IF OBJECT_ID('tempdb..##WhoIsActive_Result') IS NULL
-- return
-- Alert information
SELECT @Id_Alert_Parameter = Id_Alert_Parameter,
@Fl_Enable = Fl_Enable,
@Vl_Parameter = Vl_Parameter, -- Minutes,
@Ds_Email = Ds_Email,
@Fl_Language = Fl_Language,
@Ds_Profile_Email = Ds_Profile_Email,
@Vl_Parameter_2 = Vl_Parameter_2, --minute
@Dt_Now = GETDATE(),
@Ds_Message_Alert_ENG = Ds_Message_Alert_ENG,
@Ds_Message_Clear_ENG = Ds_Message_Clear_ENG,
@Ds_Message_Alert_PTB = Ds_Message_Alert_PTB,
@Ds_Message_Clear_PTB = Ds_Message_Clear_PTB,
@Ds_Email_Information_1_ENG = Ds_Email_Information_1_ENG,
@Ds_Email_Information_2_ENG = Ds_Email_Information_2_ENG,
@Ds_Email_Information_1_PTB = Ds_Email_Information_1_PTB,
@Ds_Email_Information_2_PTB = Ds_Email_Information_2_PTB
FROM [Traces].[dbo].Alert_Parameter
WHERE Nm_Alert = 'CPU Utilization MI'
IF @Fl_Enable = 0
RETURN
-- Look for the last time the alert was executed and find if it was a "0: CLEAR" OR "1: ALERT".
SELECT @Fl_Type = [Fl_Type]
FROM [dbo].[Alert]
WHERE [Id_Alert] = (SELECT MAX(Id_Alert) FROM [dbo].[Alert] WHERE [Id_Alert_Parameter] = @Id_Alert_Parameter )
--------------------------------------------------------------------------------------------------------------------------------
-- CPU Utilization
--------------------------------------------------------------------------------------------------------------------------------
IF ( OBJECT_ID('tempdb..#CPU_Utilization') IS NOT NULL )
DROP TABLE #CPU_Utilization
DECLARE @Top INT
SET @Top = 4 * @Vl_Parameter_2 -- 1 minute = 4 rows
SELECT TOP (@Top) A.*
INTO #CPU_Utilization
FROM master.sys.server_resource_stats A
WHERE A.start_time >= DATEADD(MINUTE,-15,GETDATE()) --6 minutes of delay from MI
ORDER BY start_time desc
-- Do we have CPU problem?
IF (
SELECT COUNT(*)
FROM #CPU_Utilization
WHERE avg_cpu_percent > @Vl_Parameter
) = @Top
BEGIN
IF ISNULL(@Fl_Type, 0) = 0 -- Control Alert/Clear
BEGIN
IF ( OBJECT_ID('tempdb..##Email_HTML') IS NOT NULL )
DROP TABLE ##Email_HTML
SELECT ISNULL(CONVERT(VARCHAR(20), GETDATE(), 120), '-') [Alert Time],ISNULL(CONVERT(VARCHAR(20), [start_time], 120), '-') [Log Azure Time],
resource_name [Resource],sku,virtual_core_count [vCores],avg_cpu_percent [** CPU (%) **],io_requests [IO Request],io_bytes_read [IO bytes Read],io_bytes_written [IO Bytes Written]
INTO ##Email_HTML
FROM #CPU_Utilization
IF ( OBJECT_ID('tempdb..##Email_HTML_2') IS NOT NULL )
DROP TABLE ##Email_HTML_2
SELECT TOP 50 *
INTO ##Email_HTML_2
FROM ##WhoIsActive_Result
-- Get HTML Informations
SELECT @Company_Link = Company_Link,
@Line_Space = Line_Space,
@Header_Default = Header
FROM HTML_Parameter
IF @Fl_Language = 1 --Portuguese
BEGIN
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_1_PTB)
SET @Ds_Subject = REPLACE(@Ds_Message_Alert_PTB,'###1',@Vl_Parameter)+@@SERVERNAME
END
ELSE
BEGIN
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_1_ENG)
SET @Ds_Subject = REPLACE(@Ds_Message_Alert_ENG,'###1',@Vl_Parameter)+@@SERVERNAME
END
EXEC dbo.stpExport_Table_HTML_Output
@Ds_Tabela = '##Email_HTML',
@Ds_Alinhamento = 'center',
@Ds_OrderBy = '[Log Azure Time] DESC',
@Ds_Saida = @HTML OUT
-- First Result
SET @Final_HTML = @Header + @Line_Space + @HTML + @Line_Space
EXEC dbo.stpExport_Table_HTML_Output
@Ds_Tabela = '##Email_HTML_2', -- varchar(max)
@Ds_Alinhamento = 'center',
@Ds_OrderBy = '[dd hh:mm:ss.mss] desc',
@Ds_Saida = @HTML OUT -- varchar(max)
IF @Fl_Language = 1
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_2_PTB)
ELSE
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_2_ENG)
-- Second Result
SET @Final_HTML = @Final_HTML + @Header + @Line_Space + @HTML + @Line_Space + @Company_Link
EXEC [msdb].[dbo].[sp_send_dbmail]
@profile_name = @Ds_Profile_Email,
@recipients = @Ds_Email,
@subject = @Ds_Subject,
@body = @Final_HTML,
@body_format = 'HTML',
@importance = 'High'
-- Fl_Type = 1 : ALERT
INSERT INTO [dbo].[Alert] ( [Id_Alert_Parameter], [Ds_Message], [Fl_Type] )
SELECT @Id_Alert_Parameter, @Ds_Subject, 1
END
END -- END - ALERT
ELSE
BEGIN -- BEGIN - CLEAR
IF @Fl_Type = 1
BEGIN
IF ( OBJECT_ID('tempdb..##Email_HTML_CLEAR') IS NOT NULL )
DROP TABLE ##Email_HTML_CLEAR
SELECT ISNULL(CONVERT(VARCHAR(20), GETDATE(), 120), '-') [Alert Time],ISNULL(CONVERT(VARCHAR(20), [start_time], 120), '-') [Log Azure Time],
resource_name [Resource],sku,virtual_core_count [vCores],avg_cpu_percent [** CPU (%) **],io_requests [IO Request],io_bytes_read [IO bytes Read],io_bytes_written [IO Bytes Written]
INTO ##Email_HTML_CLEAR
FROM #CPU_Utilization
IF ( OBJECT_ID('tempdb..##Email_HTML_CLEAR_2') IS NOT NULL )
DROP TABLE ##Email_HTML_CLEAR_2
SELECT TOP 50 *
INTO ##Email_HTML_CLEAR_2
FROM ##WhoIsActive_Result
-- Get HTML Informations
SELECT @Company_Link = Company_Link,
@Line_Space = Line_Space,
@Header_Default = Header
FROM HTML_Parameter
IF @Fl_Language = 1 --Portuguese
BEGIN
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_1_PTB)
SET @Ds_Subject = REPLACE(@Ds_Message_Clear_PTB,'###1',@Vl_Parameter)+@@SERVERNAME
END
ELSE
BEGIN
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_1_ENG)
SET @Ds_Subject = REPLACE(@Ds_Message_Clear_ENG,'###1',@Vl_Parameter)+@@SERVERNAME
END
EXEC dbo.stpExport_Table_HTML_Output
@Ds_Tabela = '##Email_HTML_CLEAR', -- varchar(max)
@Ds_Alinhamento = 'center',
@Ds_OrderBy = '[Log Azure Time] DESC',
@Ds_Saida = @HTML OUT -- varchar(max)
-- First Result
SET @Final_HTML = @Header + @Line_Space + @HTML + @Line_Space
EXEC dbo.stpExport_Table_HTML_Output
@Ds_Tabela = '##Email_HTML_CLEAR_2', -- varchar(max)
@Ds_Alinhamento = 'center',
@Ds_OrderBy = '[dd hh:mm:ss.mss] desc',
@Ds_Saida = @HTML OUT -- varchar(max)
IF @Fl_Language = 1
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_2_PTB)
ELSE
SET @Header = REPLACE(@Header_Default,'HEADERTEXT',@Ds_Email_Information_2_ENG)
-- Second Result
SET @Final_HTML = @Final_HTML + @Header + @Line_Space + @HTML + @Line_Space + @Company_Link
EXEC [msdb].[dbo].[sp_send_dbmail]
@profile_name = @Ds_Profile_Email,
@recipients = @Ds_Email,
@subject = @Ds_Subject,
@body = @Final_HTML,
@body_format = 'HTML',
@importance = 'High'
-- Fl_Type = 0 : CLEAR
INSERT INTO [dbo].[Alert] ( [Id_Alert_Parameter], [Ds_Message], [Fl_Type] )
SELECT @Id_Alert_Parameter, @Ds_Subject, 0
END
END -- END - CLEAR
END
GO
USE [Traces]
GO
GO
IF ( OBJECT_ID('[dbo].[stpAlert_MaxSize_Growth]') IS NOT NULL )
DROP PROCEDURE [dbo].stpAlert_MaxSize_Growth
GO
--[dbo].[stpWhoIsActive_Result]
CREATE PROCEDURE [dbo].stpAlert_MaxSize_Growth
AS
BEGIN
SET NOCOUNT ON
DECLARE @Id_Alert_Parameter SMALLINT, @Fl_Enable BIT, @Fl_Type TINYINT, @Vl_Parameter SMALLINT,@Ds_Email VARCHAR(500),@Ds_Profile_Email VARCHAR(200),@Dt_Now DATETIME,@Vl_Parameter_2 INT,
@Ds_Email_Information_1_ENG VARCHAR(200), @Ds_Email_Information_2_ENG VARCHAR(200), @Ds_Email_Information_1_PTB VARCHAR(200), @Ds_Email_Information_2_PTB VARCHAR(200),
@Ds_Message_Alert_ENG varchar(1000),@Ds_Message_Clear_ENG varchar(1000),@Ds_Message_Alert_PTB varchar(1000),@Ds_Message_Clear_PTB varchar(1000), @Ds_Subject VARCHAR(500)
DECLARE @Company_Link VARCHAR(4000),@Line_Space VARCHAR(4000),@Header_Default VARCHAR(4000),@Header VARCHAR(4000),@Fl_Language BIT,@Final_HTML VARCHAR(MAX),@HTML VARCHAR(MAX)
declare @Ds_Alinhamento VARCHAR(10),@Ds_OrderBy VARCHAR(MAX)
-- Alert information
SELECT @Id_Alert_Parameter = Id_Alert_Parameter,
@Fl_Enable = Fl_Enable,
@Vl_Parameter = Vl_Parameter, -- Minutes,
@Ds_Email = Ds_Email,
@Fl_Language = Fl_Language,
@Ds_Profile_Email = Ds_Profile_Email,
@Vl_Parameter_2 = Vl_Parameter_2, --minute
@Dt_Now = GETDATE(),
@Ds_Message_Alert_ENG = Ds_Message_Alert_ENG,
@Ds_Message_Clear_ENG = Ds_Message_Clear_ENG,
@Ds_Message_Alert_PTB = Ds_Message_Alert_PTB,
@Ds_Message_Clear_PTB = Ds_Message_Clear_PTB,
@Ds_Email_Information_1_ENG = Ds_Email_Information_1_ENG,
@Ds_Email_Information_2_ENG = Ds_Email_Information_2_ENG,
@Ds_Email_Information_1_PTB = Ds_Email_Information_1_PTB,
@Ds_Email_Information_2_PTB = Ds_Email_Information_2_PTB
FROM [dbo].Alert_Parameter
WHERE Nm_Alert = 'MaxSize Growth'
IF @Fl_Enable = 0
RETURN
-- Look for the last time the alert was executed and find if it was a "0: CLEAR" OR "1: ALERT".
SELECT @Fl_Type = [Fl_Type]
FROM [dbo].[Alert]
WHERE [Id_Alert] = (SELECT MAX(Id_Alert) FROM [dbo].[Alert] WHERE [Id_Alert_Parameter] = @Id_Alert_Parameter )
IF (OBJECT_ID('tempdb..##Alert_MDFs_Sizes') IS NOT NULL)
DROP TABLE ##Alert_MDFs_Sizes
CREATE TABLE ##Alert_MDFs_Sizes (
[Server] VARCHAR(500),
[Nm_Database] VARCHAR(500),
[Logical_Name] VARCHAR(500),
[Type] VARCHAR(500),
[Max_Size] NUMERIC(15,2),
[Size] NUMERIC(15,2),
[Total_Used] NUMERIC(15,2),
[Free_Space (MB)] NUMERIC(15,2),
[Percent_Free] NUMERIC(15,2)
)
EXEC sp_MSforeachdb '
Use [?]
;WITH cte_datafiles AS
(
SELECT name, size = size/128.0,max_size,type_desc FROM sys.database_files
),
cte_datainfo AS
(