SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Create Login Script


Create Login Script

Author
Message
Manie Verster
Manie Verster
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2564 Visits: 1035
I have the following stored procedure to create a login on SQL Server 2005. As is it works perfectly but I want to pass a parameter for the login name but keeps getting incorrect syntax errors. The script looks as follows:
CREATE PROCEDURE dbo.Create_Login
AS
BEGIN
SET NOCOUNT ON
CREATE LOGIN [johnny] WITH PASSWORD = '12345', DEFAULT_DATABASE=[dbname], DEFAULT_LANGUAGE=[British], CHECK_EXPIRATION=OFF, CHECK_POLICY=ON
EXEC sys.sp_addsrvrolemember @loginame = N'johnny', @rolename = N'sysadmin'
ALTER LOGIN [@username] DISABLE
END

When I pass the parameter it looks like this:

CREATE PROCEDURE dbo.Create_Login

(
@username varchar(50)
)

AS
BEGIN
SET NOCOUNT ON
CREATE LOGIN @username WITH PASSWORD = '12345', DEFAULT_DATABASE=[dbname], DEFAULT_LANGUAGE=[British], CHECK_EXPIRATION=OFF, CHECK_POLICY=ON
EXEC sys.sp_addsrvrolemember @loginame = @username, @rolename = N'sysadmin'
ALTER LOGIN @username DISABLE
END

Please can someone help me to get this right. I have searched but nowhere any site says anything about passing a parameter

Thanks
Manie Verster

:-PManie Verster
Developer
Johannesburg
South Africa

I can do all things through Christ who strengthens me. - Holy Bible
I am a man of fixed and unbending principles, the first of which is to be flexible at all times. - Everett Mckinley Dirkson (Well, I am trying. - Manie Verster)
Torsten Schüßler-406123
Torsten Schüßler-406123
SSC-Enthusiastic
SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)SSC-Enthusiastic (190 reputation)

Group: General Forum Members
Points: 190 Visits: 371
Hi Manie,

take a look at this:
http://blogs.msdn.com/lcris/archive/2005/06/15/sql-server-2005-procedure-signing-demo.aspx

CU
tosc


www.insidesql.org
SQL ORACLE
SQL ORACLE
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8597 Visits: 1314
Should you add OUTPUT AS

CREATE PROCEDURE dbo.Create_Login

(
@username varchar(50) OUTPUT
)

AS
...
?
K. Brian Kelley
K. Brian Kelley
Keeper of the Duck
Keeper of the Duck (31K reputation)

Group: Moderators
Points: 31390 Visits: 1917
The problem is that CREATE LOGIN and ALTER LOGIN won't take the variable. The way around this is to use Dynamic SQL. For instance:

CREATE PROCEDURE dbo.Create_Login
@username sysname
AS
BEGIN
SET NOCOUNT ON
DECLARE @SQL NVARCHAR(4000);

SET @SQL = 'CREATE LOGIN ' + @username + ' WITH PASSWORD = ''12345'', DEFAULT_DATABASE=[dbname], DEFAULT_LANGUAGE=[British], CHECK_EXPIRATION=OFF, CHECK_POLICY=ON';
EXECUTE(@SQL);

EXEC sys.sp_addsrvrolemember @loginame = @username, @rolename = N'sysadmin';

SET @SQL = 'ALTER LOGIN ' + @username + ' DISABLE';
EXECUTE(@SQL);
END;



K. Brian Kelley
@‌kbriankelley
Manie Verster
Manie Verster
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2564 Visits: 1035
K Brian Kelly, you are a star! I am defeinitely going to try this and I am sure it will work. This is the best answer I got do far! TongueBigGrinSmilew00t

:-PManie Verster
Developer
Johannesburg
South Africa

I can do all things through Christ who strengthens me. - Holy Bible
I am a man of fixed and unbending principles, the first of which is to be flexible at all times. - Everett Mckinley Dirkson (Well, I am trying. - Manie Verster)
DLathrop
DLathrop
SSChasing Mays
SSChasing Mays (626 reputation)SSChasing Mays (626 reputation)SSChasing Mays (626 reputation)SSChasing Mays (626 reputation)SSChasing Mays (626 reputation)SSChasing Mays (626 reputation)SSChasing Mays (626 reputation)SSChasing Mays (626 reputation)

