├── FREEPROCCACHE.sql ├── Images └── Timeline_sql.jpg ├── GetErrorLog.sql ├── GetConnections.sql ├── FindTriggers.sql ├── AnalyzeTraceFileFromSQLProfiler.sql ├── GetSynonyms.sql ├── GetExecutionPlans.sql ├── DeleteExecutionPlan.sql ├── GetExecutionAndInvokecount.sql ├── Top10WorstProcedures.sql ├── CleanupHistories.sql ├── GetProcedureMetrics.sql ├── GetStatisticSamples.sql ├── GetIndexFragmentation.sql ├── ShowFragmentation.sql ├── LICENSE ├── ChangeOptionsInDatabases.sql ├── SelectFlatFiles.sql ├── GetOldStatistics.sql ├── README.md ├── HallengrenHeaviestMail.sql ├── OpenTransactions.sql ├── TriggerDependencies.sql ├── MailFragmentation.sql ├── MailJobTimeLine.sql └── MailJobTimeLine_DE.sql /FREEPROCCACHE.sql: -------------------------------------------------------------------------------- 1 | DBCC FREEPROCCACHE (plan_handle_id_here) 2 | -------------------------------------------------------------------------------- /Images/Timeline_sql.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Thomas-S-B/SQLServerTools/HEAD/Images/Timeline_sql.jpg -------------------------------------------------------------------------------- /GetErrorLog.sql: -------------------------------------------------------------------------------- 1 | USE master 2 | GO 3 | xp_readerrorlog 1, 1, N'Logging SQL Server', NULL, '01/01/2016', '01/01/2026', N'asc' 4 | GO 5 | -------------------------------------------------------------------------------- /GetConnections.sql: -------------------------------------------------------------------------------- 1 | SELECT COUNT(dbid) AS NumberOfConnections 2 | ,loginame AS LoginName 3 | FROM sys.sysprocesses 4 | WHERE dbid > 0 5 | GROUP BY loginame 6 | ORDER BY NumberOfConnections DESC, LoginName 7 | -------------------------------------------------------------------------------- /FindTriggers.sql: -------------------------------------------------------------------------------- 1 | SELECT OBJ.name 2 | ,COM.text 3 | ,* 4 | FROM sys.objects AS OBJ 5 | INNER JOIN sys.syscomments AS COM ON OBJ.object_id = COM.id 6 | WHERE OBJ.type = 'TR' 7 | --AND COM.text LIKE '%exec ABCDEF%' 8 | 9 | -------------------------------------------------------------------------------- /AnalyzeTraceFileFromSQLProfiler.sql: -------------------------------------------------------------------------------- 1 | -- Query and analyze a tracefile from SQL Profiler 2 | SELECT * 3 | FROM::fn_trace_gettable('Path_to_your_tracefile_from_sql_profiler.trc', DEFAULT) 4 | ORDER BY Duration -- Or you can ORDER BY starttime etc. 5 | 6 | -------------------------------------------------------------------------------- /GetSynonyms.sql: -------------------------------------------------------------------------------- 1 | DECLARE @command VARCHAR(1000) 2 | SELECT @command 3 | = 'USE [?] SELECT ''[?]'', db_id(parsename(base_object_name, 3)) AS dbid 4 | , object_id(base_object_name) AS objid 5 | , base_object_name 6 | from sys.synonyms;' 7 | EXEC sys.sp_MSforeachdb @command 8 | -------------------------------------------------------------------------------- /GetExecutionPlans.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | plan_handle 3 | ,creation_time 4 | ,last_execution_time 5 | ,execution_count 6 | ,QT.text 7 | --QS.* 8 | --,QT.* 9 | FROM 10 | sys.dm_exec_query_stats AS QS 11 | CROSS APPLY sys.dm_exec_sql_text (QS.[sql_handle]) AS QT 12 | WHERE QT.text LIKE 'declare @p5 dbo.IDLIST%' 13 | ORDER BY QS.last_execution_time DESC 14 | -------------------------------------------------------------------------------- /DeleteExecutionPlan.sql: -------------------------------------------------------------------------------- 1 | --Find planhandle 2 | SELECT qs.plan_handle 3 | ,qs.creation_time 4 | ,qs.last_execution_time 5 | ,qs.execution_count 6 | ,qt.text 7 | FROM sys.dm_exec_query_stats qs 8 | CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS qt 9 | WHERE qt.text LIKE '%YOUR_TOKEN%' 10 | 11 | --And then delete the executionplan with the found plan_handle 12 | DBCC FREEPROCCACHE (FOUND_PLAN_HANDLE_FROM_PREVIOUS_SELECT) 13 | -------------------------------------------------------------------------------- /GetExecutionAndInvokecount.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | OBJECT_NAME(st.objectid,st.dbid) AS ObjectName, 3 | cp.usecounts AS ExecutionCount, 4 | st.TEXT AS QueryText, 5 | qp.query_plan AS QueryPlan, 6 | * 7 | FROM 8 | sys.dm_exec_cached_plans AS cp 9 | CROSS APPLY sys.dm_exec_query_plan(cp.plan_handle) AS qp 10 | CROSS APPLY sys.dm_exec_sql_text(cp.plan_handle) AS st 11 | WHERE 12 | cp.objtype = 'Proc' 13 | AND OBJECT_NAME(st.objectid,st.dbid) LIKE '%NAME_OF_MY_PROCEDUREg%' 14 | -------------------------------------------------------------------------------- /Top10WorstProcedures.sql: -------------------------------------------------------------------------------- 1 | SELECT TOP(10) 2 | ps.object_id 3 | ,db.name AS db_name 4 | ,OBJECT_NAME(ps.object_id, ps.database_id) AS proc_name 5 | ,ps.cached_time 6 | ,ps.last_execution_time 7 | ,ps.total_elapsed_time 8 | ,ps.total_elapsed_time / ps.execution_count AS avg_elapsed_time 9 | ,ps.last_elapsed_time 10 | ,ps.execution_count 11 | ,ps.total_worker_time 12 | FROM sys.dm_exec_procedure_stats AS ps 13 | INNER JOIN sys.databases AS db ON db.database_id = ps.database_id 14 | ORDER BY avg_elapsed_time DESC; 15 | -------------------------------------------------------------------------------- /CleanupHistories.sql: -------------------------------------------------------------------------------- 1 | -- Cleansup histories to a size of the last 60 days 2 | -- Perhaps necessary if browsing of the history runs into an "Out of memory" 3 | 4 | -- Cleanup backuphistory 5 | --DECLARE @dt DATETIME 6 | --SET @dt = GETDATE() - 60 7 | --EXEC msdb.dbo.sp_delete_backuphistory @dt 8 | --GO 9 | 10 | -- Cleanup jobhistory 11 | --DECLARE @dt DATETIME 12 | --SET @dt = GETDATE() - 60 13 | --EXEC msdb.dbo.sp_purge_jobhistory @oldest_date=@dt 14 | --GO 15 | 16 | -- Cleanup maintenance log 17 | DECLARE @dt DATETIME 18 | SET @dt = GETDATE() - 60 19 | EXEC msdb..sp_maintplan_delete_log null,null,@dt 20 | GO 21 | -------------------------------------------------------------------------------- /GetProcedureMetrics.sql: -------------------------------------------------------------------------------- 1 | SELECT d2.name 2 | ,d.object_id 3 | ,d.database_id 4 | ,OBJECT_NAME(d.object_id, d.database_id) 'procname' 5 | ,d.cached_time 6 | ,d.last_execution_time 7 | ,d.total_elapsed_time 8 | ,d.total_elapsed_time / d.execution_count AS avg_elapsed_time 9 | ,d.last_elapsed_time 10 | ,d.execution_count 11 | FROM sys.dm_exec_procedure_stats AS d --WHERE OBJECT_NAME(d.object_id, d.database_id) LIKE '%MY PROCEDURENAME%' 12 | INNER JOIN sys.databases AS d2 ON d2.database_id = d.database_id 13 | ORDER BY d2.name 14 | ,OBJECT_NAME(d.object_id, d.database_id) 15 | ,d.last_execution_time 16 | 17 | --ORDER BY [total_worker_time] DESC; 18 | -------------------------------------------------------------------------------- /GetStatisticSamples.sql: -------------------------------------------------------------------------------- 1 | SELECT SS.stats_id, 2 | OBJECT_NAME(SS.object_id) AS 'Table', 3 | AC.name AS 'Spalte', 4 | SS.name, 5 | SS.filter_definition, 6 | SHR.last_updated, 7 | SHR.rows, 8 | SHR.rows_sampled, 9 | SHR.steps, 10 | SHR.unfiltered_rows, 11 | SHR.modification_counter, 12 | (SHR.rows_sampled * 100) / SHR.rows AS Stichprobe_Prozent 13 | FROM sys.stats AS SS 14 | INNER JOIN sys.stats_columns AS SC ON SS.stats_id = SC.stats_id AND SS.object_id = SC.object_id 15 | INNER JOIN sys.all_columns AS AC ON AC.column_id = SC.column_id AND AC.object_id = SC.object_id 16 | CROSS APPLY sys.dm_db_stats_properties(SS.object_id, SS.stats_id) AS SHR 17 | WHERE (SHR.rows_sampled * 100) / SHR.rows < 100 18 | -------------------------------------------------------------------------------- /GetIndexFragmentation.sql: -------------------------------------------------------------------------------- 1 | SELECT dbschemas.name AS 'Schema' 2 | ,dbtables.name AS 'Table' 3 | ,dbindexes.name AS 'Index' 4 | ,indexstats.alloc_unit_type_desc 5 | ,indexstats.avg_fragmentation_in_percent 6 | ,indexstats.page_count 7 | FROM sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL, NULL, NULL) AS indexstats 8 | INNER JOIN sys.tables dbtables ON dbtables.object_id = indexstats.object_id 9 | INNER JOIN sys.schemas dbschemas ON dbtables.schema_id = dbschemas.schema_id 10 | INNER JOIN sys.indexes AS dbindexes ON dbindexes.object_id = indexstats.object_id 11 | AND indexstats.index_id = dbindexes.index_id 12 | WHERE indexstats.database_id = DB_ID() 13 | AND dbschemas.name = 'mySchema' 14 | AND dbtables.name = 'myTable' 15 | ORDER BY indexstats.avg_fragmentation_in_percent DESC 16 | -------------------------------------------------------------------------------- /ShowFragmentation.sql: -------------------------------------------------------------------------------- 1 | SELECT dbschemas.name AS 'Schema' 2 | ,dbtables.name AS 'Tabelle' 3 | ,dbindexes.name AS 'Index' 4 | ,indexstats.avg_fragmentation_in_percent 5 | ,indexstats.avg_fragment_size_in_pages 6 | ,indexstats.fragment_count 7 | ,indexstats.page_count 8 | ,dbindexes.fill_factor 9 | ,dbtables.type_desc 10 | -- ,* 11 | FROM sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL, NULL, NULL) AS indexstats 12 | INNER JOIN sys.tables dbtables ON dbtables.object_id = indexstats.object_id 13 | INNER JOIN sys.schemas dbschemas ON dbtables.schema_id = dbschemas.schema_id 14 | INNER JOIN sys.indexes AS dbindexes ON dbindexes.object_id = indexstats.object_id 15 | AND indexstats.index_id = dbindexes.index_id 16 | WHERE indexstats.database_id = DB_ID() 17 | AND indexstats.page_count > 100 AND indexstats.avg_fragmentation_in_percent >10 18 | ORDER BY fill_factor, indexstats.avg_fragmentation_in_percent 19 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2017 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /ChangeOptionsInDatabases.sql: -------------------------------------------------------------------------------- 1 | --Example: Sets AUTO_CLOSE to OFF on all databases with AUTO_CLOSE = ON 2 | DECLARE @cursor_DBs CURSOR 3 | DECLARE @MyDBs VARCHAR(500) 4 | DECLARE @error_msg VARCHAR(500) 5 | DECLARE @MyErrors TABLE 6 | (myErrorMessage VARCHAR(1000) 7 | ) 8 | DECLARE @SQL VARCHAR(8000) 9 | 10 | 11 | --Create cursor over all relevant databases 12 | SET 13 | @cursor_DBs = CURSOR FOR 14 | SELECT d.name 15 | FROM sys.databases AS d 16 | WHERE d.is_auto_close_on = 1 17 | 18 | 19 | --Execute SQL on all databases 20 | OPEN @cursor_DBs 21 | FETCH NEXT 22 | FROM @cursor_DBs INTO @MyDBs 23 | WHILE @@FETCH_STATUS = 0 24 | BEGIN 25 | BEGIN TRY 26 | SET @SQL = '' 27 | SELECT @SQL = @SQL + 'ALTER DATABASE ' + @MyDBs 28 | + ' SET AUTO_CLOSE OFF;' 29 | EXEC(@SQL) 30 | END TRY 31 | BEGIN CATCH 32 | --There was an error and log it 33 | INSERT INTO @MyErrors 34 | VALUES (@MyDBs + ' -- ' + ERROR_MESSAGE()) 35 | END CATCH 36 | 37 | FETCH NEXT 38 | FROM @cursor_DBs INTO @MyDBs 39 | END 40 | 41 | 42 | SELECT * 43 | FROM @MyErrors AS me 44 | ORDER BY me.myErrorMessage 45 | 46 | --Cleanup 47 | CLOSE @cursor_DBs 48 | DEALLOCATE @cursor_DBs 49 | -------------------------------------------------------------------------------- /SelectFlatFiles.sql: -------------------------------------------------------------------------------- 1 | --############################################################################################################# 2 | -- 3 | --Configuration 4 | -- 5 | --############################################################################################################# 6 | DECLARE @Filepath VARCHAR(1000) = N'\\domain\blah\blah\Mydata.txt' 7 | DECLARE @Fieldseparator CHAR(1) = ','; 8 | DECLARE @Rowseparator CHAR(1) = CHAR(10); 9 | 10 | 11 | 12 | 13 | --Cleanup from previous runs 14 | IF OBJECT_ID('tempdb..#MyTextImport') IS NOT NULL 15 | DROP TABLE #MyTextImport; 16 | 17 | --Create table for output 18 | DECLARE @MyRows TABLE 19 | (MyCol1 VARCHAR(8000) 20 | ,MyCol2 VARCHAR(8000) 21 | ,MyCol3 VARCHAR(8000) 22 | ,MyCol4 VARCHAR(8000) 23 | ); 24 | 25 | --Build SQL 26 | DECLARE @Generated_SQL VARCHAR(8000) = ' 27 | CREATE TABLE #MyTextImport ( 28 | MyCol1 VARCHAR(8000), 29 | MyCol2 VARCHAR(8000), 30 | MyCol3 VARCHAR(8000), 31 | MyCol4 VARCHAR(8000) 32 | ); 33 | 34 | BULK INSERT #MyTextImport 35 | FROM ''' + @Filepath + ''' 36 | WITH (FirstRow = 1, FieldTerminator = ''' + @Fieldseparator 37 | + ''', RowTerminator = ''' + @Rowseparator + '''); 38 | 39 | SELECT * FROM #MyTextImport'; 40 | 41 | --Insert data in generated table 42 | INSERT INTO @MyRows 43 | EXEC (@Generated_SQL 44 | ); 45 | 46 | --Output data 47 | SELECT * 48 | FROM @MyRows 49 | 50 | 51 | --Cleanup 52 | IF OBJECT_ID('tempdb..#MyTextImport') IS NOT NULL 53 | DROP TABLE #MyTextImport; 54 | -------------------------------------------------------------------------------- /GetOldStatistics.sql: -------------------------------------------------------------------------------- 1 | --############################################################################################## 2 | --# 3 | --# This SQL delivers all statistics older than x days and with at least x rows, ordered by age and rowcount descending. 4 | --# Please look at the configuration. 5 | --# 6 | --############################################################################################## 7 | 8 | DECLARE @MIN_AGE INT 9 | DECLARE @MIN_ROWCOUNT INT 10 | 11 | 12 | --############################################################################################## 13 | -- 14 | -- Configuration 15 | -- 16 | SET @MIN_AGE = 0 --Statistic must be older than x days 17 | SET @MIN_ROWCOUNT = 10 --The table must be have at least x rows 18 | --############################################################################################## 19 | 20 | 21 | SELECT SCH.name AS SchemeName 22 | ,OBJ.name AS TableName 23 | ,STA.name AS StatisticName 24 | ,COALESCE(CONVERT(VARCHAR(25), STATS_DATE(STA.object_id, STA.stats_id), 120), 'Noch nie') AS LastStatisticUpdate 25 | ,TABLEROWCOUNT.TableRowCount 26 | ,DATEDIFF(d, ISNULL(STATS_DATE(STA.object_id, STA.stats_id), { D N'1900-01-01' }), GETDATE()) AS LastStatisticUpdateXDays 27 | 28 | FROM sys.stats AS STA 29 | INNER JOIN sys.objects AS OBJ ON STA.object_id = OBJ.object_id 30 | INNER JOIN sys.schemas AS SCH ON OBJ.schema_id = SCH.schema_id 31 | INNER JOIN sys.tables AS T ON T.name = OBJ.name 32 | INNER JOIN sys.partitions AS P ON P.object_id = T.object_id 33 | AND P.index_id IN (0, 1) 34 | 35 | --Rowcount 36 | INNER JOIN(SELECT SCHEMA_NAME(T.schema_id) AS SchemeName 37 | ,T.name AS TableName 38 | ,SUM(P.rows) AS TableRowCount 39 | FROM sys.tables AS T 40 | JOIN sys.partitions AS P ON T.object_id = P.object_id 41 | AND P.index_id IN (0, 1) 42 | GROUP BY SCHEMA_NAME(T.schema_id) 43 | ,T.name 44 | HAVING SUM(P.rows) > @MIN_ROWCOUNT) AS TABLEROWCOUNT ON TABLEROWCOUNT.TableName = OBJ.name 45 | 46 | WHERE OBJ.type IN ('U', 'V') -- Only user tables and views 47 | AND DATEDIFF(d, ISNULL(STATS_DATE(STA.object_id, STA.stats_id), { D N'1900-01-01' }), GETDATE()) > @MIN_AGE 48 | AND STA.auto_created = 0 49 | 50 | ORDER BY LastStatisticUpdateXDays DESC 51 | ,TABLEROWCOUNT.TableRowCount DESC 52 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQLServerTools 2 | This repo is the home of various SQL-Server-Tools for MS SQL-Server 3 | 4 | - [MailJobTimeLine_DE.sql](../master/MailJobTimeLine_DE.sql) - This SQL (german, theres also a not actual english version [MailJobTimeLine.sql](../master/MailJobTimeLine.sql)) sends an email with all jobs displayed in a graphical timeline: 5 | [Exampletimeline](https://thomas-s-b.github.io/Timline_Example.html) 6 | ![TimelinePicture](https://github.com/Thomas-S-B/SQLServerTools/blob/master/Images/Timeline_sql.jpg) 7 | 8 | - [GetExecutionPlans.sql](../master/GetExecutionPlans.sql) - Find executionplans 9 | - [GetProcedureMetrics.sql](../master/GetProcedureMetrics.sql) - Get proceduremetrics 10 | - [GetErrorLog.sql](../master/GetErrorLog.sql) - Get/Read errorlog 11 | - [GetIndexFragmentation.sql](../master/GetIndexFragmentation.sql) - Get index fragmentaion 12 | - [GetExecutionAndInvokecount.sql](../master/GetExecutionAndInvokecount.sql) - Get executionplans and count of invoke 13 | - [FREEPROCCACHE.sql](../master/FREEPROCCACHE.sql) - Delete executionplan of specific object, see also [GetExecutionAndInvokecount.sql](../master/GetExecutionAndInvokecount.sql) to get the planhandle 14 | - [GetConnections.sql](../master/GetConnections.sql) - Get current connections 15 | - [FindTriggers.sql](../master/FindTriggers.sql) - Find triggers 16 | - [Top10WorstProcedures.sql](../master/Top10WorstProcedures.sql) - The TOP 10 of the worst procedures 17 | - [SelectFlatFiles.sql](../master/SelectFlatFiles.sql) - Run selects against flatfiles from a filesystem 18 | - [ChangeOptionsInDatabases.sql](../master/ChangeOptionsInDatabases.sql) - Executes an SQL on all or selected Databases 19 | - [CleanupHistories.sql](../master/CleanupHistories.sql) - Cleans up histories 20 | - [OpenTransactions.sql](../master/OpenTransactions.sql) - Shows all current transactions 21 | - [ShowFragmentation.sql](../master/ShowFragmentation.sql) - Shows fragmentation, customize where-clause 22 | - [GetSynonyms.sql](../master/GetSynonyms.sql) - Get all synonyms of all databases 23 | - [DeleteExecutionPlan.sql](../master/DeleteExecutionPlan.sql) - Delete specific executionplans 24 | - [GetStatisticSamples.sql](../master/GetStatisticSamples.sql) - Get all statistics with a sample size < 100% 25 | - [HallengrenHeaviestMail.sql](../master/HallengrenHeaviestMail.sql) - Sends an mail with the heaviest statisticsupdates of an hallengren maintenance 26 | - [MailFragmentation.sql](../master/MailFragmentation.sql) - Sends an mail with all indexes > 100 pages and >= 5% fragmentation 27 | - [GetOldStatistics.sql](../master/GetOldStatistics.sql) - Get old statistics 28 | - [TriggerDependencies.sql](../master/TriggerDependencies.sql) - Find dependencies to other tables in triggers 29 | - [AnalyzeTraceFileFromSQLProfiler.sql](../master/AnalyzeTraceFileFromSQLProfiler.sql) - Query and analyze a tracefile from SQL Profiler 30 | -------------------------------------------------------------------------------- /HallengrenHeaviestMail.sql: -------------------------------------------------------------------------------- 1 | --################################################################################################### 2 | -- 3 | -- This sends an email with the heaviest halengren updates, which takes 20 or more seconds 4 | -- See "config here" comments 5 | -- 6 | --################################################################################################### 7 | 8 | DECLARE @bodyMsg nvarchar(max) 9 | DECLARE @subject nvarchar(max) 10 | DECLARE @tableHTML nvarchar(max) 11 | 12 | SET @subject = 'Halengren Top-Duration' 13 | SET @tableHTML = 14 | N''+ 48 | 49 | N'

