Skip to content

Commit fa5b6a6

Browse files
author
Ajay Dwivedi
committed
Updating Codes
Updating Codes
1 parent 1736c74 commit fa5b6a6

File tree

5 files changed

+77
-16
lines changed

5 files changed

+77
-16
lines changed
0 Bytes
Binary file not shown.

Backup-Restore/Query - Backup History.sql

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11
---------------------------------------------------------------------------------
22
--Database Backups for all databases For Previous Week
33
---------------------------------------------------------------------------------
4-
SELECT TOP (100) CONVERT(CHAR(100), SERVERPROPERTY('Servername')) AS SERVER
4+
SELECT TOP (10) CONVERT(CHAR(100), SERVERPROPERTY('Servername')) AS SERVER
55
,bs.database_name
66
,bs.backup_start_date
77
,bs.backup_finish_date
@@ -24,6 +24,6 @@ SELECT TOP (100) CONVERT(CHAR(100), SERVERPROPERTY('Servername')) AS SERVER
2424
,is_copy_only
2525
FROM msdb.dbo.backupmediafamily AS bmf
2626
INNER JOIN msdb.dbo.backupset AS bs ON bmf.media_set_id = bs.media_set_id
27-
WHERE --msdb..backupset.type='D' and database_name=''
28-
database_name = 'Cosmo'
27+
WHERE bs.type='D' and
28+
database_name = 'CMS'
2929
ORDER BY bs.backup_finish_date DESC

BlitzQueries/Plan-Cache-Analysis.sql

Lines changed: 59 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,61 @@
1-
https://www.sqlskills.com/blogs/kimberly/plan-cache-adhoc-workloads-and-clearing-the-single-use-plan-cache-bloat/
1+
-- https://www.sqlskills.com/blogs/kimberly/plan-cache-adhoc-workloads-and-clearing-the-single-use-plan-cache-bloat/
2+
-- https://www.sqlskills.com/blogs/kimberly/plan-cache-and-optimizing-for-adhoc-workloads/
3+
-- https://www.sqlshack.com/searching-the-sql-server-query-plan-cache/
4+
-- https://sqlperformance.com/2014/10/t-sql-queries/performance-tuning-whole-plan
25

3-
https://www.sqlskills.com/blogs/kimberly/plan-cache-and-optimizing-for-adhoc-workloads/
46

7+
/* Query plans with Warnings */
8+
;WITH XMLNAMESPACES
9+
(DEFAULT 'http://schemas.microsoft.com/sqlserver/2004/07/showplan')
10+
SELECT TOP 20
11+
dm_exec_sql_text.text AS sql_text,
12+
CAST(CAST(dm_exec_query_stats.execution_count AS DECIMAL) / CAST((CASE WHEN DATEDIFF(HOUR, dm_exec_query_stats.creation_time, CURRENT_TIMESTAMP) = 0 THEN 1 ELSE DATEDIFF(HOUR, dm_exec_query_stats.creation_time, CURRENT_TIMESTAMP) END) AS DECIMAL) AS INT) AS executions_per_hour,
13+
dm_exec_query_stats.creation_time,
14+
dm_exec_query_stats.execution_count,
15+
CAST(CAST(dm_exec_query_stats.total_worker_time AS DECIMAL)/CAST(dm_exec_query_stats.execution_count AS DECIMAL) AS INT) as cpu_per_execution,
16+
CAST(CAST(dm_exec_query_stats.total_logical_reads AS DECIMAL)/CAST(dm_exec_query_stats.execution_count AS DECIMAL) AS INT) as logical_reads_per_execution,
17+
CAST(CAST(dm_exec_query_stats.total_elapsed_time AS DECIMAL)/CAST(dm_exec_query_stats.execution_count AS DECIMAL) AS INT) as elapsed_time_per_execution,
18+
dm_exec_query_stats.total_worker_time AS total_cpu_time,
19+
dm_exec_query_stats.max_worker_time AS max_cpu_time,
20+
dm_exec_query_stats.total_elapsed_time,
21+
dm_exec_query_stats.max_elapsed_time,
22+
dm_exec_query_stats.total_logical_reads,
23+
dm_exec_query_stats.max_logical_reads,
24+
dm_exec_query_stats.total_physical_reads,
25+
dm_exec_query_stats.max_physical_reads,
26+
dm_exec_query_plan.query_plan
27+
FROM sys.dm_exec_query_stats
28+
CROSS APPLY sys.dm_exec_sql_text(dm_exec_query_stats.sql_handle)
29+
CROSS APPLY sys.dm_exec_query_plan(dm_exec_query_stats.plan_handle)
30+
WHERE query_plan.exist('//Warnings') = 1
31+
AND query_plan.exist('//ColumnReference[@Database = "[AMGMusic]"]') = 1
32+
ORDER BY dm_exec_query_stats.total_worker_time DESC;
33+
34+
/* Plans with Table/Clustered Index Scan */
35+
;WITH XMLNAMESPACES
36+
(DEFAULT 'http://schemas.microsoft.com/sqlserver/2004/07/showplan')
37+
SELECT
38+
dm_exec_sql_text.text AS sql_text,
39+
CAST(CAST(dm_exec_query_stats.execution_count AS DECIMAL) / CAST((CASE WHEN DATEDIFF(HOUR, dm_exec_query_stats.creation_time, CURRENT_TIMESTAMP) = 0 THEN 1 ELSE DATEDIFF(HOUR, dm_exec_query_stats.creation_time, CURRENT_TIMESTAMP) END) AS DECIMAL) AS INT) AS executions_per_hour,
40+
dm_exec_query_stats.creation_time,
41+
dm_exec_query_stats.execution_count,
42+
CAST(CAST(dm_exec_query_stats.total_worker_time AS DECIMAL)/CAST(dm_exec_query_stats.execution_count AS DECIMAL) AS INT) as cpu_per_execution,
43+
CAST(CAST(dm_exec_query_stats.total_logical_reads AS DECIMAL)/CAST(dm_exec_query_stats.execution_count AS DECIMAL) AS INT) as logical_reads_per_execution,
44+
CAST(CAST(dm_exec_query_stats.total_elapsed_time AS DECIMAL)/CAST(dm_exec_query_stats.execution_count AS DECIMAL) AS INT) as elapsed_time_per_execution,
45+
dm_exec_query_stats.total_worker_time AS total_cpu_time,
46+
dm_exec_query_stats.max_worker_time AS max_cpu_time,
47+
dm_exec_query_stats.total_elapsed_time,
48+
dm_exec_query_stats.max_elapsed_time,
49+
dm_exec_query_stats.total_logical_reads,
50+
dm_exec_query_stats.max_logical_reads,
51+
dm_exec_query_stats.total_physical_reads,
52+
dm_exec_query_stats.max_physical_reads,
53+
dm_exec_query_plan.query_plan
54+
FROM sys.dm_exec_query_stats
55+
CROSS APPLY sys.dm_exec_sql_text(dm_exec_query_stats.sql_handle)
56+
CROSS APPLY sys.dm_exec_query_plan(dm_exec_query_stats.plan_handle)
57+
WHERE (query_plan.exist('//RelOp[@PhysicalOp = "Index Scan"]') = 1
58+
OR query_plan.exist('//RelOp[@PhysicalOp = "Clustered Index Scan"]') = 1)
59+
AND query_plan.exist('//ColumnReference[@Database = "[AdventureWorks2014]"]') = 1
60+
ORDER BY dm_exec_query_stats.total_worker_time DESC;
61+

