Bir sunucudaki sql loginleri diğer sunucuya şifreleriyle(hashlenmiş şekilde) beraber taşımak için microsoftun kendi sp’lerini kullanacağız(sp_hexadecimal, sp_help_revlogin) , Alwayson kurulumunda veya ortam kopyalarken işinize yarayabilir. Aşağıdaki sp’leri kaynak sunucuda oluşturup çalıştırdıktan sonra çıktılarını hedef sunucuda çalıştırıyoruz.
USE master GO IF OBJECT_ID ('sp_hexadecimal') IS NOT NULL DROP PROCEDURE sp_hexadecimal IF OBJECT_ID ('sp_help_revlogin') IS NOT NULL DROP PROCEDURE sp_help_revlogin GO /* 1. Spmiz sp_hexadecimal */ USE [master] GO CREATE PROCEDURE [dbo].[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 /* 2. Spmiz sp_help_revlogin */ CREATE PROCEDURE [dbo].[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 @tmpstr1 varchar (1024) DECLARE @is_policy_checked varchar (3) DECLARE @is_expiration_checked varchar (3) DECLARE @defaultdb sysname DECLARE @language 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,p.default_language_name 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' and p.principal_id != 1 and p.name not like '%SQL2005%' and p.name not like '%BUILTIN%' and p.name not like '%NT AUTHORITY\SYSTEM%' ELSE DECLARE login_curs CURSOR FOR SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin,p.default_language_name 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,@language IF (@@fetch_status = -1) BEGIN PRINT 'No login(s) found.' CLOSE login_curs DEALLOCATE login_curs RETURN -1 END SET @tmpstr = '/* sp_help_revlogin2 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 @tmpstr1= 'IF NOT EXISTS (SELECT name from sys.server_principals where name =' + '''' + @name + '''' + ') --DROP LOGIN [' + @name + ']' SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' FROM WINDOWS WITH DEFAULT_DATABASE=[' + @defaultdb + '], DEFAULT_LANGUAGE = [' + @language + ']' 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 @tmpstr1= 'IF NOT EXISTS (SELECT name from sys.server_principals where name =' + '''' + @name + '''' + ') --DROP LOGIN [' + @name + ']' SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' WITH PASSWORD = ' + @PWD_string + ' HASHED, SID = ' + @SID_string + ', DEFAULT_DATABASE=[' + @defaultdb + '], DEFAULT_LANGUAGE = [' + @language + ']' 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 @tmpstr1 PRINT @tmpstr END FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin,@language END CLOSE login_curs DEALLOCATE login_curs RETURN 0 GO
Sp'lerimizi create ettikten sonra sp_help_revlogin i exec edip çıktısını hedef sunucuda çalıştırıyoruz.
Exec [dbo].[sp_help_revlogin]
AŞağıdaki gibi bir çıktısı olacak, istediğiniz userın scriptini alıp hedef sunucuda çalıştırabilirsiniz. NT Servisleri almanıza gerek yok.
-- Login: DESKTOP-2M975S0\Omer Acar IF NOT EXISTS (SELECT name from sys.server_principals where name ='DESKTOP-2M975S0\Omer Acar') --DROP LOGIN [DESKTOP-2M975S0\Omer Acar] CREATE LOGIN [DESKTOP-2M975S0\Omer Acar] FROM WINDOWS WITH DEFAULT_DATABASE=[master], DEFAULT_LANGUAGE = [us_english] -- Login: muhasebe IF NOT EXISTS (SELECT name from sys.server_principals where name ='muhasebe') --DROP LOGIN [muhasebe] CREATE LOGIN [muhasebe] WITH PASSWORD = 0x0200E9ED32A055B62A0597F071B97195481F2ABA27DF07E965DA30C41EDC2FE4562BE685E335918679F2198C8E1E3E2B00AA2BAB877403FB52E39FB77C8BA02840390FD38F33 HASHED, SID = 0x79FBBD96D6862840822F822A2B308EEA, DEFAULT_DATABASE=[master], DEFAULT_LANGUAGE = [us_english], CHECK_POLICY = OFF, CHECK_EXPIRATION = OFF