diff --git a/ALLOW_PAGE_LOCKS.sql b/ALLOW_PAGE_LOCKS.sql new file mode 100644 index 0000000..a90eb81 --- /dev/null +++ b/ALLOW_PAGE_LOCKS.sql @@ -0,0 +1,8 @@ +select 'alter INDEX [' + i.name + '] ON [' + s.name + '].[' + o.name + '] SET (ALLOW_PAGE_LOCKS = ON) --this is default' +, * from sys.indexes i +inner join sys.objects o on i.object_id = o.object_id +inner join sys.schemas s on s.schema_id = o.schema_id +where allow_page_locks = 0 +and o.is_ms_shipped = 0 + + diff --git a/Add SQL Agent Failure Notifications job.sql b/Add SQL Agent Failure Notifications job.sql new file mode 100644 index 0000000..3283653 --- /dev/null +++ b/Add SQL Agent Failure Notifications job.sql @@ -0,0 +1,140 @@ +--TODO: Change the operator name dbadministrators@sparkhound.com +--TODO: Uncomment --EXEC (@TSQL) when confirmed + +USE [msdb] +GO + +--These jobs do not have a notify operator setting +select j.job_id, j.name, CategoryName = jc.name, j.enabled, j.description +, OwnerName = suser_sname(j.owner_sid), date_created,date_modified, j.notify_email_operator_id + from msdb.dbo.sysjobs j +inner join msdb.dbo.syscategories jc +on j.category_id = jc.category_id +where j.notify_email_operator_id = 0 +and j.name not in ('syspolicy_purge_history') + +DECLARE AddFailureNotifications CURSOR FAST_FORWARD +FOR +select convert(nvarchar(4000), ' +EXEC msdb.dbo.sp_update_job @job_id=N'''+convert(varchar(64), job_id)+''', /*'+j.name+'*/ + @notify_level_email=2, + @notify_email_operator_name=N''dbadministrators@sparkhound.com''') +from msdb.dbo.sysjobs j +where j.notify_email_operator_id = 0 +and j.name not in ('syspolicy_purge_history') + +declare @tsql nvarchar(4000) = null +OPEN AddFailureNotifications +FETCH NEXT FROM AddFailureNotifications +INTO @tsql + +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC (@TSQL) + SELECT @TSQL + FETCH NEXT FROM AddFailureNotifications + INTO @tsql +END + +CLOSE AddFailureNotifications +DEALLOCATE AddFailureNotifications; + +/* + + +--Change the operator name dbadministrators@sparkhound.com +--you may need to change the @server_name value below + +USE [msdb] +GO + +BEGIN TRANSACTION +DECLARE @ReturnCode INT +SELECT @ReturnCode = 0 + +IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1) +BEGIN +EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]' +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback + +END + +DECLARE @jobId BINARY(16) +EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Add Failure Notifications', + @enabled=1, + @notify_level_eventlog=2, + @notify_level_email=2, + @notify_level_netsend=0, + @notify_level_page=0, + @delete_level=0, + @description=N'Adds failure notification emails to any jobs that are created', + @category_name=N'[Uncategorized (Local)]', + @owner_login_name=N'sa', + @notify_email_operator_name=N'dbadministrators@sparkhound.com', @job_id = @jobId OUTPUT +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback + +EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'tsql', + @step_id=1, + @cmdexec_success_code=0, + @on_success_action=1, + @on_success_step_id=0, + @on_fail_action=2, + @on_fail_step_id=0, + @retry_attempts=0, + @retry_interval=0, + @os_run_priority=0, @subsystem=N'TSQL', + @command=N'USE [msdb] +GO + +DECLARE AddFailureNotifications CURSOR FAST_FORWARD +FOR +select convert(nvarchar(4000), '' +EXEC msdb.dbo.sp_update_job @job_id=N''''''+convert(varchar(64), job_id)+'''''', + @notify_level_email=2, + @notify_level_netsend=2, + @notify_level_page=2, + @notify_email_operator_name=N''''dbadministrators@sparkhound.com'''''') +from msdb.dbo.sysjobs +where notify_email_operator_id = 0 + +declare @tsql nvarchar(4000) = null +OPEN AddFailureNotifications +FETCH NEXT FROM AddFailureNotifications +INTO @tsql + +WHILE @@FETCH_STATUS = 0 +BEGIN + EXEC (@TSQL) + FETCH NEXT FROM AddFailureNotifications + INTO @tsql +END', + @database_name=N'msdb', + @flags=4 +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1 +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'nightly', + @enabled=1, + @freq_type=4, + @freq_interval=1, + @freq_subday_type=1, + @freq_subday_interval=0, + @freq_relative_interval=0, + @freq_recurrence_factor=0, + @active_start_date=20150216, + @active_end_date=99991231, + @active_start_time=200000, + @active_end_time=235959, + @schedule_uid=N'fd1a2b03-1e0b-487d-ac6f-9eac60fc4f6a' +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)' +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +COMMIT TRANSACTION +GOTO EndSave +QuitWithRollback: + IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION +EndSave: + +GO + +*/ \ No newline at end of file diff --git a/Add SQL Agent Failure Notifications.sql b/Add SQL Agent Failure Notifications.sql new file mode 100644 index 0000000..0cb90b8 --- /dev/null +++ b/Add SQL Agent Failure Notifications.sql @@ -0,0 +1,39 @@ +--TODO: Change the operator name sql.alerts@sparkhound.com +--TODO: Uncomment --EXEC (@TSQL) when confirmed + + +--These jobs do not have a notify operator setting +select j.job_id, j.name, CategoryName = jc.name, j.enabled, j.description +, OwnerName = suser_sname(j.owner_sid), date_created,date_modified, j.notify_email_operator_id + from msdb.dbo.sysjobs j +inner join msdb.dbo.syscategories jc +on j.category_id = jc.category_id +where j.notify_email_operator_id = 0 +and j.name not in ('syspolicy_purge_history') + +DECLARE AddFailureNotifications CURSOR FAST_FORWARD +FOR +select convert(nvarchar(4000), ' +EXEC msdb.dbo.sp_update_job @job_id=N'''+convert(varchar(64), job_id)+''', /*'+j.name+'*/ + @notify_level_email=2, + @notify_email_operator_name=N''sql.alerts@sparkhound.com''') +from msdb.dbo.sysjobs j +where j.notify_email_operator_id = 0 +and j.name not in ('syspolicy_purge_history') + +declare @tsql nvarchar(4000) = null +OPEN AddFailureNotifications +FETCH NEXT FROM AddFailureNotifications +INTO @tsql + +WHILE @@FETCH_STATUS = 0 +BEGIN + --EXEC (@TSQL) + SELECT @TSQL + FETCH NEXT FROM AddFailureNotifications + INTO @tsql +END + +CLOSE AddFailureNotifications +DEALLOCATE AddFailureNotifications; + diff --git a/Availability Groups/AG owner.sql b/Availability Groups/AG owner.sql new file mode 100644 index 0000000..57dfcd5 --- /dev/null +++ b/Availability Groups/AG owner.sql @@ -0,0 +1,18 @@ +--should not be owned by named account! + +SELECT ar.replica_server_name + ,ag.name AS ag_name + ,ar.owner_sid + ,sp.name +FROM sys.availability_replicas ar +LEFT JOIN sys.server_principals sp + ON sp.sid = ar.owner_sid +INNER JOIN sys.availability_groups ag + ON ag.group_id = ar.group_id +WHERE ar.replica_server_name = SERVERPROPERTY('ServerName') ; + +/* + +ALTER AUTHORIZATION ON AVAILABILITY GROUP::[drAG1] to [sa] ; + +*/ \ No newline at end of file diff --git a/Availability Groups/AG_Monitor.sql b/Availability Groups/AG_Monitor.sql new file mode 100644 index 0000000..65bd999 --- /dev/null +++ b/Availability Groups/AG_Monitor.sql @@ -0,0 +1,77 @@ +--On a secondary replica, this view returns a row for every secondary database on the server instance. +--On the primary replica, this view returns a row for each primary database and an additional row for the corresponding secondary database. + +--Updated WDA 20170622 + +IF NOT EXISTS ( +SELECT @@SERVERNAME, * + FROM sys.dm_hadr_availability_replica_states rs + inner join sys.availability_databases_cluster dc + on rs.group_id = dc.group_id + WHERE is_local = 1 + and role_desc = 'PRIMARY' +) + SELECT 'Recommend: Run This Script on Primary Replica'; + + +declare @start_tick bigint, @start_cntr bigint + +select @start_tick = MAX(ms_ticks), @start_cntr = MAX(cntr_value) --the availability database with the highest Tdata_loss becomes the limiting value for RPO compliance. +from sys.dm_os_sys_info +cross apply sys.dm_os_performance_counters where counter_name like 'Log Bytes Flushed/sec%' + +waitfor delay '00:00:02' + +declare @end_tick bigint, @end_cntr bigint +select @end_tick = MAX(ms_ticks), @end_cntr = MAX(cntr_value) --the availability database with the highest Tdata_loss becomes the limiting value for RPO compliance. +from sys.dm_os_sys_info +cross apply sys.dm_os_performance_counters where counter_name like 'Log Bytes Flushed/sec%' + +declare @LogBytesFushed decimal(19,2) +set @LogBytesFushed = (@end_cntr - @start_cntr) / NULLIF(@end_tick - @start_tick,0) + +select + Replica = ar.replica_server_name + ' ' + case when is_local = 1 then '(local)' else '' end +, Replica_Role = case when last_received_time is null then 'PRIMARY' ELSE 'SECONDARY ('+ar.secondary_role_allow_connections_desc+')' END +, DB = db_name(database_id) +, dm.synchronization_state_desc +, dm.synchronization_health_desc +, ar.availability_mode_desc +, ar.failover_mode_desc +, Suspended = case is_suspended when 1 then suspend_reason_desc else null end +, last_received_time +, last_commit_time +, redo_queue_size_mb = redo_queue_size/1024. +, Redo_Time_Left_s_RTO = dm.redo_queue_size/NULLIF(dm.redo_rate,0) --https://msdn.microsoft.com/en-us/library/dn135338(v=sql.110).aspx --only part of RTO +, Log_Send_Queue_RPO = dm.log_send_queue_size/NULLIF(@LogBytesFushed ,0) --Rate +, ar.backup_priority +, ar.modify_date +, ar.endpoint_url +, ar.read_only_routing_url +from sys.dm_hadr_database_replica_states dm +INNER JOIN sys.availability_replicas ar on dm.replica_id = ar.replica_id and dm.group_id = ar.group_id +ORDER BY DB, [Replica], Replica_Role +--WHERE db_name(database_id) = 'operations' + +--SELECT log_reuse_wait_desc FROM sys.databases WHERE name = 'operations' + +--Check for suspect pages (hopefully 0 rows returned) +--https://msdn.microsoft.com/en-us/library/ms191301.aspx +SELECT * FROM msdb.dbo.suspect_pages + WHERE (event_type <= 3); + +--Check for autorepair events (hopefully 0 rows returned) +--https://msdn.microsoft.com/en-us/library/bb677167.aspx +select db = db_name(database_id) +, file_id +, page_id +, error_type +, page_status +, modification_time +from sys.dm_hadr_auto_page_repair order by modification_time desc + + +--https://msdn.microsoft.com/en-us/library/ff877972(v=sql.110).aspx +--https://msdn.microsoft.com/en-us/library/dn135338(v=sql.110).aspx +--https://blogs.msdn.microsoft.com/psssql/2013/09/23/interpreting-the-counter-values-from-sys-dm_os_performance_counters/ +--https://msdn.microsoft.com/en-us/library/ms175048.aspx \ No newline at end of file diff --git a/Availability Groups/AG_PerfMon_Counters.sql b/Availability Groups/AG_PerfMon_Counters.sql new file mode 100644 index 0000000..4911c28 --- /dev/null +++ b/Availability Groups/AG_PerfMon_Counters.sql @@ -0,0 +1,89 @@ +declare @tempperfmon table ( +[object_name] nchar (256) null, +counter_name nchar (256) null, +instance_name nchar (256) null, +cntr_value bigint null +, second_value bigint null +) + +--For databases both the primary and secondary, with send/receive counters reflecting the local replica +insert into @tempperfmon ([object_name],counter_name,instance_name,cntr_value) +select [object_name],counter_name,instance_name,cntr_value +from sys.dm_os_performance_counters + where [object_name] like '%Availability Replica%' and instance_name <> '_Total' and + ( counter_name = 'Bytes Received from Replica/sec' --From the availability replica. Pings and status updates will generate network traffic even on databases with no user updates. + or counter_name = 'Bytes Sent to Replica/sec' --Sent to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica. + or counter_name = 'Bytes Sent to Transport/sec' --Sent over the network to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica. + or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second. + or counter_name = 'Receives from Replica/Sec' + or counter_name = 'Sends to Replica/Sec' + + ) + +insert into @tempperfmon ([object_name],counter_name,instance_name,cntr_value) +--Only valid for databases in the secondary replica role +select [object_name],counter_name,instance_name,cntr_value +from sys.dm_os_performance_counters + where [object_name] like '%database replica%' and instance_name <> '_Total' and + ( counter_name = 'File Bytes Received/sec' --FILESTREAM data only + or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.' + or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase. + ) + +WAITFOR DELAY '00:00:05'; --5s + + +--For databases both the primary and secondary, with send/receive counters reflecting the local replica +insert into @tempperfmon ([object_name],counter_name,instance_name,second_value) +select [object_name],counter_name,instance_name,cntr_value +from sys.dm_os_performance_counters + where [object_name] like '%Availability Replica%' and instance_name <> '_Total' and + ( counter_name = 'Bytes Received from Replica/sec' --From the availability replica. Pings and status updates will generate network traffic even on databases with no user updates. + or counter_name = 'Bytes Sent to Replica/sec' --Sent to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica. + or counter_name = 'Bytes Sent to Transport/sec' --Sent over the network to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica. + or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second. + or counter_name = 'Receives from Replica/Sec' + or counter_name = 'Sends to Replica/Sec' + + ) + +insert into @tempperfmon ([object_name],counter_name,instance_name,second_value) +--Only valid for databases in the secondary replica role +select [object_name],counter_name,instance_name,cntr_value +from sys.dm_os_performance_counters + where [object_name] like '%database replica%' and instance_name <> '_Total' and + ( counter_name = 'File Bytes Received/sec' --FILESTREAM data only + or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.' + or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase. + ) + +select +[object_name],counter_name,instance_name +, Observation = (max(second_value) - max(cntr_value)) /5. +from @tempperfmon +group by [object_name],counter_name,instance_name + +/* +--For databases both the primary and secondary, with send/receive counters reflecting the local replica +select object_name,counter_name,instance_name,cntr_value +from sys.dm_os_performance_counters + where object_name like '%Availability Replica%' and instance_name <> '_Total' and + ( counter_name = 'Bytes Received from Replica/sec' --From the availability replica. Pings and status updates will generate network traffic even on databases with no user updates. + or counter_name = 'Bytes Sent to Replica/sec' --Sent to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica. + or counter_name = 'Bytes Sent to Transport/sec' --Sent over the network to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica. + or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second. + or counter_name = 'Receives from Replica/Sec' + or counter_name = 'Sends to Replica/Sec' + + ) + + +--Only valid for databases in the secondary replica role +select object_name,counter_name,instance_name,cntr_value +from sys.dm_os_performance_counters + where object_name like '%database replica%' and instance_name <> '_Total' and + ( counter_name = 'File Bytes Received/sec' --FILESTREAM data only + or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.' + or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase. + ) +*/ \ No newline at end of file diff --git a/Availability Groups/AG_timing.sql b/Availability Groups/AG_timing.sql new file mode 100644 index 0000000..ed8cad3 --- /dev/null +++ b/Availability Groups/AG_timing.sql @@ -0,0 +1,63 @@ + +;WITH AG_Stats AS ( + SELECT AGS.name AS AGGroupName, + AR.replica_server_name AS InstanceName, + HARS.role_desc, + Db_name(DRS.database_id) AS DBName, + DRS.database_id, + AR.availability_mode_desc AS SyncMode, + DRS.synchronization_state_desc AS SyncState, + DRS.last_hardened_lsn, + DRS.end_of_log_lsn, + DRS.last_redone_lsn, + DRS.last_hardened_time, -- On a secondary database, time of the log-block identifier for the last hardened LSN (last_hardened_lsn). + DRS.last_redone_time, -- Time when the last log record was redone on the secondary database. + DRS.log_send_queue_size, + DRS.redo_queue_size, + Redo_Time_Left_s = DRS.redo_queue_size/DRS.redo_rate, + DRS.last_commit_time -- select * + FROM sys.dm_hadr_database_replica_states DRS + LEFT JOIN sys.availability_replicas AR + ON DRS.replica_id = AR.replica_id + LEFT JOIN sys.availability_groups AGS + ON AR.group_id = AGS.group_id + LEFT JOIN sys.dm_hadr_availability_replica_states HARS ON AR.group_id = HARS.group_id + AND AR.replica_id = HARS.replica_id + ), + Pri_CommitTime AS + ( + SELECT DBName + , last_commit_time + FROM AG_Stats + WHERE role_desc = 'PRIMARY' + ), + Rpt_CommitTime AS + ( + SELECT DBName, last_commit_time + FROM AG_Stats + WHERE role_desc = 'SECONDARY' AND [InstanceName] = 'SQLSERVER-1' + ), + FO_CommitTime AS + ( + SELECT DBName, last_commit_time + FROM AG_Stats + WHERE role_desc = 'SECONDARY' AND ([InstanceName]in ( 'SQLSERVER-0') ) + ) +SELECT p.[DBName] AS [DatabaseName] + , a.AGGroupName + , a.InstanceName + , a.role_desc + , a.SyncMode + , a.SyncState + , a.Redo_Time_Left_s + , p.last_commit_time AS [Primary_Last_Commit_Time] + , r.last_commit_time AS [Reporting_Last_Commit_Time] + , DATEDIFF(ss,r.last_commit_time,p.last_commit_time) AS [Reporting_Sync_Lag_(secs)] + , f.last_commit_time AS [FailOver_Last_Commit_Time] + , DATEDIFF(ss,f.last_commit_time,p.last_commit_time) AS [FailOver_Sync_Lag_(secs)] +FROM AG_Stats a +INNER JOIN Pri_CommitTime p ON p.DBName = a.DBName +LEFT JOIN Rpt_CommitTime r ON [r].[DBName] = [p].[DBName] +LEFT JOIN FO_CommitTime f ON [f].[DBName] = [p].[DBName] + +--stolen from http://dba.stackexchange.com/questions/60624/check-the-data-latency-between-two-always-on-availability-group-servers-in-async \ No newline at end of file diff --git a/Availability Groups/AOGCollectInformation.sql b/Availability Groups/AOGCollectInformation.sql new file mode 100644 index 0000000..38b30d4 --- /dev/null +++ b/Availability Groups/AOGCollectInformation.sql @@ -0,0 +1,65 @@ +--Inventory Baseline +select + c.cluster_name + ,c.quorum_state_desc + ,c.quorum_type_desc +from sys.dm_hadr_cluster c + +select + cm.member_name + ,cm.member_state_desc + ,cm.member_type_desc + ,cm.number_of_quorum_votes +from sys.dm_hadr_cluster_members cm + +select + cn.member_name + ,cn.is_ipv4 + ,cn.is_public + ,cn.network_subnet_ip + ,cn.network_subnet_ipv4_mask + ,cn.network_subnet_prefix_length +from sys.dm_hadr_cluster_networks cn + +SELECT + gs.primary_replica + ,gs.primary_recovery_health_desc + ,gs.secondary_recovery_health + ,gs.synchronization_health_desc + ,rcs.replica_server_name + ,rcs.join_state_desc + ,rs.role_desc + ,rs.operational_state_desc + ,rs.connected_state_desc + ,rs.synchronization_health_desc +from sys.dm_hadr_availability_group_states gs +inner join sys.dm_hadr_availability_replica_cluster_states rcs + on gs.group_id=rcs.group_id +inner join sys.dm_hadr_availability_replica_states rs + on rcs.group_id=rs.group_id + and rcs.replica_id=rs.replica_id + + + +select + rcs.replica_server_name + ,rs.role_desc + ,rs.operational_state_desc + ,rs.connected_state_desc + ,drcs.database_name + ,drs.database_state_desc + ,drs.filestream_send_rate + ,drs.is_primary_replica + ,case when drcs.is_database_joined = 1 then 'True' else 'False' end as [is_database_joined] + ,case when drcs.is_failover_ready =1 then 'True' else 'False' end as [is_failover_read] + ,case when drcs.is_pending_secondary_suspend=1 then 'True' else 'False' end as [is_pending_secondary_suspend] +from sys.dm_hadr_database_replica_cluster_states drcs +inner join sys.dm_hadr_database_replica_states drs + on drs.group_database_id=drcs.group_database_id + and drs.replica_id=drcs.replica_id +inner join sys.dm_hadr_availability_replica_cluster_states rcs + on drs.group_id= rcs.group_id + and drs.replica_id=rcs.replica_id +inner join sys.dm_hadr_availability_replica_states rs + on rcs.group_id=rs.group_id + and rcs.replica_id=rs.replica_id \ No newline at end of file diff --git a/Availability Groups/All_hadr.sql b/Availability Groups/All_hadr.sql new file mode 100644 index 0000000..67753af --- /dev/null +++ b/Availability Groups/All_hadr.sql @@ -0,0 +1,16 @@ +select * from sys.dm_hadr_cluster +select * from sys.dm_hadr_cluster_members +select * from sys.dm_hadr_cluster_networks +select * from sys.availability_groups +select * from sys.availability_groups_cluster +select * from sys.dm_hadr_availability_group_states +select * from sys.availability_replicas +select * from sys.dm_hadr_availability_replica_cluster_nodes +select * from sys.dm_hadr_availability_replica_cluster_states +select * from sys.dm_hadr_availability_replica_states +select * from sys.dm_hadr_auto_page_repair +select * from sys.dm_hadr_database_replica_states +select * from sys.dm_hadr_database_replica_cluster_states +select * from sys.availability_group_listener_ip_addresses +select * from sys.availability_group_listeners +select * from sys.dm_tcp_listener_states \ No newline at end of file diff --git a/Availability Groups/AlwaysOn_extendedEvents_Create.sql b/Availability Groups/AlwaysOn_extendedEvents_Create.sql new file mode 100644 index 0000000..0d31dc7 --- /dev/null +++ b/Availability Groups/AlwaysOn_extendedEvents_Create.sql @@ -0,0 +1,45 @@ +CREATE EVENT SESSION [AlwaysOn_health] ON SERVER +ADD EVENT sqlserver.alwayson_ddl_executed, +ADD EVENT sqlserver.availability_group_lease_expired, +ADD EVENT sqlserver.availability_replica_automatic_failover_validation, +ADD EVENT sqlserver.availability_replica_manager_state_change, +ADD EVENT sqlserver.availability_replica_state, +ADD EVENT sqlserver.availability_replica_state_change, +ADD EVENT sqlserver.error_reported( + WHERE ([error_number]=(9691) + OR [error_number]=(35204) + OR [error_number]=(9693) + OR [error_number]=(26024) + OR [error_number]=(28047) + OR [error_number]=(26023) + OR [error_number]=(9692) + OR [error_number]=(28034) + OR [error_number]=(28036) + OR [error_number]=(28048) + OR [error_number]=(28080) + OR [error_number]=(28091) + OR [error_number]=(26022) + OR [error_number]=(9642) + OR [error_number]=(35201) + OR [error_number]=(35202) + OR [error_number]=(35206) + OR [error_number]=(35207) + OR [error_number]=(26069) + OR [error_number]=(26070) + OR [error_number]>(41047) + AND [error_number]<(41056) + OR [error_number]=(41142) + OR [error_number]=(41144) + OR [error_number]=(1480) + OR [error_number]=(823) + OR [error_number]=(824) + OR [error_number]=(829) + OR [error_number]=(35264) + OR [error_number]=(35265))), +ADD EVENT sqlserver.hadr_db_partner_set_sync_state, +ADD EVENT sqlserver.lock_redo_blocked +ADD TARGET package0.event_file(SET filename=N'AlwaysOn_health.xel',max_file_size=(5),max_rollover_files=(4)) +WITH (MAX_MEMORY=4096 KB,EVENT_RETENTION_MODE=ALLOW_SINGLE_EVENT_LOSS,MAX_DISPATCH_LATENCY=30 SECONDS,MAX_EVENT_SIZE=0 KB,MEMORY_PARTITION_MODE=NONE,TRACK_CAUSALITY=OFF,STARTUP_STATE=OFF) +GO + + diff --git a/Availability Groups/Am I Primary.sql b/Availability Groups/Am I Primary.sql new file mode 100644 index 0000000..5b157db --- /dev/null +++ b/Availability Groups/Am I Primary.sql @@ -0,0 +1,17 @@ + +--add as step 1 on every AAG-aware job +IF NOT EXISTS ( +SELECT @@SERVERNAME, * + FROM sys.dm_hadr_availability_replica_states rs + inner join sys.availability_databases_cluster dc + on rs.group_id = dc.group_id + WHERE is_local = 1 + and role_desc = 'PRIMARY' + and dc.database_name = N'whateverdbname' +) + BEGIN + + print 'local SQL instance is not primary, skipping'; + throw 50000, 'Do not continue', 1; + + END diff --git a/Availability Groups/AvailabilityGroups_Alerts.sql b/Availability Groups/AvailabilityGroups_Alerts.sql new file mode 100644 index 0000000..d0dbeaf --- /dev/null +++ b/Availability Groups/AvailabilityGroups_Alerts.sql @@ -0,0 +1,91 @@ +USE [msdb] +GO +--TODO: CHANGE THE @OperatorName variable to the correct operator name + + +/* *************************************************************** */ +--Bypassing recovery for database '(null)' because it is marked as an inaccessible availability database. The session with the primary replica was interrupted while reverting the database to the common recovery point. Either the WSFC node lacks quorum or the communications links are broken because of problems with links, endpoint configuration, or permissions (for the server account or security certificate). To gain access to the database, you need to determine what has changed in the session configuration and undo the change. +EXEC msdb.dbo.sp_add_alert @name=N'Availability Groups related Error - 35273', + @message_id=35273, + @severity=0, + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' + GO +/* *************************************************************** */ +--Recovery for availability database '(null)' is pending until the secondary replica receives additional transaction log from the primary before it complete and come online. Ensure that the server instance that hosts the primary replica is running. +EXEC msdb.dbo.sp_add_alert @name=N'Availability Groups related Error - 35274', + @message_id=35274, + @severity=0, + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' + GO +/* *************************************************************** */ +--A previous RESTORE WITH CONTINUE_AFTER_ERROR operation or being removed while in the SUSPECT state from an availability group left the '(null)' database in a potentially damaged state. The database cannot be joined while in this state. Restore the database, and retry the join operation. + +EXEC msdb.dbo.sp_add_alert @name=N'Availability Groups related Error - 35275', + @message_id=35275, + @severity=0, + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' + GO +/* *************************************************************** */ +--An error occurred while accessing the availability group metadata. Remove this database or replica from the availability group, and reconfigure the availability group to add the database or replica again. For more information, see the ALTER AVAILABILITY GROUP Transact-SQL statement in SQL Server Books Online. +EXEC msdb.dbo.sp_add_alert @name=N'Availability Groups related Error - 35254', + @message_id=35254, + @severity=0, + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' + GO +/* *************************************************************** */ +--The attempt to join database '(null)' to the availability group was rejected by the primary database with error '(null)'. For more information, see the SQL Server error log for the primary replica. +EXEC msdb.dbo.sp_add_alert @name=N'Availability Groups related Error - 35279', + @message_id=35279, + @severity=0, + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' + + GO +/* *************************************************************** */ +--Skipping the default startup of database '(null)' because the database belongs to an availability group (Group ID: (null)). The database will be started by the availability group. This is an informational message only. No user action is required. +EXEC msdb.dbo.sp_add_alert @name=N'Availability Groups related Error - 35262', + @message_id=35262, + @severity=0, + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' + GO + +/* *************************************************************** */ +--Failed to allocate and schedule an AlwaysOn Availability Groups task for database '(null)'. Manual intervention may be required to resume synchronization of the database. If the problem persists, you might need to restart the local instance of SQL Server. +EXEC msdb.dbo.sp_add_alert @name=N'Availability Groups related Error - 35276', + @message_id=35276, + @severity=0, + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' + + GO + +DECLARE @OperatorName nvarchar(100)='sql.alerts@sparkhound.com' +EXEC msdb.dbo.sp_add_notification @alert_name=N'Availability Groups related Error - 35273', @operator_name=@OperatorName, @notification_method = 1; +EXEC msdb.dbo.sp_add_notification @alert_name=N'Availability Groups related Error - 35276', @operator_name=@OperatorName, @notification_method = 1; +EXEC msdb.dbo.sp_add_notification @alert_name=N'Availability Groups related Error - 35262', @operator_name=@OperatorName, @notification_method = 1; +EXEC msdb.dbo.sp_add_notification @alert_name=N'Availability Groups related Error - 35274', @operator_name=@OperatorName, @notification_method = 1 +EXEC msdb.dbo.sp_add_notification @alert_name=N'Availability Groups related Error - 35254', @operator_name=@OperatorName, @notification_method = 1 +EXEC msdb.dbo.sp_add_notification @alert_name=N'Availability Groups related Error - 35279', @operator_name=@OperatorName, @notification_method = 1 +EXEC msdb.dbo.sp_add_notification @alert_name=N'Availability Groups related Error - 35275', @operator_name=@OperatorName, @notification_method = 1 + GO + + \ No newline at end of file diff --git a/Availability Groups/Error_messages.sql b/Availability Groups/Error_messages.sql new file mode 100644 index 0000000..f46625e --- /dev/null +++ b/Availability Groups/Error_messages.sql @@ -0,0 +1,10 @@ +SELECT * + FROM sys.messages m where language_id = 1033 -- English + --AND m.message_id =1480 +AND ([message_id]=(9691) OR [message_id]=(35204) OR [message_id]=(9693) OR [message_id]=(26024) OR [message_id]=(28047) + OR [message_id]=(26023) OR [message_id]=(9692) OR [message_id]=(28034) OR [message_id]=(28036) OR [message_id]=(28048) + OR [message_id]=(28080) OR [message_id]=(28091) OR [message_id]=(26022) OR [message_id]=(9642) OR [message_id]=(35201) + OR [message_id]=(35202) OR [message_id]=(35206) OR [message_id]=(35207) OR [message_id]=(26069) OR [message_id]=(26070) + OR [message_id]>(41047) AND [message_id]<(41056) OR [message_id]=(41142) OR [message_id]=(41144) OR [message_id]=(1480) + OR [message_id]=(823) OR [message_id]=(824) OR [message_id]=(829) OR [message_id]=(35264) OR [message_id]=(35265)) +ORDER BY Message_id \ No newline at end of file diff --git a/Availability Groups/Get_AOHealth_XEvents.sql b/Availability Groups/Get_AOHealth_XEvents.sql new file mode 100644 index 0000000..ef51929 --- /dev/null +++ b/Availability Groups/Get_AOHealth_XEvents.sql @@ -0,0 +1,351 @@ +/*===================================================================== +AUTHOR: trayce@seekwellandprosper.com +FILENAME: Get_AOHealth_XEvents.sql +VERSION: 1.2 +NOTES: + +TABLES OUTPUT +============== + TempDB.dbo.#error_reported --used for stats of error/info messages + TempDB.dbo.#AOHealth_XELData --imported Xevents from AlwaysOn_Health_*.XEL files + +CHANGE HISTORY: +--------------------------- +2017/03/23 version 1.2 changed logic to find target files + changed where clauses to use object_name + only return XEvents that are found + added summary table of events & their counts + if no AO Health session found, print msg, exit + if target path not found, print msg, exit + wrapped IsNull around a value that is NULL in SQL 2012 + +2017/02/20 version 1.1 changed various casts to avoid trimming +2017/01/18 Initial revision +======================================================================*/ +SET NOCOUNT ON +USE [TempDB] +GO + +DECLARE @XELTarget VARCHAR(MAX); +DECLARE @XELPath VARCHAR(MAX); +DECLARE @XELFile VARCHAR(max); + +IF EXISTS(SELECT name FROM sys.dm_xe_sessions WHERE name = 'AlwaysOn_Health') BEGIN + SELECT @XELTarget = cast(xet.target_data AS XML).value('(EventFileTarget/File/@name)[1]', 'VARCHAR(MAX)') + FROM sys.dm_xe_sessions xes + INNER JOIN sys.dm_xe_session_targets xet + ON xes.address = xet.event_session_address + WHERE xet.target_name = 'event_file' and xes.name = 'AlwaysOn_Health' + + SELECT @XELPath = REVERSE(SUBSTRING(REVERSE(@XELTarget), + CHARINDEX('\', reverse(@XELTarget)), + LEN(@XELTarget)+1- CHARINDEX('\', REVERSE(@XELTarget)))) + + SELECT @XELFile = @XELPath + 'AlwaysOn_health*.xel' + IF @XELFile IS NULL BEGIN + PRINT 'Unable to find XEVent target files for AlwaysOn_Health XEvent session' + PRINT 'Expected AOHealth XEvent files in this location:' + PRINT @XELPath + RETURN + END +END ELSE BEGIN + PRINT 'No AlwaysOn Health XEvent session found' + RETURN +END + + +--create table +CREATE TABLE #AOHealth_XELData + (ID INT IDENTITY PRIMARY KEY CLUSTERED, + object_name varchar(max), + EventData XML, + file_name varchar(max), + file_offset bigint); + +--read from the files into the table +IF @XELFile IS NOT NULL BEGIN + INSERT INTO #AOHealth_XELData + SELECT object_name, cast(event_data as XML) AS EventData, + file_name, File_Offset + FROM sys.fn_xe_file_target_read_file( + @XELFile, NULL, null, null); +END + +-- Create table for "error_reported" events +CREATE TABLE #error_reported (Xevent varchar(15), + TimeStampUTC DATETIME, + error_number INT, + severity INT, + state INT, + user_defined varchar(5), + category_desc varchar(25), + category varchar(5), + destination varchar(20), + destination_desc varchar(20), + is_intercepted varchar(5), + message varchar(max)) +INSERT INTO #error_reported +SELECT CAST(object_name as varchar(15)) AS Xevent, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="error_number"]/value)[1]', 'int') AS error_number, + EventData.value('(event/data[@name="severity"]/value)[1]', 'int') AS severity, + EventData.value('(event/data[@name="state"]/value)[1]', 'int') AS state, + EventData.value('(event/data[@name="user_defined"]/value)[1]', 'varchar(5)') AS user_defined, + EventData.value('(event/data[@name="category"]/text)[1]', 'varchar(25)') AS category_desc, + EventData.value('(event/data[@name="category"]/value)[1]', 'varchar(5)') AS category, + EventData.value('(event/data[@name="destination"]/value)[1]', 'varchar(20)') AS destination, + EventData.value('(event/data[@name="destination"]/text)[1]', 'varchar(20)') AS destination_desc, + EventData.value('(event/data[@name="is_intercepted"]/value)[1]', 'varchar(5)') AS is_intercepted, + EventData.value('(event/data[@name="message"]/value)[1]', 'varchar(max)') AS message + FROM #AOHealth_XELData + WHERE EventData.value('(event/@name)[1]', 'varchar(max)') = 'error_reported'; + +IF EXISTS(SELECT * FROM #error_reported) BEGIN + PRINT 'Error event stats' + PRINT '================='; + --display results from "error_reported" event data + WITH ErrorCTE (ErrorNum, ErrorCount, FirstDate, LastDate) AS ( + SELECT error_number, Count(error_number), min(TimeStampUTC), max(TimeStampUTC) As ErrorCount FROM #error_reported + GROUP BY error_number) + SELECT ErrorNum, + ErrorCount,--CAST(ErrorCount as CHAR(10)) ErrorCount, + CONVERT(CHAR(25), FirstDate,121) FirstDate, + CONVERT(CHAR(25), LastDate, 121) LastDate, + CAST(CASE ErrorNum + WHEN 35202 THEN 'A connection for availability group ... has been successfully established...' + WHEN 1480 THEN 'The %S_MSG database "%.*ls" is changing roles ... because the AG failed over ...' + WHEN 35206 THEN 'A connection timeout has occurred on a previously established connection ...' + WHEN 35201 THEN 'A connection timeout has occurred while attempting to establish a connection ...' + WHEN 41050 THEN 'Waiting for local WSFC service to start.' + WHEN 41051 THEN 'Local WSFC service started.' + WHEN 41052 THEN 'Waiting for local WSFC node to start.' + WHEN 41053 THEN 'Local WSFC node started.' + WHEN 41054 THEN 'Waiting for local WSFC node to come online.' + WHEN 41055 THEN 'Local WSFC node is online.' + WHEN 41048 THEN 'Local WSFC service has become unavailable.' + WHEN 41049 THEN 'Local WSFC node is no longer online.' + ELSE m.text END AS VARCHAR(81)) [Abbreviated Message] + FROM + ErrorCTE ec LEFT JOIN sys.messages m on ec.ErrorNum = m.message_id + and m.language_id = 1033 + order by ErrorCount DESC +END + +IF EXISTS(SELECT object_name FROM #AOHealth_XELData WHERE object_name = 'alwayson_ddl_executed') +BEGIN + PRINT 'Non-failover DDL Events'; + PRINT '======================='; + WITH AODDL (object_name, TimeStampUTC, ddl_action, ddl_action_desc, ddl_phase, ddl_phase_desc, + availability_group_name, availability_group_id, [statement]) + AS + ( + SELECT object_name, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="ddl_action"]/value)[1]', 'int') AS ddl_action, + EventData.value('(event/data[@name="ddl_action"]/text)[1]', 'varchar(15)') AS ddl_action_desc, + EventData.value('(event/data[@name="ddl_phase"]/value)[1]', 'int') AS ddl_phase, + EventData.value('(event/data[@name="ddl_phase"]/text)[1]', 'varchar(10)') AS ddl_phase_desc, + EventData.value('(event/data[@name="availability_group_name"]/value)[1]', 'varchar(25)') AS availability_group_name, + EventData.value('(event/data[@name="availability_group_id"]/value)[1]', 'varchar(36)') AS availability_group_id, + EventData.value('(event/data[@name="statement"]/value)[1]', 'varchar(max)') AS [statement] + FROM #AOHealth_XELData + WHERE object_name = 'alwayson_ddl_executed' + AND EventData.value('(event/data[@name="statement"]/value)[1]', 'varchar(max)') NOT LIKE '%FAILOVER%' + OR (EventData.value('(event/data[@name="statement"]/value)[1]', 'varchar(max)') LIKE '%FAILOVER%' AND + EventData.value('(event/data[@name="statement"]/value)[1]', 'varchar(max)') LIKE '%CREATE%') + ) + SELECT cast(object_name as varchar(22)) AS XEvent, TimeStampUTC, ddl_action, ddl_action_desc, ddl_phase, + ddl_phase_desc, availability_group_name, availability_group_id, + CASE WHEN LEN([statement]) > 220 + THEN CAST([statement] as varchar(1155)) + char(10) + ELSE CAST(Replace([statement], char(10), '') as varchar(220)) + END as [statement] + FROM AODDL + ORDER BY TimeStampUTC; + + + PRINT 'Failover DDL Events'; + PRINT '==================='; + -- Display results "alwayson_ddl_executed" events + WITH AODDL (object_name, TimeStampUTC, ddl_action, ddl_action_desc, ddl_phase, ddl_phase_desc, + availability_group_name, availability_group_id, [statement]) + AS + ( + SELECT object_name, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="ddl_action"]/value)[1]', 'int') AS ddl_action, + EventData.value('(event/data[@name="ddl_action"]/text)[1]', 'varchar(15)') AS ddl_action_desc, + EventData.value('(event/data[@name="ddl_phase"]/value)[1]', 'int') AS ddl_phase, + EventData.value('(event/data[@name="ddl_phase"]/text)[1]', 'varchar(10)') AS ddl_phase_desc, + EventData.value('(event/data[@name="availability_group_name"]/value)[1]', 'varchar(25)') AS availability_group_name, + EventData.value('(event/data[@name="availability_group_id"]/value)[1]', 'varchar(36)') AS availability_group_id, + EventData.value('(event/data[@name="statement"]/value)[1]', 'varchar(max)') AS [statement] + FROM #AOHealth_XELData + WHERE object_name = 'alwayson_ddl_executed' + AND (EventData.value('(event/data[@name="statement"]/value)[1]', 'varchar(max)') LIKE '%FAILOVER%' + OR EventData.value('(event/data[@name="statement"]/value)[1]', 'varchar(max)') LIKE '%FORCE%') + AND EventData.value('(event/data[@name="statement"]/value)[1]', 'varchar(max)') NOT LIKE '%CREATE%' + ) + SELECT cast(object_name as varchar(22)) AS XEvent, TimeStampUTC, ddl_action, ddl_action_desc, ddl_phase, + ddl_phase_desc, availability_group_name, availability_group_id, + CAST(Replace([statement], char(10), '') as varchar(80)) as [statement] + FROM AODDL + ORDER BY TimeStampUTC; +END + +IF EXISTS(SELECT object_name FROM #AOHealth_XELData WHERE object_name = 'availability_replica_manager_state_change') +BEGIN + PRINT 'Availability Replica Manager state changes' + PRINT '=========================================='; + -- display results for "availability_replica_manager_state_change" events + SELECT cast(object_name as varchar(42)) AS XEvent, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="current_state"]/value)[1]', 'int') AS current_state, + EventData.value('(event/data[@name="current_state"]/text)[1]', 'varchar(30)') AS current_state_desc + FROM #AOHealth_XELData + WHERE object_name = 'availability_replica_manager_state_change' + ORDER BY EventData.value('(event/@timestamp)[1]', 'datetime'); +END + + +IF EXISTS(SELECT object_name FROM #AOHealth_XELData WHERE object_name = 'availability_replica_state') +BEGIN + PRINT 'Availability Replica state' + PRINT '=========================='; + -- display results for "availability_replica_state" events + SELECT cast(object_name as varchar(34)) AS XEvent, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="current_state"]/value)[1]', 'int') AS current_state, + EventData.value('(event/data[@name="current_state"]/text)[1]', 'varchar(20)') AS current_state_desc, + EventData.value('(event/data[@name="availability_group_name"]/value)[1]', 'varchar(36)') AS availability_group_name, + EventData.value('(event/data[@name="availability_group_id"]/value)[1]', 'varchar(36)') AS availability_group_id, + EventData.value('(event/data[@name="availability_replica_id"]/value)[1]', 'varchar(36)') AS availability_replica_id + FROM #AOHealth_XELData + WHERE object_name = 'availability_replica_state' + ORDER BY EventData.value('(event/@timestamp)[1]', 'datetime'); +END + +IF EXISTS(SELECT object_name FROM #AOHealth_XELData WHERE object_name = 'availability_replica_state_change') +BEGIN + PRINT 'Availability Replica state changes' + PRINT '=================================='; + -- display results for "availability_replica_state_change" events + SELECT cast(object_name as varchar(34)) AS XEvent, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + IsNULL(EventData.value('(event/data[@name="availability_replica_name"]/value)[1]', 'varchar(25)'), 'Data Unavailable') AS availability_replica_name, + EventData.value('(event/data[@name="availability_group_name"]/value)[1]', 'varchar(25)') AS availability_group_name, + EventData.value('(event/data[@name="previous_state"]/value)[1]', 'int') AS previous_state, + EventData.value('(event/data[@name="previous_state"]/text)[1]', 'varchar(30)') AS previous_state_desc, + EventData.value('(event/data[@name="current_state"]/value)[1]', 'int') AS current_state, + EventData.value('(event/data[@name="current_state"]/text)[1]', 'varchar(30)') AS current_state_desc, + EventData.value('(event/data[@name="availability_replica_id"]/value)[1]', 'varchar(36)') AS availability_replica_id, + EventData.value('(event/data[@name="availability_group_id"]/value)[1]', 'varchar(36)') AS availability_group_id + FROM #AOHealth_XELData + WHERE object_name = 'availability_replica_state_change' + ORDER BY EventData.value('(event/@timestamp)[1]', 'datetime'); +END + +IF EXISTS(SELECT object_name FROM #AOHealth_XELData WHERE object_name = 'availability_group_lease_expired') +BEGIN + PRINT 'Lease Expiration Events' + PRINT '======================='; + -- Display results "lease expiration" events + SELECT cast(object_name as varchar(33)) AS XEvent, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="availability_group_name"]/value)[1]', 'varchar(25)') AS AGName, + EventData.value('(event/data[@name="availability_group_id"]/value)[1]', 'varchar(36)') AS AG_ID + FROM #AOHealth_XELData + WHERE object_name = 'availability_group_lease_expired' + ORDER BY EventData.value('(event/@timestamp)[1]', 'datetime'); +END + +IF EXISTS(SELECT object_name FROM #AOHealth_XELData WHERE object_name = 'lock_redo_blocked') +BEGIN + PRINT 'BLOCKED REDO Events' + PRINT '==================='; + -- Display results "lock_redo_blocked" events + SELECT cast(object_name as varchar(42)) AS XEvent, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="resource_type"]/value)[1]', 'int') AS ResourceType, + EventData.value('(event/data[@name="resource_type"]/text)[1]', 'varchar(25)') AS ResourceTypeDesc, + EventData.value('(event/data[@name="mode"]/value)[1]', 'int') AS Mode, + EventData.value('(event/data[@name="mode"]/text)[1]', 'varchar(25)') AS ModeDesc, + EventData.value('(event/data[@name="owner_type"]/value)[1]', 'int') AS OwnerType, + EventData.value('(event/data[@name="owner_type"]/text)[1]', 'varchar(25)') AS OwnerTypeDesc, + EventData.value('(event/data[@name="transaction_id"]/value)[1]', 'bigint') AS transaction_id, + EventData.value('(event/data[@name="database_id"]/value)[1]', 'int') AS database_id, + EventData.value('(event/data[@name="lockspace_workspace_id"]/value)[1]', 'varchar(22)') AS lockspace_workspace_id, + EventData.value('(event/data[@name="lockspace_sub_id"]/value)[1]', 'bigint') AS lockspace_sub_id, + EventData.value('(event/data[@name="lockspace_nest_id"]/value)[1]', 'bigint') AS lockspace_nest_id, + EventData.value('(event/data[@name="resource_0"]/value)[1]', 'bigint') AS resource_0, + EventData.value('(event/data[@name="resource_1"]/value)[1]', 'bigint') AS resource_1, + EventData.value('(event/data[@name="resource_2"]/value)[1]', 'bigint') AS resource_2, + EventData.value('(event/data[@name="object_id"]/value)[1]', 'bigint') AS [object_id], + EventData.value('(event/data[@name="associated_object_id"]/value)[1]', 'bigint') AS associated_object_id, + EventData.value('(event/data[@name="duration"]/value)[1]', 'int') AS duration, + EventData.value('(event/data[@name="resource_description"]/value)[1]', 'varchar(25)') AS resource_description + FROM #AOHealth_XELData + WHERE object_name = 'lock_redo_blocked' + ORDER BY EventData.value('(event/@timestamp)[1]', 'datetime'); +END + +IF EXISTS(SELECT object_name FROM #AOHealth_XELData WHERE object_name = 'hadr_db_partner_set_sync_state') +BEGIN + PRINT 'hadr_db_partner_set_sync_state Events' + PRINT '====================================='; + -- Display results "hadr_db_partner_set_sync_state" events + SELECT cast(object_name as varchar(42)) AS XEvent, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="database_id"]/value)[1]', 'int') AS database_id, + EventData.value('(event/data[@name="commit_policy"]/value)[1]', 'int') AS commit_policy, + EventData.value('(event/data[@name="commit_policy"]/text)[1]', 'varchar(20)') AS commit_policy_desc, + EventData.value('(event/data[@name="commit_policy_target"]/value)[1]', 'int') AS commit_policy_target, + EventData.value('(event/data[@name="commit_policy_target"]/text)[1]', 'varchar(20)') AS commit_policy_target_desc, + EventData.value('(event/data[@name="sync_state"]/value)[1]', 'int') AS sync_state, + EventData.value('(event/data[@name="sync_state"]/text)[1]', 'varchar(20)') AS sync_state_desc, + EventData.value('(event/data[@name="sync_log_block"]/value)[1]', 'varchar(20)') AS sync_log_block, + EventData.value('(event/data[@name="group_id"]/value)[1]', 'varchar(36)') AS group_id, + EventData.value('(event/data[@name="replica_id"]/value)[1]', 'varchar(36)') AS replica_id, + EventData.value('(event/data[@name="ag_database_id"]/value)[1]', 'varchar(36)') AS ag_database_id + FROM #AOHealth_XELData + WHERE object_name = 'hadr_db_partner_set_sync_state' + ORDER BY EventData.value('(event/@timestamp)[1]', 'datetime'); +END + +IF EXISTS(SELECT object_name FROM #AOHealth_XELData WHERE object_name = 'availability_replica_automatic_failover_validation') +BEGIN + PRINT 'availability_replica_automatic_failover_validation' + PRINT '=================================================='; + -- Display results "availability_replica_automatic_failover_validation" events + SELECT cast(object_name as varchar(50)) AS XEvent, EventData.value('(event/@timestamp)[1]', 'datetime') AS TimeStampUTC, + EventData.value('(event/data[@name="availability_replica_name"]/value)[1]', 'varchar(25)') AS availability_replica_name, + EventData.value('(event/data[@name="availability_group_name"]/value)[1]', 'varchar(25)') AS availability_group_name, + EventData.value('(event/data[@name="availability_replica_id"]/value)[1]', 'varchar(36)') AS availability_replica_id, + EventData.value('(event/data[@name="availability_group_id"]/value)[1]', 'varchar(36)') AS availability_group_id, + EventData.value('(event/data[@name="forced_quorum"]/value)[1]', 'varchar(5)') AS forced_quorum, + EventData.value('(event/data[@name="joined_and_synchronized"]/value)[1]', 'varchar(5)') AS joined_and_synchronized, + EventData.value('(event/data[@name="previous_primary_or_automatic_failover_target"]/value)[1]', 'varchar(5)') AS previous_primary_or_automatic_failover_target + FROM #AOHealth_XELData + WHERE object_name = 'availability_replica_automatic_failover_validation' + ORDER BY EventData.value('(event/@timestamp)[1]', 'datetime'); +END + +CREATE TABLE #AOHealthSummary (XEvent varchar(50), [COUNT] INT); +INSERT INTO #AOHealthSummary +SELECT CAST(xv.event_name AS VARCHAR(50)), 0 + FROM sys.dm_xe_sessions xes + INNER JOIN sys.dm_xe_session_events xv ON xes.address = xv.event_session_address + WHERE xes.name like 'AlwaysOn_Health' + ORDER BY event_name; + +With Summary (XEvent, [Count]) +AS (SELECT CAST(object_name AS VARCHAR(50)) AS [XEvent], count(*) AS [Count] + FROM #AOHealth_XELData + GROUP BY object_name) +UPDATE #AOHealthSummary + SET [COUNT] = s.[COUNT] + FROM Summary s + INNER JOIN #AOHealthSummary ao ON s.XEvent = ao.XEvent; + +IF EXISTS(SELECT * FROM #AOHealthSummary) BEGIN + PRINT 'Summary event counts for AO Health XEvents' + PRINT '=========================================='; + -- Display event counts for AO Health XEvent data + SELECT * FROM #AOHealthSummary + ORDER BY [count] DESC, XEvent +END + +DROP TABLE #AOHealth_XELData +DROP TABLE #error_reported +DROP TABLE #AOHealthSummary diff --git a/Availability Groups/endpoints.sql b/Availability Groups/endpoints.sql new file mode 100644 index 0000000..fef757e --- /dev/null +++ b/Availability Groups/endpoints.sql @@ -0,0 +1,3 @@ +select * from sys.database_mirroring_endpoints +select * from sys.tcp_endpoints +select * from sys.availability_replicas diff --git a/Database_File_Sizes.sql b/Database_File_Sizes.sql new file mode 100644 index 0000000..a983d01 --- /dev/null +++ b/Database_File_Sizes.sql @@ -0,0 +1,17 @@ +-- File names and paths for TempDB and all user databases in instance (Query 21) (Database Filenames and Paths) +SELECT DB_NAME([database_id]) AS [Database Name], + [file_id], name, physical_name, type_desc, state_desc, + is_percent_growth, growth, + CONVERT(bigint, growth/128.0) AS [Growth in MB], + CONVERT(bigint, size/128.0) AS [Total Size in MB] +FROM sys.master_files WITH (NOLOCK) +ORDER BY DB_NAME([database_id]) OPTION (RECOMPILE); + +-- Things to look at: +-- Are data files and log files on different drives? +-- Is everything on the C: drive? +-- Is TempDB on dedicated drives? +-- Is there only one TempDB data file? +-- Are all of the TempDB data files the same size? +-- Are there multiple data files for user databases? +-- Is percent growth enabled for any files (which is bad)? \ No newline at end of file diff --git a/Drop_and_Recreate_Table_Objects.sql b/Drop_and_Recreate_Table_Objects.sql new file mode 100644 index 0000000..fecdb99 --- /dev/null +++ b/Drop_and_Recreate_Table_Objects.sql @@ -0,0 +1,1614 @@ + +/* Drop and Recreate Table objects +This script drops and recreated default constraints, triggers and check constraints +for any table inserted into ##Drop_and_Recreate_Objects. +It does not recreate foreign keys, partitions or indexes. +*/ + +/* +--SAMPLE SETUP CODE + +drop table tabledc1 +drop table tabledc2 +go +create table tabledc1 +( id int identity(1,1) not null primary key +, dfcol1 int not null CONSTRAINT DF_tabledc1_dfcol1 DEFAULT (0) +, dfcol2 varchar (4) not null CONSTRAINT DF_tabledc1_dfcol2 DEFAULT ('test') +, dfcol3 datetime not null CONSTRAINT DF_tabledc1_dfcol3 DEFAULT (getdate()) +, dfcol4 bit not null CONSTRAINT DF_tabledc1_dfcol4 DEFAULT (1) +, dfcol5 int not null DEFAULT (0) +, dfcol6 bit not null DEFAULT (1) +) +create table tabledc2 +( id int identity(1,1) not null primary key +, dfcol1 int not null CONSTRAINT DF_tabledc2_dfcol1 DEFAULT (0) +, dfcol2 varchar (4) not null CONSTRAINT DF_tabledc2_dfcol2 DEFAULT ('test') +, dfcol3 datetime not null CONSTRAINT DF_tabledc2_dfcol3 DEFAULT (getdate()) +, dfcol4 bit not null CONSTRAINT DF_tabledc2_dfcol4 DEFAULT (1) +, dfcol5 int not null DEFAULT (0) +, dfcol6 bit not null DEFAULT (1) +) + +ALTER TABLE dbo.tabledc1 ADD CONSTRAINT CK_Vendor_CreditRating CHECK (dfcol1 >= 0 AND dfcol1 <= 5) +ALTER TABLE dbo.tabledc2 ADD CHECK (dfcol1 >= 0 AND dfcol1 <= 5) + +drop view view1 +drop table tablet1 +drop table tablet2 +go +create table tablet1 (id int identity(1,1) not null primary key) +create table tablet2 (id int identity(1,1) not null primary key) +go +create view view1 as select * from tablet1 +go +CREATE TRIGGER [dbo].view1_trigger1 ON dbo.view1 INSTEAD OF INSERT,UPDATE AS +BEGIN +DECLARE @invno AS float +SELECT @invno = id FROM inserted +END +go +CREATE TRIGGER [dbo].tablet1_trigger1 ON dbo.tablet1 AFTER INSERT,UPDATE,DELETE AS +BEGIN +DECLARE @invno AS float +SELECT @invno = id FROM inserted +END +go +CREATE TRIGGER [dbo].tablet1_trigger2 ON dbo.tablet1 INSTEAD OF INSERT,UPDATE,DELETE AS +BEGIN +DECLARE @invno AS float +SELECT @invno = id FROM inserted +END +go +CREATE TRIGGER [dbo].tablet1_trigger3 ON dbo.tablet1 FOR INSERT,UPDATE,DELETE AS +BEGIN +DECLARE @invno AS float +SELECT @invno = id FROM inserted +END +go +CREATE TRIGGER [dbo].tablet2_trigger1 ON dbo.tablet2 AFTER INSERT,UPDATE,DELETE AS +BEGIN +DECLARE @invno AS float +SELECT @invno = id FROM inserted +END +go +CREATE TRIGGER [dbo].tablet2_trigger2 ON dbo.tablet2 INSTEAD OF INSERT,UPDATE,DELETE AS +BEGIN +DECLARE @invno AS float +SELECT @invno = id FROM inserted +END +go +CREATE TRIGGER [dbo].tablet2_trigger3 ON dbo.tablet2 FOR INSERT,UPDATE,DELETE AS +BEGIN +DECLARE @invno AS float +SELECT @invno = id FROM inserted +END +go +exec sp_settriggerorder @Triggername = N'dbo.tablet1_trigger1', @order = 'first', @stmttype = 'update' +exec sp_settriggerorder @Triggername = N'dbo.tablet1_trigger3', @order = 'last', @stmttype = 'delete' +exec sp_settriggerorder @Triggername = N'dbo.tablet2_trigger1', @order = 'first', @stmttype = 'update' +exec sp_settriggerorder @Triggername = N'dbo.tablet2_trigger3', @order = 'last', @stmttype = 'delete' +go + +BEGIN TRY +DROP TABLE ##Drop_and_Recreate_Objects; +END TRY +BEGIN CATCH +END CATCH + +CREATE TABLE ##Drop_and_Recreate_Objects ( table_object_id int not null PRIMARY KEY ) +go + +--Example of how to add a table to get its DFs, TRs and CKs recreated. +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_tax_brkdwn_headers]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tabledc2]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tablet1]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tablet2]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[view1]')) +--GO +go +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[testonlinerebuild]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable1]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable2]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable3]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable4]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable5]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable6]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable7]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable8]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable9]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable10]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fktable11]')) +go +select object_name(table_object_id), * from ##Drop_and_Recreate_Objects where object_name(table_object_id) is not null order by object_name(table_object_id) + +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[pohdr]')) +go +exec dbo.Drop_and_Store_Table_Objects @testingMode = 0, @AuditingMode = 1 +exec dbo.Alter_Floats_to_Decimal @testingMode = 0, @AuditingMode = 1 +exec dbo.Recreate_Stored_Table_Objects @testingMode = 0, @AuditingMode = 1 + +*/ + +BEGIN TRY +DROP TABLE ##Drop_and_Recreate_Objects; +END TRY +BEGIN CATCH +END CATCH + +CREATE TABLE ##Drop_and_Recreate_Objects ( table_object_id int not null PRIMARY KEY ) +go + + + +--if OBJECT_ID('dbo.Fix_Duplicate_PK_Floats') is not null +--drop procedure dbo.Fix_Duplicate_PK_Floats +--go +--create procedure dbo.Fix_Duplicate_PK_Floats (@TestingMode bit = 0, @AuditingMode bit = 0) +--WITH RECOMPILE +--AS +--BEGIN + +-- SET XACT_ABORT ON + +-- declare @PKtableTSQL as varchar(8000), @FKTableTSQL as varchar(8000), @Referenced_object_id as int, @referenced_object_name as varchar(200), @pkcol as varchar(200) +-- , @fkcol as varchar(200) = '', @referencing_object_name as varchar(200) = '', @Referencing_object_id as int = '' +-- , @previous_Referenced_object_id as int = 0 + + +-- BEGIN TRY +-- DROP TABLE ##ChangeKey; +-- END TRY +-- BEGIN CATCH +-- END CATCH + + + +-- CREATE TABLE ##ChangeKey (pkcol decimal(19,6) not null , newpkcol decimal(19,6) not null, UNIQUE CLUSTERED (pkcol,newpkcol)) + +-- DECLARE fixDupFloats CURSOR FAST_FORWARD FOR +-- --select DISTINCT +-- -- Referenced_object_id +-- --, referenced_object_name +-- --, pkcol +-- --FROM ##DupPK_Floats_to_Drop_and_Recreate pk +-- --INNER JOIN sys.objects o +-- --on pk.Referenced_object_id = o.object_id +-- --inner join sys.columns c +-- --on c.object_id = o.object_id and c.name = pk.pkcol +-- --inner join sys.types t +-- --on t.user_type_id = c.user_type_id +-- --WHERE Referenced_object_id is not null +-- --and t.name in ('float', 'real') + +-- select DISTINCT +-- Referenced_object_id +-- , referenced_object_name +-- , pkcol +-- , fkcol +-- , referencing_object_name +-- , Referencing_object_id +-- FROM ##DupPK_Table_Floats_to_Drop_and_Recreate pk +-- INNER JOIN sys.objects o +-- on pk.Referenced_object_id = o.object_id +-- inner join sys.columns c +-- on c.object_id = o.object_id and c.name = pk.pkcol +-- inner join sys.types t +-- on t.user_type_id = c.user_type_id +-- WHERE Referenced_object_id is not null +-- and t.name in ('float', 'real') + +-- OPEN fixDupFloats +-- FETCH NEXT FROM fixDupFloats INTO @Referenced_object_id, @referenced_object_name, @pkcol, @fkcol, @referencing_object_name, @Referencing_object_id +-- WHILE @@FETCH_STATUS = 0 +-- BEGIN + +-- If @previous_Referenced_object_id <> @Referenced_object_id --Check is same referenced object as last loop. We expected this. +-- BEGIN + +-- TRUNCATE TABLE ##ChangeKey + +-- IF @AuditingMode = 1 +-- select DISTINCT +-- Referenced_object_id +-- , referenced_object_name +-- , pkcol +-- , fkcol +-- , referencing_object_name +-- , Referencing_object_id +-- FROM ##DupPK_Table_Floats_to_Drop_and_Recreate +-- WHERE Referenced_object_id = @Referenced_object_id + +-- IF @AuditingMode = 1 +-- set @PKTableTSQL = 'select dupkeyfound = ''' + @referenced_object_name + ''', ['+@pkcol+'_rounded] = round(['+@pkcol+'],2), ['+@pkcol+'], [' + replace(@pkcol, ' ','_') + '_count], instance +-- from ( select ['+@pkcol+'] +-- , ['+replace(@pkcol, ' ','_')+'_count] = count(['+@pkcol+']) over (partition by round(['+@pkcol+'],2) ) +-- , instance = rank() over (partition by round(['+@pkcol+'],2) order by round(['+@pkcol+'],14)) +-- from ' + @referenced_object_name + ' as ih +-- ) x +-- where ['+replace(@pkcol, ' ','_') + '_count] > 1 order by 1,2,3' +-- --IF @AuditingMode = 1 +-- print @PKTableTSQL +-- --IF @AuditingMode = 1 +-- exec (@PKTableTSQL) + + +-- select @PKTableTSQL = 'IF EXISTS ( select round(['+@pkcol+'], 2), count(1) from '+@referenced_object_name+' group by round(['+@pkcol+'],2) having count(1) > 1) +-- BEGIN + +-- ;with cteDups ( ['+@pkcol+'], ['+replace(@pkcol, ' ','_')+'_count], instance ) as +-- ( select ['+@pkcol+'], '+replace(@pkcol, ' ', '_')+ '_count, instance +-- from ( +-- select ['+@pkcol+'] +-- , ['+replace(@pkcol, ' ','_')+ '_count] = count(['+@pkcol+']) over (partition by round(['+@pkcol+'],2) ) +-- , instance = row_number() over (partition by round(['+@pkcol+'],2) order by round(['+@pkcol+'],14)) +-- from '+@referenced_object_name+' as ih +-- ) x +-- where ['+replace(@pkcol, ' ','_')+ '_count] > 1 ) + +-- INSERT INTO ##ChangeKey (pkcol, newpkcol) +-- SELECT DISTINCT +-- pkcol = d2.['+@pkcol+'] +-- , newpkcol= convert(decimal(19,6), d2.['+@pkcol+']) + ((d2.instance -1) * .01) +-- --UPDATE ii set +-- -- [' + @pkcol + '] = convert(decimal(19,6), d2.['+@pkcol+']) + ((d2.instance -1) * .01) +-- from ' + @referenced_object_name + ' ii +-- inner join +-- cteDups d1 +-- on ii.['+@pkcol+'] = d1.['+@pkcol+'] +-- inner join +-- cteDups d2 +-- on d1.['+@pkcol+'] = d2.['+@pkcol+']; + + +-- UPDATE ii set +-- [' + @pkcol + '] = newpkcol +-- from ' + @referenced_object_name + ' ii +-- inner join ##ChangeKey ck on round(ii.[' + @pkcol + '],2) = round(ck.pkcol,2) +-- WHERE round(ii.[' + @pkcol + '],2) = newpkcol + +-- END;'; + +-- IF @AuditingMode = 1 print 'Fixing duplicate PK on ' + @referenced_object_name + CHAR(10) + CHAR(13) +-- IF @AuditingMode = 1 select * from ##ChangeKey +-- --IF @AuditingMode = 1 print @PKTableTSQL +-- IF @TestingMode = 0 exec (@PKTableTSQL) + +-- IF @AuditingMode = 1 +-- set @PKTableTSQL = 'select dupkeyfound = ''' + @referenced_object_name + ''', ['+@pkcol+'_rounded] = round(['+@pkcol+'],2), ['+@pkcol+'], [' + replace(@pkcol, ' ','_') + '_count], instance +-- from ( select ['+@pkcol+'] +-- , ['+replace(@pkcol, ' ','_')+'_count] = count(['+@pkcol+']) over (partition by round(['+@pkcol+'],2) ) +-- , instance = row_number() over (partition by round(['+@pkcol+'],2) order by round(['+@pkcol+'],14)) +-- from ' + @referenced_object_name + ' as ih +-- ) x +-- where ['+replace(@pkcol, ' ','_') + '_count] > 1 order by 1,2,3' +-- --IF @AuditingMode = 1 print @PKTableTSQL +-- IF @AuditingMode = 1 exec (@PKTableTSQL) + +-- END -- Check if same reference object + +-- --Fix the FK records in each FK table +-- ---- this isn't going to work becuase it can't tell the rows apart. +-- set @FKTableTSQL = ' +-- UPDATE ii set +-- [' + @fkcol + '] = newpkcol +-- from ' + @referencing_object_name + ' ii +-- inner join ##ChangeKey ck on round(ii.[' + @fkcol + '],2) = round(ck.pkcol,2) +-- WHERE round(ii.[' + @fkcol + '],2) = newpkcol;' + +-- IF @AuditingMode = 1 +-- print @PKTableTSQL +-- IF @AuditingMode = 1 +-- exec (@PKTableTSQL) + +-- FETCH NEXT FROM fixDupFloats INTO @Referenced_object_id, @referenced_object_name, @pkcol, @fkcol, @referencing_object_name, @Referencing_object_id + +-- END +-- CLOSE fixDupFloats; +-- DEALLOCATE fixDupFloats; + +-- DROP TABLE ##ChangeKey; + +--END +--GO + +if OBJECT_ID('dbo.Alter_Floats_to_Decimal') is not null +drop procedure dbo.Alter_Floats_to_Decimal +go +create procedure dbo.Alter_Floats_to_Decimal (@TestingMode bit = 0, @AuditingMode bit = 0) +WITH RECOMPILE +AS +BEGIN + + SET XACT_ABORT ON + + DECLARE @tsql nvarchar(max) + DECLARE AlterCol CURSOR FAST_FORWARD FOR + + select + Alter_TSQL = + --'IF NOT EXISTS (SELECT TOP 1 * FROM sys.change_tracking_tables WHERE Object_id = object_id(''' + s.name + '.' + o.name + '''))' + --+ ' ALTER TABLE [' + s.name + '].[' + o.name + '] ENABLE CHANGE_TRACKING WITH (TRACK_COLUMNS_UPDATED = OFF);' + + ' ALTER TABLE [' + s.name + '].[' + o.name + '] ALTER COLUMN [' + c.name + '] DECIMAL (19,6) ' + case c.is_nullable when 1 THEN ' NULL ' ELSE ' NOT NULL ' END + ';' + --+ ' ALTER TABLE [' + s.name + '].[' + o.name + '] ENABLE CHANGE_TRACKING WITH (TRACK_COLUMNS_UPDATED = ON);' + + from ##Drop_and_Recreate_Objects dro + inner join sys.objects o + on o.object_id = dro.table_object_id + inner join sys.columns c + on o.object_id = c.object_id + inner join sys.types t + on t.user_type_id = c.user_type_id + inner join sys.schemas s + on s.schema_id = o.schema_id + where t.name = 'float' + and o.type_desc = 'user_table' + + OPEN AlterCol + FETCH NEXT FROM AlterCol INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM AlterCol INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + END + CLOSE AlterCol; + DEALLOCATE AlterCol; + +END +GO + +if OBJECT_ID('dbo.Drop_and_Store_Table_Objects') is not null +drop procedure dbo.Drop_and_Store_Table_Objects +go +create procedure dbo.Drop_and_Store_Table_Objects (@TestingMode bit = 0, @AuditingMode bit = 0) +WITH RECOMPILE +AS +BEGIN + SET XACT_ABORT ON + + IF NOT EXISTS(select 1 from tempdb.sys.objects where name like '##Drop_and_Recreate_Objects%') + BEGIN + THROW 51000, '##Drop_and_Recreate_Objects does not exist.', 1; + SET NOEXEC ON + END + + /* + Reference only: + CREATE TABLE ##Drop_and_Recreate_Objects + ( table_object_id int not null PRIMARY KEY ) + */ + + --truncate table ##Drop_and_Recreate_Objects + --insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[pohdr]')) + + select object_name(table_object_id), * from ##Drop_and_Recreate_objects + + --Commented out recursion - should not be needed. + --declare @fksadded int = 1 + --WHILE (@fksadded > 0) + --BEGIN + + if @AuditingMode = 1 print 'Adding FK tables' + + DECLARE @FKloop int = 1 + + WHILE (@FKloop > 0) + BEGIN + + insert into ##Drop_and_Recreate_objects (table_object_id) + select fk.parent_object_id --, FKTable = object_name(fk.parent_object_id), PKTable = object_name( dro.table_object_id), * + from ##Drop_and_Recreate_objects dro + inner join sys.foreign_keys fk on fk.referenced_object_id = dro.table_object_id + where fk.parent_object_id not in (select table_object_id from ##Drop_and_Recreate_objects) + group by fk.parent_object_id + + set @FKloop = @@ROWCOUNT + + if @AuditingMode = 1 print 'Added ' + str(@FKLoop) + ' more referencing foreign key tables to ##Drop_and_Recreate_objects' + END + + BEGIN TRY + DROP TABLE ##DefaultConstraints_to_Drop_and_Recreate; + END TRY + BEGIN CATCH + END CATCH + + IF @AuditingMode = 1 PRINT 'create temp tables' + + CREATE TABLE ##DefaultConstraints_to_Drop_and_Recreate + ( id int not null identity (1,1) primary key + , object_name sysname null + , new_object_name sysname null + , object_id int not null + , drop_tsql nvarchar(max) null + , create_tsql nvarchar(max) null + ) + + BEGIN TRY + DROP TABLE ##Triggers_to_Drop_and_Recreate; + END TRY + BEGIN CATCH + END CATCH + + CREATE TABLE ##Triggers_to_Drop_and_Recreate + ( id int not null identity (1,1) primary key + , object_name sysname null + , object_id int not null + , drop_tsql nvarchar(max) null + , create_tsql nvarchar(max) null + ) + + BEGIN TRY + DROP TABLE ##CheckConstraints_to_Drop_and_Recreate; + END TRY + BEGIN CATCH + END CATCH + + CREATE TABLE ##CheckConstraints_to_Drop_and_Recreate + ( id int not null identity (1,1) primary key + , object_name sysname null + , new_object_name sysname null + , object_id int not null + , drop_tsql nvarchar(max) null + , create_tsql nvarchar(max) null + ) + + BEGIN TRY + DROP TABLE ##Indexes_to_Drop_and_Recreate; + END TRY + BEGIN CATCH + END CATCH + + CREATE TABLE ##Indexes_to_Drop_and_Recreate + ( id int not null identity (1,1) primary key + , object_name sysname null + , object_id int not null + , index_id int not null + , drop_tsql nvarchar(max) null + , create_tsql nvarchar(max) null + ) + + BEGIN TRY + DROP TABLE ##IndexConstraints_to_Drop_and_Recreate; + END TRY + BEGIN CATCH + END CATCH + + CREATE TABLE ##IndexConstraints_to_Drop_and_Recreate + ( id int not null identity (1,1) primary key + , object_name sysname null + , object_id int not null + , index_id int not null + , drop_tsql nvarchar(max) null + , create_tsql nvarchar(max) null + ) + + BEGIN TRY + DROP TABLE ##ForeignKeys_to_Drop_and_Recreate; + END TRY + BEGIN CATCH + END CATCH + + CREATE TABLE ##ForeignKeys_to_Drop_and_Recreate + ( id int not null identity (1,1) primary key + , fk_name sysname null + , drop_tsql nvarchar(max) null + , create_tsql nvarchar(max) null + ) + + BEGIN TRY + DROP TABLE ##DupPK_Floats_to_Drop_and_Recreate; + END TRY + BEGIN CATCH + END CATCH + + CREATE TABLE ##DupPK_Floats_to_Drop_and_Recreate + ( id int not null identity (1,1) primary key + , Referenced_object_id int not null + , referenced_object_name nvarchar(max) not null + , pkcol nvarchar(max) not null + ) + + BEGIN TRY + DROP TABLE ##DupPK_Table_Floats_to_Drop_and_Recreate; + END TRY + BEGIN CATCH + END CATCH + + CREATE TABLE ##DupPK_Table_Floats_to_Drop_and_Recreate + ( id int not null identity (1,1) primary key + , Referenced_object_id int not null + , referenced_object_name nvarchar(max) not null + , pkcol nvarchar(max) not null + , fkcol nvarchar(max) not null + , referencing_object_name nvarchar(max) not null + , Referencing_object_id int not null + ) + + + + --Load up working tables. + insert into ##DefaultConstraints_to_Drop_and_Recreate (object_id) + select tr.object_id from sys.Default_Constraints tr + inner join ##Drop_and_Recreate_Objects dro + on tr.parent_object_id = dro.table_object_id + + insert into ##Triggers_to_Drop_and_Recreate (object_id) + select tr.object_id from sys.triggers tr + inner join ##Drop_and_Recreate_Objects dro + on tr.parent_id = dro.table_object_id + + insert into ##CheckConstraints_to_Drop_and_Recreate (object_id) + select tr.object_id from sys.check_constraints tr + inner join ##Drop_and_Recreate_Objects dro + on tr.parent_object_id = dro.table_object_id; + + INSERT INTO ##DupPK_Floats_to_Drop_and_Recreate ( Referenced_object_id, referenced_object_name, pkcol) + select DISTINCT + Referenced_object_id = referenced_o.object_id + , referenced_object_name = '[' + referenced_s.name + '].[' + referenced_o.name + ']' + , pkcol = referenced_c.name + --, fkcol = child_c.name + --, referencing_object_name = '[' + child_s.name + '].[' + child_o.name + ']' + --, Referencing_object_id = child_o.object_id + --select * + FROM sys.objects referenced_o + inner join ##Drop_and_Recreate_Objects dro on dro.table_object_id = referenced_o.object_id + inner join sys.schemas referenced_s on referenced_o.schema_id = referenced_s.schema_id + inner join sys.columns referenced_c on referenced_c.object_id = referenced_o.object_id + inner join sys.indexes i on i.object_id = referenced_o.object_id and i.is_primary_key = 1 + inner join sys.index_columns ic on i.index_id = ic.index_id and ic.object_id = referenced_o.object_id and referenced_c.column_id = ic.column_id + inner join sys.types t on t.user_type_id = referenced_c.user_type_id + WHERE referenced_o.object_id is not null + and t.name in ('float', 'real') + + INSERT INTO ##DupPK_Table_Floats_to_Drop_and_Recreate (Referenced_object_id, referenced_object_name, pkcol, fkcol, referencing_object_name, Referencing_object_id) + select DISTINCT + Referenced_object_id = referenced_o.object_id + , referenced_object_name = '[' + referenced_s.name + '].[' + referenced_o.name + ']' + , pkcol = referenced_c.name + , fkcol = child_c.name + , referencing_object_name = '[' + child_s.name + '].[' + child_o.name + ']' + , Referencing_object_id = child_o.object_id + FROM sys.objects referenced_o + inner join ##Drop_and_Recreate_Objects dro on dro.table_object_id = referenced_o.object_id + inner join sys.schemas referenced_s on referenced_o.schema_id = referenced_s.schema_id + inner join sys.columns referenced_c on referenced_c.object_id = referenced_o.object_id + inner join sys.indexes i on i.object_id = referenced_o.object_id and i.is_primary_key = 1 + inner join sys.index_columns ic on i.index_id = ic.index_id and ic.object_id = referenced_o.object_id and referenced_c.column_id = ic.column_id + inner join sys.foreign_keys fk on fk.referenced_object_id = referenced_o.object_id + inner join sys.foreign_key_columns referenced_fkc on referenced_fkc.constraint_object_id = fk.object_id and referenced_fkc.referenced_column_id = referenced_c.column_id + inner join sys.foreign_key_columns child_fkc on child_fkc.constraint_object_id = fk.object_id + inner join sys.columns child_c on child_c.column_id = child_fkc.parent_column_id + inner join sys.objects child_o on child_o.object_id = child_fkc.parent_object_id and child_c.object_id = child_o.object_id + inner join sys.schemas child_s on child_s.schema_id = child_o.schema_id + inner join sys.types t on t.user_type_id = referenced_c.user_type_id + WHERE referenced_c.object_id is not null + and t.name in ('float', 'real'); + + /* BEGIN FOREIGN KEYS */ + + WITH cteColumnNames_Base (FKName, ReferencingColumnNames, FKingRank, ReferencedColumnNames, FKedRank) + as ( SELECT FKName = f.name + , ReferencingColumnNames = CAST(c.name as varchar(8000)) + , FKingRank = ROW_NUMBER() OVER (PARTITION BY f.Name ORDER BY rc.column_id ) + , ReferencedColumnNames = CAST(rc.name as varchar(8000)) + , FKedRank = ROW_NUMBER() OVER (PARTITION BY f.Name ORDER BY rc.column_id) + FROM sys.foreign_keys f + inner join sys.objects o on f.parent_object_Id = o.object_id + inner join sys.schemas s on o.schema_id = s.schema_id + inner join sys.objects ro on f.referenced_object_Id = ro.object_id + inner join sys.schemas rs on ro.schema_id = rs.schema_id + inner join ##Drop_and_Recreate_Objects dro on dro.table_object_id = o.object_id + inner join sys.foreign_key_columns fc on fc.constraint_object_id = f.object_id and fc.parent_object_id = o.object_id and fc.referenced_object_id = ro.object_id + inner join sys.columns c on c.object_id = o.object_id and c.column_id = fc.parent_column_id + inner join sys.columns rc on ro.object_id = rc.object_id and rc.column_id = fc.referenced_column_id ) + , cteColumnNames_Concat (FKName, ReferencingColumnNames, ReferencedColumnNames, FKingRank, FKedRank ) + as ( SELECT FKName + , ReferencingColumnNames + , ReferencedColumnNames + , FKingRank + , FKedRank + FROM cteColumnNames_Base + where FKingRank = 1 + or FKedRank = 1 + UNION ALL + SELECT b.FKName + , c.ReferencingColumnNames + '], [' + b.ReferencingColumnNames + , c.ReferencedColumnNames + '], [' + b.ReferencedColumnNames + , b.FKingRank + , b.FKedRank + FROM cteColumnNames_Base b + INNER JOIN cteColumnNames_Concat c + on b.FKName = c.FKName + and ( b.FKingRank = c.FKingRank + 1 + or b.FKedRank = c.FKedRank + 1) + and (b.FKingRank <> 1 and b.FKedRank <> 1) + ) + , cteReferencingColumnNames (FKName, ReferencingColumnNames, TopRank) + as (SELECT FKName + , ReferencingColumnNames + , TopRank = RANK() OVER (PARTITION BY FKName ORDER BY FKingRank Desc) + FROM cteColumnNames_Concat c ) + , cteReferencedColumnNames (FKName, ReferencedColumnNames, TopRank) + as (SELECT FKName + , ReferencedColumnNames + , TopRank = RANK() OVER (PARTITION BY FKName ORDER BY FKedRank Desc) + FROM cteColumnNames_Concat c ) + , cteFK (pktable, fktable) + as ( select + pktable = s1.name + '.' + o1.name + , fktable = isnull(s2.name + '.' + o2.name, '') + from sys.objects o1 + inner join ##Drop_and_Recreate_Objects dro on dro.table_object_id = o1.object_id + left outer join sys.sysforeignkeys fk on o1.object_id = fk.fkeyid + left outer join sys.objects o2 on o2.object_id = fk.rkeyid + left outer join sys.schemas s1 on o1.schema_id = s1.schema_id + left outer join sys.schemas s2 on o2.schema_id = s2.schema_id + where o1.type_desc = 'user_table' + and o1.name not in ('dtproperties','sysdiagrams') + and o1.is_ms_shipped = 0 + group by s1.name + '.' + o1.name + , isnull(s2.name + '.' + o2.name, '') ) + , cteRec (tablename, fkcount) + as ( select tablename = pktable + , fkcount = 0 + from cteFK + + UNION ALL + + select tablename = pktable + , fkcount = 1 + from cteFK + cross apply cteRec + where cteFK.fktable = cteRec.tablename + ) + + + Insert into ##ForeignKeys_to_Drop_and_Recreate (fk_name, drop_tsql, create_tsql) + select --distinct + FKName = f.name + --, ReferencingTableName = s.name + '.' + o.name + --, ReferencingColumnName = '[' + con.ReferencingColumnNames + ']' + --, ReferencedTableName = rs.name + '.' + ro.name + --, ReferencedColumnName = '[' + rcon.ReferencedColumnNames + ']' + , [Drop_TSQL] = 'IF EXISTS (select * from sys.foreign_keys where name = ''' + f.name + ''')' + CHAR(10) + CHAR(13) + + 'ALTER TABLE [' + s.name + '].[' + o.name + '] DROP CONSTRAINT [' + f.name + '] ' + , [Create_TSQL] = 'IF NOT EXISTS (select * from sys.foreign_keys where name = ''' + f.name + ''')' + CHAR(10) + CHAR(13) + + 'ALTER TABLE [' + s.name + '].[' + o.name + '] WITH CHECK ADD CONSTRAINT [' + f.name + '] FOREIGN KEY([' + con.ReferencingColumnNames + ']) ' + CHAR(10)+ CHAR(13) + + 'REFERENCES [' + rs.name + '].[' + ro.name + '] (['+rcon.ReferencedColumnNames+']) ' + + ' ON UPDATE ' + CASE update_referential_action WHEN 0 THEN 'No action' + WHEN 1 THEN 'Cascade' + WHEN 2 THEN 'Set null' + WHEN 3 THEN 'Set default' END + + ' ON DELETE ' + CASE delete_referential_action WHEN 0 THEN 'No action' + WHEN 1 THEN 'Cascade' + WHEN 2 THEN 'Set null' + WHEN 3 THEN 'Set default' END + --, Order = dense_rank() OVER ( ORDER BY max(x.fkcount) desc ) + FROM sys.foreign_keys f + inner join sys.objects o on f.parent_object_Id = o.object_id + inner join sys.schemas s on o.schema_id = s.schema_id + inner join sys.objects ro on f.referenced_object_Id = ro.object_id + inner join sys.schemas rs on ro.schema_id = rs.schema_id + inner join ##Drop_and_Recreate_Objects dro on dro.table_object_id = o.object_id + inner join sys.foreign_key_columns fc on fc.constraint_object_id = f.object_id and fc.parent_object_id = o.object_id and fc.referenced_object_id = ro.object_id + inner join sys.columns c on c.object_id = o.object_id and c.column_id = fc.parent_column_id + inner join sys.columns rc on ro.object_id = rc.object_id and rc.column_id = fc.referenced_column_id + inner join cteReferencingColumnNames con on con.FKName = f.Name and con.TopRank = 1 + inner join cteReferencedColumnNames rcon on rcon.FKName = f.Name and rcon.TopRank = 1 + inner join ( select tablename = fktable + , fkcount = 0 + from cteFK + group by fktable + UNION ALL + select + tablename = tablename + , fkcount = sum(ISNULL(fkcount,0)) + from cteRec + group by tablename + ) x + on x.tablename = rs.name + '.' + ro.name + + group by f.name, s.name, o.name, rs.name, ro.name, con.ReferencingColumnNames, rcon.ReferencedColumnNames, update_referential_action, delete_referential_action, x.tablename + order by dense_rank() OVER ( ORDER BY max(x.fkcount) desc ) asc, f.name--, ReferencingTableName, ReferencedTableName + + + DECLARE @tsql nvarchar(max) + DECLARE dropFKs CURSOR FAST_FORWARD FOR select drop_tsql from ##ForeignKeys_to_Drop_and_Recreate where drop_tsql is not null order by id asc + OPEN dropFKs + FETCH NEXT FROM dropFKs INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM dropFKs INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + END + CLOSE dropFKs; + DEALLOCATE dropFKs; + + /* Now that FK's are down, we can update floats that will create PK's when they get updated to decimal. */ + + + + + + /* END FOREIGN KEYS */ + + + /* DEFAULT CONSTRAINTS */ + /* These next two commands should be run after all needed DefaultConstraints have been inserted into ##DefaultConstraints_to_Drop_and_Recreate and are ready to be dropped. */ + UPDATE otrtemp set + --select *, + object_name = object_name (otrtemp.object_id) + , new_object_name = CASE WHEN tr.is_system_named = 1 or tr.name like '%__%__%' + THEN 'DF_'+replace(ot.name,' ','_')+'_'+replace(c.name,' ','_') + ELSE object_name (otrtemp.object_id) + END + , drop_tsql = 'IF EXISTS (select top 1 * from sys.default_constraints dc where name = '''+tr.name+''') ' + CHAR(13) + + CHAR(9) + 'ALTER TABLE ['+s.name + '].[' + ot.name + '] DROP CONSTRAINT [' + tr.name + '];' + , create_tsql = 'IF (OBJECT_ID(N''[' + tr.name + ']'') IS NULL AND OBJECT_ID(N''['+CASE WHEN tr.is_system_named = 1 or tr.name like '%__%__%' + THEN 'DF_'+replace(ot.name,' ','_')+'_'+replace(c.name,' ','_') + ELSE object_name (otrtemp.object_id) + END+']'') IS NULL)' + CHAR(13) + CHAR(9) + + 'ALTER TABLE ['+s.name + '].[' + ot.name + '] ADD CONSTRAINT ['+ + CASE WHEN tr.is_system_named = 1 or tr.name like '%__%__%' + THEN 'DF_'+replace(ot.name,' ','_')+'_'+replace(c.name,' ','_') + ELSE object_name (otrtemp.object_id) + END + +'] DEFAULT (' + tr.definition + ') FOR ['+c.name+'];' + CHAR(13) + from ##DefaultConstraints_to_Drop_and_Recreate otrtemp + inner join sys.Default_Constraints tr + on otrtemp.object_id = tr.object_id + inner join sys.objects ot + on ot.object_id = tr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.columns c + on c.object_id = ot.object_id + and tr.parent_column_id = c.column_id + + --This query for testing only. Compare to the same query run at the end to verify DefaultConstraints were created/recreated correctly. + IF @AuditingMode = 1 + select '##DefaultConstraints_to_Drop_and_Recreate ', * from ##DefaultConstraints_to_Drop_and_Recreate otrtemp + inner join sys.Default_Constraints tr + on otrtemp.object_name = object_name(tr.object_id) + inner join sys.objects ot + on ot.object_id = tr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.columns c + on c.object_id = ot.object_id + and tr.parent_column_id = c.column_id + order by ot.object_id, c.name + + /* Here is where we actually drop the DefaultConstraints. Only the DefaultConstraints inserted into ##DefaultConstraints_to_Drop_and_Recreate will be dropped.*/ + --DROP DefaultConstraints STEP + --DECLARE @tsql nvarchar(max) + DECLARE dropDefaultConstraints CURSOR FAST_FORWARD FOR select drop_tsql from ##DefaultConstraints_to_Drop_and_Recreate where drop_tsql is not null order by id asc + OPEN dropDefaultConstraints + FETCH NEXT FROM dropDefaultConstraints INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM dropDefaultConstraints INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + END + CLOSE dropDefaultConstraints; + DEALLOCATE dropDefaultConstraints; + + /* CHECK CONSTRAINTS */ + + /* These next two commands should be run after all needed CheckConstraints have been inserted into ##CheckConstraints_to_Drop_and_Recreate and are ready to be dropped. */ + UPDATE otrtemp set + --select *, + object_name = object_name (otrtemp.object_id) + , new_object_name = CASE WHEN tr.is_system_named = 1 or tr.name like '%__%__%' + THEN 'CK_'+replace(ot.name,' ','_')+'_'+replace(c.name,' ','_') + ELSE object_name (otrtemp.object_id) + END + , drop_tsql = 'IF EXISTS (select top 1 * from sys.Check_constraints dc where name = '''+tr.name+''') ' + CHAR(10)+CHAR(13) + + CHAR(9) + 'ALTER TABLE ['+s.name + '].[' + ot.name + '] DROP CONSTRAINT [' + tr.name + '];' + , create_tsql = 'IF (OBJECT_ID(N''[' + tr.name + ']'') IS NULL AND OBJECT_ID(N''[CK_'+replace(ot.name,' ','_')+'_'+replace(c.name,' ','_') + ']'') IS NULL)' + CHAR(10)+CHAR(13) + CHAR(9) + + 'ALTER TABLE ['+s.name + '].[' + ot.name + '] ADD CONSTRAINT ['+ CASE WHEN tr.is_system_named = 1 or tr.name like '%__%__%' + THEN 'CK_'+replace(ot.name,' ','_')+'_'+replace(c.name,' ','_') + ELSE object_name (otrtemp.object_id) + END +'] Check (' + tr.definition + ')' + from ##CheckConstraints_to_Drop_and_Recreate otrtemp + inner join sys.Check_Constraints tr + on otrtemp.object_id = tr.object_id + inner join sys.objects ot + on ot.object_id = tr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.columns c + on c.object_id = ot.object_id + and tr.parent_column_id = c.column_id + + --This query for testing only. Compare to the same query run at the end to verify CheckConstraints were created/recreated correctly. + IF @AuditingMode = 1 + select CheckConstraints_to_Drop_and_Recreate = '##CheckConstraints_to_Drop_and_Recreate', * from ##CheckConstraints_to_Drop_and_Recreate otrtemp + inner join sys.Check_Constraints tr + on otrtemp.object_name = object_name(tr.object_id) + inner join sys.objects ot + on ot.object_id = tr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.columns c + on c.object_id = ot.object_id + and tr.parent_column_id = c.column_id + order by ot.object_id, c.name + + /* Here is where we actually drop the CheckConstraints. Only the CheckConstraints inserted into ##CheckConstraints_to_Drop_and_Recreate will be dropped.*/ + --DROP CheckConstraints STEP + --DECLARE @tsql nvarchar(max) + DECLARE dropCheckConstraints CURSOR FAST_FORWARD FOR select drop_tsql from ##CheckConstraints_to_Drop_and_Recreate where drop_tsql is not null order by id asc + OPEN dropCheckConstraints + FETCH NEXT FROM dropCheckConstraints INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM dropCheckConstraints INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + + END + CLOSE dropCheckConstraints; + DEALLOCATE dropCheckConstraints; + + /* BEGIN DROP TRIGGERS */ + + /* These next two commands should be run after all needed triggers have been inserted into ##Triggers_to_Drop_and_Recreate and are ready to be dropped. */ + UPDATE otrtemp + set + object_name = object_name (otrtemp.object_id) + , drop_tsql = N'IF OBJECT_ID(N''[' + str.name + '].[' + otr.name +']'') IS NOT NULL ' + CHAR(10) + CHAR(13) + ' DROP TRIGGER [' + str.name + '].[' + otr.name +']' + , create_tsql = LTRIM(m.definition) + from ##Triggers_to_Drop_and_Recreate otrtemp + inner join sys.sql_modules m + on otrtemp.object_id = m.object_id + inner join sys.objects otr + on m.object_id = otr.object_id + inner join sys.schemas str + on str.schema_id = otr.schema_id + inner join sys.objects ot + on ot.object_id = otr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.triggers tr + on otr.object_id = tr.object_id + where otr.type_desc = 'SQL_TRIGGER' + and tr.is_disabled = 0 + + INSERT INTO ##Triggers_to_Drop_and_Recreate (object_id, create_tsql) + select + m.object_id + , create_tsql = LTRIM(case when te.is_first =1 THEN N'exec sp_settriggerorder @Triggername = N'''+str.name+'.'+otr.name+N''', @order = ''first'', @stmttype = '''+te.type_desc+N''';' COLLATE SQL_Latin1_General_CP1_CI_AS + when te.is_last = 1 THEN N'exec sp_settriggerorder @Triggername = N'''+str.name+'.'+otr.name+N''', @order = ''last'', @stmttype = '''+te.type_desc+N''';' COLLATE SQL_Latin1_General_CP1_CI_AS + else null + end) + from sys.sql_modules m + inner join sys.objects otr + on m.object_id = otr.object_id + inner join sys.schemas str + on str.schema_id = otr.schema_id + inner join sys.objects ot + on ot.object_id = otr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.trigger_events te + on te.object_id = otr.object_id + inner join sys.triggers tr + on otr.object_id = tr.object_id + where otr.type_desc = 'SQL_TRIGGER' + and (is_first =1 or is_last = 1) + and tr.is_disabled = 0 + + --This query for testing only. Compare to the same query run at the end to verify triggers were created/recreated correctly. + IF @AuditingMode = 1 + select Triggers_to_Drop_and_Recreate = '##Triggers_to_Drop_and_Recreate', * from + ##Triggers_to_Drop_and_Recreate tdr + inner join sys.sql_modules m + on tdr.object_name = object_name(m.object_id) + inner join sys.objects otr + on m.object_id = otr.object_id + inner join sys.schemas str + on str.schema_id = otr.schema_id + inner join sys.objects ot + on ot.object_id = otr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.trigger_events te + on te.object_id = otr.object_id + inner join sys.triggers tr + on otr.object_id = tr.object_id + where otr.type_desc = 'SQL_TRIGGER' + and tr.is_disabled = 0 + order by tdr.object_id, m.definition + + /* Here is where we actually drop the triggers. Only the triggers inserted into ##Triggers_to_Drop_and_Recreate will be dropped.*/ + --DROP TRIGGERS STEP + --DECLARE @tsql nvarchar(max) + DECLARE droptriggers CURSOR FAST_FORWARD FOR select drop_tsql from ##Triggers_to_Drop_and_Recreate where drop_tsql is not null order by id asc + OPEN droptriggers + FETCH NEXT FROM droptriggers INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM droptriggers INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + + END + CLOSE droptriggers; + DEALLOCATE droptriggers; + + /* END DROP TRIGGERS */ + + /* BEGIN DROP INDEXES */ + + DECLARE @counter int, @maxcounter int, @colsholder nvarchar(max), @includesholder nvarchar(max), @SQLHolder nvarchar(max) + + + BEGIN TRY + DROP TABLE ##IndexObjects_Working; + END TRY + BEGIN CATCH + END CATCH + + CREATE TABLE ##IndexObjects_Working ( + ID int IDENTITY(1,1) PRIMARY KEY + , ObjectID int NOT NULL + , IndexID int NOT NULL + , Index_type nvarchar(150) NOT NULL + , Index_name nvarchar(150) NOT NULL + , Primary_Key bit NOT NULL + , Unique_Constraint bit NOT NULL + , Is_Unique bit not null + , table_name nvarchar(150) NOT NULL + , Cols nvarchar(max) NULL + , Includes nvarchar(max) NULL + , Set_FillFactor tinyint NOT NULL + , Set_PADINDEX bit NOT NULL + , Set_ALLOW_ROW_LOCKS bit NOT NULL + , Set_ALLOW_PAGE_LOCKS bit NOT NULL + , DATA_COMPRESSION varchar(10) NULL + ) + + INSERT INTO ##IndexObjects_Working ( + ObjectID + , IndexID + , Index_type + , Index_name + , Primary_Key + , Unique_Constraint + , Is_Unique + , table_name + , Cols + , Includes + , Set_FillFactor + , Set_PADINDEX + , Set_ALLOW_ROW_LOCKS + , Set_ALLOW_PAGE_LOCKS + , DATA_COMPRESSION + ) + SELECT + ObjectID = o.[object_ID] + , IndexID = i.index_id + , Index_type = i.type_desc + , Index_name = i.name + , Primary_Key = i.is_primary_key + , Unique_Constraint = i.is_unique_constraint + , Is_Unique = i.is_unique + , table_name = N'[' + s.name + N'].[' + o.name + ']' + , Cols = NULL + , Includes = NULL + , Set_FillFactor = i.fill_factor + , Set_PADINDEX = i.is_padded + , Set_ALLOW_ROW_LOCKS = i.allow_row_locks + , Set_ALLOW_PAGE_LOCKS = i.allow_page_locks + , DATA_COMPRESSION = ISNULL(p.data_compression_desc, 'NONE') + FROM sys.objects o + inner join sys.indexes i + on o.[object_id] = i.[object_id] + inner join sys.schemas s + on s.schema_id = o.schema_id + inner join sys.partitions p + on p.index_id = i.index_id + and p.object_id = o.object_id + inner join ##Drop_and_Recreate_Objects dro + on dro.table_object_id = o.object_id + where 1=1 + and o.type = 'u' + and i.index_id >= 1 + ORDER BY is_Primary_key desc + + SELECT @counter = 1, @colsholder = null, @includesholder = null, @maxcounter = max(T.id) FROM ##IndexObjects_Working T + + WHILE @counter <= @maxcounter + BEGIN + + SELECT @colsholder = CASE WHEN @colsholder IS NULL THEN '' ELSE @colsholder + N', ' END + N'[' + c.name + N'] ' + CASE WHEN ic.is_descending_key = 1 THEN 'DESC' ELSE 'ASC' END + FROM ##IndexObjects_Working T + inner join sys.index_columns ic + on ic.[object_id] = T.objectid + and ic.index_id = T.indexid + inner join sys.columns c + on c.[object_id] = T.objectid + and c.column_id = ic.column_id + WHERE T.id = @counter + and is_included_column = 0 -- key field + ORDER BY Index_column_id + + UPDATE ##IndexObjects_Working + SET Cols = @colsholder + WHERE ID = @counter + + SELECT @includesholder = CASE WHEN @includesholder IS NULL THEN '' ELSE @includesholder + N', ' END + N'[' + c.name + N'] ' + FROM ##IndexObjects_Working T + inner join sys.index_columns ic + on ic.[object_id] = T.objectid + and ic.index_id = T.indexid + inner join sys.columns c + on c.[object_id] = T.objectid + and c.column_id = ic.column_id + WHERE T.id = @counter + and is_included_column = 1 -- included field + ORDER BY Index_column_id + + UPDATE ##IndexObjects_Working + SET Includes = @includesholder + WHERE ID = @counter + SELECT @counter = @counter + 1, @colsholder = null, @includesholder = null + + END + + -- Unique Constraint + INSERT INTO ##IndexConstraints_to_Drop_and_Recreate (object_name, object_id, Index_id, drop_tsql, create_tsql) + SELECT + Object_name = '[' + Index_Name + ']' + , Object_Id = t.ObjectID + , Index_id = t.IndexID + , drop_tsql = --CASE WHEN EXISTS (SELECT 1 FROM sys.change_tracking_tables where OBJECT_ID = t.ObjectID) THEN + 'IF EXISTS (SELECT TOP 1 * FROM sys.change_tracking_tables WHERE Object_id = ' + str(t.ObjectID) + ')' + CHAR(10)+CHAR(13) + + 'ALTER TABLE ' + table_name + ' DISABLE CHANGE_TRACKING;' --ELSE '' END + + CHAR(10)+CHAR(13) + + 'IF EXISTS (SELECT top 1 * from sys.indexes i where i.object_id = '+ cast (ObjectID as varchar(30)) +' and i.name = '''+Index_Name+''')'+ CHAR(10)+CHAR(13) + + ' ALTER TABLE ' + table_name + ' DROP CONSTRAINT [' + Index_Name + ']' + , create_tsql = 'IF NOT EXISTS (SELECT top 1 * from sys.indexes i where i.object_id = N'''+ cast (ObjectID as varchar(30)) +''' and i.name = '''+Index_Name+''')'+ CHAR(10)+CHAR(13) + + ' ALTER TABLE ' + table_name + ' ADD CONSTRAINT [' + Index_Name + ']' + + CASE WHEN Primary_Key = 1 THEN ' PRIMARY KEY ' WHEN Unique_Constraint = 1 THEN ' UNIQUE ' ELSE '' END + + Index_Type + ' (' + Cols + ') ' + --Add for extended options + + ' WITH (PAD_INDEX = ' + CASE WHEN Set_PADINDEX = 0 THEN ' OFF' ELSE ' ON' END + + ', ALLOW_ROW_LOCKS = ' + CASE WHEN Set_ALLOW_ROW_LOCKS = 0 THEN ' OFF' ELSE ' ON' END + + ', ALLOW_PAGE_LOCKS = ' + CASE WHEN Set_ALLOW_PAGE_LOCKS = 0 THEN ' OFF' ELSE ' ON' END + + CASE WHEN Set_FillFactor = 0 THEN '' ELSE ', FILLFACTOR = ' + CONVERT(VARCHAR(10),Set_FillFactor) END + + ', DATA_COMPRESSION = ' + t.data_compression + ')' + CHAR(10)+CHAR(13) + -- + CASE WHEN EXISTS (SELECT 1 FROM sys.change_tracking_tables where OBJECT_ID = ObjectID) THEN + + 'IF EXISTS (SELECT TOP 1 * FROM sys.change_tracking_tables WHERE Object_id = ' + str(ObjectID) + ')' + CHAR(10)+CHAR(13) + + ' ALTER TABLE ' + table_name + ' ENABLE CHANGE_TRACKING ' + + CASE WHEN EXISTS (SELECT 1 FROM sys.change_tracking_tables where is_track_columns_updated_on =1 and OBJECT_ID = t.ObjectID) THEN ' WITH (TRACK_COLUMNS_UPDATED = ON)' ELSE ';' END + --ELSE '' END + FROM ##IndexObjects_Working t + WHERE Primary_Key = 1 OR Unique_Constraint = 1 + + -- Nonclustered Index + INSERT INTO ##Indexes_to_Drop_and_Recreate (object_name, object_id, Index_id, drop_tsql, create_tsql) + SELECT + Object_name = '[' + Index_Name + ']' + , Object_Id = ObjectID + , Index_id = IndexID + , drop_tsql = 'IF EXISTS (SELECT top 1 * from sys.indexes i where i.object_id = '+ cast (ObjectID as varchar(30)) +' and i.name = '''+Index_Name+''')'+ CHAR(10)+CHAR(13) + + ' DROP INDEX [' + Index_Name + '] ON ' + table_name + ' WITH ( ONLINE = OFF ) ' + , create_tsql = 'IF NOT EXISTS (SELECT top 1 * from sys.indexes i where i.object_id = '+ cast (ObjectID as varchar(30)) +' and i.name = '''+Index_Name+''')'+ CHAR(10)+CHAR(13)+ + + 'CREATE ' + CASE t.Is_Unique WHEN 1 THEN ' UNIQUE ' ELSE '' END + + Index_Type + ' INDEX [' + Index_Name + '] ON ' + table_name + ' (' + Cols + ') ' + + CASE WHEN Includes is null then '' ELSE ' INCLUDE (' + Includes + ') ' END + + ' WITH (PAD_INDEX = ' + CASE WHEN Set_PADINDEX = 0 THEN ' OFF ' ELSE ' ON ' END + + ', ALLOW_ROW_LOCKS = ' + CASE WHEN Set_ALLOW_ROW_LOCKS = 0 THEN ' OFF ' ELSE ' ON ' END + + ', ALLOW_PAGE_LOCKS = ' + CASE WHEN Set_ALLOW_PAGE_LOCKS = 0 THEN ' OFF ' ELSE ' ON ' END + + CASE WHEN Set_FillFactor = 0 THEN '' ELSE ', FILLFACTOR = ' + CONVERT(VARCHAR(10),Set_FillFactor) END + + ', DATA_COMPRESSION = ' + t.data_compression + ')' + FROM ##IndexObjects_Working t + WHERE Primary_Key = 0 AND Unique_Constraint = 0 + + --select * from ##IndexObjects_Working where index_name like '%UIX__invoice_export_history__invoice_number__export_date%' + --select * from ##IndexConstraints_to_Drop_and_Recreate where object_name like '%UIX__invoice_export_history__invoice_number__export_date%' + + DECLARE dropIndexes CURSOR FAST_FORWARD FOR select drop_tsql from ##Indexes_to_Drop_and_Recreate where drop_tsql is not null order by id asc + OPEN dropIndexes + FETCH NEXT FROM dropIndexes INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM dropIndexes INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + END + CLOSE dropIndexes; + DEALLOCATE dropIndexes; + + DECLARE dropIndexConstraints CURSOR FAST_FORWARD FOR select drop_tsql from ##IndexConstraints_to_Drop_and_Recreate where drop_tsql is not null order by id asc + OPEN dropIndexConstraints + FETCH NEXT FROM dropIndexConstraints INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM dropIndexConstraints INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + END + CLOSE dropIndexConstraints; + DEALLOCATE dropIndexConstraints; + + /* END DROP INDEXES */ + + +END + +GO + +if OBJECT_ID('dbo.Recreate_Stored_Table_Objects') is not null +drop procedure dbo.Recreate_Stored_Table_Objects +go + +CREATE PROCEDURE dbo.Recreate_Stored_Table_Objects (@TestingMode bit = 0, @AuditingMode bit = 0) +WITH RECOMPILE +AS +BEGIN + + SET XACT_ABORT ON + + IF NOT EXISTS(select 1 from tempdb.sys.objects where name like '##Drop_and_Recreate_Objects%') + BEGIN + THROW 51000, '##Drop_and_Recreate_Objects does not exist.', 1; + SET NOEXEC ON + END + + /* IndexConstraints */ + + --This query for testing only. + IF @AuditingMode = 1 + select IndexConstraints_to_Drop_and_Recreate= '##IndexConstraints_to_Drop_and_Recreate', * from + ##IndexConstraints_to_Drop_and_Recreate tdr + order by tdr.object_id, tdr.index_id + + BEGIN TRY + BEGIN TRAN CREATEIndexConstraints + --RECREATE TRIGGERS STEP + DECLARE @tsql nvarchar(max) + DECLARE createtriggers CURSOR FAST_FORWARD FOR select create_tsql from ##IndexConstraints_to_Drop_and_Recreate where create_tsql is not null order by id asc + OPEN createtriggers + FETCH NEXT FROM createtriggers INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM createtriggers INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + + END + CLOSE createtriggers; + DEALLOCATE createtriggers; + + --This query for testing only. + IF @AuditingMode = 1 + select IndexConstraints_to_Drop_and_Recreate = '##IndexConstraints_to_Drop_and_Recreate', * from + ##IndexConstraints_to_Drop_and_Recreate tdr + inner join sys.objects otr + on tdr.object_id = otr.object_id + inner join sys.schemas str + on str.schema_id = otr.schema_id + inner join sys.indexes i + on i.index_id = tdr.index_id + and i.object_id = tdr.object_id + order by tdr.object_id, tdr.index_id + + IF ( ISNULL((SELECT COUNT(distinct object_id) from ##IndexConstraints_to_Drop_and_Recreate),0) + = ISNULL((SELECT COUNT(distinct otr.object_id) from ##IndexConstraints_to_Drop_and_Recreate t inner join sys.objects otr on t.object_id = otr.object_id),0) + ) + BEGIN; + COMMIT TRAN CREATEIndexConstraints; + PRINT 'Index Constraints count validation successful.' + DROP TABLE ##IndexConstraints_to_Drop_and_Recreate + DROP TABLE ##IndexObjects_Working + + END; + ELSE + BEGIN; + THROW 51000, 'The number of IndexConstraints that should exist does not match the number of IndexConstraints that exist! Problems re-creating IndexConstraints. Examine print statements generated by cursors for errors. The temp table containing the IndexConstraints has not been dropped, but no IndexConstraints currently exist in the database. Remediation is necessary!', 1; + END; + END TRY + BEGIN CATCH + IF @@TRANCOUNT > 0 + ROLLBACK TRAN CREATEIndexConstraints; + THROW; + + END CATCH + + + + + /* DEFAULT CONSTRAINTS */ + + BEGIN TRY + IF @TestingMode = 0 BEGIN TRAN CREATEDefaultConstraints + + --RECREATE DefaultConstraints STEP + --DECLARE @tsql nvarchar(max) + DECLARE createDefaultConstraints CURSOR FAST_FORWARD FOR select create_tsql from ##DefaultConstraints_to_Drop_and_Recreate where create_tsql is not null order by id asc + OPEN createDefaultConstraints + FETCH NEXT FROM createDefaultConstraints INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM createDefaultConstraints INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + + END + CLOSE createDefaultConstraints; + DEALLOCATE createDefaultConstraints; + + --This query for testing only. Compare to the same query run at the beginning to verify DefaultConstraints were created/recreated correctly. + IF @AuditingMode = 1 + select DefaultConstraints_to_Drop_and_Recreate = '##DefaultConstraints_to_Drop_and_Recreate', * from ##DefaultConstraints_to_Drop_and_Recreate otrtemp + inner join sys.Default_Constraints tr + on otrtemp.new_object_name = object_name(tr.object_id) + inner join sys.objects ot + on ot.object_id = tr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.columns c + on c.object_id = ot.object_id + and tr.parent_column_id = c.column_id + order by ot.object_id, c.name; + + IF ( ISNULL((SELECT COUNT(distinct object_id) from ##DefaultConstraints_to_Drop_and_Recreate),0) + = ISNULL((SELECT COUNT(distinct dc.object_id) from ##DefaultConstraints_to_Drop_and_Recreate t inner join sys.Default_Constraints dc on t.new_object_name = object_name(dc.object_id)),0) + ) + BEGIN; + IF @TestingMode = 0 COMMIT TRAN CREATEDefaultConstraints; + IF @TestingMode = 0 PRINT 'Default Constraint count validation successful.' + + DROP TABLE ##DefaultConstraints_to_Drop_and_Recreate; + END; + ELSE + BEGIN; + IF @TestingMode = 0 THROW 51000, 'The number of DefaultConstraints that should exist does not match the number of DefaultConstraints that exist! Problems re-creating DefaultConstraints. Examine print statements generated by cursors for errors. The temp table containing the defaultconstraints has not been dropped, but no defaultconstraints currently exist in the database. Remediation is necessary!', 1; + END; + END TRY + BEGIN CATCH + IF @@TRANCOUNT > 0 IF @TestingMode = 0 ROLLBACK TRAN CREATEDefaultConstraints; + THROW; + + END CATCH + + + + /* CHECK CONSTRAINTS */ + + BEGIN TRY + IF @TestingMode = 0 BEGIN TRAN CREATECheckConstraints + + --RECREATE CheckConstraints STEP + --DECLARE @tsql nvarchar(max) + DECLARE createCheckConstraints CURSOR FAST_FORWARD FOR select create_tsql from ##CheckConstraints_to_Drop_and_Recreate where create_tsql is not null order by id asc + OPEN createCheckConstraints + FETCH NEXT FROM createCheckConstraints INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM createCheckConstraints INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + + END + CLOSE createCheckConstraints; + DEALLOCATE createCheckConstraints; + + --This query for testing only. Compare to the same query run at the beginning to verify CheckConstraints were created/recreated correctly. + IF @AuditingMode = 1 + select CheckConstraints_to_Drop_and_Recreate = '##CheckConstraints_to_Drop_and_Recreate', * from ##CheckConstraints_to_Drop_and_Recreate otrtemp + inner join sys.Check_Constraints tr + on otrtemp.new_object_name = object_name(tr.object_id) + inner join sys.objects ot + on ot.object_id = tr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.columns c + on c.object_id = ot.object_id + and tr.parent_column_id = c.column_id + order by ot.object_id, c.name; + + IF ( ISNULL((SELECT COUNT(distinct object_id) from ##CheckConstraints_to_Drop_and_Recreate),0) + = ISNULL((SELECT COUNT(distinct dc.object_id) from ##CheckConstraints_to_Drop_and_Recreate t inner join sys.Check_Constraints dc on t.new_object_name = object_name(dc.object_id)),0) + ) + BEGIN; + IF @TestingMode = 0 COMMIT TRAN CREATECheckConstraints; + IF @TestingMode = 0 PRINT 'Check Constraint count validation successful.' + + DROP TABLE ##CheckConstraints_to_Drop_and_Recreate; + END; + ELSE + BEGIN; + IF @TestingMode = 0 THROW 51000, 'The number of CheckConstraints that should exist does not match the number of CheckConstraints that exist! Problems re-creating CheckConstraints. Examine print statements generated by cursors for errors. The temp table containing the Checkconstraints has not been dropped, but no Checkconstraints currently exist in the database. Remediation is necessary!', 1; + END; + END TRY + BEGIN CATCH + + IF @@TRANCOUNT > 0 IF @TestingMode = 0 ROLLBACK TRAN CREATECheckConstraints; + THROW; + + END CATCH + + + + /* TRIGGERS */ + + IF @AuditingMode = 1 + select Triggers_to_Drop_and_Recreate = '##Triggers_to_Drop_and_Recreate', * from + ##Triggers_to_Drop_and_Recreate tdr + + BEGIN TRY + BEGIN TRAN CREATETRIGGERS + --RECREATE TRIGGERS STEP + --DECLARE @tsql nvarchar(max) + DECLARE createtriggers CURSOR FAST_FORWARD FOR select create_tsql from ##Triggers_to_Drop_and_Recreate where create_tsql is not null order by id asc + OPEN createtriggers + FETCH NEXT FROM createtriggers INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM createtriggers INTO @tsql + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + + END + CLOSE createtriggers; + DEALLOCATE createtriggers; + + --This query for testing only. Compare to the same query run at the beginning to verify triggers were created/recreated correctly. + IF @AuditingMode = 1 + select Triggers_to_Drop_and_Recreate = '##Triggers_to_Drop_and_Recreate', * from + ##Triggers_to_Drop_and_Recreate tdr + inner join sys.sql_modules m + on tdr.object_name = object_name(m.object_id) + inner join sys.objects otr + on m.object_id = otr.object_id + inner join sys.schemas str + on str.schema_id = otr.schema_id + inner join sys.objects ot + on ot.object_id = otr.parent_object_id + inner join sys.schemas s + on s.schema_id = ot.schema_id + inner join sys.trigger_events te + on te.object_id = otr.object_id + inner join sys.triggers tr + on otr.object_id = tr.object_id + where otr.type_desc = 'SQL_TRIGGER' + and tr.is_disabled = 0 + order by tdr.object_id, m.definition + + IF ( ISNULL((SELECT COUNT(distinct object_id) from ##Triggers_to_Drop_and_Recreate),0) + = ISNULL((SELECT COUNT(distinct otr.object_id) from ##Triggers_to_Drop_and_Recreate t inner join sys.objects otr on t.object_name = object_name(otr.object_id)),0) + ) + BEGIN; + COMMIT TRAN CREATETRIGGERS; + PRINT 'Trigger count validation successful.' + + DROP TABLE ##Triggers_to_Drop_and_Recreate + + END; + ELSE + BEGIN; + THROW 51000, 'The number of Triggers that should exist does not match the number of Triggers that exist! Problems re-creating Triggers. Examine print statements generated by cursors for errors. The temp table containing the Triggers has not been dropped, but no Triggers currently exist in the database. Remediation is necessary!', 1; + END; + END TRY + BEGIN CATCH + IF @@TRANCOUNT > 0 + ROLLBACK TRAN CREATETRIGGERS; + THROW; + + END CATCH + + /* INDEXES */ + + --This query for testing only. + IF @AuditingMode = 1 + select Indexes_to_Drop_and_Recreate= '##Indexes_to_Drop_and_Recreate', * from + ##Indexes_to_Drop_and_Recreate tdr + order by tdr.object_id, tdr.index_id + + + BEGIN TRY + BEGIN TRAN CREATEINDEXES + --RECREATE INDEXES STEP + --DECLARE @tsql nvarchar(max) + DECLARE CREATEINDEXES CURSOR FAST_FORWARD FOR select create_tsql from ##Indexes_to_Drop_and_Recreate where create_tsql is not null order by id asc + OPEN CREATEINDEXES + FETCH NEXT FROM CREATEINDEXES INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM CREATEINDEXES INTO @tsql + + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + + END + CLOSE CREATEINDEXES; + DEALLOCATE CREATEINDEXES; + + --This query for testing only. + IF @AuditingMode = 1 + select Indexes_to_Drop_and_Recreate = '##Indexes_to_Drop_and_Recreate', * from + ##Indexes_to_Drop_and_Recreate tdr + inner join sys.objects otr + on tdr.object_id = otr.object_id + inner join sys.schemas str + on str.schema_id = otr.schema_id + inner join sys.indexes i + on i.index_id = tdr.index_id + and i.object_id = tdr.object_id + where tdr.create_tsql is not null + order by tdr.object_id, i.index_id + + IF ( ISNULL((SELECT COUNT(object_id) from ##Indexes_to_Drop_and_Recreate),0) + = ISNULL((SELECT COUNT(otr.object_id) from ##Indexes_to_Drop_and_Recreate t inner join sys.objects otr on t.object_id = otr.object_id),0) + ) + BEGIN; + COMMIT TRAN CREATEINDEXES; + PRINT 'Index count validation successful.' + DROP TABLE ##Indexes_to_Drop_and_Recreate + + END; + ELSE + BEGIN; + THROW 51000, 'The number of Indexes that should exist does not match the number of Indexes that exist! Problems re-creating Indexes. Examine print statements generated by cursors for errors. The temp table containing the Indexes has not been dropped, but no Indexes currently exist in the database. Remediation is necessary!', 1; + END; + END TRY + BEGIN CATCH + IF @@TRANCOUNT > 0 + ROLLBACK TRAN CREATEINDEXES; + THROW; + + END CATCH + + + + /* FOREIGN KEYS */ + + --This query for testing only. + IF @AuditingMode = 1 + select ForeignKeys_to_Drop_and_Recreate = '##ForeignKeys_to_Drop_and_Recreate', * from + ##ForeignKeys_to_Drop_and_Recreate tdr + order by tdr.fk_name + + + BEGIN TRY + BEGIN TRAN CREATEForeignKeys + + --RECREATE ForeignKeys STEP + --DECLARE @tsql nvarchar(max) + DECLARE CREATEForeignKeys CURSOR FAST_FORWARD FOR select create_tsql from ##ForeignKeys_to_Drop_and_Recreate where create_tsql is not null order by id asc + OPEN CREATEForeignKeys + FETCH NEXT FROM CREATEForeignKeys INTO @tsql + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + print @tsql; + IF @TestingMode = 0 exec sp_executesql @tsql; + FETCH NEXT FROM CREATEForeignKeys INTO @tsql + + END TRY + BEGIN CATCH + THROW; + SET NOEXEC ON; + END CATCH + + END + CLOSE CREATEForeignKeys; + DEALLOCATE CREATEForeignKeys; + + --This query for testing only. + IF @AuditingMode = 1 + select ForeignKeys_to_Drop_and_Recreate= '##ForeignKeys_to_Drop_and_Recreate', * from + ##ForeignKeys_to_Drop_and_Recreate tdr + inner join sys.foreign_keys fk + on fk.name = tdr.fk_name + where tdr.create_tsql is not null + order by tdr.fk_name + + IF ( ISNULL((SELECT COUNT(fk_name) from ##ForeignKeys_to_Drop_and_Recreate),0) + = ISNULL((SELECT COUNT(t.fk_name) from ##ForeignKeys_to_Drop_and_Recreate t inner join sys.foreign_keys fk on fk.name = t.fk_name),0) + ) + BEGIN; + COMMIT TRAN CREATEForeignKeys; + PRINT 'Foreign Key count validation successful.' + DROP TABLE ##ForeignKeys_to_Drop_and_Recreate + + END; + ELSE + BEGIN; + THROW 51000, 'The number of ForeignKeys that should exist does not match the number of ForeignKeys that exist! Problems re-creating ForeignKeys. Examine print statements generated by cursors for errors. The temp table containing the ForeignKeys has not been dropped, but no ForeignKeys currently exist in the database. Remediation is necessary!', 1; + END; + END TRY + BEGIN CATCH + IF @@TRANCOUNT > 0 + ROLLBACK TRAN CREATEForeignKeys; + THROW; + + END CATCH + + END +go + diff --git a/Find_Mini_Dump.sql b/Find_Mini_Dump.sql new file mode 100644 index 0000000..9e97685 --- /dev/null +++ b/Find_Mini_Dump.sql @@ -0,0 +1,5 @@ +-- Get information on location, time and size of any memory dumps from SQL Server +-- Only SQL 2008R2+ +SELECT [filename], creation_time, size_in_bytes/1048576.0 AS [Size (MB)] +FROM sys.dm_server_memory_dumps +ORDER BY creation_time DESC OPTION (RECOMPILE); \ No newline at end of file diff --git a/FirstByte.sql b/FirstByte.sql new file mode 100644 index 0000000..cd4c3fa --- /dev/null +++ b/FirstByte.sql @@ -0,0 +1,269 @@ +------------------------------------------------------------- +---- DBA Hound First Byte +-- Works only for SQL 2008+ +------------------------------------------------------------- +DECLARE @Results TABLE +(severity varchar(15) null +,Category varchar(50) null +,MostRecent datetime2(0) null +,Issue varchar(max) null +,Details varchar(max) null +); + + +------------------------------------------------------------- +--- Severity 'Critical' +------------------------------------------------------------- + +------------------ Disaster Recovery / Backups ------------- +-- This should return a row for every database, if there are no rows then +-- backups have been failing or never done +-------------------------------------------------------------- +INSERT INTO @Results(severity,Category,MostRecent,Issue,Details) +SELECT + '(1) Critical' + ,Category = 'Backup Gap' + ,MostRecent = MAX(b.backup_finish_date) + ,'Backups out of date for ' + d.name + N' ' AS Issue + ,'Database last had a full backup: ' + COALESCE(CAST(MAX(b.backup_finish_date) AS VARCHAR(25)),'never') AS Details +FROM master.sys.databases d +LEFT OUTER JOIN msdb.dbo.backupset b ON d.name COLLATE SQL_Latin1_General_CP1_CI_AS = b.database_name COLLATE SQL_Latin1_General_CP1_CI_AS + AND b.type = 'D' + AND b.server_name = SERVERPROPERTY('ServerName') +WHERE d.database_id <> 2 +AND d.state NOT IN(1, 6, 10) +AND d.is_in_standby = 0 +AND d.source_database_id IS NULL +GROUP BY d.name +HAVING MAX(b.backup_finish_date) <= DATEADD(dd, -7, sysdatetime()) OR MAX(b.backup_finish_date) IS NULL; + +INSERT INTO @Results(severity,Category,Issue,Details) +SELECT DISTINCT + '(1) Critical' + ,Category = 'Backup Gap' + ,[Issue] = 'Database '+ d.name + N' is in FULL Recovery mode w/o a recent Log Backup' + ,Details = ( 'The log file has not been backed up for at least two days, is ' + CAST(CAST((SELECT ((SUM([mf].[size]) * 8.) / 1024.) FROM sys.[master_files] AS [mf] WHERE [mf].[database_id] = d.[database_id] AND [mf].[type_desc] = 'LOG') AS DECIMAL(18,2)) AS VARCHAR) + 'MB and growing unchecked' ) +FROM master.sys.databases d +WHERE d.recovery_model IN ( 1, 2 ) + AND d.database_id NOT IN ( 2, 3 ) + AND d.source_database_id IS NULL + AND d.state NOT IN(1, 6, 10) /* Not currently offline or restoring, like log shipping databases */ + AND d.is_in_standby = 0 /* Not a log shipping target database */ + AND d.source_database_id IS NULL /* Excludes database snapshots */ + AND NOT EXISTS ( SELECT * FROM msdb.dbo.backupset b + WHERE d.name COLLATE SQL_Latin1_General_CP1_CI_AS = b.database_name COLLATE SQL_Latin1_General_CP1_CI_AS + AND b.type = 'L' + AND b.backup_finish_date >= DATEADD(dd,-2, sysdatetime()) ); + +insert into @Results(severity,Category,Issue,Details) +SELECT + '(1) Critical' , + 'Database Performance' , + 'Auto Closed Enabled on a database', + ( 'Database [' + [name] + + '] has auto-close enabled. This setting can dramatically decrease performance.' ) AS Details +FROM sys.databases d +WHERE is_auto_close_on = 1 +union All + +SELECT + '(1) Critical', + 'Database Performance' , + 'Auto-Shrink Enabled on a database' , + ( 'Database [' + [name] + + '] has auto-shrink enabled. This setting can dramatically decrease performance.' ) AS Details +FROM sys.databases +WHERE is_auto_shrink_on = 1 + +if (select value from sys.configurations c where c.name='optimize for ad hoc workloads') <> 1 +BEGIN + INSERT INTO @Results(severity,Category,Issue,Details) + SELECT + '(2) High' + ,'Server Performance' + ,'Optimze for Ad Hoc Workload is not enabled' + ,'SQL Server typicall performas better when ' + CHAR(39) + 'Optimze for Ad Hoc Workloads' + CHAR(39) +' is enabled' +END + +if(SELECT COUNT(*) + FROM tempdb.sys.database_files + WHERE type_desc = 'ROWS') = 1 +BEGIN + INSERT INTO @Results(Severity,Category,Issue,Details) + SELECT + '(2) High' + ,'Server Performance' + ,'TempDB has only 1 data file' + ,'SQL Server typically performs better when the TempDB has more than one Data file, perhaps up to the same # of data files as logical processors (' + cast(cpu_count as varchar(3)) + '), up to 8.' + FROM sys.dm_os_sys_info +END + +IF ( SELECT COUNT (distinct [size]) + FROM tempdb.sys.database_files + WHERE type_desc = 'ROWS' + ) <> 1 +BEGIN + INSERT INTO @Results(severity,Category,Issue,Details) + SELECT + '(2) High' + ,'Server Performance' + ,'TempDB File Size' + ,'TempDB data files are not configured with the same size.' +END +--------------- MAX Memory Setting ------------------ +DECLARE @MaxMemorySetting bigint +DECLARE @PhysicalMemory bigint +SELECT @PhysicalMemory = (SELECT m.total_physical_memory_kb/1024 from sys.dm_os_sys_memory m) +SELECT @MaxMemorySetting=(SELECT CAST(value_in_use as BIGINT) FROM sys.configurations WHERE name = 'max server memory (MB)') + +if @MaxMemorySetting=2147483647 +insert into @Results(severity,Category,Issue,Details) + select + '(2) High' + ,'Server Performance' + ,'MAX Memory Setting is uncapped (default) and should be changed' + ,'Based on available physical memory of ' + cast(@PhysicalMemory as varchar(20)) + ' MB' + + ' this server should have a maximum setting of ' + cast(cast(@PhysicalMemory*.90 as decimal(6,0)) as varchar(10)) + ' MB' +-------------------- SQL Server Error Log --------------------------------------------- +DECLARE @LogError TABLE +(LogDate datetime2(0),ProcessInfo varchar(50),Details varchar(max), severity varchar(1000) null, Category varchar(1000) null) +INSERT INTO @LogError (LogDate, ProcessInfo, Details) +exec sp_readerrorlog 0,1,'Severity' + +INSERT INTO @LogError (LogDate, ProcessInfo, Details) +exec sp_readerrorlog 0,1,'Error' + +DELETE A +FROM @LogError A +where a.Details LIKE '%CHECKDB%' + +DELETE A +FROM @LogError A +where a.Details like '%registry%' + +DELETE A +FROM @LogError A +where a.Details LIKE '%Logging SQL Server messages in file%' + +/* +select * from sys.messages m +inner join sys.syslanguages l on l.msglangid= m.language_id +and l.langid = @@LANGID +WHERE message_id = 18456 +*/ + +UPDATE @LogError +SET Severity = CASE WHEN (ProcessInfo like '%Backup%' + or Details like '%Backup%' + or Details like '%18210%' + or Details like '%18204%' + or Details like '%3041%' ) + and LogDate >= dateadd(day, -7, getdate()) + THEN '(2) High' + WHEN (ProcessInfo like '%Backup%' + or Details like '%Backup%' + or Details like '%18210%' + or Details like '%18204%' + or Details like '%3041%' ) + and LogDate < dateadd(day, -7, getdate()) + THEN '(3) Medium' + WHEN ProcessInfo like '%Logon%' + or Details like '%Severity: 20%' + THEN '(4) Low' + WHEN Details like '%Severity: 16%' + THEN '(3) Medium' + ELSE '(2) High' + END +, Category = CASE WHEN (Details like '%Backup%' + or Details like '%18210%' + or Details like '%18204%' + or Details like '%3041%') + and LogDate >= dateadd(day, -7, getdate()) + THEN 'Recent Backup Failure' + WHEN + (Details like '%Backup%' + or Details like '%18210%' + or Details like '%18204%' + or Details like '%3041%') + and LogDate < dateadd(day, -7, getdate()) + THEN 'Past Backup Failure' + WHEN Details like '%Logon%' or ProcessInfo = 'Logon' + THEN 'Logon Failure' + ELSE 'SQL Error Log' + END +, ProcessInfo = CASE WHEN ProcessInfo like 'spid%' THEN '' ELSE ProcessInfo END --filter out spids which will create dup entries +, Details = Left(Details, CASE WHEN (CHARINDEX(':\', Details)) = 0 THEN 200 ELSE (CHARINDEX(':\', Details)) END) + +INSERT INTO @Results(severity,Category,MostRecent,Issue,Details) +select + Severity = Severity +, Category = Category +, MostRecent = convert(varchar(30), MAX(LogDate)) +, Issue = 'Errors in the SQL Server Log' +, Details = cast(count(Details) as varchar(10)) + ' errors of ' + ProcessInfo + Details + '... ' +from @LogError r +GROUP BY Severity, Category, ProcessInfo, Details + +-------------------- Page Life Expectancy ----------------------------------------- +DECLARE @PLE int +SELECT @PLE = ( +SELECT + cntr_value AS [Page Life Expectancy] +FROM sys.dm_os_performance_counters WITH (NOLOCK) +WHERE [object_name] LIKE N'%Buffer Node%' -- Handles named instances +AND counter_name = N'Page life expectancy') + +if @PLE < 300 +BEGIN + INSERT INTO @Results(severity,Category,MostRecent,Issue,Details) + SELECT + '(3) Medium' + ,'Server Performance' + , SYSDATETIME() + ,'Page Life Expectancy (PLE)' + ,'The current PLE is ' + cast(@PLE as varchar(10)) + ' which is below the "standard" of 300. This could be an indication of low memory' +END +---------------------------------------------------------------------- +if exists (select * from msdb.dbo.suspect_pages ) + +begin + INSERT INTO @Results(severity,Category,Issue,Details) + select + '(1) Critical' + ,'Database Performance' + ,'There appears to be a corrupted page in ' + db_name(sp.database_id) + ,'Please execute DBCC CHECKDB to determine the problem and possible result' + FROM msdb.dbo.suspect_pages sp + INNER JOIN master.sys.databases db ON sp.database_id = db.database_id + WHERE sp.last_update_date >= DATEADD(dd, -30, sysdatetime()) +end + + + +------- +if ( +SELECT + COUNT(*) +FROM msdb.dbo.sysalerts +WHERE severity >= 19 and severity <= 25) < 6 --OK if 20 is not in place +BEGIN + INSERT INTO @Results(Severity,Category,Issue,Details) + SELECT + '(3) Medium' + ,'Monitoring' + ,'Some SQL Alerts are missing' + ,'Please review the SQL Agent Alerts. Some high severity errors are not sending alerts.' +END + + + + +if (select count(*) from @Results) > 0 + BEGIN + select * FROM @Results r ORDER BY severity asc, MostRecent asc, Issue asc, Details asc + END +ELSE + BEGIN + SELECT 'There are no critical findings with this SQL Server' as [Congratulations!] + END +----------------------------------------------- diff --git a/Lock Pages in Memory.sql b/Lock Pages in Memory.sql new file mode 100644 index 0000000..3cb4a88 --- /dev/null +++ b/Lock Pages in Memory.sql @@ -0,0 +1,8 @@ + +--SQL 2016 SP1 or above only!!! + +select sql_memory_model_Desc +--Conventional = Lock Pages in Memory privilege is not granted +--LOCK_PAGES = Lock Pages in Memory privilege is granted +--LARGE_PAGES = Lock Pages in Memory privilege is granted in Enterprise mode with Trace Flag 834 ON +from sys.dm_os_sys_info diff --git a/Rename_SQL_Instance.sql b/Rename_SQL_Instance.sql new file mode 100644 index 0000000..117b004 --- /dev/null +++ b/Rename_SQL_Instance.sql @@ -0,0 +1,25 @@ +/* + Rename SQL Server Instance + +When the physical server is renamed, this script must be executed to rename the SQL Server Instance. + +Change the Variables to the correct information, and then execute the script. +The results will show the old setting and the changed setting so you can verify the + +*/ + +SELECT SERVERPROPERTY('MachineName') [Machine Name],@@SERVERNAME [SQL Instance] + +----------------------------------------------------------------------------- +--- PLEASE CHANGE THE FOLLOWING VARIABLES BEFORE EXECUTION +DECLARE @Current_SQLServer_Name sysname = '' --- Old Physical name or Current SQL Instance Name +DECLARE @New_SQLServer_Name sysname = '' -- New Physical name or New SQL Instance Name + + +----------------------------------------------------------------------------- +--EXEC sp_dropserver @server=@Current_SQLServer_Name +--EXEC sp_addserver @server=@New_SQLServer_Name, @Local='local' +--GO + + +SELECT SERVERPROPERTY('MachineName') [Machine Name],@@SERVERNAME [SQL Instance] diff --git a/ReplaceFloatWithDecimal.sql b/ReplaceFloatWithDecimal.sql new file mode 100644 index 0000000..5c2b6f9 --- /dev/null +++ b/ReplaceFloatWithDecimal.sql @@ -0,0 +1,316 @@ + +--REVIEW TODO items + +IF NOT EXISTS(select 1 from sys.objects where name = 'Drop_and_Store_Table_Objects') +BEGIN + THROW 51000, 'Drop_and_Store_Table_Objects stored procedure does not exist.', 1; + SET NOEXEC ON +END + + +BEGIN TRY +DROP TABLE #Triggers_to_Drop_and_Recreate; +END TRY +BEGIN CATCH +END CATCH + +CREATE TABLE #Triggers_to_Drop_and_Recreate +( id int not null identity (1,1) primary key +, object_name sysname null +, object_id int not null +, drop_tsql nvarchar(max) null +, create_tsql nvarchar(max) null +) + + +BEGIN TRY +DROP TABLE ##Drop_and_Recreate_Objects; +END TRY +BEGIN CATCH +END CATCH + +CREATE TABLE ##Drop_and_Recreate_Objects ( table_object_id int not null PRIMARY KEY ) + + +--Example of how to add a table to get its DFs, TRs and CKs recreated. +--TODO: Uncomment out the tables that need to be converted. + +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[abr_bank_account]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[abr_bank_rec]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[abr_bank_rec_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[abr_bank_rec_sequence]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[abr_check_reg_adj]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[apbalance]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[apinvoicehdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[apinvoicetrans]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[appayments]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[ardeposits]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[arinvoicehdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[arinvoicetrans]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[asset_cost_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[assets]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[assets_improvements]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[bidhdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[biditem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[biditem_custom_fields]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[categories]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[clippership_return_tq]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[contacts]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[contacts_xref]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[customer_office_xref]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[customers]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltick_void]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickhdr_addl_fields]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_addl_fields]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_addl_fields_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_custom_fields]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_dump_site]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_meters]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_ret_auth]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_route_service]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_route_service_seq_num]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_ship_from]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickitem_ship_instruct]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[delticksubhdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[delticksubhdr2]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[estimate_serials]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[estimatehdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[estimatelines]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[estimatelines_return_info]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[eventhdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[eventitem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[exchangecounts]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[ext_descr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[ext_notes]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[ext_specs]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fastdt]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[fmv]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[grid_office_xref]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[gridhdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[hmced_contract_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[interoffice]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[inv_add_log]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[inven_custom_fields]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[inven_notes]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[inven_remarks]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[inventory]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[invoice_export_history]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[inventory_last_change]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[invoicehdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[invoiceitem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[invoiceitem_meters]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[itype]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[job]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[jobtypelist]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[kititem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[lock]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[misc_chg]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[multiprice]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[poalloc]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[poallocrecv]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[podist]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[podist_clearing]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[podist_je]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[podist_receipts_details]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[podisthdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[podisthdr_clearing]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[pohdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[poitem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[prevent]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[regdata]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[register]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[reorder]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[repairhistory]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[repairpreferences]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[sales_person]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[subcategories]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[taxcode]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_addresses]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_afe_information]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_customer_charge_checklist]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_del_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_deltick_comments]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_disposal_items]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_disposal_locations]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_dump_activity_codes]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_dump_service_pricing]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_dump_work_order]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_dump_work_order_lines]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_field_service_entry]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_field_service_maint_entry]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_fifo_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_fifo_hdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_fifo_valuation]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_interim_meter]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_inv_gljrnl]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_inv_loc_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_inv_loc_summary]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_inv_locations]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_invc_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_inventory_geolocation]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_job_activity]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_job_activity_consumables]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_job_activity_equipment]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_job_activity_labor]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_log_deltickitem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_man_burden]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_mileage_lookup]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_multi_level_approval_log]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_order_entry_custom_fields]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_order_entry_hdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_order_entry_item]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_order_entry_item_prefix]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_order_entry_load]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_order_entry_load_order]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_order_entry_truck_helper]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_order_logbook_item]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_pl_relations]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_pl_setup]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_prelien_data]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_prelien_requests]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_price_lookup]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_print_config_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_print_config_hdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_prorate]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_qlcmm_action_log]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_qlcmm_alerts]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_qlcmm_dticket_geofence_xref]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_qlcmm_equipment_location]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_qlcmm_geofences]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_qlcmm_terminals]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_ra_add_item]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_ra_hdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_ra_item]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_readings]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_rental_request_items]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_rental_requests]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_reorder_rules]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_reorder_vendors]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_repair_hdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_repair_items]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_routesmith_log]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_rwo_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_start_stop]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_tax_brkdwn_headers]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_tax_brkdwn_items]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_tax_calc_headers]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_tax_calc_items]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_ticket_totals]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_us_1099item]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_vendor_bid_branch_items]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_vendor_bid_branch_items_archive]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_work_order_types]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbl_zones]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbladdon_links]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblapproved_dist_hdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblapproved_dist_line]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblapproved_gljrnl]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblassoc_damages]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblassociated_tires]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblcommission_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblcomponent_list]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblcontact_notes]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblcost_codes_ticket]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblcreditdetails]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblcurrency_rate]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbldoc_links]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbldown_days]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbldps_custruleitem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbldps_invruleshdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbldps_invrulesitem]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblequip_request_hdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblequip_request_line]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblfleet_shipping_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblfleet_shipping_instruct]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblgl_balance_sheet_layout]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblinspection_header]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblinspection_tires]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblinspection_wear_items]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblinsurance]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblinv_wash_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblinv_wash_info]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblinvcline_billinfo]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblinvctaxadjust]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbllanded_cost_rules]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbllanded_cost_rules_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbllog_event]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblmarket_type_list]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblmas_invoices]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblmas_recv_ctr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblmeter_readings]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblowner_share]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblp21_location_translation]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblparts_hours]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblpo_add_costs]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblpo_add_costs_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblpo_currency_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblprevent_maint_parts]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblprevent_maint_request]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblpros_prospectfor]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblpros_reason_codes]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblpros_status]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblrating_group]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblrating_group_member]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblrating_keys]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblrating_values]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblre_rent_hdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblre_rent_line]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblre_rent_line_detail]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblservice_chklist]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblservice_labor]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblservice_requests]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblservice_techs]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblservice_timetasks]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblsilent_return_set_items]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbltax_authority]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbltoolcheck]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbltrans_po_link]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbluse_snapshot]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tbluse_snapshot_item]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblwarranty_info]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[tblwarranty_labels]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[terms]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[timesheet]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[totalonorder]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[transnum]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[unithistory]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[uomconversions]')) +insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[usage]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[usagehours]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[deltickhdr]')) +--insert into ##Drop_and_Recreate_Objects (table_object_id) select (OBJECT_ID('[dbo].[invoicehdr]')) +--GO + +exec dbo.Drop_and_Store_Table_Objects @testingMode = 0, @AuditingMode = 0 +--Here we need to manually fix any values that will created duplicate PK's when we convert from Float to Decimal. +--exec dbo.Fix_Duplicate_PK_Floats @testingMode = 0, @AuditingMode = 1 --Still a Work in Progress +exec dbo.Alter_Floats_to_Decimal @testingMode = 0, @AuditingMode = 0 +exec dbo.Recreate_Stored_Table_Objects @testingMode = 0, @AuditingMode = 0 + + + +PRINT N'Refreshing views.'; + +DECLARE @DropCreateTSQL nvarchar(4000) +DECLARE DropCreateDefaults CURSOR FAST_FORWARD + FOR + select DropCreateTSQL = 'exec sp_refreshview N''' +s.name + '.' + o.name + '''' + from sys.views o + inner join sys.schemas s on o.schema_id = s.schema_id + inner join sys.sql_modules m on m.object_id = o.object_id + where o.type_desc = 'view' + and m.definition not like '%schemabinding%' +OPEN DropCreateDefaults +FETCH NEXT FROM DropCreateDefaults INTO @DropCreateTSQL +WHILE @@FETCH_STATUS = 0 +BEGIN + print @DropCreateTSQL; + exec sp_executesql @DropCreateTSQL; + FETCH NEXT FROM DropCreateDefaults INTO @DropCreateTSQL +END +CLOSE DropCreateDefaults; +DEALLOCATE DropCreateDefaults; + +PRINT N'Update complete.'; + diff --git a/SQL Mini Dumps.sql b/SQL Mini Dumps.sql new file mode 100644 index 0000000..02fc47e --- /dev/null +++ b/SQL Mini Dumps.sql @@ -0,0 +1,8 @@ +------------------------------------------------------------------------------------------------------- +---- SQL Server Memory Dumps +---- Are their any recent SQL mini dumps +------------------------------------------------------------------------------------------------------- + +SELECT [filename], creation_time, size_in_bytes/1048576.0 AS [Size (MB)] +FROM sys.dm_server_memory_dumps WITH (NOLOCK) +ORDER BY creation_time DESC OPTION (RECOMPILE); \ No newline at end of file diff --git a/SSRS Subscription failures 2.sql b/SSRS Subscription failures 2.sql new file mode 100644 index 0000000..f4dde02 --- /dev/null +++ b/SSRS Subscription failures 2.sql @@ -0,0 +1,53 @@ + +IF EXISTS ( +select + InstanceName +, ReportPath +, ReportName = c.Name +, RequestType +, TimeStart +, TimeEnd +, Status +, LastStatus +, SubscriptionDescription = s.Description +--, * + from ReportServer_GP2k8r2.dbo.executionlog2 el + inner join ReportServer_GP2k8r2.dbo.Catalog c + on el.ReportPath = c.Path + inner join ReportServer_GP2k8r2.dbo.ReportSchedule a + on c.ItemID = a.ReportID + inner join ReportServer_GP2k8r2.dbo.subscriptions s + on s.Report_OID = c.ItemID + and a.SubscriptionID = s.SubscriptionID +where requesttype = 'subscription' +and status <> 'rsSuccess' +and (LastRunTime > dateadd(d, -1, getdate()) and TimeEnd > dateadd(d, -1, getdate())) + +) +BEGIN + +declare @tsql nvarchar(4000) = ' +select + '''' +, '''' +, '''' +, '''' +, '''' +, SubscriptionDescription = ''
'' + InstanceName + '''' + ReportPath+ '''' + convert(varchar(100), TimeStart) + '''' + Status+ '''' + LastStatus + '''' + s.Description + ''
'' +--, * + from ReportServer_GP2k8r2.dbo.executionlog2 el + inner join ReportServer_GP2k8r2.dbo.Catalog c + on el.ReportPath = c.Path + inner join ReportServer_GP2k8r2.dbo.ReportSchedule a + on c.ItemID = a.ReportID + inner join ReportServer_GP2k8r2.dbo.subscriptions s + on s.Report_OID = c.ItemID + and a.SubscriptionID = s.SubscriptionID +where requesttype = ''subscription'' +and status <> ''rsSuccess'' +and (LastRunTime > dateadd(d, -1, getdate()) and TimeEnd > dateadd(d, -1, getdate())) +order by el.timestart desc' + +exec msdb.dbo.sp_send_dbmail @profile_name = 'sparkhound', @recipients = 'dbadministrators@sparkhound.com', @from_address = 'ReportServer_GP2k8R2@sparkhound.com', @reply_to = 'dbadministrators@sparkhound.com', @subject = 'Failed SSRS subscriptions Report', @query = @tsql, @query_result_header = 0, @body_format ='html', @execute_query_database = 'msdb' + +END \ No newline at end of file diff --git a/SSRS Subscription failures.sql b/SSRS Subscription failures.sql new file mode 100644 index 0000000..9a41494 --- /dev/null +++ b/SSRS Subscription failures.sql @@ -0,0 +1,19 @@ +use reportserver +go +SELECT Catalog.Name AS ReportName +,'http://neillsqlssrs/Reports/Pages/Report.aspx?ItemPath=' + Catalog.Path + '&SelectedTabId=PropertiesTab&SelectedSubTabId=SubscriptionsTab' AS ReportSubscriptionMgrUrl +,Users.UserName AS SubscriptionOwner +,Subscriptions.Description AS SubscriptionDescription +,Subscriptions.LastStatus +,Subscriptions.LastRunTime +FROM [dbo].[ReportSchedule] +INNER JOIN [dbo].[Schedule] +ON ReportSchedule.ScheduleID = Schedule.ScheduleID +INNER JOIN [dbo].[Catalog] +ON ReportSchedule.ReportID = Catalog.ItemID +INNER JOIN [dbo].[Subscriptions] +ON ReportSchedule.SubscriptionID = Subscriptions.SubscriptionID +INNER JOIN [dbo].[Users] +ON Subscriptions.OwnerID = Users.UserID +WHERE (Subscriptions.DataSettings IS NULL AND Subscriptions.LastStatus LIKE 'Failure%') -- handle standard subscription errors +OR (Subscriptions.DataSettings IS NOT NULL AND RIGHT(Subscriptions.LastStatus, 11) <> '; 0 errors.') \ No newline at end of file diff --git a/SSRS Subscription inventory.sql b/SSRS Subscription inventory.sql new file mode 100644 index 0000000..7dc6911 --- /dev/null +++ b/SSRS Subscription inventory.sql @@ -0,0 +1,57 @@ +use reportserver +go +SELECT Catalog.Name AS ReportName +,'http://neillsqlssrs/Reports/Pages/Report.aspx?ItemPath=' + Catalog.Path + '&SelectedTabId=PropertiesTab&SelectedSubTabId=SubscriptionsTab' AS ReportSubscriptionMgrUrl +,Subscriptions.Description AS SubscriptionDescription +,Subscriptions.LastStatus +,Subscriptions.LastRunTime +,'Next Run Date' = CASE next_run_date +WHEN 0 THEN null +ELSE +substring(convert(varchar(15),next_run_date),1,4) + '/' + +substring(convert(varchar(15),next_run_date),5,2) + '/' + +substring(convert(varchar(15),next_run_date),7,2) +END +, 'Next Run Time' = isnull(CASE len(next_run_time) +WHEN 3 THEN cast('00:0' ++ Left(right(next_run_time,3),1) ++':' + right(next_run_time,2) as char (8)) +WHEN 4 THEN cast('00:' ++ Left(right(next_run_time,4),2) ++':' + right(next_run_time,2) as char (8)) +WHEN 5 THEN cast('0' + Left(right(next_run_time,5),1) ++':' + Left(right(next_run_time,4),2) ++':' + right(next_run_time,2) as char (8)) +WHEN 6 THEN cast(Left(right(next_run_time,6),2) ++':' + Left(right(next_run_time,4),2) ++':' + right(next_run_time,2) as char (8)) +END,'NA') +,Subscriptions.Parameters +,[ExtensionSettings] +,ISNULL( +Convert(XML,[ExtensionSettings]).value('(//ParameterValue/Value[../Name="TO"])[1]','nvarchar(50)') +,Convert(XML,[ExtensionSettings]).value('(//ParameterValue/Value[../Name="PATH"])[1]','nvarchar(150)') +) as [To] +, +ISNULL( + Convert(XML,[ExtensionSettings]).value('(//ParameterValue/Value[../Name="RenderFormat"])[1]','nvarchar(50)') +, Convert(XML,[ExtensionSettings]).value('(//ParameterValue/Value[../Name="RENDER_FORMAT"])[1]','nvarchar(50)') +) as [Render Format] +,Convert(XML,[ExtensionSettings]).value('(//ParameterValue/Value[../Name="Subject"])[1]','nvarchar(150)') as [Subject] + + + +,* +FROM [dbo].[ReportSchedule] +INNER JOIN [dbo].[Schedule] +ON ReportSchedule.ScheduleID = Schedule.ScheduleID +INNER JOIN [dbo].[Catalog] +ON ReportSchedule.ReportID = Catalog.ItemID +INNER JOIN [dbo].[Subscriptions] +ON ReportSchedule.SubscriptionID = Subscriptions.SubscriptionID +INNER JOIN [dbo].[Users] +ON Subscriptions.OwnerID = Users.UserID +INNER JOIN msdb.dbo.sysjobs J ON Convert(nvarchar(128),[ReportSchedule].ScheduleID) = J.name +INNER JOIN msdb.dbo.sysjobschedules JS ON J.job_id = JS.job_id + + diff --git a/SSRS Subscription jobs.sql b/SSRS Subscription jobs.sql new file mode 100644 index 0000000..7f4ce3f --- /dev/null +++ b/SSRS Subscription jobs.sql @@ -0,0 +1,5 @@ +select 'exec sp_start_job @job_name = ''' + cast(j.name as varchar(40)) + '''' , s.Description, s.LastRunTime, s.LastStatus, s.EventType, j.description +from msdb.dbo.sysjobs j +inner join msdb.dbo.sysjobsteps js on js.job_id = j.job_id +inner join [ReportServer].[dbo].[Subscriptions] s on js.command like '%' + cast(s.subscriptionid as varchar(40)) + '%' +where j.description = 'This job is owned by a report server process. Modifying this job could result in database incompatibilities. Use Report Manager or Management Studio to update this job.' diff --git a/Security Script - database.sql b/Security Script - database.sql new file mode 100644 index 0000000..b83b041 --- /dev/null +++ b/Security Script - database.sql @@ -0,0 +1,111 @@ +--Script out Database-level permissions +--See also Security Script 2012.sql + +--Database role membership + +--Single Database +--Run on each database for database-level security. +SELECT DB_NAME(); +SELECT DISTINCT QUOTENAME(r.name) as database_role_name, r.type_desc, QUOTENAME(d.name) as principal_name, d.type_desc +, Add_TSQL = 'EXEC sp_addrolemember @membername = N''' + d.name COLLATE DATABASE_DEFAULT + ''', @rolename = N''' + r.name + '''' +, Drop_TSQL = 'EXEC sp_droprolemember @membername = N''' + d.name COLLATE DATABASE_DEFAULT + ''', @rolename = N''' + r.name + '''' +FROM sys.database_role_members rm +inner join sys.database_principals r on rm.role_principal_id = r.principal_id +inner join sys.database_principals d on rm.member_principal_id = d.principal_id +/* +--Multi Database +declare @tsql nvarchar(4000) = 'use [?]; +SELECT DB_NAME(); +SELECT DISTINCT QUOTENAME(r.name) as database_role_name, r.type_desc, QUOTENAME(d.name) as principal_name, d.type_desc +, Add_TSQL = ''EXEC sp_addrolemember @membername = N'''''' + d.name COLLATE DATABASE_DEFAULT + '''''', @rolename = N'''''' + r.name + '''''''' +, Drop_TSQL = ''EXEC sp_droprolemember @membername = N'''''' + d.name COLLATE DATABASE_DEFAULT + '''''', @rolename = N'''''' + r.name + '''''''' +FROM sys.database_role_members rm +inner join sys.database_principals r on rm.role_principal_id = r.principal_id +inner join sys.database_principals d on rm.member_principal_id = d.principal_id +'; +exec sp_msforeachdb @tsql +go +*/ + + +--Database Permissions +--Run on each database for database-level security. +--Too large to wrap in sp_msforeachdb +SELECT DB_NAME(); +SELECT Permission_State_Desc = perm.state_desc + , Permission_Name = perm.permission_name + , Permission_Object_Name = ISNULL(QUOTENAME(s.name ) + '.','') + QUOTENAME(obj.name COLLATE database_default) + CASE WHEN cl.name COLLATE database_default is null THEN '' ELSE '.' + QUOTENAME(cl.name COLLATE database_default) END + , Object_Type_Desc = obj.type_desc + , Principal_Name = QUOTENAME(u.name COLLATE database_default) + , User_Type = u.type_desc + , Create_TSQL = perm.state_desc + N' ' + perm.permission_name + + case when obj.name COLLATE database_default is not null THEN + N' ON ' + sc.class_desc + '::' + ISNULL(QUOTENAME(s.name COLLATE database_default) + '.','') + QUOTENAME(obj.name COLLATE database_default) ELSE '' END + + CASE WHEN cl.column_id IS NULL THEN ' ' ELSE '(' + QUOTENAME(cl.name COLLATE database_default) + ')' END + + N' TO ' + QUOTENAME(u.name COLLATE database_default) + , Revoke_TSQL = N'REVOKE ' + perm.permission_name + + case when obj.name COLLATE database_default is not null THEN + N' ON ' + sc.class_desc + '::' + ISNULL(QUOTENAME(s.name COLLATE database_default) + '.','') + QUOTENAME(obj.name COLLATE database_default) ELSE '' END + + CASE WHEN cl.column_id IS NULL THEN ' ' ELSE '(' + QUOTENAME(cl.name COLLATE database_default) + ')' END + + N' TO ' + QUOTENAME(u.name COLLATE database_default) + , * +FROM sys.database_permissions AS perm +INNER JOIN sys.database_principals AS u ON perm.grantee_principal_id = u.principal_id + +LEFT OUTER JOIN (--https://msdn.microsoft.com/en-us/library/ms188367.aspx + select name, object_id, schema_id, is_ms_shipped, class_desc='OBJECT', type_desc from sys.objects + union all + select name, 0, null, null, 'DATABASE', 'DATABASE' from sys.databases + union all + select name, schema_id, null, null, 'SCHEMA', 'SCHEMA' from sys.schemas + union all + select name, principal_id, null, null, 'USER', type_desc from sys.database_principals where type_desc in ('WINDOWS_USER','SQL_USER','ASYMMETRIC_KEY_MAPPED_USER','CERTIFICATE_MAPPED_USER', 'WINDOWS_GROUP','EXTERNAL_GROUPS') + union all + select name, principal_id, null, null, 'USER', type_desc from sys.database_principals where type_desc in ('WINDOWS_USER','SQL_USER','ASYMMETRIC_KEY_MAPPED_USER','CERTIFICATE_MAPPED_USER', 'WINDOWS_GROUP','EXTERNAL_GROUPS') + union all + select name, principal_id, null, null, 'APPLICATION ROLE', type_desc from sys.database_principals where type_desc in ('APPLICATION_ROLE') + union all + select name, principal_id, null, null, 'ROLE', type_desc from sys.database_principals where type_desc in ('DATABASE_ROLE') + union all + select name, assembly_id, null, null, 'ASSEMBLY', 'ASSEMBLY' from sys.assemblies + union all + select name, user_type_id, null, null, 'TYPE', 'USER TYPE' from sys.types + union all + select name, xml_collection_id, null, null, 'XML SCHEMA COLLECTION', 'XML SCHEMA COLLECTION' from sys.xml_schema_collections + union all + select name COLLATE database_default, message_type_id, null, null, 'MESSAGE TYPE', 'MESSAGE TYPE' from sys.service_message_types + union all + select name COLLATE database_default, service_contract_id, null, null, 'CONTRACT', 'CONTRACT' from sys.service_contracts + union all + select name COLLATE database_default, service_id, null, null, 'SERVICE', 'SERVICE' from sys.services + union all + select name COLLATE database_default, remote_service_binding_id, null, null, 'REMOTE SERVICE BINDING', 'REMOTE SERVICE BINDING' from sys.remote_service_bindings + union all + select name COLLATE database_default, route_id, null, null, 'ROUTE', 'ROUTE' from sys.routes + union all + select name COLLATE database_default, fulltext_catalog_id, null, null, 'FULLTEXT CATALOG', 'FULLTEXT CATALOG' from sys.fulltext_catalogs + union all + select name, symmetric_key_id, null, null, 'SYMMETRIC KEY', 'SYMMETRIC KEY' from sys.symmetric_keys + union all + select name, certificate_id, null, null, 'CERTIFICATE', 'CERTIFICATE' from sys.certificates + union all + select name, asymmetric_key_id, null, null, 'ASYMMETRIC KEY', 'ASYMMETRIC KEY' from sys.asymmetric_keys + ) obj +ON perm.major_id = obj.[object_id] +INNER JOIN sys.securable_classes sc on sc.class = perm.class +and sc.class_desc = obj.class_desc +LEFT OUTER JOIN sys.schemas s ON s.schema_id = obj.schema_id +LEFT OUTER JOIN sys.columns cl ON cl.column_id = perm.minor_id AND cl.[object_id] = perm.major_id +where 1=1 +and perm.major_id > 0 +--Ignore internal principals +and u.name COLLATE database_default not in ('dbo','guest','INFORMATION_SCHEMA','sys','MS_DataCollectorInternalUser','PolicyAdministratorRole','ServerGroupReaderRole' +,'ServerGroupAdministratorRole','TargetServersRole','SQLAgentUserRole','UtilityCMRReader','SQLAgentOperatorRole','dc_operator','dc_proxy','dc_admin','db_ssisadmin','db_ssisltduser','db_ssisoperator' +,'UtilityIMRWriter','UtilityIMRReader','RSExecRole','DatabaseMailUserRole') +--Ignore ## principals +and u.name COLLATE database_default not like '##%##' +--Ignore built-in svc accounts (not recommended anyway!) +and u.name COLLATE database_default not like 'NT SERVICE%' +--Ignore MS shipped internal objects +and (obj.is_ms_shipped = 0 or obj.is_ms_shipped is null) +--Ignore system sprocs (be aware of your naming conventions!) +--and (obj.name not like 'sp_%' or obj.name is null) +order by Object_Type_Desc, Principal_Name \ No newline at end of file diff --git a/Security Script 2012.sql b/Security Script 2012.sql new file mode 100644 index 0000000..2fc541a --- /dev/null +++ b/Security Script 2012.sql @@ -0,0 +1,224 @@ +--Script out Server-level permissions +--See also Security Script - database.sql +--This script works SQL 2012+ (thus the title) + +SELECT @@SERVERNAME + +--script out SQL logins to create/transfer +--http://support.microsoft.com/kb/918992 +-- or see bottom +EXEC sp_help_revlogin +GO + +--or, use the next two. + +--create windows logins +select + CreateTSQL_Source = 'CREATE LOGIN ['+ name +'] FROM WINDOWS WITH DEFAULT_DATABASE=['+default_database_name+'], DEFAULT_LANGUAGE=['+default_language_name+']' + CHAR(10) + CHAR(13) + 'GO' +, DropTSQL_Source = 'DROP LOGIN ['+ name +']' + +from sys.server_principals +where type in ('U','G') +and name not like 'NT %' +and is_disabled = 0 +order by name, type_desc + +USE [master] +GO + +--compare sql logins, use to drop only. Can only get Password hash from sp_help_revlogin. +select + sid, QUOTENAME(name) as sql_login_name +, CreateTSQL_Source = 'CREATE LOGIN ['+ name +'] WITH DEFAULT_DATABASE=['+default_database_name+'], DEFAULT_LANGUAGE=['+default_language_name+'] + , CHECK_EXPIRATION=' + CASE is_expiration_checked WHEN 0 THEN 'OFF' ELSE 'ON' END + ' + , CHECK_POLICY= ' + CASE is_policy_checked WHEN 0 THEN 'OFF' ELSE 'ON' END + ';' +, DropTSQL_Source = 'DROP LOGIN ['+ name +']' +, 'Need sp_help_revlogin for PW' +from sys.sql_logins +where type = ('S') +and name not in ('dbo', 'sa', 'public') +and is_disabled = 0 +order by sid, sql_login_name +GO + +--Server level roles +SELECT DISTINCT + Server_Role_Name = QUOTENAME(r.name) +, Role_Type = r.type_desc +, Principal_Name = QUOTENAME(m.name) +, Principal_Type = m.type_desc +, SQL2008R2_below_CreateTSQL = 'exec sp_addsrvrolemember @loginame= '''+m.name+''', @rolename = '''+r.name+'''' +, SQL2012_above_CreateTSQL = 'ALTER SERVER ROLE [' + r.name + '] ADD MEMBER [' + m.name + ']' +, DropTSQL_Source = 'ALTER SERVER ROLE [' + r.name + '] DROP MEMBER [' + m.name + ']' +FROM sys.server_role_members AS rm +inner join sys.server_principals r on rm.role_principal_id = r.principal_id +inner join sys.server_principals m on rm.member_principal_id = m.principal_id +where r.is_disabled = 0 and m.is_disabled = 0 +and m.name not in ('dbo', 'sa', 'public') +and m.name not like 'NT %' +order by QUOTENAME(r.name) + + +--Server Level Security +SELECT + Permission_State = rm.state_desc +, Permission = rm.permission_name +, Principal_name = QUOTENAME(u.name) +, Principal_type = u.type_desc +, CreateTSQL_Source = rm.state_desc + N' ' + rm.permission_name + + CASE WHEN e.name is not null THEN 'ON ENDPOINT::[' + e.name + '] ' ELSE '' END + + N' TO ' + cast(QUOTENAME(u.name COLLATE DATABASE_DEFAULT) as nvarchar(256)) + ';' +, DropTSQL_Source = N'REVOKE ' + rm.permission_name + + CASE WHEN e.name is not null THEN 'ON ENDPOINT::[' + e.name + '] ' ELSE '' END + + N' TO ' + cast(QUOTENAME(u.name COLLATE DATABASE_DEFAULT) as nvarchar(256)) + ';', * +FROM sys.server_permissions rm +inner join sys.server_principals u +on rm.grantee_principal_id = u.principal_id +left outer join sys.endpoints e +on e.endpoint_id = major_id and class_desc = 'ENDPOINT' +where u.name not like '##%' +and u.name not in ('dbo', 'sa', 'public') +and u.name not like 'NT %' +order by rm.permission_name, u.name + + + +/* + +USE master +GO +IF OBJECT_ID ('sp_hexadecimal') IS NOT NULL + DROP PROCEDURE sp_hexadecimal +GO +CREATE PROCEDURE sp_hexadecimal + @binvalue varbinary(256), + @hexvalue varchar (514) OUTPUT +AS +DECLARE @charvalue varchar (514) +DECLARE @i int +DECLARE @length int +DECLARE @hexstring char(16) +SELECT @charvalue = '0x' +SELECT @i = 1 +SELECT @length = DATALENGTH (@binvalue) +SELECT @hexstring = '0123456789ABCDEF' +WHILE (@i <= @length) +BEGIN + DECLARE @tempint int + DECLARE @firstint int + DECLARE @secondint int + SELECT @tempint = CONVERT(int, SUBSTRING(@binvalue,@i,1)) + SELECT @firstint = FLOOR(@tempint/16) + SELECT @secondint = @tempint - (@firstint*16) + SELECT @charvalue = @charvalue + + SUBSTRING(@hexstring, @firstint+1, 1) + + SUBSTRING(@hexstring, @secondint+1, 1) + SELECT @i = @i + 1 +END + +SELECT @hexvalue = @charvalue +GO + +IF OBJECT_ID ('sp_help_revlogin') IS NOT NULL + DROP PROCEDURE sp_help_revlogin +GO +CREATE PROCEDURE sp_help_revlogin @login_name sysname = NULL AS +DECLARE @name sysname +DECLARE @type varchar (1) +DECLARE @hasaccess int +DECLARE @denylogin int +DECLARE @is_disabled int +DECLARE @PWD_varbinary varbinary (256) +DECLARE @PWD_string varchar (514) +DECLARE @SID_varbinary varbinary (85) +DECLARE @SID_string varchar (514) +DECLARE @tmpstr varchar (1024) +DECLARE @is_policy_checked varchar (3) +DECLARE @is_expiration_checked varchar (3) + +DECLARE @defaultdb sysname + +IF (@login_name IS NULL) + DECLARE login_curs CURSOR FOR + + SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM +sys.server_principals p LEFT JOIN sys.syslogins l + ON ( l.name = p.name ) WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name <> 'sa' +ELSE + DECLARE login_curs CURSOR FOR + + + SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin FROM +sys.server_principals p LEFT JOIN sys.syslogins l + ON ( l.name = p.name ) WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name = @login_name +OPEN login_curs + +FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin +IF (@@fetch_status = -1) +BEGIN + PRINT 'No login(s) found.' + CLOSE login_curs + DEALLOCATE login_curs + RETURN -1 +END +SET @tmpstr = '/* sp_help_revlogin script ' +PRINT @tmpstr +SET @tmpstr = '** Generated ' + CONVERT (varchar, GETDATE()) + ' on ' + @@SERVERNAME + ' */' +PRINT @tmpstr +PRINT '' +WHILE (@@fetch_status <> -1) +BEGIN + IF (@@fetch_status <> -2) + BEGIN + PRINT '' + SET @tmpstr = '-- Login: ' + @name + PRINT @tmpstr + IF (@type IN ( 'G', 'U')) + BEGIN -- NT authenticated account/group + + SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' FROM WINDOWS WITH DEFAULT_DATABASE = [' + @defaultdb + ']' + END + ELSE BEGIN -- SQL Server authentication + -- obtain password and sid + SET @PWD_varbinary = CAST( LOGINPROPERTY( @name, 'PasswordHash' ) AS varbinary (256) ) + EXEC sp_hexadecimal @PWD_varbinary, @PWD_string OUT + EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT + + -- obtain password policy state + SELECT @is_policy_checked = CASE is_policy_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSE NULL END FROM sys.sql_logins WHERE name = @name + SELECT @is_expiration_checked = CASE is_expiration_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSE NULL END FROM sys.sql_logins WHERE name = @name + + SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' WITH PASSWORD = ' + @PWD_string + ' HASHED, SID = ' + @SID_string + ', DEFAULT_DATABASE = [' + @defaultdb + ']' + + IF ( @is_policy_checked IS NOT NULL ) + BEGIN + SET @tmpstr = @tmpstr + ', CHECK_POLICY = ' + @is_policy_checked + END + IF ( @is_expiration_checked IS NOT NULL ) + BEGIN + SET @tmpstr = @tmpstr + ', CHECK_EXPIRATION = ' + @is_expiration_checked + END + END + IF (@denylogin = 1) + BEGIN -- login is denied access + SET @tmpstr = @tmpstr + '; DENY CONNECT SQL TO ' + QUOTENAME( @name ) + END + ELSE IF (@hasaccess = 0) + BEGIN -- login exists but does not have access + SET @tmpstr = @tmpstr + '; REVOKE CONNECT SQL TO ' + QUOTENAME( @name ) + END + IF (@is_disabled = 1) + BEGIN -- login is disabled + SET @tmpstr = @tmpstr + '; ALTER LOGIN ' + QUOTENAME( @name ) + ' DISABLE' + END + PRINT @tmpstr + END + + FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin + END +CLOSE login_curs +DEALLOCATE login_curs +RETURN 0 +GO + +*/ \ No newline at end of file diff --git a/Unsent_DB_Email.sql b/Unsent_DB_Email.sql new file mode 100644 index 0000000..070449a --- /dev/null +++ b/Unsent_DB_Email.sql @@ -0,0 +1,8 @@ +SELECT m.recipients, m.subject, m.body, + m.send_request_date, m.send_request_user, m.sent_status +FROM msdb.dbo.sysmail_allitems m +WHERE m.sent_status<>'sent' +--WHERE m.send_request_date > CURRENT_TIMESTAMP - 3 +--AND m.sent_status <> 'sent' +ORDER BY m.send_request_date DESC +GO \ No newline at end of file diff --git a/VLF generation example.sql b/VLF generation example.sql new file mode 100644 index 0000000..14e3eb2 Binary files /dev/null and b/VLF generation example.sql differ diff --git a/VLFs.sql b/VLFs.sql new file mode 100644 index 0000000..ee12340 --- /dev/null +++ b/VLFs.sql @@ -0,0 +1,160 @@ + + +--displays each transaction log size and space used. +--Dbcc sqlperf (logspace) --replaced, look for "space in log files.sql" + +--Shows transactions in the log +--Dbcc log ([tempdb], 0) + +--shows the number of VLF's. CreateLSN = 0 for the original created files. +--filesize /1024, *8 to get MB +--Ideally <50 VLF's per tlog +--If too many VLF's truncate the log and recreate in 8gb increments. +----http://www.sqlskills.com/blogs/kimberly/transaction-log-vlfs-too-many-or-too-few/ +----http://www.sqlskills.com/blogs/kimberly/8-steps-to-better-transaction-log-throughput/ + +--If no TSQL scripts generated in the Messages tab, then no log files of a significant size were found with >50 VLF's. + +--Shrink/regrow step only works for databases with one log file. Why do you have more than one log file anyway? + +BEGIN TRY +IF EXISTS (select * from tempdb.sys.objects where name like '#LogInfo%') +DROP TABLE #LogInfo +IF EXISTS (select * from tempdb.sys.objects where name like '#VLFCount%') +DROP TABLE #VLFCount +END TRY +BEGIN CATCH +END CATCH + +SET NOCOUNT ON + +Create Table #LogInfo( + RecoveryUnitId bigint not null--SQL 2012 and above only, comment out for <=SQL 2008 + , FileID bigint not null + , FileSize bigint not null + , StartOffset bigint not null + , FSeqNo bigint not null + , [Status] bigint not null + , Parity bigint not null + , CreateLSN decimal(28,0) not null +); + +Create Table #VLFCount( + Database_Name sysname not null + , Recovery_model_desc nvarchar(60) not null + , VLFCount bigint not null + , CreateLSNCount bigint not null + , log_size_KB bigint not null +); + +Exec sp_MSforeachdb N'Use [?]; +Insert Into #LogInfo +Exec sp_executesql N''DBCC LogInfo([?]) with no_infomsgs''; + +Insert Into #VLFCount +Select d.name, d.Recovery_model_desc, Count_big(distinct l.FSeqNo), Count_Big(distinct l.CreateLSN), log_size_KB = sum(convert(bigint, l.FileSize)) +From #LogInfo l +inner join sys.databases d on db_name() = d.name +--inner join sys.master_files mf on db_id() = mf.database_id WHERE type_desc = ''log'' +group by d.name, Recovery_model_desc + +if ((select Count_big(*) from #LogInfo) > 50) +BEGIN + + + DECLARE @LogFileSize_MB_To_Allocate bigint, @loopcounter int, @LogFileSize_MB bigint , @TSQL nvarchar(4000) + select @LogFileSize_MB = sum(convert(bigint, mf.size))*8 FROM sys.master_files mf where type_desc = ''log'' and db_id() = mf.database_id + + IF (@LogFileSize_MB < (8000*1024)) BEGIN + select DBName= db_name(), VLFCount = sum(VLFCount), CreateLSNCount = sum(CreateLSNCount), Size_GB = sum(log_size_KB)/1024./1024. + from #VLFCount where database_name = db_name(); + + select @TSQL = '' + USE [''+d.name+''] + DBCC SHRINKFILE (N''''''+mf.name+'''''' , 0, TRUNCATEONLY) + GO + USE [master] + ALTER DATABASE [''+d.name+''] MODIFY FILE ( NAME = N''''''+mf.name+'''''', SIZE = ''+convert(varchar(30), mf.size*8/1024)+''MB ) + GO + '' + FROM sys.databases d inner join sys.master_files mf on d.database_id = mf.database_id where type_desc = ''log'' and db_name() = d.name + + IF @TSQL IS NOT NULL + BEGIN + set @TSQL = @TSQL + '' + --Returns file to original size.'' + SELECT DB_NAME() + '' log file excessive VLFs. See messages.'' + print @TSQL + END + END + +END +Truncate Table #LogInfo;' + +--Had to split up this foreachdb because of char limits +Exec sp_MSforeachdb N'Use [?]; +Insert Into #LogInfo +Exec sp_executesql N''DBCC LogInfo([?]) with no_infomsgs''; +if ((select Count_big(*) from #LogInfo) > 50) +BEGIN +DECLARE @LogFileSize_MB_To_Allocate bigint, @loopcounter int, @LogfileSize_MB bigint , @logFileSize_MB_Current bigint, @TSQL nvarchar(4000) +select @LogfileSize_MB = sum(convert(bigint, mf.size))*8/1024. FROM sys.master_files mf where type_desc = ''log'' and db_id() = mf.database_id +IF (@LogfileSize_MB >= (8000)) BEGIN +select DBName= db_name(), VLFCount = sum(VLFCount), CreateLSNCount = sum(CreateLSNCount), Size_GB = sum(log_size_KB)/1024./1024. +from #VLFCount where database_name = db_name(); +SET @LogFileSize_MB_To_Allocate = (@LogfileSize_MB - 8000) +SET @loopcounter = 1 +select top 1 @TSQL = ''USE [''+d.name+''] +DBCC SHRINKFILE (N''''''+mf.name+'''''' , 0, TRUNCATEONLY) +GO +USE [master] +ALTER DATABASE [''+d.name+''] MODIFY FILE ( NAME = N''''''+mf.name+'''''', SIZE = 8000MB ) --INITIAL FILE SIZE CAPPED at 8000MB (See Paul Randal blog). EXTEND IN 8GB INCREMENTS +GO +'' +FROM sys.databases d inner join sys.master_files mf on d.database_id = mf.database_id where type_desc = ''log'' and db_name() = d.name + +WHILE (@LogFileSize_MB_To_Allocate> 0) +BEGIN +SET @LogFileSize_MB_current = CASE WHEN (8000 + (@loopCounter * 8192)) > @LogfileSize_MB THEN @LogfileSize_MB ELSE (8000 + (@loopCounter * 8192)) END +select top 1 @TSQL = @TSQL + ''ALTER DATABASE [''+d.name+''] MODIFY FILE ( NAME = N''''''+mf.name+'''''', SIZE = '' + convert(varchar(1000), @LogFileSize_MB_current) +''MB ) +GO +'' +FROM sys.databases d inner join sys.master_files mf on d.database_id = mf.database_id where type_desc = ''log'' and db_name() = d.name +SET @LoopCounter = @LoopCounter + 1 +SET @LogFileSize_MB_To_Allocate = @LogfileSize_MB - @LogFileSize_MB_current +END +set @TSQL = @TSQL + '' +--Returns file to original size.'' +END +IF @TSQL is not null +BEGIN +SELECT DB_NAME() + '' log file excessive VLFs. See messages.'' +print @TSQL +END +END +Truncate Table #LogInfo;' + +select * from #VLFCount + +Drop Table #LogInfo; +Drop Table #VLFCount; + + +/* +--print ''At '' + convert(varchar(100), @LogFileSize_MB_current) +'', '' + convert(varchar(100), @LogFileSize_MB_To_Allocate) + '' left of '' + convert(varchar(100), @LogfileSize_MB) + +USE [w] +GO +DBCC SHRINKFILE (N'w_log' , 0, TRUNCATEONLY) +GO +USE [master] +GO +ALTER DATABASE [w] MODIFY FILE ( NAME = N'w_log', SIZE = 8000MB ) --INITIAL FILE SIZE CAPPED at 8000MB (See Paul Randal blog). EXTEND IN 8GB INCREMENTS +GO +--like this: +ALTER DATABASE [w] MODIFY FILE ( NAME = N'w_log', SIZE = 8001MB ) --... and so on up to current size = 8001MB + +*/ + + + \ No newline at end of file diff --git a/Volume_Stats_Alert.sql b/Volume_Stats_Alert.sql new file mode 100644 index 0000000..e2cb726 --- /dev/null +++ b/Volume_Stats_Alert.sql @@ -0,0 +1,118 @@ +USE DBAHound; +go + +/* +USE DBAHound; +GO + +CREATE TABLE [dbo].[VolumeStats]( + [ID] [int] IDENTITY(1,1) NOT NULL, + [volume_mount_point] [nvarchar](512) NULL, + [file_system_type] [nvarchar](512) NULL, + [logical_volume_name] [nvarchar](512) NULL, + [Total_Size] [float] NULL, + [Available_Size] [float] NULL, + [Space_Free] [float] NULL, + [DateTimeStamp] [datetime2](7) NULL, + CONSTRAINT [PK_VolumeStats] PRIMARY KEY CLUSTERED +( [ID] ASC) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] +) ON [PRIMARY] + +GO +*/ + +CREATE PROCEDURE usp_GetVolumeStats +@Threshold int +AS +BEGIN + +if object_id('tempdb..#VolumeStats') is not null begin drop table #VolumeStats end; +Create table #VolumeStats +(ID int identity(1,1), +volume_mount_point nvarchar(512), +file_system_type nvarchar(512), +logical_volume_name nvarchar(512), +Total_Size float, +Available_Size float, +Space_Free float, +DateTimePerformed datetime2 +) + + +DECLARE @TimeStamp datetime2 = getdate() +DECLARE VolumeInfo cursor +FOR +SELECT DISTINCT vs.volume_mount_point, vs.file_system_type, +vs.logical_volume_name, CONVERT(DECIMAL(18,2),vs.total_bytes/1073741824.0) AS [Total Size (GB)], +CONVERT(DECIMAL(18,2), vs.available_bytes/1073741824.0) AS [Available Size (GB)], +CONVERT(DECIMAL(18,2), vs.available_bytes * 1. / vs.total_bytes * 100.) AS [Space Free %], +@TimeStamp +FROM sys.master_files AS f WITH (NOLOCK) +CROSS APPLY sys.dm_os_volume_stats(f.database_id, f.[file_id]) AS vs + +DECLARE @volume nvarchar(512),@file_system_type nvarchar(512),@logical_name nvarchar(512) +DECLARE @TotalSize float,@AvailableSize float, @percent float +DECLARE @MyTime datetime2 + +OPEN VolumeInfo + +FETCH NEXT FROM VolumeInfo INTO @volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@MyTime +WHILE (@@FETCH_STATUS <> -1) +BEGIN + +if @percent > 20 +BEGIN + INSERT INTO dbo.VolumeStats(volume_mount_point,file_system_type,logical_volume_name,Total_Size,Available_Size,Space_Free,DateTimeStamp) + values(@volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@TimeStamp) + insert into #VolumeStats(volume_mount_point,file_system_type,logical_volume_name,Total_Size,Available_Size,Space_Free,DateTimePerformed) + VALUES(@volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@TimeStamp) +END +else +BEGIN + INSERT INTO dbo.VolumeStats(volume_mount_point,file_system_type,logical_volume_name,Total_Size,Available_Size,Space_Free,DateTimeStamp) + values(@volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@TimeStamp) + +END + +FETCH NEXT FROM VolumeInfo INTO @volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@Mytime +END +CLOSE VolumeInfo +DEALLOCATE VolumeInfo + +if (SELECT COUNT(*) FROM #VolumeStats) > 0 +DECLARE @tableHTML NVARCHAR(MAX) ; + +SET @tableHTML = + N'

Server: ' + @@SERVERNAME + '

' + + N'

Drive Space Alert

' + + N'' + + N'' + + N'' + + N'' + + CAST ( ( SELECT + td = v.volume_mount_point, '', + td = v.file_system_type, '', + td = v.logical_volume_name, '', + td = convert(varchar(8),v.Total_Size), '', + td = convert(varchar(8),v.Available_Size), '', + td = convert(varchar(8),v.Space_Free), '' + from #VolumeStats v + order by v.volume_mount_point + FOR XML PATH('tr'), TYPE + ) AS NVARCHAR(MAX) ) + + N'
VolumeFile Sytem TypeLogical NameTotal SizeAvailable SizePercent Free
' ; + +BEGIN +--select * from #VolumeStats +if @percent < @Threshold +BEGIN + EXEC msdb.dbo.sp_send_dbmail + @recipients = 'managed.sql@sparkhound.com', + @body = @tableHTML, + @importance = 'HIGH', + @body_format ='HTML', + @subject = 'Volume Size Report' ; +END +END +END; \ No newline at end of file diff --git a/add database descriptions.sql b/add database descriptions.sql new file mode 100644 index 0000000..e7e1df6 --- /dev/null +++ b/add database descriptions.sql @@ -0,0 +1,12 @@ + + +exec sp_MSforeachdb ' +if ((select db_id(''?'')) > 4 or ''?'' = ''model'' ) +BEGIN +EXEC [?].sys.sp_addextendedproperty @name=N''Description'', @value=N''Change this value''; +EXEC [?].sys.sp_addextendedproperty @name=N''BusinessOwner'', @value=N''Change this value''; +END' + +select * from sys.databases +exec sp_MSforeachdb 'select ''[?]'', class_desc, name, value from [?].sys.extended_properties ep where class_desc = ''database''' + diff --git a/add error event alerts.sql b/add error event alerts.sql new file mode 100644 index 0000000..e7e9aa1 --- /dev/null +++ b/add error event alerts.sql @@ -0,0 +1,167 @@ +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 16', + @message_id=0, + @severity=16, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 16', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 17', + @message_id=0, + @severity=17, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 17', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 18', + @message_id=0, + @severity=18, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 18', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 19', + @message_id=0, + @severity=19, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 19', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 20', + @message_id=0, + @severity=20, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 20', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 21', + @message_id=0, + @severity=21, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 21', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 22', + @message_id=0, + @severity=22, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 22', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 23', + @message_id=0, + @severity=23, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 23', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 24', + @message_id=0, + @severity=24, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 24', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'errorseverity 25', + @message_id=0, + @severity=25, + @enabled=1, + @delay_between_responses=600, + @include_event_description_in=1 +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'errorseverity 25', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +EXEC msdb.dbo.sp_add_alert @name=N'error 3041 - backup failure', + @message_id=3041, + @severity=0, + @enabled=1, + @delay_between_responses=0, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'error 3041 - backup failure', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +/* +exec sp_MSforeachdb ' +EXEC msdb.dbo.sp_add_alert @name=N''pct log used - [?] database'', + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @performance_condition=N''MSSQLSERVER:Databases|Percent Log Used|?|>|95'', + @job_id=N''00000000-0000-0000-0000-000000000000''; +EXEC msdb.dbo.sp_add_notification @alert_name=N''pct log used - [?] database'', @operator_name=N''sql.alerts@sparkhound.com'', @notification_method = 1' +GO +*/ +EXEC msdb.dbo.sp_add_alert @name=N'error 825 - read-retry error (severity 10)', + @message_id=825, + @severity=0, + @enabled=1, + @delay_between_responses=0, + @include_event_description_in=1, + @job_id=N'00000000-0000-0000-0000-000000000000' +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'error 825 - read-retry error (severity 10)', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO + + +/* +EXEC msdb.dbo.sp_add_alert @name=N'deadlocks', + @message_id=0, + @severity=0, + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @category_name=N'[Uncategorized]', + @performance_condition=N'SQLServer:Locks|Number of Deadlocks/sec|_Total|>|0', + @job_id=N'00000000-0000-0000-0000-000000000000' +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'deadlocks', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO + + +--MSSQL$GP2k8r2 + +USE [msdb] +GO +EXEC msdb.dbo.sp_add_alert @name=N'buffer cache hit ratio', + @enabled=1, + @delay_between_responses=300, + @include_event_description_in=1, + @performance_condition=N'SQLServer:Buffer Manager|Buffer cache hit ratio||<|0.8' +GO +EXEC msdb.dbo.sp_add_notification @alert_name=N'buffer cache hit ratio', @operator_name=N'sql.alerts@sparkhound.com', @notification_method = 1 +GO +*/ \ No newline at end of file diff --git a/alwayson metrics.sql b/alwayson metrics.sql new file mode 100644 index 0000000..64ae4f8 --- /dev/null +++ b/alwayson metrics.sql @@ -0,0 +1,24 @@ +select * from sys.dm_hadr_cluster hc +select * from sys.dm_hadr_cluster_members cm + +select td.instance_name, delay_ms = td.cntr_value, transactions_count = mts.cntr_value, transactiondelay_ms = convert(decimal(9,2),td.cntr_value / mts.cntr_value) +from +( select instance_name,cntr_value = convert(decimal(9,2), cntr_value) +from sys.dm_os_performance_counters + where object_name like '%database replica%' + and counter_name = 'transaction delay' --cumulative transaction delay in ms + ) td + inner join + ( +select instance_name,cntr_value = convert(decimal(9,2), cntr_value) +from sys.dm_os_performance_counters + where object_name like '%database replica%' + and counter_name = 'mirrored write transactions/sec' --actually a cumulative transactions count, not per sec + ) mts + on td.instance_name = mts.instance_name + + + +select wait_type, waiting_tasks_count, wait_time_ms, wait_time_ms/waiting_tasks_count as'time_per_wait' +from sys.dm_os_wait_stats where waiting_tasks_count >0 +and wait_type like 'HADR_%_COMMIT' diff --git a/autogrow change all 1mb growth files.sql b/autogrow change all 1mb growth files.sql new file mode 100644 index 0000000..dc7b922 --- /dev/null +++ b/autogrow change all 1mb growth files.sql @@ -0,0 +1,15 @@ + + +USE [master] +GO +select 'ALTER DATABASE ['+d.name+'] MODIFY FILE ( NAME = N'''+ mf.name+ ''', FILEGROWTH = 512000KB )' +, mf.* +FROM sys.databases d +inner join sys.master_files mf +on d.database_id = mf.database_id +where mf.is_percent_growth = 0 and growth = 128 + +/* +ALTER DATABASE [model] MODIFY FILE ( NAME = N'modeldev', FILEGROWTH = 512000KB ) + +*/ \ No newline at end of file diff --git a/autogrow events.sql b/autogrow events.sql new file mode 100644 index 0000000..0c0f213 --- /dev/null +++ b/autogrow events.sql @@ -0,0 +1,38 @@ + +--The trace automatically finds _n files, strip off the _nnn. For example, will read all data from log_14.trc, log_15.trc, log_16.trc, log_17.trc, etc. +--Default trace files are limited to 20mb, and there are at most five of them, so we have 100mb of history. Depends on activity to determine how far back that goes. + + + SELECT + DBName = g.DatabaseName + , DBFileName = mf.physical_name + , FileType = CASE mf.type WHEN 0 THEN 'Row' WHEN 1 THEN 'Log' WHEN 2 THEN 'FILESTREAM' WHEN 4 THEN 'Full-text' END + , EventName = te.name + , EventGrowthMB = convert(decimal(19,2),g.IntegerData*8/1024.) -- Number of 8-kilobyte (KB) pages by which the file increased. + , EventTime = g.StartTime + , EventDurationSec = convert(decimal(19,2),g.Duration/1000./1000.) -- Length of time (in milliseconds) necessary to extend the file. + , CurrentAutoGrowthSet= CASE + WHEN mf.is_percent_growth = 1 + THEN CONVERT(char(2), mf.growth) + '%' + ELSE CONVERT(varchar(30), convert(decimal(19,2), mf.growth*8./1024.)) + 'MB' + END + , CurrentFileSizeMB = convert(decimal(19,2),mf.size* 8./1024.) + , d.Recovery_model_Desc + --, @tracepath + --, MaxFileSizeMB = CASE WHEN mf.max_size = -1 THEN 'Unlimited' ELSE convert(varchar(30), convert(decimal(19,2),mf.max_size*8./1024.)) END + --select count(1) + FROM fn_trace_gettable((select substring((select path from sys.traces where is_default =1), 0, charindex('\log_', (select path from sys.traces where is_default =1),0)+4) + '.trc'), default) g + cross apply sys.trace_events te + inner join sys.master_files mf + on mf.database_id = g.DatabaseID + and g.FileName = mf.name + inner join sys.databases d + on d.database_id = g.DatabaseID + WHERE g.eventclass = te.trace_event_id + and te.name in ('Data File Auto Grow','Log File Auto Grow') + and g.StartTime > CURRENT_TIMESTAMP -1 + --GROUP BY StartTime,Databaseid, Filename, IntegerData, Duration + order by StartTime desc + + + diff --git a/automated index rebuild w online 2012.sql b/automated index rebuild w online 2012.sql new file mode 100644 index 0000000..1a68ed9 --- /dev/null +++ b/automated index rebuild w online 2012.sql @@ -0,0 +1,332 @@ +/* Automated index maint script +Added by William Assaf, Sparkhound 20140304 +Modified by William Assaf, Sparkhound 20140313 +Modified by Robert Bishop, Sparkhound 20170107 -- changed Version selection to be compatible +--Primary objective is to never perform an offline index rebuild unless it is the only option. +*/ +--#TODO For each database: +--Change name after USE below +--Change name in ALTER ... BULK_LOGGED below +--Change name in ALTER ... FULL near end + +USE WideWorldImporters --#TODO Change database name +GO +DECLARE @testmode bit +DECLARE @startwindow tinyint +DECLARE @endwindow tinyint + +SELECT @testmode = 1 -- flip to 1 to run out of cycle, without actually executing any code. +SELECT @startwindow = 0 -- Range (0-23). 24-hour of the day. Ex: 4 = 4am, 16 = 4pm. 0 = midnight. +SELECT @endwindow = 23 -- Range (0-23). 24-hour of the day. Ex: 4 = 4am, 16 = 4pm. 0 = midnight. + +SET XACT_ABORT ON; + +BEGIN TRY + + IF @testmode = 0 + ALTER DATABASE wideWorldImporters SET RECOVERY BULK_LOGGED; --#TODO Change database name + + SET NOCOUNT ON; + + DECLARE @objectid int + , @indexid int + , @partitioncount bigint + , @schemaname sysname + , @objectname sysname + , @indexname sysname + , @partitionnum bigint + , @partitions bigint + , @frag float + , @command varchar(8000) + , @Can_Reorg bit + , @Can_RebuildOnline nvarchar(60) + , @Can_Compress bit + DECLARE @ProductVersion varchar(15) + DECLARE @ServerEdition varchar(30) + + SET @ServerEdition = convert(varchar(30),(SELECT SERVERPROPERTY('Edition'))) + SET @ProductVersion = convert(varchar(15),(SELECT SERVERPROPERTY('ProductVersion'))) + + -- ensure the temporary table does not exist + IF EXISTS (SELECT name FROM tempdb.sys.objects WHERE name like '%C__work_to_do%') + DROP TABLE #C__work_to_do; + + CREATE TABLE #C__work_to_do + ( + objectid int NOT NULL + , indexid int NOT NULL + , partitionnum int NOT NULL + , frag decimal(9,2) NOT NULL + , Can_Reorg bit NOT NULL + , Can_RebuildOnline bit NOT NULL + , Can_Compress bit NOT NULL + , indexname sysname NOT NULL, + + PRIMARY KEY ( objectid, indexid, partitionnum ) + ) + + -- conditionally select from the function, converting object and index IDs to names. + INSERT INTO #C__work_to_do + ( objectid + , indexid + , partitionnum + , frag + , Can_Reorg + , Can_RebuildOnline + , Can_Compress + , indexname + ) + SELECT + objectid = s.object_id + , indexid = s.index_id + , partitionnum = s.partition_number + , frag = max(s.avg_fragmentation_in_percent) + , Can_Reorg = i.ALLOW_PAGE_LOCKS --An index cannot be reorganized when ALLOW_PAGE_LOCKS is set to 0. + ,Can_RebuildOnline = + CASE + WHEN A.index_id is not null and A.user_type_id is not null + THEN 0 -- Cannot do ONLINE REBUILDs with certain data types in the index (key or INCLUDE). + WHEN A.index_id is null and s.index_id <= 1 and A.user_type_id is not null + THEN 0 -- Cannot do ONLINE REBUILDs with certain data types in the index (key or INCLUDE). + WHEN i.type_desc in ('xml','spatial') THEN 0 -- Cannot do ONLINE REBUILDs for certain index types. + WHEN (left(@ProductVersion,2) >= 10 ) and (@ServerEdition like 'Developer%' or @ServerEdition like 'Enterprise%' ) + THEN 1 + ELSE 0 + END + , Can_Compress = CASE WHEN + (left(@ProductVersion,2) >= 10 ) and (@ServerEdition like 'Developer%' or @ServerEdition like 'Enterprise%' ) + THEN 1 + ELSE 0 + END + , indexname = i.name + FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED') s + inner join --select * from + sys.indexes i on s.object_id = i.object_id and s.index_id = i.index_id + left outer join + ( + select + c.object_id, ic.index_id, user_type_id = COALESCE(t.user_type_id, null) + from sys.columns c + left outer join sys.index_columns ic + on ic.object_id = c.object_id + and ic.column_id = c.column_id + left outer join sys.types t + on c.user_type_id = t.user_type_id + WHERE + ( t.name in (N'image', N'text', N'ntext', N'xml') + or (t.name in ('varchar', 'nvarchar', 'varbinary') + and c.max_length = -1 --indicates (MAX) + ) + ) + ) A + on i.object_id = A.object_id + AND i.index_id = A.index_id + WHERE + 1=1 + AND s.avg_fragmentation_in_percent > 10.0 + AND s.index_id > 0 -- + AND s.page_count > 1280 --12800 pages is 100mb + and i.name is not null + group by + s.object_id + , s.index_id + , s.partition_number + , i.ALLOW_PAGE_LOCKS + , A.index_id + , A.user_type_id + , i.type_desc + , i.name; + + -- Declare the cursor for the list of partitions to be processed. + DECLARE partitions CURSOR FAST_FORWARD FOR + SELECT * FROM #C__work_to_do; + + -- Open the cursor. + OPEN partitions; + + -- Loop through the partitions. + FETCH NEXT + FROM partitions + INTO @objectid, @indexid, @partitionnum, @frag, @Can_Reorg, @Can_RebuildOnline, @Can_Compress, @indexname; + + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + + DECLARE @currenthour int = datepart(hour, Getdate()) + + IF(@startwindow > @endwindow -- wraps midnight + AND ( @currenthour >= @startwindow + OR (@currenthour <= @startwindow + AND @currenthour < @endwindow) + ) + + ) + OR + (@startwindow <= @endwindow -- AM only or PM only + AND @currenthour >= @startwindow + and @currenthour < @endwindow + ) + OR + @testmode = 1 + BEGIN + + SELECT @objectname = o.name + , @schemaname = s.name + FROM sys.objects AS o + INNER JOIN sys.schemas as s ON s.schema_id = o.schema_id + WHERE o.object_id = @objectid; + + --SELECT @objectid, @indexid, @partitionnum, @frag, @Can_Reorg, @Can_RebuildOnline, @indexname, @objectname, @schemaname + + SELECT @partitioncount = count (*) + FROM sys.partitions + WHERE object_id = @objectid AND index_id = @indexid; + + SELECT @command = ''; + + -- 30 is an arbitrary decision point at which to switch between reorganizing and rebuilding + IF @frag < 30.0 and @Can_Reorg = 1 + BEGIN + + --print '0'; + + SELECT @command = 'ALTER INDEX [' + @indexname + '] ON [' + @schemaname + '].[' + @objectname + '] REORGANIZE '; + + IF @partitioncount > 1 + SELECT @command = @command + ' PARTITION=' + CONVERT (CHAR, @partitionnum); + + SELECT @command = @command + '; UPDATE STATISTICS [' + @schemaname + '].[' + @objectname + '] ([' + @indexname + ']); ' + + --PRINT 'FragLevel ' + str(@FRAG) + + END + + IF @frag >= 60.0 + BEGIN + + --Doing an INDEX REBUILD with ONLINE = ON reduces the impact of locking to the production server, + -- though it will still create resource contention by keeping the drives and tempdb busy. + -- Unlike REORGANIZE steps, a REBUILD also updates the STATISTICS of an index. + IF @Can_RebuildOnline = 1 + BEGIN + --print '1' + + SELECT @command = 'ALTER INDEX [' + @indexname +'] ON [' + @schemaname + '].[' + @objectname + '] REBUILD '; + + IF @partitioncount > 1 + SELECT @command = @command + ' PARTITION=' + CONVERT (CHAR, @partitionnum); + + SELECT @command = @command + ' WITH (ONLINE = ON' + + IF @Can_Compress = 1 + SELECT @command = @command + ', DATA_COMPRESSION = PAGE' + + select @command = @command + ');' + END + + --REORGANIZE processes are always ONLINE and are less intense than REBUILDs. + ELSE IF @Can_Reorg = 1 + BEGIN + + --print '2' + + SELECT @command = 'ALTER INDEX [' + @indexname +'] ON [' + @schemaname + '].[' + @objectname + '] REORGANIZE '; + + IF @partitioncount > 1 + SELECT @command = @command + ' PARTITION=' + CONVERT (CHAR, @partitionnum); + + SELECT @command = @command + '; UPDATE STATISTICS [' + @schemaname + '].[' + @objectname + '] ([' + @indexname + ']); ' + + END + + --Only do a full, offline index rebuild in the middle of the night. + ELSE IF datepart(hour, Getdate()) < 3 --inclusive both hours. + BEGIN + + --print '3' + + SELECT @command = 'ALTER INDEX [' + @indexname + '] ON [' + @schemaname + '.' + @objectname + '] REBUILD'; + + IF @partitioncount > 1 + SELECT @command = @command + ' PARTITION = ' + CONVERT (CHAR, @partitionnum); + + IF @Can_Compress = 1 + SELECT @command = @command + ' WITH (DATA_COMPRESSION = PAGE); ' + + --PRINT 'FragLevel ' + str(@FRAG) + + END + END + IF @command <> '' + BEGIN + INSERT INTO DBAHound.dbo.IndexMaintLog (CurrentDatabase, Command, ObjectName, BeginTimeStamp, StartWindow, EndWindow, TestMode) + SELECT DB_NAME(), @Command, '[' + DB_Name() + '].[' + @objectname + '].[' + @schemaname + ']', getdate(), @StartWindow, @EndWindow, @TestMode + + BEGIN TRY + IF @testmode = 0 EXEC (@command); + + PRINT N'Executed: ' + @command + UPDATE DBAHound.dbo.IndexMaintLog + SET EndTimeStamp = Getdate() + , Duration_s = datediff(s, BeginTimeStamp, getdate()) + where id = SCOPE_IDENTITY() and EndTimeStamp is null + + END TRY + BEGIN CATCH + Print N'Error: ' + ERROR_MESSAGE() + UPDATE DBAHound.dbo.IndexMaintLog + SET ErrorMessage = cast(ERROR_NUMBER() as char(9)) + ERROR_MESSAGE() + where id = SCOPE_IDENTITY() and EndTimeStamp is null + END CATCH + + END + END + END TRY + BEGIN CATCH + PRINT N'Failed to execute the command: ' + @command + N' Error Message: ' + ERROR_MESSAGE() + END CATCH + + FETCH NEXT FROM partitions + INTO @objectid, @indexid, @partitionnum, @frag, @Can_Reorg, @Can_RebuildOnline, @Can_Compress, @indexname; + END + + -- Close and deallocate the cursor. + CLOSE partitions; + DEALLOCATE partitions; + + -- drop the temporary table + IF EXISTS (SELECT name FROM tempdb.sys.objects WHERE name like '%C__work_to_do%') + DROP TABLE #C__work_to_do; + + IF @testmode = 0 + ALTER DATABASE [WideWorldImporters] SET RECOVERY FULL --#TODO Change database name + + END TRY + BEGIN CATCH + INSERT INTO DBAHound.dbo.IndexMaintLog (CurrentDatabase, ErrorMessage , BeginTimeStamp, TestMode) + SELECT DB_NAME(), cast(ERROR_NUMBER() as char(9)) + ERROR_MESSAGE(), getdate(), @TestMode + + END CATCH +GO + +/* +DROP TABLE DBAHound.dbo.IndexMaintLog; +CREATE TABLE DBAHound.dbo.IndexMaintLog +( id int not null identity(1,1) PRIMARY KEY +, CurrentDatabase sysname not null DEFAULT (DB_NAME()) +, Command nvarchar(1000) null +, ObjectName nvarchar(100) null +, BeginTimeStamp datetime null +, TestMode bit null +, StartWindow tinyint null +, EndWindow tinyint null +, EndTimeStamp datetime null +, Duration_s int null +, ErrorMessage nvarchar(4000) null +) + + +select * from DBAHound.dbo.indexmaintlog + +*/ diff --git a/automated index rebuild w online 2016.sql b/automated index rebuild w online 2016.sql new file mode 100644 index 0000000..539af8b --- /dev/null +++ b/automated index rebuild w online 2016.sql @@ -0,0 +1,350 @@ +/* Automated index maint script +Added by William Assaf, Sparkhound 20140304 +Modified by William Assaf, Sparkhound 20140313 +Modified by Robert Bishop, Sparkhound 20170107 -- changed Version selection to be compatible +--Primary objective is to never perform an offline index rebuild unless it is the only option. +*/ +--#TODO For each database: +--Change name after USE below +--Change name in ALTER ... BULK_LOGGED below +--Change name in ALTER ... FULL near end + +--USE WideWorldImporters --#TODO Change database name +GO +DECLARE @testmode bit +DECLARE @startwindow tinyint +DECLARE @endwindow tinyint + +SELECT @testmode = 0 -- flip to 1 to run out of cycle, without actually executing any code. +SELECT @startwindow = 0 -- Range (0-23). 24-hour of the day. Ex: 4 = 4am, 16 = 4pm. 0 = midnight. +SELECT @endwindow = 23 -- Range (0-23). 24-hour of the day. Ex: 4 = 4am, 16 = 4pm. 0 = midnight. + +SET XACT_ABORT ON; + +BEGIN TRY + + --IF @testmode = 0 + --ALTER DATABASE wideWorldImporters SET RECOVERY BULK_LOGGED; --#TODO Change database name + + SET NOCOUNT ON; + + DECLARE @objectid int + , @indexid int + , @partitioncount bigint + , @schemaname sysname + , @objectname sysname + , @indexname sysname + , @partitionnum bigint + , @partitions bigint + , @frag float + , @command varchar(8000) + , @Can_Reorg bit + , @Can_RebuildOnline nvarchar(60) + , @Can_Compress bit + , @ProductVersion varchar(15) + , @ServerEdition varchar(30) + + SET @ServerEdition = convert(varchar(30),(SELECT SERVERPROPERTY('Edition'))) + SET @ProductVersion = convert(varchar(15),(SELECT SERVERPROPERTY('ProductVersion'))) + + -- ensure the temporary table does not exist + IF EXISTS (SELECT name FROM tempdb.sys.objects WHERE name like '%C__work_to_do%') + DROP TABLE #C__work_to_do; + + CREATE TABLE #C__work_to_do + ( + objectid int NOT NULL + , indexid int NOT NULL + , partitionnum int NOT NULL + , frag decimal(9,2) NOT NULL + , Can_Reorg bit NOT NULL + , Can_RebuildOnline bit NOT NULL + , Can_Compress bit NOT NULL + , indexname sysname NOT NULL, + + PRIMARY KEY ( objectid, indexid, partitionnum ) + ) + + -- conditionally select from the function, converting object and index IDs to names. + INSERT INTO #C__work_to_do + ( objectid + , indexid + , partitionnum + , frag + , Can_Reorg + , Can_RebuildOnline + , Can_Compress + , indexname + ) + SELECT + objectid = s.object_id + , indexid = s.index_id + , partitionnum = s.partition_number + , frag = max(s.avg_fragmentation_in_percent) + , Can_Reorg = i.ALLOW_PAGE_LOCKS --An index cannot be reorganized when ALLOW_PAGE_LOCKS is set to 0. + ,Can_RebuildOnline = + CASE + WHEN A.index_id is not null and A.user_type_id is not null + THEN 0 -- Cannot do ONLINE REBUILDs with certain data types in the index (key or INCLUDE). + WHEN A.index_id is null and s.index_id <= 1 and A.user_type_id is not null + THEN 0 -- Cannot do ONLINE REBUILDs with certain data types in the index (key or INCLUDE). + WHEN i.type_desc in ('xml','spatial') THEN 0 -- Cannot do ONLINE REBUILDs for certain index types. + WHEN (left(@ProductVersion,2) >= 10 ) and (@ServerEdition like 'Developer%' or @ServerEdition like 'Enterprise%' ) + THEN 1 + ELSE 0 + END + , Can_Compress = CASE WHEN + (left(@ProductVersion,2) >= 10 ) and (@ServerEdition like 'Developer%' or @ServerEdition like 'Enterprise%' ) + THEN 1 + ELSE 0 + END + , indexname = i.name --select object_name(object_id), * + FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED') s + inner join --select * from + sys.indexes i on s.object_id = i.object_id and s.index_id = i.index_id + left outer join + ( + select + c.object_id, ic.index_id, user_type_id = COALESCE(t.user_type_id, null) + from sys.columns c + left outer join sys.index_columns ic + on ic.object_id = c.object_id + and ic.column_id = c.column_id + left outer join sys.types t + on c.user_type_id = t.user_type_id + WHERE + ( t.name in (N'image', N'text', N'ntext', N'xml') + or (t.name in ('varchar', 'nvarchar', 'varbinary') + and c.max_length = -1 --indicates (MAX) + ) + ) + ) A + on i.object_id = A.object_id + AND i.index_id = A.index_id + WHERE + 1=1 + AND s.avg_fragmentation_in_percent > 10.0 + AND s.index_id > 0 -- + AND s.page_count > 1280 --12800 pages is 100mb + and i.name is not null + group by + s.object_id + , s.index_id + , s.partition_number + , i.ALLOW_PAGE_LOCKS + , A.index_id + , A.user_type_id + , i.type_desc + , i.name; + + IF CURSOR_STATUS('local', 'curIndexPartitions') >= 0 + BEGIN + CLOSE curIndexPartitions; + DEALLOCATE curIndexPartitions; + END + + -- Declare the cursor for the list of partitions to be processed. + DECLARE curIndexPartitions CURSOR LOCAL FAST_FORWARD FOR + SELECT * FROM #C__work_to_do; + + -- Open the cursor. + OPEN curIndexPartitions; + + -- Loop through the partitions. + FETCH NEXT + FROM curIndexPartitions + INTO @objectid, @indexid, @partitionnum, @frag, @Can_Reorg, @Can_RebuildOnline, @Can_Compress, @indexname; + + WHILE @@FETCH_STATUS = 0 + BEGIN + BEGIN TRY + + DECLARE @currenthour int = datepart(hour, Getdate()) + + IF(@startwindow > @endwindow -- wraps midnight + AND ( @currenthour >= @startwindow + OR (@currenthour <= @startwindow + AND @currenthour < @endwindow) + ) + + ) + OR + (@startwindow <= @endwindow -- AM only or PM only + AND @currenthour >= @startwindow + and @currenthour < @endwindow + ) + OR + @testmode = 1 + BEGIN + + SELECT @objectname = o.name + , @schemaname = s.name + FROM sys.objects AS o + INNER JOIN sys.schemas as s ON s.schema_id = o.schema_id + WHERE o.object_id = @objectid; + + --SELECT @objectid, @indexid, @partitionnum, @frag, @Can_Reorg, @Can_RebuildOnline, @indexname, @objectname, @schemaname + + SELECT @partitioncount = count (*) + FROM sys.partitions + WHERE object_id = @objectid AND index_id = @indexid; + + SELECT @command = ''; + + -- 30 is an arbitrary decision point at which to switch between reorganizing and rebuilding + IF @frag < 30.0 and @Can_Reorg = 1 + BEGIN + + --print '0'; + + SELECT @command = 'ALTER INDEX [' + @indexname + '] ON [' + @schemaname + '].[' + @objectname + '] REORGANIZE '; + + IF @partitioncount > 1 + SELECT @command = @command + ' PARTITION=' + CONVERT (CHAR, @partitionnum); + + SELECT @command = @command + '; UPDATE STATISTICS [' + @schemaname + '].[' + @objectname + '] ([' + @indexname + ']); ' + + END + + IF @frag >= 60.0 + BEGIN + + --Doing an INDEX REBUILD with ONLINE = ON reduces the impact of locking to the production server, + -- though it will still create resource contention by keeping the drives and tempdb busy. + -- Unlike REORGANIZE steps, a REBUILD also updates the STATISTICS of an index. + IF @Can_RebuildOnline = 1 + BEGIN + --print '1' + + SELECT @command = 'ALTER INDEX [' + @indexname +'] ON [' + @schemaname + '].[' + @objectname + '] REBUILD '; + + IF @partitioncount > 1 + SELECT @command = @command + ' PARTITION=' + CONVERT (CHAR, @partitionnum); + + SELECT @command = @command + ' WITH (ONLINE = ON' + + IF @Can_Compress = 1 + SELECT @command = @command + ', DATA_COMPRESSION = PAGE' + + select @command = @command + ');' + END + + --REORGANIZE processes are always ONLINE and are less intense than REBUILDs. + ELSE IF @Can_Reorg = 1 + BEGIN + + --print '2' + + SELECT @command = 'ALTER INDEX [' + @indexname +'] ON [' + @schemaname + '].[' + @objectname + '] REORGANIZE '; + + IF @partitioncount > 1 + SELECT @command = @command + ' PARTITION=' + CONVERT (CHAR, @partitionnum); + + SELECT @command = @command + '; UPDATE STATISTICS [' + @schemaname + '].[' + @objectname + '] ([' + @indexname + ']); ' + + END + + --OPTIONAL: Only do a full, offline index rebuild in the middle of the night. + --ELSE IF datepart(hour, Getdate()) < 3 --inclusive both hours. + ELSE + BEGIN + + --print '3' + + SELECT @command = 'ALTER INDEX [' + @indexname + '] ON [' + @schemaname + '.' + @objectname + '] REBUILD'; + + IF @partitioncount > 1 + SELECT @command = @command + ' PARTITION = ' + CONVERT (CHAR, @partitionnum); + + IF @Can_Compress = 1 + SELECT @command = @command + ' WITH (DATA_COMPRESSION = PAGE); ' + + + END + END + IF @command <> '' + BEGIN + INSERT INTO DBAHound.dbo.IndexMaintLog (CurrentDatabase, Command, ObjectName, BeginTimeStamp, StartWindow, EndWindow, TestMode) + SELECT DB_NAME(), @Command, '[' + DB_Name() + '].[' + @objectname + '].[' + @schemaname + ']', getdate(), @StartWindow, @EndWindow, @TestMode + + BEGIN TRY + IF @testmode = 0 EXEC (@command); + + PRINT N'Executed: ' + @command + ' Frag level: ' + str(@frag) + UPDATE DBAHound.dbo.IndexMaintLog + SET EndTimeStamp = Getdate() + , Duration_s = datediff(s, BeginTimeStamp, getdate()) + where id = SCOPE_IDENTITY() and EndTimeStamp is null + + END TRY + BEGIN CATCH + Print N'Error: ' + ERROR_MESSAGE() + UPDATE DBAHound.dbo.IndexMaintLog + SET ErrorMessage = cast(ERROR_NUMBER() as char(9)) + ERROR_MESSAGE() + where id = SCOPE_IDENTITY() and EndTimeStamp is null + END CATCH + + END + END + END TRY + BEGIN CATCH + PRINT N'Failed to execute the command: ' + @command + N' Error Message: ' + ERROR_MESSAGE() + END CATCH + + FETCH NEXT FROM curIndexPartitions + INTO @objectid, @indexid, @partitionnum, @frag, @Can_Reorg, @Can_RebuildOnline, @Can_Compress, @indexname; + END + + -- Close and deallocate the cursor. + IF CURSOR_STATUS('local', N'curIndexPartitions') >= 0 + BEGIN + CLOSE curIndexPartitions; + DEALLOCATE curIndexPartitions; + END + + -- drop the temporary table + IF EXISTS (SELECT name FROM tempdb.sys.objects WHERE name like '%C__work_to_do%') + DROP TABLE #C__work_to_do; + + --IF @testmode = 0 + --ALTER DATABASE [WideWorldImporters] SET RECOVERY FULL --#TODO Change database name + + END TRY + BEGIN CATCH + PRINT N'Failed to execute. Error Message: ' + ERROR_MESSAGE() + INSERT INTO DBAHound.dbo.IndexMaintLog (CurrentDatabase, ErrorMessage , BeginTimeStamp, TestMode) + SELECT DB_NAME(), cast(ERROR_NUMBER() as char(9)) + ERROR_MESSAGE(), getdate(), @TestMode + + IF EXISTS (SELECT name FROM tempdb.sys.objects WHERE name like '%C__work_to_do%') + DROP TABLE #C__work_to_do; + + IF CURSOR_STATUS('local', N'curIndexPartitions') >= 0 + BEGIN + CLOSE curIndexPartitions; + DEALLOCATE curIndexPartitions; + END + + + END CATCH +GO + +/* +DROP TABLE DBAHound.dbo.IndexMaintLog; +CREATE TABLE DBAHound.dbo.IndexMaintLog +( id int not null identity(1,1) PRIMARY KEY +, CurrentDatabase sysname not null DEFAULT (DB_NAME()) +, Command nvarchar(1000) null +, ObjectName nvarchar(100) null +, BeginTimeStamp datetime null +, TestMode bit null +, StartWindow tinyint null +, EndWindow tinyint null +, EndTimeStamp datetime null +, Duration_s int null +, ErrorMessage nvarchar(4000) null +) + + +select * from DBAHound.dbo.indexmaintlog + +*/ diff --git a/avg disk secwrite.png b/avg disk secwrite.png new file mode 100644 index 0000000..3c9b30b Binary files /dev/null and b/avg disk secwrite.png differ diff --git a/azure dtu usage every 15s.sql b/azure dtu usage every 15s.sql new file mode 100644 index 0000000..73eb72d --- /dev/null +++ b/azure dtu usage every 15s.sql @@ -0,0 +1,34 @@ +--https://msdn.microsoft.com/en-us/library/dn800981.aspx +--Run in the user Azure database + +SELECT + Database_Name = DB_NAME() +, TierDTU = dtu_limit +, 'Average CPU Utilization In %' = AVG(avg_cpu_percent) +, 'Maximum CPU Utilization In %' = MAX(avg_cpu_percent) +, 'Average Data IO In %' = AVG(avg_data_io_percent) +, 'Maximum Data IO In %' = MAX(avg_data_io_percent) +, 'Average Log Write Utilization In %' = AVG(avg_log_write_percent) +, 'Maximum Log Write Utilization In %' = MAX(avg_log_write_percent) +, 'Average Memory Usage In %' = AVG(avg_memory_usage_percent) +, 'Maximum Memory Usage In %' = MAX(avg_memory_usage_percent) +FROM sys.dm_db_resource_stats --past hour only +group by dtu_limit + +go +select + UTC_time = end_time +, 'CPU Utilization In % of Limit' = rs.avg_cpu_percent +, 'Data IO In % of Limit' = rs.avg_data_io_percent +, 'Log Write Utilization In % of Limit' = rs.avg_log_write_percent +, 'Memory Usage In % of Limit' = rs.avg_memory_usage_percent +, 'In-Memory OLTP Storage in % of Limit' = rs.xtp_storage_percent +, 'Concurrent Requests in % of Limit' = rs.max_worker_percent +, 'Concurrent Sessions in % of Limit' = rs.max_session_percent + +from +sys.dm_db_resource_stats as rs --past hour only +order by end_time desc + + + diff --git a/azure dtu usage every hour.sql b/azure dtu usage every hour.sql new file mode 100644 index 0000000..9064ad1 --- /dev/null +++ b/azure dtu usage every hour.sql @@ -0,0 +1,45 @@ +--https://msdn.microsoft.com/en-us/library/dn800981.aspx +--Run in the master Azure SQL server database +select + Database_Name +, sku --Basic, Standard, Premium +, TierDTU = dtu_limit +, Storage_in_mb = MAX(Storage_in_megabytes) +, 'Average CPU Utilization In %' = AVG(avg_cpu_percent) +, 'Maximum CPU Utilization In %' = MAX(avg_cpu_percent) +, 'Average Data IO In %' = AVG(avg_data_io_percent) +, 'Maximum Data IO In %' = MAX(avg_data_io_percent) +, 'Average Log Write Utilization In %' = AVG(avg_log_write_percent) +, 'Maximum Log Write Utilization In %' = MAX(avg_log_write_percent) +, 'Average Requests In %' = AVG(max_worker_percent) +, 'Maximum Requests In %' = MAX(max_worker_percent) +, 'Average Sessions In %' = AVG(max_session_percent) +, 'Maximum Sessions In %' = MAX(max_session_percent) +--select * +from +master.sys.resource_stats as rs --past 14 days +group by Database_Name, sku, dtu_limit +order by Database_Name desc + +select + Timestamp = datetimefromparts(year(rs.end_time), month(rs.end_time), day(rs.end_time), datepart(hh,rs.end_time), 0,0,0) +, Database_Name +, sku --Basic, Standard, Premium +, TierDTU = dtu_limit +, Storage_in_mb = MAX(Storage_in_megabytes) +, 'Average CPU Utilization In %' = AVG(avg_cpu_percent) +, 'Maximum CPU Utilization In %' = MAX(avg_cpu_percent) +, 'Average Data IO In %' = AVG(avg_data_io_percent) +, 'Maximum Data IO In %' = MAX(avg_data_io_percent) +, 'Average Log Write Utilization In %' = AVG(avg_log_write_percent) +, 'Maximum Log Write Utilization In %' = MAX(avg_log_write_percent) +, 'Average Requests In %' = AVG(max_worker_percent) +, 'Maximum Requests In %' = MAX(max_worker_percent) +, 'Average Sessions In %' = AVG(max_session_percent) +, 'Maximum Sessions In %' = MAX(max_session_percent) +--select * +from +master.sys.resource_stats as rs --past 14 days only +group by Database_Name, sku, dtu_limit, datetimefromparts(year(rs.end_time), month(rs.end_time), day(rs.end_time), datepart(hh,rs.end_time), 0,0,0) +order by Database_Name desc + diff --git a/backup history oldest latest.sql b/backup history oldest latest.sql new file mode 100644 index 0000000..0fa4b93 --- /dev/null +++ b/backup history oldest latest.sql @@ -0,0 +1,91 @@ +--sql2005 and above +select + backuptype + , recovery_model_desc + , OldestLatestBackupDate = MIN(BackupDate) +FROM +( +select + database_Name + , backuptype + , d.recovery_model_desc + , BackupDate = MAX(BackupDate) + , d.state_desc + from sys.databases d + inner join + ( +select distinct + database_name + , backuptype = case type WHEN 'D' then 'Database' + WHEN 'I' then 'Differential database' + WHEN 'L' then 'Transaction Log' + WHEN 'F' then 'File or filegroup' + WHEN 'G' then 'Differential file' + WHEN 'P' then 'Partial' + WHEN 'Q' then 'Differential partial' END + , BackupDate = MAX(backup_start_date) + from msdb.dbo.backupset bs + group by Database_name, type + UNION + select distinct + db_name(d.database_id) + , backuptype = 'Database' + , null + FROM master.sys.databases d + UNION + select distinct + db_name(d.database_id) + , backuptype = 'Transaction Log' + , null + FROM master.sys.databases d + where d.recovery_model_desc in ('FULL', 'BULK_LOGGED') + + ) a + on db_name(d.database_id) = a.database_name + WHERE backuptype = 'transaction log' + group by database_name, backuptype, d.recovery_model_desc, d.state_desc +) x +group by backuptype, recovery_model_desc +order by backuptype, recovery_model_desc + +GO + +select + database_Name + , backuptype + , d.recovery_model_desc + , BackupDate = MAX(BackupDate) + , d.state_desc + from sys.databases d + inner join + ( +select distinct + database_name + , backuptype = case type WHEN 'D' then 'Database' + WHEN 'I' then 'Differential database' + WHEN 'L' then 'Transaction Log' + WHEN 'F' then 'File or filegroup' + WHEN 'G' then 'Differential file' + WHEN 'P' then 'Partial' + WHEN 'Q' then 'Differential partial' END + , BackupDate = MAX(backup_start_date) + from msdb.dbo.backupset bs + group by Database_name, type + UNION + select distinct + db_name(d.database_id) + , backuptype = 'Database' + , null + FROM master.sys.databases d + UNION + select distinct + db_name(d.database_id) + , backuptype = 'Transaction Log' + , null + FROM master.sys.databases d + where d.recovery_model_desc in ('FULL', 'BULK_LOGGED') + + ) a + on db_name(d.database_id) = a.database_name + --WHERE backuptype = 'transaction log' + group by database_name, backuptype, d.recovery_model_desc, d.state_desc \ No newline at end of file diff --git a/backup history.sql b/backup history.sql new file mode 100644 index 0000000..15a882d --- /dev/null +++ b/backup history.sql @@ -0,0 +1,146 @@ +use master +go +--sql2005 and above +select + a.database_name + , a.backuptype + , d.recovery_model_desc + , LatestBackupDate = max(a.BackupFinishDate) + , LatestBackupStartDate = max(a.BackupStartDate) + , LatestBackupLocation = max(a.physical_device_name) + , d.state_desc + from sys.databases d + inner join ( select * from ( + select + database_name + , backuptype = case type WHEN 'D' then 'Database' + WHEN 'I' then 'Differential database' + WHEN 'L' then 'Transaction Log' + WHEN 'F' then 'File or filegroup' + WHEN 'G' then 'Differential file' + WHEN 'P' then 'Partial' + WHEN 'Q' then 'Differential partial' END + , BackupFinishDate = bs.backup_finish_date + , BackupStartDate = bs.backup_start_date + , physical_device_name + , latest = Row_number() OVER (PARTITION BY database_name, type order by backup_finish_date desc) + from msdb.dbo.backupset bs + left outer join msdb.dbo.[backupmediafamily] bf + on bs.[media_set_id] = bf.[media_set_id] + WHERE backup_finish_date is not null + ) x + where latest = 1 + UNION + select + db_name(d.database_id) + , backuptype = 'Database' + , null, null, null, null + FROM master.sys.databases d + group by db_name(d.database_id) + UNION + select + db_name(d.database_id) + , backuptype = 'Transaction Log' + , null, null, null, null + FROM master.sys.databases d + where d.recovery_model_desc in ('FULL', 'BULK_LOGGED') + group by db_name(d.database_id) + ) a + on db_name(d.database_id) = a.database_name + WHERE a.database_name not in ('tempdb') +group by + a.database_name + , a.backuptype + , d.recovery_model_desc + , d.state_desc +order by a.backuptype, d.recovery_model_desc, max(a.BackupFinishDate) asc, a.database_name asc + + go + + + /* + + + select d.name, Latest_Restore = max(restore_date) + from sys.databases d + LEFT OUTER JOIN msdb.dbo.restorehistory rh on d.name = rh.destination_database_name + group by d.name + order by Latest_Restore desc + + --sql 2000 and above +select distinct + database_name = d.name + , a.backuptype + , RecoveryModel = databasepropertyex(d.name, 'Recovery') + , BackupDate = Max(a.backup_finish_date) + from master.dbo.sysdatabases d + left outer join + ( select distinct + database_name + , backuptype = case type WHEN 'D' then 'Database' + WHEN 'I' then 'Differential database' + WHEN 'L' then 'Transaction Log' + WHEN 'F' then 'File or filegroup' + WHEN 'G' then 'Differential file' + WHEN 'P' then 'Partial' + WHEN 'Q' then 'Differential partial' END + , backup_finish_date = MAX(backup_finish_date) + from msdb.dbo.backupset bs + group by Database_name, type + UNION + select distinct + d.name + , backuptype = 'Database' + , null + FROM master.dbo.sysdatabases d + UNION + select distinct + d.name + , backuptype = 'Transaction Log' + , null + FROM master.dbo.sysdatabases d + where databasepropertyex(d.name, 'Recovery') in ('FULL', 'BULK_LOGGED') + + ) a + on d.name = a.database_name + group by d.name , backuptype , databasepropertyex(d.name, 'Recovery') +order by backuptype, RecoveryModel, BackupDate asc + */ + + /* +--granular backup history +SELECT + database_name + , type + , backuptype = CASE bs.type WHEN 'D' then 'Database' + WHEN 'I' then 'Differential database' + WHEN 'L' then 'Transaction Log' + WHEN 'F' then 'File or filegroup' + WHEN 'G' then 'Differential file' + WHEN 'P' then 'Partial' + WHEN 'Q' then 'Differential partial' END + , BackupDate = backup_finish_date + , database_backup_lsn + , bf.physical_device_name + , begins_log_chain + , backup_size_mb = bs.backup_size / 1024./1024. + , compressed_backup_size_mb = bs.compressed_backup_size /1024./1024. + , bs.is_copy_only + , bs.recovery_model + FROM msdb.dbo.backupset bs + LEFT OUTER JOIN msdb.dbo.[backupmediafamily] bf + on bs.[media_set_id] = bf.[media_set_id] + where database_name = 'SP2010_UserProfile_Sync' + ORDER BY bs.database_name asc, BackupDate desc; + + select convert(Date, backup_finish_date), SizeGB = sum(compressed_backup_size)/1024./1024./1024. + from msdb.dbo.backupset bs + left outer join msdb.dbo.[backupmediafamily] bf + on bs.[media_set_id] = bf.[media_set_id] + where 1=1 + and datepart(dw, backup_finish_date) = 1 + group by convert(Date, backup_finish_date) + order by convert(Date, backup_finish_date) desc + + +*/ \ No newline at end of file diff --git a/backup restore progress.sql b/backup restore progress.sql new file mode 100644 index 0000000..ac70bb9 --- /dev/null +++ b/backup restore progress.sql @@ -0,0 +1,14 @@ +SELECT command, + s.text, + start_time, + percent_complete, + CAST(((DATEDIFF(s,start_time,GetDate()))/3600) as varchar) + ' hour(s), ' + + CAST((DATEDIFF(s,start_time,GetDate())%3600)/60 as varchar) + 'min, ' + + CAST((DATEDIFF(s,start_time,GetDate())%60) as varchar) + ' sec' as running_time, + CAST((estimated_completion_time/3600000) as varchar) + ' hour(s), ' + + CAST((estimated_completion_time %3600000)/60000 as varchar) + 'min, ' + + CAST((estimated_completion_time %60000)/1000 as varchar) + ' sec' as est_time_to_go, + dateadd(second,estimated_completion_time/1000, getdate()) as est_completion_time +FROM sys.dm_exec_requests r +CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) s +WHERE r.command like 'RESTORE%' or r.command like 'BACKUP%' \ No newline at end of file diff --git a/busy databases.sql b/busy databases.sql new file mode 100644 index 0000000..0e869f4 --- /dev/null +++ b/busy databases.sql @@ -0,0 +1,16 @@ +--Most resource intensive database + + +Select DatabaseName = db_name(st.dbid) +, TotalIO = sum(qs.total_logical_reads + qs.total_logical_writes) +, TotalCPU = sum(qs.total_worker_time) +, TotalQueryDuration= sum(qs.total_elapsed_time) +, TotalReads = sum(qs.total_logical_reads) +, TotalWrites = sum(qs.total_logical_writes) +, OldestCachedPlan = min(creation_time) +--select * +FROM sys.dm_exec_query_stats qs +Cross apply sys.dm_exec_sql_text (qs.plan_handle) st +where st.dbid <> 32767 +Group by db_name (st.dbid) +Order by TotalIO desc \ No newline at end of file diff --git a/cached exec plans.sql b/cached exec plans.sql new file mode 100644 index 0000000..bc1b470 --- /dev/null +++ b/cached exec plans.sql @@ -0,0 +1,26 @@ +select + eqp.query_plan +, o.name +, DBName = DB_NAME(eps.database_id) +, eps.TYPE_desc +, cached_time +, last_execution_time, execution_count +, total_worker_time, last_worker_time, min_worker_time, max_worker_time +, total_physical_reads, last_physical_reads, min_physical_reads, max_physical_reads +, total_logical_writes, last_logical_writes, min_logical_writes, max_logical_writes +, total_logical_reads, last_logical_reads, min_logical_reads, max_logical_reads +, total_elapsed_time, last_elapsed_time, min_elapsed_time, max_elapsed_time +, 'DBCC FREEPROCCACHE('+convert(varchar(max),plan_handle,1)+')' as DeleteQueryPlan --delete just this plan +, st.text +from sys.objects o +LEFT OUTER JOIN sys.dm_exec_procedure_stats eps on eps.object_id = o.object_id +CROSS APPLY sys.dm_exec_query_plan (eps.plan_handle) eqp +CROSS APPLY sys.dm_exec_sql_text(plan_handle) st +where 1=1 +and eps.database_id = db_id() +and last_execution_time >= '2014-09-29' +and st.text like '%[dbo].[pt_time_time_entry]%' + +--order by total_worker_time/execution_count desc +order by cached_time desc + diff --git a/checksum vs hashbytes.sql b/checksum vs hashbytes.sql new file mode 100644 index 0000000..ede450f --- /dev/null +++ b/checksum vs hashbytes.sql @@ -0,0 +1,20 @@ +--same +Select CHECKSUM('sha2_512','Sparkhound') +Select CHECKSUM('sha2_512','AAAAAAAAAAAAAAAASparkhound') + +--same +Select BINARY_CHECKSUM('sha2_512','Sparkhound') +Select BINARY_CHECKSUM('sha2_512','AAAAAAAAAAAAAAAASparkhound') + +--same +select CHECKSUM('aaaa') +select CHECKSUM('aaaaaaaaaaaaaaaaaaaa') + +--not the same +select HASHBYTES('SHA2_512', N'aaaa') +select HASHBYTES('SHA2_512', N'aaaaaaaaaaaaaaaaaaaa') + +--not the same +Select HASHBYTES('sha2_512','Sparkhound') +Select HASHBYTES('sha2_512','AAAAAAAAAAAAAAAASparkhound') + diff --git a/collect connections.sql b/collect connections.sql new file mode 100644 index 0000000..b74b766 --- /dev/null +++ b/collect connections.sql @@ -0,0 +1,70 @@ + /* + +USE [DBAHound] +GO +DROP TABLE [dbo].[ExecRequests_connections] +GO +CREATE TABLE [dbo].[ExecRequests_connections]( + id int not null IDENTITY(1,1), + [login_name] [nvarchar](128) NOT NULL, + [client_interface_name] [nvarchar](32) NULL, + [host_name] [nvarchar](128) NULL, + [nt_domain] [nvarchar](128) NULL, + [nt_user_name] [nvarchar](128) NULL, + [endpoint_name] [sysname] NULL, + [program_name] [nvarchar](128) NULL, + [observed_count] bigint NOT NULL CONSTRAINT DF_ExecRequests_connections_observed_count DEFAULT(0), +CONSTRAINT pk_execrequests_connections_id PRIMARY KEY (ID) +) ON [PRIMARY] +CREATE INDEX idx_execrequests_connections ON execrequests_connections (login_name, client_interface_name, [host_name], nt_domain, nt_user_name, endpoint_name, [program_name]) +GO + + +*/ + + insert into dbo.ExecRequests_connections ( + login_name, client_interface_name, [host_name], nt_domain, nt_user_name, [program_name], endpoint_name + ) + select + LEFT(s.login_name, 128), LEFT(s.client_interface_name, 128), LEFT(s.[host_name], 128), LEFT(s.nt_domain, 128), LEFT(s.nt_user_name, 128), LEFT(s.[program_name], 128), e.name + from sys.dm_exec_sessions s + left outer join sys.endpoints E ON E.endpoint_id = s.endpoint_id + left outer join dbo.ExecRequests_connections erc + on + erc.login_name = LEFT(s.login_name, 128) + and erc.client_interface_name = LEFT(s.client_interface_name, 128) + and erc.[host_name] = LEFT(s.[host_name], 128) + and erc.nt_domain = LEFT(s.nt_domain, 128) + and erc.nt_user_name = LEFT(s.nt_user_name, 128) + and erc.[program_name] = LEFT(s.[program_name], 128) + and erc.endpoint_name = e.name + where + s.session_id >= 50 --retrieve only user spids + and s.session_id <> @@SPID --ignore myself + and erc.id is null + GROUP BY LEFT(s.login_name, 128), LEFT(s.client_interface_name, 128), LEFT(s.[host_name], 128), LEFT(s.nt_domain, 128), LEFT(s.nt_user_name, 128), LEFT(s.[program_name], 128), e.name + + + GO + + UPDATE erc + SET observed_count = observed_count + s.session_id_count + FROM dbo.ExecRequests_connections erc + inner join (select s.login_name, s.client_interface_name, s.[host_name], s.nt_domain, s.nt_user_name, s.[program_name], s.endpoint_id, session_id_count = count(session_id) from sys.dm_exec_sessions s + where + s.session_id >= 50 --retrieve only user spids + and s.session_id <> @@SPID --ignore myself + GROUP BY s.login_name, s.client_interface_name, s.[host_name], s.nt_domain, s.nt_user_name, s.[program_name], s.endpoint_id + ) s + on + erc.login_name = LEFT(s.login_name, 128) + and erc.client_interface_name = LEFT(s.client_interface_name, 128) + and erc.[host_name] = LEFT(s.[host_name], 128) + and erc.nt_domain = LEFT(s.nt_domain, 128) + and erc.nt_user_name = LEFT(s.nt_user_name, 128) + and erc.[program_name] = LEFT(s.[program_name], 128) + left outer join sys.endpoints e + ON E.endpoint_id = s.endpoint_id + and erc.endpoint_name = e.name + +--select * from dbo.ExecRequests_connections erc \ No newline at end of file diff --git a/compress indexes.sql b/compress indexes.sql new file mode 100644 index 0000000..7b97521 --- /dev/null +++ b/compress indexes.sql @@ -0,0 +1,23 @@ +--Index/partitions in current database +select SizeMb= (p.in_row_reserved_page_count*8.)/1024. +, indexname = i.name +, tablename = '[' + s.name + '].[' + o.name + ']' +, pr.data_compression_desc +, p.partition_number +, rebuildcompress = +CASE WHEN pr.data_compression_desc = 'columnstore' THEN NULL ELSE + 'ALTER INDEX [' + i.name + '] ON [' + s.name + '].[' + o.name + '] REBUILD ' + + CASE WHEN MAX(p.partition_number) OVER (PARTITION by i.name) > 1 THEN + 'PARTITION = ' + cast(p.partition_number as varchar(5)) ELSE '' END + + ' WITH (SORT_IN_TEMPDB = ON + , DATA_COMPRESSION = PAGE) ' + CHAR(10) + CHAR(13) +END +, * +from sys.dm_db_partition_stats p +inner join sys.partitions pr on p.partition_id = pr.partition_id +inner join sys.objects o on p.object_id = o.object_id +inner join sys.schemas s on s.schema_id = o.schema_id +left outer join sys.indexes i on i.object_id = o.object_id and i.index_id = p.index_id +WHERE o.is_ms_shipped = 0 + +order by SizeMb desc diff --git a/configuration changes history.sql b/configuration changes history.sql new file mode 100644 index 0000000..22b909c --- /dev/null +++ b/configuration changes history.sql @@ -0,0 +1,73 @@ +--Based on the configuration changes history report in SSMS +exec sp_executesql @stmt=N'begin try +declare @enable int; +select @enable = convert(int,value_in_use) from sys.configurations where name = ''default trace enabled'' +if @enable = 1 --default trace is enabled +begin + declare @d1 datetime; + declare @diff int; + declare @curr_tracefilename varchar(500); + declare @base_tracefilename varchar(500); + declare @indx int ; + declare @temp_trace table ( + textdata nvarchar(MAX) collate database_default + , login_name sysname collate database_default + , start_time datetime + , event_class int + ); + + select @curr_tracefilename = path from sys.traces where is_default = 1 ; + + set @curr_tracefilename = reverse(@curr_tracefilename) + select @indx = PATINDEX(''%\%'', @curr_tracefilename) + set @curr_tracefilename = reverse(@curr_tracefilename) + set @base_tracefilename = LEFT( @curr_tracefilename,len(@curr_tracefilename) - @indx) + ''\log.trc''; + + insert into @temp_trace + select TextData + , LoginName + , StartTime + , EventClass + from ::fn_trace_gettable( @base_tracefilename, default ) + where ((EventClass = 22 and Error = 15457) or (EventClass = 116 and TextData like ''%TRACEO%(%'')) + + select @d1 = min(start_time) from @temp_trace + + --set @diff= datediff(hh,@d1,getdate()) + --set @diff=@diff/24; + + select --(row_number() over (order by start_time desc))%2 as l1 + @d1 as TraceStartDate + , start_time as EventDate + , case event_class + when 116 then ''Trace Flag '' + substring(textdata,patindex(''%(%'',textdata),len(textdata) - patindex(''%(%'',textdata) + 1) + when 22 then substring(textdata,58,patindex(''%changed from%'',textdata)-60) + end as config_option + , login_name + , case event_class + when 116 then ''--'' + when 22 then substring(substring(textdata,patindex(''%changed from%'',textdata),len(textdata) - patindex(''%changed from%'',textdata)) + ,patindex(''%changed from%'',substring(textdata,patindex(''%changed from%'',textdata),len(textdata) - patindex(''%changed from%'',textdata)))+13 + ,patindex(''%to%'',substring(textdata,patindex(''%changed from%'',textdata),len(textdata) - patindex(''%changed from%'',textdata))) - patindex(''%from%'',substring(textdata,patindex(''%changed from%'',textdata),len(textdata) - patindex(''%changed from%'',textdata))) - 6) + end as old_value + , case event_class + when 116 then substring(textdata,patindex(''%TRACE%'',textdata)+5,patindex(''%(%'',textdata) - patindex(''%TRACE%'',textdata)-5) + when 22 then substring(substring(textdata,patindex(''%changed from%'',textdata),len(textdata) - patindex(''%changed from%'',textdata)) + ,patindex(''%to%'',substring(textdata,patindex(''%changed from%'',textdata),len(textdata) - patindex(''%changed from%'',textdata)))+3 + , patindex(''%. Run%'',substring(textdata,patindex(''%changed from%'',textdata),len(textdata) - patindex(''%changed from%'',textdata))) - patindex(''%to%'',substring(textdata,patindex(''%changed from%'',textdata),len(textdata) - patindex(''%changed from%'',textdata))) - 3) + end as new_value + from @temp_trace + order by start_time desc +end else +begin + select top 0 1 as l1, 1 as difference,1 as date , 1 as config_option,1 as start_time , 1 as login_name, 1 as old_value, 1 as new_value +end +end try +begin catch +select ERROR_NUMBER() as Error_Number +, ERROR_SEVERITY() as date +, ERROR_STATE() as config_option +, 1 as start_time +, ERROR_MESSAGE() as login_name +, 1 as old_value, 1 as new_value +end catch',@params=N'' \ No newline at end of file diff --git a/cpu utilization.sql b/cpu utilization.sql new file mode 100644 index 0000000..350e2d9 --- /dev/null +++ b/cpu utilization.sql @@ -0,0 +1,23 @@ +--http://sqlblog.com/blogs/ben_nevarez/archive/2009/07/26/getting-cpu-utilization-data-from-sql-server.aspx + +declare @ts_now bigint +--select @ts_now = cpu_ticks / convert(float, cpu_ticks_in_ms) from sys.dm_os_sys_info +select @ts_now = cpu_ticks / (cpu_ticks/ms_ticks) from sys.dm_os_sys_info; +select record_id + , EventTime = dateadd(ms, -1 * (@ts_now - [timestamp]), GetDate()) + , SQLProcessUtilization + , SystemIdle + , OtherProcessUtilization = 100 - SystemIdle - SQLProcessUtilization +from ( + select + record_id = record.value('(./Record/@id)[1]', 'int') + , SystemIdle = record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int') + , SQLProcessUtilization = record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int') + , timestamp + from ( + select timestamp, convert(xml, record) as record + from sys.dm_os_ring_buffers + where ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR' + and record like '%%') as x + ) as y +order by record_id desc \ No newline at end of file diff --git a/database mail diag.sql b/database mail diag.sql new file mode 100644 index 0000000..71b4818 --- /dev/null +++ b/database mail diag.sql @@ -0,0 +1,17 @@ +SELECT is_broker_enabled FROM sys.databases WHERE name = 'msdb' ; + +EXECUTE msdb.dbo.sysmail_help_status_sp ; +--EXECUTE msdb.dbo.sysmail_start_sp --start the database mail queues; + + +GO + +SELECT m.recipients, m.subject, m.body, + m.send_request_date, m.send_request_user, m.sent_status +FROM msdb.dbo.sysmail_allitems m +WHERE m.sent_status<>'sent' +--WHERE m.send_request_date > CURRENT_TIMESTAMP - 3 +--AND m.sent_status <> 'sent' +ORDER BY m.send_request_date DESC +GO + diff --git a/database ownership.sql b/database ownership.sql new file mode 100644 index 0000000..4096789 --- /dev/null +++ b/database ownership.sql @@ -0,0 +1,11 @@ +select + + database_name = d.name +, principal_name = SUSER_SNAME (d.owner_sid) +, set_to_sa = case when sp.name <> 'sa' THEN 'alter authorization on database::' + d.name + ' to sa' ELSE null END +, set_to_current = case when sp.name <> 'sa' THEN 'alter authorization on database::' + d.name + ' to [' + sp.name + ']' ELSE null END +, * +from sys.databases d +left outer join sys.server_principals sp +on d.owner_sid = sp.sid +--where sp.name <> 'sa' \ No newline at end of file diff --git a/database settings.sql b/database settings.sql new file mode 100644 index 0000000..5c413ef --- /dev/null +++ b/database settings.sql @@ -0,0 +1,13 @@ +select + name +, database_id +, [compatibility_level] --should be latest (130 = SQL2016, 120 = SQL2014, 110 = SQL2012, 100 = SQL2008, 90 = SQL2005) +, user_access_desc --should be MULTI_USER +, is_read_only +, is_auto_close_on --should be 0 +, is_auto_shrink_on --should be 0 +, is_auto_create_stats_on --should be 1 except for some SharePoint db's +, is_auto_update_stats_on --should be 1 except for some SharePoint db's +, state_desc +, recovery_model_Desc + from sys.databases \ No newline at end of file diff --git a/deadlock part 1.sql b/deadlock part 1.sql new file mode 100644 index 0000000..c90a228 --- /dev/null +++ b/deadlock part 1.sql @@ -0,0 +1,22 @@ +use w +go + +DROP TABLE dbo.dead +DROP TABLE dbo.lock +go +CREATE TABLE dbo.dead (col1 INT) +INSERT INTO dbo.dead SELECT 1 +CREATE TABLE dbo.lock (col1 INT) +INSERT INTO dbo.lock SELECT 1 + +BEGIN TRAN t1 +UPDATE dbo.dead WITH (TABLOCK) SET col1 = 2 +-- +UPDATE dbo.lock WITH (TABLOCK) SET col1 = 4 +COMMIT TRAN t1 +select SYSDATETIME() + + + + + diff --git a/deadlock part 2.sql b/deadlock part 2.sql new file mode 100644 index 0000000..b603a96 --- /dev/null +++ b/deadlock part 2.sql @@ -0,0 +1,6 @@ +USE w +go +BEGIN TRAN t2 +UPDATE dbo.lock WITH (TABLOCK) SET col1 = 3 +UPDATE dbo.dead WITH (TABLOCK) SET col1 = 3 +commit tran t2 \ No newline at end of file diff --git a/deadlocks in xevents.sql b/deadlocks in xevents.sql new file mode 100644 index 0000000..15fe4ab --- /dev/null +++ b/deadlocks in xevents.sql @@ -0,0 +1,105 @@ + + +declare @xml xml +select @xml = CAST(t.target_data as xml) +from sys.dm_xe_session_targets t +inner join sys.dm_xe_sessions s + on s.address = t.event_session_address + where s.name = 'system_health' + and t.target_name = 'ring_buffer' +select @xml.query('/RingBufferTarget/event [@name="xml_deadlock_report"]') +FOR XML PATH ('XEvent') + +go + + + +/* +--alternative version for SQL 2016 +--http://www.sqlservercentral.com/blogs/simple-sql-server/2016/01/25/querying-deadlocks-from-system_health-xevent/ + +DECLARE @SessionName SysName + +SELECT @SessionName = 'system_health' + +/* +SELECT Session_Name = s.name, s.blocked_event_fire_time, s.dropped_buffer_count, s.dropped_event_count, s.pending_buffers +FROM sys.dm_xe_session_targets t + INNER JOIN sys.dm_xe_sessions s ON s.address = t.event_session_address +WHERE target_name = 'event_file' +--*/ + +IF OBJECT_ID('tempdb..#Events') IS NOT NULL BEGIN + DROP TABLE #Events +END + +DECLARE @Target_File NVarChar(1000) + , @Target_Dir NVarChar(1000) + , @Target_File_WildCard NVarChar(1000) + +SELECT @Target_File = CAST(t.target_data as XML).value('EventFileTarget[1]/File[1]/@name', 'NVARCHAR(256)') +FROM sys.dm_xe_session_targets t + INNER JOIN sys.dm_xe_sessions s ON s.address = t.event_session_address +WHERE s.name = @SessionName + AND t.target_name = 'event_file' + +SELECT @Target_Dir = LEFT(@Target_File, Len(@Target_File) - CHARINDEX('\', REVERSE(@Target_File))) + +SELECT @Target_File_WildCard = @Target_Dir + '\' + @SessionName + '_*.xel' + +--Keep this as a separate table because it's called twice in the next query. You don't want this running twice. +SELECT DeadlockGraph = CAST(event_data AS XML) + , DeadlockID = Row_Number() OVER(ORDER BY file_name, file_offset) +INTO #Events +FROM sys.fn_xe_file_target_read_file(@Target_File_WildCard, null, null, null) AS F +WHERE event_data like ' 4 THEN ''use [?]; REVOKE CONNECT TO GUEST;'' END +, * +FROM [?].sys.database_principals AS prins +INNER JOIN [?].sys.database_permissions AS perms +ON perms.grantee_principal_id = prins.principal_id +WHERE prins.name = ''guest'' +AND state_desc = ''GRANT'' + +' diff --git a/hekaton lab.sql b/hekaton lab.sql new file mode 100644 index 0000000..8246df2 --- /dev/null +++ b/hekaton lab.sql @@ -0,0 +1,99 @@ +USE w +GO + +--Add MEMORY_OPTIMIZED_DATA filegroup to the database. +ALTER DATABASE w +ADD FILEGROUP PRIMARY_HEKATON CONTAINS MEMORY_OPTIMIZED_DATA + +--Add file to the MEMORY_OPTIMIZED_DATA filegroup. +ALTER DATABASE w +ADD FILE + ( NAME = PRIMARY_HEKATON_1, + FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL12.SQL2K14\MSSQL\DATA\PRIMARY_HEKATON_1.mdf') +TO FILEGROUP PRIMARY_HEKATON +go +if exists (select * from sys.objects where name = 'hekaton_table_test') +drop table hekaton_table_test +go +if exists (select * from sys.objects where name = 'hekaton_table_test_2') +drop table hekaton_table_test_2 +go + +--Create memory optimized table and indexes on the memory optimized table. +CREATE TABLE dbo.hekaton_table_test +( id int not null identity(1,1) +, text1 nvarchar(10) COLLATE Latin1_General_100_BIN2 not null +, CONSTRAINT PK_hekaton_table_test PRIMARY KEY NONCLUSTERED (id) +, INDEX IDX_HASH_hekaton_table_test_text1 HASH (id) WITH (BUCKET_COUNT = 8388608) --pick a power of 2 greater than, 8x the number of expected unique keys +) WITH (MEMORY_OPTIMIZED = ON, DURABILITY = SCHEMA_AND_DATA) +go + +--Create memory optimized table and indexes on the memory optimized table. +CREATE TABLE dbo.hekaton_table_test_2 +( id int not null identity(1,1) +, text1 nvarchar(10) COLLATE Latin1_General_100_BIN2 not null +, CONSTRAINT PK_hekaton_table_test_2 PRIMARY KEY NONCLUSTERED (id) +, INDEX IDX_HASH_hekaton_table_test_2_text1 HASH (text1) WITH (BUCKET_COUNT = 8388608) --pick a power of 2 greater than, 8x the number of expected unique keys +) WITH (MEMORY_OPTIMIZED = ON, DURABILITY = SCHEMA_AND_DATA) +go + +insert into hekaton_table_test (text1) +values (replicate(char(round(rand()*100+50,0)),round(rand()*10,0))) +go +declare @x int = 1 +while @x <= 20 +begin +insert into hekaton_table_test (text1) +select replicate(char(round(rand()*100+50,0)),round(rand()*10,0)) from hekaton_table_test +select @x = @x +1 +END +go +insert into hekaton_table_test_2 (text1) +select text1 from hekaton_table_test +go +select count(1) from hekaton_table_test +go +select count(1) from hekaton_table_test_2 + +select * from hekaton_table_test_2 order by id asc + +select + DBName = db_name(mf.database_id) +, mf.name +, mf.physical_name +, cf.file_type_desc +, FileCount = count(checkpoint_file_id) +, Total_Size_mb = sum(file_size_in_bytes)/1024/1024 +, Used_Size_mb = sum(isnull(file_size_used_in_bytes,0)) /1024/1024 +, Total_inserted_row_count = sum(isnull(inserted_row_count,0)) +, Total_deleted_row_count = sum(isnull(deleted_row_count,0)) +from sys.dm_db_xtp_checkpoint_files cf +inner join sys.master_files mf on cf.container_id = mf.file_id +group by db_name(mf.database_id), mf.name, mf.physical_name, cf.file_type_desc + +select + Name = object_name (tms.object_id) +, memory_allocated_for_indexes_mb = tms.memory_allocated_for_indexes_kb/1024. +, memory_used_by_indexes_mb = tms.memory_used_by_indexes_kb/1024. +, memory_allocated_for_table_mb = tms.memory_allocated_for_table_kb/1024. +, memory_used_by_table_mb = tms.memory_used_by_table_kb/1024. +from sys.dm_db_xtp_table_memory_stats tms +where object_id > 0 --ignore system objects + +select + Name = object_name (mc.object_id) +, sum(allocated_bytes)/1024./1024. as total_allocated_mb +, sum(used_bytes)/1024./1024. as total_used_mb +from sys.dm_db_xtp_memory_consumers mc +where mc.object_id > 0 --ignore system objects +group by mc.object_id +order by mc.object_id + +select + name = object_name(his.object_id) +, total_bucket_count +, empty_bucket_count +, used_buckets = total_bucket_count - empty_bucket_count +, avg_chain_length --want these LOW +, max_chain_length --want these LOW +from sys.dm_db_xtp_hash_index_stats his \ No newline at end of file diff --git a/index_usage_stats.sql b/index_usage_stats.sql new file mode 100644 index 0000000..195a24b --- /dev/null +++ b/index_usage_stats.sql @@ -0,0 +1,42 @@ + + +SELECT [tSQL] = 'DROP INDEX [' + i.name + '] ON [' + sc.name + '].[' + o.name + ']' + , o.name + , IndexName = i.name + , s.user_seeks + , s.user_scans + , s.user_lookups + , s.user_updates + , ps.row_count + , SizeMb = (ps.in_row_reserved_page_count*8.)/1024. + , s.last_user_lookup + , s.last_user_scan + , s.last_user_seek + , s.last_user_update +FROM sys.dm_db_index_usage_stats s + INNER JOIN sys.indexes i + ON i.object_id = s.object_id + AND i.index_id = s.index_id + INNER JOIN sys.objects o + ON o.object_id=i.object_id + inner join sys.schemas sc + on sc.schema_id = o.schema_id + inner join sys.partitions pr + on pr.object_id = i.object_id + and pr.index_id = i.index_id + inner join sys.dm_db_partition_stats ps + on ps.object_id = i.object_id + and ps.partition_id = pr.partition_id +WHERE o.is_ms_shipped = 0 +--and o.type_desc = 'USER_TABLE' +and i.type_desc = 'NONCLUSTERED' +--and user_updates / 5. > (user_seeks + user_scans + user_lookups ) +--and o.name in ('ContactBase') +--and o.name not like '%cascade%' +--order by [OBJECT NAME] +and is_unique = 0 +and is_primary_key = 0 +and is_unique_constraint = 0 +--and (ps.in_row_reserved_page_count) > 1280 --10mb +order by user_seeks + user_scans + user_lookups asc, s.user_updates desc + diff --git a/instant_file_initialization.sql b/instant_file_initialization.sql new file mode 100644 index 0000000..37f9596 --- /dev/null +++ b/instant_file_initialization.sql @@ -0,0 +1,4 @@ +--Check to see if the SQL Server Database Engine service has instant_file_initialization_enabled. +select servicename, instant_file_initialization_enabled +from sys.dm_server_services +where filename like '%sqlservr.exe%' \ No newline at end of file diff --git a/job owners.sql b/job owners.sql new file mode 100644 index 0000000..b31e529 --- /dev/null +++ b/job owners.sql @@ -0,0 +1,21 @@ +use msdb +go +--TODO Change @owner_login_name to desired SQL agent service account to own the job + +--sql 2005 and above +select owner = sp.name, jobname = j.name, j.job_id +, change_tsql = N'EXEC msdb.dbo.sp_update_job @job_id=N'''+convert(nvarchar(100), j.job_id)+N''', @owner_login_name=N''domain\sqlsvcacct''' +, revert_tsql = N'EXEC msdb.dbo.sp_update_job @job_id=N'''+convert(nvarchar(100), j.job_id)+N''', @owner_login_name=N'''+sp.name+'''' +from sysjobs j +left outer join sys.server_principals sp on j.owner_sid = sp.sid +where sp.name not in ('sa','distributor_admin','domain\sqlsvcacct') or sp.name is null +--EXEC msdb.dbo.sp_update_job @job_id=N'd5722a5c-d7cf-4332-8af9-d5839257cb4b', @owner_login_name=N'sa' + +/* +--sql 2000 +select sp.name, j.name, j.job_id from msdb.dbo.sysjobs j +left outer join master.dbo.syslogins sp on j.owner_sid = sp.sid +where sp.name not in ('sa','distributor_admin') or sp.name is null +--EXEC msdb.dbo.sp_update_job @job_id=N'8eab379e-958e-4576-92ae-b5999aeec01c', @owner_login_name=N'distributor_admin' +*/ + diff --git a/kill detect blocking sessions setup.sql b/kill detect blocking sessions setup.sql new file mode 100644 index 0000000..5ae6033 --- /dev/null +++ b/kill detect blocking sessions setup.sql @@ -0,0 +1,42 @@ +use dbalogging +go +--setup kill detect blocking sessions +--drop table dbo.ExecRequestsLog +go +create table dbo.ExecRequestsLog ( + id int IDENTITY(1,1) not null PRIMARY KEY + , timecaptured datetime + , session_id smallint not null + , request_id int null + , blocking_session_id int null + , blocking_these varchar(1000) NULL + , request_start_time datetime null + , login_time datetime not null + , login_name nvarchar(256) null + , client_interface_name nvarchar(64) + , session_status nvarchar(60) null + , request_status nvarchar(60) null + , command nvarchar(32) null + , sql_handle varbinary(64) null + , statement_start_offset int null + , statement_end_offset int null + , plan_handle varbinary (64) null + , database_id smallint null + , user_id int null + , wait_type nvarchar (120) null + , wait_time_s int null + , wait_resource nvarchar(120) null + , last_wait_type nvarchar(120) null + , cpu_time_s int null + , tot_time_s int null + , reads bigint null + , writes bigint null + , logical_reads bigint null + , [host_name] nvarchar(256) null + , [program_name] nvarchar(256) null + , percent_complete int null + , session_transaction_isolation_level varchar(20) null + , request_transaction_isolation_level varchar(20) null + , offsettext nvarchar(4000) null + , kill_text nvarchar(100) null + ) diff --git a/kill detect blocking spids job.sql b/kill detect blocking spids job.sql new file mode 100644 index 0000000..1f6373d Binary files /dev/null and b/kill detect blocking spids job.sql differ diff --git a/kill detect blocking spids.sql b/kill detect blocking spids.sql new file mode 100644 index 0000000..729bfde --- /dev/null +++ b/kill detect blocking spids.sql @@ -0,0 +1,134 @@ +use DBALogging +go +ALTER PROCEDURE dbo.killblockingsessions +AS +SET NOCOUNT OFF + + /* Kill Blocking Sessions + This procedure is intended to be run regularly against a SQL Server to detect and kill sessions that + 1) have been running >5 minutes + 2) are blocking other sessions + The procedure kills the most-blocking and longest-running session (in that order) each time it runs. + The SQL Job that executes this sproc is Kill Blocking Sessions + By default, this sproc cleans up old records older than 3 months. + Activity is logged to the table dbalogging.dbo.ExecRequestsLog + + First implemented 20150129 William Assaf, Sparkhound + */ + + --Detect blocking spids + declare @blockingspids table + (blocking_session_id int not null, blocking_len int not null, blocked_request_start_time date null) + + insert into @blockingspids (blocking_session_id, blocking_len, blocked_request_start_time) + select r.blocking_session_id, blocking_len = count(distinct s.session_id), blocked_request_start_time = max(r.start_time) + from + sys.dm_exec_sessions s left outer join + sys.dm_exec_requests r on s.session_id = r.session_id + inner join + sys.dm_exec_sessions s2 on r.blocking_session_id = s2.session_id + left outer join + sys.dm_exec_requests r2 on s2.session_id = r2.session_id + where 1=1 + and r.session_id >= 50 --retrieve only user spids + and s2.session_id >= 50 --retrieve only user spids + and r.session_id <> @@SPID --ignore myself + and s2.session_id <> @@SPID --ignore myself + and r.blocking_session_id is not null + and (datediff(SECOND, r2.start_time, getdate()) > 30 -- five minutes + or datediff(SECOND, r.start_time, getdate()) > 30 -- five minutes + ) + --Next line is specifically for D'Addario on 99-SQL2012 + and (s2.program_name = 'Microsoft Office 2010' or s2.program_name like 'SQLAgent%') + + group by r.blocking_session_id + + + IF EXISTS ( select * from @blockingspids b where blocking_session_id > 0 ) + BEGIN + declare @blocking_session_id int = null, @str nvarchar(100) = null + + --select 'before', * from @blockingspids b + + select top 1 @blocking_session_id = b.blocking_session_id + from @blockingspids b where blocking_session_id > 0 + order by blocking_len desc --kill the root blocker first\ + , blocked_request_start_time asc + + SELECT @str=N'KILL '+CONVERT(nvarchar(10),@blocking_session_id ) + + declare @when datetime = getdate(); + + insert into dbalogging.dbo.ExecRequestsLog (timecaptured, blocking_session_id,session_id,request_id, request_start_time, login_time, login_name, client_interface_name, session_status, request_status, command,sql_handle,statement_start_offset,statement_end_offset,plan_handle,database_id,user_id,wait_type,last_wait_type,wait_time_s,wait_resource,cpu_time_s,tot_time_s,reads,writes,logical_reads,[host_name], [program_name] , session_transaction_isolation_level , request_transaction_isolation_level , offsettext) + select timecaptured = @when, blocking_session_id,s.session_id,request_id, r.start_time, s.login_time, s.login_name, s.client_interface_name, s.status, r.status,command,r.sql_handle,r.statement_start_offset,r.statement_end_offset,r.plan_handle,r.database_id,user_id,wait_type,r.last_wait_type, r.wait_time/1000.,r.wait_resource ,r.cpu_time/1000.,r.total_elapsed_time/1000.,r.reads,r.writes,r.logical_reads,s.[host_name], s.[program_name], s.transaction_isolation_level, r.transaction_isolation_level + , offsettext = CASE WHEN r.statement_start_offset = 0 and r.statement_end_offset= 0 THEN NULL + ELSE SUBSTRING ( est.[text] + , r.statement_start_offset/2 + 1, + CASE WHEN r.statement_end_offset = -1 THEN LEN (CONVERT(nvarchar(max), est.[text])) + ELSE r.statement_end_offset/2 - r.statement_start_offset/2 + 1 + END ) + END + + from sys.dm_exec_sessions s + left outer join sys.dm_exec_requests r on r.session_id = s.session_id + LEFT OUTER JOIN sys.dm_exec_cached_plans p ON p.plan_handle = r.plan_handle + OUTER APPLY sys.dm_exec_query_plan (r.plan_handle) qp + OUTER APPLY sys.dm_exec_sql_text (r.sql_handle) est + LEFT OUTER JOIN sys.dm_exec_query_stats stat on stat.plan_handle = r.plan_handle + and r.statement_start_offset = stat.statement_start_offset + and r.statement_end_offset = stat.statement_end_offset + where 1=1 + and s.session_id >= 50 --retrieve only user spids + and s.session_id <> @@SPID --ignore myself + + update r + set blocking_these = LEFT((select isnull(convert(varchar(5), er.session_id),'') + ', ' + from dbalogging.dbo.ExecRequestsLog er + where er.blocking_session_id = isnull(r.session_id ,0) + and er.blocking_session_id <> 0 + and timecaptured = @when + FOR XML PATH('') + ),1000) + FROM dbalogging.dbo.ExecRequestsLog r + WHERE blocking_these IS NULL + and timecaptured = @when + + update r + set kill_text = @str + FROM dbalogging.dbo.ExecRequestsLog r + where @blocking_session_id = session_id + and timecaptured = @when + + if @blocking_session_id is not null + BEGIN + PRINT @str + EXEC (@str) + + END + + update @blockingspids + set blocking_session_id = 0 + where blocking_session_id = @blocking_session_id + + set @blocking_session_id = null + + --select 'after', * from @blockingspids b + + --select * from dbalogging.dbo.ExecRequestsLog where timecaptured = @when + + END + + delete from dbalogging.dbo.ExecRequestsLog + where blocking_these is null and (blocking_session_id is null or blocking_session_id = 0) + + --Only do maintenance in the middle of the night + if (datepart(hour, getdate()) = 1) + BEGIN + + delete from dbalogging.dbo.ExecRequestsLog + where timecaptured < dateadd(month, -3, getdate()) + + END + +GO + diff --git a/missing index setup demo.sql b/missing index setup demo.sql new file mode 100644 index 0000000..a5136f7 --- /dev/null +++ b/missing index setup demo.sql @@ -0,0 +1,29 @@ + +USE [WideWorldImporters] +GO + +---------------- + +SELECT + c.CustomerName, c.PhoneNumber, cc.CustomerCategoryName +FROM +[Sales].[Customers] c +inner join sales.CustomerCategories cc +on cc.CustomerCategoryID = c.CustomerCategoryID +where c.CreditLimit > 1000 + + + + + + +/* + +CREATE NONCLUSTERED INDEX IDX_NC_Customers_CreditLimit ON [WideWorldImporters].[Sales].[Customers] ([CreditLimit]) INCLUDE ([CustomerName], [CustomerCategoryID], [DeliveryCityID], [PhoneNumber]) + +*/ + +/* + +DROP INDEX IDX_NC_Customers_CreditLimit ON [WideWorldImporters].[Sales].[Customers] +*/ \ No newline at end of file diff --git a/missing indexes.sql b/missing indexes.sql new file mode 100644 index 0000000..eed4b54 --- /dev/null +++ b/missing indexes.sql @@ -0,0 +1,42 @@ + +SELECT + mid.statement +, create_index_statement = 'CREATE NONCLUSTERED INDEX IDX_NC_' + replace(t.name, ' ' ,'') + + replace(replace(replace(ISNULL(replace(mid.equality_columns, ' ' ,''),'') , '],[' ,'_'),'[','_'),']','') + + replace(replace(replace(ISNULL(replace(mid.inequality_columns, ' ' ,''),''), '],[' ,'_'),'[','_'),']','') + + ' ON ' + statement + + ' (' + ISNULL (mid.equality_columns,'') + + CASE WHEN mid.equality_columns IS NOT NULL AND mid.inequality_columns IS NOT NULL THEN ',' ELSE '' END + + ISNULL (mid.inequality_columns, '') + + ')' + + ISNULL (' INCLUDE (' + mid.included_columns + ')', '') COLLATE SQL_Latin1_General_CP1_CI_AS +, unique_compiles, migs.user_seeks, migs.user_scans, last_user_seek, migs.avg_total_user_cost +, avg_user_impact, mid.equality_columns, mid.inequality_columns, mid.included_columns +, quartile +--select * +FROM sys.dm_db_missing_index_groups mig +INNER JOIN +(select *, quartile = NTILE(5) OVER (ORDER BY avg_total_user_cost asc) from sys.dm_db_missing_index_group_stats) migs +ON migs.group_handle = mig.index_group_handle +--and migs.quartile = 1 --get only the top 20% of suggestions based on cost. +INNER JOIN sys.dm_db_missing_index_details mid +ON mig.index_handle = mid.index_handle +inner join sys.tables t +on t.object_id = mid.object_id +inner join sys.schemas s +on s.schema_id = t.schema_id +WHERE 1=1 +and mid.database_id = db_id() +--and (datediff(week, last_user_seek, getdate())) < 1 +--AND migs.unique_compiles > 10 +--and migs.quartile >= 3 +--and migs.user_seeks > 10 +--and migs.avg_user_impact > 75 +--and t.name like '%pt_time_salesorder_ids%' +--order by avg_user_impact * avg_total_user_cost desc +order by create_index_statement + +/* + + +*/ \ No newline at end of file diff --git a/modules vs routines.sql b/modules vs routines.sql new file mode 100644 index 0000000..e192798 --- /dev/null +++ b/modules vs routines.sql @@ -0,0 +1,17 @@ +use [AdventureWorks2012] +go + +select s.name +'.' + o.name, o.type_desc, m.definition, LEN(m.definition) +from sys.sql_modules m +inner join sys.objects o on m.object_id = o.object_id +inner join sys.schemas s on s.schema_id = o.schema_id +where definition like '%switch%partition%' +order by o.name + +select r.SPECIFIC_SCHEMA + '.' + r.SPECIFIC_NAME, r.routine_type, r.ROUTINE_DEFINITION, LEN(routine_definition) +from INFORMATION_SCHEMA.routines r +where ROUTINE_DEFINITION like '%GroupName%' +order by ROUTINE_NAME + + + diff --git a/move system databases.sql b/move system databases.sql new file mode 100644 index 0000000..7f6d90f --- /dev/null +++ b/move system databases.sql @@ -0,0 +1,39 @@ + + +USE master; +GO +alter database msdb modify file ( NAME = MSDBData , FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\MSDBData.mdf') +go +alter database msdb modify file ( NAME = MSDBlog , FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\MSDBLog.ldf') +go +alter database model modify file ( NAME = modeldev, FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\model.mdf') +go +alter database model modify file ( NAME = modellog, FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\modellog.ldf') +go +ALTER DATABASE tempdb MODIFY FILE (NAME = tempdev, FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\tempdb.mdf'); +go +ALTER DATABASE tempdb MODIFY FILE (NAME = templog, FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\templog.ldf'); +go +alter database reportserver MODIFY file ( NAME = ReportServer , FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\ReportServer.mdf') +go +alter database reportserver MODIFY file ( NAME = ReportServer_log , FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\ReportServer_Log.ldf') +go +alter database ReportServerTempDB MODIFY file ( NAME = ReportServerTempDB , FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\ReportServerTempDB.mdf') +go +alter database ReportServerTempDB MODIFY file ( NAME = ReportServerTempDB_log , FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\ReportServerTempDB_log.LDF') +go +alter database SSISDB MODIFY file ( NAME = data , FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\SSISDB.mdf') +go +alter database SSISDB MODIFY file ( NAME = log , FILENAME = 'F:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\SSISDB.LDF') + +/* +master startup parameters + +--old +-dC:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\master.mdf;-eC:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\Log\ERRORLOG;-lC:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\mastlog.ldf + +--new +-dF:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\master.mdf;-eC:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\Log\ERRORLOG;-lF:\Program Files\Microsoft SQL Server\MSSQL13.SQL2K16\MSSQL\data2\mastlog.ldf +*/ + +select name, physical_name, state_desc from sys.master_files \ No newline at end of file diff --git a/multiserver backup history.sql b/multiserver backup history.sql new file mode 100644 index 0000000..b6b28e0 --- /dev/null +++ b/multiserver backup history.sql @@ -0,0 +1,43 @@ +--sql2005 and above +select + database_Name + , backuptype + , d.recovery_model_desc + , BackupDate = MAX(BackupDate) + from sys.databases d + inner join + ( +select distinct + database_name + , backuptype = case type WHEN 'D' then 'Database' + WHEN 'I' then 'Differential database' + WHEN 'L' then 'Transaction Log' + WHEN 'F' then 'File or filegroup' + WHEN 'G' then 'Differential file' + WHEN 'P' then 'Partial' + WHEN 'Q' then 'Differential partial' END + , BackupDate = MAX(backup_finish_date) + from msdb.dbo.backupset bs + group by Database_name, type + UNION + select distinct + db_name(d.database_id) + , backuptype = 'Database' + , null + FROM master.sys.databases d + UNION + select distinct + db_name(d.database_id) + , backuptype = 'Transaction Log' + , null + FROM master.sys.databases d + where d.recovery_model_desc in ('FULL', 'BULK_LOGGED') + + ) a + on db_name(d.database_id) = a.database_name + where database_name not in ('model','tempdb') + group by database_name, backuptype, d.recovery_model_desc + having ( (max(backupdate) <= dateadd(day,-1,getdate()) and (max(backupdate) >= dateadd(month, -1, getdate())) ) or max(backupdate) is null) +order by backuptype, recovery_model_desc, database_name asc + + go \ No newline at end of file diff --git a/multiserver space in files.sql b/multiserver space in files.sql new file mode 100644 index 0000000..2907c10 --- /dev/null +++ b/multiserver space in files.sql @@ -0,0 +1,25 @@ +use master +go +exec sp_MSforeachdb 'use [?]; +select * from ( +SELECT + ''DatabaseName_____________'' = d.name +, Recovery = d.recovery_model_desc +, ''DatabaseFileName_______'' = df.name +, ''Location_______________________________________________________________________'' = df.physical_name +, df.File_ID +, FileSizeMB = CAST(size/128.0 as Decimal(9,2)) +, SpaceUsedMB = CAST(CAST(FILEPROPERTY(df.name, ''SpaceUsed'') AS int)/128.0 as Decimal(9,2)) +, AvailableMB = CAST(size/128.0 - CAST(FILEPROPERTY(df.name, ''SpaceUsed'') AS int)/128.0 as Decimal(9,2)) +, ''Free%'' = CAST((((size/128.0) - (CAST(FILEPROPERTY(df.name, ''SpaceUsed'') AS int)/128.0)) / NULLIF(size/128.0, 0) ) * 100. as Decimal(9,2)) + FROM sys.database_files df + cross apply sys.databases d + where d.database_id = DB_ID() + and size > 0 + and d.name not like ''%test%'' + ) x + where [Free%] <= 10. + and filesizemb > 500. + and availableMB < 500. + +' \ No newline at end of file diff --git a/my_permissions.sql b/my_permissions.sql new file mode 100644 index 0000000..3d84f42 --- /dev/null +++ b/my_permissions.sql @@ -0,0 +1,9 @@ + +execute as login = 'whateverloginname' --login name you want to test +use Labor_Mobile_Labor +select * from sys.fn_my_permissions (null, 'DATABASE') --https://msdn.microsoft.com/en-us/library/ms176097.aspx +REVERT; --undo the execute as + +use Labor_Mobile_Labor +GRANT EXECUTE to whateverusername --granting database permissions here to user. Typically, this shares the same name as the Login, but not necessarily. + diff --git a/open transactions.sql b/open transactions.sql new file mode 100644 index 0000000..b75d4eb --- /dev/null +++ b/open transactions.sql @@ -0,0 +1,37 @@ +--http://www.sqlskills.com/blogs/paul/script-open-transactions-with-text-and-plans/ + + +SELECT + [s_tst].[session_id], + [s_es].[login_name] AS [Login Name], + DB_NAME (s_tdt.database_id) AS [Database], + [s_tdt].[database_transaction_begin_time] AS [Begin Time], + [s_tdt].[database_transaction_log_bytes_used] AS [Log Bytes], + [s_tdt].[database_transaction_log_bytes_reserved] AS [Log Rsvd], + [s_est].text AS [Last T-SQL Text], + [s_eqp].[query_plan] AS [Last Plan] +FROM + sys.dm_tran_database_transactions [s_tdt] +JOIN + sys.dm_tran_session_transactions [s_tst] +ON + [s_tst].[transaction_id] = [s_tdt].[transaction_id] +JOIN + sys.[dm_exec_sessions] [s_es] +ON + [s_es].[session_id] = [s_tst].[session_id] +JOIN + sys.dm_exec_connections [s_ec] +ON + [s_ec].[session_id] = [s_tst].[session_id] +LEFT OUTER JOIN + sys.dm_exec_requests [s_er] +ON + [s_er].[session_id] = [s_tst].[session_id] +CROSS APPLY + sys.dm_exec_sql_text ([s_ec].[most_recent_sql_handle]) AS [s_est] +OUTER APPLY + sys.dm_exec_query_plan ([s_er].[plan_handle]) AS [s_eqp] +ORDER BY + [Begin Time] ASC; +GO diff --git a/optimize for ad hoc workloads.sql b/optimize for ad hoc workloads.sql new file mode 100644 index 0000000..8730204 Binary files /dev/null and b/optimize for ad hoc workloads.sql differ diff --git a/overdue jobs.sql b/overdue jobs.sql new file mode 100644 index 0000000..7b782f2 --- /dev/null +++ b/overdue jobs.sql @@ -0,0 +1,157 @@ +use msdb +go + +--jobs still running +create table #enum_job ( +Job_ID uniqueidentifier, +Last_Run_Date int, +Last_Run_Time int, +Next_Run_Date int, +Next_Run_Time int, +Next_Run_Schedule_ID int, +Requested_To_Run int, +Request_Source int, +Request_Source_ID varchar(100), +Running int, +Current_Step int, +Current_Retry_Attempt int, +State int +) + +insert into #enum_job +exec master.dbo.xp_sqlagent_enum_jobs 1,'' + +declare @now datetime = GETDATE() + +IF NOT EXISTS (select 1 from admindb.sys.objects o where name = 'overduejobs') +CREATE TABLE admindb.[dbo].[overduejobs]( + ID int not null identity(1,1) PRIMARY KEY, + [name] [sysname] NOT NULL, + [job_id] [uniqueidentifier] NOT NULL, + [State] [varchar](29) NULL, + [last_run_datetime] [datetime] NULL, + [next_run_datetime] [datetime] NULL, + [If_Nightly_Job_When_Start] [datetime] NULL, + [Avg_Duration_s] [int] NULL, + [Expected_Current_End_Time] [datetime] NULL, + [Now] [datetime] NOT NULL, + capturedtime datetime not null default(getdate()) +) ON [PRIMARY] + +insert into admindb.dbo.overduejobs ( + name + , job_id + , State + , last_run_datetime + , next_run_datetime + , If_Nightly_Job_When_Start + , Avg_Duration_s + , Expected_Current_End_Time + , Now) + select name, job_id, State, last_run_datetime, next_run_datetime, If_Nightly_Job_When_Start, Avg_Duration_s + , Expected_Current_End_Time = CASE WHEN If_Nightly_Job_When_Start is not null + THEN dateadd(s, avg_duration_s, If_Nightly_Job_When_Start) + WHEN next_run_datetime is not null + and next_run_datetime > last_run_datetime + and @now > next_run_datetime + THEN dateadd(s, avg_duration_s, next_run_datetime) + ELSE dateadd(s, avg_duration_s, last_run_datetime) END + , Now = @now +from + ( + select + j.name + , j.job_id + , Category_name = c.name + , State = case e.State WHEN 1 THEN 'Executing' + WHEN 2 THEN 'Waiting for thread' + WHEN 3 THEN 'Between retries' + WHEN 4 THEN 'Idle' + WHEN 5 THEN 'Suspended' + WHEN 7 THEN 'Performing completion actions' END + --convert integer date and integer time HHMMSS to a datetime + , last_run_datetime = convert(datetime, (ltrim(convert(varchar(20), converT(smalldatetime, convert(varchar(20), jh.run_date)), 111))) + + ' ' + (isnull(ltrim(stuff(stuff(right('00' + convert(varchar(6), jh.run_time),6),3,0, ':' ), 6,0,':')),'00:00:00')) + ) + --convert integer date and integer time HHMMSS to a datetime + , next_run_datetime = min(convert(datetime, case when js.next_run_date <> 0 THEN convert(varchar(20), js.next_run_date, 113) ELSE NULL END + + ' ' + (isnull(ltrim(stuff(stuff(right('00' + convert(varchar(6), js.next_run_time),6),3,0, ':' ), 6,0,':')),'00:00:00')) + )) + --convert HHMMSS integer to seconds so that we can average it + , Avg_Duration_s = avg(cast(Right(rtrim(ltrim(converT(char(10), jh.run_duration))),2) as int) + + (cast(reverse(substring(reverse( rtrim(ltrim(converT(char(10), jh.run_duration)))), 3,2)) as int) *60) + + (cast(reverse(substring(reverse( rtrim(ltrim(converT(char(10), jh.run_duration)))), 5,6)) as int) * 3600)) + * 1.05 --pad the duration by 5% to prevent false positives + , If_Nightly_Job_When_Start = max(sc.If_Nightly_Job_When_Start) + + from dbo.sysjobs j + inner join (select job_id, run_duration + , run_date, run_time, run_status + , instancerank= rank() over (partition by job_id order by run_date desc, run_time desc) + from dbo.sysjobhistory + where step_id = 0 + ) jh + on j.job_id = jh.job_id + and jh.instancerank = 1 + left outer join dbo.syscategories c + on j.category_id = c.category_id + left outer join dbo.sysjobschedules js + on js.job_id = j.job_id + left outer join + (SELECT schedule_id, If_Nightly_Job_When_Start = CASE WHEN + (sc.freq_type = 4 and freq_interval = 1 and freq_subday_type = 1)--once daily + or (sc.freq_type = 8 and freq_interval = 127 and freq_subday_type = 1)-- every day + or (sc.freq_type = 8 and freq_interval = 62 and DATEPART(dw, @now) between 2 and 6) --weekdays + THEN convert(datetime, + convert(varchar(10), convert(date, + CASE WHEN datepart(hour, @now) >= left(right('00' + convert(varchar(6), sc.active_start_time),6),2) + THEN @now + ELSE DATEADD(day, -1, @now) END)) + + ' ' + (isnull(ltrim(stuff(stuff(right('00' + convert(varchar(6), sc.active_start_time),6),3,0, ':' ), 6,0,':')),'00:00:00') + )) + ELSE NULL + END + FROM dbo.sysschedules sc + WHERE sc.enabled = 1 + ) sc + on sc.schedule_id = js.schedule_id + inner join #enum_job e + on e.job_id = j.job_id + + where + 1=1 + and c.name not like 'repl%' + and c.name <> 'Report Server' + and j.name <> 'overdue jobs' --ignore myself + and e.state in (1,2,3,7) + group by j.name, j.job_id, jh.run_date, jh.run_time, c.name, e.state + ) x +where @now > CASE WHEN If_Nightly_Job_When_Start is not null + THEN dateadd(s, avg_duration_s, If_Nightly_Job_When_Start) + WHEN next_run_datetime is not null + and next_run_datetime > last_run_datetime + and @now > next_run_datetime + THEN dateadd(s, avg_duration_s, next_run_datetime) + ELSE dateadd(s, avg_duration_s, last_run_datetime) END +order by name, state, last_run_datetime, next_run_datetime + +drop table #enum_job + +declare @querytext varchar(150) +select @querytext = 'SELECT name FROM admindb.dbo.overduejobs where convert(smalldatetime, now) = convert(smalldatetime, ''' + convert(varchar(20), @now, 120) + ''')' +declare @subjecttext varchar(100) +select @subjecttext = @@servername + ' Overdue Database Jobs ' + +insert into admindb.dbo.overduejobs (name, job_id, now) values ('TESTING ONLY', NEWID(), @now) + +IF exists (SELECT 1 FROM admindb.dbo.overduejobs where now = @now) +EXEC dbo.sp_send_dbmail + @profile_name = 'prodsql1', + @recipients = 'william.assaf@sparkhound.com', + --@body = 'Failed Jobs', + @query = @querytext, + @attach_query_result_as_file = 0, + @execute_query_database = 'admindb', + @subject = @subjecttext + + diff --git a/page life expectancy.sql b/page life expectancy.sql new file mode 100644 index 0000000..ceb5ef9 --- /dev/null +++ b/page life expectancy.sql @@ -0,0 +1,37 @@ +--dbcc memorystatus +;with cte as ( +select 'InstanceName' = @@SERVERNAME , Version = @@VERSION, +'min server memory (MB)' = max(case when name = 'min server memory (MB)' then value_in_use end) , +'max server memory (MB)' = max(case when name = 'max server memory (MB)' then value_in_use end) +from sys.configurations) +select + p.InstanceName +, c.Version +, 'LogicalCPUCount' = os.cpu_count +, os.[Server Physical Memory MB] -- SQL2012+ only +, c.[min server memory (MB)] +, c.[max server memory (MB)] +, p.[Target Server Memory (MB)] +, p.[Total Server Memory (MB)] +, p.[Page Life Expectancy (s)] --300s is only a rule for smaller memory servers (<16gb) +, 'ChurnMB/s' = cast((p.[Total Server Memory (MB)])/1024./NULLIF(p.[Page Life Expectancy (s)],0) as decimal(19,2)) +from( +select + InstanceName = @@SERVERNAME +, 'Target Server Memory (MB)' = max(case when counter_name = 'Target Server Memory (KB)' then convert(decimal(19,2), cntr_value/1024.)end) +, 'Total Server Memory (MB)' = max(case when counter_name = 'Total Server Memory (KB)' then convert(decimal(19,2), cntr_value/1024.) end) +, 'Page Life Expectancy (s)' = max(case when counter_name = 'Page life expectancy' then cntr_value end) +from sys.dm_os_performance_counters) +as p +inner join cte c on p.InstanceName = c.InstanceName +inner join (SELECT 'InstanceName' = @@SERVERNAME +, cpu_count , hyperthread_ratio AS 'HyperthreadRatio', +cpu_count/hyperthread_ratio AS 'PhysicalCPUCount' +, 'Server Physical Memory MB' = cast(physical_memory_kb/1024. as decimal(19,2)) -- SQL2012+ only +FROM sys.dm_os_sys_info ) as os +on c.InstanceName=os.InstanceName + + + +--adapted from http://www.datavail.com/category-blog/max-server-memory-300-second-rule/ + diff --git a/public permissions.sql b/public permissions.sql new file mode 100644 index 0000000..e9780b6 --- /dev/null +++ b/public permissions.sql @@ -0,0 +1,148 @@ + +SELECT @@SERVERNAME + +--Server level roles +SELECT DISTINCT + QUOTENAME(r.name) as server_role_name, r.type_desc, QUOTENAME(m.name) as principal_name, m.type_desc +, CreateTSQL = 'ALTER SERVER ROLE [' + r.name + '] ADD MEMBER [' + m.name + ']' +, DropTSQL = 'ALTER SERVER ROLE [' + r.name + '] DROP MEMBER [' + m.name + ']' +FROM sys.server_role_members AS rm +inner join sys.server_principals r on rm.role_principal_id = r.principal_id +inner join sys.server_principals m on rm.member_principal_id = m.principal_id +where r.is_disabled = 0 and m.is_disabled = 0 +and m.name = 'public' +order by QUOTENAME(r.name) + + +--Server Level Security +SELECT rm.state_desc, rm.permission_name, principal_name = QUOTENAME(u.name), u.type_desc +, TSQL = rm.state_desc + N' ' + rm.permission_name + + CASE WHEN e.name is not null THEN ' ON ENDPOINT::[' + e.name + '] ' ELSE '' END + + N' TO ' + cast(QUOTENAME(u.name COLLATE DATABASE_DEFAULT) as nvarchar(256)) + ';' +, TSQL = N'REVOKE ' + rm.permission_name + + CASE WHEN e.name is not null THEN ' ON ENDPOINT::[' + e.name + '] ' ELSE '' END + + N' TO ' + cast(QUOTENAME(u.name COLLATE DATABASE_DEFAULT) as nvarchar(256)) + ';', * +FROM sys.server_permissions rm +inner join sys.server_principals u +on rm.grantee_principal_id = u.principal_id +left outer join sys.endpoints e +on e.endpoint_id = major_id and class_desc = 'ENDPOINT' +where u.name not like '##%' +and u.name = 'public' +order by rm.permission_name, u.name + + + + +--Database role membership + +--Single Database +--Run on each database for database-level security. +SELECT DB_NAME(); +SELECT DISTINCT QUOTENAME(r.name) as database_role_name, r.type_desc, QUOTENAME(d.name) as principal_name, d.type_desc +, Add_TSQL = 'EXEC sp_addrolemember @membername = N''' + d.name COLLATE DATABASE_DEFAULT + ''', @rolename = N''' + r.name + '''' +, Drop_TSQL = 'EXEC sp_droprolemember @membername = N''' + d.name COLLATE DATABASE_DEFAULT + ''', @rolename = N''' + r.name + '''' +FROM sys.database_role_members rm +inner join sys.database_principals r on rm.role_principal_id = r.principal_id +inner join sys.database_principals d on rm.member_principal_id = d.principal_id +where d.name = 'public' +/* +--Multi Database +declare @tsql nvarchar(4000) = 'use [?]; +SELECT DB_NAME(); +SELECT DISTINCT QUOTENAME(r.name) as database_role_name, r.type_desc, QUOTENAME(d.name) as principal_name, d.type_desc +, Add_TSQL = ''EXEC sp_addrolemember @membername = N'''''' + d.name COLLATE DATABASE_DEFAULT + '''''', @rolename = N'''''' + r.name + '''''''' +, Drop_TSQL = ''EXEC sp_droprolemember @membername = N'''''' + d.name COLLATE DATABASE_DEFAULT + '''''', @rolename = N'''''' + r.name + '''''''' +FROM sys.database_role_members rm +inner join sys.database_principals r on rm.role_principal_id = r.principal_id +inner join sys.database_principals d on rm.member_principal_id = d.principal_id +where d.name = ''public'' +'; +exec sp_msforeachdb @tsql +go +*/ + +--Database Permissions +--Run on each database for database-level security. +--Too large to wrap in sp_msforeachdb +SELECT DB_NAME(); +SELECT Permission_State_Desc = perm.state_desc + , Permission_Name = perm.permission_name + , Permission_Object_Name = ISNULL(QUOTENAME(s.name ) + '.','') + QUOTENAME(obj.name COLLATE database_default) + CASE WHEN cl.name COLLATE database_default is null THEN '' ELSE '.' + QUOTENAME(cl.name COLLATE database_default) END + , Object_Type_Desc = obj.type_desc + , Principal_Name = QUOTENAME(u.name COLLATE database_default) + , User_Type = u.type_desc + , Create_TSQL = perm.state_desc + N' ' + perm.permission_name + + case when obj.name COLLATE database_default is not null THEN + N' ON ' + sc.class_desc + '::' + ISNULL(QUOTENAME(s.name COLLATE database_default) + '.','') + QUOTENAME(obj.name COLLATE database_default) ELSE '' END + + CASE WHEN cl.column_id IS NULL THEN ' ' ELSE '(' + QUOTENAME(cl.name COLLATE database_default) + ')' END + + N' TO ' + QUOTENAME(u.name COLLATE database_default) + , Revoke_TSQL = N'REVOKE ' + perm.permission_name + + case when obj.name COLLATE database_default is not null THEN + N' ON ' + sc.class_desc + '::' + ISNULL(QUOTENAME(s.name COLLATE database_default) + '.','') + QUOTENAME(obj.name COLLATE database_default) ELSE '' END + + CASE WHEN cl.column_id IS NULL THEN ' ' ELSE '(' + QUOTENAME(cl.name COLLATE database_default) + ')' END + + N' TO ' + QUOTENAME(u.name COLLATE database_default) + , * +FROM sys.database_permissions AS perm +INNER JOIN sys.database_principals AS u ON perm.grantee_principal_id = u.principal_id + +LEFT OUTER JOIN (--https://msdn.microsoft.com/en-us/library/ms188367.aspx + select name, object_id, schema_id, is_ms_shipped, class_desc='OBJECT', type_desc from sys.objects + union all + select name, 0, null, null, 'DATABASE', 'DATABASE' from sys.databases + union all + select name, schema_id, null, null, 'SCHEMA', 'SCHEMA' from sys.schemas + union all + select name, principal_id, null, null, 'USER', type_desc from sys.database_principals where type_desc in ('WINDOWS_USER','SQL_USER','ASYMMETRIC_KEY_MAPPED_USER','CERTIFICATE_MAPPED_USER', 'WINDOWS_GROUP','EXTERNAL_GROUPS') + union all + select name, principal_id, null, null, 'USER', type_desc from sys.database_principals where type_desc in ('WINDOWS_USER','SQL_USER','ASYMMETRIC_KEY_MAPPED_USER','CERTIFICATE_MAPPED_USER', 'WINDOWS_GROUP','EXTERNAL_GROUPS') + union all + select name, principal_id, null, null, 'APPLICATION ROLE', type_desc from sys.database_principals where type_desc in ('APPLICATION_ROLE') + union all + select name, principal_id, null, null, 'ROLE', type_desc from sys.database_principals where type_desc in ('DATABASE_ROLE') + union all + select name, assembly_id, null, null, 'ASSEMBLY', 'ASSEMBLY' from sys.assemblies + union all + select name, user_type_id, null, null, 'TYPE', 'USER TYPE' from sys.types + union all + select name, xml_collection_id, null, null, 'XML SCHEMA COLLECTION', 'XML SCHEMA COLLECTION' from sys.xml_schema_collections + union all + select name COLLATE database_default, message_type_id, null, null, 'MESSAGE TYPE', 'MESSAGE TYPE' from sys.service_message_types + union all + select name COLLATE database_default, service_contract_id, null, null, 'CONTRACT', 'CONTRACT' from sys.service_contracts + union all + select name COLLATE database_default, service_id, null, null, 'SERVICE', 'SERVICE' from sys.services + union all + select name COLLATE database_default, remote_service_binding_id, null, null, 'REMOTE SERVICE BINDING', 'REMOTE SERVICE BINDING' from sys.remote_service_bindings + union all + select name COLLATE database_default, route_id, null, null, 'ROUTE', 'ROUTE' from sys.routes + union all + select name COLLATE database_default, fulltext_catalog_id, null, null, 'FULLTEXT CATALOG', 'FULLTEXT CATALOG' from sys.fulltext_catalogs + union all + select name, symmetric_key_id, null, null, 'SYMMETRIC KEY', 'SYMMETRIC KEY' from sys.symmetric_keys + union all + select name, certificate_id, null, null, 'CERTIFICATE', 'CERTIFICATE' from sys.certificates + union all + select name, asymmetric_key_id, null, null, 'ASYMMETRIC KEY', 'ASYMMETRIC KEY' from sys.asymmetric_keys + ) obj +ON perm.major_id = obj.[object_id] +INNER JOIN sys.securable_classes sc on sc.class = perm.class +and sc.class_desc = obj.class_desc +LEFT OUTER JOIN sys.schemas s ON s.schema_id = obj.schema_id +LEFT OUTER JOIN sys.columns cl ON cl.column_id = perm.minor_id AND cl.[object_id] = perm.major_id +where 1=1 +and perm.major_id > 0 +and u.name = 'public' +--Ignore internal principals +and u.name COLLATE database_default not in ('dbo','guest','INFORMATION_SCHEMA','sys','MS_DataCollectorInternalUser','PolicyAdministratorRole','ServerGroupReaderRole' +,'ServerGroupAdministratorRole','TargetServersRole','SQLAgentUserRole','UtilityCMRReader','SQLAgentOperatorRole','dc_operator','dc_proxy','dc_admin','db_ssisadmin','db_ssisltduser','db_ssisoperator' +,'UtilityIMRWriter','UtilityIMRReader','RSExecRole','DatabaseMailUserRole') +--Ignore ## principals +and u.name COLLATE database_default not like '##%##' +--Ignore built-in svc accounts (not recommended anyway!) +and u.name COLLATE database_default not like 'NT SERVICE%' +--Ignore MS shipped internal objects +and (obj.is_ms_shipped = 0 or obj.is_ms_shipped is null) +--Ignore system sprocs (be aware of your naming conventions!) +--and (obj.name not like 'sp_%' or obj.name is null) +order by Object_Type_Desc, Principal_Name + + diff --git a/record_dm_io_virtual_file_stats.sql b/record_dm_io_virtual_file_stats.sql new file mode 100644 index 0000000..4f03ee3 --- /dev/null +++ b/record_dm_io_virtual_file_stats.sql @@ -0,0 +1,134 @@ + +--Snapshot +SELECT + dbname = db_name(a.database_id) +, io_stall_s = (a.io_stall)/60. +, a.io_stall_read_ms +, a.io_stall_write_ms +, num_of_reads = (a.num_of_reads) +, num_of_writes = (a.num_of_writes) +, MB_read = ( convert(decimal(19,2),( ( a.num_of_bytes_read/ 1024. ) / 1024. ) )) +, MB_written = ( convert(decimal(19,2),( ( a.num_of_bytes_written/ 1024. ) / 1024. ) )) +, a.io_stall_write_ms +, MB_size_on_disk = ( convert(decimal(19,2),( ( a.size_on_disk_bytes/ 1024. ) / 1024. ) )) +, mf.name +, a.file_id +, db_file_type = mf.Type_desc +, disk_location = UPPER(SUBSTRING(mf.physical_name, 1, 2)) +FROM sys.dm_io_virtual_file_stats (NULL, NULL) a +INNER JOIN sys.master_files mf ON a.file_id = mf.file_id +AND a.database_id = mf.database_id +ORDER BY a.database_id ASC + + +/* + +USE DBAHound +GO +--Setup Logging Table +CREATE TABLE dbo.record_dm_io_virtual_file_stats +( ID int not null IDENTITY(1,1) CONSTRAINT PK_record_dm_io_virtual_file_stats PRIMARY KEY +, dbname sysname not null +, io_stall_s bigint not null +, num_of_reads bigint not null +, num_of_writes bigint not null +, MB_Read decimal(19,2) not null +, MB_Written decimal(19,2) not null +, MB_size_on_disk decimal(19,2) not null +, sample_ms bigint +) +GO +CREATE INDEX IDX_NC_record_dm_io_virtual_file_stats_Sample_Ms ON dbo.record_dm_io_virtual_file_stats (Sample_MS DESC) INCLUDE (dbname) +GO +*/ +/* +--Capture a Sample +INSERT INTO dbo.record_dm_io_virtual_file_stats +SELECT + dbname = db_name(a.database_id) +, io_stall_s = sum(a.io_stall)/60. +--, a.io_stall_read_ms +--, a.io_stall_write_ms +, num_of_reads = sum(a.num_of_reads) +, num_of_writes = sum(a.num_of_writes) +, MB_read = sum( convert(decimal(19,2),( ( a.num_of_bytes_read/ 1024. ) / 1024. ) )) +, MB_written = sum( convert(decimal(19,2),( ( a.num_of_bytes_written/ 1024. ) / 1024. ) )) +--, a.io_stall_write_ms +, MB_size_on_disk = sum( convert(decimal(19,2),( ( a.size_on_disk_bytes/ 1024. ) / 1024. ) )) +--, mf.name +--, a.file_id +--, db_file_type = mf.Type_desc +--, disk_location = UPPER(SUBSTRING(mf.physical_name, 1, 2)) +, a.sample_ms +FROM sys.dm_io_virtual_file_stats (NULL, NULL) a +INNER JOIN sys.master_files mf ON a.file_id = mf.file_id +AND a.database_id = mf.database_id +GROUP BY a.sample_ms, a.database_id +ORDER BY a.database_id ASC +*/ + +--Latest Two Samples +;WITH cteVFS (dbname, sample_ms, sampleset, SampleStart) +AS +(SELECT +dbname +,sample_ms +,sampleset = DENSE_RANK() oVER ( ORDER BY sample_ms desc) +, SampleStart = convert(datetime2(0), dateadd(ms, round(sample_ms - (select top 1 sample_ms from sys.dm_io_virtual_file_stats(1,null)),0), getdate())) +from dbo.record_dm_io_virtual_file_stats vfs +) +, cteVFS2 (dbname,sampleset,io_stall_s,num_of_reads,num_of_writes,MB_read,MB_written,MB_size_on_disk, SampleTime_Min,SampleStart, SampleEnd) +as ( +select + vfs.dbname +, sampleset +, io_stall_s = io_stall_s - LAG(io_stall_s, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, num_of_reads = num_of_reads - LAG(num_of_reads, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, num_of_writes = num_of_writes - LAG(num_of_writes, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, MB_read = MB_read - LAG(MB_read, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, MB_written = MB_written - LAG(MB_written, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, MB_size_on_disk = CASE WHEN c1.Sampleset = 1 THEN MB_size_on_disk ELSE NULL END +, Sample_Duration_Min = convert(decimal(19,2), (vfs.sample_ms - LAG(vfs.sample_ms, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc))/1000./60.) +, Sample_Start = min(samplestart) OVER () +, Sample_End = max(samplestart) OVER () +from dbo.record_dm_io_virtual_file_stats vfs +inner join cteVFS c1 on vfs.dbname = c1.dbname +and vfs.sample_ms = c1.sample_ms +WHERE Sampleset in (1,2) +) +select dbname,io_stall_s,num_of_reads,num_of_writes,MB_read,MB_written,MB_size_on_disk, SampleTime_Min, SampleStart, SampleEnd +from cteVFS2 where sampleset = 1 +ORDER BY MB_read + MB_Written desc + +--First Sample vs Latest Sample +;WITH cteVFS (dbname, sample_ms, sampleset, SampleStart) +AS +(SELECT +dbname +,sample_ms +,sampleset = DENSE_RANK() oVER ( ORDER BY sample_ms desc) +, SampleStart = convert(datetime2(0), dateadd(ms, round(sample_ms - (select top 1 sample_ms from sys.dm_io_virtual_file_stats(1,null)),0), getdate())) +from dbo.record_dm_io_virtual_file_stats vfs +) +, cteVFS2 (dbname,sampleset,io_stall_s,num_of_reads,num_of_writes,MB_read,MB_written,MB_size_on_disk, SampleTime_Min,SampleStart, SampleEnd) +as ( +select + vfs.dbname +, sampleset +, io_stall_s = io_stall_s - LAG(io_stall_s, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, num_of_reads = num_of_reads - LAG(num_of_reads, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, num_of_writes = num_of_writes - LAG(num_of_writes, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, MB_read = MB_read - LAG(MB_read, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, MB_written = MB_written - LAG(MB_written, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc) +, MB_size_on_disk = CASE WHEN c1.Sampleset = 1 THEN MB_size_on_disk ELSE NULL END +, Sample_Duration_Min = convert(decimal(19,2), (vfs.sample_ms - LAG(vfs.sample_ms, 1) OVER (PARTITION BY vfs.dbname ORDER BY c1.sampleset desc))/1000./60.) +, Sample_Start = min(samplestart) OVER () +, Sample_End = max(samplestart) OVER () +from dbo.record_dm_io_virtual_file_stats vfs +inner join cteVFS c1 on vfs.dbname = c1.dbname +and vfs.sample_ms = c1.sample_ms +WHERE Sampleset = 1 OR SampleSet = (SELECT MAX(SampleSet) FROM cteVFS) +) +select dbname,io_stall_s,num_of_reads,num_of_writes,MB_read,MB_written,MB_size_on_disk, SampleTime_Min, SampleStart, SampleEnd +from cteVFS2 where sampleset = 1 +ORDER BY MB_read + MB_Written desc \ No newline at end of file diff --git a/refresh view metadata.sql b/refresh view metadata.sql new file mode 100644 index 0000000..d9cb589 --- /dev/null +++ b/refresh view metadata.sql @@ -0,0 +1,34 @@ + + +PRINT N'Refreshing views.'; + +DECLARE @TSQL nvarchar(4000) +DECLARE RefreshViewMetadata CURSOR FAST_FORWARD + FOR + select TSQL = 'exec sp_refreshview N''' +s.name + '.' + o.name + '''' + from sys.views o + inner join sys.schemas s on o.schema_id = s.schema_id + inner join sys.sql_modules m on m.object_id = o.object_id + where o.type_desc = 'view' + and o.is_ms_shipped = 0 + and m.definition not like '%schemabinding%' + order by s.name, o.name +OPEN RefreshViewMetadata +FETCH NEXT FROM RefreshViewMetadata INTO @TSQL +WHILE @@FETCH_STATUS = 0 +BEGIN + --print @TSQL; + BEGIN TRY + BEGIN TRAN vwRefresh + exec sp_executesql @TSQL; + COMMIT TRAN vwRefresh + END TRY + BEGIN CATCH + print @TSQL + print ERROR_MESSAGE() + ROLLBACK TRAN vwRefresh + END CATCH + FETCH NEXT FROM RefreshViewMetadata INTO @TSQL +END +CLOSE RefreshViewMetadata; +DEALLOCATE RefreshViewMetadata; diff --git a/reports catalog metadata.sql b/reports catalog metadata.sql new file mode 100644 index 0000000..7c2e3f6 --- /dev/null +++ b/reports catalog metadata.sql @@ -0,0 +1,29 @@ + +;WITH cteCatalog ([Path], Name, [Description], CreationDate, ModifiedDate, AverageRowCount, AverageDuration_sec, XML, row) +as ( + SELECT + [Path], Name, [Description], CreationDate, ModifiedDate, AverageRowCount = AVG(e.[RowCount]) OVER (Partition By [Path], Name) + , AverageDuration_sec = (AVG(e.timedataretrieval + e.timeprocessing + e.TimeRendering) OVER (Partition By [Path], Name))/1000.0 + , XML = CONVERT(XML,C.Parameter) + , Row = ROW_NUMBER () OVER (Partition BY Path, Name order by path, name) + from Catalog c + inner join ExecutionLog2 e + on e.ReportPath = c.Path +) +SELECT distinct + [Path], Name, [Description], CreationDate, ModifiedDate, AverageRowCount + , AverageDuration_sec = round(AverageDuration_sec,2) + , Param_Name = ParamXML.value('Name[1]', 'VARCHAR(250)') + , Param_DataType = ParamXML.value('Type[1]', 'VARCHAR(250)') + , Param_Nullable = ParamXML.value('Nullable[1]', 'VARCHAR(250)') + , Param_AllowBlank = ParamXML.value('AllowBlank[1]', 'VARCHAR(250)') + , Param_MultiValue = ParamXML.value('MultiValue[1]', 'VARCHAR(250)') + , Param_UsedInQuery = ParamXML.value('UsedInQuery[1]', 'VARCHAR(250)') + , Param_Prompt = ParamXML.value('Prompt[1]', 'VARCHAR(250)') + , Param_DynamicPrompt = ParamXML.value('DynamicPrompt[1]', 'VARCHAR(250)') + , Param_PromptUser = ParamXML.value('PromptUser[1]', 'VARCHAR(250)') + , Param_State = ParamXML.value('State[1]', 'VARCHAR(250)') + FROM cteCatalog c +CROSS APPLY c.XML.nodes('//Parameters/Parameter') p ( ParamXML ) +WHERE c.row = 1 +order by AverageDuration_sec desc \ No newline at end of file diff --git a/restore 2.sql b/restore 2.sql new file mode 100644 index 0000000..0cf7e9b Binary files /dev/null and b/restore 2.sql differ diff --git a/script ssisdb env.sql b/script ssisdb env.sql new file mode 100644 index 0000000..6cbf3cc --- /dev/null +++ b/script ssisdb env.sql @@ -0,0 +1,81 @@ +/* +This script will take all environment variables in an existing environment and make "insert" scripts +out of them so you can easily deploy them to a new server or a new environment on the same server. + +Script first created by Henning Frettem, www.thefirstsql.com, 2013-05-28, adapted by William Assaf 2015-07-20 + +Integration Services Catalogs / SSISDB / Folder_Name / Projects / ETLName + + +*/ +use ssisdb +go +SET NOCOUNT ON + +DECLARE + @folder_name nvarchar(200) = 'Folder_Name', + @environment_name_current nvarchar(200) = 'TEST', + @environment_name_new nvarchar(200) = 'TEST', + @name sysname, + @sensitive bit, + @description nvarchar(1024), + @value sql_variant, + @type nvarchar(128) + +PRINT 'DECLARE + @folder_id bigint, + @environment_id bigint' + +PRINT '' + +--> Create folder if it doesn't exist and get folder_id +PRINT 'IF NOT EXISTS (SELECT 1 FROM [SSISDB].[catalog].[folders] WHERE name = N''' + @folder_name + ''') + EXEC [SSISDB].[catalog].[create_folder] @folder_name=N''' + @folder_name + ''', @folder_id=@folder_id OUTPUT +ELSE + SET @folder_id = (SELECT folder_id FROM [SSISDB].[catalog].[folders] WHERE name = N''' + @folder_name + ''')' + +PRINT '' + +--> Create environment if it doesn't exist +PRINT 'IF NOT EXISTS (SELECT 1 FROM [SSISDB].[catalog].[environments] WHERE folder_id = @folder_id AND name = N''' + @environment_name_new + ''') + EXEC [SSISDB].[catalog].[create_environment] @environment_name=N''' + @environment_name_new + ''', @folder_name=N''' + @folder_name + '''' + +PRINT '' + +--> Get the environment_id +PRINT 'SET @environment_id = (SELECT environment_id FROM [SSISDB].[catalog].[environments] WHERE folder_id = @folder_id and name = N''' + @environment_name_new + ''')' + +PRINT '' + +--> Making cursor because mapping of sql_variant datatype is different than the normal datatypes +DECLARE cur CURSOR FOR + SELECT c.name, c.sensitive, c.description, c.value, c.type + FROM [SSISDB].[catalog].[folders] a + INNER JOIN [SSISDB].[catalog].[environments] b + ON a.folder_id = b.folder_id + INNER JOIN [SSISDB].[catalog].[environment_variables] c + ON b.environment_id = c.environment_id + WHERE a.name = @folder_name + AND b.name = @environment_name_current + +OPEN cur +FETCH NEXT FROM cur INTO @name, @sensitive, @description, @value, @type + +PRINT 'DECLARE @var sql_variant' +PRINT '' + +WHILE (@@FETCH_STATUS = 0) + BEGIN + PRINT 'SET @var = N''' + CONVERT(nvarchar(max), @value) + '''' + + PRINT 'IF NOT EXISTS (SELECT 1 FROM [SSISDB].[catalog].[environment_variables] WHERE environment_id = @environment_id AND name = N''' + PRINT + @name + ''')' + PRINT ' EXEC [SSISDB].[catalog].[create_environment_variable] @variable_name=N''' + @name + ''', @sensitive=' + CONVERT(varchar(2), @sensitive) + ', @description=N''' + @description + ''', @environment_name=N''' + @environment_name_new + ''', @folder_name=N''' + @folder_name + ''', @value=@var, @data_type=N''' + @type + '''' + + PRINT '' + + FETCH NEXT FROM cur INTO @name, @sensitive, @description, @value, @type + END + +CLOSE cur +DEALLOCATE cur \ No newline at end of file diff --git a/services dmv.sql b/services dmv.sql new file mode 100644 index 0000000..5d68503 --- /dev/null +++ b/services dmv.sql @@ -0,0 +1,30 @@ +-- This works for SQL 2008 R2 SP1 and above only +SELECT servicename -- Ex: SQL Server (SQL2K8R2) +, startup_type_desc -- Manual, Automatic +, status_desc -- Running, Stopped, etc. +, process_id +, last_startup_time -- datetime +, service_account +, filename +, is_clustered -- Y/N +, cluster_nodename +FROM sys.dm_server_services +/* +-- This works prior to SQL 2008 R2 SP1 +DECLARE @DBEngineLogin VARCHAR(100) +DECLARE @AgentLogin VARCHAR(100) +EXECUTE master.dbo.xp_instance_regread +@rootkey = N'HKEY_LOCAL_MACHINE', +@key = N'SYSTEM\CurrentControlSet\Services\MSSQLServer', +@value_name = N'ObjectName', +@value = @DBEngineLogin OUTPUT +EXECUTE master.dbo.xp_instance_regread +@rootkey = N'HKEY_LOCAL_MACHINE', +@key = N'SYSTEM\CurrentControlSet\Services\SQLServerAgent', +@value_name = N'ObjectName', +@value = @AgentLogin OUTPUT +SELECT [DBEngineLogin] = @DBEngineLogin, [AgentLogin] = @AgentLogin +GO +  +*/ + diff --git a/sessions and requests blocking chain.jpg b/sessions and requests blocking chain.jpg new file mode 100644 index 0000000..03be346 Binary files /dev/null and b/sessions and requests blocking chain.jpg differ diff --git a/sessions and requests table.sql b/sessions and requests table.sql new file mode 100644 index 0000000..664a35e --- /dev/null +++ b/sessions and requests table.sql @@ -0,0 +1,59 @@ +USE DBAAdmin +GO +DROP TABLE +--this syntax is 2016 only +IF EXISTS +[dbo].[SessionsAndRequestsLog] +go +CREATE TABLE [dbo].[SessionsAndRequestsLog]( + [timestamp] [datetime] NOT NULL INDEX IDX_NC_SessionsAndRequestsLog_timestamp CLUSTERED, + [session_id] [smallint] NOT NULL INDEX IDX_NC_SessionsAndRequestsLog_session_id NONCLUSTERED, + [host_name] [nvarchar](256) NULL, + [program_name] [nvarchar](256) NULL, + [session_status] [nvarchar](60) NULL, + [request_status] [nvarchar](60) NULL, + [blocking_these] [varchar](1000) NULL, + [blocked_by] [smallint] NULL, + [wait_type] [nvarchar](120) NULL, + [wait_resource] [nvarchar](120) NULL, + [last_wait_type] [nvarchar](120) NULL, + [DBName] [nvarchar](128) NULL, + [objectid] [int] NULL, + [command] [nvarchar](32) NULL, + [login_time] [datetime] NOT NULL, + [login_name] [nvarchar](256) NULL, + [client_interface_name] [nvarchar](64) NULL, + [request_start_time] [datetime] NULL, + [tot_time_s] [int] NULL, + [wait_time_s] [int] NULL, + [cpu_time_s] [int] NULL, + [reads] [bigint] NULL, + [writes] [bigint] NULL, + [logical_reads] [bigint] NULL, + [offsettext] [nvarchar](max) NULL, + [statement_start_offset] [int] NULL, + [statement_end_offset] [int] NULL, + [cacheobjtype] [nvarchar](35) NULL, + [QueryPlan] [xml] NULL, + [request_transaction_isolation_level] [varchar](15) NULL, + [session_transaction_isolation_level] [varchar](15) NULL, + [plan_handle] [varbinary](64) NULL, + [execution_count] [bigint] NULL, + [total_worker_time_s] [numeric](30, 11) NULL, + [last_worker_time_s] [numeric](30, 11) NULL, + [total_elapsed_time_s] [numeric](30, 11) NULL, + [last_elapsed_time_s] [numeric](30, 11) NULL, + [total_physical_reads] [bigint] NULL, + [total_logical_writes] [bigint] NULL, + [total_logical_reads] [bigint] NULL, + [Governor_Group_Name] [sysname] NULL, + [Governor_Group_ID] [int] NULL, + [Governor_Pool_Name] [sysname] NULL, + [Governor_Pool_ID] [int] NULL, + [total_rows] [bigint] NULL, + [last_rows] [bigint] NULL +) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY] + +GO + + diff --git a/sessions and requests.sql b/sessions and requests.sql new file mode 100644 index 0000000..fe31ef2 --- /dev/null +++ b/sessions and requests.sql @@ -0,0 +1,224 @@ +--In Azure SQL, cannot run this in Master, must run in a user database. + + declare @showallspids bit + select @showallspids =1 + + create table #ExecRequests ( + id int IDENTITY(1,1) PRIMARY KEY + , session_id smallint not null + , request_id int null + , request_start_time datetime null + , login_time datetime not null + , login_name nvarchar(256) null + , client_interface_name nvarchar(64) + , session_status nvarchar(60) null + , request_status nvarchar(60) null + , command nvarchar(32) null + , sql_handle varbinary(64) null + , statement_start_offset int null + , statement_end_offset int null + , plan_handle varbinary (64) null + , database_id smallint null + , user_id int null + , blocking_session_id smallint null + , wait_type nvarchar (120) null + , wait_time_s int null + , wait_resource nvarchar(120) null + , last_wait_type nvarchar(120) null + , cpu_time_s int null + , tot_time_s int null + , reads bigint null + , writes bigint null + , logical_reads bigint null + , [host_name] nvarchar(256) null + , [program_name] nvarchar(256) null + , Governor_Group_Id int null + , blocking_these varchar(1000) NULL + , percent_complete int null + , session_transaction_isolation_level varchar(20) null + , request_transaction_isolation_level varchar(20) null + , EndPointName sysname null + , Protocol nvarchar(120) null + ) + + + insert into #ExecRequests (session_id,request_id, request_start_time, login_time, login_name, client_interface_name, session_status, request_status, command,sql_handle,statement_start_offset,statement_end_offset,plan_handle,database_id,user_id,blocking_session_id,wait_type,last_wait_type,wait_time_s,wait_resource,cpu_time_s,tot_time_s,reads,writes,logical_reads,[host_name], [program_name] , session_transaction_isolation_level , request_transaction_isolation_level , Governor_Group_Id + --, EndPointName, Protocol -- sql2k16+ only + ) + select s.session_id,request_id, r.start_time, s.login_time, s.login_name, s.client_interface_name, s.status, r.status,command,sql_handle,statement_start_offset,statement_end_offset,plan_handle,r.database_id,user_id,blocking_session_id,wait_type,r.last_wait_type, r.wait_time/1000.,r.wait_resource ,r.cpu_time/1000.,r.total_elapsed_time/1000.,r.reads,r.writes,r.logical_reads,s.[host_name], s.[program_name], s.transaction_isolation_level, r.transaction_isolation_level, s.group_id + --, EndPointName= e.name, Protocol = e.Protocol_Desc + from sys.dm_exec_sessions s + left outer join sys.dm_exec_requests r on r.session_id = s.session_id + --left outer join sys.endpoints E ON E.endpoint_id = s.endpoint_id + where 1=1 + and s.session_id >= 50 --retrieve only user spids + and s.session_id <> @@SPID --ignore myself + and (@showallspids = 1 or r.session_id is not null) + + print 'insert done' + + update #ExecRequests + set blocking_these = LEFT((select isnull(convert(varchar(5), er.session_id),'') + ', ' + from #ExecRequests er + where er.blocking_session_id = isnull(#ExecRequests.session_id ,0) + and er.blocking_session_id <> 0 + FOR XML PATH('') + ),1000) + + print 'update done' + + select * from + ( + select + timestamp = getdate() + , r.session_id , r.host_name , r.program_name + , r.session_status + , r.request_status + , r.blocking_these + , blocked_by = r.blocking_session_id + , r.wait_type + , r.wait_resource + , r.last_wait_type + , DBName = db_name(r.database_id) + , est.objectid + , r.command + , login_time + , login_name + , client_interface_name + , request_start_time + , r.tot_time_s, r.wait_time_s + , r.cpu_time_s --cpu_time is not accurate prior to SQL Server 2012 SP2. http://blogs.msdn.com/b/psssql/archive/2014/11/11/how-come-sys-dm-exec-requests-cpu-time-never-moves.aspx + , r.reads, r.writes, r.logical_reads + --, [fulltext] = est.[text] + , offsettext = CASE WHEN r.statement_start_offset = 0 and r.statement_end_offset= 0 THEN left(est.text, 4000) + ELSE SUBSTRING ( est.[text] + , r.statement_start_offset/2 + 1, + CASE WHEN r.statement_end_offset = -1 THEN LEN (CONVERT(nvarchar(max), est.[text])) + ELSE r.statement_end_offset/2 - r.statement_start_offset/2 + 1 + END ) + END + , r.statement_start_offset, r.statement_end_offset + , cacheobjtype = LEFT (p.cacheobjtype + ' (' + p.objtype + ')', 35) + , QueryPlan = qp.query_plan + , request_transaction_isolation_level = case request_transaction_isolation_level + when 0 then 'Unspecified' + when 1 then 'ReadUncommitted' + when 2 then 'ReadCommitted' + when 3 then 'Repeatable' + when 4 then 'Serializable' + when 5 then 'Snapshot' end + , session_transaction_isolation_level = case session_transaction_isolation_level + when 0 then 'Unspecified' + when 1 then 'ReadUncommitted' + when 2 then 'ReadCommitted' + when 3 then 'Repeatable' + when 4 then 'Serializable' + when 5 then 'Snapshot' end + , p.plan_handle + , stat.execution_count, total_worker_time_s = stat.total_worker_time/1000./1000., last_worker_time_s = stat.last_worker_time/1000./1000., total_elapsed_time_s = stat.total_elapsed_time/1000./1000., last_elapsed_time_s = stat.last_elapsed_time/1000./1000., stat.total_physical_reads, stat.total_logical_writes, stat.total_logical_reads + , Governor_Group_Name = wg.name + , Governor_Group_ID = r.Governor_Group_Id + , Governor_Pool_Name = wp.name + , Governor_Pool_ID = wg.Pool_id + , EndpointName + , Protocol + --next two lines are SQL 2012 only! + --, stat.total_rows, stat.last_rows + from #ExecRequests r + LEFT OUTER JOIN sys.dm_exec_cached_plans p ON p.plan_handle = r.plan_handle + OUTER APPLY sys.dm_exec_query_plan (r.plan_handle) qp + OUTER APPLY sys.dm_exec_sql_text (r.sql_handle) est + LEFT OUTER JOIN sys.dm_exec_query_stats stat on stat.plan_handle = r.plan_handle + and r.statement_start_offset = stat.statement_start_offset + and r.statement_end_offset = stat.statement_end_offset + LEFT OUTER JOIN sys.resource_governor_workload_groups wg + on wg.group_id = r.Governor_Group_Id + LEFT OUTER JOIN sys.resource_governor_resource_pools wp + on wp.pool_id = wg.Pool_id + + + ) a + order by len(blocking_these) - len(replace(blocking_these,',','')) desc, blocking_these desc, blocked_by desc, session_id asc + + /* + insert into DBAAdmin.dbo.[SessionsAndRequestsLog] + select * + from + ( + select + timestamp = getdate() + , r.session_id , r.host_name , r.program_name + , r.session_status + , r.request_status + , r.blocking_these + , blocked_by = r.blocking_session_id + , r.wait_type + , r.wait_resource + , r.last_wait_type + , DBName = db_name(r.database_id) + , est.objectid + , r.command + , login_time + , login_name + , client_interface_name + , request_start_time + , r.tot_time_s, r.wait_time_s + , r.cpu_time_s --cpu_time is not accurate prior to SQL Server 2012 SP2. http://blogs.msdn.com/b/psssql/archive/2014/11/11/how-come-sys-dm-exec-requests-cpu-time-never-moves.aspx + , r.reads, r.writes, r.logical_reads + --, [fulltext] = est.[text] + , offsettext = CASE WHEN r.statement_start_offset = 0 and r.statement_end_offset= 0 THEN left(est.text, 4000) + ELSE SUBSTRING ( est.[text] + , r.statement_start_offset/2 + 1, + CASE WHEN r.statement_end_offset = -1 THEN LEN (CONVERT(nvarchar(max), est.[text])) + ELSE r.statement_end_offset/2 - r.statement_start_offset/2 + 1 + END ) + END + , r.statement_start_offset, r.statement_end_offset + , cacheobjtype = LEFT (p.cacheobjtype + ' (' + p.objtype + ')', 35) + , QueryPlan = qp.query_plan + , request_transaction_isolation_level = case request_transaction_isolation_level + when 0 then 'Unspecified' + when 1 then 'ReadUncommitted' + when 2 then 'ReadCommitted' + when 3 then 'Repeatable' + when 4 then 'Serializable' + when 5 then 'Snapshot' end + , session_transaction_isolation_level = case session_transaction_isolation_level + when 0 then 'Unspecified' + when 1 then 'ReadUncommitted' + when 2 then 'ReadCommitted' + when 3 then 'Repeatable' + when 4 then 'Serializable' + when 5 then 'Snapshot' end + , p.plan_handle + , stat.execution_count, total_worker_time_s = stat.total_worker_time/1000./1000., last_worker_time_s = stat.last_worker_time/1000./1000., total_elapsed_time_s = stat.total_elapsed_time/1000./1000., last_elapsed_time_s = stat.last_elapsed_time/1000./1000., stat.total_physical_reads, stat.total_logical_writes, stat.total_logical_reads + , Governor_Group_Name = wg.name + , Governor_Group_ID = r.Governor_Group_Id + , Governor_Pool_Name = wp.name + , Governor_Pool_ID = wg.Pool_id + --next two lines are SQL 2012 only! + , stat.total_rows, stat.last_rows + + from #ExecRequests r + LEFT OUTER JOIN sys.dm_exec_cached_plans p ON p.plan_handle = r.plan_handle + OUTER APPLY sys.dm_exec_query_plan (r.plan_handle) qp + OUTER APPLY sys.dm_exec_sql_text (r.sql_handle) est + LEFT OUTER JOIN sys.dm_exec_query_stats stat on stat.plan_handle = r.plan_handle + and r.statement_start_offset = stat.statement_start_offset + and r.statement_end_offset = stat.statement_end_offset + LEFT OUTER JOIN sys.resource_governor_workload_groups wg + on wg.group_id = r.Governor_Group_Id + LEFT OUTER JOIN sys.resource_governor_resource_pools wp + on wp.pool_id = wg.Pool_id + + + ) a + order by len(blocking_these) - len(replace(blocking_these,',','')) desc, blocking_these desc, blocked_by desc, session_id asc +*/ + + + print 'done' + go + drop table #ExecRequests + + diff --git a/sessions sql2000.sql b/sessions sql2000.sql new file mode 100644 index 0000000..c034dfb --- /dev/null +++ b/sessions sql2000.sql @@ -0,0 +1,36 @@ +use master +go +declare @sql_handle binary(20) +select *, DBName = db_name(dbid) from sys.sysprocesses sysprc +where spid <> @@SPID +--and db_name(dbid) = 'LPMS_BE' +order by blocked desc, spid asc + +declare cursyssysprocesses cursor fast_forward for +select sql_handle from sys.sysprocesses +where spid >= 50 +and sql_handle <> convert(binary(20), 0x0000000000000000000000000000000000000000)--status='runnable'; +and spid <> @@SPID +and db_name(dbid) = 'LPMS_BE' +open cursyssysprocesses; + fetch next from cursyssysprocesses into @sql_handle; + while (@@FETCH_STATUS =0) + BEGIN + select + b.hostname + , c.name + , b.program_name + , b.loginame + , b.spid + , getsql.text + , getsql.objectid + , DatabaseName = db_name(getsql.dbid) + , getsql.dbid + from sys.fn_get_sql(@sql_handle) getsql + cross join sysprocesses b + inner join sys.sysdatabases c on c.dbid=b.dbid + where b.sql_handle =@sql_handle + fetch next from cursyssysprocesses into @sql_handle; + END +close cursyssysprocesses +deallocate cursyssysprocesses diff --git a/size in memory.sql b/size in memory.sql new file mode 100644 index 0000000..0fa27a5 --- /dev/null +++ b/size in memory.sql @@ -0,0 +1,33 @@ +use w +go +select top 100 objectname, indexname, [object_id], index_id, Buffer_MB = SUM(Buffer_MB) +from +( + SELECT + objectname = obj.[name], + indexname = i.[name], + obj.[object_id], + i.[index_id], + i.[type_desc], + --count(*)AS Buffered_Page_Count , + count(*) * 8192.0 / (1024.0 * 1024.0) as Buffer_MB + -- ,obj.name ,obj.index_id, i.[name] + FROM sys.dm_os_buffer_descriptors AS bd + INNER JOIN + ( + SELECT object_name(object_id) AS name + ,index_id ,allocation_unit_id, object_id + FROM sys.allocation_units AS au + INNER JOIN sys.partitions AS p + ON au.container_id = p.hobt_id + ) AS obj + ON bd.allocation_unit_id = obj.allocation_unit_id + LEFT OUTER JOIN sys.indexes i on i.object_id = obj.object_id AND i.index_id = obj.index_id + + WHERE database_id = db_id() + + + GROUP BY obj.name, obj.index_id , i.[name],i.[type_desc], obj.[object_id], i.index_id +) x + GROUP BY objectname, indexname, [type_desc], [object_id], index_id + order by Buffer_MB desc diff --git a/size.sql b/size.sql new file mode 100644 index 0000000..3d9271f --- /dev/null +++ b/size.sql @@ -0,0 +1,46 @@ +--Database files on disk +select d.name, Initial_size = (size*8.)/1024., * from sys.master_files mf +inner join sys.databases d +on mf.database_id = d.database_id +order by size desc + +--Size of files in current database +select name, SizeMb = size *8./2014. +from sys.database_files + +--Tables in current database +select sizemb = SUM(sizemb), tablename from ( +select SizeMb= (p.in_row_reserved_page_count*8.)/1024., +tablename = o.name, indexname = i.name +from sys.dm_db_partition_stats p +inner join sys.objects o on p.object_id = o.object_id +inner join sys.indexes i on i.object_id = o.object_id and i.index_id = p.index_id +where o.is_ms_shipped = 0 +) x +group by tablename +order by sizemb desc + +--Index/partitions in current database +select SizeMb= (p.in_row_reserved_page_count*8.)/1024. +, indexname = i.name +, tablename = '[' + s.name + '].[' + o.name + ']' +, pr.data_compression_desc +, p.partition_number +, rebuildcompress = +CASE WHEN pr.data_compression_desc = 'columnstore' THEN NULL ELSE + 'ALTER INDEX [' + i.name + '] ON [' + s.name + '].[' + o.name + '] REBUILD ' + + CASE WHEN MAX(p.partition_number) OVER (PARTITION by i.name) > 1 THEN + 'PARTITION = ' + cast(p.partition_number as varchar(5)) ELSE '' END + + ' WITH (SORT_IN_TEMPDB = ON + , DATA_COMPRESSION = PAGE) ' + CHAR(10) + CHAR(13) +END +, * +from sys.dm_db_partition_stats p +inner join sys.partitions pr on p.partition_id = pr.partition_id +inner join sys.objects o on p.object_id = o.object_id +inner join sys.schemas s on s.schema_id = o.schema_id +left outer join sys.indexes i on i.object_id = o.object_id and i.index_id = p.index_id +WHERE o.is_ms_shipped = 0 + +order by SizeMb desc + diff --git a/sp_GetAGInformation.sql b/sp_GetAGInformation.sql new file mode 100644 index 0000000..380d53c --- /dev/null +++ b/sp_GetAGInformation.sql @@ -0,0 +1,259 @@ +CREATE PROCEDURE sp_GetAGInformation + +AS +--http://sirsql.net/blog/2014/10/26/gathering-ag-information-spgetaginformation +/****************************************************************************************************************** +* * +* Proc will gather relevant AG information on the currently selected node. * +* It will only return information for AGs for which this is the primary as certain information is only kept there * +* * +******************************************************************************************************************/ + +/* Declare a whole bunch of table variables. It may seem ugly, but it is far more efficient than constantly + joining back to the TVFs and DMVs which hold the AG information +*/ +DECLARE @RoutingOrder TABLE ( + Replica_ID UNIQUEIDENTIFIER + , routing_priority INT + , read_only_replica_id UNIQUEIDENTIFIER + , PrimaryServer nvarchar(512) + , ReadReplica NVARCHAR(512) + ) + +DECLARE @ReadRoutingFinal TABLE ( + name SYSNAME + , availability_mode TINYINT + , failover_mode TINYINT + , ReadRoutingOrder NVARCHAR(1000) + ) + +DECLARE @AvailabilityGroups TABLE ( + Name SYSNAME + , group_id UNIQUEIDENTIFIER + ) + +DECLARE @AvailabilityReplicas TABLE ( + group_id UNIQUEIDENTIFIER + , replica_id UNIQUEIDENTIFIER + , replica_server_name NVARCHAR(256) + , availability_mode TINYINT + , failover_mode TINYINT + ) + +DECLARE @AvailabilityReplicaStates TABLE ( + group_id UNIQUEIDENTIFIER + , replica_id UNIQUEIDENTIFIER + , role_desc NVARCHAR(60) + , role TINYINT + ) + +DECLARE @AvailabilityDatabases TABLE ( + name SYSNAME + , database_name NVARCHAR(256) + ) + +DECLARE @AGDatabasesFinal TABLE ( + name SYSNAME + , DatabaseList NVARCHAR(1000) + ) + +/* Load up the table vars with the relevant data from each DMV */ +INSERT INTO @AvailabilityReplicaStates + SELECT group_id + , replica_id + , role_desc + , role + FROM sys.dm_hadr_availability_replica_states + + +INSERT INTO @AvailabilityReplicas + SELECT group_id + , replica_id + , replica_server_name + , availability_mode + , failover_mode + FROM sys.availability_replicas + + +INSERT INTO @AvailabilityGroups + SELECT name + , group_id + FROM sys.availability_groups + + +INSERT INTO @RoutingOrder + SELECT l.replica_id + , l.routing_priority + , l.read_only_replica_id + , r.replica_server_name as PrimaryServer + , r2.replica_server_name as ReadReplica + FROM sys.availability_read_only_routing_lists l + join @AvailabilityReplicas r on l.replica_id = r.replica_id + join @AvailabilityReplicas r2 on l.read_only_replica_id = r2.replica_id + + + --Aggregate Read Routing for report +;with cteReadReplicas AS ( + select replica_id + ,PrimaryServer + , STUFF((SELECT N', ' + ReadReplica FROM @RoutingOrder cr2 WHERE cr2.PrimaryServer = cr.PrimaryServer and cr2.replica_id = cr.replica_id order by cr2.routing_priority + for xml path(N''), type).value(N'.[1]', N'nvarchar(1000)'),1,2,N'') as ReadRoutingOrder + from @RoutingOrder cr + group by Replica_ID, PrimaryServer + ) + + + --Final details for read routing +INSERT INTO @ReadRoutingFinal + select + ag.name + , ar.availability_mode --1 sync, 2 async + , ar.failover_mode --0 auto, 1 manual + , c.ReadRoutingOrder + From @AvailabilityGroups ag + join @AvailabilityReplicas ar on ag.group_id = ar.group_id + join @AvailabilityReplicaStates hars on ar.group_id = hars.group_id and ar.replica_id = hars.replica_id + left join cteReadReplicas c on hars.replica_id = c.replica_id and hars.role = 1 + where hars.role = 1 + + + --Details for Databases in an AG +INSERT INTO @AvailabilityDatabases + SELECT a.name + , adc.database_name + FROM sys.availability_databases_cluster adc + JOIN @AvailabilityGroups a ON a.group_id = adc.group_id + +INSERT INTO @AGDatabasesFinal + SELECT name + , STUFF((SELECT N', ' + database_name FROM @AvailabilityDatabases ad2 WHERE ad2.name = ad.name order by ad2.database_name + for xml path(N''), type).value(N'.[1]', N'nvarchar(1000)'),1,2,N'') as DatabaseList + FROM @AvailabilityDatabases ad + GROUP BY name + + + --The primary for the AG +;with ctePrimary AS + ( + select + ag.name + , ar.availability_mode --1 sync, 2 async + , ar.replica_server_name as PrimaryReplica + , ar.replica_id as PrimaryReplicaId + , ar.failover_mode --0 auto, 1 manual + From @AvailabilityGroups ag + join @AvailabilityReplicas ar on ag.group_id = ar.group_id + join @AvailabilityReplicas ar2 on ag.group_id = ar2.group_id + join @AvailabilityReplicaStates hars on ar.group_id = hars.group_id and ar.replica_id = hars.replica_id + where hars.role_desc = 'PRIMARY' + group by ag.name, ar.availability_mode, ar.replica_server_name, ar.replica_id, ar.failover_mode, hars.role_desc + ) + + --Any auto failover partners +, cteFailoverPartner AS ( + select + ag.name + , ar.replica_server_name as FailoverPartner + From @AvailabilityGroups ag + join @AvailabilityReplicas ar on ag.group_id = ar.group_id + join @AvailabilityReplicas ar2 on ag.group_id = ar2.group_id + join @AvailabilityReplicaStates hars on ar.group_id = hars.group_id and ar.replica_id = hars.replica_id + where hars.role_desc = 'SECONDARY' and ar.availability_mode = 1 and ar.failover_mode = 0 + group by ag.name, ar.availability_mode, ar.replica_server_name, ar.replica_id, ar.failover_mode + ) + + + + --Any sync secondary replicas +, cteSyncSecondary AS ( + select + ag.name + , ar.replica_server_name as SyncSecondary + , ROW_NUMBER() OVER (PARTITION BY ag.name ORDER BY CASE WHEN ar.failover_mode = 0 THEN 1 ELSE 2 END) as SyncRowNum + From @AvailabilityGroups ag + join @AvailabilityReplicas ar on ag.group_id = ar.group_id + join @AvailabilityReplicas ar2 on ag.group_id = ar2.group_id + join @AvailabilityReplicaStates hars on ar.group_id = hars.group_id and ar.replica_id = hars.replica_id + where hars.role_desc = 'SECONDARY' and ar.availability_mode = 1 --and ar.failover_mode = 0 + group by ag.name, ar.availability_mode, ar.replica_server_name, ar.replica_id, ar.failover_mode + ) + + --Any async secondary replicas +, cteAsyncSecondary AS ( + select + ag.name + , ar.replica_server_name as AsyncSecondary + , ROW_NUMBER() OVER (PARTITION BY ag.name ORDER BY ar.replica_server_name) as ASyncRowNum + From @AvailabilityGroups ag + join @AvailabilityReplicas ar on ag.group_id = ar.group_id + join @AvailabilityReplicas ar2 on ag.group_id = ar2.group_id + join @AvailabilityReplicaStates hars on ar.group_id = hars.group_id and ar.replica_id = hars.replica_id + where hars.role_desc = 'SECONDARY' and ar.availability_mode = 0 --and ar.failover_mode = 0 + group by ag.name, ar.availability_mode, ar.replica_server_name, ar.replica_id, ar.failover_mode + ) + + --Build Sync replica basic information +, ctePartnerResults AS ( + select c1.*, c2.FailoverPartner, c3.SyncSecondary, c3.SyncRowNum + From ctePrimary c1 + left join cteFailoverPartner c2 on c1.name = c2.name + left join cteSyncSecondary c3 on c1.name = c3.name + group by c1.name, c1.availability_mode, c1.PrimaryReplica, c1.PrimaryReplicaId, c1.failover_mode + , c2.FailoverPartner + , c3.SyncSecondary, c3.SyncRowNum + ) + + --Build comma delimited sync secondary list +, cteSyncList AS ( + select + name + , PrimaryReplica + , FailoverPartner + , STUFF((SELECT N', ' + cpr2.SyncSecondary FROM ctePartnerResults cpr2 WHERE cpr2.name = cpr.name order by cpr2.SyncRowNum + for xml path(N''), type).value(N'.[1]', N'nvarchar(1000)'),1,2,N'') as SyncSecondaries + from ctePartnerResults cpr + group by name, FailoverPartner, PrimaryReplica + ) + + --Build async replica basic information +, cteASyncPartnerResults AS ( + select c1.*, c2.FailoverPartner, c4.AsyncSecondary, c4.ASyncRowNum + From ctePrimary c1 + left join cteFailoverPartner c2 on c1.name = c2.name + left join cteAsyncSecondary c4 on c1.name = c4.name + group by c1.name, c1.availability_mode, c1.PrimaryReplica, c1.PrimaryReplicaId, c1.failover_mode + , c2.FailoverPartner + , c4.AsyncSecondary, c4.ASyncRowNum + ) + + --Build comma delimited sync secondary list +, cteASyncList AS ( + select + name + , FailoverPartner + , STUFF((SELECT N', ' + cpr2.ASyncSecondary FROM cteASyncPartnerResults cpr2 WHERE cpr2.name = cpr.name order by cpr2.ASyncRowNum + for xml path(N''), type).value(N'.[1]', N'nvarchar(1000)'),1,2,N'') as ASyncSecondaries + from cteASyncPartnerResults cpr + group by name, FailoverPartner + ) + + --Merge all the data and give the complete AG reference +select + csl.name as AGName + , ISNULL(agl.dns_name,'') as ListenerName + , csl.PrimaryReplica + , ISNULL(csl.FailoverPartner,'') as AutoFailoverPartner + , ISNULL(csl.SyncSecondaries, '') as SyncSecondaries + , ISNULL(casl.ASyncSecondaries, '') as ASyncSecondaries + , ISNULL(crr.ReadRoutingOrder, '') as ReadRoutingOrder + , DatabaseList +from cteSyncList csl + join @AvailabilityGroups ag on csl.name = ag.name + join @AGDatabasesFinal adf on ag.name = adf.name + left join sys.availability_group_listeners agl on ag.group_id = agl.group_id + left join cteASyncList casl on csl.name = casl.name + left join @ReadRoutingFinal crr on csl.name = crr.name +where PrimaryReplica = @@servername +OPTION (MAXDOP 1, RECOMPILE) + + diff --git a/space in files.sql b/space in files.sql new file mode 100644 index 0000000..596fa70 --- /dev/null +++ b/space in files.sql @@ -0,0 +1,102 @@ +DECLARE @TempTable TABLE +( DatabaseName varchar(128) +,recovery_model_desc varchar(50) +,DatabaseFileName varchar(500) +,FileLocation varchar(500) +,FileId int +,FileSizeMB decimal(19,2) +,SpaceUsedMB decimal(19,2) +,AvailableMB decimal(19,2) +,FreePercent decimal(19,2) +) + +INSERT INTO @TempTable +exec sp_MSforeachdb 'use [?]; +SELECT + ''DatabaseName_____________'' = d.name +, Recovery = d.recovery_model_desc +, ''DatabaseFileName_______'' = df.name +, ''Location_______________________________________________________________________'' = df.physical_name +, df.File_ID +, FileSizeMB = CAST(size/128.0 as Decimal(9,2)) +, SpaceUsedMB = CAST(CAST(FILEPROPERTY(df.name, ''SpaceUsed'') AS int)/128.0 as Decimal(9,2)) +, AvailableMB = CAST(size/128.0 - CAST(FILEPROPERTY(df.name, ''SpaceUsed'') AS int)/128.0 as Decimal(9,2)) +, ''Free%'' = CAST((((size/128.0) - (CAST(FILEPROPERTY(df.name, ''SpaceUsed'') AS int)/128.0)) / (size/128.0) ) * 100. as Decimal(9,2)) + FROM sys.database_files df + cross apply sys.databases d + where d.database_id = DB_ID() + and size > 0 +' + +SELECT + * +FROM @TempTable + +ORDER BY DatabaseName,FileId +/* + +alter database [SP13PROD_SearchService_DB_AnalyticsReportingStore] set recovery simple +use Neill_12182014; +DBCC SHRINKFILE (N'Neill' , 1) +DBCC SHRINKFILE (N'RAMI_LIVE_log' , 100) +*/ + +/* +SELECT + 'DatabaseName_____________' = d.name +, Recovery = d.recovery_model_desc +, 'DatabaseFileName_______' = df.name +, 'Location_______________________________________________________________________' = df.physical_name +, df.File_ID +, FileSizeMB = CAST(size/128.0 as Decimal(9,2)) +, SpaceUsedMB = CAST(CAST(FILEPROPERTY(df.name, 'SpaceUsed') AS int)/128. as Decimal(9,2)) +, AvailableMB = CAST(size/128.0 - CAST(FILEPROPERTY(df.name, 'SpaceUsed') AS int)/128.0 as Decimal(9,2)) +, 'Free%' = CAST((((size/128.0) - (CAST(FILEPROPERTY(df.name, 'SpaceUsed') AS int)/128.0)) / (size/128.0) ) * 100. as Decimal(9,2)) + FROM sys.database_files df + cross apply sys.databases d + where d.database_id = DB_ID() + +GO + +select * from sys.database_files df + + +DBCC PAGE ( 2 , 1 , 103 , 3 ) + + +SELECT DB_NAME(database_id) as database_name, physical_name, SizeMB = (size*8./1024.) , * +FROM sys.master_files mf +WHERE DB_NAME(database_id) = 'tempdb' + + +tempdb SIMPLE tempdev S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb.mdf 350.00 2.81 347.19 99.20 +tempdb SIMPLE templog S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\templog.ldf 9.94 1.81 8.13 81.76 +tempdb SIMPLE tempdev2 S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb2.ndf 350.00 0.06 349.94 99.98 + +tempdb SIMPLE tempdev S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb.mdf 350.00 3.63 346.38 98.96 +tempdb SIMPLE templog S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\templog.ldf 9.94 1.95 7.98 80.35 +tempdb SIMPLE tempdev2 S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb2.ndf 350.00 0.19 349.81 99.95 + +tempdb SIMPLE tempdev S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb.mdf 350.00 3.19 346.81 99.09 +tempdb SIMPLE templog S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\templog.ldf 9.94 2.29 7.65 76.97 +tempdb SIMPLE tempdev2 S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb2.ndf 350.00 0.13 349.88 99.96 + +tempdb SIMPLE tempdev S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb.mdf 1329.56 1093.25 236.31 17.77 +tempdb SIMPLE templog S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\templog.ldf 10.94 10.45 0.49 4.50 +tempdb SIMPLE tempdev2 S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb2.ndf 1329.56 958.63 370.94 27.90 + +tempdb SIMPLE tempdev S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb.mdf 1329.56 3.38 1326.19 99.75 +tempdb SIMPLE templog S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\templog.ldf 10.94 1.45 9.48 86.71 +tempdb SIMPLE tempdev2 S:\MSSQL\MSSQL10_50.MSSQLSERVER\MSSQL\DATA\tempdb2.ndf 1329.56 0.25 1329.31 99.98 + + +create table #tempfiller +(text1 char(8000) +) +go +insert into #tempfiller values ('a') +insert into #tempfiller +select TEXT1 from #tempfiller +go 100 +drop table #tempfiller +*/ \ No newline at end of file diff --git a/space in log files.sql b/space in log files.sql new file mode 100644 index 0000000..a7b1d63 --- /dev/null +++ b/space in log files.sql @@ -0,0 +1,34 @@ +--displays each transaction log size and space used. + +--http://sqlblog.com/blogs/jonathan_kehayias/archive/2009/06/06/getting-log-space-usage-without-using-dbcc-sqlperf.aspx +SELECT instance_name AS DatabaseName, + [Data File(s) Size (KB)], + [Log File(s) Size (KB)], + [Log File(s) Used Size (KB)], + [Percent Log Used] +FROM +( + SELECT * + FROM sys.dm_os_performance_counters + WHERE counter_name IN + ( + 'Data File(s) Size (KB)', + 'Log File(s) Size (KB)', + 'Log File(s) Used Size (KB)', + 'Percent Log Used' + ) + AND instance_name not in ('_Total', 'mssqlsystemresource') + +) AS Src +PIVOT +( + MAX(cntr_value) + FOR counter_name IN + ( + [Data File(s) Size (KB)], + [Log File(s) Size (KB)], + [Log File(s) Used Size (KB)], + [Percent Log Used] + ) +) AS pvt +ORDER BY [Percent Log Used] desc diff --git a/sproc sessions and requests.sql b/sproc sessions and requests.sql new file mode 100644 index 0000000..108bef9 --- /dev/null +++ b/sproc sessions and requests.sql @@ -0,0 +1,132 @@ +CREATE procedure dbo.CaptureLongRunningQueries as +begin + + If Exists ( select 1 from sys.dm_exec_requests where blocking_session_id > 0) + or + Exists ( select 1 from sys.dm_exec_requests where total_elapsed_time > 10000 and session_id >= 50 ) --10s + BEGIN + + create table #ExecRequests ( + id int IDENTITY(1,1) PRIMARY KEY + , session_id smallint not null + , request_id int null + , request_start_time datetime null + , login_time datetime not null + , login_name nvarchar(256) null + , client_interface_name nvarchar(64) + , session_status nvarchar(60) null + , request_status nvarchar(60) null + , command nvarchar(32) null + , sql_handle varbinary(64) null + , statement_start_offset int null + , statement_end_offset int null + , plan_handle varbinary (64) null + , database_id smallint null + , user_id int null + , blocking_session_id smallint null + , wait_type nvarchar (120) null + , wait_time_s int null + , wait_resource nvarchar(120) null + , last_wait_type nvarchar(120) null + , cpu_time_s int null + , tot_time_s int null + , reads bigint null + , writes bigint null + , logical_reads bigint null + , [host_name] nvarchar(256) null + , [program_name] nvarchar(256) null + , blocking_these varchar(1000) NULL + , percent_complete int null + , session_transaction_isolation_level varchar(20) null + , request_transaction_isolation_level varchar(20) null + ) + + insert into #ExecRequests (session_id,request_id, request_start_time, login_time, login_name, client_interface_name, session_status, request_status, command,sql_handle,statement_start_offset,statement_end_offset,plan_handle,database_id,user_id,blocking_session_id,wait_type,last_wait_type,wait_time_s,wait_resource,cpu_time_s,tot_time_s,reads,writes,logical_reads,[host_name], [program_name] , session_transaction_isolation_level , request_transaction_isolation_level ) + select s.session_id,request_id, r.start_time, s.login_time, s.login_name, s.client_interface_name, s.status, r.status,command,sql_handle,statement_start_offset,statement_end_offset,plan_handle,r.database_id,user_id,blocking_session_id,wait_type,r.last_wait_type, r.wait_time/1000.,r.wait_resource ,r.cpu_time/1000.,r.total_elapsed_time/1000.,r.reads,r.writes,r.logical_reads,s.[host_name], s.[program_name], s.transaction_isolation_level, r.transaction_isolation_level + from sys.dm_exec_sessions s + left outer join sys.dm_exec_requests r on r.session_id = s.session_id + where 1=1 + and s.session_id >= 50 --retrieve only user spids + and s.session_id <> @@SPID --ignore myself + + update #ExecRequests + set blocking_these = LEFT((select isnull(convert(varchar(5), er.session_id),'') + ', ' + from #ExecRequests er + where er.blocking_session_id = isnull(#ExecRequests.session_id ,0) + and er.blocking_session_id <> 0 + FOR XML PATH('') + ),1000) + + + + INSERT INTO DBALogging.dbo.SessionsAndRequestsLog + select * + from + ( + select + timestamp = getdate() + , r.session_id , r.host_name , r.program_name + , r.session_status + , r.request_status + , r.blocking_these + , blocked_by = r.blocking_session_id + , r.wait_type + , r.wait_resource + , r.last_wait_type + , DBName = db_name(r.database_id) + , r.command + , login_time + , login_name + , client_interface_name + , request_start_time + , r.tot_time_s, r.wait_time_s, r.cpu_time_s, r.reads, r.writes, r.logical_reads + --, [fulltext] = est.[text] + , offsettext = CASE WHEN r.statement_start_offset = 0 and r.statement_end_offset= 0 THEN NULL + ELSE SUBSTRING ( est.[text] + , r.statement_start_offset/2 + 1, + CASE WHEN r.statement_end_offset = -1 THEN LEN (CONVERT(nvarchar(max), est.[text])) + ELSE r.statement_end_offset/2 - r.statement_start_offset/2 + 1 + END ) + END + , r.statement_start_offset, r.statement_end_offset + , cacheobjtype = LEFT (p.cacheobjtype + ' (' + p.objtype + ')', 35) + , QueryPlan = qp.query_plan + , request_transaction_isolation_level = case request_transaction_isolation_level + when 0 then 'Unspecified' + when 1 then 'ReadUncommitted' + when 2 then 'ReadCommitted' + when 3 then 'Repeatable' + when 4 then 'Serializable' + when 5 then 'Snapshot' end + , session_transaction_isolation_level = case session_transaction_isolation_level + when 0 then 'Unspecified' + when 1 then 'ReadUncommitted' + when 2 then 'ReadCommitted' + when 3 then 'Repeatable' + when 4 then 'Serializable' + when 5 then 'Snapshot' end + , p.plan_handle + , stat.execution_count, stat.total_worker_time, stat.last_worker_time, stat.total_elapsed_time, stat.last_elapsed_time, stat.total_physical_reads, stat.total_logical_writes, stat.total_logical_reads, stat.total_rows, stat.last_rows + from #ExecRequests r + LEFT OUTER JOIN sys.dm_exec_cached_plans p ON p.plan_handle = r.plan_handle + OUTER APPLY sys.dm_exec_query_plan (r.plan_handle) qp + OUTER APPLY sys.dm_exec_sql_text (r.sql_handle) est + LEFT OUTER JOIN sys.dm_exec_query_stats stat on stat.plan_handle = r.plan_handle or stat.sql_handle = r.sql_handle + WHERE + ( r.blocking_these is not null + or r.blocking_session_id is not null + or r.request_status is not null + ) + + ) a + + order by session_id asc + + drop table #ExecRequests + + END +end +go +--drop table DBALogging.dbo.SessionsAndRequestsLog +exec CaptureLongRunningQueries +select * from DBALogging.dbo.SessionsAndRequestsLog order by timestamp desc \ No newline at end of file diff --git a/sql agent execution lab.sql b/sql agent execution lab.sql new file mode 100644 index 0000000..7d21501 --- /dev/null +++ b/sql agent execution lab.sql @@ -0,0 +1,232 @@ +--Create job to test out how the jobs execute. + +USE [msdb] +GO + +/****** Object: Job [CredTest] Script Date: 2/10/2016 10:08:28 AM ******/ +BEGIN TRANSACTION +DECLARE @ReturnCode INT +SELECT @ReturnCode = 0 +/****** Object: JobCategory [[Uncategorized (Local)]] Script Date: 2/10/2016 10:08:28 AM ******/ +IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1) +BEGIN +EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]' +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback + +END + +DECLARE @jobId BINARY(16) +EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'CredTest', + @enabled=1, + @notify_level_eventlog=0, + @notify_level_email=0, + @notify_level_netsend=0, + @notify_level_page=0, + @delete_level=0, + @description=N'No description available.', + @category_name=N'[Uncategorized (Local)]', + @owner_login_name=N'sa', @job_id = @jobId OUTPUT +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +/****** Object: Step [A_TSQL] Script Date: 2/10/2016 10:08:28 AM ******/ +EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'A_TSQL', + @step_id=1, + @cmdexec_success_code=0, + @on_success_action=3, + @on_success_step_id=0, + @on_fail_action=2, + @on_fail_step_id=0, + @retry_attempts=0, + @retry_interval=0, + @os_run_priority=0, @subsystem=N'TSQL', + @command=N'SET NOCOUNT ON +SELECT + CAST(ORIGINAL_LOGIN() AS VARCHAR(20)) AS Original_login +,CAST(SUSER_SNAME() AS VARCHAR(20)) AS Effective_user +,CAST(USER_NAME() AS VARCHAR(20)) AS Db_user', + @database_name=N'master', + @flags=8 +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +/****** Object: Step [B_OS] Script Date: 2/10/2016 10:08:28 AM ******/ +EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'B_OS', + @step_id=2, + @cmdexec_success_code=0, + @on_success_action=1, + @on_success_step_id=0, + @on_fail_action=2, + @on_fail_step_id=0, + @retry_attempts=0, + @retry_interval=0, + @os_run_priority=0, @subsystem=N'CmdExec', + @command=N'whoami.exe', + @flags=8, + @proxy_name=N'ssis_cmdexec_proxy' +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1 +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)' +IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback +COMMIT TRANSACTION +GOTO EndSave +QuitWithRollback: + IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION +EndSave: + +GO + + +--Testing + +--TODO: Create cred for a sysadmin called ssiscred + +USE [msdb] +GO + +/****** Object: ProxyAccount [ssis_cmdexec_proxy] Script Date: 2/10/2016 10:05:34 AM ******/ +EXEC msdb.dbo.sp_add_proxy @proxy_name=N'ssis_cmdexec_proxy',@credential_name=N'ssiscred', + @enabled=1 +GO + +EXEC msdb.dbo.sp_grant_proxy_to_subsystem @proxy_name=N'ssis_cmdexec_proxy', @subsystem_id=3 +GO + +EXEC msdb.dbo.sp_grant_login_to_proxy @proxy_name=N'ssis_cmdexec_proxy', @login_name=N'SPARKHOUND\shawn.usher' +GO + +USE [msdb] +GO +EXEC msdb.dbo.sp_update_proxy @proxy_name=N'ssis_cmdexec_proxy',@credential_name=N'ssiscred', + @description=N'' +GO +EXEC msdb.dbo.sp_grant_login_to_proxy @proxy_name=N'ssis_cmdexec_proxy', @login_name=N'SPARKHOUND\shawn.usher' +GO + +select * from msdb..sysjobstepslogs + +--- owned by sa, no proxy on cmdexec (run as SQL Server Service Account), SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 09:18:38 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +SPARKHOUND\CORP-8KJT NT SERVICE\SQLAgent$ dbo + + +nt service\sqlagent$sql2k14 + + +--owned by sparkhound\shawn.usher (not a sysadmin), no proxy on cmdexec (run as SQL Server Service Account), SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 + +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 09:27:41 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +SPARKHOUND\CORP-8KJT NT SERVICE\SQLAgent$ dbo + +nt service\sqlagent$sql2k14 + +--owned by sparkhound\william.assaf (in the sysadmin role), no proxy on cmdexec (run as SQL Server Service Account), SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 + +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 09:25:12 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +SPARKHOUND\CORP-8KJT NT SERVICE\SQLAgent$ dbo + +nt service\sqlagent$sql2k14 + + + +--- owned by sa, with proxy ssis_cmdexec_proxy on the cmdexec step, SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 + +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:02:45 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +SPARKHOUND\CORP-8KJT NT SERVICE\SQLAgent$ dbo + +sparkhound\william.assaf + +--owned by sparkhound\shawn.usher (not a sysadmin), with proxy ssis_cmdexec_proxy on the cmdexec step, SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14. Fails unless non-sysadmin has permission to use the Proxy. + +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:05:56 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +SPARKHOUND\CORP-8KJT SPARKHOUND\shawn.ush guest + +sparkhound\william.assaf + + +--owned by sparkhound\william.assaf (in the sysadmin role), with proxy ssis_cmdexec_proxy on the cmdexec step, SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:06:31 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +SPARKHOUND\CORP-8KJT NT SERVICE\SQLAgent$ dbo + +sparkhound\william.assaf + + +--Create and switch SQL Agent service account to a local machine user in the local administrators group called (local machine name)\svc_local_SQLAgent + + +select * from msdb..sysjobstepslogs + +--- owned by sa, no proxy on cmdexec (run as SQL Server Service Account), SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:21:35 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +CORP-8KJTYZ1\svc_loc CORP-8KJTYZ1\svc_loc dbo + +corp-8kjtyz1\svc_local_sqlagent + +--owned by sparkhound\shawn.usher (not a sysadmin), no proxy on cmdexec (run as SQL Server Service Account), SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:22:05 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +CORP-8KJTYZ1\svc_loc SPARKHOUND\shawn.ush guest + +!!!Non-SysAdmins have been denied permission to run CmdExec job steps without a proxy account. The step failed. + +--owned by sparkhound\william.assaf (in the sysadmin role), no proxy on cmdexec (run as SQL Server Service Account), SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 + +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:23:06 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +CORP-8KJTYZ1\svc_loc CORP-8KJTYZ1\svc_loc dbo + +corp-8kjtyz1\svc_local_sqlagent + + +--- owned by sa, with proxy ssis_cmdexec_proxy on the cmdexec step, SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 + +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:24:22 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +CORP-8KJTYZ1\svc_loc CORP-8KJTYZ1\svc_loc dbo + +sparkhound\william.assaf + + +--owned by sparkhound\shawn.usher (not a sysadmin), with proxy ssis_cmdexec_proxy on the cmdexec step, SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14. Fails unless non-sysadmin has permission to use the Proxy. +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:25:34 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +CORP-8KJTYZ1\svc_loc SPARKHOUND\shawn.ush guest + +sparkhound\william.assaf + +--owned by sparkhound\william.assaf (in the sysadmin role), with proxy ssis_cmdexec_proxy on the cmdexec step, SQLAgent svcaccount is NT Service\SQLAgent$SQL2K14 + +Job 'CredTest' : Step 1, 'A_TSQL' : Began Executing 2016-02-10 10:26:04 + +Original_login Effective_user Db_user +-------------------- -------------------- -------------------- +CORP-8KJTYZ1\svc_loc CORP-8KJTYZ1\svc_loc dbo + +sparkhound\william.assaf + diff --git a/ssis events.sql b/ssis events.sql new file mode 100644 index 0000000..a995dbd Binary files /dev/null and b/ssis events.sql differ diff --git a/ssisdb execution query.sql b/ssisdb execution query.sql new file mode 100644 index 0000000..4b870ef --- /dev/null +++ b/ssisdb execution query.sql @@ -0,0 +1,19 @@ + +SELECT + om.message +, om.message_time +, em.execution_path +, em.package_name +, em.event_name +, em.message_source_name +, o.start_time +, o.end_time +, o.caller_name +, o.server_name +, o.machine_name +, * + FROM [SSISDB].internal.event_messages em + inner join ssisdb.internal.operations o on em.operation_id =o.operation_id + inner join ssisdb.internal.operation_messages om on om.operation_message_id = em.event_message_id + where o.operation_id = 10205 + order by o.operation_id, em.event_message_id \ No newline at end of file diff --git a/stats out of date whileloop.sql b/stats out of date whileloop.sql new file mode 100644 index 0000000..66be0d9 --- /dev/null +++ b/stats out of date whileloop.sql @@ -0,0 +1,78 @@ +--This script only works in SQL2008R2SP2+ or SQL2012SP1+ + +--TODO BEFORE EXECUTING: comment out three lines below in 1 THEN p.partition_number ELSE null END +-- , sta.is_incremental --Only works in SQL 2014+, comment out this line in prior versions. + , ''[?]'' AS [?] + , TSQL = CASE WHEN I.type_desc like ''%columnstore%'' THEN NULL ELSE + N''USE [?]; '' + + N''UPDATE STATISTICS '' + + QUOTENAME(s.name) + N''.'' + QUOTENAME(o.name) + N'' '' + + QUOTENAME(sta.name) + N'' '' + + ''WITH RESAMPLE'' + + CASE WHEN +-- sta.Is_Incremental = 1 and --Only works in SQL 2014+, comment out this line in prior versions. + MAX(p.partition_number) OVER (PARTITION by sta.name, i.name) > 1 THEN '' ON PARTITIONS ('' + cast(p.partition_number as varchar(5)) + '') '' ELSE '''' END + + END + FROM sys.objects o + INNER JOIN sys.stats sta ON sta.object_id = o.object_id + CROSS APPLY sys.dm_db_stats_properties (sta.object_id, sta.stats_id) sp -- Only works in SQL2008R2SP2+ or SQL2012SP1+ + INNER JOIN sys.schemas AS s + ON o.schema_id = s.schema_id + LEFT OUTER JOIN sys.indexes as I + on I.index_id = STA.stats_id + and (I.type_desc not like ''%columnstore%'') + LEFT OUTER join sys.dm_db_partition_stats p + on ( +-- sta.Is_Incremental = 1 and --Only works in SQL 2014+, comment out this line in prior versions. + p.object_id = o.object_id and + i.index_id = p.index_id + ) + LEFT JOIN + (SELECT IUS.object_id + ,MIN(ISNULL(IUS.last_user_update, IUS.last_system_update)) AS LastUpdate + FROM sys.dm_db_index_usage_stats AS IUS + WHERE database_id = DB_ID() + AND NOT ISNULL(IUS.last_user_update, IUS.last_system_update) IS NULL + GROUP BY IUS.object_id + ) AS IUS + ON IUS.object_id = STA.object_id + WHERE o.type IN (''U'', ''V'') -- only user tables and views + AND DATEDIFF(d, ISNULL(STATS_DATE(STA.object_id, STA.stats_id), N''1900-01-01'') , IUS.LastUpdate) > 30 --indexes that haven''t been updated in the last month + AND sp.modification_counter > 1000 + ORDER BY Rows_Changed desc, Stats_Last_Updated desc + OPTION (MAXDOP 1) ' + +declare @dblist table (id int not null identity(1,1) primary key, dbname sysname not null) +declare @x int = 1, @xmax int = null, @dbname sysname, @runtsql nvarchar(max) = null +insert into @dblist +select name from sys.databases +where state_desc = 'online' and database_id > 4 +select @xmax = max(id) from @dblist l + +while (@x <= @xmax) +BEGIN + select @dbname = dbname from @dblist l where @x = id + + select @runtsql = replace(@tsql, N'?', @dbname) + + --generates scripts, does not actually perform the UPDATE STATISTICS. Use the column [TSQL]. + exec sp_executesql @runtsql + + set @x = @x + 1 +END + +/* + +*/ diff --git a/stats out of date.sql b/stats out of date.sql new file mode 100644 index 0000000..e7c4bf1 --- /dev/null +++ b/stats out of date.sql @@ -0,0 +1,61 @@ +--This script only works in SQL2008R2SP2+ or SQL2012SP1+ + +--TODO BEFORE EXECUTING: comment out three lines below in 1 THEN p.partition_number ELSE null END + , sta.is_incremental --Only works in SQL 2014+, comment out this line in prior versions. + , TSQL = CASE WHEN i.type_desc like '%columnstore%' THEN NULL ELSE + N'UPDATE STATISTICS ' + + QUOTENAME(s.name) + N'.' + QUOTENAME(o.name) + N' ' + + QUOTENAME(sta.name) + N' ' + + 'WITH RESAMPLE' + + CASE WHEN + sta.is_incremental = 1 and --Only works in SQL 2014+, comment out this line in prior versions. + MAX(p.partition_number) OVER (PARTITION by sta.name, i.name) > 1 THEN ' ON PARTITIONS (' + cast(p.partition_number as varchar(5)) + ') ' ELSE '' END + + END + FROM sys.objects o + INNER JOIN sys.stats sta ON sta.object_id = o.object_id + CROSS APPLY sys.dm_db_stats_properties (sta.object_id, sta.stats_id) sp -- Only works in SQL2008R2SP2+ or SQL2012SP1+ + INNER JOIN sys.schemas AS s + ON o.schema_id = s.schema_id + LEFT OUTER JOIN sys.indexes as i + on i.index_id = sta.stats_id + + LEFT OUTER join sys.dm_db_partition_stats p + on ( + sta.is_incremental = 1 and --Only works in SQL 2014+, comment out this line in prior versions. + p.object_id = o.object_id and + i.index_id = p.index_id + ) + LEFT JOIN + (SELECT IUS.object_id + ,MIN(ISNULL(IUS.last_user_update, IUS.last_system_update)) AS LastUpdate + FROM sys.dm_db_index_usage_stats AS IUS + WHERE database_id = DB_ID() + AND NOT ISNULL(IUS.last_user_update, IUS.last_system_update) IS NULL + GROUP BY IUS.object_id + ) AS IUS + ON IUS.object_id = sta.object_id + WHERE o.type IN ('U', 'V') -- only user tables and views + --AND DATEDIFF(d, ISNULL(STATS_DATE(sta.object_id, sta.stats_id), N'1900-01-01') , IUS.LastUpdate) > 30 --indexes that haven't been updated in the last month + --AND sp.modification_counter > 1000 + ORDER BY Rows_Changed desc, Stats_Last_Updated desc + + /* + + UPDATE STATISTICS [sales].[sales] [PK__sales__3213E83F11F8B16A] WITH RESAMPLE + + */ + + diff --git a/sys.dm_io_virtual_file_stats.sql b/sys.dm_io_virtual_file_stats.sql new file mode 100644 index 0000000..316e8cf --- /dev/null +++ b/sys.dm_io_virtual_file_stats.sql @@ -0,0 +1,13 @@ +--http://blogs.msdn.com/b/dpless/archive/2010/12/01/leveraging-sys-dm-io-virtual-file-stats.aspx?Redirected=true + +select d.name, mf.physical_name +, SizeMb = size_on_disk_bytes /1024./1024. +--, mf.size*8./1024. --same +, io_stall_read_s = fs.io_stall_read_ms /1000. +, io_stall_write_s = fs.io_stall_write_ms /1000. +, io_stall_s = fs.io_stall / 1000. +from sys.dm_io_virtual_file_stats (null,null) fs +inner join sys.master_files mf on fs.file_id = mf.file_id +inner join sys.databases d on d.database_id = mf.database_id and fs.database_id = d.database_id + +order by io_stall desc \ No newline at end of file diff --git a/tables without clustered indexes.sql b/tables without clustered indexes.sql new file mode 100644 index 0000000..8f4d327 --- /dev/null +++ b/tables without clustered indexes.sql @@ -0,0 +1,24 @@ +--Doesn't work on 2000 databases or databases in 2000 compatability mode. + +select + [Database Name] = db_name() +, [Table Name] = s.name + '.' + o.name +, [rows] = sum(ps.row_count) + +from + sys.objects o +inner join + sys.schemas s +on o.schema_id = s.schema_id +inner join + sys.dm_db_partition_stats ps + on ps.object_id = o.object_id + and index_id = 0 +WHERE + o.name <> 'dtproperties' +and is_ms_shipped = 0 +and o.type = 'u' +group by s.name + '.' + o.name +order by rows desc +go + diff --git a/tempdb data files.sql b/tempdb data files.sql new file mode 100644 index 0000000..d0d5a15 --- /dev/null +++ b/tempdb data files.sql @@ -0,0 +1,13 @@ +--Tempdb data files should all be the same size, same autogrowth settings +select d.name +, CurrentSizeMb = (size*8.)/1024. --actual current windows file size +, is_percent_growth +, type_desc +, GrowthMb = (growth*8.)/1024. +, MaxFileSizeMB = CASE WHEN max_size > -1 THEN (max_size*8.)/1024. ELSE max_size END -- -1 is unlimited + from sys.master_files mf +inner join sys.databases d +on mf.database_id = d.database_id +where d.name = 'tempdb'-- and type_desc = 'rows' +order by size desc + diff --git a/test user permissions.sql b/test user permissions.sql new file mode 100644 index 0000000..dda5f4a --- /dev/null +++ b/test user permissions.sql @@ -0,0 +1,15 @@ +use w; + +--test my permissions +select * from fn_my_permissions('dbo.ssisyslog', 'OBJECT') order by 1,2,3; + +--Find role membership +exec xp_logininfo 'dbm\william.assaf', 'all' + +/* +--test another's permissions + +execute as login = 'domain\username' --or 'sqlloginname'; +select * from fn_my_permissions('dbo.ssisyslog', 'OBJECT') order by 1,2,3; +REVERT; --VERY IMPORTANT, or you will continue to execute as. +*/ \ No newline at end of file diff --git a/usp_GetVolumeStats.sql b/usp_GetVolumeStats.sql new file mode 100644 index 0000000..20a4617 --- /dev/null +++ b/usp_GetVolumeStats.sql @@ -0,0 +1,132 @@ +USE [DBAHound] +GO + +/****** Object: StoredProcedure [dbo].[usp_GetVolumeStats] Script Date: 4/18/2017 12:56:18 PM ******/ +SET ANSI_NULLS ON +GO + +SET QUOTED_IDENTIFIER ON +GO + + +/* +USE DBAHound; +GO + +CREATE TABLE [dbo].[VolumeStats]( + [ID] [int] IDENTITY(1,1) NOT NULL, + [volume_mount_point] [nvarchar](512) NULL, + [file_system_type] [nvarchar](512) NULL, + [logical_volume_name] [nvarchar](512) NULL, + [Total_Size] [DECIMAL(19,2)] NULL, + [Available_Size] [DECIMAL(19,2)] NULL, + [Space_Free] [DECIMAL(19,2)] NULL, + [DateTimeStamp] [datetime2](7) NULL, + CONSTRAINT [PK_VolumeStats] PRIMARY KEY CLUSTERED +( [ID] ASC) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] +) ON [PRIMARY] + +GO +*/ + +ALTER PROCEDURE [dbo].[usp_GetVolumeStats] +@Threshold int +AS +BEGIN +--Changed all floats and decimal(18,2) to decimal(19,2) - WDA 20170312 +if object_id('tempdb..#VolumeStats') is not null begin drop table #VolumeStats end; +Create table #VolumeStats +(ID int identity(1,1), +volume_mount_point nvarchar(512), +file_system_type nvarchar(512), +logical_volume_name nvarchar(512), +Total_Size DECIMAL(19,2), +Available_Size DECIMAL(19,2), +Space_Free DECIMAL(19,2), +DateTimePerformed datetime2 +) + + +DECLARE @TimeStamp datetime2 = getdate() +DECLARE VolumeInfo cursor +FOR +SELECT DISTINCT vs.volume_mount_point, vs.file_system_type, +vs.logical_volume_name, CONVERT(DECIMAL(19,2),vs.total_bytes/1073741824.0) AS [Total Size (GB)], +CONVERT(DECIMAL(19,2), vs.available_bytes/1073741824.0) AS [Available Size (GB)], +CONVERT(DECIMAL(19,2), vs.available_bytes * 1. / vs.total_bytes * 100.) AS [Space Free %],@TimeStamp +FROM sys.master_files AS f WITH (NOLOCK) +CROSS APPLY sys.dm_os_volume_stats(f.database_id, f.[file_id]) AS vs + +DECLARE @volume nvarchar(512),@file_system_type nvarchar(512),@logical_name nvarchar(512) +DECLARE @TotalSize DECIMAL(19,2),@AvailableSize DECIMAL(19,2), @percent DECIMAL(19,2) +DECLARE @MyTime datetime2 + +OPEN VolumeInfo + +FETCH NEXT FROM VolumeInfo INTO @volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@MyTime +WHILE (@@FETCH_STATUS <> -1) +BEGIN + +--if @percent > 20 -- changed 20170312 WDA +if @percent <= @Threshold --If free space % is less than 20% --- changed by to @Threshold parameter which is passed via the Agent Job. This way you don't have to change the Sproc just the job +BEGIN + INSERT INTO dbo.VolumeStats(volume_mount_point,file_system_type,logical_volume_name,Total_Size,Available_Size,Space_Free,DateTimeStamp) + values(@volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@TimeStamp) + insert into #VolumeStats(volume_mount_point,file_system_type,logical_volume_name,Total_Size,Available_Size,Space_Free,DateTimePerformed) + VALUES(@volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@TimeStamp) +END +else +BEGIN + INSERT INTO dbo.VolumeStats(volume_mount_point,file_system_type,logical_volume_name,Total_Size,Available_Size,Space_Free,DateTimeStamp) + values(@volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@TimeStamp) + +END + +FETCH NEXT FROM VolumeInfo INTO @volume,@file_system_type,@logical_name,@TotalSize,@AvailableSize,@percent,@Mytime +END +CLOSE VolumeInfo +DEALLOCATE VolumeInfo + +if (SELECT COUNT(*) FROM #VolumeStats +where logical_volume_name <> 'TempDBdata' --added to ignore the tempdb drive - 20170311 WDA +) > 0 +BEGIN --added BEGIN/END wrap on IF - WDA 20170312 + DECLARE @tableHTML NVARCHAR(MAX) ; + + SET @tableHTML = + N'

Server: ' + @@SERVERNAME + '

' + + N'

Drive Space Alert

' + + N'' + + N'' + + N'' + + N'' + + CAST ( ( SELECT + td = v.volume_mount_point, '', + td = v.file_system_type, '', + td = v.logical_volume_name, '', + td = convert(varchar(8),v.Total_Size), '', + td = convert(varchar(8),v.Available_Size), '', + td = convert(varchar(8),v.Space_Free), '' + from #VolumeStats v + order by v.volume_mount_point + FOR XML PATH('tr'), TYPE + ) AS NVARCHAR(MAX) ) + + N'
VolumeFile Sytem TypeLogical NameTotal SizeAvailable SizePercent Free
' ; + + BEGIN + --if @percent < @Threshold -- removed WDA 20170418 + --BEGIN + EXEC msdb.dbo.sp_send_dbmail + @recipients = 'managed.sql@sparkhound.com', + @body = @tableHTML, + @importance = 'HIGH', + @body_format ='HTML', + @subject = 'Volume Size Report' ; + --END + END + END +END; +GO + + diff --git a/volume stats.sql b/volume stats.sql new file mode 100644 index 0000000..27d2c70 --- /dev/null +++ b/volume stats.sql @@ -0,0 +1,15 @@ + + +select distinct +upper(vs.volume_mount_point), +file_system_type, + drive_size_GB = convert(decimal(19,2), vs.total_bytes/1024./1024./1024. ) , + drive_free_space_GB = convert(decimal(19,2), vs.available_bytes/1024./1024./1024. ), + drive_percent_free = CONVERT(DECIMAL(5,2), vs.available_bytes * 100.0 / vs.total_bytes) +FROM + sys.master_files AS f +CROSS APPLY + sys.dm_os_volume_stats(f.database_id, f.file_id) vs --only return volumes where there is database file (data or log) + go + +--exec xp_fixeddrives \ No newline at end of file diff --git a/worst queries.sql b/worst queries.sql new file mode 100644 index 0000000..a55fcdd --- /dev/null +++ b/worst queries.sql @@ -0,0 +1,118 @@ +--Worst queries +--Table to capture this data at bottom + +--INSERT INTO dbo.worstqueries +select top 15 +* +, Average_cpu = convert(decimal(19,2), tot_cpu_ms)/convert(decimal(19,2),usecounts) +, Average_Duration = convert(decimal(19,2),tot_duration_ms)/convert(decimal(19,2),usecounts) +, WorstQueriesObservedWhen = sysdatetime() + from +( + SELECT + PlanStats.CpuRank, PlanStats.PhysicalReadsRank, PlanStats.DurationRank + , runtime = sysdatetime() + , cacheobjtype = LEFT (p.cacheobjtype + ' (' + p.objtype + ')', 35) + , p.usecounts, p.size_in_bytes / 1024 AS size_in_kb, + PlanStats.total_worker_time/1000 AS tot_cpu_ms, PlanStats.total_elapsed_time/1000 AS tot_duration_ms, + PlanStats.total_physical_reads, PlanStats.total_logical_writes, PlanStats.total_logical_reads, + PlanStats.last_execution_time + , dbname = db_name( convert(int, pa.value) ) + , sql.objectid + , Procedure_name = CONVERT (nvarchar(75), CASE + WHEN sql.objectid IS NULL THEN NULL + ELSE REPLACE (REPLACE (sql.[text],CHAR(13), ' '), CHAR(10), ' ') + END) + , stmt_text = REPLACE (REPLACE (SUBSTRING (sql.[text], PlanStats.statement_start_offset/2 + 1, + CASE WHEN PlanStats.statement_end_offset = -1 THEN LEN (CONVERT(nvarchar(max), sql.[text])) + ELSE PlanStats.statement_end_offset/2 - PlanStats.statement_start_offset/2 + 1 + END), CHAR(13), ' '), CHAR(10), ' ') + , ReasonforEarlyTermination = CASE WHEN tqp.query_plan LIKE '%StatementOptmEarlyAbortReason%' THEN substring(substring(tqp.query_plan, charindex('EarlyAbortReason', tqp.query_plan,1)+18, 21), 1, ISNULL(ABS(charindex('"',substring(tqp.query_plan, charindex('EarlyAbortReason', tqp.query_plan,1)+18, 21),1)-1),0)) + ELSE NULL END + , QueryPlan = qp.query_plan + FROM + ( + SELECT + stat.plan_handle, statement_start_offset, statement_end_offset, + stat.total_worker_time, stat.total_elapsed_time, stat.total_physical_reads, + stat.total_logical_writes, stat.total_logical_reads, stat.last_execution_time, + ROW_NUMBER() OVER (ORDER BY stat.total_worker_time DESC) AS CpuRank, + ROW_NUMBER() OVER (ORDER BY stat.total_physical_reads DESC) AS PhysicalReadsRank, + ROW_NUMBER() OVER (ORDER BY stat.total_elapsed_time DESC) AS DurationRank + FROM sys.dm_exec_query_stats stat + where creation_time > '1/16/2014 7:00' + + ) AS PlanStats + INNER JOIN sys.dm_exec_cached_plans p ON p.plan_handle = PlanStats.plan_handle + OUTER APPLY sys.dm_exec_plan_attributes (p.plan_handle) pa + OUTER APPLY sys.dm_exec_sql_text (p.plan_handle) AS sql + inner join sys.databases d on d.database_id = pa.value + OUTER APPLY sys.dm_exec_query_plan (p.plan_handle) qp + OUTER APPLY sys.dm_exec_text_query_plan(p.plan_handle, + PlanStats.statement_start_offset, + PlanStats.statement_end_offset) AS tqp + + WHERE 1=1 + + --and (PlanStats.CpuRank < 10 OR PlanStats.PhysicalReadsRank < 10 OR PlanStats.DurationRank < 10) + AND pa.attribute = 'dbid' + --and usecounts > 1 + --and (sql.text like '%SH_View_Utilization_Detail%' ) + AND (CONVERT(nvarchar(max), sql.[text])) not like '%StatementOptmEarlyAbortReason%' + --AND (tqp.query_plan LIKE '%StatementOptmEarlyAbortReason="TimeOut%' or tqp.query_plan LIKE '%StatementOptmEarlyAbortReason="Memory Limit%') +) x + +--where dbname = N'ram_tax' + +ORDER BY CpuRank + PhysicalReadsRank + DurationRank asc + +--select * from dbo.worstqueries + +/*---------------- +SQL 2000 only +SELECT +UseCounts, RefCounts,CacheObjtype, ObjType, DB_NAME(dbid) as DatabaseName, SQL +FROM sys.syscacheobjects +where sql like '%mtblFeeEndorsement%' +ORDER BY dbid,usecounts DESC,objtype +GO +-----------------*/ +/* +ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; --sql 2016+ + +DBCC FREEPROCCACHE + + +*/ +/* +--table to capture this data + +USE [tempdb] +GO +DROP TABLE IF EXISTS [dbo].[worstqueries] +CREATE TABLE [dbo].[worstqueries]( + [CpuRank] [bigint] NULL, + [PhysicalReadsRank] [bigint] NULL, + [DurationRank] [bigint] NULL, + [cacheobjtype] [nvarchar](35) NULL, + [usecounts] [int] NOT NULL, + [size_in_kb] [int] NULL, + [tot_cpu_ms] [bigint] NULL, + [tot_duration_ms] [bigint] NULL, + [total_physical_reads] [bigint] NOT NULL, + [total_logical_writes] [bigint] NOT NULL, + [total_logical_reads] [bigint] NOT NULL, + [last_execution_time] [datetime2] NULL, + [dbname] [nvarchar](128) NULL, + [objectid] [int] NULL, + [procname] [nvarchar](75) NULL, + [stmt_text] [nvarchar](max) NULL, + [ReasonforEarlyTermination] varchar(50) NULL, + [QueryPlan] [xml] NULL, + [Average_cpu] [decimal](38, 19) NULL, + [Average_Duration] [decimal](38, 19) NULL, + [ObservedWhen] [datetime2](2) NOT NULL CONSTRAINT DF_worstqueries_ObservedWhen DEFAULT (sysdatetime()) +) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY] +GO + +*/ \ No newline at end of file diff --git a/xevent ringbuffer.sql b/xevent ringbuffer.sql new file mode 100644 index 0000000..149f766 --- /dev/null +++ b/xevent ringbuffer.sql @@ -0,0 +1,15 @@ +WITH CteRingBuffer (XMLData) as +( SELECT CAST(xet.target_data as XML) as XMLData + FROM sys.dm_xe_session_targets xet INNER JOIN + sys.dm_xe_sessions xe ON (xe.address = xet.event_session_address) +WHERE xe.name = 'system_health' ) +SELECT top 100 e.query('.').value('(/event/@timestamp)[1]', 'datetime2(0)') as "TimeStamp", + e.query('.').value('(/event/data/value)[1]', 'int') as "ErrorNumber", + e.query('.').value('(/event/data/value)[2]', 'int') as "ErrorSeverity", + e.query('.').value('(/event/data/value)[3]', 'int') as "ErrorState", + e.query('.').value('(/event/data/value)[5]', 'varchar(max)') as "ErrorMessage" + FROM cteRingBuffer CROSS APPLY + XMLData.nodes('/RingBufferTarget/event') AS Event(e) + WHERE e.query('.').value('(/event/@name)[1]', 'varchar(255)') = 'error_reported' + AND e.query('.').value('(/event/@timestamp)[1]', 'datetime2(0)') > GETDATE()-14 + \ No newline at end of file