Hallengren Top-Durations >= 20 seconds:

' + 50 | N'' + 51 | N' 52 | 53 | 54 | 55 | 56 | 57 | 58 | 59 | 60 | 61 | ' + 62 | 63 | CAST ( ( 64 | SELECT td = CAST(SchemaName AS VARCHAR(100)),'', 65 | td = ObjectName,'', 66 | td = COALESCE(IndexName, CONVERT(VARCHAR(300),IndexName,120), '') ,'', 67 | td = COALESCE(StatisticsName, CONVERT(VARCHAR(300),StatisticsName,120), '') ,'', 68 | td = COALESCE(starttime, CONVERT(VARCHAR(30),starttime,120), '') ,'', 69 | td = COALESCE(EndTime, CONVERT(VARCHAR(30),EndTime,120), '') ,'', 70 | td = CONVERT(VARCHAR(30),DATEDIFF(ss,starttime, endtime),120) ,'', 71 | td = COALESCE(command, CONVERT(VARCHAR(30),command,120), '') ,'' 72 | FROM [master].[dbo].[CommandLog] 73 | --WHERE DATEDIFF(Mi,starttime, endtime) >= 1 --Config here 74 | WHERE DATEDIFF(ss,starttime, endtime) >= 20 --Config here 75 | AND StartTime > DATEADD(dd, DATEDIFF(dd, 0, getdate()), 0) --Only from the actual day (without time) 76 | --AND StatisticsName IS NOT NULL 77 | ORDER BY DATEDIFF(ss,starttime, endtime) DESC 78 | FOR XML PATH('tr'), TYPE 79 | ) AS NVARCHAR(MAX) ) + 80 | N'
SchemaObjectIndexStatisticStartEndDuration (s)Command
' 81 | 82 | --Config here 83 | EXEC msdb.dbo.sp_send_dbmail @recipients='joe.doq@compuserve.com', 84 | @subject = @subject, 85 | @body = @tableHTML, 86 | @body_format = 'HTML' ; 87 | -------------------------------------------------------------------------------- /OpenTransactions.sql: -------------------------------------------------------------------------------- 1 | SELECT TRANS.session_id AS [SESSION ID], 2 | ES.host_name AS [HOST NAME], 3 | ES.login_name AS [Login NAME], 4 | TRANS.transaction_id AS [TRANSACTION ID], 5 | TAS.name AS [TRANSACTION NAME], 6 | TAS.transaction_begin_time AS [TRANSACTION BEGIN TIME], 7 | TDS.database_id AS [DATABASE ID], 8 | DBS.name AS [DATABASE NAME], 9 | ES.program_name, 10 | 11 | --https://docs.microsoft.com/de-de/sql/relational-databases/system-dynamic-management-views/sys-dm-tran-active-transactions-transact-sql 12 | CASE 13 | WHEN TAS.transaction_state = 0 THEN 14 | 'Die Transaktion wurde noch nicht vollständig initialisiert.' 15 | WHEN TAS.transaction_state = 1 THEN 16 | 'Die Transaktion wurde initialisiert, aber noch nicht gestartet.' 17 | WHEN TAS.transaction_state = 2 THEN 18 | 'Die Transaktion ist aktiv.' 19 | WHEN TAS.transaction_state = 3 THEN 20 | 'Die Transaktion wurde beendet. Diese Einstellung wird für schreibgeschützte Transaktionen verwendet.' 21 | WHEN TAS.transaction_state = 4 THEN 22 | 'Der Commitprozess wurde für die verteilte Transaktion initiiert. Diese Einstellung wird nur für verteilte Transaktionen verwendet. Die verteilte Transaktion ist noch aktiv, doch ist keine weitere Verarbeitung möglich.' 23 | WHEN TAS.transaction_state = 5 THEN 24 | 'Die Transaktion hat den Status "Vorbereitet" und wartet auf Auflösung.' 25 | WHEN TAS.transaction_state = 6 THEN 26 | 'Die Transaktion ein Commit ausgeführt wurde.' 27 | WHEN TAS.transaction_state = 7 THEN 28 | 'Es wird ein Rollback für die Transaktion durchgeführt.' 29 | WHEN TAS.transaction_state = 8 THEN 30 | 'Die Transaktion wurde ein Rollback.' 31 | ELSE 32 | 'UNBEKANNT' 33 | END AS TRANSAKTIONS_STATUS, 34 | 35 | CASE 36 | WHEN TAS.transaction_type = 1 THEN 37 | 'Lese-/Schreibtransaktion' 38 | WHEN TAS.transaction_type = 2 THEN 39 | 'Schreibgeschützte Transaktion' 40 | WHEN TAS.transaction_type = 3 THEN 41 | 'Systemtransaktion' 42 | WHEN TAS.transaction_type = 4 THEN 43 | 'Verteilte Transaktion' 44 | ELSE 45 | 'UNBEKANNT' 46 | END AS TRANSAKTIONS_TYP, 47 | 48 | DATEDIFF(millisecond, TAS.transaction_begin_time, GETDATE()) AS DAUER_IN_MS 49 | ,ES.session_id 50 | --,* 51 | FROM sys.dm_tran_active_transactions AS TAS 52 | INNER JOIN sys.dm_tran_session_transactions AS TRANS 53 | ON (TRANS.transaction_id = TAS.transaction_id) 54 | LEFT JOIN sys.dm_tran_database_transactions AS TDS 55 | ON (TAS.transaction_id = TDS.transaction_id) 56 | LEFT JOIN sys.databases AS DBS 57 | ON TDS.database_id = DBS.database_id 58 | LEFT JOIN sys.dm_exec_sessions AS ES 59 | ON TRANS.session_id = ES.session_id 60 | WHERE ES.session_id IS NOT NULL 61 | 62 | --ORDER BY [DATABASE NAME], ES.program_name 63 | ORDER BY DAUER_IN_MS DESC 64 | -------------------------------------------------------------------------------- /TriggerDependencies.sql: -------------------------------------------------------------------------------- 1 | SET NOCOUNT ON; 2 | 3 | DECLARE @trigger_id BIGINT 4 | ,@trigger_name NVARCHAR(100) 5 | ,@trigger_table_view_name NVARCHAR(80) 6 | ,@trigger_table_schema NVARCHAR(50) 7 | ,@trigger_text VARCHAR(8000) 8 | ,@trigger_schema_table_view NVARCHAR(200) 9 | ,@table_view_name NVARCHAR(80) 10 | ,@table_schema NVARCHAR(50) 11 | ,@schema_table_view NVARCHAR(200) 12 | 13 | 14 | PRINT '-------------------------------------------------------------------------------------------------'; 15 | PRINT '-------------------------------- Tables/views and their triggers --------------------------------'; 16 | PRINT '------------------ Lists all tables which have triggers using other tables ----------------------'; 17 | PRINT '-------------------------------------------------------------------------------------------------'; 18 | PRINT ' '; 19 | 20 | DECLARE trigger_cursor CURSOR FORWARD_ONLY FAST_FORWARD LOCAL FOR 21 | SELECT ROW_NUMBER() OVER (ORDER BY SYS_OBJ.name) AS trigger_id 22 | ,SYS_OBJ.name AS trigger_name 23 | ,OBJECT_NAME(SYS_OBJ.parent_obj) AS table_name 24 | ,SYS_SCHEMAS.name AS table_schema 25 | ,SYS_COMMENTS.text 26 | FROM sys.sysobjects AS SYS_OBJ 27 | INNER JOIN sys.tables AS SYS_TABLES ON SYS_TABLES.object_id = SYS_OBJ.parent_obj 28 | INNER JOIN sys.schemas AS SYS_SCHEMAS ON SYS_SCHEMAS.schema_id = SYS_TABLES.schema_id 29 | INNER JOIN sys.syscomments AS SYS_COMMENTS ON SYS_COMMENTS.id = SYS_OBJ.id 30 | WHERE SYS_OBJ.type = 'TR' 31 | ORDER BY trigger_name 32 | 33 | 34 | OPEN trigger_cursor 35 | 36 | FETCH NEXT FROM trigger_cursor 37 | 38 | INTO @trigger_id 39 | ,@trigger_name 40 | ,@trigger_table_view_name 41 | ,@trigger_table_schema 42 | ,@trigger_text 43 | 44 | WHILE @@FETCH_STATUS = 0 45 | BEGIN 46 | 47 | -- Check tables and views, used in triggersource 48 | DECLARE tables_views_cursor CURSOR FORWARD_ONLY FAST_FORWARD LOCAL FOR 49 | SELECT TABLE_NAME 50 | ,TABLE_SCHEMA 51 | FROM INFORMATION_SCHEMA.TABLES 52 | WHERE TABLE_TYPE = 'BASE TABLE' 53 | OR TABLE_TYPE = 'VIEW' 54 | ORDER BY TABLE_NAME 55 | 56 | OPEN tables_views_cursor 57 | FETCH NEXT FROM tables_views_cursor 58 | INTO @table_view_name 59 | ,@table_schema 60 | 61 | IF @@FETCH_STATUS <> 0 PRINT ' ### NO DEPENDENCIES ###' 62 | 63 | WHILE @@FETCH_STATUS = 0 64 | BEGIN 65 | SELECT @trigger_schema_table_view = @trigger_table_schema + N'.' + @trigger_table_view_name 66 | SELECT @schema_table_view = @table_schema + N'.' + @table_view_name 67 | 68 | 69 | IF CHARINDEX(@schema_table_view, @trigger_schema_table_view) < 1 70 | BEGIN 71 | IF CHARINDEX(@schema_table_view, @trigger_text) > 0 72 | BEGIN 73 | PRINT @trigger_schema_table_view + ' ----- the trigger ' + @trigger_name + '(id = ' + CAST(@trigger_id AS VARCHAR(MAX)) + ') uses also table -----> ' + @schema_table_view 74 | PRINT ' ' 75 | END 76 | END 77 | 78 | FETCH NEXT FROM tables_views_cursor 79 | INTO @table_view_name 80 | ,@table_schema 81 | END 82 | 83 | CLOSE tables_views_cursor 84 | DEALLOCATE tables_views_cursor 85 | 86 | FETCH NEXT FROM trigger_cursor 87 | 88 | INTO @trigger_id 89 | ,@trigger_name 90 | ,@trigger_table_view_name 91 | ,@trigger_table_schema 92 | ,@trigger_text 93 | END 94 | 95 | 96 | CLOSE trigger_cursor; 97 | DEALLOCATE trigger_cursor; 98 | -------------------------------------------------------------------------------- /MailFragmentation.sql: -------------------------------------------------------------------------------- 1 | --################################################################################################### 2 | -- Sending an mail with all indexes > THRESHOLD_PAGES pages and >= THRESHOLD_FRAGMENTATION % fragmentation 3 | -- 4 | --################################################################################################### 5 | 6 | DECLARE @bodyMsg nvarchar(max) 7 | DECLARE @subject nvarchar(max) 8 | DECLARE @tableHTML nvarchar(max) 9 | DECLARE @THRESHOLD_PAGES INT 10 | DECLARE @THRESHOLD_FRAGMENTATION INT 11 | DECLARE @EmailTo VARCHAR(500) 12 | 13 | --################################################################################################### 14 | -- 15 | -- Configuration Start 16 | -- 17 | --################################################################################################### 18 | SET @THRESHOLD_PAGES = 100 19 | 20 | SET @THRESHOLD_FRAGMENTATION = 5 21 | 22 | SET @EmailTo = 'John.Doe@xyz.com;Jennifer.Doe@xyz.com' 23 | --################################################################################################### 24 | -- 25 | -- Configuration End 26 | -- 27 | --################################################################################################### 28 | 29 | 30 | SET @subject = db_name() + ' indexes > ' + CAST(@THRESHOLD_PAGES AS varchar(10)) + ' pages and >= ' + CAST(@THRESHOLD_FRAGMENTATION AS varchar(3)) + '% fragmentation' 31 | 32 | SET @tableHTML = 33 | N''+ 60 | N'

