Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Create Login Script Expand / Collapse
Author
Message
Posted Friday, May 9, 2008 12:52 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Friday, July 25, 2014 5:21 AM
Points: 1,205, Visits: 923
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


Manie 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)
Post #497615
Posted Friday, May 9, 2008 1:46 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, July 8, 2014 1:37 AM
Points: 28, Visits: 366
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
Post #497642
Posted Friday, May 9, 2008 2:34 PM
UDP Broadcaster

UDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP Broadcaster

Group: General Forum Members
Last Login: Friday, April 5, 2013 4:43 PM
Points: 1,473, Visits: 1,314
Should you add OUTPUT AS

CREATE PROCEDURE dbo.Create_Login

(
@username varchar(50) OUTPUT
)

AS
...
?
Post #498229
Posted Saturday, May 10, 2008 6:14 AM


Keeper of the Duck

Keeper of the Duck

Group: Moderators
Last Login: Thursday, July 10, 2014 1:34 PM
Points: 6,623, Visits: 1,855
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, CISA, MCSE, Security+, MVP - SQL Server
Regular Columnist (Security), SQLServerCentral.com
Author of Introduction to SQL Server: Basic Skills for Any SQL Server User
| Professional Development blog | Technical Blog | LinkedIn | Twitter
Post #498347
Posted Wednesday, May 14, 2008 12:36 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Friday, July 25, 2014 5:21 AM
Points: 1,205, Visits: 923
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! :P:D:)

Manie 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)
Post #500203
Posted Thursday, December 17, 2009 12:05 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Monday, April 7, 2014 6:15 PM
Points: 86, Visits: 216
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
Post #835887
Posted Monday, November 29, 2010 6:11 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, December 3, 2010 6:54 AM
Points: 6, Visits: 12
Can this script be amended so it will read a spreadsheet with a list of

Username, password database access?
Post #1027284
Posted Tuesday, June 7, 2011 2:43 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, July 25, 2014 8:10 AM
Points: 2, Visits: 58
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
Post #1121390
Posted Thursday, April 12, 2012 4:15 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Today @ 9:21 AM
Points: 291, Visits: 364
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?
Post #1282224
Posted Friday, April 13, 2012 2:13 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Friday, July 25, 2014 5:21 AM
Points: 1,205, Visits: 923
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]


Manie 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)
Post #1283441
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse