Pre-General Availability Draft: 2017-07-17
You can create MySQL accounts two ways:
By using account-management statements intended for creating accounts and establishing their privileges, such as
CREATE USERandGRANT. These statements cause the server to make appropriate modifications to the underlying grant tables.By manipulating the MySQL grant tables directly with statements such as
INSERT,UPDATE, orDELETE.
The preferred method is to use account-management statements because they are more concise and less error-prone than manipulating the grant tables directly. All such statements are described in Section 13.7.1, “Account Management Statements”. Direct grant table manipulation is discouraged, and is not described here. The server is free to ignore rows that become malformed as a result of such modifications.
Another option for creating accounts is to use the GUI tool
MySQL Workbench. Also, several third-party programs offer capabilities
for MySQL account administration. phpMyAdmin is
one such program.
The following examples show how to use the
mysql client program to set up new accounts.
These examples assume that privileges have been set up according
to the defaults described in Section 2.9.4, “Securing the Initial MySQL Account”.
This means that to make changes, you must connect to the MySQL
server as the MySQL root user, which has the
CREATE USER privilege.
First, use the mysql program to connect to the
server as the MySQL root user:
shell> mysql --user=root mysql
If you have assigned a password to the root
account, you must also supply a --password or
-p option.
After connecting to the server as root, you can
add new accounts. The following example uses
CREATE USER and
GRANT statements to set up four
accounts:
mysql> CREATE USER 'monty'@'localhost' IDENTIFIED BY 'some_pass';
mysql> GRANT ALL PRIVILEGES ON *.* TO 'monty'@'localhost'
-> WITH GRANT OPTION;
mysql> CREATE USER 'monty'@'%' IDENTIFIED BY 'some_pass';
mysql> GRANT ALL PRIVILEGES ON *.* TO 'monty'@'%'
-> WITH GRANT OPTION;
mysql> CREATE USER 'admin'@'localhost' IDENTIFIED BY 'admin_pass';
mysql> GRANT RELOAD,PROCESS ON *.* TO 'admin'@'localhost';
mysql> CREATE USER 'dummy'@'localhost';The accounts created by those statements have the following properties:
Two accounts have a user name of
montyand a password ofsome_pass. Both are superuser accounts with full privileges to do anything. The'monty'@'localhost'account can be used only when connecting from the local host. The'monty'@'%'account uses the'%'wildcard for the host part, so it can be used to connect from any host.The
'monty'@'localhost'account is necessary if there is an anonymous-user account forlocalhost. Without the'monty'@'localhost'account, that anonymous-user account takes precedence whenmontyconnects from the local host andmontyis treated as an anonymous user. The reason for this is that the anonymous-user account has a more specificHostcolumn value than the'monty'@'%'account and thus comes earlier in theusertable sort order. (usertable sorting is discussed in Section 6.2.6, “Access Control, Stage 1: Connection Verification”.)The
'admin'@'localhost'account has a password ofadmin_pass. This account can be used only byadminto connect from the local host. It is granted theRELOADandPROCESSadministrative privileges. These privileges enable theadminuser to execute the mysqladmin reload, mysqladmin refresh, and mysqladmin flush-xxxcommands, as well as mysqladmin processlist . No privileges are granted for accessing any databases. You could add such privileges usingGRANTstatements.The
'dummy'@'localhost'account has no password (which is insecure and not recommended). This account can be used only to connect from the local host. No privileges are granted. It is assumed that you will grant specific privileges to the account usingGRANTstatements.
To see the privileges for an account, use
SHOW GRANTS:
mysql> SHOW GRANTS FOR 'admin'@'localhost';
+-----------------------------------------------------+
| Grants for admin@localhost |
+-----------------------------------------------------+
| GRANT RELOAD, PROCESS ON *.* TO 'admin'@'localhost' |
+-----------------------------------------------------+
To see nonprivilege properties for an account, use
SHOW CREATE USER:
mysql> SHOW CREATE USER 'admin'@'localhost'\G
*************************** 1. row ***************************
CREATE USER for admin@localhost: CREATE USER 'admin'@'localhost'
IDENTIFIED WITH 'mysql_native_password'
AS '*67ACDEBDAB923990001F0FFB017EB8ED41861105'
REQUIRE NONE PASSWORD EXPIRE DEFAULT ACCOUNT UNLOCK
The next examples create three accounts and grant them access to
specific databases. Each of them has a user name of
custom and password of
obscure:
mysql> CREATE USER 'custom'@'localhost' IDENTIFIED BY 'obscure';
mysql> GRANT SELECT,INSERT,UPDATE,DELETE,CREATE,DROP
-> ON bankaccount.*
-> TO 'custom'@'localhost';
mysql> CREATE USER 'custom'@'host47.example.com' IDENTIFIED BY 'obscure';
mysql> GRANT SELECT,INSERT,UPDATE,DELETE,CREATE,DROP
-> ON expenses.*
-> TO 'custom'@'host47.example.com';
mysql> CREATE USER 'custom'@'%.example.com' IDENTIFIED BY 'obscure';
mysql> GRANT SELECT,INSERT,UPDATE,DELETE,CREATE,DROP
-> ON customer.*
-> TO 'custom'@'%.example.com';The three accounts can be used as follows:
The first account can access the
bankaccountdatabase, but only from the local host.The second account can access the
expensesdatabase, but only from the hosthost47.example.com.The third account can access the
customerdatabase, from any host in theexample.comdomain. This account has access from all machines in the domain due to use of the%wildcard character in the host part of the account name.