High Availability and Disaster Recover – Syncronize logins [SQL Server]

Often I connect in new environments and I see solutions of High Availability and Disaster Recovery. But just the simple solution is sufficient for your applications?
I’m saying that because in many cases a just simple detail is forgotten. Many professionals forget to create a option to syncronize logins and when you need to use the otherside, application not run and your solution of High Availability failed.

Follow below one example of script to syncronize your environment.

You need to create one LINKEDSERVER between instances and run one job for a specific times or a trigger to execute this jobs when you have a new user or when the user has been modified.

After you need to create a procedure hexadecimal according with your version. Look that and create in both instances: http://support.microsoft.com/kb/918992

And finaly, create the procedure below. Don’t forget to change the name of LINKEDSERVER

This script is simple and just create login without administratives privileges and with the same SID and when password has been modified. If you need sysadmin for example, you will need input manually. I think is better because sometimes you have a diferent instance and maybe you can’t grant acess in a especific server.

BEGIN
SET NOCOUNT ON

	CREATE TABLE #Logins
	(
		loginId int IDENTITY(1, 1) NOT NULL,
		loginName nvarchar(128) NOT NULL,
		passwordHash varbinary(256) NULL,
		default_database_name nvarchar(128) NULL,
		sid varbinary(85) NOT NULL
	)

	INSERT INTO #Logins(loginName, passwordHash, sid, default_database_name)
	SELECT *
	FROM OPENQUERY([INSTANCE], '
	SELECT name, CONVERT(varbinary(256), LOGINPROPERTY(name, ''PasswordHash'')), sid, default_database_name
	FROM master.sys.server_principals
	WHERE
		type = ''S'' AND 
		name NOT IN (''sa'', ''guest'',''##MS_PolicyEventProcessingLogin##'',''usr_alwayson'') AND
		create_date >= ''01/05/2014''
	ORDER BY name')

	DECLARE 
		@count int, @loginId int, @loginName nvarchar(128), 
		@passwordHashOld varbinary(256), @passwordHashNew varbinary(256), 
		@SID_varbinary varbinary(85), @sql nvarchar(4000), @password varchar(514), @default_database_name nvarchar(128), @SID_string varchar (514)

	SELECT @loginId = 1, @count = COUNT(*)
	FROM #Logins

	WHILE @loginId <= @count
	BEGIN
		SELECT @loginName = loginName, @passwordHashNew = passwordHash, @SID_varbinary = sid, @default_database_name = default_database_name
		FROM #Logins
		WHERE loginId = @loginId

		IF NOT EXISTS (SELECT * FROM master.sys.server_principals WHERE name = @loginName)
		BEGIN
			EXEC master.dbo.sp_hexadecimal @passwordHashNew, @password OUTPUT
			EXEC master.dbo.sp_hexadecimal @SID_varbinary,@SID_string OUT

			SET @sql = 'CREATE LOGIN ' + @loginName + ' WITH PASSWORD = '
			SET @sql = @sql + CONVERT(nvarchar(512), COALESCE(@password, 'NULL')) 
			SET @sql = @sql + ' HASHED , SID = ' + CONVERT(nvarchar(512), @SID_string)
			SET @sql = @sql + ' , DEFAULT_DATABASE = [' + @default_database_name + ']'
			SET @sql = @sql + ' , CHECK_POLICY = OFF' 
			PRINT @sql
			EXEC (@sql)

			PRINT 'login created'
		END
		ELSE
		BEGIN
			SELECT @passwordHashOld = CONVERT(varbinary(256), LOGINPROPERTY(@loginName, 'PasswordHash'))

			-- only bother updating if the password has changed since the last sync
			IF @passwordHashOld <> @passwordHashNew
			BEGIN
				EXEC master.dbo.sp_hexadecimal @passwordHashNew, @password OUTPUT

				--SET @sql = 'DROP LOGIN ' + @loginName
				--PRINT @sql
				--EXEC (@sql)

				SET @sql = 'ALTER LOGIN ' + @loginName + ' WITH PASSWORD = '
				SET @sql = @sql + CONVERT(nvarchar(512), COALESCE(@password, 'NULL'))
				SET @sql = @sql + ' HASHED, CHECK_POLICY = OFF' 
				PRINT @sql
				EXEC (@sql)

				PRINT 'login "altered"'
			END
		END

		SET @loginId = @loginId + 1
	END

	DROP TABLE #Logins

END
Advertisements

Danilo Braga is a Database Administrator with over nine years of experience. He is a Microsoft Certified IT Professional (MCITP) Database Administrator and Developer. His experience includes solutions for management, assessment and implementation of SQL Server environments making use of best practices, performance tuning, and high availability.

Tagged with:
Posted in High Availability, Scripts, SQL Server Tips

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

%d bloggers like this: