CREATE USER

You are viewing an old version of this article. View the current version here.

Syntax

CREATE USER user 
    [IDENTIFIED [BY [PASSWORD] 'password']|
        |[{VIA|WITH} plugin_name [{USING|AS} 'plugin_option']]]

 [, user [IDENTIFIED [BY [PASSWORD] 'password']|[{VIA|WITH} plugin_name [{USING|AS} 'plugin_option']]]] 
 ...
MariaDB starting with 10.1.3

In MariaDB 10.1.3, the CREATE USER syntax was updated to:

CREATE [OR REPLACE] USER [IF NOT EXISTS] user 
    [IDENTIFIED [BY [PASSWORD] 'password']|
        |[{VIA|WITH} plugin_name [{USING|AS} 'plugin_option']]]

 [, user [IDENTIFIED [BY [PASSWORD] 'password']|[{VIA|WITH} plugin_name [{USING|AS} 'plugin_option']]]] 
 ...

Description

The CREATE USER statement creates new MariaDB accounts. To use it, you must have the global CREATE USER privilege or the INSERT privilege for the mysql database. For each account, CREATE USER creates a new row in the mysql.user table that has no privileges.

See Account Names below for details on how account names are specified.

If any of the specified user accounts already exist, ERROR 1396 (HY000) results. If an error occurs, CREATE USER will still create the accounts that do not result in an error. Only one error is produced for all users which have not been created:

ERROR 1396 (HY000): Operation CREATE USER failed for 'u1'@'%','u2'@'%'

Failed CREATE or DROP operations, for both users and roles, produce the same error code.

The account can be given a password with the optional IDENTIFIED BY clause. To specify the password in plain text, omit the PASSWORD keyword. To specify the password as the hashed value as returned by the PASSWORD function, include the PASSWORD keyword.

If you do not specify a password with the IDENTIFIED BY clause, the user will be able to connect without a password. A blank password is not a wildcard to match any password. The user must connect without providing a password if no password is set.

If you specify a plugin using the VIA clause, the plugin name must be an active authentication plugin as per show plugins. If it doesn't show up you will need to install it with INSTALL PLUGIN or install-soname). Some plugins require a plugin_option (like mysql_native_password).

MariaDB starting with 10.1.3

If the optional OR REPLACE clause is used, it acts as a shortcut for:

DROP USER IF EXISTS name;
CREATE USER name ...;

Account Names

Account names have both a user name and a host name, and are specified as 'user_name'@'host_name'.

When you connect to a MariaDB server, your user name and host must match a single account.

The user name and host name may be unquoted, quoted as strings using double quotes (") or single quotes ('), or quoted as identifiers using backticks (`). You must use quotes when using special characters (such as a hyphen) or wildcard characters. If you quote, you must quote the user name and host name separately (for example 'user_name'@'host_name').

Host Names

If the host name is not provided, it is assumed to be '%'.

Host names may contain the wildcard characters % and _. They are matched as if by the LIKE clause. If you need to use a wildcard character literally (for example, to match a domain name with an underscore), prefix the character with a backslash. See LIKE for more information on escaping wildcard characters.

Host name matches are case-insensitive. Host names can match either domain names or IP addresses. Use 'localhost' as the host name to allow only local client connections.

You can use a netmask to match a range of IP addresses using 'base_ip/netmask' as the host name. A user with an IP address ip_addr will be allowed to connect if the following condition is true:

ip_addr & netmask = base_ip

You can only use netmasks that specify a multiple of 8 bits of the address to match. That is, only the following netmasks are allowed:

255.0.0.0
255.255.0.0
255.255.255.0
255.255.255.255

Using 255.255.255.255 is equivalent to not using a netmask at all.

User Names

User names must match exactly, including case. You can use the empty string to allow a user with any user name.

It is possible for more than one account to match when a user connects. MariaDB selects the first matching account after sorting according to the following criteria:

  • Accounts with an exact host name are sorted before accounts using a wildcard in the host name. Host names using a netmask are considered to be exact for sorting.
  • Accounts with a wildcard in the host name are sorted according to the position of the first wildcard character. Those with a wildcard character later in the host name sort before those with a wildcard character earlier in the host name.
  • Accounts with a non-empty user name sort before accounts with an empty user name.

The following table shows a list of example account as sorted by these criteria:

+---------+-------------+
| User    | Host        |
+---------+-------------+
| joffrey | 192.168.0.3 |
|         | 192.168.0.% |
| joffrey | 192.168.%   |
|         | 192.168.%   |
+---------+-------------+

Once connected, you only have the privileges granted to the account that matched, not all accounts that could have matched. For example, consider the following commands:

CREATE USER 'jeffrey'@'192.168.0.3';
CREATE USER 'jeffrey'@'%';
GRANT SELECT ON test.t1 to 'jeffrey'@'192.168.0.3';
GRANT SELECT ON test.t2 to 'jeffrey'@'%';

If you connect as jeffrey from 192.168.0.3, you will have the SELECT privilege on the table test.t1, but not on the table test.t2. If you connect as jeffrey from any other IP address, you will have the SELECT privilege on the table test.t2, but not on the table test.t1.

MariaDB starting with 5.5.31

Beginning with MariaDB 5.5.31, usernames can be up to 80 characters long. However, in order to enable this feature, the following schema changes must be made:

alter table mysql.user         modify User         char(80)  binary not null default '';
alter table mysql.db           modify User         char(80)  binary not null default '';
alter table mysql.tables_priv  modify User         char(80)  binary not null default '';
alter table mysql.columns_priv modify User         char(80)  binary not null default '';
alter table mysql.procs_priv   modify User         char(80)  binary not null default '';
alter table mysql.proc         modify definer      char(141) collate utf8_bin not null default '';
alter table mysql.event        modify definer      char(141) collate utf8_bin not null default '';
alter table mysql.proxies_priv modify User         char(80)  COLLATE utf8_bin not null default '';
alter table mysql.proxies_priv modify Proxied_user char(80)  COLLATE utf8_bin not null default '';
alter table mysql.proxies_priv modify Grantor      char(141) COLLATE utf8_bin not null default '';
alter table mysql.servers      modify Username     char(80)                   not null default '';
alter table mysql.procs_priv   modify Grantor      char(141) COLLATE utf8_bin not null default '';
alter table mysql.tables_priv  modify Grantor      char(141) COLLATE utf8_bin not null default '';

flush privileges;

Comments

Comments loading...
Content reproduced on this site is the property of its respective owners, and this content is not reviewed in advance by MariaDB. The views, information and opinions expressed by this content do not necessarily represent those of MariaDB or any other party.