├── LICENSE ├── README.md ├── database_schema └── SQLMonitor │ ├── Database Triggers │ ├── ddlDatabaseTriggerLog.sql │ └── ddlDatabaseTriggerLog_Archive.sql │ ├── README.md │ ├── Security │ ├── schemas.sql │ └── users.sql │ ├── Stored Procedures │ ├── Reporting │ │ ├── uspBlitzResults.sql │ │ ├── uspBlitzResults4Email.sql │ │ ├── uspFailedServerAgentJobs.sql │ │ ├── uspListAvailableServerRoles.sql │ │ ├── uspListAvailableServers.sql │ │ ├── uspListDatabaseGrowthTrend.sql │ │ ├── uspListDatabaseIndexUsage.sql │ │ ├── uspListDatabaseMissingIndex.sql │ │ ├── uspListDatabaseTableColumns.sql │ │ ├── uspListFailedLogins.sql │ │ ├── uspListServerDrives.sql │ │ ├── uspListServerFreeSpace.sql │ │ ├── uspListServerLogins.sql │ │ ├── uspReportSQLBuilds.sql │ │ └── uspReportServerInformation.sql │ └── dbo │ │ ├── uspGetProfile.sql │ │ ├── uspGetReports.sql │ │ ├── uspGetServers.sql │ │ ├── uspLogError.sql │ │ ├── uspPrintError.sql │ │ └── usp_CreateDataMaintenanceProcs.sql │ ├── Synonyms │ └── synonyms.sql │ ├── Tables │ ├── Archive │ │ ├── DatabaseBackupHistory.sql │ │ ├── DatabaseConfigurations.sql │ │ ├── DatabaseTables.sql │ │ ├── DatabaseUsers.sql │ │ ├── IndexUsageStats.sql │ │ ├── MissingIndexStats.sql │ │ ├── ServerAgentConfig.sql │ │ ├── ServerAgentJobs.sql │ │ ├── ServerAgentJobsHistory.sql │ │ ├── ServerConfigurations.sql │ │ ├── ServerDatabases.sql │ │ ├── ServerEndpoints.sql │ │ ├── ServerErrorLog.sql │ │ ├── ServerFreeSpace.sql │ │ ├── ServerInfo.sql │ │ ├── ServerLogins.sql │ │ ├── ServerServers.sql │ │ └── ServerTriggers.sql │ ├── Monitor │ │ ├── BlitzResults.sql │ │ ├── DatabaseBackupHistory.sql │ │ ├── DatabaseConfigurations.sql │ │ ├── DatabaseTableColumns.sql │ │ ├── DatabaseTables.sql │ │ ├── DatabaseUsers.sql │ │ ├── IndexUsageStats.sql │ │ ├── MissingIndexStats.sql │ │ ├── ServerAgentConfig.sql │ │ ├── ServerAgentJobs.sql │ │ ├── ServerAgentJobsHistory.sql │ │ ├── ServerConfigurations.sql │ │ ├── ServerDatabases.sql │ │ ├── ServerEndpoints.sql │ │ ├── ServerErrorLog.sql │ │ ├── ServerFreeSpace.sql │ │ ├── ServerInfo.sql │ │ ├── ServerLogins.sql │ │ ├── ServerServers.sql │ │ └── ServerTriggers.sql │ ├── Staging │ │ ├── IndexUsageStats.sql │ │ └── MissingIndexStats.sql │ └── dbo │ │ ├── DatabaseLog.sql │ │ ├── DatabaseLog_Archive.sql │ │ ├── ErrorLog.sql │ │ ├── MonitoredServers.sql │ │ ├── Profile.sql │ │ ├── ReportRecipients.sql │ │ ├── ReportSubscriptions.sql │ │ ├── Reports.sql │ │ └── SystemParams.sql │ ├── Views │ ├── Monitor │ │ ├── blitz_results.sql │ │ ├── database_backup_history.sql │ │ ├── database_configurations.sql │ │ ├── database_indexusagestats.sql │ │ ├── database_missingindexstats.sql │ │ ├── database_table_columns.sql │ │ ├── database_tables.sql │ │ ├── database_users.sql │ │ ├── server_agentconfig.sql │ │ ├── server_agentjobs.sql │ │ ├── server_agentjobshistory.sql │ │ ├── server_configurations.sql │ │ ├── server_databases.sql │ │ ├── server_endpoints.sql │ │ ├── server_errorlog.sql │ │ ├── server_freespace.sql │ │ ├── server_info.sql │ │ ├── server_logins.sql │ │ ├── server_servers.sql │ │ └── server_triggers.sql │ ├── Reporting │ │ └── vwErrorLog.sql │ └── dbo │ │ └── vwProfile.sql │ ├── create_database.sql │ ├── create_database_archive.sql │ ├── initial_data_set.sql │ └── initial_depolyment.ps1 └── information_collection ├── Community_Functions.ps1 ├── Export-ServerInfo.ps1 ├── Get-ServerInfo.ps1 ├── Invoke-ArchiveMaintenance.ps1 ├── Invoke-SQLMonitorUI.ps1 ├── Send-EmailReport.ps1 ├── Settings.xml ├── Test-NetworkConnection.ps1 ├── scripts ├── blitz_results.sql ├── database_backup_history.sql ├── database_configurations.sql ├── database_indexusagestats.sql ├── database_missingindexstats.sql ├── database_table_columns.sql ├── database_tables.sql ├── database_users.sql ├── server_agentconfig.sql ├── server_agentjobs.sql ├── server_agentjobshistory.sql ├── server_configurations.sql ├── server_databases.sql ├── server_endpoints.sql ├── server_errorlog.sql ├── server_freespace.sql ├── server_info.sql ├── server_logins.sql ├── server_msb.sql ├── server_servers.sql └── server_triggers.sql └── tasks ├── README.md ├── SQLMonitor Export Failed Logins Daily.xml ├── SQLMonitor Get-ServerInfo Annual.xml ├── SQLMonitor Get-ServerInfo Daily.xml ├── SQLMonitor Get-ServerInfo Hourly.xml ├── SQLMonitor Get-ServerInfo Manual.xml ├── SQLMonitor Get-ServerInfo Minute.xml ├── SQLMonitor Get-ServerInfo Monthly.xml ├── SQLMonitor Get-ServerInfo Weekly.xml └── SQLMonitor Invoke-ArchiveMaintenance Daily.xml /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2018 Reuben Sultana 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 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQLMonitor 2 | SQL Server monitoring tool based on PowerShell v3 and TSQL scripts only 3 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Database Triggers/ddlDatabaseTriggerLog.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF EXISTS (SELECT * FROM sys.triggers WHERE parent_class_desc = 'DATABASE' AND name = N'ddlDatabaseTriggerLog') 5 | DROP TRIGGER [ddlDatabaseTriggerLog] ON DATABASE 6 | GO 7 | 8 | CREATE TRIGGER [ddlDatabaseTriggerLog] ON DATABASE 9 | FOR DDL_DATABASE_LEVEL_EVENTS AS 10 | BEGIN 11 | SET NOCOUNT ON; 12 | 13 | DECLARE @data XML; 14 | DECLARE @schema nvarchar(128); 15 | DECLARE @object nvarchar(128); 16 | DECLARE @eventType nvarchar(128); 17 | 18 | SET @data = EVENTDATA(); 19 | SET @eventType = @data.value('(/EVENT_INSTANCE/EventType)[1]', 'sysname'); 20 | SET @schema = @data.value('(/EVENT_INSTANCE/SchemaName)[1]', 'sysname'); 21 | SET @object = @data.value('(/EVENT_INSTANCE/ObjectName)[1]', 'sysname') 22 | 23 | --IF @object IS NOT NULL 24 | -- PRINT ' ' + @eventType + ' - ' + @schema + '.' + @object; 25 | --ELSE 26 | -- PRINT ' ' + @eventType + ' - ' + @schema; 27 | 28 | --IF @eventType IS NULL 29 | -- PRINT CONVERT(nvarchar(max), @data); 30 | 31 | INSERT [dbo].[DatabaseLog] ( 32 | [PostTime], 33 | [DatabaseUser], 34 | [Event], 35 | [Schema], 36 | [Object], 37 | [TSQL], 38 | [XmlEvent] 39 | ) 40 | VALUES ( 41 | CURRENT_TIMESTAMP, 42 | CONVERT(nvarchar(128), CURRENT_USER), 43 | @eventType, 44 | CONVERT(nvarchar(128), @schema), 45 | CONVERT(nvarchar(128), @object), 46 | @data.value('(/EVENT_INSTANCE/TSQLCommand)[1]', 'nvarchar(max)'), 47 | @data 48 | ); 49 | END; 50 | GO 51 | 52 | ENABLE TRIGGER [ddlDatabaseTriggerLog] ON DATABASE 53 | GO 54 | 55 | 56 | USE [master] 57 | GO 58 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Database Triggers/ddlDatabaseTriggerLog_Archive.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF EXISTS (SELECT * FROM sys.triggers WHERE parent_class_desc = 'DATABASE' AND name = N'ddlDatabaseTriggerLog') 5 | DROP TRIGGER [ddlDatabaseTriggerLog] ON DATABASE 6 | GO 7 | 8 | CREATE TRIGGER [ddlDatabaseTriggerLog] ON DATABASE 9 | FOR DDL_DATABASE_LEVEL_EVENTS AS 10 | BEGIN 11 | SET NOCOUNT ON; 12 | 13 | DECLARE @data XML; 14 | DECLARE @schema nvarchar(128); 15 | DECLARE @object nvarchar(128); 16 | DECLARE @eventType nvarchar(128); 17 | 18 | SET @data = EVENTDATA(); 19 | SET @eventType = @data.value('(/EVENT_INSTANCE/EventType)[1]', 'sysname'); 20 | SET @schema = @data.value('(/EVENT_INSTANCE/SchemaName)[1]', 'sysname'); 21 | SET @object = @data.value('(/EVENT_INSTANCE/ObjectName)[1]', 'sysname') 22 | 23 | --IF @object IS NOT NULL 24 | -- PRINT ' ' + @eventType + ' - ' + @schema + '.' + @object; 25 | --ELSE 26 | -- PRINT ' ' + @eventType + ' - ' + @schema; 27 | 28 | --IF @eventType IS NULL 29 | -- PRINT CONVERT(nvarchar(max), @data); 30 | 31 | INSERT [dbo].[DatabaseLog] ( 32 | [PostTime], 33 | [DatabaseUser], 34 | [Event], 35 | [Schema], 36 | [Object], 37 | [TSQL], 38 | [XmlEvent] 39 | ) 40 | VALUES ( 41 | CURRENT_TIMESTAMP, 42 | CONVERT(nvarchar(128), CURRENT_USER), 43 | @eventType, 44 | CONVERT(nvarchar(128), @schema), 45 | CONVERT(nvarchar(128), @object), 46 | @data.value('(/EVENT_INSTANCE/TSQLCommand)[1]', 'nvarchar(max)'), 47 | @data 48 | ); 49 | END; 50 | GO 51 | 52 | ENABLE TRIGGER [ddlDatabaseTriggerLog] ON DATABASE 53 | GO 54 | 55 | 56 | USE [master] 57 | GO 58 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/README.md: -------------------------------------------------------------------------------- 1 | # SQLMonitor Database Schema 2 | The project database schema, including files used for the initial deployment. 3 | 4 | The "initial_deplyment.ps1" will do that. Before running the script you'd have to change values in the "initial_data_set.sql" file. 5 | 6 | Other than that, you're good to go! 7 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Security/schemas.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF NOT EXISTS(SELECT 1 FROM sys.schemas WHERE name = 'Monitor') 5 | EXEC sp_executesql N'CREATE SCHEMA [Monitor] AUTHORIZATION [dbo];'; 6 | GO 7 | 8 | IF NOT EXISTS(SELECT 1 FROM sys.schemas WHERE name = 'Reporting') 9 | EXEC sp_executesql N'CREATE SCHEMA [Reporting] AUTHORIZATION [dbo];'; 10 | GO 11 | 12 | IF NOT EXISTS(SELECT 1 FROM sys.schemas WHERE name = 'Staging') 13 | EXEC sp_executesql N'CREATE SCHEMA [Staging] AUTHORIZATION [dbo];'; 14 | GO 15 | 16 | IF NOT EXISTS(SELECT 1 FROM sys.schemas WHERE name = 'Archive') 17 | EXEC sp_executesql N'CREATE SCHEMA [Archive] AUTHORIZATION [dbo];'; 18 | GO 19 | 20 | ---------- 21 | USE [SQLMonitorArchive] 22 | GO 23 | 24 | IF NOT EXISTS(SELECT 1 FROM sys.schemas WHERE name = 'Archive') 25 | EXEC sp_executesql N'CREATE SCHEMA [Archive] AUTHORIZATION [dbo];'; 26 | GO 27 | 28 | ---------- 29 | USE [master] 30 | GO 31 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Security/users.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | 5 | 6 | 7 | 8 | 9 | USE [master] 10 | GO 11 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspBlitzResults.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspBlitzResults]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspBlitzResults] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspBlitzResults] 9 | @ServerOrder smallint = 1, -- Production servers by default 10 | @ServerName nvarchar(128) = NULL, 11 | @Priority tinyint = NULL, 12 | @CheckID int = NULL 13 | AS 14 | BEGIN 15 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 16 | SET NOCOUNT ON; 17 | /*-- NOTE: If anything is changed here make sure the same is applied to uspBlitzResults4Email --*/ 18 | SELECT 19 | br.[Priority] 20 | ,br.[CheckID] 21 | ,br.[FindingsGroup] 22 | ,br.[Finding] 23 | ,br.[ServerName] 24 | ,br.[DatabaseName] 25 | ,br.[Details] 26 | ,br.[URL] 27 | 28 | FROM [Monitor].[BlitzResults] br 29 | INNER JOIN [dbo].[MonitoredServers] ms ON br.[ServerName] = COALESCE(ms.[ServerAlias], ms.[ServerName]) 30 | -- CheckID exclusions based on https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/blob/master/Documentation/sp_Blitz%20Checks%20by%20Priority.md 31 | WHERE br.[CheckID] NOT IN ( 32 | -1 -- Thanks!; From Your Community Volunteers 33 | ,49 -- Informational; Linked Server Configured 34 | ,53 -- Informational; Cluster Node 35 | ,74 -- Informational; TraceFlag On 36 | ,76 -- Informational; Collation is... 37 | ,83 -- Server Info; Services 38 | ,84 -- Server Info; Hardware 39 | ,85 -- Server Info; SQL Server Service 40 | ,92 -- Server Info; Drive Space 41 | ,103 -- Server Info; Virtual Server 42 | ,106 -- Server Info; Default Trace Contents 43 | ,114 -- Server Info; Hardware - NUMA Config 44 | ,130 -- Server Info; Server Name 45 | ,153 -- Wait Stats; No Significant Waits Detected 46 | ,155 -- Outdated sp_Blitz; sp_Blitz is Over 6 Months Old 47 | ,156 -- Rundate; (Current Date) 48 | ,193 -- Server Info; Instant File Initialization Enabled 49 | ,204 -- Informational; @CheckUserDatabaseObjects Disabled 50 | ) 51 | -- production servers are usually set to "1" 52 | AND ms.[ServerOrder] = COALESCE(@ServerOrder, ms.[ServerOrder]) 53 | -- temporpermanent (?) fix due to incorrect server name in sys.servers 54 | AND COALESCE(ms.[ServerAlias], ms.[ServerName]) LIKE COALESCE(NULLIF(@ServerName, ''), '%') 55 | 56 | AND br.[Priority] = COALESCE(@Priority, br.[Priority]) 57 | AND br.[CheckID] = COALESCE(@CheckID, br.[CheckID]) 58 | 59 | ORDER BY br.[Priority], br.[CheckID], br.[FindingsGroup], br.[ServerName], br.[DatabaseName] 60 | 61 | END 62 | GO 63 | 64 | -- EXEC [Reporting].[uspBlitzResults] 65 | -- EXEC [Reporting].[uspBlitzResults] @ServerOrder=NULL 66 | -- EXEC [Reporting].[uspBlitzResults] @ServerOrder=1, @Priority = 1, @CheckID = 1; -- Backup; Backups Not Performed Recently 67 | -- EXEC [Reporting].[uspBlitzResults] @ServerOrder=1, @Priority = 1, @CheckID = 2; -- Backup; Full Recovery Model w/o Log Backups 68 | 69 | 70 | USE [master] 71 | GO 72 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspBlitzResults4Email.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspBlitzResults4Email]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspBlitzResults4Email] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspBlitzResults4Email] 9 | @ServerOrder smallint = 1, -- Production servers by default 10 | @ServerName nvarchar(128) = NULL, 11 | @Priority tinyint = NULL, 12 | @CheckID int = NULL 13 | AS 14 | BEGIN 15 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 16 | SET NOCOUNT ON; 17 | /*-- NOTE: If anything is changed here make sure the same is applied to uspBlitzResults --*/ 18 | SELECT 19 | br.[ServerName] 20 | ,br.[DatabaseName] 21 | ,br.[Details] 22 | ,br.[URL] 23 | 24 | FROM [Monitor].[BlitzResults] br 25 | INNER JOIN [dbo].[MonitoredServers] ms ON br.[ServerName] = COALESCE(ms.[ServerAlias], ms.[ServerName]) 26 | -- CheckID exclusions based on https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/blob/master/Documentation/sp_Blitz%20Checks%20by%20Priority.md 27 | WHERE br.[CheckID] NOT IN ( 28 | -1 -- Thanks!; From Your Community Volunteers 29 | ,49 -- Informational; Linked Server Configured 30 | ,53 -- Informational; Cluster Node 31 | ,74 -- Informational; TraceFlag On 32 | ,76 -- Informational; Collation is... 33 | ,83 -- Server Info; Services 34 | ,84 -- Server Info; Hardware 35 | ,85 -- Server Info; SQL Server Service 36 | ,92 -- Server Info; Drive Space 37 | ,103 -- Server Info; Virtual Server 38 | ,106 -- Server Info; Default Trace Contents 39 | ,114 -- Server Info; Hardware - NUMA Config 40 | ,130 -- Server Info; Server Name 41 | ,153 -- Wait Stats; No Significant Waits Detected 42 | ,155 -- Outdated sp_Blitz; sp_Blitz is Over 6 Months Old 43 | ,156 -- Rundate; (Current Date) 44 | ,193 -- Server Info; Instant File Initialization Enabled 45 | ,204 -- Informational; @CheckUserDatabaseObjects Disabled 46 | ) 47 | -- production servers are usually set to "1" 48 | AND ms.[ServerOrder] = COALESCE(@ServerOrder, ms.[ServerOrder]) 49 | -- temporpermanent (?) fix due to incorrect server name in sys.servers 50 | AND COALESCE(ms.[ServerAlias], ms.[ServerName]) LIKE COALESCE(NULLIF(@ServerName, ''), '%') 51 | 52 | AND br.[Priority] = COALESCE(@Priority, br.[Priority]) 53 | AND br.[CheckID] = COALESCE(@CheckID, br.[CheckID]) 54 | 55 | ORDER BY br.[Priority], br.[CheckID], br.[FindingsGroup], br.[ServerName], br.[DatabaseName] 56 | 57 | END 58 | GO 59 | 60 | -- EXEC [Reporting].[uspBlitzResults4Email] 61 | -- EXEC [Reporting].[uspBlitzResults4Email] @ServerOrder=NULL 62 | -- EXEC [Reporting].[uspBlitzResults4Email] @ServerOrder=1, @Priority = 1, @CheckID = 1; -- Backup; Backups Not Performed Recently 63 | -- EXEC [Reporting].[uspBlitzResults4Email] @ServerOrder=1, @Priority = 1, @CheckID = 2; -- Backup; Full Recovery Model w/o Log Backups 64 | 65 | 66 | USE [master] 67 | GO 68 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspFailedServerAgentJobs.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspFailedServerAgentJobs]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspFailedServerAgentJobs] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspFailedServerAgentJobs] 9 | @TopRowCount int = 100, 10 | @ServerName nvarchar(128) = NULL, 11 | @LastRunTime datetime = NULL 12 | AS 13 | BEGIN 14 | SET NOCOUNT ON; 15 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 16 | 17 | SELECT TOP (@TopRowCount) 18 | [ServerName], [JobName], [StepID], [StepName], MAX([LastRunTime]) AS [LastRunTime], [RunStatus], COUNT(*) AS [ItemCount] 19 | FROM [SQLMonitor].[Monitor].[ServerAgentJobsHistory] 20 | -- [RunStatus] not equal to Successful 21 | WHERE [RunStatus] <> 1 22 | -- [ServerName] filter 23 | AND [ServerName] = COALESCE(NULLIF(REPLACE(@ServerName, '%', ''), ''), [ServerName]) 24 | -- [LastRunTime] as specified or limited to the last 24 hours 25 | AND [LastRunTime] >= COALESCE(@LastRunTime, DATEADD(hh, -24, CURRENT_TIMESTAMP)) 26 | GROUP BY 27 | [ServerName], [JobName], [StepID], [StepName], [RunStatus] 28 | -- ORDER BY server function 29 | ORDER BY 30 | CASE 31 | WHEN [ServerName] LIKE 'CFS%' THEN 1 32 | WHEN [ServerName] LIKE 'STG%' THEN 2 33 | WHEN [ServerName] LIKE 'DEV%' THEN 3 34 | ELSE 4 35 | END, 36 | [LastRunTime] DESC, [JobName] ASC, [StepID] ASC 37 | 38 | END 39 | GO 40 | 41 | -- EXEC [SQLMonitor].[Reporting].[uspFailedServerAgentJobs] 42 | 43 | 44 | USE [master] 45 | GO 46 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListAvailableServerRoles.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspListAvailableServerRoles]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspListAvailableServerRoles] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspListAvailableServerRoles] 9 | AS 10 | BEGIN 11 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 12 | SET NOCOUNT ON; 13 | SELECT 14 | '***** Select All ***** ' AS [RoleName], 15 | '%' AS [RoleNameValue], 16 | NULL AS [PrincipalID] 17 | UNION ALL 18 | SELECT 19 | [name] AS [RoleName], 20 | [name] AS [RoleNameValue], 21 | sp.principal_id AS [PrincipalID] 22 | FROM [master].sys.server_principals sp 23 | WHERE sp.type = 'R' AND sp.is_fixed_role = 1 24 | ORDER BY [PrincipalID]; 25 | END 26 | GO 27 | 28 | -- EXEC [SQLMonitor].[Reporting].[uspListAvailableServerRoles] 29 | 30 | 31 | USE [master] 32 | GO 33 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListAvailableServers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspListAvailableServers]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspListAvailableServers] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspListAvailableServers] 9 | @DomainName nvarchar(15) = NULL 10 | AS 11 | BEGIN 12 | SET NOCOUNT ON; 13 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 14 | 15 | -- get the domain name for the login running the stored procedure 16 | IF (NULLIF(@DomainName, '') IS NULL) 17 | SET @DomainName = SUBSTRING(SYSTEM_USER, 1, CHARINDEX('\', SYSTEM_USER, 1)-1); 18 | 19 | WITH cteServerList AS ( 20 | SELECT '***** Select All ***** ' AS [ServerName], '%' AS [ServerNameValue], NULL AS [ServerOrder] 21 | UNION ALL 22 | SELECT 23 | [ServerName], 24 | -- temporpermanent (?) fix due to incorrect server name in sys.servers 25 | COALESCE([ServerAlias], [ServerName]) AS [ServerNameValue], 26 | [ServerOrder] 27 | FROM [dbo].[MonitoredServers] 28 | WHERE ([RecordStatus] = 'A' 29 | AND [ServerDomain] LIKE @DomainName) 30 | ) 31 | SELECT [ServerName], [ServerNameValue], [ServerOrder] 32 | FROM cteServerList 33 | ORDER BY [ServerOrder], [ServerName]; 34 | END 35 | GO 36 | 37 | -- EXEC [SQLMonitor].[Reporting].[uspListAvailableServers] 38 | 39 | 40 | USE [master] 41 | GO 42 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListDatabaseIndexUsage.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspListDatabaseIndexUsage]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspListDatabaseIndexUsage] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspListDatabaseIndexUsage] 9 | @ServerName nvarchar(128) = '%', 10 | @DatabaseName nvarchar(128) = '%' 11 | AS 12 | BEGIN 13 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 14 | SET NOCOUNT ON; 15 | SELECT [ServerName] 16 | ,[DatabaseName] 17 | ,[ObjectName] 18 | ,[IndexID] 19 | ,[IndexName] 20 | ,[UserSeeks] 21 | ,[UserScans] 22 | ,[UserLookups] 23 | ,[UserUpdates] 24 | ,[LastPollDate] 25 | FROM [Monitor].[IndexUsageStats] 26 | WHERE [ServerName] LIKE @ServerName 27 | AND [DatabaseName] LIKE @DatabaseName 28 | AND [RecordStatus] = 'A' 29 | ORDER BY 30 | [ServerName] 31 | ,[DatabaseName] 32 | ,[ObjectName] 33 | ,[IndexID] 34 | ,[IndexName]; 35 | END 36 | GO 37 | 38 | -- EXEC [SQLMonitor].[Reporting].[uspListDatabaseIndexUsage] 39 | 40 | 41 | USE [master] 42 | GO 43 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListDatabaseMissingIndex.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspListDatabaseMissingIndex]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspListDatabaseMissingIndex] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspListDatabaseMissingIndex] 9 | @ServerName nvarchar(128) = '%', 10 | @DatabaseName nvarchar(128) = '%' 11 | AS 12 | BEGIN 13 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 14 | SET NOCOUNT ON; 15 | SELECT [ServerName] 16 | ,[DatabaseName] 17 | ,[ObjectName] 18 | ,[EqualityColumns] 19 | ,[InequalityColumns] 20 | ,[IncludedColumns] 21 | ,[UniqueCompiles] 22 | ,[UserSeeks] 23 | ,[UserScans] 24 | ,[AvgTotalUserCost] 25 | ,[AvgUserImpact] 26 | ,[LastPollDate] 27 | FROM [Monitor].[MissingIndexStats] 28 | WHERE [ServerName] LIKE @ServerName 29 | AND [DatabaseName] LIKE @DatabaseName 30 | AND [RecordStatus] = 'A' 31 | ORDER BY 32 | [ServerName] 33 | ,[DatabaseName] 34 | ,[AvgUserImpact] DESC 35 | ,[ObjectName]; 36 | END 37 | GO 38 | 39 | -- EXEC [SQLMonitor].[Reporting].[uspListDatabaseMissingIndex] 40 | 41 | 42 | USE [master] 43 | GO 44 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListDatabaseTableColumns.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/database_schema/SQLMonitor/Stored Procedures/Reporting/uspListDatabaseTableColumns.sql -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListFailedLogins.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspListFailedLogins]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspListFailedLogins] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspListFailedLogins] 9 | @ReportDate datetime = NULL, 10 | @ServerName nvarchar(128) = NULL, 11 | @IncludeArchive bit = 0 12 | AS 13 | BEGIN 14 | SET NOCOUNT ON; 15 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 16 | 17 | IF (@ReportDate IS NULL) 18 | SET @ReportDate = DATEADD(D, -1, CAST(CURRENT_TIMESTAMP AS date)); 19 | 20 | DECLARE @StartDate date = CAST(@ReportDate AS date); 21 | DECLARE @EndDate date = DATEADD(D, 1, CAST(@ReportDate AS date)); 22 | 23 | WITH cteFailedLoginAttempts 24 | AS ( 25 | SELECT 26 | [ServerName] 27 | ,[LogDate] 28 | ,[ProcessInfo] 29 | ,[LogText] 30 | -- Extract Login points 31 | ,(CHARINDEX('''', [LogText], 0)+1) AS [LoginStartPoint] 32 | ,((CHARINDEX('''', [LogText], (CHARINDEX('''', [LogText], 0)+1))-1) - (CHARINDEX('''', [LogText], 0))) AS [LoginEndPoint] 33 | -- Extract IP Address points 34 | ,(CHARINDEX('[', [LogText], 0)+1) AS [IPStartPoint] 35 | ,((CHARINDEX(']', [LogText], (CHARINDEX('[', [LogText], 0)+1))-1) - (CHARINDEX('[', [LogText], 0))) AS [IPEndPoint] 36 | -- Extract Reason points 37 | ,(CHARINDEX('Reason: ', [LogText], 0)+8) AS [ReasonStartPoint] 38 | ,((CHARINDEX('[', [LogText], (CHARINDEX('Reason: ', [LogText], 0)+8))-8) - (CHARINDEX('Reason: ', [LogText], 0))) AS [ReasonEndPoint] 39 | FROM [Monitor].[ServerErrorLog] 40 | WHERE [LogText] LIKE N'Login failed for user%' 41 | AND [LogDate] BETWEEN @StartDate AND @EndDate 42 | AND [ServerName] LIKE COALESCE(NULLIF(@ServerName, ''), [ServerName]) 43 | 44 | UNION ALL 45 | 46 | SELECT 47 | [ServerName] 48 | ,[LogDate] 49 | ,[ProcessInfo] 50 | ,[LogText] 51 | -- Extract Login points 52 | ,(CHARINDEX('''', [LogText], 0)+1) AS [LoginStartPoint] 53 | ,((CHARINDEX('''', [LogText], (CHARINDEX('''', [LogText], 0)+1))-1) - (CHARINDEX('''', [LogText], 0))) AS [LoginEndPoint] 54 | -- Extract IP Address points 55 | ,(CHARINDEX('[', [LogText], 0)+1) AS [IPStartPoint] 56 | ,((CHARINDEX(']', [LogText], (CHARINDEX('[', [LogText], 0)+1))-1) - (CHARINDEX('[', [LogText], 0))) AS [IPEndPoint] 57 | -- Extract Reason points 58 | ,(CHARINDEX('Reason: ', [LogText], 0)+8) AS [ReasonStartPoint] 59 | ,((CHARINDEX('[', [LogText], (CHARINDEX('Reason: ', [LogText], 0)+8))-8) - (CHARINDEX('Reason: ', [LogText], 0))) AS [ReasonEndPoint] 60 | FROM [Archive].[ServerErrorLog] 61 | WHERE [LogText] LIKE N'Login failed for user%' 62 | AND [LogDate] BETWEEN @StartDate AND @EndDate 63 | AND [ServerName] LIKE COALESCE(NULLIF(@ServerName, ''), [ServerName]) 64 | AND @IncludeArchive = 1 65 | 66 | ) 67 | SELECT 68 | [ServerName] 69 | ,CONVERT(varchar(19), [LogDate], 121) AS [LogDate] 70 | ,[ProcessInfo] 71 | --,[LogText] 72 | -- Extract Login 73 | ,SUBSTRING( 74 | [LogText], 75 | [LoginStartPoint], 76 | (CASE WHEN [LoginEndPoint] > 0 THEN [LoginEndPoint] ELSE 0 END) 77 | ) AS [LoginName] 78 | -- Extract IP Address 79 | ,REPLACE( 80 | SUBSTRING( 81 | [LogText], 82 | [IPStartPoint], 83 | (CASE WHEN [IPEndPoint] > 0 THEN [IPEndPoint] ELSE 0 END) 84 | ), 85 | 'CLIENT: ', 86 | '' 87 | ) AS [IPAddress] 88 | -- Extract Reason 89 | ,SUBSTRING( 90 | [LogText], 91 | [ReasonStartPoint], 92 | [ReasonEndPoint] 93 | ) AS [ReasonForFailure] 94 | FROM cteFailedLoginAttempts; 95 | 96 | END 97 | GO 98 | 99 | /* 100 | @ECHO OFF 101 | For /F "Tokens=1-3 Delims=/:. " %%d In ("%Date%") Do bcp "EXEC [SQLMonitor].[Reporting].[uspListFailedLogins];" queryout ".\_export\FailedLogins_%%f%%e%%d.txt" -S "%1" -T -c -k -t"|" 102 | */ 103 | 104 | USE [master] 105 | GO 106 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListServerDrives.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspListServerDrives]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspListServerDrives] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspListServerDrives] 9 | @ServerName nvarchar(128) = '' 10 | AS 11 | BEGIN 12 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 13 | SET NOCOUNT ON; 14 | 15 | IF ((COALESCE(@ServerName, NULLIF(LTRIM(RTRIM(@ServerName)), '')) IS NOT NULL) 16 | AND EXISTS( 17 | SELECT 1 FROM [dbo].[MonitoredServers] WHERE [RecordStatus] = 'A' 18 | -- temporpermanent (?) fix due to incorrect server name in sys.servers 19 | AND COALESCE([ServerAlias], [ServerName]) = @ServerName 20 | ) 21 | ) 22 | BEGIN 23 | SELECT '***** Select All ***** ' AS [DriveLetter], '%' AS [DriveLetterValue], 0 AS [LetterOrder] 24 | UNION ALL 25 | SELECT DISTINCT sfs.[Drive], sfs.[Drive], 1 26 | FROM [Monitor].[ServerFreeSpace] sfs 27 | INNER JOIN [dbo].[MonitoredServers] ms ON COALESCE(ms.[ServerAlias], ms.[ServerName]) = sfs.[ServerName] 28 | -- temporpermanent (?) fix due to incorrect server name in sys.servers 29 | WHERE COALESCE(ms.[ServerAlias], ms.[ServerName]) = @ServerName 30 | ORDER BY [LetterOrder], [DriveLetter] ASC 31 | END 32 | END 33 | GO 34 | 35 | 36 | USE [master] 37 | GO 38 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListServerFreeSpace.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspListServerFreeSpaceTrend]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspListServerFreeSpaceTrend] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspListServerFreeSpaceTrend] 9 | @ServerName nvarchar(128) = '', 10 | @DriveLetter char(1) = '%', 11 | @IncludeArchive bit = 0 12 | AS 13 | BEGIN 14 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 15 | SET NOCOUNT ON; 16 | 17 | IF ((COALESCE(@ServerName, NULLIF(LTRIM(RTRIM(@ServerName)), '')) IS NOT NULL) 18 | AND EXISTS( 19 | SELECT 1 FROM [dbo].[MonitoredServers] WHERE [RecordStatus] = 'A' 20 | -- temporpermanent (?) fix due to incorrect server name in sys.servers 21 | AND COALESCE([ServerAlias], [ServerName]) = @ServerName 22 | ) 23 | ) 24 | BEGIN 25 | SELECT sfs.[ServerName] 26 | ,sfs.[Drive] 27 | ,sfs.[FreeMB] 28 | ,sfs.[RecordCreated] 29 | FROM [Archive].[ServerFreeSpace] sfs 30 | INNER JOIN [dbo].[MonitoredServers] ms ON COALESCE(ms.[ServerAlias], ms.[ServerName]) = sfs.[ServerName] 31 | -- temporpermanent (?) fix due to incorrect server name in sys.servers 32 | WHERE COALESCE(ms.[ServerAlias], ms.[ServerName]) = @ServerName 33 | AND sfs.[Drive] LIKE @DriveLetter 34 | AND @IncludeArchive = 1 -- depends on input parameter (functions as an "if" or "case" statement) 35 | 36 | UNION ALL 37 | 38 | SELECT sfs.[ServerName] 39 | ,sfs.[Drive] 40 | ,sfs.[FreeMB] 41 | ,sfs.[RecordCreated] 42 | FROM [Monitor].[ServerFreeSpace] sfs 43 | INNER JOIN [dbo].[MonitoredServers] ms ON COALESCE(ms.[ServerAlias], ms.[ServerName]) = sfs.[ServerName] 44 | -- temporpermanent (?) fix due to incorrect server name in sys.servers 45 | WHERE COALESCE(ms.[ServerAlias], ms.[ServerName]) = @ServerName 46 | AND sfs.[Drive] LIKE @DriveLetter 47 | END 48 | END 49 | GO 50 | 51 | 52 | USE [master] 53 | GO 54 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspListServerLogins.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[Reporting].[uspListServerLogins]') IS NOT NULL 5 | DROP PROCEDURE [Reporting].[uspListServerLogins] 6 | GO 7 | 8 | CREATE PROCEDURE [Reporting].[uspListServerLogins] 9 | @ServerName nvarchar(128) = '%', 10 | @RoleName nvarchar(128) = '%' 11 | AS 12 | BEGIN 13 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 14 | SET NOCOUNT ON; 15 | SELECT [ServerName] 16 | ,[LoginName] 17 | ,[Type] 18 | ,[CreateDate] 19 | ,[ModifyDate] 20 | ,[PasswordLastSet] 21 | ,[DefaultDatabase] 22 | ,[DefaultLanguage] 23 | ,[IsDisabled] 24 | ,[IsPolicyChecked] 25 | ,[IsExpirationChecked] 26 | ,[sysadmin] 27 | ,[securityadmin] 28 | ,[serveradmin] 29 | ,[setupadmin] 30 | ,[processadmin] 31 | ,[diskadmin] 32 | ,[dbcreator] 33 | ,[bulkadmin] 34 | ,[SecurablesPermissions] 35 | FROM [SQLMonitor].[Monitor].[server_logins] 36 | WHERE [ServerName] LIKE @ServerName 37 | AND [RecordStatus] = 'A' 38 | AND ( 39 | (CASE WHEN @RoleName = '%' THEN 1 END) = 1 OR 40 | [sysadmin] = (CASE WHEN @RoleName = 'sysadmin' THEN 1 END) OR 41 | [securityadmin] = (CASE WHEN @RoleName = 'securityadmin' THEN 1 END) OR 42 | [serveradmin] = (CASE WHEN @RoleName = 'serveradmin' THEN 1 END) OR 43 | [setupadmin] = (CASE WHEN @RoleName = 'setupadmin' THEN 1 END) OR 44 | [processadmin] = (CASE WHEN @RoleName = 'processadmin' THEN 1 END) OR 45 | [diskadmin] = (CASE WHEN @RoleName = 'diskadmin' THEN 1 END) OR 46 | [dbcreator] = (CASE WHEN @RoleName = 'dbcreator' THEN 1 END) OR 47 | [bulkadmin] = (CASE WHEN @RoleName = 'bulkadmin' THEN 1 END) 48 | ) 49 | ORDER BY 50 | CASE 51 | WHEN [ServerName] LIKE 'CFS%' THEN 1 52 | WHEN [ServerName] LIKE 'STG%' THEN 2 53 | WHEN [ServerName] LIKE 'DEV%' THEN 3 54 | ELSE 4 55 | END, 56 | [Type], [LoginName]; 57 | END 58 | GO 59 | 60 | -- EXEC [SQLMonitor].[Reporting].[uspListServerLogins] 61 | 62 | 63 | USE [master] 64 | GO 65 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspReportSQLBuilds.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/database_schema/SQLMonitor/Stored Procedures/Reporting/uspReportSQLBuilds.sql -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/Reporting/uspReportServerInformation.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/database_schema/SQLMonitor/Stored Procedures/Reporting/uspReportServerInformation.sql -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/dbo/uspGetProfile.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[dbo].[uspGetProfile]') IS NOT NULL 5 | DROP PROCEDURE [dbo].[uspGetProfile] 6 | GO 7 | 8 | CREATE PROCEDURE [dbo].[uspGetProfile] 9 | @ProfileName varchar(50), 10 | @ProfileType varchar(50) 11 | AS 12 | BEGIN 13 | SET NOCOUNT ON; 14 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 15 | 16 | -- the only allowed types 17 | IF (@ProfileType NOT IN ( 18 | 'Annual', 'Monthly', 'Weekly', 'Daily', 'Hourly', 'Minute', 'Manual')) 19 | BEGIN 20 | RAISERROR('Invalid Profile Type.', 16, 1) 21 | RETURN -1 22 | END 23 | 24 | IF NOT EXISTS(SELECT 1 FROM [dbo].[Profile] WHERE [ProfileName] = @ProfileName) 25 | BEGIN 26 | RAISERROR('Invalid Profile Name.', 16, 1) 27 | RETURN -1 28 | END 29 | 30 | SELECT 31 | p.[ScriptName], p.[PreExecuteScript], p.[ExecuteScript], 32 | p.[IntervalMinutes] 33 | FROM [dbo].[vwProfile] p 34 | WHERE p.[ProfileName] = @ProfileName AND p.[ProfileType] = @ProfileType 35 | ORDER BY [IntervalMinutes], p.[ProfileName], p.[ExecutionOrder], p.[ScriptName]; 36 | 37 | END 38 | GO 39 | 40 | 41 | USE [master] 42 | GO 43 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/dbo/uspGetReports.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[dbo].[uspGetReports]') IS NOT NULL 5 | DROP PROCEDURE [dbo].[uspGetReports] 6 | GO 7 | 8 | CREATE PROCEDURE [dbo].[uspGetReports] 9 | @ReportType varchar(50) 10 | AS 11 | BEGIN 12 | SET NOCOUNT ON; 13 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 14 | 15 | -- the only allowed types 16 | IF (@ReportType NOT IN ( 17 | 'Monthly', 'Weekly', 'Daily', 'Manual', 'Custom Monthly', 'Custom Weekly', 'Custom Daily', 'Custom Test')) 18 | BEGIN 19 | RAISERROR('Invalid Report Type.', 16, 1) 20 | RETURN -1 21 | END 22 | 23 | SELECT 24 | r.ReportID, r.ReportName, r.ReportType, r.ExecuteScript 25 | ,rr.RecipientName, rr.RecipientEmailAddress 26 | ,r.CreateChart 27 | FROM [dbo].[ReportSubscriptions] rs 28 | INNER JOIN [dbo].[ReportRecipients] rr ON rs.ReportRecipient = rr.ReportRecipientID 29 | -- get only assigned reports, or all if wildcard is used 30 | INNER JOIN [dbo].[Reports] r ON ((r.ReportID = rs.ReportID) OR ((rs.ReportID IS NULL) AND (r.ReportType NOT LIKE 'Custom%'))) 31 | 32 | -- active reports and recipients 33 | WHERE rs.RecordStatus = 'A' AND rr.RecordStatus = 'A' AND r.RecordStatus = 'A' 34 | -- limit to a specific type 35 | AND r.ReportType = @ReportType 36 | ORDER BY rr.SendingOrder, rr.RecipientName, r.ExecutionOrder; 37 | 38 | END 39 | GO 40 | 41 | 42 | USE [master] 43 | GO 44 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/dbo/uspGetServers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID(N'[dbo].[uspGetServers]') IS NOT NULL 5 | DROP PROCEDURE [dbo].[uspGetServers] 6 | GO 7 | 8 | CREATE PROCEDURE [dbo].[uspGetServers] 9 | @DomainName nvarchar(15) = NULL 10 | AS 11 | BEGIN 12 | SET NOCOUNT ON; 13 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 14 | 15 | -- get the domain name for the login running the stored procedure 16 | IF (NULLIF(@DomainName, '') IS NULL) 17 | SET @DomainName = SUBSTRING(SYSTEM_USER, 1, CHARINDEX('\', SYSTEM_USER, 1)-1); 18 | 19 | SELECT ServerName, SqlTcpPort FROM [dbo].[MonitoredServers] 20 | WHERE [RecordStatus] = 'A' 21 | AND [ServerDomain] LIKE @DomainName 22 | ORDER BY [ServerOrder] ASC, [ServerName] ASC; 23 | END 24 | GO 25 | 26 | 27 | USE [master] 28 | GO 29 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/dbo/uspLogError.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[uspLogError]') AND type in (N'P', N'PC')) 5 | DROP PROCEDURE [dbo].[uspLogError] 6 | GO 7 | 8 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[uspLogError]') AND type in (N'P', N'PC')) 9 | BEGIN 10 | EXEC dbo.sp_executesql @statement = N'CREATE PROCEDURE [dbo].[uspLogError] AS' 11 | END 12 | GO 13 | 14 | 15 | -- uspLogError logs error information in the ErrorLog table about the 16 | -- error that caused execution to jump to the CATCH block of a 17 | -- TRY...CATCH construct. This should be executed from within the scope 18 | -- of a CATCH block otherwise it will return without inserting error 19 | -- information. 20 | ALTER PROCEDURE [dbo].[uspLogError] 21 | @ErrorLogID [int] = 0 OUTPUT -- contains the ErrorLogID of the row inserted 22 | AS -- by uspLogError in the ErrorLog table 23 | BEGIN 24 | SET NOCOUNT ON; 25 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 26 | 27 | -- Output parameter value of 0 indicates that error 28 | -- information was not logged 29 | SET @ErrorLogID = 0; 30 | 31 | BEGIN TRY 32 | -- Return if there is no error information to log 33 | IF ERROR_NUMBER() IS NULL 34 | RETURN; 35 | 36 | -- Return if inside an uncommittable transaction. 37 | -- Data insertion/modification is not allowed when 38 | -- a transaction is in an uncommittable state. 39 | IF XACT_STATE() = -1 40 | BEGIN 41 | PRINT 'Cannot log error since the current transaction is in an uncommittable state. ' 42 | + 'Rollback the transaction before executing uspLogError in order to successfully log error information.'; 43 | RETURN; 44 | END 45 | 46 | INSERT [dbo].[ErrorLog] 47 | ( 48 | [UserName], 49 | [ErrorNumber], 50 | [ErrorSeverity], 51 | [ErrorState], 52 | [ErrorProcedure], 53 | [ErrorLine], 54 | [ErrorMessage] 55 | ) 56 | VALUES 57 | ( 58 | CONVERT(sysname, CURRENT_USER), 59 | ERROR_NUMBER(), 60 | ERROR_SEVERITY(), 61 | ERROR_STATE(), 62 | ERROR_PROCEDURE(), 63 | ERROR_LINE(), 64 | ERROR_MESSAGE() 65 | ); 66 | 67 | -- Pass back the ErrorLogID of the row inserted 68 | SET @ErrorLogID = @@IDENTITY; 69 | END TRY 70 | BEGIN CATCH 71 | PRINT 'An error occurred in stored procedure uspLogError: '; 72 | EXECUTE [dbo].[uspPrintError]; 73 | RETURN -1; 74 | END CATCH 75 | END; 76 | 77 | GO 78 | 79 | 80 | USE [master] 81 | GO 82 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Stored Procedures/dbo/uspPrintError.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[uspPrintError]') AND type in (N'P', N'PC')) 5 | DROP PROCEDURE [dbo].[uspPrintError] 6 | GO 7 | 8 | IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[uspPrintError]') AND type in (N'P', N'PC')) 9 | BEGIN 10 | EXEC dbo.sp_executesql @statement = N'CREATE PROCEDURE [dbo].[uspPrintError] AS' 11 | END 12 | GO 13 | 14 | 15 | -- uspPrintError prints error information about the error that caused 16 | -- execution to jump to the CATCH block of a TRY...CATCH construct. 17 | -- Should be executed from within the scope of a CATCH block otherwise 18 | -- it will return without printing any error information. 19 | ALTER PROCEDURE [dbo].[uspPrintError] 20 | AS 21 | BEGIN 22 | SET NOCOUNT ON; 23 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 24 | 25 | -- Print error information. 26 | PRINT 'Error ' + CONVERT(varchar(50), ERROR_NUMBER()) + 27 | ', Severity ' + CONVERT(varchar(5), ERROR_SEVERITY()) + 28 | ', State ' + CONVERT(varchar(5), ERROR_STATE()) + 29 | ', Procedure ' + ISNULL(ERROR_PROCEDURE(), '-') + 30 | ', Line ' + CONVERT(varchar(5), ERROR_LINE()); 31 | PRINT ERROR_MESSAGE(); 32 | END; 33 | 34 | GO 35 | 36 | 37 | USE [master] 38 | GO 39 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Synonyms/synonyms.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | /* 4 | DROP TABLE [Archive].[DatabaseBackupHistory] 5 | DROP TABLE [Archive].[DatabaseConfigurations] 6 | DROP TABLE [Archive].[DatabaseTables] 7 | DROP TABLE [Archive].[DatabaseUsers] 8 | DROP TABLE [Archive].[IndexUsageStats] 9 | DROP TABLE [Archive].[MissingIndexStats] 10 | DROP TABLE [Archive].[ServerAgentConfig] 11 | DROP TABLE [Archive].[ServerAgentJobs] 12 | DROP TABLE [Archive].[ServerAgentJobsHistory] 13 | DROP TABLE [Archive].[ServerConfigurations] 14 | DROP TABLE [Archive].[ServerDatabases] 15 | DROP TABLE [Archive].[ServerEndpoints] 16 | DROP TABLE [Archive].[ServerErrorLog] 17 | DROP TABLE [Archive].[ServerFreeSpace] 18 | DROP TABLE [Archive].[ServerInfo] 19 | DROP TABLE [Archive].[ServerLogins] 20 | DROP TABLE [Archive].[ServerServers] 21 | DROP TABLE [Archive].[ServerTriggers] 22 | GO 23 | */ 24 | 25 | CREATE SYNONYM [Archive].[DatabaseBackupHistory] FOR [SQLMonitorArchive].[Archive].[DatabaseBackupHistory] 26 | CREATE SYNONYM [Archive].[DatabaseConfigurations] FOR [SQLMonitorArchive].[Archive].[DatabaseConfigurations] 27 | CREATE SYNONYM [Archive].[DatabaseTables] FOR [SQLMonitorArchive].[Archive].[DatabaseTables] 28 | CREATE SYNONYM [Archive].[DatabaseUsers] FOR [SQLMonitorArchive].[Archive].[DatabaseUsers] 29 | CREATE SYNONYM [Archive].[IndexUsageStats] FOR [SQLMonitorArchive].[Archive].[IndexUsageStats] 30 | CREATE SYNONYM [Archive].[MissingIndexStats] FOR [SQLMonitorArchive].[Archive].[MissingIndexStats] 31 | CREATE SYNONYM [Archive].[ServerAgentConfig] FOR [SQLMonitorArchive].[Archive].[ServerAgentConfig] 32 | CREATE SYNONYM [Archive].[ServerAgentJobs] FOR [SQLMonitorArchive].[Archive].[ServerAgentJobs] 33 | CREATE SYNONYM [Archive].[ServerAgentJobsHistory] FOR [SQLMonitorArchive].[Archive].[ServerAgentJobsHistory] 34 | CREATE SYNONYM [Archive].[ServerConfigurations] FOR [SQLMonitorArchive].[Archive].[ServerConfigurations] 35 | CREATE SYNONYM [Archive].[ServerDatabases] FOR [SQLMonitorArchive].[Archive].[ServerDatabases] 36 | CREATE SYNONYM [Archive].[ServerEndpoints] FOR [SQLMonitorArchive].[Archive].[ServerEndpoints] 37 | CREATE SYNONYM [Archive].[ServerErrorLog] FOR [SQLMonitorArchive].[Archive].[ServerErrorLog] 38 | CREATE SYNONYM [Archive].[ServerFreeSpace] FOR [SQLMonitorArchive].[Archive].[ServerFreeSpace] 39 | CREATE SYNONYM [Archive].[ServerInfo] FOR [SQLMonitorArchive].[Archive].[ServerInfo] 40 | CREATE SYNONYM [Archive].[ServerLogins] FOR [SQLMonitorArchive].[Archive].[ServerLogins] 41 | CREATE SYNONYM [Archive].[ServerServers] FOR [SQLMonitorArchive].[Archive].[ServerServers] 42 | CREATE SYNONYM [Archive].[ServerTriggers] FOR [SQLMonitorArchive].[Archive].[ServerTriggers] 43 | GO 44 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/DatabaseBackupHistory.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[DatabaseBackupHistory]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[DatabaseBackupHistory]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[DatabaseBackupHistory]( 11 | [DatabaseBackupHistoryID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [BackupType] [varchar](25) NULL, 15 | [BackupName] [nvarchar](128) NULL, 16 | [LoginName] [nvarchar](128) NULL, 17 | [StartDate] [datetime] NULL, 18 | [FinishDate] [datetime] NULL, 19 | [BackupSizeMB] [decimal](20,2) NULL, 20 | [SourceServer] [nvarchar](128) NULL, 21 | [PhysicalDeviceName] [nvarchar](260) NULL, 22 | [LogicalDeviceName] [nvarchar](128) NULL, 23 | [ExpirationDate] [datetime] NULL, 24 | [Description] [nvarchar](255) NULL, 25 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 26 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 27 | ) ON [TABLES] 28 | GO 29 | 30 | 31 | -- clustered index on DatabaseTableID 32 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[DatabaseBackupHistory]') AND name = N'PK_DatabaseBackupHistory_Archive') 33 | ALTER TABLE [Archive].[DatabaseBackupHistory] 34 | ADD CONSTRAINT [PK_DatabaseBackupHistory_Archive] PRIMARY KEY CLUSTERED ([DatabaseBackupHistoryID] ASC) 35 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 36 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 37 | GO 38 | 39 | 40 | USE [master] 41 | GO 42 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/DatabaseConfigurations.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[DatabaseConfigurations]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[DatabaseConfigurations]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[DatabaseConfigurations]( 11 | [DatabaseConfigID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [FileID] [int] NOT NULL, 15 | [FileType] [nvarchar](60) NOT NULL, 16 | [FileName] [nvarchar](128) NOT NULL, 17 | [FilePath] [nvarchar](260) NOT NULL, 18 | [State] [nvarchar](60) NOT NULL, 19 | [IsReadOnly] [bit] NOT NULL, 20 | [SizeMB] [numeric](15,2) NOT NULL, 21 | [MaxSizeMB] [numeric](15,0) NOT NULL, 22 | [GrowthMB] [numeric](15,0) NOT NULL, 23 | [IsPercentGrowth] [bit] NOT NULL, 24 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 25 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 26 | ) ON [TABLES] 27 | GO 28 | 29 | 30 | -- clustered index on DatabaseConfigID 31 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[DatabaseConfigurations]') AND name = N'PK_DatabaseConfigurations_Archive') 32 | ALTER TABLE [Archive].[DatabaseConfigurations] 33 | ADD CONSTRAINT [PK_DatabaseConfigurations_Archive] PRIMARY KEY CLUSTERED ([DatabaseConfigID] ASC) 34 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 35 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 36 | GO 37 | 38 | 39 | USE [master] 40 | GO 41 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/DatabaseTables.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[DatabaseTables]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[DatabaseTables]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[DatabaseTables]( 11 | [DatabaseTableID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [TableName] [nvarchar](128) NOT NULL, 15 | [RowCount] [bigint] NOT NULL, 16 | [ReservedKB] [bigint] NOT NULL, 17 | [DataSizeKB] [bigint] NOT NULL, 18 | [IndexSizeKB] [bigint] NOT NULL, 19 | [UnusedSpaceKB] [bigint] NOT NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on DatabaseTableID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[DatabaseTables]') AND name = N'PK_DatabaseTables_Archive') 28 | ALTER TABLE [Archive].[DatabaseTables] 29 | ADD CONSTRAINT [PK_DatabaseTables_Archive] PRIMARY KEY CLUSTERED ([DatabaseTableID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | 35 | USE [master] 36 | GO 37 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/DatabaseUsers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[DatabaseUsers]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[DatabaseUsers]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[DatabaseUsers]( 11 | [DatabaseUserID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [PrincipalName] [nvarchar](128) NOT NULL, 15 | [db_accessadmin] [int] NOT NULL, 16 | [db_backupoperator] [int] NOT NULL, 17 | [db_ddladmin] [int] NOT NULL, 18 | [db_owner] [int] NOT NULL, 19 | [db_securityadmin] [int] NOT NULL, 20 | [SecurablesPermissions] [varchar](max) NOT NULL, 21 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 22 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 23 | ) ON [TABLES] TEXTIMAGE_ON [TABLES] 24 | GO 25 | 26 | 27 | -- clustered index on ServerInfoID 28 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[DatabaseUsers]') AND name = N'PK_DatabaseUsers_Archive') 29 | ALTER TABLE [Archive].[DatabaseUsers] 30 | ADD CONSTRAINT [PK_DatabaseUsers_Archive] PRIMARY KEY CLUSTERED ([DatabaseUserID] ASC) 31 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 32 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 33 | GO 34 | 35 | 36 | USE [master] 37 | GO 38 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/IndexUsageStats.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[IndexUsageStats]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[IndexUsageStats]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[IndexUsageStats]( 11 | [IndexUsageStatsID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [ObjectName] [nvarchar](260) NOT NULL, 15 | [IndexID] [int] NOT NULL, 16 | [IndexName] [nvarchar](130) NULL, 17 | [UserSeeks] [bigint] NOT NULL, 18 | [UserScans] [bigint] NOT NULL, 19 | [UserLookups] [bigint] NOT NULL, 20 | [UserUpdates] [bigint] NOT NULL, 21 | [LastPollUserSeeks] [bigint] NOT NULL, 22 | [LastPollUserScans] [bigint] NOT NULL, 23 | [LastPollUserLookups] [bigint] NOT NULL, 24 | [LastPollUserUpdates] [bigint] NOT NULL, 25 | [LastPollDate] [datetime] NOT NULL, 26 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 27 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 28 | ) ON [TABLES]; 29 | 30 | 31 | -- clustered index on IndexUsageStatsID 32 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[IndexUsageStats]') AND name = N'PK_IndexUsageStats_Archive') 33 | ALTER TABLE [Archive].[IndexUsageStats] 34 | ADD CONSTRAINT [PK_IndexUsageStats_Archive] PRIMARY KEY CLUSTERED ([IndexUsageStatsID] ASC) 35 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 36 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 37 | GO 38 | 39 | 40 | USE [master] 41 | GO -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/MissingIndexStats.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[MissingIndexStats]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[MissingIndexStats]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[MissingIndexStats]( 11 | [MissingIndexStatsID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [ObjectName] [nvarchar](260), 15 | [EqualityColumns] [nvarchar](4000) NULL, 16 | [InequalityColumns] [nvarchar](4000) NULL, 17 | [IncludedColumns] [nvarchar](4000) NULL, 18 | [UniqueCompiles] [bigint] NOT NULL, 19 | [UserSeeks] [bigint] NOT NULL, 20 | [UserScans] [bigint] NOT NULL, 21 | [LastPollUniqueCompiles] [bigint] NOT NULL, 22 | [LastPollUserSeeks] [bigint] NOT NULL, 23 | [LastPollUserScans] [bigint] NOT NULL, 24 | [AvgTotalUserCost] [numeric] (15,2) NULL, 25 | [AvgUserImpact] [numeric] (5,2) NULL, 26 | [LastPollDate] [datetime] NOT NULL, 27 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 28 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 29 | ) ON [TABLES]; 30 | 31 | 32 | -- clustered index on MissingIndexStatsID 33 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[MissingIndexStats]') AND name = N'PK_MissingIndexStats_Archive') 34 | ALTER TABLE [Archive].[MissingIndexStats] 35 | ADD CONSTRAINT [PK_MissingIndexStats_Archive] PRIMARY KEY CLUSTERED ([MissingIndexStatsID] ASC) 36 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 37 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 38 | GO 39 | 40 | 41 | USE [master] 42 | GO -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerAgentConfig.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerAgentConfig]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerAgentConfig]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerAgentConfig]( 11 | [ServerAgentConfigID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [AutoStart] [int] NOT NULL, 14 | [StartupAccount] [nvarchar] (128) NOT NULL, 15 | [JobHistoryMaxRows] [int] NOT NULL, 16 | [JobHistoryMaxRowsPerJob] [int] NOT NULL, 17 | [ErrorLogFile] [nvarchar] (255) NOT NULL, 18 | [EmailProfile] [nvarchar] (64) NULL, 19 | [FailSafeOperator] [nvarchar] (255) NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on ServerInfoID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerAgentConfig]') AND name = N'PK_ServerAgentConfig_Archive') 28 | ALTER TABLE [Archive].[ServerAgentConfig] 29 | ADD CONSTRAINT [PK_ServerAgentConfig_Archive] PRIMARY KEY CLUSTERED ([ServerAgentConfigID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | 35 | USE [master] 36 | GO 37 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerAgentJobs.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerAgentJobs]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerAgentJobs]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerAgentJobs]( 11 | [ServerAgentJobsID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [JobID] [uniqueidentifier] NOT NULL, 14 | [JobName] [nvarchar](128) NOT NULL, 15 | [Enabled] [tinyint] NOT NULL, 16 | [JobOwner] [nvarchar](128) NOT NULL, 17 | [DateCreated] [datetime] NOT NULL, 18 | [DateModified] [datetime] NOT NULL, 19 | [JobSteps] [XML] NULL, 20 | [JobSchedules] [XML] NULL, 21 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 22 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 23 | ) ON [TABLES] 24 | GO 25 | 26 | 27 | -- clustered index on ServerInfoID 28 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerAgentJobs]') AND name = N'PK_ServerAgentJobs_Archive') 29 | ALTER TABLE [Archive].[ServerAgentJobs] 30 | ADD CONSTRAINT [PK_ServerAgentJobs_Archive] PRIMARY KEY CLUSTERED ([ServerAgentJobsID] ASC) 31 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 32 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 33 | GO 34 | 35 | 36 | USE [master] 37 | GO 38 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerAgentJobsHistory.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerAgentJobsHistory]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerAgentJobsHistory]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerAgentJobsHistory]( 11 | [ServerAgentJobsHistoryID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [JobID] [uniqueidentifier] NOT NULL, 14 | [JobName] [nvarchar](128) NOT NULL, 15 | [StepID] [int] NOT NULL, 16 | [StepName] [nvarchar](128) NOT NULL, 17 | [LastRunTime] [datetime] NULL, 18 | [RunStatus] [int] NOT NULL, 19 | [Message] [nvarchar](4000) NOT NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on ServerInfoID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerAgentJobsHistory]') AND name = N'PK_ServerAgentJobsHistory_Archive') 28 | ALTER TABLE [Archive].[ServerAgentJobsHistory] 29 | ADD CONSTRAINT [PK_ServerAgentJobsHistory_Archive] PRIMARY KEY CLUSTERED ([ServerAgentJobsHistoryID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | 35 | 36 | USE [master] 37 | GO 38 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerConfigurations.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerConfigurations]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerConfigurations]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerConfigurations]( 11 | [ServerConfigID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [ConfigID] [int] NOT NULL, 14 | [ConfigName] [nvarchar](255) NOT NULL, 15 | [ValueSet] [int] NOT NULL, 16 | [ValueInUse] [int] NOT NULL, 17 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 18 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 19 | ) ON [TABLES] 20 | GO 21 | 22 | 23 | -- clustered index on ServerInfoID 24 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerConfigurations]') AND name = N'PK_ServerConfigurations_Archive') 25 | ALTER TABLE [Archive].[ServerConfigurations] 26 | ADD CONSTRAINT [PK_ServerConfigurations_Archive] PRIMARY KEY CLUSTERED ([ServerConfigID] ASC) 27 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 28 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 29 | GO 30 | 31 | 32 | USE [master] 33 | GO 34 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerDatabases.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerDatabases]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerDatabases]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerDatabases]( 11 | [ServerDatabaseID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [DatabaseOwner] [nvarchar](128) NOT NULL, 15 | [CreateDate] [datetime] NOT NULL, 16 | [CompatibilityLevel] [tinyint] NOT NULL, 17 | [CollationName] [nvarchar](128) NOT NULL, 18 | [UserAccess] [nvarchar](60) NOT NULL, 19 | [IsReadOnly] [bit] NOT NULL, 20 | [IsAutoClose] [bit] NOT NULL, 21 | [IsAutoShrink] [bit] NOT NULL, 22 | [State] [nvarchar](60) NOT NULL, 23 | [IsInStandby] [bit] NOT NULL, 24 | [RecoveryModel] [nvarchar](60) NOT NULL, 25 | [PageVerifyOption] [nvarchar](60) NOT NULL, 26 | [IsFullTextEnabled] [bit] NOT NULL, 27 | [IsTrustworthy] [bit] NOT NULL, 28 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 29 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 30 | ) ON [TABLES] 31 | GO 32 | 33 | 34 | -- clustered index on ServerDatabaseID 35 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerDatabases]') AND name = N'PK_ServerDatabases_Archive') 36 | ALTER TABLE [Archive].[ServerDatabases] 37 | ADD CONSTRAINT [PK_ServerDatabases_Archive] PRIMARY KEY CLUSTERED ([ServerDatabaseID] ASC) 38 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 39 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 40 | GO 41 | 42 | 43 | USE [master] 44 | GO 45 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerEndpoints.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerEndpoints]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerEndpoints]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerEndpoints]( 11 | [ServerEndpointID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [EndpointName] [nvarchar](128) NOT NULL, 14 | [Owner] [nvarchar](128) NOT NULL, 15 | [ProtocolDesc] [nvarchar](60) NOT NULL, 16 | [PayloadType] [nvarchar](60) NOT NULL, 17 | [StateDesc] [nvarchar](60) NOT NULL, 18 | [IsAdminEndpoint] [bit] NOT NULL, 19 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 20 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 21 | ) ON [TABLES] 22 | GO 23 | 24 | 25 | -- clustered index on ServerInfoID 26 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerEndpoints]') AND name = N'PK_ServerEndpoints_Archive') 27 | ALTER TABLE [Archive].[ServerEndpoints] 28 | ADD CONSTRAINT [PK_ServerEndpoints_Archive] PRIMARY KEY CLUSTERED ([ServerEndpointID] ASC) 29 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 30 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 31 | GO 32 | 33 | 34 | USE [master] 35 | GO 36 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerErrorLog.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerErrorLog]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerErrorLog]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerErrorLog]( 11 | [ServerErrorLogID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [LogDate] [datetime] NOT NULL, 14 | [ProcessInfo] [nvarchar](128) NOT NULL, 15 | [LogText] [varchar](max) NOT NULL, 16 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 17 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 18 | ) ON [TABLES] TEXTIMAGE_ON [TABLES] 19 | GO 20 | 21 | 22 | -- clustered index on ServerInfoID 23 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerErrorLog]') AND name = N'PK_ServerErrorLog_Archive') 24 | ALTER TABLE [Archive].[ServerErrorLog] 25 | ADD CONSTRAINT [PK_ServerErrorLog_Archive] PRIMARY KEY CLUSTERED ([ServerErrorLogID] ASC) 26 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 27 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 28 | GO 29 | 30 | 31 | USE [master] 32 | GO 33 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerFreeSpace.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerFreeSpace]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerFreeSpace]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerFreeSpace]( 11 | [ServerFreeSpaceID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [Drive] [char](1) NOT NULL, 14 | [FreeMB] [int] NOT NULL, 15 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 16 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 17 | ) ON [TABLES] 18 | GO 19 | 20 | 21 | -- clustered index on ServerInfoID 22 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerFreeSpace]') AND name = N'PK_ServerFreeSpace_Archive') 23 | ALTER TABLE [Archive].[ServerFreeSpace] 24 | ADD CONSTRAINT [PK_ServerFreeSpace_Archive] PRIMARY KEY CLUSTERED ([ServerFreeSpaceID] ASC) 25 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 26 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 27 | GO 28 | 29 | 30 | USE [master] 31 | GO 32 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerInfo.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerInfo]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerInfo]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerInfo]( 11 | [ServerInfoID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [ProductVersion] [nvarchar](128) NOT NULL, 14 | [ProductLevel] [nvarchar](128) NOT NULL, 15 | [ResourceLastUpdateDateTime] [datetime] NOT NULL, 16 | [ResourceVersion] [nvarchar](128) NOT NULL, 17 | [ServerAuthentication] [varchar](22) NOT NULL, 18 | [Edition] [nvarchar](128) NOT NULL, 19 | [InstanceName] [nvarchar](128) NOT NULL, 20 | [ComputerNamePhysicalNetBIOS] [nvarchar](128) NOT NULL, 21 | [BuildClrVersion] [nvarchar](128) NOT NULL, 22 | [Collation] [nvarchar](128) NOT NULL, 23 | [IsClustered] [bit] NOT NULL, 24 | [IsFullTextInstalled] [bit] NOT NULL, 25 | [SqlCharSetName] [nvarchar](128) NOT NULL, 26 | [SqlSortOrderName] [nvarchar](128) NOT NULL, 27 | [SqlRootPath] nvarchar(512) NOT NULL, 28 | [Product] nvarchar(128) NOT NULL, 29 | [Language] nvarchar(128) NOT NULL, 30 | [Platform] nvarchar(128) NOT NULL, 31 | [LogicalProcessors] [int] NOT NULL, 32 | [OSVersion] nvarchar(128) NOT NULL, 33 | [TotalMemoryMB] [int] NOT NULL, 34 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 35 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 36 | ) ON [TABLES] 37 | GO 38 | 39 | 40 | -- clustered index on ServerInfoID 41 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerInfo]') AND name = N'PK_ServerInfo_Archive') 42 | ALTER TABLE [Archive].[ServerInfo] 43 | ADD CONSTRAINT [PK_ServerInfo_Archive] PRIMARY KEY CLUSTERED ([ServerInfoID] ASC) 44 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 45 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 46 | GO 47 | 48 | 49 | USE [master] 50 | GO 51 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerLogins.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerLogins]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerLogins]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerLogins]( 11 | [ServerLoginID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [LoginName] [nvarchar](128) NOT NULL, 14 | [Type] [nvarchar](60) NOT NULL, 15 | [CreateDate] [datetime] NOT NULL, 16 | [ModifyDate] [datetime] NOT NULL, 17 | [PasswordLastSet] [datetime] NULL, 18 | [DefaultDatabase] [nvarchar](128) NOT NULL, 19 | [DefaultLanguage] [nvarchar](128) NOT NULL, 20 | [IsDisabled] [bit] NOT NULL, 21 | [IsPolicyChecked] [int] NOT NULL, 22 | [IsExpirationChecked] [int] NOT NULL, 23 | [sysadmin] [int] NOT NULL, 24 | [securityadmin] [int] NOT NULL, 25 | [serveradmin] [int] NOT NULL, 26 | [setupadmin] [int] NOT NULL, 27 | [processadmin] [int] NOT NULL, 28 | [diskadmin] [int] NOT NULL, 29 | [dbcreator] [int] NOT NULL, 30 | [bulkadmin] [int] NOT NULL, 31 | [SecurablesPermissions] [varchar](max) NOT NULL, 32 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 33 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 34 | ) ON [TABLES] TEXTIMAGE_ON [TABLES] 35 | GO 36 | 37 | 38 | -- clustered index on ServerInfoID 39 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerLogins]') AND name = N'PK_ServerLogins_Archive') 40 | ALTER TABLE [Archive].[ServerLogins] 41 | ADD CONSTRAINT [PK_ServerLogins_Archive] PRIMARY KEY CLUSTERED ([ServerLoginID] ASC) 42 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 43 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 44 | GO 45 | 46 | 47 | USE [master] 48 | GO 49 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerServers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerServers]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerServers]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerServers]( 11 | [ServerServerID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [ServerID] [int] NOT NULL, 14 | [LinkedServer] [nvarchar](128) NOT NULL, 15 | [ProductName] [nvarchar](128) NOT NULL, 16 | [ProviderName] [nvarchar](128) NOT NULL, 17 | [DataSource] [nvarchar](400) NULL, 18 | [ProviderString] [nvarchar](400) NULL, 19 | [CatalogConnection] [nvarchar](128) NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on ServerInfoID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerServers]') AND name = N'PK_ServerServers_Archive') 28 | ALTER TABLE [Archive].[ServerServers] 29 | ADD CONSTRAINT [PK_ServerServers_Archive] PRIMARY KEY CLUSTERED ([ServerServerID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | 35 | USE [master] 36 | GO 37 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Archive/ServerTriggers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF OBJECT_ID('[Archive].[ServerTriggers]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Archive].[ServerTriggers]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Archive].[ServerTriggers]( 11 | [ServerTriggerID] [int] NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [ObjectName] [nvarchar](128) NOT NULL, 14 | [ObjectType] [nvarchar](60) NOT NULL, 15 | [CreateDate] [datetime] NOT NULL, 16 | [ModifyDate] [datetime] NOT NULL, 17 | [IsDisabled] [bit] NOT NULL, 18 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 19 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 20 | ) ON [TABLES] 21 | GO 22 | 23 | 24 | -- clustered index on ServerInfoID 25 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Archive].[ServerTriggers]') AND name = N'PK_ServerTriggers_Archive') 26 | ALTER TABLE [Archive].[ServerTriggers] 27 | ADD CONSTRAINT [PK_ServerTriggers_Archive] PRIMARY KEY CLUSTERED ([ServerTriggerID] ASC) 28 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 29 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 30 | GO 31 | 32 | 33 | USE [master] 34 | GO 35 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/BlitzResults.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[BlitzResults]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[BlitzResults]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[BlitzResults] ( 11 | [BlitzResultID] INT IDENTITY(-2147483648, 1) NOT NULL , 12 | [ServerName] NVARCHAR(128) , 13 | [Priority] TINYINT , 14 | [FindingsGroup] VARCHAR(50) , 15 | [Finding] VARCHAR(200) , 16 | [DatabaseName] NVARCHAR(128) , 17 | [URL] VARCHAR(200) , 18 | [Details] NVARCHAR(4000) , 19 | [QueryPlan] [XML] NULL , 20 | [QueryPlanFiltered] [NVARCHAR](MAX) NULL , 21 | [CheckID] INT , 22 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 23 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 24 | ) ON [TABLES] 25 | GO 26 | 27 | 28 | -- clustered index on DatabaseTableID 29 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[BlitzResults]') AND name = N'PK_BlitzResults') 30 | ALTER TABLE [Monitor].[BlitzResults] 31 | ADD CONSTRAINT [PK_BlitzResults] PRIMARY KEY CLUSTERED ([BlitzResultID] ASC) 32 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 33 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 34 | GO 35 | 36 | -- indexes created for performance 37 | CREATE NONCLUSTERED INDEX [IX_BlitzResults_ServerName] 38 | ON [Monitor].[BlitzResults] ([ServerName]) 39 | WITH ( 40 | PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, 41 | DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90 42 | ) 43 | GO 44 | 45 | -- default constraint on RecordStatus = "A" 46 | ALTER TABLE [Monitor].[BlitzResults] ADD CONSTRAINT 47 | DF_BlitzResults_RecordStatus DEFAULT 'A' FOR RecordStatus 48 | GO 49 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 50 | ALTER TABLE [Monitor].[BlitzResults] ADD CONSTRAINT 51 | CK_BlitzResults_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 52 | GO 53 | 54 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 55 | ALTER TABLE [Monitor].[BlitzResults] ADD CONSTRAINT 56 | DF_BlitzResults_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 57 | GO 58 | 59 | 60 | USE [master] 61 | GO 62 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/DatabaseBackupHistory.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[DatabaseBackupHistory]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[DatabaseBackupHistory]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[DatabaseBackupHistory]( 11 | [DatabaseBackupHistoryID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [BackupType] [varchar](25) NULL, 15 | [BackupName] [nvarchar](128) NULL, 16 | [LoginName] [nvarchar](128) NULL, 17 | [StartDate] [datetime] NULL, 18 | [FinishDate] [datetime] NULL, 19 | [BackupSizeMB] [decimal](20,2) NULL, 20 | [SourceServer] [nvarchar](128) NULL, 21 | [PhysicalDeviceName] [nvarchar](260) NULL, 22 | [LogicalDeviceName] [nvarchar](128) NULL, 23 | [ExpirationDate] [datetime] NULL, 24 | [Description] [nvarchar](255) NULL, 25 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 26 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 27 | ) ON [TABLES] 28 | GO 29 | 30 | 31 | -- clustered index on DatabaseTableID 32 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[DatabaseBackupHistory]') AND name = N'PK_DatabaseBackupHistory') 33 | ALTER TABLE [Monitor].[DatabaseBackupHistory] 34 | ADD CONSTRAINT [PK_DatabaseBackupHistory] PRIMARY KEY CLUSTERED ([DatabaseBackupHistoryID] ASC) 35 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 36 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 37 | GO 38 | 39 | -- indexes created for performance 40 | CREATE NONCLUSTERED INDEX [IX_DatabaseBackupHistory_ServerName] 41 | ON [Monitor].[DatabaseBackupHistory] ([ServerName]) 42 | INCLUDE ([StartDate]) 43 | WITH ( 44 | PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, 45 | DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90 46 | ) 47 | GO 48 | 49 | -- default constraint on RecordStatus = "A" 50 | ALTER TABLE [Monitor].[DatabaseBackupHistory] ADD CONSTRAINT 51 | DF_DatabaseBackupHistory_RecordStatus DEFAULT 'A' FOR RecordStatus 52 | GO 53 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 54 | ALTER TABLE [Monitor].[DatabaseBackupHistory] ADD CONSTRAINT 55 | CK_DatabaseBackupHistory_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 56 | GO 57 | 58 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 59 | ALTER TABLE [Monitor].[DatabaseBackupHistory] ADD CONSTRAINT 60 | DF_DatabaseBackupHistory_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 61 | GO 62 | 63 | 64 | USE [master] 65 | GO 66 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/DatabaseConfigurations.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[DatabaseConfigurations]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[DatabaseConfigurations]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[DatabaseConfigurations]( 11 | [DatabaseConfigID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [FileID] [int] NOT NULL, 15 | [FileType] [nvarchar](60) NOT NULL, 16 | [FileName] [nvarchar](128) NOT NULL, 17 | [FilePath] [nvarchar](260) NOT NULL, 18 | [State] [nvarchar](60) NOT NULL, 19 | [IsReadOnly] [bit] NOT NULL, 20 | [SizeMB] [numeric](15,2) NOT NULL, 21 | [MaxSizeMB] [numeric](15,0) NOT NULL, 22 | [GrowthMB] [numeric](15,0) NOT NULL, 23 | [IsPercentGrowth] [bit] NOT NULL, 24 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 25 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 26 | ) ON [TABLES] 27 | GO 28 | 29 | 30 | -- clustered index on DatabaseConfigID 31 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[DatabaseConfigurations]') AND name = N'PK_DatabaseConfigurations') 32 | ALTER TABLE [Monitor].[DatabaseConfigurations] 33 | ADD CONSTRAINT [PK_DatabaseConfigurations] PRIMARY KEY CLUSTERED ([DatabaseConfigID] ASC) 34 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 35 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 36 | GO 37 | 38 | 39 | -- default constraint on RecordStatus = "A" 40 | ALTER TABLE [Monitor].[DatabaseConfigurations] ADD CONSTRAINT 41 | DF_DatabaseConfigurations_RecordStatus DEFAULT 'A' FOR RecordStatus 42 | GO 43 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 44 | ALTER TABLE [Monitor].[DatabaseConfigurations] ADD CONSTRAINT 45 | CK_DatabaseConfigurations_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 46 | GO 47 | 48 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 49 | ALTER TABLE [Monitor].[DatabaseConfigurations] ADD CONSTRAINT 50 | DF_DatabaseConfigurations_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 51 | GO 52 | 53 | 54 | USE [master] 55 | GO 56 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/DatabaseTableColumns.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[DatabaseTableColumns]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[DatabaseTableColumns]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[DatabaseTableColumns]( 11 | [DatabaseTableColumnID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [TableSchema] [nvarchar](128) NOT NULL, 15 | [TableName] [nvarchar](128) NOT NULL, 16 | [ColumnName] [nvarchar](128) NOT NULL, 17 | [OrdinalPosition] [int] NOT NULL, 18 | [DataType] [nvarchar](128) NULL, 19 | [LengthOrPrecision] [nvarchar](128) NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on DatabaseTableID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[DatabaseTableColumns]') AND name = N'PK_DatabaseTableColumns') 28 | ALTER TABLE [Monitor].[DatabaseTableColumns] 29 | ADD CONSTRAINT [PK_DatabaseTableColumns] PRIMARY KEY CLUSTERED ([DatabaseTableColumnID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | 35 | -- default constraint on RecordStatus = "A" 36 | ALTER TABLE [Monitor].[DatabaseTableColumns] ADD CONSTRAINT 37 | DF_DatabaseTableColumns_RecordStatus DEFAULT 'A' FOR RecordStatus 38 | GO 39 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 40 | ALTER TABLE [Monitor].[DatabaseTableColumns] ADD CONSTRAINT 41 | CK_DatabaseTableColumns_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 42 | GO 43 | 44 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 45 | ALTER TABLE [Monitor].[DatabaseTableColumns] ADD CONSTRAINT 46 | DF_DatabaseTableColumns_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 47 | GO 48 | 49 | 50 | USE [master] 51 | GO 52 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/DatabaseTables.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[DatabaseTables]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[DatabaseTables]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[DatabaseTables]( 11 | [DatabaseTableID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [TableName] [nvarchar](128) NOT NULL, 15 | [RowCount] [bigint] NOT NULL, 16 | [ReservedKB] [bigint] NOT NULL, 17 | [DataSizeKB] [bigint] NOT NULL, 18 | [IndexSizeKB] [bigint] NOT NULL, 19 | [UnusedSpaceKB] [bigint] NOT NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on DatabaseTableID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[DatabaseTables]') AND name = N'PK_DatabaseTables') 28 | ALTER TABLE [Monitor].[DatabaseTables] 29 | ADD CONSTRAINT [PK_DatabaseTables] PRIMARY KEY CLUSTERED ([DatabaseTableID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | 35 | -- default constraint on RecordStatus = "A" 36 | ALTER TABLE [Monitor].[DatabaseTables] ADD CONSTRAINT 37 | DF_DatabaseTables_RecordStatus DEFAULT 'A' FOR RecordStatus 38 | GO 39 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 40 | ALTER TABLE [Monitor].[DatabaseTables] ADD CONSTRAINT 41 | CK_DatabaseTables_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 42 | GO 43 | 44 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 45 | ALTER TABLE [Monitor].[DatabaseTables] ADD CONSTRAINT 46 | DF_DatabaseTables_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 47 | GO 48 | 49 | 50 | USE [master] 51 | GO 52 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/DatabaseUsers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[DatabaseUsers]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[DatabaseUsers]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[DatabaseUsers]( 11 | [DatabaseUserID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [PrincipalName] [nvarchar](128) NOT NULL, 15 | [db_accessadmin] [int] NOT NULL, 16 | [db_backupoperator] [int] NOT NULL, 17 | [db_ddladmin] [int] NOT NULL, 18 | [db_owner] [int] NOT NULL, 19 | [db_securityadmin] [int] NOT NULL, 20 | [SecurablesPermissions] [varchar](max) NOT NULL, 21 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 22 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 23 | ) ON [TABLES] TEXTIMAGE_ON [TABLES] 24 | GO 25 | 26 | 27 | -- clustered index on ServerInfoID 28 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[DatabaseUsers]') AND name = N'PK_DatabaseUsers') 29 | ALTER TABLE [Monitor].[DatabaseUsers] 30 | ADD CONSTRAINT [PK_DatabaseUsers] PRIMARY KEY CLUSTERED ([DatabaseUserID] ASC) 31 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 32 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 33 | GO 34 | 35 | 36 | -- default constraint on RecordStatus = "A" 37 | ALTER TABLE [Monitor].[DatabaseUsers] ADD CONSTRAINT 38 | DF_DatabaseUsers_RecordStatus DEFAULT 'A' FOR RecordStatus 39 | GO 40 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 41 | ALTER TABLE [Monitor].[DatabaseUsers] ADD CONSTRAINT 42 | CK_DatabaseUsers_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 43 | GO 44 | 45 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 46 | ALTER TABLE [Monitor].[DatabaseUsers] ADD CONSTRAINT 47 | DF_DatabaseUsers_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 48 | GO 49 | 50 | 51 | USE [master] 52 | GO 53 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/IndexUsageStats.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[IndexUsageStats]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[IndexUsageStats]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[IndexUsageStats]( 11 | [IndexUsageStatsID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [ObjectName] [nvarchar](260) NOT NULL, 15 | [IndexID] [int] NOT NULL, 16 | [IndexName] [nvarchar](130) NULL, 17 | [UserSeeks] [bigint] NOT NULL, 18 | [UserScans] [bigint] NOT NULL, 19 | [UserLookups] [bigint] NOT NULL, 20 | [UserUpdates] [bigint] NOT NULL, 21 | [LastPollUserSeeks] [bigint] NOT NULL, 22 | [LastPollUserScans] [bigint] NOT NULL, 23 | [LastPollUserLookups] [bigint] NOT NULL, 24 | [LastPollUserUpdates] [bigint] NOT NULL, 25 | [LastPollDate] [datetime] NOT NULL, 26 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 27 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 28 | ) ON [TABLES]; 29 | 30 | 31 | -- clustered index on IndexUsageStatsID 32 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[IndexUsageStats]') AND name = N'PK_IndexUsageStats') 33 | ALTER TABLE [Monitor].[IndexUsageStats] 34 | ADD CONSTRAINT [PK_IndexUsageStats] PRIMARY KEY CLUSTERED ([IndexUsageStatsID] ASC) 35 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 36 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 37 | GO 38 | 39 | 40 | -- default constraint on RecordStatus = "A" 41 | ALTER TABLE [Monitor].[IndexUsageStats] ADD CONSTRAINT 42 | DF_IndexUsageStats_RecordStatus DEFAULT 'A' FOR RecordStatus 43 | GO 44 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 45 | ALTER TABLE [Monitor].[IndexUsageStats] ADD CONSTRAINT 46 | CK_IndexUsageStats_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 47 | GO 48 | 49 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 50 | ALTER TABLE [Monitor].[IndexUsageStats] ADD CONSTRAINT 51 | DF_IndexUsageStats_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 52 | GO 53 | 54 | 55 | USE [master] 56 | GO -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/MissingIndexStats.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[MissingIndexStats]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[MissingIndexStats]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[MissingIndexStats]( 11 | [MissingIndexStatsID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [ObjectName] [nvarchar](260), 15 | [EqualityColumns] [nvarchar](4000) NULL, 16 | [InequalityColumns] [nvarchar](4000) NULL, 17 | [IncludedColumns] [nvarchar](4000) NULL, 18 | [UniqueCompiles] [bigint] NOT NULL, 19 | [UserSeeks] [bigint] NOT NULL, 20 | [UserScans] [bigint] NOT NULL, 21 | [LastPollUniqueCompiles] [bigint] NOT NULL, 22 | [LastPollUserSeeks] [bigint] NOT NULL, 23 | [LastPollUserScans] [bigint] NOT NULL, 24 | [AvgTotalUserCost] [numeric] (15,2) NULL, 25 | [AvgUserImpact] [numeric] (5,2) NULL, 26 | [LastPollDate] [datetime] NOT NULL, 27 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 28 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 29 | ) ON [TABLES]; 30 | 31 | 32 | -- clustered index on MissingIndexStatsID 33 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[MissingIndexStats]') AND name = N'PK_MissingIndexStats') 34 | ALTER TABLE [Monitor].[MissingIndexStats] 35 | ADD CONSTRAINT [PK_MissingIndexStats] PRIMARY KEY CLUSTERED ([MissingIndexStatsID] ASC) 36 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 37 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 38 | GO 39 | 40 | 41 | -- default constraint on RecordStatus = "A" 42 | ALTER TABLE [Monitor].[MissingIndexStats] ADD CONSTRAINT 43 | DF_MissingIndexStats_RecordStatus DEFAULT 'A' FOR RecordStatus 44 | GO 45 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 46 | ALTER TABLE [Monitor].[MissingIndexStats] ADD CONSTRAINT 47 | CK_MissingIndexStats_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 48 | GO 49 | 50 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 51 | ALTER TABLE [Monitor].[MissingIndexStats] ADD CONSTRAINT 52 | DF_MissingIndexStats_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 53 | GO 54 | 55 | 56 | USE [master] 57 | GO -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerAgentConfig.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerAgentConfig]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerAgentConfig]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerAgentConfig]( 11 | [ServerAgentConfigID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [AutoStart] [int] NOT NULL, 14 | [StartupAccount] [nvarchar] (128) NOT NULL, 15 | [JobHistoryMaxRows] [int] NOT NULL, 16 | [JobHistoryMaxRowsPerJob] [int] NOT NULL, 17 | [ErrorLogFile] [nvarchar] (255) NOT NULL, 18 | [EmailProfile] [nvarchar] (64) NULL, 19 | [FailSafeOperator] [nvarchar] (255) NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on ServerInfoID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerAgentConfig]') AND name = N'PK_ServerAgentConfig') 28 | ALTER TABLE [Monitor].[ServerAgentConfig] 29 | ADD CONSTRAINT [PK_ServerAgentConfig] PRIMARY KEY CLUSTERED ([ServerAgentConfigID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | 35 | -- default constraint on RecordStatus = "A" 36 | ALTER TABLE [Monitor].[ServerAgentConfig] ADD CONSTRAINT 37 | DF_ServerAgentConfig_RecordStatus DEFAULT 'A' FOR RecordStatus 38 | GO 39 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 40 | ALTER TABLE [Monitor].[ServerAgentConfig] ADD CONSTRAINT 41 | CK_ServerAgentConfig_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 42 | GO 43 | 44 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 45 | ALTER TABLE [Monitor].[ServerAgentConfig] ADD CONSTRAINT 46 | DF_ServerAgentConfig_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 47 | GO 48 | 49 | 50 | USE [master] 51 | GO 52 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerAgentJobs.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerAgentJobs]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerAgentJobs]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerAgentJobs]( 11 | [ServerAgentJobsID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [JobID] [uniqueidentifier] NOT NULL, 14 | [JobName] [nvarchar](128) NOT NULL, 15 | [Enabled] [tinyint] NOT NULL, 16 | [JobOwner] [nvarchar](128) NOT NULL, 17 | [DateCreated] [datetime] NOT NULL, 18 | [DateModified] [datetime] NOT NULL, 19 | [JobSteps] [XML] NULL, 20 | [JobSchedules] [XML] NULL, 21 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 22 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 23 | ) ON [TABLES] 24 | GO 25 | 26 | 27 | -- clustered index on ServerInfoID 28 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerAgentJobs]') AND name = N'PK_ServerAgentJobs') 29 | ALTER TABLE [Monitor].[ServerAgentJobs] 30 | ADD CONSTRAINT [PK_ServerAgentJobs] PRIMARY KEY CLUSTERED ([ServerAgentJobsID] ASC) 31 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 32 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 33 | GO 34 | 35 | 36 | -- default constraint on RecordStatus = "A" 37 | ALTER TABLE [Monitor].[ServerAgentJobs] ADD CONSTRAINT 38 | DF_ServerAgentJobs_RecordStatus DEFAULT 'A' FOR RecordStatus 39 | GO 40 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 41 | ALTER TABLE [Monitor].[ServerAgentJobs] ADD CONSTRAINT 42 | CK_ServerAgentJobs_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 43 | GO 44 | 45 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 46 | ALTER TABLE [Monitor].[ServerAgentJobs] ADD CONSTRAINT 47 | DF_ServerAgentJobs_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 48 | GO 49 | 50 | 51 | USE [master] 52 | GO 53 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerAgentJobsHistory.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerAgentJobsHistory]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerAgentJobsHistory]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerAgentJobsHistory]( 11 | [ServerAgentJobsHistoryID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [JobID] [uniqueidentifier] NOT NULL, 14 | [JobName] [nvarchar](128) NOT NULL, 15 | [StepID] [int] NOT NULL, 16 | [StepName] [nvarchar](128) NOT NULL, 17 | [LastRunTime] [datetime] NULL, 18 | [RunStatus] [int] NOT NULL, 19 | [Message] [nvarchar](4000) NOT NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on ServerInfoID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerAgentJobsHistory]') AND name = N'PK_ServerAgentJobsHistory') 28 | ALTER TABLE [Monitor].[ServerAgentJobsHistory] 29 | ADD CONSTRAINT [PK_ServerAgentJobsHistory] PRIMARY KEY CLUSTERED ([ServerAgentJobsHistoryID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | -- indexes created for performance 35 | CREATE NONCLUSTERED INDEX [IX_ServerAgentJobsHistory_ServerName] 36 | ON [Monitor].[ServerAgentJobsHistory] ([ServerName], [RecordStatus]) 37 | INCLUDE ([LastRunTime], [RecordCreated]) 38 | WITH ( 39 | PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, 40 | DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90 41 | ) 42 | GO 43 | 44 | CREATE NONCLUSTERED INDEX [IX_ServerAgentJobsHistory_LastRunTime_RunStatus] 45 | ON [Monitor].[ServerAgentJobsHistory] ([LastRunTime],[RunStatus]) 46 | INCLUDE ([ServerName],[JobName],[StepID],[StepName]) 47 | WITH ( 48 | PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, 49 | DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100 50 | ) 51 | GO 52 | 53 | -- default constraint on RecordStatus = "A" 54 | ALTER TABLE [Monitor].[ServerAgentJobsHistory] ADD CONSTRAINT 55 | DF_ServerAgentJobsHistory_RecordStatus DEFAULT 'A' FOR RecordStatus 56 | GO 57 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 58 | ALTER TABLE [Monitor].[ServerAgentJobsHistory] ADD CONSTRAINT 59 | CK_ServerAgentJobsHistory_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 60 | GO 61 | 62 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 63 | ALTER TABLE [Monitor].[ServerAgentJobsHistory] ADD CONSTRAINT 64 | DF_ServerAgentJobsHistory_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 65 | GO 66 | 67 | 68 | USE [master] 69 | GO 70 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerConfigurations.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerConfigurations]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerConfigurations]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerConfigurations]( 11 | [ServerConfigID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [ConfigID] [int] NOT NULL, 14 | [ConfigName] [nvarchar](255) NOT NULL, 15 | [ValueSet] [int] NOT NULL, 16 | [ValueInUse] [int] NOT NULL, 17 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 18 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 19 | ) ON [TABLES] 20 | GO 21 | 22 | 23 | -- clustered index on ServerInfoID 24 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerConfigurations]') AND name = N'PK_ServerConfigurations') 25 | ALTER TABLE [Monitor].[ServerConfigurations] 26 | ADD CONSTRAINT [PK_ServerConfigurations] PRIMARY KEY CLUSTERED ([ServerConfigID] ASC) 27 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 28 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 29 | GO 30 | 31 | 32 | -- default constraint on RecordStatus = "A" 33 | ALTER TABLE [Monitor].[ServerConfigurations] ADD CONSTRAINT 34 | DF_ServerConfigurations_RecordStatus DEFAULT 'A' FOR RecordStatus 35 | GO 36 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 37 | ALTER TABLE [Monitor].[ServerConfigurations] ADD CONSTRAINT 38 | CK_ServerConfigurations_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 39 | GO 40 | 41 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 42 | ALTER TABLE [Monitor].[ServerConfigurations] ADD CONSTRAINT 43 | DF_ServerConfigurations_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 44 | GO 45 | 46 | 47 | USE [master] 48 | GO 49 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerDatabases.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerDatabases]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerDatabases]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerDatabases]( 11 | [ServerDatabaseID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [DatabaseName] [nvarchar](128) NOT NULL, 14 | [DatabaseOwner] [nvarchar](128) NOT NULL, 15 | [CreateDate] [datetime] NOT NULL, 16 | [CompatibilityLevel] [tinyint] NOT NULL, 17 | [CollationName] [nvarchar](128) NOT NULL, 18 | [UserAccess] [nvarchar](60) NOT NULL, 19 | [IsReadOnly] [bit] NOT NULL, 20 | [IsAutoClose] [bit] NOT NULL, 21 | [IsAutoShrink] [bit] NOT NULL, 22 | [State] [nvarchar](60) NOT NULL, 23 | [IsInStandby] [bit] NOT NULL, 24 | [RecoveryModel] [nvarchar](60) NOT NULL, 25 | [PageVerifyOption] [nvarchar](60) NOT NULL, 26 | [IsFullTextEnabled] [bit] NOT NULL, 27 | [IsTrustworthy] [bit] NOT NULL, 28 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 29 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 30 | ) ON [TABLES] 31 | GO 32 | 33 | 34 | -- clustered index on ServerDatabaseID 35 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerDatabases]') AND name = N'PK_ServerDatabases') 36 | ALTER TABLE [Monitor].[ServerDatabases] 37 | ADD CONSTRAINT [PK_ServerDatabases] PRIMARY KEY CLUSTERED ([ServerDatabaseID] ASC) 38 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 39 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 40 | GO 41 | 42 | 43 | -- default constraint on RecordStatus = "A" 44 | ALTER TABLE [Monitor].[ServerDatabases] ADD CONSTRAINT 45 | DF_ServerDatabases_RecordStatus DEFAULT 'A' FOR RecordStatus 46 | GO 47 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 48 | ALTER TABLE [Monitor].[ServerDatabases] ADD CONSTRAINT 49 | CK_ServerDatabases_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 50 | GO 51 | 52 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 53 | ALTER TABLE [Monitor].[ServerDatabases] ADD CONSTRAINT 54 | DF_ServerDatabases_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 55 | GO 56 | 57 | 58 | USE [master] 59 | GO 60 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerEndpoints.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerEndpoints]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerEndpoints]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerEndpoints]( 11 | [ServerEndpointID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [EndpointName] [nvarchar](128) NOT NULL, 14 | [Owner] [nvarchar](128) NOT NULL, 15 | [ProtocolDesc] [nvarchar](60) NOT NULL, 16 | [PayloadType] [nvarchar](60) NOT NULL, 17 | [StateDesc] [nvarchar](60) NOT NULL, 18 | [IsAdminEndpoint] [bit] NOT NULL, 19 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 20 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 21 | ) ON [TABLES] 22 | GO 23 | 24 | 25 | -- clustered index on ServerInfoID 26 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerEndpoints]') AND name = N'PK_ServerEndpoints') 27 | ALTER TABLE [Monitor].[ServerEndpoints] 28 | ADD CONSTRAINT [PK_ServerEndpoints] PRIMARY KEY CLUSTERED ([ServerEndpointID] ASC) 29 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 30 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 31 | GO 32 | 33 | 34 | -- default constraint on RecordStatus = "A" 35 | ALTER TABLE [Monitor].[ServerEndpoints] ADD CONSTRAINT 36 | DF_ServerEndpoints_RecordStatus DEFAULT 'A' FOR RecordStatus 37 | GO 38 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 39 | ALTER TABLE [Monitor].[ServerEndpoints] ADD CONSTRAINT 40 | CK_ServerEndpoints_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 41 | GO 42 | 43 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 44 | ALTER TABLE [Monitor].[ServerEndpoints] ADD CONSTRAINT 45 | DF_ServerEndpoints_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 46 | GO 47 | 48 | 49 | USE [master] 50 | GO 51 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerErrorLog.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerErrorLog]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerErrorLog]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerErrorLog]( 11 | [ServerErrorLogID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [LogDate] [datetime] NOT NULL, 14 | [ProcessInfo] [nvarchar](128) NOT NULL, 15 | [LogText] [varchar](max) NOT NULL, 16 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 17 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 18 | ) ON [TABLES] TEXTIMAGE_ON [TABLES] 19 | GO 20 | 21 | 22 | -- clustered index on ServerInfoID 23 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerErrorLog]') AND name = N'PK_ServerErrorLog') 24 | ALTER TABLE [Monitor].[ServerErrorLog] 25 | ADD CONSTRAINT [PK_ServerErrorLog] PRIMARY KEY CLUSTERED ([ServerErrorLogID] ASC) 26 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 27 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 28 | GO 29 | 30 | -- indexes created for performance 31 | CREATE NONCLUSTERED INDEX [IX_ServerErrorLog_ServerName_RecordStatus] 32 | ON [Monitor].[ServerErrorLog] ([ServerName] ASC, [RecordStatus] ASC) 33 | INCLUDE ([RecordCreated], [LogDate]) 34 | WITH ( 35 | PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, 36 | ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100 37 | ) ON [TABLES] 38 | GO 39 | 40 | 41 | -- default constraint on RecordStatus = "A" 42 | ALTER TABLE [Monitor].[ServerErrorLog] ADD CONSTRAINT 43 | DF_ServerErrorLog_RecordStatus DEFAULT 'A' FOR RecordStatus 44 | GO 45 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 46 | ALTER TABLE [Monitor].[ServerErrorLog] ADD CONSTRAINT 47 | CK_ServerErrorLog_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 48 | GO 49 | 50 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 51 | ALTER TABLE [Monitor].[ServerErrorLog] ADD CONSTRAINT 52 | DF_ServerErrorLog_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 53 | GO 54 | 55 | 56 | USE [master] 57 | GO 58 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerFreeSpace.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerFreeSpace]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerFreeSpace]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerFreeSpace]( 11 | [ServerFreeSpaceID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [Drive] [char](1) NOT NULL, 14 | [FreeMB] [int] NOT NULL, 15 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 16 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 17 | ) ON [TABLES] 18 | GO 19 | 20 | 21 | -- clustered index on ServerInfoID 22 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerFreeSpace]') AND name = N'PK_ServerFreeSpace') 23 | ALTER TABLE [Monitor].[ServerFreeSpace] 24 | ADD CONSTRAINT [PK_ServerFreeSpace] PRIMARY KEY CLUSTERED ([ServerFreeSpaceID] ASC) 25 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 26 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 27 | GO 28 | 29 | 30 | -- default constraint on RecordStatus = "A" 31 | ALTER TABLE [Monitor].[ServerFreeSpace] ADD CONSTRAINT 32 | DF_ServerFreeSpace_RecordStatus DEFAULT 'A' FOR RecordStatus 33 | GO 34 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 35 | ALTER TABLE [Monitor].[ServerFreeSpace] ADD CONSTRAINT 36 | CK_ServerFreeSpace_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 37 | GO 38 | 39 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 40 | ALTER TABLE [Monitor].[ServerFreeSpace] ADD CONSTRAINT 41 | DF_ServerFreeSpace_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 42 | GO 43 | 44 | 45 | USE [master] 46 | GO 47 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerInfo.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerInfo]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerInfo]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerInfo]( 11 | [ServerInfoID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [ProductVersion] [nvarchar](128) NOT NULL, 14 | [ProductLevel] [nvarchar](128) NOT NULL, 15 | [ResourceLastUpdateDateTime] [datetime] NOT NULL, 16 | [ResourceVersion] [nvarchar](128) NOT NULL, 17 | [ServerAuthentication] [varchar](22) NOT NULL, 18 | [Edition] [nvarchar](128) NOT NULL, 19 | [InstanceName] [nvarchar](128) NOT NULL, 20 | [ComputerNamePhysicalNetBIOS] [nvarchar](128) NOT NULL, 21 | [BuildClrVersion] [nvarchar](128) NOT NULL, 22 | [Collation] [nvarchar](128) NOT NULL, 23 | [IsClustered] [bit] NOT NULL, 24 | [IsFullTextInstalled] [bit] NOT NULL, 25 | [SqlCharSetName] [nvarchar](128) NOT NULL, 26 | [SqlSortOrderName] [nvarchar](128) NOT NULL, 27 | [SqlRootPath] nvarchar(512) NOT NULL, 28 | [Product] nvarchar(128) NOT NULL, 29 | [Language] nvarchar(128) NOT NULL, 30 | [Platform] nvarchar(128) NOT NULL, 31 | [LogicalProcessors] [int] NOT NULL, 32 | [OSVersion] nvarchar(128) NOT NULL, 33 | [TotalMemoryMB] [int] NOT NULL, 34 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 35 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 36 | ) ON [TABLES] 37 | GO 38 | 39 | 40 | -- clustered index on ServerInfoID 41 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerInfo]') AND name = N'PK_ServerInfo') 42 | ALTER TABLE [Monitor].[ServerInfo] 43 | ADD CONSTRAINT [PK_ServerInfo] PRIMARY KEY CLUSTERED ([ServerInfoID] ASC) 44 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 45 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 46 | GO 47 | 48 | 49 | -- default constraint on RecordStatus = "A" 50 | ALTER TABLE [Monitor].[ServerInfo] ADD CONSTRAINT 51 | DF_ServerInfo_RecordStatus DEFAULT 'A' FOR RecordStatus 52 | GO 53 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 54 | ALTER TABLE [Monitor].[ServerInfo] ADD CONSTRAINT 55 | CK_ServerInfo_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 56 | GO 57 | 58 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 59 | ALTER TABLE [Monitor].[ServerInfo] ADD CONSTRAINT 60 | DF_ServerInfo_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 61 | GO 62 | 63 | 64 | USE [master] 65 | GO 66 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerLogins.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerLogins]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerLogins]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerLogins]( 11 | [ServerLoginID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [LoginName] [nvarchar](128) NOT NULL, 14 | [Type] [nvarchar](60) NOT NULL, 15 | [CreateDate] [datetime] NOT NULL, 16 | [ModifyDate] [datetime] NOT NULL, 17 | [PasswordLastSet] [datetime] NULL, 18 | [DefaultDatabase] [nvarchar](128) NOT NULL, 19 | [DefaultLanguage] [nvarchar](128) NOT NULL, 20 | [IsDisabled] [bit] NOT NULL, 21 | [IsPolicyChecked] [int] NOT NULL, 22 | [IsExpirationChecked] [int] NOT NULL, 23 | [sysadmin] [int] NOT NULL, 24 | [securityadmin] [int] NOT NULL, 25 | [serveradmin] [int] NOT NULL, 26 | [setupadmin] [int] NOT NULL, 27 | [processadmin] [int] NOT NULL, 28 | [diskadmin] [int] NOT NULL, 29 | [dbcreator] [int] NOT NULL, 30 | [bulkadmin] [int] NOT NULL, 31 | [SecurablesPermissions] [varchar](max) NOT NULL, 32 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 33 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 34 | ) ON [TABLES] TEXTIMAGE_ON [TABLES] 35 | GO 36 | 37 | 38 | -- clustered index on ServerInfoID 39 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerLogins]') AND name = N'PK_ServerLogins') 40 | ALTER TABLE [Monitor].[ServerLogins] 41 | ADD CONSTRAINT [PK_ServerLogins] PRIMARY KEY CLUSTERED ([ServerLoginID] ASC) 42 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 43 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 44 | GO 45 | 46 | 47 | -- default constraint on RecordStatus = "A" 48 | ALTER TABLE [Monitor].[ServerLogins] ADD CONSTRAINT 49 | DF_ServerLogins_RecordStatus DEFAULT 'A' FOR RecordStatus 50 | GO 51 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 52 | ALTER TABLE [Monitor].[ServerLogins] ADD CONSTRAINT 53 | CK_ServerLogins_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 54 | GO 55 | 56 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 57 | ALTER TABLE [Monitor].[ServerLogins] ADD CONSTRAINT 58 | DF_ServerLogins_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 59 | GO 60 | 61 | 62 | USE [master] 63 | GO 64 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerServers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerServers]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerServers]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerServers]( 11 | [ServerServerID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [ServerID] [int] NOT NULL, 14 | [LinkedServer] [nvarchar](128) NOT NULL, 15 | [ProductName] [nvarchar](128) NOT NULL, 16 | [ProviderName] [nvarchar](128) NOT NULL, 17 | [DataSource] [nvarchar](400) NULL, 18 | [ProviderString] [nvarchar](400) NULL, 19 | [CatalogConnection] [nvarchar](128) NULL, 20 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 21 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 22 | ) ON [TABLES] 23 | GO 24 | 25 | 26 | -- clustered index on ServerInfoID 27 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerServers]') AND name = N'PK_ServerServers') 28 | ALTER TABLE [Monitor].[ServerServers] 29 | ADD CONSTRAINT [PK_ServerServers] PRIMARY KEY CLUSTERED ([ServerServerID] ASC) 30 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 31 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 32 | GO 33 | 34 | 35 | -- default constraint on RecordStatus = "A" 36 | ALTER TABLE [Monitor].[ServerServers] ADD CONSTRAINT 37 | DF_ServerServers_RecordStatus DEFAULT 'A' FOR RecordStatus 38 | GO 39 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 40 | ALTER TABLE [Monitor].[ServerServers] ADD CONSTRAINT 41 | CK_ServerServers_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 42 | GO 43 | 44 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 45 | ALTER TABLE [Monitor].[ServerServers] ADD CONSTRAINT 46 | DF_ServerServers_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 47 | GO 48 | 49 | 50 | USE [master] 51 | GO 52 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/Monitor/ServerTriggers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[ServerTriggers]') IS NOT NULL 5 | BEGIN 6 | DROP TABLE [Monitor].[ServerTriggers]; 7 | END 8 | GO 9 | 10 | CREATE TABLE [Monitor].[ServerTriggers]( 11 | [ServerTriggerID] [int] IDENTITY(-2147483648,1) NOT NULL, 12 | [ServerName] [nvarchar](128) NOT NULL, 13 | [ObjectName] [nvarchar](128) NOT NULL, 14 | [ObjectType] [nvarchar](60) NOT NULL, 15 | [CreateDate] [datetime] NOT NULL, 16 | [ModifyDate] [datetime] NOT NULL, 17 | [IsDisabled] [bit] NOT NULL, 18 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 19 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 20 | ) ON [TABLES] 21 | GO 22 | 23 | 24 | -- clustered index on ServerInfoID 25 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[Monitor].[ServerTriggers]') AND name = N'PK_ServerTriggers') 26 | ALTER TABLE [Monitor].[ServerTriggers] 27 | ADD CONSTRAINT [PK_ServerTriggers] PRIMARY KEY CLUSTERED ([ServerTriggerID] ASC) 28 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 29 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 30 | GO 31 | 32 | 33 | -- default constraint on RecordStatus = "A" 34 | ALTER TABLE [Monitor].[ServerTriggers] ADD CONSTRAINT 35 | DF_ServerTriggers_RecordStatus DEFAULT 'A' FOR RecordStatus 36 | GO 37 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 38 | ALTER TABLE [Monitor].[ServerTriggers] ADD CONSTRAINT 39 | CK_ServerTriggers_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 40 | GO 41 | 42 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 43 | ALTER TABLE [Monitor].[ServerTriggers] ADD CONSTRAINT 44 | DF_ServerTriggers_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 45 | GO 46 | 47 | 48 | USE [master] 49 | GO 50 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/DatabaseLog.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF EXISTS (SELECT * FROM sys.triggers WHERE parent_class_desc = 'DATABASE' AND name = N'ddlDatabaseTriggerLog') 5 | DISABLE TRIGGER [ddlDatabaseTriggerLog] ON DATABASE 6 | GO 7 | 8 | IF OBJECT_ID('[dbo].[DatabaseLog]') IS NOT NULL 9 | DROP TABLE [dbo].[DatabaseLog] 10 | GO 11 | 12 | CREATE TABLE [dbo].[DatabaseLog]( 13 | [DatabaseLogID] [int] IDENTITY(-2147483648,1) NOT NULL, 14 | [PostTime] [datetime] NOT NULL, 15 | [DatabaseUser] [sysname] COLLATE Latin1_General_CI_AS NOT NULL, 16 | [Event] [sysname] COLLATE Latin1_General_CI_AS NOT NULL, 17 | [Schema] [sysname] COLLATE Latin1_General_CI_AS NULL, 18 | [Object] [sysname] COLLATE Latin1_General_CI_AS NULL, 19 | [TSQL] [nvarchar](max) COLLATE Latin1_General_CI_AS NOT NULL, 20 | [XmlEvent] [xml] NOT NULL 21 | ) ON [TABLES] 22 | GO 23 | 24 | -- clustered index on DatabaseLogID 25 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[DatabaseLog]') AND name = N'PK_DatabaseLog') 26 | ALTER TABLE [dbo].[DatabaseLog] 27 | ADD CONSTRAINT [PK_DatabaseLog] PRIMARY KEY CLUSTERED ([DatabaseLogID] ASC) 28 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 29 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 30 | GO 31 | 32 | -- default constraint on PostTime = CURRENT_TIMESTAMP 33 | ALTER TABLE [dbo].[DatabaseLog] ADD CONSTRAINT 34 | [DF_DatabaseLog_PostTime] DEFAULT (CURRENT_TIMESTAMP) FOR [PostTime] 35 | GO 36 | 37 | 38 | USE [master] 39 | GO 40 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/DatabaseLog_Archive.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitorArchive] 2 | GO 3 | 4 | IF EXISTS (SELECT * FROM sys.triggers WHERE parent_class_desc = 'DATABASE' AND name = N'ddlDatabaseTriggerLog') 5 | DISABLE TRIGGER [ddlDatabaseTriggerLog] ON DATABASE 6 | GO 7 | 8 | IF OBJECT_ID('[dbo].[DatabaseLog]') IS NOT NULL 9 | DROP TABLE [dbo].[DatabaseLog] 10 | GO 11 | 12 | CREATE TABLE [dbo].[DatabaseLog]( 13 | [DatabaseLogID] [int] IDENTITY(-2147483648,1) NOT NULL, 14 | [PostTime] [datetime] NOT NULL, 15 | [DatabaseUser] [sysname] COLLATE Latin1_General_CI_AS NOT NULL, 16 | [Event] [sysname] COLLATE Latin1_General_CI_AS NOT NULL, 17 | [Schema] [sysname] COLLATE Latin1_General_CI_AS NULL, 18 | [Object] [sysname] COLLATE Latin1_General_CI_AS NULL, 19 | [TSQL] [nvarchar](max) COLLATE Latin1_General_CI_AS NOT NULL, 20 | [XmlEvent] [xml] NOT NULL 21 | ) ON [TABLES] 22 | GO 23 | 24 | -- clustered index on DatabaseLogID 25 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[DatabaseLog]') AND name = N'PK_DatabaseLog') 26 | ALTER TABLE [dbo].[DatabaseLog] 27 | ADD CONSTRAINT [PK_DatabaseLog] PRIMARY KEY CLUSTERED ([DatabaseLogID] ASC) 28 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 29 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 30 | GO 31 | 32 | -- default constraint on PostTime = CURRENT_TIMESTAMP 33 | ALTER TABLE [dbo].[DatabaseLog] ADD CONSTRAINT 34 | [DF_DatabaseLog_PostTime] DEFAULT (CURRENT_TIMESTAMP) FOR [PostTime] 35 | GO 36 | 37 | 38 | USE [master] 39 | GO 40 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/ErrorLog.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[dbo].[ErrorLog]') IS NOT NULL 5 | DROP TABLE [dbo].[ErrorLog] 6 | GO 7 | 8 | CREATE TABLE [dbo].[ErrorLog] ( 9 | [ErrorLogID] [int] IDENTITY(-2147483648,1) NOT NULL, 10 | [ErrorTime] [datetime] NOT NULL, 11 | [UserName] [sysname] COLLATE Latin1_General_CI_AS NOT NULL, 12 | [ErrorNumber] [int] NOT NULL, 13 | [ErrorSeverity] [int] NULL, 14 | [ErrorState] [int] NULL, 15 | [ErrorProcedure] [nvarchar](126) COLLATE Latin1_General_CI_AS NULL, 16 | [ErrorLine] [int] NULL, 17 | [ErrorMessage] [nvarchar](4000) COLLATE Latin1_General_CI_AS NOT NULL 18 | ) ON [TABLES] 19 | GO 20 | 21 | -- clustered index on ErrorLogID 22 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[ErrorLog]') AND name = N'PK_ErrorLog') 23 | ALTER TABLE [dbo].[ErrorLog] 24 | ADD CONSTRAINT [PK_ErrorLog] PRIMARY KEY CLUSTERED ([ErrorLogID] ASC) 25 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 26 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 27 | GO 28 | 29 | -- default constraint on ErrorTime = CURRENT_TIMESTAMP 30 | ALTER TABLE [dbo].[ErrorLog] ADD CONSTRAINT 31 | [DF_ErrorLog_ErrorTime] DEFAULT (CURRENT_TIMESTAMP) FOR [ErrorTime] 32 | GO 33 | 34 | 35 | USE [master] 36 | GO 37 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/MonitoredServers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[dbo].[MonitoredServers]') IS NOT NULL 5 | DROP TABLE [dbo].[MonitoredServers]; 6 | GO 7 | 8 | CREATE TABLE [dbo].[MonitoredServers] ( 9 | [ServerId] [int] IDENTITY(1,1) NOT NULL, -- unique identifier 10 | [ServerName] [nvarchar] (128) NOT NULL, -- server name 11 | [ServerAlias] [nvarchar] (128) NULL, -- server alias (for servers which have been set up incorrectly) 12 | [ServerDescription] [varchar] (500) NULL, -- short description 13 | [ServerIpAddress] [varchar] (20) NOT NULL, -- server ip address 14 | [SqlTcpPort] [int] NOT NULL, -- instance listening port used for data collection 15 | [ServerDomain] [nvarchar] (15) NOT NULL, -- the server domain name 16 | [ServerOrder] [smallint] NOT NULL, -- result set ordering - used to define a specific order how servers are processed 17 | [SqlVersion] [numeric] (6, 2) NULL, -- dbms version - may have to be used for version-specific scripts 18 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if server will be processed or not 19 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 20 | ) ON [TABLES] 21 | GO 22 | 23 | 24 | -- clustered index on ServerId 25 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[MonitoredServers]') AND name = N'PK_MonitoredServers') 26 | ALTER TABLE [dbo].[MonitoredServers] 27 | ADD CONSTRAINT [PK_MonitoredServers] PRIMARY KEY CLUSTERED ([ServerId] ASC) 28 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 29 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 30 | GO 31 | 32 | -- unique constraint on ServerName AND TcpPort 33 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[MonitoredServers]') AND name = N'IX_MonitoredServers_ServerName') 34 | CREATE UNIQUE NONCLUSTERED INDEX [IX_MonitoredServers_ServerName_TcpPort] 35 | ON [dbo].[MonitoredServers] ([ServerName] ASC, [SqlTcpPort] ASC) 36 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, DROP_EXISTING = OFF, ONLINE = OFF, 37 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [TABLES] 38 | GO 39 | 40 | -- unique constraint on ServerIpAddress AND TcpPort 41 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[MonitoredServers]') AND name = N'IX_MonitoredServers_ServerIpAddress') 42 | CREATE UNIQUE NONCLUSTERED INDEX [IX_MonitoredServers_ServerIpAddress_TcpPort] 43 | ON [dbo].[MonitoredServers] ([ServerIpAddress] ASC, [SqlTcpPort] ASC) 44 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, DROP_EXISTING = OFF, ONLINE = OFF, 45 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [TABLES] 46 | GO 47 | 48 | -- default constraint on ServerOrder = "0" 49 | ALTER TABLE dbo.MonitoredServers ADD CONSTRAINT 50 | DF_MonitoredServers_ServerOrder DEFAULT 0 FOR ServerOrder 51 | GO 52 | 53 | -- default constraint on RecordStatus = "A" 54 | ALTER TABLE dbo.MonitoredServers ADD CONSTRAINT 55 | DF_MonitoredServers_RecordStatus DEFAULT 'A' FOR RecordStatus 56 | GO 57 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 58 | ALTER TABLE dbo.MonitoredServers ADD CONSTRAINT 59 | CK_MonitoredServers_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 60 | GO 61 | 62 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 63 | ALTER TABLE dbo.MonitoredServers ADD CONSTRAINT 64 | DF_MonitoredServers_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 65 | GO 66 | 67 | -- TODO: create trigger firing when RecordStatus is set to "D" 68 | 69 | 70 | USE [master] 71 | GO 72 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/Profile.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[dbo].[Profile]') IS NOT NULL 5 | DROP TABLE [dbo].[Profile]; 6 | GO 7 | 8 | CREATE TABLE [dbo].[Profile] ( 9 | [ProfileID] [int] IDENTITY(1,1) NOT NULL, 10 | [ProfileName] [varchar](50) NOT NULL, -- equivalent to the destination schema name 11 | [ScriptName] [nvarchar](255) NOT NULL, -- equivalent to the destination table name 12 | [ProfileType] [varchar](50) NOT NULL, -- defines execution schedule: Manual, Recurrent, Daily, Weekly, Monthly 13 | [PreExecuteScript] [nvarchar](4000) NOT NULL, -- optional: script which should be run before every iteration of the main script; used to retrieve single values which can then be used in the main script. 14 | [ExecuteScript] nvarchar(max) NOT NULL, -- the actual script which will be executed with each iteration - if empty, the script file will be used instead 15 | [ExecutionOrder] [tinyint] NOT NULL DEFAULT(0), 16 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 17 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 18 | ) ON [TABLES] 19 | GO 20 | 21 | 22 | -- clustered index on ProfileID 23 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[Profile]') AND name = N'PK_Profile') 24 | ALTER TABLE [dbo].[Profile] 25 | ADD CONSTRAINT [PK_Profile] PRIMARY KEY CLUSTERED ([ProfileID] ASC) 26 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 27 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 28 | GO 29 | 30 | 31 | -- default constraint on RecordStatus = "A" 32 | ALTER TABLE [dbo].[Profile] ADD CONSTRAINT 33 | DF_Profile_RecordStatus DEFAULT 'A' FOR RecordStatus 34 | GO 35 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 36 | ALTER TABLE [dbo].[Profile] ADD CONSTRAINT 37 | CK_Profile_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 38 | GO 39 | 40 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 41 | ALTER TABLE [dbo].[Profile] ADD CONSTRAINT 42 | DF_Profile_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 43 | GO 44 | 45 | -- default constraint on PreExecuteScript = "" 46 | ALTER TABLE [dbo].[Profile] ADD CONSTRAINT 47 | DF_Profile_PreExecuteScript DEFAULT N'' FOR [PreExecuteScript] 48 | GO 49 | 50 | -- default constraint on ExecuteScript = "" 51 | ALTER TABLE [dbo].[Profile] ADD CONSTRAINT 52 | DF_Profile_ExecuteScript DEFAULT N'' FOR [ExecuteScript] 53 | GO 54 | 55 | 56 | USE [master] 57 | GO 58 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/ReportRecipients.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[dbo].[ReportRecipients]') IS NOT NULL 5 | DROP TABLE [dbo].[ReportRecipients]; 6 | GO 7 | 8 | CREATE TABLE [dbo].[ReportRecipients] ( 9 | [ReportRecipientID] [int] IDENTITY(1,1) NOT NULL, 10 | [RecipientName] [varchar](50) NOT NULL, 11 | [RecipientEmailAddress] [varchar](65) NOT NULL, 12 | [SendingOrder] [tinyint] NOT NULL DEFAULT(0), 13 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 14 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 15 | ) ON [TABLES] 16 | GO 17 | 18 | 19 | -- clustered index on ProfileID 20 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[ReportRecipients]') AND name = N'PK_ReportRecipient') 21 | ALTER TABLE [dbo].[ReportRecipients] 22 | ADD CONSTRAINT [PK_ReportRecipient] PRIMARY KEY CLUSTERED ([ReportRecipientID] ASC) 23 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 24 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 25 | GO 26 | 27 | -- nonclustered index on ReportID and RecipientEmailAddress to enforce uniqueness 28 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[ReportRecipients]') AND name = N'IDX_ReportRecipients_EmailAddress') 29 | CREATE UNIQUE NONCLUSTERED INDEX [IDX_ReportRecipients_EmailAddress] 30 | ON [dbo].[ReportRecipients] ( [RecipientEmailAddress] ASC ) 31 | WITH ( 32 | PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, 33 | ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 34 | GO 35 | 36 | 37 | -- check constraint on RecipientEmailAddress - allowed values are properly formed company email addresses 38 | ALTER TABLE [dbo].[ReportRecipients] ADD CONSTRAINT 39 | CK_ReportRecipient_RecipientEmailAddress CHECK (RecipientEmailAddress NOT LIKE '%[^a-z,0-9,@,.]%' 40 | -- AND RecipientEmailAddress LIKE '%_@mycompany.com' 41 | ) 42 | GO 43 | 44 | -- default constraint on RecordStatus = "A" 45 | ALTER TABLE [dbo].[ReportRecipients] ADD CONSTRAINT 46 | DF_ReportRecipient_RecordStatus DEFAULT 'A' FOR RecordStatus 47 | GO 48 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 49 | ALTER TABLE [dbo].[ReportRecipients] ADD CONSTRAINT 50 | CK_ReportRecipient_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 51 | GO 52 | 53 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 54 | ALTER TABLE [dbo].[ReportRecipients] ADD CONSTRAINT 55 | DF_ReportRecipient_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 56 | GO 57 | 58 | 59 | USE [master] 60 | GO 61 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/ReportSubscriptions.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[dbo].[ReportSubscriptions]') IS NOT NULL 5 | DROP TABLE [dbo].[ReportSubscriptions]; 6 | GO 7 | 8 | CREATE TABLE [dbo].[ReportSubscriptions] ( 9 | [ReportSubscriptionID] [int] IDENTITY(1,1) NOT NULL, 10 | [ReportRecipient] [int] NOT NULL, 11 | [ReportID] [int] NULL, -- can be NULL to represent "all reports" option 12 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 13 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 14 | ) ON [TABLES] 15 | GO 16 | 17 | 18 | -- clustered index on ProfileID 19 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[ReportSubscriptions]') AND name = N'PK_ReportSubscription') 20 | ALTER TABLE [dbo].[ReportSubscriptions] 21 | ADD CONSTRAINT [PK_ReportSubscription] PRIMARY KEY CLUSTERED ([ReportSubscriptionID] ASC) 22 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 23 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 24 | GO 25 | 26 | -- default constraint on RecordStatus = "A" 27 | ALTER TABLE [dbo].[ReportSubscriptions] ADD CONSTRAINT 28 | DF_ReportSubscription_RecordStatus DEFAULT 'A' FOR RecordStatus 29 | GO 30 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 31 | ALTER TABLE [dbo].[ReportSubscriptions] ADD CONSTRAINT 32 | CK_ReportSubscription_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 33 | GO 34 | 35 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 36 | ALTER TABLE [dbo].[ReportSubscriptions] ADD CONSTRAINT 37 | DF_ReportSubscription_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 38 | GO 39 | 40 | 41 | USE [master] 42 | GO 43 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/Reports.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[dbo].[Reports]') IS NOT NULL 5 | DROP TABLE [dbo].[Reports]; 6 | GO 7 | 8 | CREATE TABLE [dbo].[Reports] ( 9 | [ReportID] [int] IDENTITY(1,1) NOT NULL, 10 | [ReportName] [varchar](100) NOT NULL, -- the actual report name as it will appear on the output 11 | [ReportType] [varchar](50) NOT NULL, -- defines execution schedule: Monthly, Weekly, Daily, Manual, Custom Monthly, Custom Weekly, Custom Daily 12 | [PreExecuteScript] [nvarchar](4000) NOT NULL, -- optional: script which should be run before every iteration of the main script; used to retrieve single values which can then be used in the main script. 13 | [ExecuteScript] nvarchar(max) NOT NULL, -- the actual script which will be executed with each iteration - if empty, the script file will be used instead 14 | [ExecutionOrder] [tinyint] NOT NULL DEFAULT(0), 15 | [CreateChart] [bit] NOT NULL DEFAULT(0), -- flag to instruct PowerShell to create a chart with the results - requires a specific output format 16 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 17 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 18 | ) ON [TABLES] 19 | GO 20 | 21 | 22 | -- clustered index on ReportID 23 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[Reports]') AND name = N'PK_Report') 24 | ALTER TABLE [dbo].[Reports] 25 | ADD CONSTRAINT [PK_Report] PRIMARY KEY CLUSTERED ([ReportID] ASC) 26 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 27 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 28 | GO 29 | 30 | 31 | -- default constraint on RecordStatus = "A" 32 | ALTER TABLE [dbo].[Reports] ADD CONSTRAINT 33 | DF_Report_RecordStatus DEFAULT 'A' FOR RecordStatus 34 | GO 35 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 36 | ALTER TABLE [dbo].[Reports] ADD CONSTRAINT 37 | CK_Report_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 38 | GO 39 | 40 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 41 | ALTER TABLE [dbo].[Reports] ADD CONSTRAINT 42 | DF_Report_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 43 | GO 44 | 45 | -- default constraint on PreExecuteScript = "" 46 | ALTER TABLE [dbo].[Reports] ADD CONSTRAINT 47 | DF_Report_PreExecuteScript DEFAULT N'' FOR [PreExecuteScript] 48 | GO 49 | 50 | -- default constraint on ExecuteScript = "" 51 | ALTER TABLE [dbo].[Reports] ADD CONSTRAINT 52 | DF_Report_ExecuteScript DEFAULT N'' FOR [ExecuteScript] 53 | GO 54 | 55 | 56 | USE [master] 57 | GO 58 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Tables/dbo/SystemParams.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[dbo].[SystemParams]') IS NOT NULL 5 | DROP TABLE [dbo].[SystemParams] 6 | GO 7 | 8 | CREATE TABLE [dbo].[SystemParams] ( 9 | [ParamID] [int] IDENTITY(1,1) NOT NULL, 10 | [ParamName] [nvarchar] (128) COLLATE Latin1_General_CI_AS NOT NULL, 11 | [ParamValue] [nvarchar] (4000) COLLATE Latin1_General_CI_AS NOT NULL, 12 | [ParamDescription] [nvarchar] (4000) COLLATE Latin1_General_CI_AS NOT NULL, 13 | [RecordStatus] [char] (1) NOT NULL, -- record status - used to determine if the record is active or not 14 | [RecordCreated] [datetime2] (0) NOT NULL -- audit timestamp storing the date and time the record was created (is additional detail necessary?) 15 | ) ON [TABLES] 16 | GO 17 | 18 | -- clustered index on ParamID 19 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[SystemParams]') AND name = N'PK_SystemParams') 20 | ALTER TABLE [dbo].[SystemParams] 21 | ADD CONSTRAINT [PK_SystemParams] PRIMARY KEY CLUSTERED ([ParamID] ASC) 22 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, IGNORE_DUP_KEY = OFF, ONLINE = OFF, 23 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 100) ON [TABLES] 24 | GO 25 | 26 | -- default constraint on RecordStatus = "A" 27 | ALTER TABLE [dbo].[SystemParams] ADD CONSTRAINT 28 | DF_SystemParams_RecordStatus DEFAULT 'A' FOR RecordStatus 29 | GO 30 | -- check constraint on RecordStatus - allowed values "A", "D", "H" 31 | ALTER TABLE [dbo].[SystemParams] ADD CONSTRAINT 32 | CK_SystemParams_RecordStatus CHECK (RecordStatus LIKE '[ADH]') 33 | GO 34 | 35 | -- default constraint on RecordCreated = CURRENT_TIMESTAMP 36 | ALTER TABLE [dbo].[SystemParams] ADD CONSTRAINT 37 | DF_SystemParams_RecordCreated DEFAULT CURRENT_TIMESTAMP FOR RecordCreated 38 | GO 39 | 40 | -- unique constraint on ParamName 41 | IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE object_id = OBJECT_ID(N'[dbo].[SystemParams]') AND name = N'IX_SystemParams_ParamName') 42 | CREATE UNIQUE NONCLUSTERED INDEX [IX_SystemParams_ParamName] 43 | ON [dbo].[SystemParams] ([ParamName] ASC) 44 | WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = ON, DROP_EXISTING = OFF, ONLINE = OFF, 45 | ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [TABLES] 46 | GO 47 | 48 | 49 | USE [master] 50 | GO 51 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/blitz_results.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[blitz_results]') IS NOT NULL 5 | DROP VIEW [Monitor].[blitz_results] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[blitz_results] 9 | AS 10 | SELECT 11 | [ServerName] 12 | ,[Priority] 13 | ,[FindingsGroup] 14 | ,[Finding] 15 | ,[DatabaseName] 16 | ,[URL] 17 | ,[Details] 18 | ,[QueryPlan] 19 | ,[QueryPlanFiltered] 20 | ,[CheckID] 21 | ,[RecordStatus] 22 | ,[RecordCreated] 23 | FROM [Monitor].[BlitzResults] 24 | GO 25 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/database_backup_history.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[database_backup_history]') IS NOT NULL 5 | DROP VIEW [Monitor].[database_backup_history] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[database_backup_history] 9 | AS 10 | SELECT [ServerName] 11 | ,[DatabaseName] 12 | ,[BackupType] 13 | ,[BackupName] 14 | ,[LoginName] 15 | ,[StartDate] 16 | ,[FinishDate] 17 | ,[BackupSizeMB] 18 | ,[SourceServer] 19 | ,[PhysicalDeviceName] 20 | ,[LogicalDeviceName] 21 | ,[ExpirationDate] 22 | ,[Description] 23 | ,[RecordStatus] 24 | ,[RecordCreated] 25 | FROM [Monitor].[DatabaseBackupHistory] 26 | --WHERE [RecordStatus] = 'A' 27 | GO 28 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/database_configurations.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[database_configurations]') IS NOT NULL 5 | DROP VIEW [Monitor].[database_configurations] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[database_configurations] 9 | AS 10 | SELECT [ServerName] 11 | ,[DatabaseName] 12 | ,[FileID] 13 | ,[FileType] 14 | ,[FileName] 15 | ,[FilePath] 16 | ,[State] 17 | ,[IsReadOnly] 18 | ,[SizeMB] 19 | ,[MaxSizeMB] 20 | ,[GrowthMB] 21 | ,[IsPercentGrowth] 22 | ,[RecordStatus] 23 | ,[RecordCreated] 24 | FROM [Monitor].[DatabaseConfigurations] 25 | -- WHERE [RecordStatus] = 'A' 26 | GO 27 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/database_indexusagestats.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[database_indexusagestats]') IS NOT NULL 5 | DROP VIEW [Monitor].[database_indexusagestats] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[database_indexusagestats] 9 | AS 10 | SELECT [ServerName] 11 | ,[DatabaseName] 12 | ,[ObjectName] 13 | ,[IndexID] 14 | ,[IndexName] 15 | ,[UserSeeks] 16 | ,[UserScans] 17 | ,[UserLookups] 18 | ,[UserUpdates] 19 | ,[LastServiceStartDate] 20 | ,[RecordStatus] 21 | ,[RecordCreated] 22 | FROM [Staging].[IndexUsageStats] 23 | --WHERE [RecordStatus] = 'A' 24 | GO 25 | 26 | /* 27 | NOTE: 28 | In this case an object in the "Staging" schema is used as the VIEW target because we 29 | wanted to accumulate the results of the data collection rather than appending them. 30 | A trigger has been created on the destination object to achieve this functionality. 31 | */ 32 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/database_missingindexstats.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[database_missingindexstats]') IS NOT NULL 5 | DROP VIEW [Monitor].[database_missingindexstats] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[database_missingindexstats] 9 | AS 10 | SELECT [ServerName] 11 | ,[DatabaseName] 12 | ,[ObjectName] 13 | ,[EqualityColumns] 14 | ,[InequalityColumns] 15 | ,[IncludedColumns] 16 | ,[UniqueCompiles] 17 | ,[UserSeeks] 18 | ,[UserScans] 19 | ,[AvgTotalUserCost] 20 | ,[AvgUserImpact] 21 | ,[LastServiceStartDate] 22 | ,[RecordStatus] 23 | ,[RecordCreated] 24 | FROM [Staging].[MissingIndexStats] 25 | --WHERE [RecordStatus] = 'A' 26 | GO 27 | 28 | /* 29 | NOTE: 30 | In this case an object in the "Staging" schema is used as the VIEW target because we 31 | wanted to accumulate the results of the data collection rather than appending them. 32 | A trigger has been created on the destination object to achieve this functionality. 33 | */ 34 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/database_table_columns.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[database_table_columns]') IS NOT NULL 5 | DROP VIEW [Monitor].[database_table_columns] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[database_table_columns] 9 | AS 10 | SELECT [ServerName] 11 | ,[DatabaseName] 12 | ,[TableSchema] 13 | ,[TableName] 14 | ,[ColumnName] 15 | ,[OrdinalPosition] 16 | ,[DataType] 17 | ,[LengthOrPrecision] 18 | ,[RecordStatus] 19 | ,[RecordCreated] 20 | FROM [Monitor].[DatabaseTableColumns] 21 | --WHERE [RecordStatus] = 'A' 22 | GO 23 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/database_tables.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[database_tables]') IS NOT NULL 5 | DROP VIEW [Monitor].[database_tables] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[database_tables] 9 | AS 10 | SELECT [ServerName] 11 | ,[DatabaseName] 12 | ,[TableName] 13 | ,[RowCount] 14 | ,[ReservedKB] 15 | ,[DataSizeKB] 16 | ,[IndexSizeKB] 17 | ,[UnusedSpaceKB] 18 | ,[RecordStatus] 19 | ,[RecordCreated] 20 | FROM [Monitor].[DatabaseTables] 21 | --WHERE [RecordStatus] = 'A' 22 | GO 23 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/database_users.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[database_users]') IS NOT NULL 5 | DROP VIEW [Monitor].[database_users] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[database_users] 9 | AS 10 | SELECT [ServerName] 11 | ,[DatabaseName] 12 | ,[PrincipalName] 13 | ,[db_accessadmin] 14 | ,[db_backupoperator] 15 | ,[db_ddladmin] 16 | ,[db_owner] 17 | ,[db_securityadmin] 18 | ,[SecurablesPermissions] 19 | ,[RecordStatus] 20 | ,[RecordCreated] 21 | FROM [Monitor].[DatabaseUsers] 22 | --WHERE [RecordStatus] = 'A' 23 | GO 24 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_agentconfig.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_agentconfig]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_agentconfig] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_agentconfig] 9 | AS 10 | SELECT [ServerName] 11 | ,[AutoStart] 12 | ,[StartupAccount] 13 | ,[JobHistoryMaxRows] 14 | ,[JobHistoryMaxRowsPerJob] 15 | ,[ErrorLogFile] 16 | ,[EmailProfile] 17 | ,[FailSafeOperator] 18 | ,[RecordStatus] 19 | ,[RecordCreated] 20 | FROM [Monitor].[ServerAgentConfig] 21 | --WHERE [RecordStatus] = 'A' 22 | GO 23 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_agentjobs.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_agentjobs]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_agentjobs] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_agentjobs] 9 | AS 10 | SELECT [ServerName] 11 | ,[JobID] 12 | ,[JobName] 13 | ,[Enabled] 14 | ,[JobOwner] 15 | ,[DateCreated] 16 | ,[DateModified] 17 | ,[JobSteps] 18 | ,[JobSchedules] 19 | ,[RecordStatus] 20 | ,[RecordCreated] 21 | FROM [Monitor].[ServerAgentJobs] 22 | --WHERE [RecordStatus] = 'A' 23 | GO 24 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_agentjobshistory.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_agentjobshistory]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_agentjobshistory] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_agentjobshistory] 9 | AS 10 | SELECT [ServerName] 11 | ,[JobID] 12 | ,[JobName] 13 | ,[StepID] 14 | ,[StepName] 15 | ,[LastRunTime] 16 | ,[RunStatus] 17 | ,[Message] 18 | ,[RecordStatus] 19 | ,[RecordCreated] 20 | FROM [Monitor].[ServerAgentJobsHistory] 21 | --WHERE [RecordStatus] = 'A' 22 | GO 23 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_configurations.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_configurations]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_configurations] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_configurations] 9 | AS 10 | SELECT [ServerName] 11 | ,[ConfigID] 12 | ,[ConfigName] 13 | ,[ValueSet] 14 | ,[ValueInUse] 15 | ,[RecordStatus] 16 | ,[RecordCreated] 17 | FROM [Monitor].[ServerConfigurations] 18 | --WHERE [RecordStatus] = 'A' 19 | GO 20 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_databases.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_databases]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_databases] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_databases] 9 | AS 10 | SELECT [ServerName] 11 | ,[DatabaseName] 12 | ,[DatabaseOwner] 13 | ,[CreateDate] 14 | ,[CompatibilityLevel] 15 | ,[CollationName] 16 | ,[UserAccess] 17 | ,[IsReadOnly] 18 | ,[IsAutoClose] 19 | ,[IsAutoShrink] 20 | ,[State] 21 | ,[IsInStandby] 22 | ,[RecoveryModel] 23 | ,[PageVerifyOption] 24 | ,[IsFullTextEnabled] 25 | ,[IsTrustworthy] 26 | ,[RecordStatus] 27 | ,[RecordCreated] 28 | FROM [Monitor].[ServerDatabases] 29 | --WHERE [RecordStatus] = 'A' 30 | GO 31 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_endpoints.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_endpoints]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_endpoints] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_endpoints] 9 | AS 10 | SELECT [ServerName] 11 | ,[EndpointName] 12 | ,[Owner] 13 | ,[ProtocolDesc] 14 | ,[PayloadType] 15 | ,[StateDesc] 16 | ,[IsAdminEndpoint] 17 | ,[RecordStatus] 18 | ,[RecordCreated] 19 | FROM [Monitor].[ServerEndpoints] 20 | --WHERE [RecordStatus] = 'A' 21 | GO 22 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_errorlog.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_errorlog]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_errorlog] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_errorlog] 9 | AS 10 | SELECT [ServerName] 11 | ,[LogDate] 12 | ,[ProcessInfo] 13 | ,[LogText] 14 | ,[RecordStatus] 15 | ,[RecordCreated] 16 | FROM [Monitor].[ServerErrorLog] 17 | --WHERE [RecordStatus] = 'A' 18 | GO 19 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_freespace.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_freespace]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_freespace] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_freespace] 9 | AS 10 | SELECT [ServerName] 11 | ,[Drive] 12 | ,[FreeMB] 13 | ,[RecordStatus] 14 | ,[RecordCreated] 15 | FROM [Monitor].[ServerFreeSpace] 16 | --WHERE [RecordStatus] = 'A' 17 | GO 18 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_info.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_info]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_info] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_info] 9 | AS 10 | SELECT [ServerName] 11 | ,[ProductVersion] 12 | ,[ProductLevel] 13 | ,[ResourceLastUpdateDateTime] 14 | ,[ResourceVersion] 15 | ,[ServerAuthentication] 16 | ,[Edition] 17 | ,[InstanceName] 18 | ,[ComputerNamePhysicalNetBIOS] 19 | ,[BuildClrVersion] 20 | ,[Collation] 21 | ,[IsClustered] 22 | ,[IsFullTextInstalled] 23 | ,[SqlCharSetName] 24 | ,[SqlSortOrderName] 25 | ,[SqlRootPath] 26 | ,[Product] 27 | ,[Language] 28 | ,[Platform] 29 | ,[LogicalProcessors] 30 | ,[OSVersion] 31 | ,[TotalMemoryMB] 32 | ,[RecordStatus] 33 | ,[RecordCreated] 34 | FROM [Monitor].[ServerInfo] 35 | --WHERE [RecordStatus] = 'A' 36 | GO 37 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_logins.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_logins]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_logins] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_logins] 9 | AS 10 | SELECT [ServerName] 11 | ,[LoginName] 12 | ,[Type] 13 | ,[CreateDate] 14 | ,[ModifyDate] 15 | ,[PasswordLastSet] 16 | ,[DefaultDatabase] 17 | ,[DefaultLanguage] 18 | ,[IsDisabled] 19 | ,[IsPolicyChecked] 20 | ,[IsExpirationChecked] 21 | ,[sysadmin] 22 | ,[securityadmin] 23 | ,[serveradmin] 24 | ,[setupadmin] 25 | ,[processadmin] 26 | ,[diskadmin] 27 | ,[dbcreator] 28 | ,[bulkadmin] 29 | ,[SecurablesPermissions] 30 | ,[RecordStatus] 31 | ,[RecordCreated] 32 | FROM [Monitor].[ServerLogins] 33 | --WHERE [RecordStatus] = 'A' 34 | GO 35 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_servers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_servers]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_servers] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_servers] 9 | AS 10 | SELECT [ServerName] 11 | ,[ServerID] 12 | ,[LinkedServer] 13 | ,[ProductName] 14 | ,[ProviderName] 15 | ,[DataSource] 16 | ,[ProviderString] 17 | ,[CatalogConnection] 18 | ,[RecordStatus] 19 | ,[RecordCreated] 20 | FROM [Monitor].[ServerServers] 21 | --WHERE [RecordStatus] = 'A' 22 | GO 23 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Monitor/server_triggers.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Monitor].[server_triggers]') IS NOT NULL 5 | DROP VIEW [Monitor].[server_triggers] 6 | GO 7 | 8 | CREATE VIEW [Monitor].[server_triggers] 9 | AS 10 | SELECT [ServerName] 11 | ,[ObjectName] 12 | ,[ObjectType] 13 | ,[CreateDate] 14 | ,[ModifyDate] 15 | ,[IsDisabled] 16 | ,[RecordStatus] 17 | ,[RecordCreated] 18 | FROM [Monitor].[ServerTriggers] 19 | --WHERE [RecordStatus] = 'A' 20 | GO 21 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/Reporting/vwErrorLog.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[Reporting].[vwErrorLog]') IS NOT NULL 5 | DROP VIEW [Reporting].[vwErrorLog] 6 | GO 7 | 8 | CREATE VIEW [Reporting].[vwErrorLog] 9 | AS 10 | WITH cteFailedLoginAttempts 11 | AS ( 12 | SELECT 13 | [ServerName] 14 | ,[LogDate] 15 | ,[ProcessInfo] 16 | ,[LogText] 17 | -- Extract Login points 18 | ,(CHARINDEX('''', [LogText], 0)+1) AS [LoginStartPoint] 19 | ,((CHARINDEX('''', [LogText], (CHARINDEX('''', [LogText], 0)+1))-1) - (CHARINDEX('''', [LogText], 0))) AS [LoginEndPoint] 20 | -- Extract IP Address points 21 | ,(CHARINDEX('[', [LogText], 0)+1) AS [IPStartPoint] 22 | ,((CHARINDEX(']', [LogText], (CHARINDEX('[', [LogText], 0)+1))-1) - (CHARINDEX('[', [LogText], 0))) AS [IPEndPoint] 23 | -- Extract Reason points 24 | ,(CHARINDEX('Reason: ', [LogText], 0)+8) AS [ReasonStartPoint] 25 | ,((CHARINDEX('[', [LogText], (CHARINDEX('Reason: ', [LogText], 0)+8))-8) - (CHARINDEX('Reason: ', [LogText], 0))) AS [ReasonEndPoint] 26 | FROM [Monitor].[ServerErrorLog] 27 | WHERE [LogText] LIKE N'Login failed for user%' 28 | ) 29 | SELECT 30 | [ServerName] 31 | ,[LogDate] 32 | ,[ProcessInfo] 33 | --,[LogText] 34 | -- Extract Login 35 | ,SUBSTRING( 36 | [LogText], 37 | [LoginStartPoint], 38 | (CASE WHEN [LoginEndPoint] > 0 THEN [LoginEndPoint] ELSE 0 END) 39 | ) AS [LoginName] 40 | -- Extract IP Address 41 | ,REPLACE( 42 | SUBSTRING( 43 | [LogText], 44 | [IPStartPoint], 45 | (CASE WHEN [IPEndPoint] > 0 THEN [IPEndPoint] ELSE 0 END) 46 | ), 47 | 'CLIENT: ', 48 | '' 49 | ) AS [IPAddress] 50 | -- Extract Reason 51 | ,SUBSTRING( 52 | [LogText], 53 | [ReasonStartPoint], 54 | [ReasonEndPoint] 55 | ) AS [ReasonForFailure] 56 | FROM cteFailedLoginAttempts 57 | GO 58 | 59 | USE [master] 60 | GO 61 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/Views/dbo/vwProfile.sql: -------------------------------------------------------------------------------- 1 | USE [SQLMonitor] 2 | GO 3 | 4 | IF OBJECT_ID('[dbo].[vwProfile]') IS NOT NULL 5 | DROP VIEW [dbo].[vwProfile] 6 | GO 7 | 8 | CREATE VIEW [dbo].[vwProfile] 9 | AS 10 | SELECT 11 | p.[ProfileType], p.[ProfileName], 12 | p.[ScriptName], p.[PreExecuteScript], p.[ExecuteScript], 13 | -- an integer indicating the number of minutes that should elapse between iterations 14 | CASE p.[ProfileType] 15 | WHEN 'Annual' THEN DATEDIFF(N, DATEADD(YY, -1, CURRENT_TIMESTAMP), CURRENT_TIMESTAMP) 16 | WHEN 'Monthly' THEN DATEDIFF(N, DATEADD(MM, -1, CURRENT_TIMESTAMP), CURRENT_TIMESTAMP) 17 | WHEN 'Weekly' THEN DATEDIFF(N, DATEADD(WW, -1, CURRENT_TIMESTAMP), CURRENT_TIMESTAMP) 18 | WHEN 'Daily' THEN DATEDIFF(N, DATEADD(DD, -1, CURRENT_TIMESTAMP), CURRENT_TIMESTAMP) 19 | WHEN 'Hourly' THEN DATEDIFF(N, DATEADD(HH, -1, CURRENT_TIMESTAMP), CURRENT_TIMESTAMP) 20 | WHEN 'Minute' THEN DATEDIFF(N, DATEADD(N , -1, CURRENT_TIMESTAMP), CURRENT_TIMESTAMP) 21 | WHEN 'Manual' THEN 1 22 | ELSE 0 23 | END AS [IntervalMinutes], 24 | p.[ExecutionOrder] 25 | FROM [dbo].[Profile] p 26 | WHERE p.[RecordStatus] = 'A'; 27 | GO 28 | 29 | USE [master] 30 | GO 31 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/create_database.sql: -------------------------------------------------------------------------------- 1 | USE [master] 2 | GO 3 | 4 | SET NOCOUNT ON 5 | 6 | DECLARE @device_directory nvarchar(1000); 7 | SET @device_directory = ( 8 | SELECT SUBSTRING([physical_name], 1, CHARINDEX(N'master.mdf', LOWER([physical_name])) - 1) 9 | FROM sys.master_files WHERE [database_id] = DB_ID('master') AND [file_id] = 1) 10 | 11 | IF NOT EXISTS (SELECT name FROM sys.databases WHERE name = N'SQLMonitor') 12 | BEGIN 13 | DECLARE @sqlcmd nvarchar(2000); 14 | SET @sqlcmd = N' 15 | CREATE DATABASE [SQLMonitor] ON PRIMARY ( 16 | NAME = N''SQLMonitor'', 17 | FILENAME = ''' + @device_directory + 'SQLMonitor.mdf'' , 18 | SIZE = 5MB , 19 | FILEGROWTH = 1MB, 20 | MAXSIZE = 20MB ), 21 | FILEGROUP TABLES ( 22 | NAME = N''SQLMonitor_tables'', 23 | FILENAME = ''' + @device_directory + 'SQLMonitor_tables.ndf'' , 24 | SIZE = 100MB , 25 | FILEGROWTH = 100MB, 26 | MAXSIZE = 5GB ), 27 | FILEGROUP ARCHIVE ( 28 | NAME = N''SQLMonitor_archive'', 29 | FILENAME = ''' + @device_directory + 'SQLMonitor_archive.ndf'' , 30 | SIZE = 100MB , 31 | FILEGROWTH = 100MB, 32 | MAXSIZE = 5GB ) 33 | LOG ON ( 34 | NAME = N''SQLMonitor_log'', 35 | FILENAME = ''' + @device_directory + 'SQLMonitor_log.ldf'' , 36 | SIZE = 100MB , 37 | FILEGROWTH = 100MB, 38 | MAXSIZE = 2GB );'; 39 | 40 | EXEC sp_executesql @sqlcmd; 41 | 42 | EXEC sys.sp_dbcmptlevel @dbname=N'SQLMonitor', @new_cmptlevel=120; 43 | 44 | ALTER DATABASE [SQLMonitor] SET RECOVERY SIMPLE; 45 | 46 | ALTER DATABASE [SQLMonitor] SET MULTI_USER; 47 | 48 | ALTER DATABASE [SQLMonitor] SET AUTO_CLOSE OFF WITH NO_WAIT; 49 | END 50 | GO 51 | 52 | IF NOT EXISTS (SELECT [name] FROM [sys].[databases] WHERE [name] = N'SQLMonitor') 53 | BEGIN 54 | RAISERROR('Database SQLMonitor does not exist!', 16, 1); 55 | RETURN; 56 | END 57 | GO 58 | 59 | 60 | /* ************************************************** */ 61 | DECLARE @SQLcmd nvarchar(1000); 62 | DECLARE @SALoginName sysname; -- login name for the 'sa' 63 | SET @SQLcmd = ''; 64 | SET @SALoginName = (SELECT [name] FROM sys.sql_logins WHERE sid = 0x01); 65 | 66 | SET @SQLcmd = 'ALTER AUTHORIZATION ON DATABASE::[SQLMonitor] TO ' + @SALoginName; 67 | 68 | EXEC sp_executesql @SQLcmd; 69 | GO 70 | 71 | 72 | USE [SQLMonitor] 73 | GO 74 | 75 | IF NOT EXISTS (SELECT name FROM sys.filegroups WHERE is_default=1 AND name = N'TABLES') 76 | ALTER DATABASE [SQLMonitor] MODIFY FILEGROUP [TABLES] DEFAULT 77 | GO 78 | 79 | 80 | USE [master] 81 | GO 82 | -------------------------------------------------------------------------------- /database_schema/SQLMonitor/create_database_archive.sql: -------------------------------------------------------------------------------- 1 | USE [master] 2 | GO 3 | 4 | SET NOCOUNT ON 5 | 6 | DECLARE @device_directory nvarchar(1000); 7 | SET @device_directory = ( 8 | SELECT SUBSTRING([physical_name], 1, CHARINDEX(N'master.mdf', LOWER([physical_name])) - 1) 9 | FROM sys.master_files WHERE [database_id] = DB_ID('master') AND [file_id] = 1) 10 | 11 | IF NOT EXISTS (SELECT name FROM sys.databases WHERE name = N'SQLMonitorArchive') 12 | BEGIN 13 | DECLARE @sqlcmd nvarchar(2000); 14 | SET @sqlcmd = N' 15 | CREATE DATABASE [SQLMonitorArchive] ON PRIMARY ( 16 | NAME = N''SQLMonitorArchive'', 17 | FILENAME = ''' + @device_directory + 'SQLMonitorArchive.mdf'' , 18 | SIZE = 5MB , 19 | FILEGROWTH = 1MB, 20 | MAXSIZE = 20MB ), 21 | FILEGROUP TABLES ( 22 | NAME = N''SQLMonitorArchive_tables'', 23 | FILENAME = ''' + @device_directory + 'SQLMonitorArchive_tables.ndf'' , 24 | SIZE = 100MB , 25 | FILEGROWTH = 100MB, 26 | MAXSIZE = 5GB ) 27 | LOG ON ( 28 | NAME = N''SQLMonitorArchive_log'', 29 | FILENAME = ''' + @device_directory + 'SQLMonitorArchive_log.ldf'' , 30 | SIZE = 100MB , 31 | FILEGROWTH = 100MB, 32 | MAXSIZE = 2GB );'; 33 | 34 | EXEC sp_executesql @sqlcmd; 35 | 36 | EXEC sys.sp_dbcmptlevel @dbname=N'SQLMonitorArchive', @new_cmptlevel=120; 37 | 38 | ALTER DATABASE [SQLMonitorArchive] SET RECOVERY SIMPLE; 39 | 40 | ALTER DATABASE [SQLMonitorArchive] SET MULTI_USER; 41 | 42 | ALTER DATABASE [SQLMonitorArchive] SET AUTO_CLOSE OFF WITH NO_WAIT; 43 | END 44 | GO 45 | 46 | IF NOT EXISTS (SELECT [name] FROM [sys].[databases] WHERE [name] = N'SQLMonitorArchive') 47 | BEGIN 48 | RAISERROR('Database SQLMonitorArchive does not exist!', 16, 1); 49 | RETURN; 50 | END 51 | GO 52 | 53 | 54 | /* ************************************************** */ 55 | DECLARE @SQLcmd nvarchar(1000); 56 | DECLARE @SALoginName sysname; -- login name for the 'sa' 57 | SET @SQLcmd = ''; 58 | SET @SALoginName = (SELECT [name] FROM sys.sql_logins WHERE sid = 0x01); 59 | 60 | SET @SQLcmd = 'ALTER AUTHORIZATION ON DATABASE::[SQLMonitorArchive] TO ' + @SALoginName; 61 | 62 | EXEC sp_executesql @SQLcmd; 63 | GO 64 | 65 | 66 | USE [SQLMonitorArchive] 67 | GO 68 | 69 | IF NOT EXISTS (SELECT name FROM sys.filegroups WHERE is_default=1 AND name = N'TABLES') 70 | ALTER DATABASE [SQLMonitorArchive] MODIFY FILEGROUP [TABLES] DEFAULT 71 | GO 72 | 73 | 74 | USE [master] 75 | GO 76 | -------------------------------------------------------------------------------- /information_collection/Export-ServerInfo.ps1: -------------------------------------------------------------------------------- 1 | param( 2 | [Parameter(Mandatory=$true)] [String]$ServerName, 3 | [Parameter(Mandatory=$true)] [String]$ScriptsFolder, 4 | [Parameter(Mandatory=$true)] [String]$OutputPath 5 | ) 6 | # 7 | # Usage: .\Export-ServerInfo.ps1 -ServerName "localhost,1433" -ScriptsFolder ".\scripts" -OutputPath "C:\temp" 8 | # 9 | Clear-Host 10 | 11 | # Global params 12 | $ServerInstance = $ServerName 13 | $Database = "master" # <-- to avoid connecting to a database which does not exist 14 | 15 | # build an array of files, in the order they have to be executed 16 | $FileList = New-Object System.Collections.ArrayList 17 | # read list of files from the "configuration" text file 18 | $ScriptFiles = Get-ChildItem -Path $ScriptsFolder -Filter *.sql | Select-Object Name 19 | # verify that the files adhere to specific criteria 20 | ForEach ($ScriptFile in $ScriptFiles) { 21 | $ScriptFile = "$ScriptsFolder\$($ScriptFile.Name)"; 22 | # only SQL files allowed; check if the file exists 23 | if (($ScriptFile -like "*.sql") -and (Test-Path $ScriptFile -PathType Leaf)) { 24 | # NOTE: The "> $null" part is to remove the array item index output 25 | $FileList.Add($ScriptFile.ToString()) > $null 26 | } 27 | else { "Script '{0}' could not be found" -f $ScriptFile } 28 | } 29 | 30 | # read and run scripts against the SQL Server instance 31 | if ($FileList.Count -gt 0) { 32 | # load and run the scripts listed in the array 33 | "{0} : Starting execution of {1} database scripts on {2}" -f $(Get-Date -Format "HH:mm:ss"), $FileList.Count, $ServerInstance 34 | "{0} : ---------------------------------------------------------------------------" -f $(Get-Date -Format "HH:mm:ss") 35 | # start loop 36 | $OutputPath = "$OutputPath\$ServerName" 37 | New-Item -Path $OutputPath -ItemType Directory -Force -ErrorAction SilentlyContinue | Out-Null; 38 | ForEach ($Script In $FileList) { 39 | $ScriptExecPath = $Script.ToString() 40 | # check if the file exists, again 41 | if (Test-Path $ScriptExecPath -PathType Leaf) { 42 | $Sql = Get-Content -Path $ScriptExecPath -Raw 43 | $Sql = $Sql -f ((Get-Date).AddDays(5)).ToString("yyyy-MM-dd"); 44 | "{0} : Running script: {1}" -f $(Get-Date -Format "HH:mm:ss"), $ScriptExecPath 45 | try { 46 | Invoke-Sqlcmd -ServerInstance $ServerInstance -Database $Database -Query $Sql -QueryTimeout 300 | ` 47 | Export-Csv -Path ($ScriptExecPath.Replace(".sql", ".csv").Replace($ScriptsFolder, $OutputPath)) -Delimiter "," -NoClobber -NoTypeInformation 48 | } 49 | catch { break } # On Error, Exit the ForEach Loop 50 | } 51 | else { "{0} : Script '{1}' could not be found" -f $(Get-Date -Format "HH:mm:ss"), $ScriptExecPath } 52 | } 53 | # end loop 54 | "{0} : ---------------------------------------------------------------------------" -f $(Get-Date -Format "HH:mm:ss") 55 | "{0} : Script execution complete" -f $(Get-Date -Format "HH:mm:ss") 56 | } 57 | 58 | # deallocate variables 59 | $ServerInstance = $null 60 | $Database = $null 61 | $FileList = $null 62 | $Script = $null 63 | $ScriptExecPath = $null 64 | $Sql = $null -------------------------------------------------------------------------------- /information_collection/Invoke-ArchiveMaintenance.ps1: -------------------------------------------------------------------------------- 1 | param([String]$ServerName = '', 2 | [String]$DatabaseName = '', 3 | [String]$QueryTimeout = 30) 4 | 5 | # 6 | # Usage: 7 | # .\Invoke-ArchiveMaintenance.ps1 -ServerName "Server Name" -DatabaseName "SQL Monitor Database" 8 | # Will run the function (if all input parameters are present and valid) 9 | # 10 | 11 | # Global params 12 | $CurrentPath = Get-Location 13 | . "$($CurrentPath)\Community_Functions.ps1" 14 | 15 | #------------------------------------------------------------# 16 | 17 | function Invoke-ArchiveMaintenance () { 18 | [CmdletBinding()] 19 | param( 20 | [Parameter(Position=0, Mandatory=$true)] [string]$ServerInstance, 21 | [Parameter(Position=1, Mandatory=$true)] [string]$Database, 22 | [Parameter(Position=2, Mandatory=$false)] [string]$QueryTimeout = 360 23 | ) 24 | 25 | [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.Smo") | out-null 26 | [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.ConnectionInfo") | out-null 27 | 28 | # start here 29 | "{0} : ============================== " -f $(Get-Date -Format "HH:mm:ss") 30 | "{0} : Starting function: Invoke-ArchiveMaintenance" -f $(Get-Date -Format "HH:mm:ss") 31 | "{0} : Server Name: {1}" -f $(Get-Date -Format "HH:mm:ss"), $ServerInstance 32 | "{0} : Database Name: {1}" -f $(Get-Date -Format "HH:mm:ss"), $Database 33 | "{0} : Query Timeout: {1}" -f $(Get-Date -Format "HH:mm:ss"), $QueryTimeout 34 | "{0} : ============================== " -f $(Get-Date -Format "HH:mm:ss") 35 | 36 | # execute archiving stored procedure 37 | $Sql = "EXEC [Archive].[usp_Mantain_Archive];" 38 | $MantainArchive = Invoke-Sqlcmd2 -ServerInstance $ServerInstance -Database $Database -Query $Sql -Verbose -QueryTimeout $QueryTimeout 39 | 40 | # clear 41 | $Sql = $null 42 | $MantainArchive = $null 43 | "{0} : Done" -f $(Get-Date -Format "HH:mm:ss") 44 | "{0} : ============================== " -f $(Get-Date -Format "HH:mm:ss") 45 | } 46 | 47 | Clear-Host 48 | # run this only if the parameters have been passed to the script 49 | # interface implemented to be called from Windows Task Scheduler or similar applications 50 | if (($ServerName -ne '') -and ($DatabaseName -ne '')) { 51 | Invoke-ArchiveMaintenance -ServerInstance $ServerName -Database $DatabaseName -QueryTimeout $QueryTimeout 52 | } 53 | # otherwise, do nothing 54 | -------------------------------------------------------------------------------- /information_collection/Settings.xml: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | SQLSRV01 5 | SQLMonitor 6 | Monitor 7 | 1800 8 | 9 | 10 | mailserver.mycompany.com 11 | 25 12 | SQL Monitor {0} Reports 13 | dba.team@mycompany.com 14 | 15 | 16 | {border-width: 1px;border-style: solid;border-color: black;border-collapse: collapse;} 17 | {border-width: 1px;padding: 3px;border-style: solid;border-color: black;font-family: Verdana;font-size: x-small;} 18 | {border-width: 1px;padding: 3px;border-style: solid;border-color: black;font-family: Verdana;font-size: x-small;} 19 | 20 | 21 | -------------------------------------------------------------------------------- /information_collection/Test-NetworkConnection.ps1: -------------------------------------------------------------------------------- 1 | param([String]$ServerName = '', 2 | [String]$DatabaseName = '') 3 | 4 | # 5 | # Usage: 6 | # .\Test-NetworkConnection.ps1 -ServerName "Server Name" -DatabaseName "SQL Monitor Database" 7 | # Will run the function (if all input parameters are present and valid) 8 | # 9 | 10 | # Global params 11 | $CurrentPath = Get-Location 12 | . "$($CurrentPath)\Community_Functions.ps1" 13 | 14 | #------------------------------------------------------------# 15 | 16 | function Test-Port($hostname, $port) { 17 | # This works no matter in which form we get $host - hostname or ip address 18 | try { 19 | $ip = [System.Net.Dns]::GetHostAddresses($hostname) | 20 | Select-Object IPAddressToString -expandproperty IPAddressToString 21 | if ($ip.GetType().Name -eq "Object[]") { 22 | #If we have several ip's for that address, let's take first one 23 | $ip = $ip[0] 24 | } 25 | } 26 | catch { 27 | # $hostname could be the incorrect Hostname or IP Address 28 | Return $False 29 | } 30 | $t = New-Object Net.Sockets.TcpClient 31 | # We use Try\Catch to remove exception info from console if we can't connect 32 | try {$t.Connect($ip,$port)} catch {} 33 | 34 | if($t.Connected) { 35 | $t.Close() 36 | Return $True 37 | } 38 | else { 39 | Return $False 40 | } 41 | } 42 | 43 | #------------------------------------------------------------# 44 | 45 | function Test-DatabaseConnection($InstanceName) { 46 | # test authentication 47 | try { 48 | $result = Invoke-Sqlcmd2 -ServerInstance $InstanceName -Database master -Query "SELECT @@ServerName AS [ServerName];" -QueryTimeout 10 49 | # if the connection succeeds... 50 | Return $True 51 | } 52 | catch { 53 | # if the connection fails... 54 | Return $False 55 | } 56 | } 57 | 58 | #------------------------------------------------------------# 59 | 60 | function Test-NetworkConnection() { 61 | [CmdletBinding()] 62 | param( 63 | [Parameter(Position=0, Mandatory=$true)] [string]$ServerInstance, 64 | [Parameter(Position=1, Mandatory=$true)] [string]$Database 65 | ) 66 | 67 | [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.Smo") | out-null 68 | [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.ConnectionInfo") | out-null 69 | 70 | # start here 71 | "{0} : ============================== " -f $(Get-Date -Format "HH:mm:ss") 72 | "{0} : Starting function: Test-NetworkConnection" -f $(Get-Date -Format "HH:mm:ss") 73 | "{0} : Server Name: {1}" -f $(Get-Date -Format "HH:mm:ss"), $ServerInstance 74 | "{0} : Database Name: {1}" -f $(Get-Date -Format "HH:mm:ss"), $Database 75 | "{0} : ============================== " -f $(Get-Date -Format "HH:mm:ss") 76 | 77 | # get list of servers 78 | $sql = "EXEC dbo.uspGetServers;" 79 | $ServerInstances = Invoke-Sqlcmd2 -ServerInstance $ServerInstance -Database $Database -Query $sql -QueryTimeout 30 80 | 81 | # clear 82 | $sql = $null 83 | 84 | Foreach ($Server in $ServerInstances) { 85 | $ServerName = $Server.ServerName 86 | $TcpPort = $Server.SqlTcpPort 87 | $InstanceName = "$ServerName,$TcpPort" 88 | "{0} : Testing {1}" -f $(Get-Date -Format "HH:mm:ss"), $InstanceName 89 | 90 | # test connection 91 | $TestConnection = Test-Port -hostname $ServerName -port $TcpPort 92 | if ($TestConnection -eq $true) { 93 | "{0} : Network access OK" -f $(Get-Date -Format "HH:mm:ss") 94 | # test database authentication 95 | $TestAuthentication = Test-DatabaseConnection -InstanceName $InstanceName 96 | if ($TestAuthentication -eq $true) { 97 | "{0} : Authentication OK" -f $(Get-Date -Format "HH:mm:ss") 98 | } 99 | else { 100 | Write-Warning "Could not log on to $ServerName on port $TcpPort" 101 | } 102 | } 103 | else { 104 | Write-Warning "Network access to $ServerName on port $TcpPort not available" 105 | } 106 | "{0} : ------------------------------ " -f $(Get-Date -Format "HH:mm:ss") 107 | } 108 | } 109 | 110 | Clear-Host 111 | # run this only if the parameters have been passed to the script 112 | # interface implemented to be called from Windows Task Scheduler or similar applications 113 | if (($ServerName -ne '') -and ($DatabaseName -ne '')) { 114 | Test-NetworkConnection -ServerInstance $ServerName -Database $DatabaseName 115 | } 116 | # otherwise, do nothing 117 | -------------------------------------------------------------------------------- /information_collection/scripts/database_backup_history.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Recoverability 2 | SET NOCOUNT ON; 3 | DECLARE @StartDate datetime; 4 | SET @StartDate = CONVERT(datetime, '{0}', 120); 5 | --SET @StartDate = CONVERT(datetime, '1753-01-01 00:00:00', 120); 6 | 7 | SELECT 8 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS [ServerName], 9 | bs.database_name AS [DatabaseName], 10 | CASE bs.[type] -- Can be NULL 11 | WHEN 'D' THEN 'Database' 12 | WHEN 'I' THEN 'Differential database' 13 | WHEN 'L' THEN 'Log' 14 | WHEN 'F' THEN 'File or filegroup' 15 | WHEN 'G' THEN 'Differential file' 16 | WHEN 'P' THEN 'Partial' 17 | WHEN 'Q' THEN 'Differential partial' 18 | ELSE bs.[type] 19 | END AS [BackupType], 20 | bs.[name] AS [BackupName], 21 | bs.[user_name] AS [LoginName], 22 | bs.[backup_start_date] AS [StartDate], 23 | bs.[backup_finish_date] AS [FinishDate], 24 | CAST(((bs.[backup_size]/1024)/1024) AS decimal(15,2)) AS [BackupSizeMB], 25 | bs.server_name AS [SourceServer], 26 | bmf.physical_device_name AS [PhysicalDeviceName], 27 | bmf.logical_device_name AS [LogicalDeviceName], 28 | bs.expiration_date AS [ExpirationDate], 29 | bs.description AS [Description] 30 | FROM msdb.dbo.backupmediafamily bmf 31 | INNER JOIN msdb.dbo.backupset bs ON bmf.media_set_id = bs.media_set_id 32 | WHERE 33 | (CONVERT(datetime, bs.backup_start_date, 102) >= @StartDate) 34 | -- remove entries for restores 35 | AND NOT EXISTS ( 36 | SELECT 1 FROM msdb.dbo.restorehistory rh 37 | WHERE rh.[backup_set_id] = bs.[backup_set_id]) 38 | ORDER BY [StartDate], [DatabaseName]; 39 | -------------------------------------------------------------------------------- /information_collection/scripts/database_configurations.sql: -------------------------------------------------------------------------------- 1 | -- Category: Databases Configuration 2 | SET NOCOUNT ON; 3 | 4 | SELECT 5 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS [ServerName], 6 | DB_NAME(database_id) AS [DatabaseName], 7 | [file_id] AS [FileID], 8 | [type_desc] AS [FileType], 9 | [name] AS [FileName], 10 | [physical_name] AS [FilePath], 11 | [state_desc] AS [State], 12 | [is_read_only] AS [IsReadOnly], 13 | CAST(((CAST([size] AS numeric(15,4))*8)/1024) AS numeric(15,2)) AS [SizeMB], 14 | CASE 15 | WHEN [max_size] = 0 THEN 0 16 | WHEN [max_size] = -1 THEN -1 17 | ELSE CAST(((CAST([max_size] AS numeric(15,0))*8)/1024) AS numeric(15,0)) 18 | END AS [MaxSizeMB], 19 | CASE [is_percent_growth] 20 | WHEN 1 THEN [growth] 21 | ELSE CAST(((CAST([growth] AS numeric(15,0))*8)/1024) AS numeric(15,0)) 22 | END AS [GrowthMB], 23 | [is_percent_growth] AS [IsPercentGrowth] 24 | FROM sys.master_files 25 | ORDER BY [database_id] ASC, [file_id] ASC, [name] ASC; 26 | -------------------------------------------------------------------------------- /information_collection/scripts/database_missingindexstats.sql: -------------------------------------------------------------------------------- 1 | USE [tempdb]; 2 | SET NOCOUNT ON; 3 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 4 | 5 | DECLARE @SQLCmd nvarchar(max); 6 | 7 | SET @SQLCmd = ' 8 | IF OBJECT_ID(''dbo.[MissingIndexStats]'') IS NOT NULL 9 | BEGIN 10 | DROP TABLE [dbo].[MissingIndexStats]; 11 | END'; 12 | EXEC sp_executesql @SQLCmd; 13 | 14 | -- create temporary storage 15 | CREATE TABLE [dbo].[MissingIndexStats]( 16 | [database_name] [nvarchar](128) NOT NULL, 17 | [object_id] [int] NOT NULL, 18 | [object_name] [nvarchar](260) NULL, 19 | [equality_columns] [nvarchar](4000) NULL, 20 | [inequality_columns] [nvarchar](4000) NULL, 21 | [included_columns] [nvarchar](4000) NULL, 22 | [unique_compiles] [bigint] NOT NULL, 23 | [user_seeks] [bigint] NOT NULL, 24 | [user_scans] [bigint] NOT NULL, 25 | [avg_total_user_cost] [numeric] (15,2) NULL, 26 | [avg_user_impact] [numeric] (5,2) NULL 27 | ) ON [PRIMARY]; 28 | 29 | -- retrieve data and store in temporary store 30 | INSERT INTO [dbo].[MissingIndexStats] ( 31 | [database_name] 32 | ,[object_id] 33 | ,[object_name] 34 | ,[equality_columns] 35 | ,[inequality_columns] 36 | ,[included_columns] 37 | ,[unique_compiles] 38 | ,[user_seeks] 39 | ,[user_scans] 40 | ,[avg_total_user_cost] 41 | ,[avg_user_impact] 42 | ) 43 | SELECT 44 | DB_NAME(d.database_id) AS [database_name] 45 | ,d.object_id 46 | ,CAST(NULL AS nvarchar(260)) AS [object_name] 47 | ,d.[equality_columns] 48 | ,d.[inequality_columns] 49 | ,d.[included_columns] 50 | ,s.[unique_compiles] 51 | ,s.[user_seeks] 52 | ,s.[user_scans] 53 | ,CAST(s.[avg_total_user_cost] AS numeric(15,2)) AS [avg_total_user_cost] 54 | ,CAST(s.[avg_user_impact] AS numeric(5,2)) AS [avg_user_impact] 55 | FROM sys.dm_db_missing_index_groups g 56 | INNER JOIN sys.dm_db_missing_index_details d ON d.index_handle = g.index_handle 57 | INNER JOIN sys.dm_db_missing_index_group_stats s ON s.group_handle = g.index_group_handle 58 | WHERE d.database_id > 4 59 | AND DB_NAME(d.database_id) NOT IN ('DBAToolbox', 'SSISDB') 60 | AND DB_NAME(d.database_id) NOT LIKE 'AdventureWorks%' 61 | AND DB_NAME(d.database_id) NOT LIKE 'ReportServer%'; 62 | 63 | -- update object names 64 | DECLARE @DatabaseName nvarchar(128); 65 | --DECLARE @SqlCmd nvarchar(4000); 66 | DECLARE curDatabases CURSOR READ_ONLY FOR 67 | SELECT DISTINCT [database_name] 68 | FROM [dbo].[MissingIndexStats] 69 | ORDER BY [database_name] ASC; 70 | 71 | OPEN curDatabases; 72 | FETCH NEXT FROM curDatabases INTO @DatabaseName; 73 | WHILE (@@FETCH_STATUS = 0) 74 | BEGIN 75 | -- PRINT @DatabaseName; 76 | SET @SqlCmd = N' 77 | UPDATE [tempdb].[dbo].[MissingIndexStats] 78 | SET [object_name] = QUOTENAME(s.[name], ''['') + ''.'' + QUOTENAME(o.[name], ''['') 79 | FROM [' + @DatabaseName + N'].sys.objects o 80 | INNER JOIN [tempdb].[dbo].[MissingIndexStats] mis ON o.object_id = mis.object_id 81 | INNER JOIN [' + @DatabaseName + N'].sys.schemas s ON o.schema_id = s.schema_id 82 | WHERE mis.[database_name] = N''' + @DatabaseName + N''' 83 | AND mis.[object_name] IS NULL;'; 84 | -- PRINT @SqlCmd; 85 | EXEC sp_executesql @SqlCmd; 86 | 87 | FETCH NEXT FROM curDatabases INTO @DatabaseName; 88 | END 89 | CLOSE curDatabases; 90 | DEALLOCATE curDatabases; 91 | 92 | -- the object_id column is necessary only until the object name is retrieved 93 | ALTER TABLE [dbo].[MissingIndexStats] DROP COLUMN [object_id]; 94 | 95 | -- Determine last service restart date based upon tempdb creation date 96 | DECLARE @last_service_start_date datetime; 97 | SELECT @last_service_start_date = [create_date] FROM sys.databases WHERE [name] = N'tempdb'; 98 | 99 | -- return results 100 | SELECT 101 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) as [ServerName] 102 | ,[database_name] AS [DatabaseName] 103 | ,[object_name] AS [ObjectName] 104 | ,[equality_columns] AS [EqualityColumns] 105 | ,[inequality_columns] AS [InequalityColumns] 106 | ,[included_columns] AS [IncludedColumns] 107 | ,[unique_compiles] AS [UniqueCompiles] 108 | ,[user_seeks] AS [UserSeeks] 109 | ,[user_scans] AS [UserScans] 110 | ,[avg_total_user_cost] AS [AvgTotalUserCost] 111 | ,[avg_user_impact] AS [AvgUserImpact] 112 | ,@last_service_start_date AS [LastServiceStartDate] 113 | FROM [dbo].[MissingIndexStats] 114 | ORDER BY [database_name], 115 | --([avg_total_user_cost] * [avg_user_impact] * ([user_seeks]+[user_scans])) DESC, 116 | [object_name]; 117 | 118 | SET @SQLCmd = ' 119 | IF OBJECT_ID(''dbo.[MissingIndexStats]'') IS NOT NULL 120 | BEGIN 121 | DROP TABLE [dbo].[MissingIndexStats]; 122 | END'; 123 | EXEC sp_executesql @SQLCmd; 124 | -------------------------------------------------------------------------------- /information_collection/scripts/database_table_columns.sql: -------------------------------------------------------------------------------- 1 | -- Category: Databases - Database Objects 2 | SET NOCOUNT ON; 3 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 4 | 5 | DECLARE @database_name nvarchar(128); 6 | DECLARE @SQLcmd nvarchar(4000); 7 | 8 | CREATE TABLE #server_databases_columns ( 9 | [server_name] nvarchar(128), 10 | [table_catalog] nvarchar(128), 11 | [table_schema] nvarchar(128), 12 | [table_name] nvarchar(128), 13 | [column_name] nvarchar(128), 14 | [ordinal_position] int, 15 | [data_type] nvarchar(128), 16 | [length/precision] nvarchar(128) 17 | ); 18 | 19 | /* START: for each database */ 20 | DECLARE d1 CURSOR FOR 21 | SELECT [name] FROM sys.databases 22 | WHERE database_id > 4 23 | AND ([name] NOT LIKE N'AdventureWorks%') AND ([name] NOT LIKE N'DBAToolbox%') 24 | AND ([name] NOT LIKE N'Northwind%') AND ([name] NOT LIKE N'pubs%') 25 | AND ([name] NOT LIKE N'ReportServer%') AND ([name] NOT LIKE N'DQS_%') 26 | ORDER BY [name] ASC; 27 | OPEN d1; 28 | FETCH NEXT FROM d1 INTO @database_name; 29 | WHILE (@@FETCH_STATUS = 0) 30 | BEGIN 31 | SET @SQLCmd = N' 32 | USE [' + @database_name + N']; 33 | -- check if 34 | IF ((SELECT COUNT(*) FROM INFORMATION_SCHEMA.TABLES) > 5000) 35 | BEGIN 36 | PRINT ''More than 5,000 Tables have been found in ' + @database_name + N'. This database will be skipped.'' 37 | END 38 | ELSE 39 | BEGIN 40 | SELECT 41 | @@SERVERNAME AS [server_name], 42 | c.table_catalog, c.table_schema, c.table_name, c.column_name, c.ordinal_position, 43 | c.data_type, 44 | [length/precision] = 45 | CASE data_type 46 | WHEN ''char'' THEN (CASE ISNULL(c.character_maximum_length, 0) WHEN 0 THEN '''' WHEN -1 THEN ''MAX'' ELSE convert(varchar(10), c.character_maximum_length) END) 47 | WHEN ''nchar'' THEN (CASE ISNULL(c.character_maximum_length, 0) WHEN 0 THEN '''' WHEN -1 THEN ''MAX'' ELSE convert(varchar(10), c.character_maximum_length) END) 48 | WHEN ''varchar'' THEN (CASE ISNULL(c.character_maximum_length, 0) WHEN 0 THEN '''' WHEN -1 THEN ''MAX'' ELSE convert(varchar(10), c.character_maximum_length) END) 49 | WHEN ''nvarchar'' THEN (CASE ISNULL(c.character_maximum_length, 0) WHEN 0 THEN '''' WHEN -1 THEN ''MAX'' ELSE convert(varchar(10), c.character_maximum_length) END) 50 | WHEN ''numeric'' THEN (CASE ISNULL(c.numeric_precision, 0) WHEN 0 THEN '''' ELSE convert(varchar(10), numeric_precision) + '', '' + convert(varchar(10), c.numeric_scale) END) 51 | WHEN ''decimal'' THEN (CASE ISNULL(c.numeric_precision, 0) WHEN 0 THEN '''' ELSE convert(varchar(10), numeric_precision) + '', '' + convert(varchar(10), c.numeric_scale) END) 52 | Else '''' 53 | END 54 | FROM INFORMATION_SCHEMA.COLUMNS c 55 | INNER JOIN INFORMATION_SCHEMA.TABLES t ON c.TABLE_CATALOG = t.TABLE_CATALOG AND c.TABLE_NAME = t.TABLE_NAME 56 | WHERE t.TABLE_TYPE = ''BASE TABLE'' 57 | AND c.table_name NOT IN (''dtproperties'', ''sysconstraints'', ''syssegments''); 58 | END 59 | '; 60 | 61 | INSERT INTO #server_databases_columns 62 | EXEC sp_executesql @SQLcmd; 63 | 64 | FETCH NEXT FROM d1 INTO @database_name; 65 | END 66 | CLOSE d1 67 | DEALLOCATE d1 68 | /* END: for each database */ 69 | 70 | -- return data 71 | SELECT 72 | [server_name] 73 | ,[table_catalog] 74 | ,[table_schema] 75 | ,[table_name] 76 | ,[column_name] 77 | ,[ordinal_position] 78 | ,[data_type] 79 | ,[length/precision] 80 | FROM #server_databases_columns 81 | ORDER BY [table_catalog], [table_schema], [table_name], [ordinal_position]; 82 | -------------------------------------------------------------------------------- /information_collection/scripts/database_tables.sql: -------------------------------------------------------------------------------- 1 | -- Category: Databases - Database Objects 2 | SET NOCOUNT ON; 3 | 4 | CREATE TABLE #TableSpaceUsed ( 5 | [DatabaseName] [nvarchar](128) NOT NULL, 6 | [TableName] [nvarchar](128) NOT NULL, 7 | [RowCount] [bigint] NOT NULL, 8 | [ReservedKB] [bigint] NOT NULL, 9 | [DataSizeKB] [bigint] NOT NULL, 10 | [IndexSizeKB] [bigint] NOT NULL, 11 | [UnusedSpaceKB] [bigint] NOT NULL 12 | ); 13 | 14 | CREATE TABLE #TableSpaceUsed_temp ( 15 | [TableName] [nvarchar](128) NOT NULL, 16 | [RowCount] [bigint] NOT NULL, 17 | [ReservedKB] [bigint] NOT NULL, 18 | [DataSizeKB] [bigint] NOT NULL, 19 | [IndexSizeKB] [bigint] NOT NULL, 20 | [UnusedSpaceKB] [bigint] NOT NULL 21 | ); 22 | 23 | -- process info 24 | DECLARE @database_name nvarchar(128); 25 | DECLARE @SQLCmd nvarchar(2000); 26 | SET @SQLCmd = N''; 27 | 28 | /* START: for each database */ 29 | DECLARE d1 CURSOR FOR 30 | SELECT [name] FROM sys.databases 31 | WHERE database_id > 4 32 | AND ([name] NOT LIKE N'AdventureWorks%') AND ([name] NOT LIKE N'DBAToolbox%') 33 | AND ([name] NOT LIKE N'Northwind%') AND ([name] NOT LIKE N'pubs%') 34 | AND ([name] NOT LIKE N'ReportServer%') AND ([name] NOT LIKE N'DQS_%') 35 | ORDER BY [name] ASC; 36 | OPEN d1; 37 | FETCH NEXT FROM d1 INTO @database_name; 38 | WHILE (@@FETCH_STATUS = 0) 39 | BEGIN 40 | SET @SQLCmd = N' 41 | USE [' + @database_name + N']; 42 | -- check if 43 | IF ((SELECT COUNT(*) FROM INFORMATION_SCHEMA.TABLES) > 5000) 44 | BEGIN 45 | PRINT ''More than 5,000 Tables have been found in ' + @database_name + N'. This database will be skipped.'' 46 | END 47 | ELSE 48 | BEGIN 49 | SELECT 50 | SCHEMA_NAME(sobj.schema_id) + ''.'' + sobj.name AS [TableName], 51 | (SELECT TOP(1) Rows FROM sys.partitions WHERE object_id = sptn.object_id) AS [RowCount], 52 | SUM(total_pages*8) AS [ReservedKB], 53 | SUM(data_pages*8) AS [DataSizeKB], 54 | SUM((used_pages-data_pages)*8) AS [IndexSizeKB], 55 | SUM((total_pages-used_pages)*8) AS [UnusedSpaceKB] 56 | FROM sys.objects AS sobj 57 | INNER JOIN sys.partitions AS sptn ON sobj.object_id = sptn.object_id 58 | INNER JOIN sys.allocation_units sau ON sau.container_id = ( 59 | CASE sau.type 60 | WHEN 1 THEN sptn.hobt_id 61 | WHEN 2 THEN sptn.partition_id 62 | WHEN 3 THEN sptn.hobt_id 63 | END 64 | ) 65 | WHERE sobj.type = ''U'' 66 | AND sobj.is_ms_shipped = 0x0 67 | AND sptn.index_id < 2 -- 0:Heap, 1:Clustered 68 | GROUP BY sobj.schema_id, sobj.name, sptn.object_id 69 | ORDER BY [TableName]; 70 | END 71 | '; 72 | INSERT INTO #TableSpaceUsed_temp 73 | EXEC sp_executesql @SQLCmd; 74 | 75 | INSERT INTO #TableSpaceUsed 76 | SELECT 77 | @database_name, t1.[TableName], 78 | t1.[RowCount], t1.[ReservedKB], t1.[DataSizeKB], t1.[IndexSizeKB], t1.[UnusedSpaceKB] 79 | FROM #TableSpaceUsed_temp t1 80 | ORDER BY t1.[TableName]; 81 | 82 | DELETE FROM #TableSpaceUsed_temp; 83 | 84 | FETCH NEXT FROM d1 INTO @database_name; 85 | END 86 | CLOSE d1 87 | DEALLOCATE d1 88 | /* END: for each database */ 89 | 90 | -- return data 91 | SELECT 92 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS [ServerName], 93 | [DatabaseName], 94 | [TableName], 95 | [RowCount], 96 | [ReservedKB], 97 | [DataSizeKB], 98 | [IndexSizeKB], 99 | [UnusedSpaceKB] 100 | FROM #TableSpaceUsed 101 | ORDER BY [DatabaseName], [TableName]; 102 | -------------------------------------------------------------------------------- /information_collection/scripts/server_agentconfig.sql: -------------------------------------------------------------------------------- 1 | SET NOCOUNT ON; 2 | 3 | CREATE TABLE #sqlagent_properties ( 4 | auto_start INT 5 | ,msx_server_name NVARCHAR(128) NULL 6 | ,sqlagent_type INT 7 | ,startup_account NVARCHAR(128) 8 | ,sqlserver_restart INT 9 | ,jobhistory_max_rows INT 10 | ,jobhistory_max_rows_per_job INT 11 | ,errorlog_file NVARCHAR(255) 12 | ,errorlogging_level INT 13 | ,error_recipient NVARCHAR(30) NULL 14 | ,monitor_autostart INT 15 | ,local_host_server NVARCHAR(128) NULL 16 | ,job_shutdown_timeout INT 17 | ,cmdexec_account VARBINARY(64) NULL 18 | ,regular_connections INT 19 | ,host_login_name NVARCHAR(128) NULL 20 | ,host_login_password VARBINARY(512) NULL 21 | ,login_timeout INT 22 | ,idle_cpu_percent INT 23 | ,idle_cpu_duration INT 24 | ,oem_errorlog INT 25 | ,sysadmin_only INT NULL 26 | ,email_profile NVARCHAR(64) NULL 27 | ,email_save_in_sent_folder INT 28 | ,cpu_poller_enabled INT 29 | ,alert_replace_runtime_tokens INT 30 | ); 31 | 32 | CREATE TABLE #sqlagent_alerts ( 33 | FailSafeOperator nvarchar(255) NULL, 34 | NotificationMethod int NULL, 35 | ForwardingServer nvarchar(255) NULL, 36 | ForwardingSeverity int NULL, 37 | ForwardAlways int NULL, 38 | PagerToTemplate nvarchar(255) NULL, 39 | PagerCCTemplate nvarchar(255) NULL, 40 | PagerSubjectTemplate nvarchar(255) NULL, 41 | PagerSendSubjectOnly int NULL 42 | ); 43 | 44 | DECLARE @Edition nvarchar(128); 45 | DECLARE @UseDatabaseMail int; 46 | DECLARE @DatabaseMailProfile nvarchar(128); 47 | 48 | -- run only on supported Editions 49 | SET @Edition = CAST(SERVERPROPERTY('Edition') AS nvarchar(128)); 50 | IF (@Edition LIKE 'Developer%') OR 51 | (@Edition LIKE 'Enterprise%') OR 52 | (@Edition LIKE 'Business Intelligence%') OR 53 | (@Edition LIKE 'Standard%') 54 | BEGIN 55 | IF EXISTS (SELECT 1 FROM sys.configurations WHERE [name] = 'show advanced options' AND [value] = 0) 56 | BEGIN 57 | EXEC sp_configure 'show advanced options', 1; 58 | RECONFIGURE WITH OVERRIDE; 59 | END 60 | IF EXISTS (SELECT 1 FROM sys.configurations WHERE [name] = 'Agent XPs' AND [value] = 0) 61 | BEGIN 62 | EXEC sp_configure 'Agent XPs', 1; 63 | RECONFIGURE WITH OVERRIDE; 64 | END 65 | 66 | -- SQL Agent Properties 67 | INSERT INTO #sqlagent_properties 68 | EXEC msdb..sp_get_sqlagent_properties; 69 | 70 | -- Mail Profile 71 | EXEC master.dbo.xp_instance_regread 72 | N'HKEY_LOCAL_MACHINE', 73 | N'SOFTWARE\Microsoft\MSSQLServer\SQLServerAgent', 74 | N'UseDatabaseMail', 75 | @UseDatabaseMail OUTPUT; 76 | 77 | IF (@UseDatabaseMail = 1) 78 | BEGIN 79 | -- Mail Profile name 80 | EXEC master.dbo.xp_instance_regread 81 | N'HKEY_LOCAL_MACHINE', 82 | N'SOFTWARE\Microsoft\MSSQLServer\SQLServerAgent', 83 | N'DatabaseMailProfile', 84 | @DatabaseMailProfile OUTPUT; 85 | END 86 | 87 | -- check for failsafe operator 88 | INSERT INTO #sqlagent_alerts 89 | EXEC sp_MSgetalertinfo; 90 | END 91 | 92 | SELECT CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS ServerName, 93 | auto_start AS [AutoStart] 94 | ,startup_account AS [StartupAccount] 95 | ,jobhistory_max_rows AS [JobHistoryMaxRows] 96 | ,jobhistory_max_rows_per_job AS [JobHistoryMaxRowsPerJob] 97 | ,errorlog_file AS [ErrorLogFile] 98 | ,(CASE @UseDatabaseMail WHEN 1 THEN @DatabaseMailProfile ELSE '' END) AS [EmailProfile] 99 | ,FailSafeOperator 100 | FROM #sqlagent_properties 101 | CROSS APPLY #sqlagent_alerts; 102 | 103 | DROP TABLE #sqlagent_properties; 104 | DROP TABLE #sqlagent_alerts; 105 | -------------------------------------------------------------------------------- /information_collection/scripts/server_agentjobs.sql: -------------------------------------------------------------------------------- 1 | -- job information 2 | USE [tempdb]; 3 | 4 | DECLARE @SQLCmd nvarchar(max); 5 | 6 | SET @SQLCmd = ' 7 | IF OBJECT_ID(''dbo.fn_JobInterval'') IS NOT NULL 8 | BEGIN 9 | DROP FUNCTION dbo.fn_JobInterval; 10 | END'; 11 | EXEC sp_executesql @SQLCmd; 12 | 13 | SET @SQLCmd = ' 14 | CREATE FUNCTION dbo.fn_JobInterval (@IntervalValue int) 15 | RETURNS varchar(max) 16 | WITH EXECUTE AS CALLER 17 | AS 18 | BEGIN 19 | DECLARE @JobInterval varchar(max); 20 | WITH cteIntervals AS ( 21 | SELECT @IntervalValue AS IntervalValue, IntervalDescription 22 | FROM ( 23 | SELECT 1 AS IntervalValue, ''Sunday'' AS IntervalDescription UNION ALL 24 | SELECT 2, ''Monday'' UNION ALL 25 | SELECT 4, ''Tuesday'' UNION ALL 26 | SELECT 8, ''Wednesday'' UNION ALL 27 | SELECT 16, ''Thursday'' UNION ALL 28 | SELECT 32, ''Friday'' UNION ALL 29 | SELECT 64, ''Saturday'' 30 | ) a 31 | WHERE @IntervalValue & IntervalValue > 0 32 | ) 33 | SELECT @JobInterval = ( 34 | SELECT STUFF( (SELECT '','' + IntervalDescription 35 | FROM cteIntervals p2 36 | WHERE p2.IntervalValue = p1.IntervalValue 37 | ORDER BY IntervalValue 38 | FOR XML PATH(''''), TYPE).value(''.'', ''varchar(max)'') 39 | ,1,1,'''') AS Products 40 | FROM cteIntervals p1 41 | GROUP BY IntervalValue 42 | ); 43 | RETURN (@JobInterval); 44 | END'; 45 | EXEC sp_executesql @SQLCmd; 46 | 47 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 48 | SET NOCOUNT ON; 49 | SELECT 50 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS ServerName, 51 | j.[job_id] AS [JobID], j.[name] AS [JobName], j.[Enabled], msdb.dbo.SQLAGENT_SUSER_SNAME(j.owner_sid) AS [JobOwner], 52 | j.[date_created] AS [DateCreated], j.[date_modified] AS [DateModified], 53 | -- job details with step/s as XML 54 | CAST(( 55 | SELECT 56 | step_id, step_name, subsystem, command, database_name, proxy_id, 57 | on_success_action, on_success_step_id, on_fail_action, on_fail_step_id 58 | FROM [msdb].dbo.sysjobsteps 59 | WHERE job_id = j.job_id 60 | ORDER BY step_id 61 | FOR XML PATH('jobstep'), ROOT('jobsteps'), ELEMENTS XSINIL 62 | ) AS XML) AS [JobSteps], 63 | -- job details with schedule/s as XML 64 | CAST(( 65 | SELECT 66 | s.name AS schedule_name, 67 | [msdb].dbo.agent_datetime(s.active_start_date, s.active_start_time) AS schedule_time, 68 | --s.freq_type, s.freq_interval, s.freq_relative_interval, 69 | CASE s.freq_type 70 | WHEN 1 THEN 'One time only' 71 | WHEN 4 THEN 'Daily' 72 | WHEN 8 THEN 'Weekly on ' + dbo.fn_JobInterval(s.freq_interval) 73 | WHEN 16 THEN 'Monthly, on the ' + CAST(s.freq_interval as varchar(10)) + ' of the month' 74 | WHEN 32 THEN 'Monthly, on the ' + ( 75 | CASE s.freq_relative_interval 76 | WHEN 1 THEN 'first' 77 | WHEN 2 THEN 'second' 78 | WHEN 4 THEN 'third' 79 | WHEN 8 THEN 'fourth' 80 | WHEN 16 THEN 'last' 81 | ELSE '' 82 | END ) + ' ' + ( 83 | CASE s.freq_interval 84 | WHEN 1 THEN 'Sunday' 85 | WHEN 2 THEN 'Monday' 86 | WHEN 3 THEN 'Tuesday' 87 | WHEN 4 THEN 'Wednesday' 88 | WHEN 5 THEN 'Thursday' 89 | WHEN 6 THEN 'Friday' 90 | WHEN 7 THEN 'Saturday' 91 | WHEN 8 THEN 'Day' 92 | WHEN 9 THEN 'Weekday' 93 | WHEN 10 THEN 'Weekend day' 94 | ELSE '' 95 | END ) 96 | WHEN 64 THEN 'When the SQL Server Agent service starts' 97 | WHEN 128 THEN 'When the computer is idle' 98 | ELSE '' 99 | END AS [schedule_frequency], 100 | s.[enabled] AS [schedule_status] 101 | FROM [msdb].dbo.sysschedules s 102 | INNER JOIN [msdb].dbo.sysjobschedules js ON s.schedule_id = js.schedule_id 103 | WHERE js.job_id = j.job_id 104 | ORDER BY [msdb].dbo.agent_datetime(s.active_start_date, s.active_start_time) 105 | FOR XML PATH('jobschedule'), ROOT('jobschedules'), ELEMENTS XSINIL 106 | ) AS XML) AS [JobSchedules] 107 | FROM [msdb].dbo.sysjobs j; 108 | 109 | SET @SQLCmd = ' 110 | IF OBJECT_ID(''dbo.fn_JobInterval'') IS NOT NULL 111 | BEGIN 112 | DROP FUNCTION dbo.fn_JobInterval; 113 | END'; 114 | EXEC sp_executesql @SQLCmd; 115 | -------------------------------------------------------------------------------- /information_collection/scripts/server_agentjobshistory.sql: -------------------------------------------------------------------------------- 1 | -- job history 2 | SET NOCOUNT ON; 3 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED; 4 | 5 | DECLARE @StartDate datetime; 6 | SET @StartDate = CONVERT(datetime, '{0}', 120); 7 | --SET @StartDate = CONVERT(datetime, '2016-11-02 05:28:00', 120); 8 | 9 | WITH cteJobHistory AS ( 10 | SELECT 11 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS ServerName, 12 | j.[job_id] AS [JobID], j.[name] AS [JobName], h.step_id AS [StepID], h.step_name AS [StepName], 13 | [msdb].dbo.agent_datetime(h.run_date, h.run_time) AS [LastRunTime], 14 | h.run_status AS [RunStatus], -- 0 = Failed; 1 = Succeeded; 2 = Retry; 3 = Cancelled 15 | h.[message] AS [Message] 16 | FROM [msdb].dbo.sysjobs j 17 | INNER JOIN [msdb].dbo.sysjobhistory h ON j.job_id = h.job_id 18 | WHERE j.enabled = 1 AND h.step_id > 0 19 | ) 20 | SELECT * FROM cteJobHistory 21 | WHERE [LastRunTime] > @StartDate 22 | ORDER BY [LastRunTime] DESC, [JobName] ASC, [StepID] ASC; 23 | -------------------------------------------------------------------------------- /information_collection/scripts/server_configurations.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Engine Configuration 2 | SET NOCOUNT ON; 3 | 4 | SELECT 5 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS ServerName, 6 | [configuration_id] AS [ConfigID], 7 | CAST([name] AS nvarchar(255)) AS [ConfigName], -- Is this necessary? Store centrally instead of repeating set for every environment 8 | CAST([value] AS int) AS [ValueSet], 9 | CAST([value_in_use] AS int) AS [ValueInUse] 10 | FROM sys.configurations 11 | ORDER BY configuration_id ASC; 12 | -------------------------------------------------------------------------------- /information_collection/scripts/server_databases.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Engine Databases 2 | SET NOCOUNT ON; 3 | 4 | SELECT 5 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS ServerName, 6 | [name] AS [DatabaseName], 7 | SUSER_SNAME([owner_sid]) AS [DatabaseOwner], 8 | CONVERT(datetime, [create_date]) AS [CreateDate], 9 | [compatibility_level] AS [CompatibilityLevel], 10 | COALESCE([collation_name], '') AS [CollationName], 11 | [user_access_desc] AS [UserAccess], 12 | [is_read_only] AS [IsReadOnly], 13 | [is_auto_close_on] AS [IsAutoClose], 14 | [is_auto_shrink_on] AS [IsAutoShrink], 15 | [state_desc] AS [State], 16 | [is_in_standby] AS [IsInStandby], 17 | [recovery_model_desc] AS [RecoveryModel], 18 | [page_verify_option_desc] AS [PageVerifyOption], 19 | [is_fulltext_enabled] AS [IsFullTextEnabled], 20 | [is_trustworthy_on] AS [IsTrustworthy] 21 | FROM sys.databases 22 | ORDER BY database_id ASC; 23 | -------------------------------------------------------------------------------- /information_collection/scripts/server_endpoints.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Engine Configuration 2 | SET NOCOUNT ON; 3 | 4 | SELECT 5 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS ServerName, 6 | [name] AS [EndpointName], 7 | COALESCE(SUSER_NAME(principal_id), '') AS [Owner], 8 | COALESCE([protocol_desc], '') AS [ProtocolDesc], 9 | COALESCE([type_desc], '') AS [PayloadType], 10 | COALESCE([state_desc], '') AS [StateDesc], 11 | [is_admin_endpoint] AS [Is AdminEndpoint] 12 | FROM sys.endpoints 13 | WHERE [endpoint_id] > 5; 14 | -------------------------------------------------------------------------------- /information_collection/scripts/server_errorlog.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Engine Security 2 | SET NOCOUNT ON; 3 | SET DATEFORMAT mdy; 4 | 5 | DECLARE @ErrorLogNumber int; 6 | DECLARE @ErrorMsg nvarchar(500); 7 | DECLARE @SQLCmd nvarchar(4000); 8 | DECLARE @StartDate datetime; 9 | 10 | SET @ErrorLogNumber = 0; 11 | --SET @ErrorMsg = N'Login failed for user'; 12 | SET @ErrorMsg = N''; 13 | SET @SQLCmd = N''; 14 | SET @StartDate = CONVERT(datetime, '{0}', 120); 15 | 16 | CREATE TABLE #ErrorLogs ( 17 | [LogNumber] int, 18 | [LogDate] datetime, 19 | [LogSize] int 20 | ); 21 | 22 | CREATE TABLE #ErrorLog ( 23 | [LogDate] datetime, 24 | [ProcessInfo] nvarchar(128), 25 | [LogText] varchar(max) 26 | ); 27 | 28 | -- exclude servers 29 | IF CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) NOT IN ( 30 | N'SRVR01', 31 | N'SRVR99') 32 | BEGIN 33 | INSERT INTO #ErrorLogs 34 | EXEC sys.sp_enumerrorlogs; 35 | 36 | DECLARE L1 CURSOR FOR 37 | SELECT [LogNumber] FROM #ErrorLogs WHERE [LogDate] >= @StartDate 38 | UNION ALL 39 | SELECT TOP(1) [LogNumber] FROM #ErrorLogs WHERE [LogDate] < @StartDate ORDER BY [LogNumber] ASC; 40 | OPEN L1; 41 | FETCH NEXT FROM L1 INTO @ErrorLogNumber; 42 | WHILE (@@FETCH_STATUS = 0) 43 | BEGIN 44 | SET @SQLCmd = N'EXEC sys.sp_readerrorlog ' + CAST(@ErrorLogNumber AS nvarchar(10)) + N', 1, ''' + @ErrorMsg + N''';' 45 | INSERT INTO #ErrorLog 46 | EXEC sp_executesql @SQLCmd; 47 | 48 | FETCH NEXT FROM L1 INTO @ErrorLogNumber; 49 | END 50 | CLOSE L1; 51 | DEALLOCATE L1; 52 | END 53 | 54 | SELECT 55 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) as [ServerName], 56 | [LogDate], 2 57 | [ProcessInfo], 58 | [LogText] 59 | FROM #ErrorLog 60 | WHERE [LogDate] > @StartDate 61 | AND [LogText] IS NOT NULL 62 | ORDER BY [LogDate] ASC; 63 | 64 | DROP TABLE #ErrorLogs; 65 | DROP TABLE #ErrorLog; 66 | -------------------------------------------------------------------------------- /information_collection/scripts/server_freespace.sql: -------------------------------------------------------------------------------- 1 | SET NOCOUNT ON; 2 | 3 | CREATE TABLE #FreeSpace( 4 | Drive char(1), 5 | FreeMB int 6 | ); 7 | 8 | INSERT INTO #FreeSpace 9 | EXEC master..xp_fixeddrives; 10 | 11 | SELECT 12 | CONVERT(varchar(100), SERVERPROPERTY('Servername')) AS Server, 13 | Drive, 14 | FreeMB 15 | FROM #FreeSpace; 16 | 17 | DROP TABLE #FreeSpace; 18 | -------------------------------------------------------------------------------- /information_collection/scripts/server_info.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Engine Configuration 2 | SET NOCOUNT ON; 3 | 4 | DECLARE @SQLVer TABLE ( 5 | [ID] int, 6 | [Name] nvarchar(128), 7 | [Internal_Value] int, 8 | [Value] nvarchar(512) 9 | ); 10 | INSERT INTO @SQLVer EXEC master.dbo.xp_msver; 11 | 12 | -- get sql installation folder from registry 13 | DECLARE @SQLRoot nvarchar(512) 14 | 15 | EXEC master.dbo.xp_instance_regread 16 | N'HKEY_LOCAL_MACHINE', N'SOFTWARE\Microsoft\MSSQLServer\Setup', 17 | N'SQLPath', 18 | @SQLRoot OUTPUT; 19 | 20 | INSERT INTO @SQLVer(Name, Value) 21 | VALUES ('SQLRootDir', ISNULL(@SQLRoot, '')); 22 | 23 | -- get other options 24 | SELECT 25 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS ServerName, 26 | CONVERT(nvarchar(128), SERVERPROPERTY('ProductVersion')) AS ProductVersion, 27 | CONVERT(nvarchar(128), SERVERPROPERTY('ProductLevel')) AS ProductLevel, 28 | CONVERT(datetime, SERVERPROPERTY('ResourceLastUpdateDateTime')) AS ResourceLastUpdateDateTime, 29 | CONVERT(nvarchar(128), SERVERPROPERTY('ResourceVersion')) AS ResourceVersion, 30 | CASE CONVERT(int, SERVERPROPERTY('IsIntegratedSecurityOnly')) 31 | WHEN 0 THEN 'SQL Server and Windows' 32 | WHEN 1 THEN 'Windows only' 33 | ELSE 'Error' 34 | END AS ServerAuthentication, 35 | CONVERT(nvarchar(128), SERVERPROPERTY('Edition')) AS Edition, 36 | COALESCE(CONVERT(nvarchar(128), SERVERPROPERTY('InstanceName')), '') AS InstanceName, 37 | CONVERT(nvarchar(128), SERVERPROPERTY('ComputerNamePhysicalNetBIOS')) AS ComputerNamePhysicalNetBIOS, 38 | CONVERT(nvarchar(128), SERVERPROPERTY('BuildClrVersion')) AS BuildClrVersion, 39 | CONVERT(nvarchar(128), SERVERPROPERTY('Collation')) AS Collation, 40 | CAST(SERVERPROPERTY('IsClustered') AS [bit]) AS IsClustered, 41 | CAST(SERVERPROPERTY('IsFullTextInstalled') AS [bit]) AS IsFullTextInstalled, 42 | CONVERT(nvarchar(128), SERVERPROPERTY('SqlCharSetName')) AS SqlCharSetName, 43 | CONVERT(nvarchar(128), SERVERPROPERTY('SqlSortOrderName')) AS SqlSortOrderName, 44 | (SELECT Value FROM @SQLVer WHERE Name = N'SQLRootDir') AS [SqlRootPath], 45 | (SELECT Value FROM @SQLVer WHERE Name = N'ProductName') AS [Product], 46 | (SELECT Value FROM @SQLVer WHERE Name = N'Language') AS [Language], 47 | (SELECT Value FROM @SQLVer WHERE Name = N'Platform') AS [Platform], 48 | (SELECT Internal_Value FROM @SQLVer WHERE Name = N'ProcessorCount') AS [LogicalProcessors], 49 | (SELECT Value FROM @SQLVer WHERE Name = N'WindowsVersion') AS [OSVersion], 50 | (SELECT Internal_Value FROM @SQLVer WHERE Name = N'PhysicalMemory') AS [TotalMemoryMB]; 51 | -------------------------------------------------------------------------------- /information_collection/scripts/server_logins.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Engine Security 2 | SET NOCOUNT ON; 3 | 4 | SELECT 5 | [ServerName], [LoginName], [Type], [CreateDate], [ModifyDate], 6 | CONVERT(datetime, LOGINPROPERTY([LoginName], 'PasswordLastSetTime')) AS [PasswordLastSet], 7 | [DefaultDatabase], [DefaultLanguage], [IsDisabled], [IsPolicyChecked], [IsExpirationChecked], 8 | SUM([sysadmin]) AS [sysadmin], SUM([securityadmin]) AS [securityadmin], SUM([serveradmin]) AS [serveradmin], SUM([setupadmin]) AS [setupadmin], 9 | SUM([processadmin]) AS [processadmin], SUM([diskadmin]) AS [diskadmin], SUM([dbcreator]) AS [dbcreator], SUM([bulkadmin]) AS [bulkadmin], 10 | COALESCE(d.[permission_name], '') AS [SecurablesPermissions] 11 | FROM ( 12 | SELECT 13 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS [ServerName], 14 | sp.[sid] AS [sid], 15 | sp.[name] AS [LoginName], 16 | sp.[type_desc] AS [Type], 17 | CONVERT(datetime, sp.[create_date]) AS [CreateDate], 18 | CONVERT(datetime, sp.[modify_date]) AS [ModifyDate], 19 | COALESCE(sp.[default_database_name], '') AS [DefaultDatabase], 20 | COALESCE(sp.[default_language_name], '') AS [DefaultLanguage], 21 | sp.[is_disabled] AS [IsDisabled], 22 | COALESCE(sl.[is_policy_checked], 0) AS [IsPolicyChecked], 23 | COALESCE(sl.[is_expiration_checked], 0) AS [IsExpirationChecked], 24 | CASE COALESCE(SUSER_NAME([srm].[role_principal_id]), '') WHEN 'sysadmin' THEN 1 ELSE 0 END AS [sysadmin], 25 | CASE COALESCE(SUSER_NAME([srm].[role_principal_id]), '') WHEN 'securityadmin' THEN 1 ELSE 0 END AS [securityadmin], 26 | CASE COALESCE(SUSER_NAME([srm].[role_principal_id]), '') WHEN 'serveradmin' THEN 1 ELSE 0 END AS [serveradmin], 27 | CASE COALESCE(SUSER_NAME([srm].[role_principal_id]), '') WHEN 'setupadmin' THEN 1 ELSE 0 END AS [setupadmin], 28 | CASE COALESCE(SUSER_NAME([srm].[role_principal_id]), '') WHEN 'processadmin' THEN 1 ELSE 0 END AS [processadmin], 29 | CASE COALESCE(SUSER_NAME([srm].[role_principal_id]), '') WHEN 'diskadmin' THEN 1 ELSE 0 END AS [diskadmin], 30 | CASE COALESCE(SUSER_NAME([srm].[role_principal_id]), '') WHEN 'dbcreator' THEN 1 ELSE 0 END AS [dbcreator], 31 | CASE COALESCE(SUSER_NAME([srm].[role_principal_id]), '') WHEN 'bulkadmin' THEN 1 ELSE 0 END AS [bulkadmin] 32 | FROM [sys].[server_principals] sp 33 | LEFT JOIN [sys].[sql_logins] sl ON sp.[sid] = sl.[sid] 34 | LEFT JOIN [sys].[server_role_members] srm ON sp.[principal_id] = srm.[member_principal_id] 35 | WHERE sp.[type] LIKE '[GSU]' 36 | ) a 37 | CROSS APPLY ( 38 | SELECT STUFF( 39 | (SELECT N',' + [srvperm].[permission_name] + N' (' + [srvperm].[class_desc] + ( 40 | CASE [srvperm].[class_desc] 41 | WHEN N'SERVER' THEN N'' 42 | WHEN N'ENDPOINT' THEN N' ' + (SELECT CONVERT(nvarchar(10), port) FROM sys.tcp_endpoints WHERE endpoint_id >= 65536 AND endpoint_id = srvperm.major_id) 43 | ELSE N'' 44 | END 45 | ) + N')' 46 | FROM [sys].[server_permissions] srvperm 47 | INNER JOIN [sys].[server_principals] srvprin ON [srvperm].[grantee_principal_id] = [srvprin].[principal_id] 48 | WHERE [srvprin].sid = a.sid 49 | AND [srvperm].[permission_name] <> 'CONNECT SQL' 50 | ORDER BY srvprin.[name], srvperm.class, [permission_name] 51 | FOR XML PATH(''), TYPE).value('.', 'varchar(max)') 52 | ,1,1,'') 53 | ) D ( [permission_name] ) 54 | 55 | GROUP BY [ServerName], [LoginName], [Type], [CreateDate], [ModifyDate], [DefaultDatabase], [DefaultLanguage], [IsDisabled], [IsPolicyChecked], [IsExpirationChecked], d.[permission_name] 56 | ORDER BY [Type], [LoginName]; 57 | -------------------------------------------------------------------------------- /information_collection/scripts/server_servers.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Engine Configuration 2 | SET NOCOUNT ON; 3 | 4 | SELECT 5 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS [ServerName] 6 | ,[server_id] AS [ServerID] 7 | ,[name] AS [LinkedServer] 8 | ,[product] AS [ProductName] 9 | ,[provider] AS [ProviderName] 10 | ,[data_source] AS [DataSource] 11 | ,[provider_string] AS [ProviderString] 12 | ,[catalog] AS [CatalogConnection] 13 | FROM sys.servers 14 | ORDER BY [server_id] ASC; -------------------------------------------------------------------------------- /information_collection/scripts/server_triggers.sql: -------------------------------------------------------------------------------- 1 | -- Category: Database Engine Configuration 2 | SET NOCOUNT ON; 3 | 4 | SELECT 5 | CONVERT(nvarchar(128), SERVERPROPERTY('ServerName')) AS ServerName 6 | ,[name] AS [ObjectName] 7 | ,[type_desc] AS [ObjectType] 8 | ,CAST([create_date] AS datetime) AS [CreateDate] 9 | ,CAST([modify_date] AS datetime) AS [ModifyDate] 10 | ,is_disabled AS [IsDisabled] 11 | FROM sys.server_triggers 12 | ORDER BY [name] ASC; 13 | -------------------------------------------------------------------------------- /information_collection/tasks/README.md: -------------------------------------------------------------------------------- 1 | # SQLMonitor Automation Schedules 2 | Used to create scheduled tasks if using the Express Edition 3 | -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Export Failed Logins Daily.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Export Failed Logins Daily.xml -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Get-ServerInfo Annual.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Get-ServerInfo Annual.xml -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Get-ServerInfo Daily.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Get-ServerInfo Daily.xml -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Get-ServerInfo Hourly.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Get-ServerInfo Hourly.xml -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Get-ServerInfo Manual.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Get-ServerInfo Manual.xml -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Get-ServerInfo Minute.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Get-ServerInfo Minute.xml -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Get-ServerInfo Monthly.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Get-ServerInfo Monthly.xml -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Get-ServerInfo Weekly.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Get-ServerInfo Weekly.xml -------------------------------------------------------------------------------- /information_collection/tasks/SQLMonitor Invoke-ArchiveMaintenance Daily.xml: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/reubensultana/SQLMonitor/ee19bc8150ffd434c5b76d1f96a28638ac09d512/information_collection/tasks/SQLMonitor Invoke-ArchiveMaintenance Daily.xml --------------------------------------------------------------------------------