时间:2023-10-27来源:系统城装机大师作者:佚名
本文介绍如何在 Windows 上运行的 SQL Server 的不同实例之间传输登录名和密码, 适用于 SQL mirroring , SQL AG 中的本地logins的迁移或者同步。
也就说源服务器A可以是SQL mirroring , SQL AG的principal DB 或者任意 一台新的独立的SQL DB
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 |
USE [master] GO IF OBJECT_ID ( 'sp_hexadecimal' ) IS NOT NULL DROP PROCEDURE sp_hexadecimal GO CREATE PROCEDURE [dbo].[sp_hexadecimal] ( @binvalue varbinary(256), @hexvalue varchar (514) OUTPUT ) AS BEGIN 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 END go IF OBJECT_ID ( 'sp_help_revlogin' ) IS NOT NULL DROP PROCEDURE sp_help_revlogin GO CREATE PROCEDURE [dbo].[sp_help_revlogin] ( @login_name sysname = NULL ) AS BEGIN 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 @Prefix VARCHAR (255) DECLARE @defaultdb SYSNAME DECLARE @defaultlanguage SYSNAME DECLARE @tmpstrRole VARCHAR (1024) IF (@login_name IS NULL ) BEGIN 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' ORDER BY p. name END 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 ORDER BY p. name OPEN login_curs FETCH NEXT FROM login_curs INTO @SID_varbinary, @ name , @type, @is_disabled, @defaultdb, @hasaccess, @denylogin, @defaultlanguage 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 SET @tmpstr= 'IF NOT EXISTS (SELECT * FROM sys.server_principals WHERE name = N' '' +@ name + '' ') BEGIN' Print @tmpstr IF (@type IN ( 'G' , 'U' )) BEGIN -- NT authenticated account/group SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @ name ) + ' FROM WINDOWS WITH DEFAULT_DATABASE = [' + @defaultdb + ']' + ', DEFAULT_LANGUAGE = [' + @defaultlanguage + ']' 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 + ']' + ', DEFAULT_LANGUAGE = [' + @defaultlanguage + ']' 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 SET @Prefix = ' EXEC master.dbo.sp_addsrvrolemember @loginame=' '' SET @tmpstrRole= '' SELECT @tmpstrRole = @tmpstrRole + CASE WHEN sysadmin = 1 THEN @Prefix + [LoginName] + '' ', @rolename=' 'sysadmin' '' ELSE '' END + CASE WHEN securityadmin = 1 THEN @Prefix + [LoginName] + '' ', @rolename=' 'securityadmin' '' ELSE '' END + CASE WHEN serveradmin = 1 THEN @Prefix + [LoginName] + '' ', @rolename=' 'serveradmin' '' ELSE '' END + CASE WHEN setupadmin = 1 THEN @Prefix + [LoginName] + '' ', @rolename=' 'setupadmin' '' ELSE '' END + CASE WHEN processadmin = 1 THEN @Prefix + [LoginName] + '' ', @rolename=' 'processadmin' '' ELSE '' END + CASE WHEN diskadmin = 1 THEN @Prefix + [LoginName] + '' ', @rolename=' 'diskadmin' '' ELSE '' END + CASE WHEN dbcreator = 1 THEN @Prefix + [LoginName] + '' ', @rolename=' 'dbcreator' '' ELSE '' END + CASE WHEN bulkadmin = 1 THEN @Prefix + [LoginName] + '' ', @rolename=' 'bulkadmin' '' ELSE '' END FROM ( SELECT CONVERT ( VARCHAR (100),SUSER_SNAME(sid)) AS [LoginName], sysadmin, securityadmin, serveradmin, setupadmin, processadmin, diskadmin, dbcreator, bulkadmin FROM sys.syslogins WHERE ( sysadmin<>0 OR securityadmin<>0 OR serveradmin<>0 OR setupadmin <>0 OR processadmin <>0 OR diskadmin<>0 OR dbcreator<>0 OR bulkadmin<>0 ) AND name =@ name ) L PRINT @tmpstr PRINT @tmpstrRole PRINT 'END' END FETCH NEXT FROM login_curs INTO @SID_varbinary, @ name , @type, @is_disabled, @defaultdb, @hasaccess, @denylogin, @defaultlanguage END CLOSE login_curs DEALLOCATE login_curs RETURN 0 END |
1 2 |
EXEC sp_help_revlogin -- 结果中会输出所有账户以及其加密密码 |
1 | https://learn.microsoft.com/en-us/troubleshoot/sql/database-engine/security/transfer-logins-passwords-between-instances |
到此这篇关于SQL Server 实例之间传输登录名和密码的文章就介绍到这了
2023-10-27
windows11安装SQL server数据库报错等待数据库引擎恢复句柄失败解决办法2023-10-27
SQL Server截取字符串函数操作常见方法2023-10-27
浅谈SELECT *会导致查询效率低的原因收缩数据文件通过将数据页从文件末尾移动到更靠近文件开头的未占用的空间来恢复空间,在文件末尾创建足够的空间后,可取消对文件末尾的数据页的分配并将它们返回给文件系统,本文给大家介绍SQL Server 数据库中的收缩数据...
2023-10-27