' + db_name() + ' indexes > ' + CAST(@THRESHOLD_PAGES AS varchar(10)) + ' pages and >= ' + CAST(@THRESHOLD_FRAGMENTATION AS varchar(3)) + '% fragmentation' + 61 | N' (time ' + CONVERT(char(19), GetDate(),121) + '):

' + 62 | N'' + 63 | N' 64 | 65 | 66 | 67 | 68 | 69 | ' + 70 | CAST ( ( 71 | 72 | SELECT td = CAST(dbschemas.name + '.' + dbtables.name + ' ' + ISNULL(dbindexes.name, 'HEAP') AS VARCHAR(100)),'', 73 | td = CAST(indexstats.avg_fragmentation_in_percent AS VARCHAR(100)),'', 74 | td = CAST(indexstats.avg_fragment_size_in_pages AS VARCHAR(100)),'', 75 | td = indexstats.page_count,'', 76 | td = dbindexes.fill_factor,'' 77 | 78 | FROM sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL, NULL, NULL) AS indexstats 79 | INNER JOIN sys.tables dbtables ON dbtables.object_id = indexstats.object_id 80 | INNER JOIN sys.schemas dbschemas ON dbtables.schema_id = dbschemas.schema_id 81 | INNER JOIN sys.indexes AS dbindexes ON dbindexes.object_id = indexstats.object_id 82 | AND indexstats.index_id = dbindexes.index_id 83 | WHERE indexstats.database_id = DB_ID() 84 | AND indexstats.page_count > @THRESHOLD_PAGES AND indexstats.avg_fragmentation_in_percent >= @THRESHOLD_FRAGMENTATION 85 | ORDER BY indexstats.avg_fragmentation_in_percent DESC 86 | 87 | FOR XML PATH('tr'), TYPE 88 | ) AS NVARCHAR(MAX) ) + 89 | N'
Indexavg_fragmentation_in_percentavg_fragment_size_in_pagespage_countfill_factor
' 90 | 91 | 92 | EXEC msdb.dbo.sp_send_dbmail @recipients = @EmailTo, 93 | @subject = @subject, 94 | @body = @tableHTML, 95 | @body_format = 'HTML' ; 96 | -------------------------------------------------------------------------------- /MailJobTimeLine.sql: -------------------------------------------------------------------------------- 1 | 2 | --################################################################################################### 3 | -- This SQL sends an email with all Jobs as an graphical timeline 4 | -- 5 | -- You can configure this in the section "Configuration" 6 | -- 7 | -- History: 8 | -- 2017-07-28 Initial version 9 | --################################################################################################### 10 | 11 | 12 | SET NOCOUNT ON 13 | 14 | 15 | DECLARE @StartDate DATETIME 16 | DECLARE @EndDate DATETIME 17 | DECLARE @MinimalJobDurationInSeconds INT 18 | DECLARE @EmailTo VARCHAR(500) 19 | DECLARE @DaysPast INT 20 | DECLARE @HoursPast INT 21 | DECLARE @Servername VARCHAR(50) 22 | 23 | 24 | --################################################################################################### 25 | -- 26 | -- Configuration Start 27 | -- 28 | --################################################################################################### 29 | --Wer soll alles eine Mail bekomen? 30 | SET @EmailTo = 'John.Doe@xyz.com;Jennifer.Doe@xyz.com' 31 | 32 | --How many days in the past should be displayed? 33 | SET @DaysPast = 1 34 | 35 | --How many hours in the past should be displayed? 36 | SET @HoursPast = 0 37 | 38 | --How long must a job taken to displayed? 39 | SET @MinimalJobDurationInSeconds = 0 40 | --################################################################################################### 41 | -- 42 | -- Configuration End 43 | -- 44 | --################################################################################################### 45 | 46 | 47 | 48 | --################################################################################################### 49 | -- 50 | -- Calculate timespan 51 | -- 52 | --################################################################################################### 53 | SET @StartDate = DateAdd(hh, -(@HoursPast), GETDATE() - @DaysPast) 54 | SET @EndDate = GETDATE() 55 | 56 | 57 | --################################################################################################### 58 | -- 59 | -- Textliterals 60 | -- 61 | --################################################################################################### 62 | DECLARE @TEXT_SUCCESS VARCHAR(20) 63 | SET @TEXT_SUCCESS = 'Successful' 64 | 65 | 66 | 67 | --################################################################################################### 68 | -- 69 | -- Colors 70 | -- 71 | --################################################################################################### 72 | DECLARE @COLOR_ERROR VARCHAR(10) 73 | SET @COLOR_ERROR = '#FF4136' 74 | 75 | DECLARE @COLOR_SUCCESS VARCHAR(10) 76 | SET @COLOR_SUCCESS = '#2ECC40' 77 | 78 | DECLARE @COLOR_RETRY VARCHAR(10) 79 | SET @COLOR_RETRY = '#FFDC00' 80 | 81 | DECLARE @COLOR_ABORTED VARCHAR(10) 82 | SET @COLOR_ABORTED = '#AAAAAA' 83 | 84 | DECLARE @COLOR_UNDEFINED VARCHAR(10) 85 | SET @COLOR_UNDEFINED = '#111111' 86 | 87 | DECLARE @COLOR_RUNNING VARCHAR(10) 88 | SET @COLOR_RUNNING = '#7FDBFF' 89 | 90 | DECLARE @COLOR_SERVERSTART VARCHAR(10) 91 | SET @COLOR_SERVERSTART = '#FF851B' 92 | 93 | 94 | 95 | --################################################################################################### 96 | -- 97 | -- Cleanup, perhaps there are temptables from other executions 98 | -- 99 | --################################################################################################### 100 | IF OBJECT_ID('tempdb..#JobExecutionTimes') IS NOT NULL 101 | DROP TABLE #JobExecutionTimes; 102 | 103 | IF OBJECT_ID('tempdb..##TimelineGraph') IS NOT NULL 104 | DROP TABLE ##TimelineGraph; 105 | 106 | 107 | 108 | --################################################################################################### 109 | -- 110 | -- Create table which holds the generated HTML 111 | -- 112 | --################################################################################################### 113 | CREATE TABLE ##TimelineGraph 114 | (ID INT IDENTITY(1, 1) 115 | NOT NULL 116 | ,HTML VARCHAR(8000) NULL --8000, so it works with SQL-Server < 2008R2 117 | ) 118 | 119 | 120 | 121 | --################################################################################################### 122 | -- 123 | -- Create table of the jobs 124 | -- 125 | --################################################################################################### 126 | SELECT JOBDATA.* 127 | INTO #JobExecutionTimes 128 | FROM ( 129 | --Jobs, which are currently not running 130 | SELECT JOB.name AS JobName 131 | ,CAT.name AS CatName 132 | ,CONVERT(DATETIME, CONVERT(CHAR(8), HIS.run_date, 112) + ' ' 133 | + STUFF(STUFF(RIGHT('000000' 134 | + CONVERT(VARCHAR(8), HIS.run_time), 6), 135 | 5, 0, ':'), 3, 0, ':'), 120) AS SDT 136 | ,DATEADD(s, 137 | ((HIS.run_duration / 10000) % 100 * 3600) 138 | + ((HIS.run_duration / 100) % 100 * 60) 139 | + HIS.run_duration % 100, 140 | CONVERT(DATETIME, CONVERT(CHAR(8), HIS.run_date, 112) 141 | + ' ' + STUFF(STUFF(RIGHT('000000' 142 | + CONVERT(VARCHAR(8), HIS.run_time), 143 | 6), 5, 0, ':'), 3, 0, ':'), 120)) AS EDT 144 | ,JOB.description 145 | ,HIS.run_status 146 | ,CASE WHEN HIS.run_status = 0 THEN @COLOR_ERROR 147 | WHEN HIS.run_status = 1 THEN @COLOR_SUCCESS 148 | WHEN HIS.run_status = 2 THEN @COLOR_RETRY 149 | WHEN HIS.run_status = 3 THEN @COLOR_ABORTED 150 | ELSE @COLOR_UNDEFINED 151 | END AS JobStatus 152 | ,CASE WHEN HIS.run_status = 0 THEN HIS.message -- 0 = Error (red) 153 | WHEN HIS.run_status = 1 THEN @TEXT_SUCCESS -- 1 = Successful (green) 154 | WHEN HIS.run_status = 2 THEN HIS.message -- 2 = New try (yellow) 155 | WHEN HIS.run_status = 3 THEN HIS.message -- 3 = Aborted (gray) 156 | ELSE HIS.message -- undefined status (black) 157 | END AS JobMessage 158 | 159 | FROM msdb.dbo.sysjobs AS JOB 160 | LEFT JOIN msdb.dbo.sysjobhistory AS HIS ON HIS.job_id = job.job_id 161 | INNER JOIN msdb.dbo.syscategories AS CAT ON CAT.category_id = JOB.category_id 162 | WHERE CONVERT(DATETIME, CONVERT(CHAR(8), HIS.run_date, 112) + ' ' 163 | + STUFF(STUFF(RIGHT('000000' 164 | + CONVERT(VARCHAR(8), HIS.run_time), 6), 165 | 5, 0, ':'), 3, 0, ':'), 120) BETWEEN @StartDate 166 | AND 167 | @EndDate 168 | AND HIS.step_id = 0 -- step_id = 0 is the job, step_id > 0 are the subjobs of this job 169 | AND ((HIS.run_duration / 10000) % 100 * 3600) 170 | + ((HIS.run_duration / 100) % 100 * 60) + HIS.run_duration 171 | % 100 >= @MinimalJobDurationInSeconds 172 | 173 | UNION ALL 174 | 175 | --Jobs currently running 176 | SELECT JOB.name AS JobName 177 | ,CAT.name AS CatName 178 | ,JA.start_execution_date AS SDT 179 | ,GETDATE() AS EDT 180 | ,JOB.description 181 | ,HIS.run_status 182 | ,CASE WHEN HIS.run_status = 0 THEN @COLOR_ERROR 183 | WHEN HIS.run_status = 1 THEN @COLOR_SUCCESS 184 | WHEN HIS.run_status = 2 THEN @COLOR_RETRY 185 | WHEN HIS.run_status = 3 THEN @COLOR_ABORTED 186 | WHEN HIS.run_status IS NULL THEN @COLOR_RUNNING 187 | ELSE @COLOR_UNDEFINED 188 | END AS JobStatus 189 | ,CASE WHEN HIS.run_status = 0 THEN HIS.message -- 0 = Error (red) 190 | WHEN HIS.run_status = 1 THEN @TEXT_SUCCESS -- 1 = Successful (green) 191 | WHEN HIS.run_status = 2 THEN HIS.message -- 2 = New try (yellow) 192 | WHEN HIS.run_status = 3 THEN HIS.message -- 3 = Aborted (gray) 193 | WHEN HIS.run_status IS NULL THEN 'Running currently' 194 | ELSE HIS.message -- undefined status (black) 195 | END AS JobMessage 196 | 197 | FROM msdb.dbo.sysjobactivity AS JA 198 | LEFT JOIN msdb.dbo.sysjobhistory AS HIS ON HIS.instance_id = JA.job_history_id 199 | JOIN msdb.dbo.sysjobs AS JOB ON JOB.job_id = JA.job_id 200 | JOIN msdb.dbo.sysjobsteps AS JS ON JS.job_id = JA.job_id 201 | AND ISNULL(JA.last_executed_step_id, 202 | 0) + 1 = JS.step_id 203 | LEFT JOIN msdb.dbo.syscategories AS CAT ON CAT.category_id = JOB.category_id 204 | WHERE JA.session_id = (SELECT TOP 1 205 | session_id 206 | FROM msdb.dbo.syssessions 207 | ORDER BY agent_start_date DESC 208 | ) 209 | AND JA.start_execution_date IS NOT NULL 210 | AND JA.stop_execution_date IS NULL 211 | ) AS JOBDATA 212 | 213 | ORDER BY JOBDATA.JobName 214 | 215 | IF NOT EXISTS ( SELECT 1 216 | FROM #JobExecutionTimes ) 217 | GOTO NothingToDo 218 | 219 | 220 | 221 | --################################################################################################### 222 | -- 223 | -- Create errormessage 224 | -- 225 | --################################################################################################### 226 | DECLARE @ERROR_COUNT AS INTEGER 227 | DECLARE @ERROR_TEXT AS VARCHAR(50) 228 | SET @ERROR_COUNT = (SELECT COUNT(*) FROM #JobExecutionTimes WHERE run_status=0) 229 | IF @ERROR_COUNT > 0 230 | SET @ERROR_TEXT = 'There are ' + CONVERT(varchar(4), @ERROR_COUNT) +' faulty jobs.' 231 | ELSE 232 | SET @ERROR_TEXT = '' 233 | 234 | 235 | 236 | --################################################################################################### 237 | -- 238 | -- Html Timeline - Head 239 | -- 240 | --################################################################################################### 241 | INSERT INTO ##TimelineGraph 242 | (HTML 243 | ) 244 | SELECT ' 245 | 246 | ' 322 | 323 | 324 | INSERT INTO ##TimelineGraph 325 | (HTML 326 | ) 327 | SELECT ' 328 | ' 329 | 330 | 331 | INSERT INTO ##TimelineGraph 332 | (HTML 333 | ) 334 | SELECT ' 526 | 527 | ' + '' + @@servername 528 | + ' Jobs' + ' from ' + CONVERT(VARCHAR(20), @StartDate, 120) 529 | + ' to ' + CONVERT(VARCHAR(20), @EndDate, 120) + 530 | + CASE WHEN @ERROR_COUNT = 0 THEN '' 531 | ELSE 532 | '. ' + @ERROR_TEXT 533 | END 534 | + CASE WHEN @MinimalJobDurationInSeconds = 0 THEN '' 535 | ELSE ' (Jobs longer than ' 536 | + CAST(@MinimalJobDurationInSeconds AS VARCHAR(10)) 537 | + ' seconds)' 538 | END 539 | + ' 540 |

