Setup fresh/Scriptout Existing Mirroring on SQL Server
|In my current organization, we have lot of servers where database mirroring is used as a disaster recovery option. Either we are setting up mirroring from scratch or dropping the existing mirroring and re-establishing it, it is going to take from 30 min to an hour. So in order to reduce the overall mirroring setup time, I have created below script that will provide TSQL Code to create database mirroring from scratch or will script out existing mirroring setup on server. Scripting out existing setup can be useful in cases where we need database refresh from other environments.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 |
/* Created By: Ajay Dwivedi Created Date: Jan 26, 2016 Purpose: The script can be used to script out current mirroring of database, or, Will create entire script to create mirroring on server */ SET NOCOUNT ON; DECLARE @databaseName SYSNAME = 'AjayDwivedi' -- Database ,@principalServer SYSNAME = 'SQL_A' -- Principal ,@mirrorServer SYSNAME = 'SQL_B' -- Mirror ,@witnessServer SYSNAME = NULL--'SQL_C' ,@localBackupPath_Certificate VARCHAR(255) = 'E:\TSMSQL\ADHOC\' -- Path ending with '\' IF (@@SERVERNAME NOT IN (@principalServer,@mirrorServer,ISNULL(@witnessServer,'Wrong Server'))) PRINT 'ERROR: Something is wrong. Either wrong Principal or Mirror Server, or query is being run in wrong server window.' ELSE BEGIN -- Main Begin Block DECLARE @isMirroringFoundOnServer TINYINT = 0 ,@isMirroringFoundOnDatabase TINYINT = 0 ,@contextServer VARCHAR(20) ,@version VARCHAR(20) ,@productVersion VARCHAR(20) ,@sqlServerServiceAccount VARCHAR(100) ,@mirroringCertificate NVARCHAR(500) ,@mirroringCertificateID BIGINT ,@mirroringCertificateSubject VARCHAR(200) ,@partnerCertificate_01 NVARCHAR(500) ,@partnerCertificate_02 NVARCHAR(500) ,@certificatePath_01 VARCHAR(255) ,@certificatePath_02 VARCHAR(255) ,@partner_01 VARCHAR(20) ,@partner_02 VARCHAR(20) ,@networkBackupPath_Certificate VARCHAR(255) = REPLACE(@localBackupPath_Certificate,':','$') ,@sqlLoginName SYSNAME ,@sqlUserName SYSNAME ,@isSQLLoginUserExisting TINYINT = 0 ,@mirroringEndPoint NVARCHAR(500) ,@mirroringEndPointID BIGINT ,@mirroringTCPPort BIGINT ,@sqlQueryText NVARCHAR(4000) IF (@@SERVERNAME = @principalServer) SELECT @contextServer = 'Principal' ,@partner_01 = 'Mirror', @partner_02 = 'Witness'; ELSE IF (@@SERVERNAME = @mirrorServer) SELECT @contextServer = 'Mirror' ,@partner_01 = 'Principal', @partner_02 = 'Witness'; ELSE SELECT @contextServer = 'Witness' ,@partner_01 = 'Principal', @partner_02 = 'Mirror'; IF OBJECT_ID('tempdb..#database_mirroring') IS NOT NULL DROP TABLE #database_mirroring; SELECT DB_NAME(database_id) as database_name, * INTO #database_mirroring FROM sys.database_mirroring as dm WHERE dm.mirroring_state = 4 --SYNCHRONIZED PRINT '/* !~~~~~~~~~~~ Analyzing '+@contextServer+' server <<'+@@servername+ '>> ~~~~~~~~~~~~~~~~~!'; IF EXISTS (SELECT * FROM #database_mirroring as m) BEGIN SET @isMirroringFoundOnServer = 1; PRINT ' Mirroring is existing on server'; IF EXISTS (SELECT * FROM #database_mirroring as m WHERE m.database_name = @databaseName) BEGIN SET @isMirroringFoundOnDatabase = 1; PRINT ' Mirroring is existing for concerned database'; END END ELSE PRINT ' This would be 1st Mirroring setup on server.'; /* Pre-Implementation Steps · Verify the database is in Full recovery mode. · Verify the principal and mirror databases are on separate instances. · Verify the principal and mirror servers are running on the same edition of SQL Server. · If configuring a witness server, verify it is running version SQL 2005 or later. (All editions are supported on a witness server). */ PRINT ''; PRINT '-- Pre-Implementation Steps'; IF (@contextServer = 'Witness') PRINT ' 1) UNKNOWN - Verify that databases on Primary & Secondary databases are in Full recovery mode.'; ELSE IF NOT EXISTS (SELECT * FROM sys.databases d WHERE d.name IN (@databaseName) AND d.recovery_model_desc = 'FULL') PRINT ' 1) FAILED - Verify the database is in Full recovery mode.' ELSE PRINT ' 1) PASSED - Verify the database is in Full recovery mode.' -- Verify the principal and mirror databases are on separate instances. IF (@principalServer=@mirrorServer) PRINT ' 2) FAILED - Verify the principal and mirror databases are on separate instances.' ELSE PRINT ' 2) PASSED - Verify the principal and mirror databases are on separate instances.' SELECT @productVersion = CONVERT(VARCHAR(20),SERVERPROPERTY('ProductVersion')); SELECT @version = CASE WHEN @productVersion LIKE '10.50%' THEN '2008 R2' WHEN @productVersion LIKE '11.%' THEN '2012' WHEN @productVersion LIKE '12.%' THEN '2014' WHEN @productVersion LIKE '13.%' THEN '2016' WHEN @productVersion LIKE '10.%' THEN '2008' ELSE '2005' END; IF (@contextServer='Principal') PRINT ' 3) UNKNOWN - Verify the mirror database is running on SQL Server '+@version+ ' '+CONVERT(VARCHAR(30),SERVERPROPERTY('Edition')); ELSE PRINT ' 3) UNKNOWN - Verify the Principal database is running on SQL Server '+@version+ ' '+CONVERT(VARCHAR(30),SERVERPROPERTY('Edition')); -- If configuring a witness server, verify it is running version SQL 2005 or later IF (@witnessServer IS NOT NULL AND LEN(@witnessServer)>0) PRINT ' 4) UNKNOWN - If configuring the witness server '+@witnessServer+' verify it is running version SQL 2005 or later'; ELSE PRINT ' 4) UNKNOWN - If configuring a witness server verify it is running version SQL 2005 or later'; PRINT '*/ -- Determine/Create Database Master Key'; IF EXISTS (SELECT * FROM master.sys.symmetric_keys as sk WHERE sk.name = '##MS_DatabaseMasterKey##') PRINT ' -- Master Key already exists on '+@contextServer+' Server '+@@servername; -- Still print code for master key creation BEGIN SET @sqlQueryText = 'USE master GO CREATE MASTER KEY ENCRYPTION BY PASSWORD = ''Ox6$Nd4&Vv7&Rn2&Fy7%''; GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END --drop certificate MasterCert --drop endpoint Endpoint_Mirroring PRINT ' -- Determine/Create Certificate'; WITH T_Mirroring_Certificate AS ( SELECT c.name as CertificateName, c.certificate_id, c.subject FROM sys.database_mirroring_endpoints AS me INNER JOIN sys.tcp_endpoints AS ep ON ep.endpoint_id = me.endpoint_id INNER JOIN sys.certificates AS c ON c.certificate_id = me.certificate_id ) ,T_Certificate_Latest AS ( SELECT TOP 1 c.name as CertificateName, c.certificate_id, c.subject FROM sys.certificates AS c WHERE c.pvt_key_encryption_type_desc = 'ENCRYPTED_BY_MASTER_KEY' AND NOT EXISTS (SELECT * FROM T_Mirroring_Certificate) ORDER BY start_date DESC ) SELECT @mirroringCertificate = crt.CertificateName ,@mirroringCertificateID = crt.certificate_id ,@mirroringCertificateSubject = crt.subject FROM ( SELECT CertificateName, certificate_id, subject FROM T_Mirroring_Certificate -- UNION -- SELECT CertificateName, certificate_id, subject FROM T_Certificate_Latest ) AS crt; IF (@mirroringCertificate IS NOT NULL) PRINT ' -- Certificate already exists on '+@contextServer+' Server '+@@servername; ELSE BEGIN PRINT ' -- Create a certificate using below TSQL code'; SELECT @mirroringCertificate = @@SERVERNAME+'_Cert', @mirroringCertificateSubject = @@SERVERNAME+' Certificate'; END BEGIN SET @sqlQueryText = 'CREATE CERTIFICATE '+ @mirroringCertificate + ' WITH SUBJECT = '''+@mirroringCertificateSubject+''', EXPIRY_DATE = ''12/31/2049''; GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END -- Find out port no if Mirroring is pre-existing SELECT @mirroringEndPoint = me.name ,@mirroringEndPointID = me.endpoint_id ,@mirroringTCPPort = ep.port --me.name as MirroringEndpointName, me.endpoint_id, me.protocol_desc, me.type_desc, me.state_desc, me.connection_auth_desc --,me.certificate_id, ep.port, c.name as CertificateName FROM sys.database_mirroring_endpoints AS me INNER JOIN sys.tcp_endpoints AS ep ON ep.endpoint_id = me.endpoint_id INNER JOIN sys.certificates AS c ON c.certificate_id = me.certificate_id WHERE me.certificate_id = @mirroringCertificateID PRINT ' -- Determine/Create Mirroring Enpoint'; IF (@mirroringEndPoint IS NOT NULL) PRINT ' -- Mirroring Endpoint already exists using certificate authentication'; ELSE PRINT ' -- Create a Mirroring Endpoint using certificate authentication'; BEGIN SET @sqlQueryText = 'CREATE ENDPOINT '+ISNULL(@mirroringEndPoint,'Endpoint_Mirroring')+' STATE = STARTED AS TCP ( LISTENER_PORT= '+CAST(ISNULL(@mirroringTCPPort,5022) AS VARCHAR(20))+' ,LISTENER_IP = ALL ) FOR DATABASE_MIRRORING ( AUTHENTICATION = CERTIFICATE '+@mirroringCertificate+' ,ENCRYPTION = REQUIRED ALGORITHM AES ,ROLE = ALL ); GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END PRINT '-- BackupCertificate BACKUP CERTIFICATE '+@mirroringCertificate+' TO FILE = '''+@localBackupPath_Certificate+@mirroringCertificate+'.cer''; GO '; SET @certificatePath_01 = '\\'+CASE @contextServer WHEN 'Principal' THEN @mirrorServer WHEN 'Mirror' THEN @principalServer ELSE @principalServer END +'\'+@networkBackupPath_Certificate; SET @certificatePath_02 = '\\'+CASE @contextServer WHEN 'Principal' THEN @witnessServer WHEN 'Mirror' THEN @witnessServer ELSE @mirrorServer END +'\'+@networkBackupPath_Certificate; PRINT ' /* Take the backed up certificate '''+@localBackupPath_Certificate+@mirroringCertificate+'.cer'', and copy across partner servers. Run following command in elevated Command Prompt/Powershell window:- copy ''\\'+@@servername+'\'+@networkBackupPath_Certificate+@mirroringCertificate+'.cer'' '''+@certificatePath_01+''' copy ''\\'+@@servername+'\'+@networkBackupPath_Certificate+@mirroringCertificate+'.cer'' '''+@certificatePath_02+''' */'; SELECT @sqlLoginName = s.name --e.name as mirror_endpoint_name, s.name AS login_name, p.permission_name, p.state_desc as permission_state, e.state_desc endpoint_state FROM sys.server_permissions p INNER JOIN sys.endpoints e ON p.major_id = e.endpoint_id INNER JOIN sys.server_principals s ON p.grantee_principal_id = s.principal_id WHERE p.class_desc = 'ENDPOINT' AND e.type_desc = 'DATABASE_MIRRORING' AND p.permission_name = 'CONNECT' IF (@sqlLoginName IS NULL) IF EXISTS (SELECT * FROM sys.sql_logins as l WHERE l.name = 'endPointUser') SELECT @isSQLLoginUserExisting = 1, @sqlLoginName = l.name ,@sqlUserName = (SELECT u.name FROM sys.database_principals AS u WHERE u.sid = l.sid) FROM sys.server_principals AS l WHERE l.name = 'endPointUser' ELSE SELECT @isSQLLoginUserExisting = 0 ELSE BEGIN SELECT @isSQLLoginUserExisting = 1 ,@sqlUserName = (SELECT u.name FROM sys.database_principals AS u WHERE u.sid = l.sid) FROM sys.server_principals AS l WHERE l.name = @sqlLoginName END IF (@isSQLLoginUserExisting = 1) BEGIN IF OBJECT_ID('tempdb..#MirrorCertificates') IS NOT NULL DROP TABLE #MirrorCertificates; SELECT TOP 5 ROW_NUMBER() OVER (ORDER BY certificate_id ASC) AS ID, c.name, USER_NAME(c.principal_id) AS sqlUserName INTO #MirrorCertificates FROM sys.certificates AS c CROSS APPLY ( SELECT sp.name AS login_name FROM sys.server_principals sp JOIN sys.database_principals dp ON (sp.sid = dp.sid) WHERE dp.name = USER_NAME(c.principal_id) ) as l WHERE l.login_name = @sqlLoginName; END PRINT ' -- Determine/Create SQLUser'; IF (@isSQLLoginUserExisting = 1) PRINT ' -- SQLUser ['+@sqlLoginName+'] with CONNECT permission to Mirroring Endpoint already exists'; ELSE BEGIN SELECT @sqlLoginName = 'endPointUser', @sqlUserName = 'endPointUser'; PRINT ' -- Create a SQLUser for mirroring'; END BEGIN SET @sqlQueryText = 'USE master GO CREATE LOGIN ['+@sqlLoginName+'] WITH PASSWORD=N''ˆTB‹[1]§YvB¦Ð«H·™»›ÃOâE3Y‡8°¶Ô€'', DEFAULT_DATABASE=[master], DEFAULT_LANGUAGE=[us_english], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF; GO CREATE USER ['+@sqlUserName+'] FOR LOGIN ['+@sqlLoginName+'] WITH DEFAULT_SCHEMA=[dbo]; GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END PRINT ' /* NOTE 01: Repeat all above steps on '+(CASE WHEN @contextServer='Witness' THEN 'Partner Instances' WHEN @witnessServer IS NOT NULL AND LEN(@witnessServer)>3 THEN 'Partner Instance & Witness server '+@witnessServer ELSE 'Partner Instance' END)+' as well before proceeding further. */'; -- \\DBSW8196\E$\TSMSQL\ADHOC\ SET @certificatePath_01 = '\\'+CASE @contextServer WHEN 'Principal' THEN @mirrorServer WHEN 'Mirror' THEN @principalServer ELSE @principalServer END +'\'+@networkBackupPath_Certificate; SET @certificatePath_02 = '\\'+CASE @contextServer WHEN 'Principal' THEN @witnessServer WHEN 'Mirror' THEN @witnessServer ELSE @mirrorServer END +'\'+@networkBackupPath_Certificate; SELECT @partnerCertificate_01 = CASE ID WHEN 1 THEN c.name ELSE @partnerCertificate_01 END, @partnerCertificate_02 = CASE ID WHEN 2 THEN c.name ELSE @partnerCertificate_02 END, @sqlUserName = c.sqlUserName FROM #MirrorCertificates AS c IF EXISTS (select * from #MirrorCertificates as c WHERE c.name like '%'+@principalServer+'%' or c.name like '%'+@mirrorServer+'%' OR c.name like '%'+@witnessServer+'%') BEGIN SELECT @partnerCertificate_01 = CASE ID WHEN 1 THEN c.name ELSE @partnerCertificate_01 END, @partnerCertificate_02 = CASE ID WHEN 2 THEN c.name ELSE @partnerCertificate_02 END, @sqlUserName = c.sqlUserName FROM (select ROW_NUMBER()over(order by id) as ID, c.name, c.sqlUserName from #MirrorCertificates as c WHERE c.name like '%'+@principalServer+'%' or c.name like '%'+@mirrorServer+'%' OR c.name like '%'+@witnessServer+'%') AS c END PRINT ' -- Determine/Associate '+@partner_01+' Certificate with SQLUser'; IF (@partnerCertificate_01 IS NOT NULL) PRINT ' -- Partner certificate '''+@partnerCertificate_01+'.cer'' is already associated with SQLUser ['+@sqlLoginName+']'; ELSE BEGIN SET @partnerCertificate_01 = @mirrorServer+'_Cert' PRINT ' -- Create a certificate from partner certificate copy, assuming that you already copied partner certificate from path '''+@certificatePath_01+@partnerCertificate_01+'.cer'' to '''+@networkBackupPath_Certificate+''''; END BEGIN SET @sqlQueryText = 'USE master GO CREATE CERTIFICATE '+@partnerCertificate_01+' AUTHORIZATION ['+@sqlUserName+'] FROM FILE = '''+@localBackupPath_Certificate+@partnerCertificate_01+'.cer''; GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END IF (@witnessServer IS NOT NULL AND LEN(@witnessServer)>0) BEGIN PRINT ' -- Determine/Associate '+@partner_02+' Certificate with SQLUser'; IF (@partnerCertificate_02 IS NOT NULL) PRINT ' -- '+@partner_02+' certificate '''+@partnerCertificate_02+'.cer'' is already associated with SQLUser ['+@sqlLoginName+']'; ELSE BEGIN SET @partnerCertificate_02 = (case when @partner_02 = 'Mirror' then @mirrorServer else @witnessServer end)+'_Cert' PRINT ' -- Create a certificate from '+@partner_02+' certificate copy, assuming that you already copied certificate from path '''+@certificatePath_02+@partnerCertificate_02+'.cer'' to '''+@networkBackupPath_Certificate+''''; END BEGIN SET @sqlQueryText = 'USE master GO CREATE CERTIFICATE '+@partnerCertificate_02+' AUTHORIZATION ['+@sqlUserName+'] FROM FILE = '''+@localBackupPath_Certificate+@partnerCertificate_02+'.cer''; GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END END PRINT ' /* After login, user, and certificate for partner instance have been created, grant permissions to the login on the endpoint */'; BEGIN SET @sqlQueryText = 'GRANT CONNECT ON ENDPOINT::'+ISNULL(@mirroringEndPoint,'Endpoint_Mirroring')+' TO ['+@sqlLoginName+']; GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END PRINT ' /* NOTE 02: Repeat all activites till this point on partner instance as well. */'; PRINT ' -- CAUTION: First perform below steps on Mirror Instance <<'+@mirrorServer+'>> using mirror script, and then proceed for Primary instance <<'+@principalServer+'>>'; DECLARE @Domain varchar(100), @key varchar(100) SET @key = 'SYSTEM\ControlSet001\Services\Tcpip\Parameters\' EXEC master..xp_regread @rootkey='HKEY_LOCAL_MACHINE', @key=@key,@value_name='Domain',@value=@Domain OUTPUT BEGIN IF (@contextServer='Principal') SET @sqlQueryText = 'ALTER DATABASE ['+@databaseName+'] SET PARTNER = ''TCP://'+@mirrorServer+'.'+@Domain+':'+CAST(ISNULL(@mirroringTCPPort,5022) AS VARCHAR(20))+'''; GO ' ELSE SET @sqlQueryText = 'ALTER DATABASE ['+@databaseName+'] SET PARTNER = ''TCP://'+@principalServer+'.'+@Domain+':'+CAST(ISNULL(@mirroringTCPPort,5022) AS VARCHAR(20))+'''; GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END IF (@witnessServer IS NOT NULL AND LEN(@witnessServer)>0) BEGIN PRINT ' /* Execute below code on Principal to Add Witness Server <<'+@witnessServer+'>> */'; SET @sqlQueryText = 'ALTER DATABASE ['+@databaseName+'] SET WITNESS = ''TCP://'+@witnessServer+'.'+@Domain+':'+CAST(ISNULL(@mirroringTCPPort,5022) AS VARCHAR(20))+'''; GO ' PRINT @sqlQueryText; SET @sqlQueryText = ''; END PRINT ' /* Congrats! As you have reached this step, your database must have got mirrored in high-safety mode. */'; END -- Main End Block |
Sample result from above query is as below:-
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 |
/* !~~~~~~~~~~~ Analyzing Principal server <<SQL_A>> ~~~~~~~~~~~~~~~~~! Mirroring is existing on server Mirroring is existing for concerned database -- Pre-Implementation Steps 1) PASSED - Verify the database is in Full recovery mode. 2) PASSED - Verify the principal and mirror databases are on separate instances. 3) UNKNOWN - Verify the mirror database is running on SQL Server 2008 R2 Enterprise Edition (64-bit) 4) UNKNOWN - If configuring a witness server verify it is running version SQL 2005 or later */ -- Determine/Create Database Master Key -- Master Key already exists on Principal Server SQL_A USE master GO CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Ox6$Nd4&Vv7&Rn2&Fy7%'; GO -- Determine/Create Certificate -- Certificate already exists on Principal Server SQL_A CREATE CERTIFICATE SQL_A_cert WITH SUBJECT = 'SQL_A certificate', EXPIRY_DATE = '12/31/2049'; GO -- Determine/Create Mirroring Enpoint -- Mirroring Endpoint already exists using certificate authentication CREATE ENDPOINT Endpoint_Mirroring STATE = STARTED AS TCP ( LISTENER_PORT= 5022 ,LISTENER_IP = ALL ) FOR DATABASE_MIRRORING ( AUTHENTICATION = CERTIFICATE SQL_A_cert ,ENCRYPTION = REQUIRED ALGORITHM AES ,ROLE = ALL ); GO -- BackupCertificate BACKUP CERTIFICATE SQL_A_cert TO FILE = 'E:\TSMSQL\ADHOC\SQL_A_cert.cer'; GO -- Determine/Create SQLUser -- SQLUser [SQL_B_Login] with CONNECT permission to Mirroring Endpoint already exists USE master GO CREATE LOGIN [SQL_B_Login] WITH PASSWORD=N'ˆTB‹[1]§YvB¦Ð«H·™»›ÃOâE3Y‡8°¶Ô€', DEFAULT_DATABASE=[master], DEFAULT_LANGUAGE=[us_english], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF; GO CREATE USER [SQL_B_User] FOR LOGIN [SQL_B_Login] WITH DEFAULT_SCHEMA=[dbo]; GO /* NOTE 01: Repeat all above steps on Partner Instance as well before proceeding further. */ -- Determine/Associate Mirror Certificate with SQLUser -- Partner certificate 'SQL_B_cert.cer' is already associated with SQLUser [SQL_B_Login] USE master GO CREATE CERTIFICATE SQL_B_cert AUTHORIZATION [SQL_B_User] FROM FILE = 'E:\TSMSQL\ADHOC\SQL_B_cert.cer'; GO /* After login, user, and certificate for partner instance have been created, grant permissions to the login on the endpoint */ GRANT CONNECT ON ENDPOINT::Endpoint_Mirroring TO [SQL_B_Login]; GO /* NOTE 02: Repeat all activites till this point on partner instance as well. */ -- CAUTION: First perform below steps on Mirror Instance <<SQL-B>> using mirror script, and then proceed for Primary instance <<SQL_A>> ALTER DATABASE [AjayDwivedi] SET PARTNER = 'TCP://SQL_B.Contso.com:5022'; GO /* Congrats! As you have reached this step, your database must have got mirrored in high-safety mode. */ |
Friends, please try the script, and let me know of any bugs by comments. If you like the article, do Like & Share. Happy Coding 🙂