PowerShell Commands/Ping Servers.sql

Lines changed: 1 addition & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,8 @@
11
/* PowerShell Command */
22
$sizeThreshold_In_MB = 5;
33
$pingResultPath = 'F:\PingMirroringPartners\';
4-
#$pingResultPath = '\\TUL1CORPWIT1\F$\PingMirroringPartners\';
54
$pingResultFile = 'F:\PingMirroringPartners\pingResult';
6-
$names = @('TUL1CIPXIDB2','TUL1CIPXIDB3');
5+
$names = @('MyDatabaseServer01');
76

87
# Delete files older than 15 days
98
$limit = (Get-Date).AddDays(-15);

SQL Jobs/Mail-Notification-Long-Running-Jobs.sql

Lines changed: 14 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -57,6 +57,8 @@ where Ignore = 0
5757
--select * FROM dbo.SqlAgentJobs where Ignore = 0;
5858

5959

60+
SET NOCOUNT ON;
61+
6062
IF OBJECT_ID('tempdb..#JobPastHistory') IS NOT NULL
6163
DROP TABLE #JobPastHistory;
6264
;with t_history as
@@ -121,9 +123,7 @@ IF OBJECT_ID('tempdb..#JobActivityMonitor') IS NOT NULL
121123
select JobName = COALESCE(a.JobName, h.JobName), h.instance_id, [Running Since] = a.start_execution_date
122124
,[<3-Hrs], [3-Hrs], [6-Hrs], [9-Hrs], [12-Hrs], [18-Hrs], [24-Hrs], [36-Hrs], [48-Hrs]
123125
into #JobActivityMonitor
124-
from t_jobActivityMonitor as a full outer join t_history_info as h on h.JobName = a.JobName;
125-
126-
--select * from #JobActivityMonitor
126+
from t_jobActivityMonitor as a full outer join t_history_info as h on h.JobName = a.JobName
127127

128128
-- Step 01 - Remove Previous Running Jobs ([Running Since] = NULL)
129129
UPDATE DBA.dbo.SqlAgentJobs
@@ -228,14 +228,19 @@ SET @tableHTML = N'
228228
<p></p><br><br>
229229
Thanks & Regards,<br>
230230
SQLAlerts<br>
231-
-- Alert from job [DBA - Long Running Jobs]
231+
-- Alert from job [DBA - Long Running Jobs]
232232
' ;
233233

234-
EXEC msdb.dbo.sp_send_dbmail
235-
@recipients='[email protected]',
236-
@subject = @subject,
237-
@body = @tableHTML,
238-
@body_format = 'HTML' ;
234+
IF @tableHTML IS NOT NULL
235+
BEGIN
236+
EXEC msdb.dbo.sp_send_dbmail
237+
@recipients='[email protected]',
238+
@subject = @subject,
239+
@body = @tableHTML,
240+
@body_format = 'HTML' ;
241+
END
242+
ELSE
243+
PRINT 'No Long Running job found.';
239244

240245
SELECT * FROM DBA.dbo.SqlAgentJobs as j WHERE j.Ignore = 0 AND j.[Running Since] IS NOT NULL
241246
--AND (DATEDIFF(MINUTE,[Running Since],GETDATE()) > [Expected-Max-Duration(Min)] AND DATEDIFF(MINUTE,[Running Since],GETDATE()) > 60)

0 commit comments

Comments
 (0)