Wait for Mirror treshold
This procedure is very handy if you want to control the load on a mirrored database. For example rebuilding indexes on the principal database generates a lot of load on the mirrored database (especially with a snapshot).
In order to control the load on a mirrored server, create this procedure (on the principal) and insert a call to this procedure between each "heavy" (statement on the principal).
For example, I rebuild my indexes by a cursor loop and just before I fetch the next index, I call this procedure. This procedure takes the mirror tresholds from SQL. NOTE: By using this procedure, you still might get messages in your errorlog about mirror tresholds. This procedure only slows down your statements (in order to give the mirrored database more breath).
In order to prevent an infinite execution of this statement, @MaxWaitSeconds determines the number of seconds before this procedure aborts (a returncode is set).
@Checkdelay is the delaytime before the tresholds are checked again.
if exists(select 1 from information_schema.routines where routine_name = 'usp_WaitforMirrorTreshold')
drop procedure usp_WaitforMirrorTreshold
go
create procedure usp_WaitforMirrorTreshold @databasename sysname
, @MaxWaitseconds int = 60
, @CheckDelay datetime = '00:00:10'
, @debug bit = 0
as
/*
created by wilfred van dijk
http://www.wilfredvandijk.nl
*/ declare @LogValue1 int
declare @LogTreshold1 int
declare @LogValue2 int
declare @LogTreshold2 int
declare @TimeBehind int
declare @TimeBehindTreshold int
declare @MyReturnCode int
declare @MyProcID sysname
declare @role int
declare @StartChecktime datetime
set nocount on
set @MyReturnCode = 0
set @StartCheckTime = GETDATE()
set @MyProcID = OBJECT_NAME(@@PROCID)
print '/* Executing ' + @MyProcId + ' */'
/*
Since insert/exec results in nested exec error, update seperately
*/ begin try
exec msdb.dbo.sp_dbmmonitorupdate @Databasename
end try
begin catch
print '-- ERROR: ' + ERROR_MESSAGE()
GOTO EndOfProc
end catch
/*
create temporary tables
*/ declare @monitorresults table(databasename sysname, role int, mirroring_state int, witness_status int
, log_generation_rate int, unsend_log int, send_rate int, unrestored_log int
, recovery_rate int, transaction_delay int, transactions_per_sec int
, average_delay int, time_recorded datetime, time_behind datetime, local_time datetime)
declare @monitoralert table (alertid int, treshold int, enabled bit)
/*
get data
*/ insert
into @monitorresults
exec msdb.dbo.sp_dbmmonitorresults @Databasename,0,0
insert into @monitoralert
exec msdb.dbo.sp_dbmmonitorhelpalert @databasename
if @debug = 1
begin
select * from @monitoralert
select * from @monitorresults
end
select @role = role
from @monitorresults
where databasename = @databasename
print '-- Role of database ' + QUOTENAME(@Databasename) + ' on server ' + @@SERVERNAME + ' is ' + case @Role when 1 then 'Principal' else 'Mirror' end
while (1=1)
begin
select @TimeBehind = datediff(minute, r.time_behind, r.time_recorded)
, @TimeBehindTreshold = a.treshold
from @monitorresults r
, @monitoralert a
where a.alertid = 1
select @LogValue1 = r.unsend_log
, @LogTreshold1 = a.treshold
from @monitorresults r
, @monitoralert a
where a.alertid = 2
select @LogValue2 = r.unrestored_log
, @LogTreshold2 = a.treshold
from @monitorresults r
, @monitoralert a
where a.alertid = 3
if @debug = 1
select @logValue1, @logTreshold1, @logValue2, @logTreshold2, @TimeBehind, @TimeBehindTreshold
/*
No treshold? exit
*/ if @LogValue1 < @LogTreshold1 and @LogValue2 < @LogTreshold2 and @TimeBehind < @TimeBehindTreshold
begin
print '-- No Mirror tresholds at this moment'
break
end
if @LogValue1 > @LogTreshold1 print '-- Waiting: Unsend log exceeds treshold'
if @LogValue2 > @LogTreshold2 print '-- Waiting: Unrestored log exceeds treshold'
if @timeBehind > @TimeBehindTreshold print '-- Waiting: Oldest unsend transaction exceeds treshold'
/*
exit in case of debug mode
*/ if @debug = 1
break
/*
Give server some breath
*/ waitfor delay @CheckDelay
/*
In order to prevent infinite execution, this procedure aborts after @MaxWaitSeconds
*/ if datediff(second, @StartChecktime, GETDATE()) > @MaxWaitSeconds
begin
print '-- Aborting, because time is up'
set @MyReturnCode = 1
break
end
/*
refresh data
*/ delete from @monitorresults
delete from @monitoralert
insert
into @monitorresults
exec msdb.dbo.sp_dbmmonitorresults @Databasename,0,0
insert into @monitoralert
exec msdb.dbo.sp_dbmmonitorhelpalert @databasename
end
EndOfProc:
print '/* Finished */'
return @MyReturncode
go