CREATE LOGIN (Transact-SQL)

Creates a new SQL Server login. 

Topic link iconTransact-SQL Syntax Conventions

Syntax

CREATE LOGIN loginName { WITH <option_list1> | FROM <sources> }

<option_list1> ::= 
    PASSWORD = { 'password' | hashed_password HASHED } [ MUST_CHANGE ]
    [ , <option_list2> [ ,... ] ]

<option_list2> ::=  
    SID = sid
    | DEFAULT_DATABASE =database    
    | DEFAULT_LANGUAGE =language
    | CHECK_EXPIRATION = { ON | OFF}
    | CHECK_POLICY = { ON | OFF}
    | CREDENTIAL =credential_name <sources> ::=
    WINDOWS [ WITH <windows_options>[ ,... ] ]
    | CERTIFICATE certname
    | ASYMMETRIC KEY asym_key_name<windows_options> ::=      
    DEFAULT_DATABASE =database
    | DEFAULT_LANGUAGE =language

Arguments

  • loginName
    Specifies the name of the login that is created. There are four types of logins: SQL Server logins, Windows logins, certificate-mapped logins, and asymmetric key-mapped logins. When creating logins mapped from a Windows domain account you must use the pre-Windows 2000 user logon name in the format [<domainName>\<loginName>]. You cannot use a UPN in the format loginName@DomainName. See example D later in this topic.

  • PASSWORD ='password'
    Applies to SQL Server logins only. Specifies the password for the login that is being created. You should use a strong password. For more information see Strong Passwords.

  • PASSWORD **=**hashed_password
    Applies to the HASHED keyword only. Specifies the hashed value of the password for the login that is being created.

  • HASHED
    Applies to SQL Server logins only. Specifies that the password entered after the PASSWORD argument is already hashed. If this option is not selected, the string entered as password is hashed before it is stored in the database. This option should only be used for migrating databases from one server to another. Do not use the HASHED option to create new logins.

  • MUST_CHANGE
    Applies to SQL Server logins only. If this option is included, SQL Server prompts the user for a new password the first time the new login is used.

  • CREDENTIAL **=**credential_name
    The name of a credential to be mapped to the new SQL Server login. The credential must already exist in the server. Currently this option only links the credential to a login. This option might be expanded in a future SQL Server version.

  • SID = sid
    Applies to SQL Server logins only. Specifies the GUID of the new SQL Server login. If this option is not selected, SQL Server automatically assigns a GUID.

  • DEFAULT_DATABASE **=**database
    Specifies the default database to be assigned to the login. If this option is not included, the default database is set to master.

  • DEFAULT_LANGUAGE **=**language
    Specifies the default language to be assigned to the login. If this option is not included, the default language is set to the current default language of the server. If the default language of the server is later changed, the default language of the login remains unchanged.

  • CHECK_EXPIRATION = { ON | OFF }
    Applies to SQL Server logins only. Specifies whether password expiration policy should be enforced on this login. The default value is OFF.

  • CHECK_POLICY = { ON | OFF }
    Applies to SQL Server logins only. Specifies that the Windows password policies of the computer on which SQL Server is running should be enforced on this login. The default value is ON.

  • WINDOWS
    Specifies that the login be mapped to a Windows login.

  • CERTIFICATE certname
    Specifies the name of a certificate to be associated with this login. This certificate must already occur in the master database.

  • ASYMMETRIC KEY asym_key_name
    Specifies the name of an asymmetric key to be associated with this login. This key must already occur in the master database.

Remarks

Passwords are case-sensitive.

Prehashing of passwords is supported only when you are creating SQL Server logins.

If MUST_CHANGE is specified, CHECK_EXPIRATION and CHECK_POLICY must be set to ON. Otherwise, the statement will fail.

A combination of CHECK_POLICY = OFF and CHECK_EXPIRATION = ON is not supported.

When CHECK_POLICY is set to OFF, lockout_time is reset and CHECK_EXPIRATION is set to OFF.

Important

CHECK_EXPIRATION and CHECK_POLICY are only enforced on Windows Server 2003 and later. For more information, see Password Policy.

Logins created from certificates or asymmetric keys are used only for code signing. They cannot be used to connect to SQL Server. You can create a login from a certificate or asymmetric key only when the certificate or asymmetric key already exists in master.

Permissions

Requires ALTER ANY LOGIN or ALTER LOGIN permission on the server.

If the CREDENTIAL option is used, also requires ALTER ANY CREDENTIAL permission on the server.

Examples

A. Creating a login with a password

The following example creates a login for a particular user ID and assigns a password. The MUST_CHANGE option requires users to change this password the first time they connect to the server.

CREATE LOGIN <loginName> WITH PASSWORD = '<enterStrongPasswordHere>' MUST_CHANGE;
GO

B. Creating a login mapped to a credential

The following example creates the login for a particular user, using the user ID. This login is mapped to the credential.

CREATE LOGIN <loginName> WITH PASSWORD = '<enterStrongPasswordHere>', 
    CREDENTIAL = <credentialName>;
GO

C. Creating a login from a certificate

The following example creates login for a particular user ID from a certificate in master.

USE MASTER;
CREATE CERTIFICATE <certificateName>
    WITH SUBJECT = '<loginName> certificate in master database',
    EXPIRY_DATE = '12/05/2025';
GO
CREATE LOGIN <loginName> FROM CERTIFICATE <certificateName>;
GO

D. Creating a login from a Windows domain account

The following example creates a login from a Windows domain account.

CREATE LOGIN [<domainName>\<loginName>] FROM WINDOWS;
GO