Clone SQL Logins with same permissions and with different Usernames/Password

  • I need to create clones of existing logins in SQL Server on the same server (With the same permissions and with different usernames and password). There are nearly 1000 Logins. Is there any easy way to do this other that scripting out each user and editing it ?

    Thanks in Advance !

    Sanz
  • Please try the below script. This will script for object access and roles,downside is u need to specify individual user name each time.

    DECLARE @DatabaseUserName [sysname]

    SET @DatabaseUserName = 'dbo'

    SET NOCOUNT ON

    DECLARE

    @errStatement [varchar](8000),

    @msgStatement [varchar](8000),

    @DatabaseUserID [smallint],

    @ServerUserName [sysname],

    @RoleName [varchar](8000),

    @ObjectID [int],

    @ObjectName [varchar](261)

    SELECT

    @DatabaseUserID = [sysusers].[uid],

    @ServerUserName = [master].[dbo].[syslogins].[loginname]

    FROM [dbo].[sysusers]

    INNER JOIN [master].[dbo].[syslogins]

    ON [sysusers].[sid] = [master].[dbo].[syslogins].[sid]

    WHERE [sysusers].[name] = @DatabaseUserName

    IF @DatabaseUserID IS NULL

    BEGIN

    SET @errStatement = 'User ' + @DatabaseUserName + ' does not exist in ' + DB_NAME() + CHAR(13) +

    'Please provide the name of a current user in ' + DB_NAME() + ' you wish to script.'

    RAISERROR(@errStatement, 16, 1)

    END

    ELSE

    BEGIN

    SET @msgStatement = '--Security creation script for user ' + @ServerUserName + CHAR(13) +

    '--Created At: ' + CONVERT(varchar, GETDATE(), 112) + REPLACE(CONVERT(varchar, GETDATE(), 108), ':', '') + CHAR(13) +

    '--Created By: ' + SUSER_NAME() + CHAR(13) +

    '--Add User To Database' + CHAR(13) +

    'USE [' + DB_NAME() + ']' + CHAR(13) +

    'EXEC [sp_grantdbaccess]' + CHAR(13) +

    CHAR(9) + '@loginame = ''' + @ServerUserName + ''',' + CHAR(13) +

    CHAR(9) + '@name_in_db = ''' + @DatabaseUserName + '''' + CHAR(13) +

    'GO' + CHAR(13) +

    '--Add User To Roles'

    PRINT @msgStatement

    DECLARE _sysusers

    CURSOR

    LOCAL

    FORWARD_ONLY

    READ_ONLY

    FOR

    SELECT

    [name]

    FROM [dbo].[sysusers]

    WHERE

    [uid] IN

    (

    SELECT

    [groupuid]

    FROM [dbo].[sysmembers]

    WHERE [memberuid] = @DatabaseUserID

    )

    OPEN _sysusers

    FETCH

    NEXT

    FROM _sysusers

    INTO @RoleName

    WHILE @@FETCH_STATUS = 0

    BEGIN

    SET @msgStatement = 'EXEC [sp_addrolemember]' + CHAR(13) +

    CHAR(9) + '@rolename = ''' + @RoleName + ''',' + CHAR(13) +

    CHAR(9) + '@membername = ''' + @DatabaseUserName + ''''

    PRINT @msgStatement

    FETCH

    NEXT

    FROM _sysusers

    INTO @RoleName

    END

    SET @msgStatement = 'GO' + CHAR(13) +

    '--Set Object Specific Permissions'

    PRINT @msgStatement

    DECLARE _sysobjects

    CURSOR

    LOCAL

    FORWARD_ONLY

    READ_ONLY

    FOR

    SELECT

    DISTINCT([sysobjects].[id]),

    '[' + USER_NAME([sysobjects].[uid]) + '].[' + [sysobjects].[name] + ']'

    FROM [dbo].[sysprotects]

    INNER JOIN [dbo].[sysobjects]

    ON [sysprotects].[id] = [sysobjects].[id]

    WHERE [sysprotects].[uid] = @DatabaseUserID

    OPEN _sysobjects

    FETCH

    NEXT

    FROM _sysobjects

    INTO

    @ObjectID,

    @ObjectName

    WHILE @@FETCH_STATUS = 0

    BEGIN

    SET @msgStatement = ''

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 193 AND [protecttype] = 205)

    SET @msgStatement = @msgStatement + 'SELECT,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 195 AND [protecttype] = 205)

    SET @msgStatement = @msgStatement + 'INSERT,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 197 AND [protecttype] = 205)

    SET @msgStatement = @msgStatement + 'UPDATE,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 196 AND [protecttype] = 205)

    SET @msgStatement = @msgStatement + 'DELETE,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 224 AND [protecttype] = 205)

    SET @msgStatement = @msgStatement + 'EXECUTE,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 26 AND [protecttype] = 205)

    SET @msgStatement = @msgStatement + 'REFERENCES,'

    IF LEN(@msgStatement) > 0

    BEGIN

    IF RIGHT(@msgStatement, 1) = ','

    SET @msgStatement = LEFT(@msgStatement, LEN(@msgStatement) - 1)

    SET @msgStatement = 'GRANT' + CHAR(13) +

    CHAR(9) + @msgStatement + CHAR(13) +

    CHAR(9) + 'ON ' + @ObjectName + CHAR(13) +

    CHAR(9) + 'TO ' + @DatabaseUserName

    PRINT @msgStatement

    END

    SET @msgStatement = ''

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 193 AND [protecttype] = 206)

    SET @msgStatement = @msgStatement + 'SELECT,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 195 AND [protecttype] = 206)

    SET @msgStatement = @msgStatement + 'INSERT,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 197 AND [protecttype] = 206)

    SET @msgStatement = @msgStatement + 'UPDATE,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 196 AND [protecttype] = 206)

    SET @msgStatement = @msgStatement + 'DELETE,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 224 AND [protecttype] = 206)

    SET @msgStatement = @msgStatement + 'EXECUTE,'

    IF EXISTS(SELECT * FROM [dbo].[sysprotects] WHERE [id] = @ObjectID AND [uid] = @DatabaseUserID AND [action] = 26 AND [protecttype] = 206)

    SET @msgStatement = @msgStatement + 'REFERENCES,'

    IF LEN(@msgStatement) > 0

    BEGIN

    IF RIGHT(@msgStatement, 1) = ','

    SET @msgStatement = LEFT(@msgStatement, LEN(@msgStatement) - 1)

    SET @msgStatement = 'DENY' + CHAR(13) +

    CHAR(9) + @msgStatement + CHAR(13) +

    CHAR(9) + 'ON ' + @ObjectName + CHAR(13) +

    CHAR(9) + 'TO ' + @DatabaseUserName

    PRINT @msgStatement

    END

    FETCH

    NEXT

    FROM _sysobjects

    INTO

    @ObjectID,

    @ObjectName

    END

    CLOSE _sysobjects

    DEALLOCATE _sysobjects

    PRINT 'GO'

    END

  • So what you are saying is after scripting the Logins, I have to change username/password manually(to clone the login). After doing this I will have to run the above script for every Login on each database.

    Sanz
  • Above script is for database User.

    Below script will give you create script of all Logins

    use master

    DECLARE @login_name sysname

    SET @login_name = null

    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 @defaultdb 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 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'

    ELSE

    DECLARE login_curs SCROLL CURSOR FOR

    SELECT p.sid, p.name, p.type, p.is_disabled, p.default_database_name, l.hasaccess, l.denylogin 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

    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

    IF (@type IN ( 'G', 'U'))

    BEGIN -- NT authenticated account/group

    SET @tmpstr = 'CREATE LOGIN ' + QUOTENAME( @name ) + ' FROM WINDOWS WITH DEFAULT_DATABASE = [' + @defaultdb + ']'

    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

    SELECT @PWD_string = master.dbo.fn_varbintohexstr(@PWD_varbinary)

    -- EXEC sp_hexadecimal @SID_varbinary,@SID_string OUT

    SELECT @SID_string = master.dbo.fn_varbintohexstr(@SID_varbinary)

    -- 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 + ']'

    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 @tmpstr

    END

    FETCH NEXT FROM login_curs INTO @SID_varbinary, @name, @type, @is_disabled, @defaultdb, @hasaccess, @denylogin

    END

    CLOSE login_curs

    DEALLOCATE login_curs

    -- RETURN 0

    GO

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply