Skip to content

Commit f48cbf1

Browse files
authored
add sp_help_revlogin (#270)
* add sp_help_revlogin * add sp_help_revlogin * Updated bundled installer [skip ci] * disable linting * Updated bundled installer [skip ci] --------- Co-authored-by: lowlydba <[email protected]>
1 parent 84ae9e7 commit f48cbf1

File tree

4 files changed

+429
-1
lines changed

4 files changed

+429
-1
lines changed

LICENSE

Lines changed: 5 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,10 @@
1+
Copyright for sp_help_revlogin is held by Microsoft. All other copyright for project DBA MultiTool are held by John McCall.
2+
3+
---
4+
15
MIT License
26

3-
Copyright (c) 2018-2022 John McCall
7+
Copyright (c) 2018-2023 John McCall
48

59
Permission is hereby granted, free of charge, to any person obtaining a copy
610
of this software and associated documentation files (the "Software"), to deal

docs/README.md

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -27,6 +27,7 @@ For detailed instructions and documentation, see [dba-multitool.org](https://dba
2727
| ---- | ----------- |
2828
| [sp_doc][sp_doc] | Always have current documentation by generating it on the fly in markdown. |
2929
| [sp_estindex][sp_estindex] | Estimate a new index's size and statistics without having to create it. |
30+
| [sp_help_revlogin][sp_help_revlogin] | Stored procedures that will help generate necessary scripts to transfer logins and their passwords. |
3031
| [sp_helpme][sp_helpme] | A drop-in modern alternative to `sp_help`. |
3132
| [sp_sizeoptimiser][sp_sizeoptimiser] | Recommends space saving measures for data footprints, with special checks for SQL Server Express. |
3233

@@ -64,5 +65,6 @@ from [www.flaticon.com](https://www.flaticon.com/)*</sub>
6465
[slack]: https://sqlcommunity.slack.com/archives/C026Y2YCM9N
6566
[sp_doc]: https://dba-multitool.org/sp_doc
6667
[sp_estindex]: https://dba-multitool.org/sp_estindex
68+
[sp_help_revlogin]: https://learn.microsoft.com/en-us/troubleshoot/sql/database-engine/security/transfer-logins-passwords-between-instances
6769
[sp_helpme]: https://dba-multitool.org/sp_helpme
6870
[sp_sizeoptimiser]: https://dba-multitool.org/sp_sizeoptimiser

install_dba-multitool.sql

Lines changed: 211 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3147,6 +3147,217 @@ GO
31473147

31483148
EXEC sys.sp_addextendedproperty @name=N'@Verbose', @value=N'Show intermediate variables used in size calculations. Default is 0.' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'PROCEDURE',@level1name=N'sp_estindex';
31493149
GO
3150+
/* tsqllint-disable */
3151+
3152+
IF OBJECT_ID ('sp_hexadecimal') IS NOT NULL
3153+
DROP PROCEDURE sp_hexadecimal
3154+
GO
3155+
CREATE PROCEDURE [dbo].[sp_hexadecimal]
3156+
(
3157+
@binvalue varbinary(256),
3158+
@hexvalue varchar (514) OUTPUT
3159+
)
3160+
AS
3161+
BEGIN
3162+
DECLARE @charvalue varchar (514)
3163+
DECLARE @i int
3164+
DECLARE @length int
3165+
DECLARE @hexstring char(16)
3166+
SELECT @charvalue = '0x'
3167+
SELECT @i = 1
3168+
SELECT @length = DATALENGTH (@binvalue)
3169+
SELECT @hexstring = '0123456789ABCDEF'
3170+
3171+
WHILE (@i <= @length)
3172+
BEGIN
3173+
DECLARE @tempint int
3174+
DECLARE @firstint int
3175+
DECLARE @secondint int
3176+
3177+
SELECT @tempint = CONVERT(int, SUBSTRING(@binvalue,@i,1))
3178+
SELECT @firstint = FLOOR(@tempint/16)
3179+
SELECT @secondint = @tempint - (@firstint*16)
3180+
SELECT @charvalue = @charvalue + SUBSTRING(@hexstring, @firstint+1, 1) + SUBSTRING(@hexstring, @secondint+1, 1)
3181+
3182+
SELECT @i = @i + 1
3183+
END
3184+
SELECT @hexvalue = @charvalue
3185+
END
3186+
go
3187+
IF OBJECT_ID ('sp_help_revlogin') IS NOT NULL
3188+
DROP PROCEDURE sp_help_revlogin
3189+
GO
3190+
CREATE PROCEDURE [dbo].[sp_help_revlogin]
3191+
(
3192+
@login_name sysname = NULL
3193+
)
3194+
AS
3195+
BEGIN
3196+
DECLARE @name SYSNAME
3197+
DECLARE @type VARCHAR (1)
3198+
DECLARE @hasaccess INT
3199+
DECLARE @denylogin INT
3200+
DECLARE @is_disabled INT
3201+
DECLARE @PWD_varbinary VARBINARY (256)
3202+
DECLARE @PWD_string VARCHAR (514)
3203+
DECLARE @SID_varbinary VARBINARY (85)
3204+
DECLARE @SID_string VARCHAR (514)
3205+
DECLARE @tmpstr VARCHAR (1024)
3206+
DECLARE @is_policy_checked VARCHAR (3)
3207+
DECLARE @is_expiration_checked VARCHAR (3)
3208+
Declare @Prefix VARCHAR(255)
3209+
DECLARE @defaultdb SYSNAME
3210+
DECLARE @defaultlanguage SYSNAME
3211+
DECLARE @tmpstrRole VARCHAR (1024)
3212+
3213+
IF (@login_name IS NULL)
3214+
BEGIN
3215+
DECLARE login_curs CURSOR
3216+
FOR
3217+
SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin, p.default_language_name
3218+
FROM sys.server_principals p
3219+
LEFT JOIN sys.syslogins l ON ( l.name = p.name )
3220+
WHERE p.type IN ( 'S', 'G', 'U' )
3221+
AND p.name <> 'sa'
3222+
ORDER BY p.name
3223+
END
3224+
ELSE
3225+
DECLARE login_curs CURSOR
3226+
FOR
3227+
SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin, p.default_language_name
3228+
FROM sys.server_principals p
3229+
LEFT JOIN sys.syslogins l ON ( l.name = p.name )
3230+
WHERE p.type IN ( 'S', 'G', 'U' )
3231+
AND p.name = @login_name
3232+
ORDER BY p.name
3233+
3234+
OPEN login_curs
3235+
FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin, @defaultlanguage
3236+
IF (@@fetch_status = -1)
3237+
BEGIN
3238+
PRINT 'No login(s) found.'
3239+
CLOSE login_curs
3240+
DEALLOCATE login_curs
3241+
RETURN -1
3242+
END
3243+
3244+
SET @tmpstr = '/* sp_help_revlogin script '
3245+
PRINT @tmpstr
3246+
3247+
SET @tmpstr = '** Generated ' + CONVERT (varchar, GETDATE()) + ' on ' + @@SERVERNAME + ' */'
3248+
3249+
PRINT @tmpstr
3250+
PRINT ''
3251+
3252+
WHILE (@@fetch_status <> -1)
3253+
BEGIN
3254+
IF (@@fetch_status <> -2)
3255+
BEGIN
3256+
PRINT ''
3257+
3258+
SET @tmpstr = '-- Login: ' + @name
3259+
3260+
PRINT @tmpstr
3261+
3262+
SET @tmpstr='IF NOT EXISTS (SELECT * FROM sys.server_principals WHERE name = N'''+@name+''')
3263+
BEGIN'
3264+
Print @tmpstr
3265+
3266+
IF (@type IN ( 'G', 'U'))
3267+
BEGIN -- NT authenticated account/group
3268+
SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' FROM WINDOWS WITH DEFAULT_DATABASE = [' + @defaultdb + ']' + ', DEFAULT_LANGUAGE = [' + @defaultlanguage + ']'
3269+
END
3270+
ELSE
3271+
BEGIN -- SQL Server authentication
3272+
-- obtain password and sid
3273+
SET @PWD_varbinary = CAST( LOGINPROPERTY( @name, 'PasswordHash' ) AS varbinary (256) )
3274+
3275+
EXEC sp_hexadecimal @PWD_varbinary, @PWD_string OUT
3276+
EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT
3277+
3278+
-- obtain password policy state
3279+
SELECT @is_policy_checked = CASE is_policy_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSE NULL END
3280+
FROM sys.sql_logins
3281+
WHERE name = @name
3282+
3283+
SELECT @is_expiration_checked = CASE is_expiration_checked WHEN 1 THEN 'ON' WHEN 0 THEN 'OFF' ELSE NULL END
3284+
FROM sys.sql_logins
3285+
WHERE name = @name
3286+
3287+
SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' WITH PASSWORD = ' + @PWD_string + ' HASHED, SID = '
3288+
+ @SID_string + ', DEFAULT_DATABASE = [' + @defaultdb + ']' + ', DEFAULT_LANGUAGE = [' + @defaultlanguage + ']'
3289+
3290+
IF ( @is_policy_checked IS NOT NULL )
3291+
BEGIN
3292+
SET @tmpstr = @tmpstr + ', CHECK_POLICY = ' + @is_policy_checked
3293+
END
3294+
3295+
IF ( @is_expiration_checked IS NOT NULL )
3296+
BEGIN
3297+
SET @tmpstr = @tmpstr + ', CHECK_EXPIRATION = ' + @is_expiration_checked
3298+
END
3299+
END
3300+
3301+
IF (@denylogin = 1)
3302+
BEGIN -- login is denied access
3303+
SET @tmpstr = @tmpstr + '; DENY CONNECT SQL TO ' + QUOTENAME( @name )
3304+
END
3305+
ELSE IF (@hasaccess = 0)
3306+
BEGIN -- login exists but does not have access
3307+
SET @tmpstr = @tmpstr + '; REVOKE CONNECT SQL TO ' + QUOTENAME( @name )
3308+
END
3309+
IF (@is_disabled = 1)
3310+
BEGIN -- login is disabled
3311+
SET @tmpstr = @tmpstr + '; ALTER LOGIN ' + QUOTENAME( @name ) + ' DISABLE'
3312+
END
3313+
3314+
SET @Prefix = '
3315+
EXEC master.dbo.sp_addsrvrolemember @loginame='''
3316+
3317+
SET @tmpstrRole=''
3318+
3319+
SELECT @tmpstrRole = @tmpstrRole
3320+
+ CASE WHEN sysadmin = 1 THEN @Prefix + [LoginName] + ''', @rolename=''sysadmin''' ELSE '' END
3321+
+ CASE WHEN securityadmin = 1 THEN @Prefix + [LoginName] + ''', @rolename=''securityadmin''' ELSE '' END
3322+
+ CASE WHEN serveradmin = 1 THEN @Prefix + [LoginName] + ''', @rolename=''serveradmin''' ELSE '' END
3323+
+ CASE WHEN setupadmin = 1 THEN @Prefix + [LoginName] + ''', @rolename=''setupadmin''' ELSE '' END
3324+
+ CASE WHEN processadmin = 1 THEN @Prefix + [LoginName] + ''', @rolename=''processadmin''' ELSE '' END
3325+
+ CASE WHEN diskadmin = 1 THEN @Prefix + [LoginName] + ''', @rolename=''diskadmin''' ELSE '' END
3326+
+ CASE WHEN dbcreator = 1 THEN @Prefix + [LoginName] + ''', @rolename=''dbcreator''' ELSE '' END
3327+
+ CASE WHEN bulkadmin = 1 THEN @Prefix + [LoginName] + ''', @rolename=''bulkadmin''' ELSE '' END
3328+
FROM (
3329+
SELECT CONVERT(VARCHAR(100),SUSER_SNAME(sid)) AS [LoginName],
3330+
sysadmin,
3331+
securityadmin,
3332+
serveradmin,
3333+
setupadmin,
3334+
processadmin,
3335+
diskadmin,
3336+
dbcreator,
3337+
bulkadmin
3338+
FROM sys.syslogins
3339+
WHERE ( sysadmin<>0
3340+
OR securityadmin<>0
3341+
OR serveradmin<>0
3342+
OR setupadmin <>0
3343+
OR processadmin <>0
3344+
OR diskadmin<>0
3345+
OR dbcreator<>0
3346+
OR bulkadmin<>0
3347+
)
3348+
AND name=@name
3349+
) L
3350+
3351+
PRINT @tmpstr
3352+
PRINT @tmpstrRole
3353+
PRINT 'END'
3354+
END
3355+
FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin, @defaultlanguage
3356+
END
3357+
CLOSE login_curs
3358+
DEALLOCATE login_curs
3359+
RETURN 0
3360+
END
31503361
SET ANSI_NULLS ON;
31513362
GO
31523363

0 commit comments

Comments
 (0)