Group: General Forum Members
Points: 626 Visits: 219
Yes, you need to use dynamic SQL to do this. Which means that whoever causes the stored procedure to execute needs the appropriate permissions to create logins, modify database users, grant permissions, etc. So unless this is just a convenience for people who are in the SysAdmin role, you will want to look at the solution referenced in the first reply o your post (which does use dynamic SQL for CREATE LOGIN).

Repeating the link:
http://blogs.msdn.com/lcris/archive/2005/06/15/sql-server-2005-procedure-signing-demo.aspx

David Lathrop
DBA
WA Dept of Health
david.griffiths 57552
david.griffiths 57552
SSC Rookie
SSC Rookie (34 reputation)SSC Rookie (34 reputation)SSC Rookie (34 reputation)SSC Rookie (34 reputation)SSC Rookie (34 reputation)SSC Rookie (34 reputation)SSC Rookie (34 reputation)SSC Rookie (34 reputation)

Group: General Forum Members
Points: 34 Visits: 12
Can this script be amended so it will read a spreadsheet with a list of

Username, password database access?
Aristides Rapozo
Aristides Rapozo
Grasshopper
Grasshopper (24 reputation)Grasshopper (24 reputation)Grasshopper (24 reputation)Grasshopper (24 reputation)Grasshopper (24 reputation)Grasshopper (24 reputation)Grasshopper (24 reputation)Grasshopper (24 reputation)

Group: General Forum Members
Points: 24 Visits: 65
david.griffiths 57552 (11/29/2010)
Can this script be amended so it will read a spreadsheet with a list of

Username, password database access?


You can create a stored procedure that accepts username, password, etc..

Then in another column of your excel file using concatenate function create the sql statement for each on
somethin Like =CONCATENATE("EXEC usp_CreateLogin @username='",A2,"', @Password = '",B2,"' … ")

Then copy the cell and paste it all the way down until a statement per username is created, after that copy the whole column and paste it in the SQL Management Studio

This should create all the users
richardmgreen1
richardmgreen1
SSCrazy
SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)

Group: General Forum Members
Points: 2404 Visits: 1038
I'm looking for a similar thing but can't get this to work.

Can anyone think of a reason why this won't work in 2008 R2?
Does it need any alterations to work properly?
Manie Verster
Manie Verster
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2564 Visits: 1035
Hi guys,

Sorry for never giving feedback here but work has been hectic taking all my free time but no, sorry Brian I could not get your script going and was strapped for time at the time and got a different script and here it is.


declare @userid sysname = 'jon', @password sysname = 'password', @sqlstr nvarchar(250)
exec sp_addlogin @loginame = @userid,
@passwd = @password,
@defdb = 'ToolboxDB',
@deflanguage = [British],
@sid = null,
@encryptopt= null
EXEC sys.sp_addsrvrolemember @userid, @rolename = N'sysadmin'
USE [ToolboxDB]
set @sqlstr = 'CREATE USER '+@userid+' FOR LOGIN '+@userid
EXECUTE sp_executesql @sqlstr


Allow me to explain. The top part creates a login in sql server (not the database). You will see a security folder just below the database folder as follows:


exec sp_addlogin @loginame = @userid,
@passwd = @password,
@defdb = 'ToolboxDB',
@deflanguage = [British],
@sid = null,
@encryptopt= null


The following part adds the login to a server role. I have sysadmin here but you can change that according to your own needs.

EXEC sys.sp_addsrvrolemember @userid, @rolename = N'sysadmin'


You can also add it to more than one role if needed. The following part maps your login to a specific database and here you can also use more than one database just put the code in for each database.

USE [ToolboxDB]
set @sqlstr = 'CREATE USER '+@userid+' FOR LOGIN '+@userid
EXECUTE sp_executesql @sqlstr


Check out the link below for more on sp_executesql but the reason why I used this is because when I used Brian's script I kept getting "Cannot find the stored procedure ..........".
[url=http://http://www.mssqltips.com/sqlservertip/1160/execute-dynamic-sql-commands-in-sql-server/][/url]

:-PManie Verster
Developer
Johannesburg
South Africa

I can do all things through Christ who strengthens me. - Holy Bible
I am a man of fixed and unbending principles, the first of which is to be flexible at all times. - Everett Mckinley Dirkson (Well, I am trying. - Manie Verster)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search