541 | ' 542 | 543 | 544 | INSERT INTO ##TimelineGraph 545 | (HTML 546 | ) 547 | SELECT ' 548 |

549 | 589 |
590 | ' 591 | 592 | 593 | 594 | --################################################################################################### 595 | -- 596 | -- Html Timeline - End 597 | -- 598 | --################################################################################################### 599 | DECLARE @Timeline_Width AS INTEGER 600 | IF @DaysPast < 1 601 | SET @Timeline_Width = 1800 602 | ELSE 603 | SET @Timeline_Width = @DaysPast * 1800 604 | 605 | 606 | INSERT INTO ##TimelineGraph 607 | (HTML 608 | ) 609 | SELECT ' 610 |
612 | 613 | ' 614 | 615 | 616 | 617 | --################################################################################################### 618 | -- 619 | -- Send timeline as an email 620 | -- 621 | --################################################################################################### 622 | DECLARE @emailBodyText NVARCHAR(MAX); 623 | SET @emailBodyText = 'Timeline of all jobs between ' 624 | + CONVERT(VARCHAR(20), @StartDate, 120) + ' to ' 625 | + CONVERT(VARCHAR(20), @EndDate, 120) + ' open the attachement.' 626 | 627 | DECLARE @emailSubjectText NVARCHAR(MAX); 628 | SET @emailSubjectText = @@servername + ' Jons between ' 629 | + CONVERT(VARCHAR(20), @StartDate, 120) + ' and ' 630 | + CONVERT(VARCHAR(20), @EndDate, 120) 631 | + ' ' + @ERROR_TEXT 632 | 633 | DECLARE @emailHTMLFilenameText NVARCHAR(MAX); 634 | SET @emailHTMLFilenameText = @@servername + ' Jobs between ' 635 | + CONVERT(VARCHAR(20), @StartDate, 120) + ' and ' 636 | + CONVERT(VARCHAR(20), @EndDate, 120) + '.html' 637 | SET @emailHTMLFilenameText = REPLACE(@emailHTMLFilenameText, ':', '_') 638 | 639 | DECLARE @email_Importance NVARCHAR(10); 640 | IF @ERROR_COUNT > 0 641 | SET @email_Importance = 'High' 642 | ELSE 643 | SET @email_Importance = 'Normal' 644 | 645 | EXECUTE msdb.dbo.sp_send_dbmail @recipients = @EmailTo, 646 | @subject = @emailSubjectText, @body = @emailBodyText, 647 | @body_format = 'HTML' -- or TEXT 648 | , @importance = @email_Importance 649 | , @sensitivity = 'Normal' --Normal Personal Private Confidential 650 | , @execute_query_database = 'master', @query_result_header = 0, --@query_result_header = 0 is important, otherwise "HTML----" comes from the query into the html 651 | @query = 'set nocount on; SELECT HTML FROM ##TimelineGraph ORDER BY ID', 652 | @query_result_no_padding = 1 653 | --,@query_no_truncate= 1 654 | , @attach_query_result_as_file = 1, 655 | @query_attachment_filename = @emailHTMLFilenameText 656 | 657 | 658 | GOTO Cleanup 659 | 660 | 661 | --################################################################################################### 662 | -- 663 | -- Nothing to do or errorhandling 664 | -- 665 | --################################################################################################### 666 | 667 | NothingToDo: 668 | PRINT 'Found no jobs (this could be also an error)' 669 | 670 | 671 | 672 | --################################################################################################### 673 | -- 674 | -- Cleanup 675 | -- 676 | --################################################################################################### 677 | Cleanup: 678 | 679 | IF OBJECT_ID('tempdb..#JobExecutionTimes') IS NOT NULL 680 | DROP TABLE #JobExecutionTimes; 681 | 682 | IF OBJECT_ID('tempdb..##TimelineGraph') IS NOT NULL 683 | DROP TABLE ##TimelineGraph; 684 | -------------------------------------------------------------------------------- /MailJobTimeLine_DE.sql: -------------------------------------------------------------------------------- 1 | --################################################################################################### 2 | -- Dieser SQL verschickt per Mail alle Aufträge als grafischen Zeitstrahl 3 | -- 4 | -- Konfiguriert kann im Teil 'Konfiguration' werden 5 | -- 6 | --################################################################################################### 7 | 8 | 9 | 10 | SET NOCOUNT ON 11 | 12 | 13 | DECLARE @DT DATETIME 14 | DECLARE @StartDatum DATETIME 15 | DECLARE @EndeDatum DATETIME 16 | DECLARE @MindestLaufzeitInSekunden INT 17 | DECLARE @EmailEmpfaenger VARCHAR(500) 18 | DECLARE @EmailNurBeiFehlerEmpfaenger VARCHAR(500) 19 | DECLARE @Tage INT 20 | DECLARE @Stunden INT 21 | DECLARE @Servername VARCHAR(50) 22 | 23 | 24 | --################################################################################################### 25 | -- Konfiguration 26 | --################################################################################################### 27 | 28 | --Wer soll eine Mail bekommen? 29 | SET @EmailEmpfaenger = 'Jenny.Doe@abc.com;John.Doe@abc.com' 30 | 31 | --Wer soll nur bei einem fehlerhaften Auftrag eine Mail bekommen? 32 | SET @EmailNurBeiFehlerEmpfaenger = '' 33 | 34 | --Wie viele Tage soll in die Vergangenheit gegangen werden? 35 | SET @Tage = 1 36 | 37 | --Wie viele Stunden soll in die Vergangenheit gegangen werden? 38 | SET @Stunden = 0 39 | 40 | --Wie lange soll ein Auftrag mindestens gedauert haben, damit er angezeigt wird? 41 | SET @MindestLaufzeitInSekunden = 0 42 | 43 | 44 | SET @StartDatum = DateAdd(hh, -(@Stunden), GETDATE() - @Tage) 45 | SET @EndeDatum = GETDATE() 46 | 47 | --################################################################################################### 48 | -- Textliterale 49 | --################################################################################################### 50 | DECLARE @TEXT_ERFOLGREICH VARCHAR(20) 51 | SET @TEXT_ERFOLGREICH = 'Erfolgreich' 52 | 53 | 54 | 55 | --################################################################################################### 56 | -- Farben 57 | --################################################################################################### 58 | DECLARE @FARBE_FEHLER VARCHAR(10) 59 | SET @FARBE_FEHLER = '#FF4136' 60 | 61 | DECLARE @FARBE_ERFOLGREICH VARCHAR(10) 62 | SET @FARBE_ERFOLGREICH = '#2ECC40' 63 | 64 | DECLARE @FARBE_NEUVERSUCH VARCHAR(10) 65 | SET @FARBE_NEUVERSUCH = '#FFDC00' 66 | 67 | DECLARE @FARBE_ABGEBROCHEN VARCHAR(10) 68 | SET @FARBE_ABGEBROCHEN = '#AAAAAA' 69 | 70 | DECLARE @FARBE_UNDEFINIERT VARCHAR(10) 71 | SET @FARBE_UNDEFINIERT = '#111111' 72 | 73 | DECLARE @FARBE_LAEUFT VARCHAR(10) 74 | SET @FARBE_LAEUFT = '#7FDBFF' 75 | 76 | DECLARE @FARBE_NEUSTART VARCHAR(10) 77 | SET @FARBE_NEUSTART = '#FF851B' 78 | 79 | 80 | --################################################################################################### 81 | -- Aufräumen, falls vorher was hängen blieb 82 | --################################################################################################### 83 | IF OBJECT_ID('tempdb..#AuftragsLaufzeiten') IS NOT NULL 84 | DROP TABLE #AuftragsLaufzeiten; 85 | IF OBJECT_ID('tempdb..##ZeitstrahlGraph') IS NOT NULL 86 | DROP TABLE ##ZeitstrahlGraph; 87 | 88 | 89 | --################################################################################################### 90 | -- Tabelle für die HTML anlegen 91 | --################################################################################################### 92 | CREATE TABLE ##ZeitstrahlGraph 93 | (ID INT IDENTITY(1, 1) 94 | NOT NULL 95 | ,HTML VARCHAR(8000) NULL --8000, damit es auch mit Servern < 2008R2 funktioniert 96 | ) 97 | 98 | 99 | --################################################################################################### 100 | -- Tabelle der Aufträge anlegen 101 | --################################################################################################### 102 | SELECT AUFTRAEGE.* 103 | INTO #AuftragsLaufzeiten 104 | FROM ( 105 | --Gelaufene Aufträge, welche abgeschlossen sind 106 | SELECT job.name AS JobName 107 | ,cat.name AS CatName 108 | ,CONVERT(DATETIME, CONVERT(CHAR(8), his.run_date, 112) + ' ' 109 | + STUFF(STUFF(RIGHT('000000' 110 | + CONVERT(VARCHAR(8), his.run_time), 6), 111 | 5, 0, ':'), 3, 0, ':'), 120) AS SDT 112 | ,DATEADD(s, 113 | ((his.run_duration / 10000) % 100 * 3600) 114 | + ((his.run_duration / 100) % 100 * 60) 115 | + his.run_duration % 100, 116 | CONVERT(DATETIME, CONVERT(CHAR(8), his.run_date, 112) 117 | + ' ' + STUFF(STUFF(RIGHT('000000' 118 | + CONVERT(VARCHAR(8), his.run_time), 119 | 6), 5, 0, ':'), 3, 0, ':'), 120)) AS EDT 120 | ,job.description 121 | ,his.run_status 122 | ,CASE WHEN his.run_status = 0 THEN @FARBE_FEHLER 123 | WHEN his.run_status = 1 THEN @FARBE_ERFOLGREICH 124 | WHEN his.run_status = 2 THEN @FARBE_NEUVERSUCH 125 | WHEN his.run_status = 3 THEN @FARBE_ABGEBROCHEN 126 | ELSE @FARBE_UNDEFINIERT 127 | END AS JobStatus 128 | ,CASE WHEN his.run_status = 0 THEN his.message -- 0 = Fehler (rot) 129 | WHEN his.run_status = 1 THEN @TEXT_ERFOLGREICH -- 1 = Erfolgreich (grün) 130 | WHEN his.run_status = 2 THEN his.message -- 2 = Neuversuch (gelb) 131 | WHEN his.run_status = 3 THEN his.message -- 3 = Abgebrochen (grau) 132 | ELSE his.message -- undefinierter Status (schwarz) 133 | END AS JobMeldung 134 | FROM msdb.dbo.sysjobs AS job 135 | LEFT JOIN msdb.dbo.sysjobhistory AS his ON his.job_id = job.job_id 136 | INNER JOIN msdb.dbo.syscategories AS cat ON job.category_id = cat.category_id 137 | WHERE CONVERT(DATETIME, CONVERT(CHAR(8), his.run_date, 112) + ' ' 138 | + STUFF(STUFF(RIGHT('000000' 139 | + CONVERT(VARCHAR(8), his.run_time), 6), 140 | 5, 0, ':'), 3, 0, ':'), 120) BETWEEN @StartDatum 141 | AND 142 | @EndeDatum 143 | AND his.step_id = 0 -- step_id = 0 ist der eigentliche Auftrag, step_id > 0 sind die Einzelschritte davon 144 | AND ((his.run_duration / 10000) % 100 * 3600) 145 | + ((his.run_duration / 100) % 100 * 60) + his.run_duration 146 | % 100 >= @MindestLaufzeitInSekunden 147 | UNION ALL 148 | 149 | --Aktuell laufende Aufträge 150 | SELECT JOB.name AS JobName 151 | ,cat.name AS CatName 152 | ,ja.start_execution_date AS SDT 153 | ,GETDATE() AS EDT 154 | ,JOB.description 155 | ,HIS.run_status 156 | ,CASE WHEN HIS.run_status = 0 THEN @FARBE_FEHLER 157 | WHEN HIS.run_status = 1 THEN @FARBE_ERFOLGREICH 158 | WHEN HIS.run_status = 2 THEN @FARBE_NEUVERSUCH 159 | WHEN HIS.run_status = 3 THEN @FARBE_ABGEBROCHEN 160 | WHEN HIS.run_status IS NULL THEN @FARBE_LAEUFT 161 | ELSE @FARBE_UNDEFINIERT 162 | END AS JobStatus 163 | ,CASE WHEN HIS.run_status = 0 THEN HIS.message -- 0 = Fehler (rot) 164 | WHEN HIS.run_status = 1 THEN @TEXT_ERFOLGREICH -- 1 = Erfolgreich (grün) 165 | WHEN HIS.run_status = 2 THEN HIS.message -- 2 = Neuversuch (gelb) 166 | WHEN HIS.run_status = 3 THEN HIS.message -- 3 = Abgebrochen (grau) 167 | WHEN HIS.run_status IS NULL THEN 'Läuft aktuell' 168 | ELSE HIS.message -- undefinierter Status (schwarz) 169 | END AS JobMeldung 170 | FROM msdb.dbo.sysjobactivity ja 171 | LEFT JOIN msdb.dbo.sysjobhistory AS HIS ON ja.job_history_id = HIS.instance_id 172 | JOIN msdb.dbo.sysjobs AS JOB ON ja.job_id = JOB.job_id 173 | JOIN msdb.dbo.sysjobsteps js ON ja.job_id = js.job_id 174 | AND ISNULL(ja.last_executed_step_id, 175 | 0) + 1 = js.step_id 176 | LEFT JOIN msdb.dbo.syscategories AS cat ON JOB.category_id = cat.category_id 177 | WHERE ja.session_id = (SELECT TOP 1 178 | session_id 179 | FROM msdb.dbo.syssessions 180 | ORDER BY agent_start_date DESC 181 | ) 182 | AND ja.start_execution_date IS NOT NULL 183 | AND ja.stop_execution_date IS NULL 184 | ) AS AUFTRAEGE 185 | ORDER BY AUFTRAEGE.JobName 186 | 187 | 188 | IF NOT EXISTS ( SELECT 1 189 | FROM #AuftragsLaufzeiten ) 190 | GOTO NichtsZuTun 191 | 192 | 193 | --################################################################################################### 194 | -- Hinweis Fehler 195 | --################################################################################################### 196 | DECLARE @FEHLERANZAHL AS INTEGER 197 | DECLARE @FEHLERVORHANDEN_TEXT AS VARCHAR(50) 198 | SET @FEHLERANZAHL = (SELECT COUNT(*) FROM #AuftragsLaufzeiten WHERE run_status=0) 199 | IF @FEHLERANZAHL > 0 200 | SET @FEHLERVORHANDEN_TEXT = 'Es sind ' + CONVERT(varchar(4), @FEHLERANZAHL) +' fehlerhafte Aufträge vorhanden.' 201 | ELSE 202 | SET @FEHLERVORHANDEN_TEXT = '' 203 | 204 | 205 | 206 | --################################################################################################### 207 | -- Html Zeitstrahl - Kopf 208 | -- Wird in mehrere Inserts aufgeteilt, da per Standard Text maxmial 256 Zeichen 209 | --################################################################################################### 210 | INSERT INTO ##ZeitstrahlGraph 211 | (HTML 212 | ) 213 | SELECT ' 214 | 215 | ' 282 | 283 | 284 | INSERT INTO ##ZeitstrahlGraph 285 | (HTML 286 | ) 287 | SELECT ' 288 | ' 289 | INSERT INTO ##ZeitstrahlGraph 290 | (HTML 291 | ) 292 | SELECT ' 459 | 460 | ' + '' + @@servername 461 | + ' Aufträge' + ' von ' + CONVERT(VARCHAR(20), @StartDatum, 120) 462 | + ' bis ' + CONVERT(VARCHAR(20), @EndeDatum, 120) + 463 | + CASE WHEN @FEHLERANZAHL = 0 THEN '' 464 | ELSE 465 | '. ' + @FEHLERVORHANDEN_TEXT 466 | END 467 | + CASE WHEN @MindestLaufzeitInSekunden = 0 THEN '' 468 | ELSE ' (Aufträge länger ' 469 | + CAST(@MindestLaufzeitInSekunden AS VARCHAR(10)) 470 | + ' Sekunden)' 471 | END 472 | + ' 473 |

474 | ' 475 | 476 | INSERT INTO ##ZeitstrahlGraph 477 | (HTML 478 | ) 479 | SELECT ' 480 |

481 | 519 |
520 | ' 521 | 522 | 523 | --################################################################################################### 524 | -- Zeitstrahl/Ende abschnitt 525 | --################################################################################################### 526 | DECLARE @Zeitstrahlbreite AS INTEGER 527 | IF @Tage < 1 528 | SET @Zeitstrahlbreite = 1800 529 | ELSE 530 | SET @Zeitstrahlbreite = @Tage * 1800 531 | 532 | INSERT INTO ##ZeitstrahlGraph 533 | (HTML 534 | ) 535 | SELECT ' 536 |
538 | 539 | ' 540 | 541 | 542 | --################################################################################################### 543 | -- Ausgabe als Email 544 | --################################################################################################### 545 | DECLARE @emailBodyText NVARCHAR(MAX); 546 | SET @emailBodyText = 'Zeitstrahl der Aufträge von ' 547 | + CONVERT(VARCHAR(20), @StartDatum, 120) + ' bis ' 548 | + CONVERT(VARCHAR(20), @EndeDatum, 120) + ' siehe Anhang.' 549 | DECLARE @emailSubjectText NVARCHAR(MAX); 550 | SET @emailSubjectText = @@servername + ' Aufträge von ' 551 | + CONVERT(VARCHAR(20), @StartDatum, 120) + ' bis ' 552 | + CONVERT(VARCHAR(20), @EndeDatum, 120) 553 | + ' ' + @FEHLERVORHANDEN_TEXT 554 | DECLARE @emailHTMLDateinameText NVARCHAR(MAX); 555 | SET @emailHTMLDateinameText = @@servername + ' Aufträge von ' 556 | + CONVERT(VARCHAR(20), @StartDatum, 120) + ' bis ' 557 | + CONVERT(VARCHAR(20), @EndeDatum, 120) + '.html' 558 | SET @emailHTMLDateinameText = REPLACE(@emailHTMLDateinameText, ':', '_') 559 | 560 | DECLARE @emailWichtigkeit NVARCHAR(10); 561 | IF @FEHLERANZAHL > 0 562 | SET @emailWichtigkeit = 'High' 563 | ELSE 564 | SET @emailWichtigkeit = 'Normal' 565 | 566 | IF @EmailEmpfaenger <> '' 567 | EXECUTE msdb.dbo.sp_send_dbmail @recipients = @EmailEmpfaenger, 568 | @subject = @emailSubjectText, @body = @emailBodyText, 569 | @body_format = 'HTML' -- oder TEXT 570 | , @importance = @emailWichtigkeit 571 | , @sensitivity = 'Normal' --Normal Personal Private Confidential 572 | , @execute_query_database = 'master', @query_result_header = 0, --@query_result_header = 0 ist wichtig, da sonst "HTML----" aus der Query in den html-Code gelangt 573 | @query = 'set nocount on; SELECT HTML FROM ##ZeitstrahlGraph ORDER BY ID', 574 | @query_result_no_padding = 1 575 | --,@query_no_truncate= 1 576 | , @attach_query_result_as_file = 1, 577 | @query_attachment_filename = @emailHTMLDateinameText 578 | 579 | IF @FEHLERANZAHL > 0 AND @EmailNurBeiFehlerEmpfaenger <> '' 580 | EXECUTE msdb.dbo.sp_send_dbmail @recipients = @EmailNurBeiFehlerEmpfaenger, 581 | @subject = @emailSubjectText, @body = @emailBodyText, 582 | @body_format = 'HTML' -- oder TEXT 583 | , @importance = @emailWichtigkeit 584 | , @sensitivity = 'Normal' --Normal Personal Private Confidential 585 | , @execute_query_database = 'master', @query_result_header = 0, --@query_result_header = 0 ist wichtig, da sonst "HTML----" aus der Query in den html-Code gelangt 586 | @query = 'set nocount on; SELECT HTML FROM ##ZeitstrahlGraph ORDER BY ID', 587 | @query_result_no_padding = 1 588 | --,@query_no_truncate= 1 589 | , @attach_query_result_as_file = 1, 590 | @query_attachment_filename = @emailHTMLDateinameText 591 | 592 | 593 | GOTO Aufraeumen 594 | 595 | --################################################################################################### 596 | -- Nur für alle Fälle 597 | --################################################################################################### 598 | NichtsZuTun: 599 | 600 | PRINT 'Keine Aufträge gefunden (Kann auch ein Fehler sein)' 601 | 602 | --################################################################################################### 603 | -- Aufräumen 604 | --################################################################################################### 605 | Aufraeumen: 606 | IF OBJECT_ID('tempdb..#AuftragsLaufzeiten') IS NOT NULL 607 | DROP TABLE #AuftragsLaufzeiten; 608 | IF OBJECT_ID('tempdb..##ZeitstrahlGraph') IS NOT NULL 609 | DROP TABLE ##ZeitstrahlGraph; 610 | 611 | --------------------------------------------------------------------------------