mysql.user Table
MariaDB starting with 10.4
In MariaDB 10.4 and later, the mysql.global_priv table has replaced the mysql.user
table, and mysql.user
should be considered obsolete. It is now a view into mysql.global_priv
created for compatibility with older applications and monitoring scripts. New tools are supposed to use INFORMATION_SCHEMA
tables. From MariaDB 10.4.13, the dedicated mariadb.sys
user is created as the definer of the view. Previously, root
was the definer, which resulted in privilege problems when this username was changed (MDEV-19650).
The mysql.user
table contains information about users that have permission to access the MariaDB server, and their global privileges. The table can be queried and although it is possible to directly update it, it is best to use GRANT and CREATE USER for adding users and privileges.
Note that the MariaDB privileges occur at many levels. A user may not be granted create
privilege at the user level, but may still have create
permission on certain tables or databases, for example. See privileges for a more complete view of the MariaDB privilege system.
The mysql.user
table contains the following fields:
Field | Type | Null | Key | Default | Description |
---|---|---|---|---|---|
Host | char(60) | NO | PRI | Host (together with User makes up the unique identifier for this account. | |
User | char(80) | NO | PRI | User (together with Host makes up the unique identifier for this account. | |
Password | longtext (>= MariaDB 10.4.1), char(41) (<= MariaDB 10.4.0) | NO | Hashed password, generated by the PASSWORD() function. | ||
Select_priv | enum('N','Y') | NO | N | Can perform SELECT statements. | |
Insert_priv | enum('N','Y') | NO | N | Can perform INSERT statements. | |
Update_priv | enum('N','Y') | NO | N | Can perform UPDATE statements. | |
Delete_priv | enum('N','Y') | NO | N | Can perform DELETE statements. | |
Create_priv | enum('N','Y') | NO | N | Can CREATE DATABASE's or CREATE TABLE's. | |
Drop_priv | enum('N','Y') | NO | N | Can DROP DATABASE's or DROP TABLE's. | |
Reload_priv | enum('N','Y') | NO | N | Can execute FLUSH statements or equivalent mariadb-admin commands. | |
Shutdown_priv | enum('N','Y') | NO | N | Can shut down the server with SHUTDOWN or mariadb-admin shutdown. | |
Process_priv | enum('N','Y') | NO | N | Can show information about active processes, via SHOW PROCESSLIST or mariadb-admin processlist. | |
File_priv | enum('N','Y') | NO | N | Read and write files on the server, using statements like LOAD DATA INFILE or functions like LOAD_FILE(). Also needed to create CONNECT outward tables. MariaDB server must have permission to access those files. | |
Grant_priv | enum('N','Y') | NO | N | User can grant privileges they possess. | |
References_priv | enum('N','Y') | NO | N | Unused | |
Index_priv | enum('N','Y') | NO | N | Can create an index on a table using the CREATE INDEX statement. Without the INDEX privilege, user can still create indexes when creating a table using the CREATE TABLE statement if the user has have the CREATE privilege, and user can create indexes using the ALTER TABLE statement if they have the ALTER privilege. | |
Alter_priv | enum('N','Y') | NO | N | Can perform ALTER TABLE statements. | |
Show_db_priv | enum('N','Y') | NO | N | Can list all databases using the SHOW DATABASES statement. Without the SHOW DATABASES privilege, user can still issue the SHOW DATABASES statement, but it will only list databases containing tables on which they have privileges. | |
Super_priv | enum('N','Y') | NO | N | Can execute superuser statements: CHANGE MASTER TO, KILL (users who do not have this privilege can only KILL their own threads), PURGE LOGS, SET global system variables, or the mariadb-admin debug command. Also, this permission allows the user to write data even if the read_only startup option is set, enable or disable logging, enable or disable replication on slaves, specify a DEFINER for statements that support that clause, connect once after reaching the MAX_CONNECTIONS . If a statement has been specified for the init-connect mysqld option, that command will not be executed when a user with SUPER privileges connects to the server. | |
Create_tmp_table_priv | enum('N','Y') | NO | N | Can create temporary tables with the CREATE TEMPORARY TABLE statement. | |
Lock_tables_priv | enum('N','Y') | NO | N | Acquire explicit locks using the LOCK TABLES statement; user also needs to have the SELECT privilege on a table in order to lock it. | |
Execute_priv | enum('N','Y') | NO | N | Can execute stored procedure or functions. | |
Repl_slave_priv | enum('N','Y') | NO | N | Accounts used by slave servers on the master need this privilege. This is needed to get the updates made on the master. | |
Repl_client_priv | enum('N','Y') | NO | N | Can execute SHOW MASTER STATUS and SHOW SLAVE STATUS statements. | |
Create_view_priv | enum('N','Y') | NO | N | Can create a view using the CREATE_VIEW statement. | |
Show_view_priv | enum('N','Y') | NO | N | Can show the CREATE VIEW statement to create a view using the SHOW CREATE VIEW statement. | |
Create_routine_priv | enum('N','Y') | NO | N | Can create stored programs using the CREATE PROCEDURE and CREATE FUNCTION statements. | |
Alter_routine_priv | enum('N','Y') | NO | N | Can change the characteristics of a stored function using the ALTER FUNCTION statement. | |
Create_user_priv | enum('N','Y') | NO | N | Can create a user using the CREATE USER statement, or implicitly create a user with the GRANT statement. | |
Event_priv | enum('N','Y') | NO | N | Create, drop and alter events. | |
Trigger_priv | enum('N','Y') | NO | N | Can execute triggers associated with tables the user updates, execute the CREATE TRIGGER and DROP TRIGGER statements. | |
Create_tablespace_priv | enum('N','Y') | NO | N | ||
Delete_history_priv | enum('N','Y') | NO | N | Can delete rows created through system versioning. | |
ssl_type | enum('', 'ANY', 'X509', 'SPECIFIED') | NO | TLS type - see TLS options. | ||
ssl_cipher | blob | NO | NULL | TLS cipher - see TLS options. | |
x509_issuer | blob | NO | NULL | X509 cipher - see TLS options. | |
x509_subject | blob | NO | NULL | SSL subject - see TLS options. | |
max_questions | int(11) unsigned | NO | 0 | Number of queries the user can perform per hour. Zero is unlimited. See per-account resource limits. | |
max_updates | int(11) unsigned | NO | 0 | Number of updates the user can perform per hour. Zero is unlimited. See per-account resource limits. | |
max_connections | int(11) unsigned | NO | 0 | Number of connections the account can start per hour. Zero is unlimited. See per-account resource limits. | |
max_user_connections | int(11) | NO | 0 | Number of simultaneous connections the account can have. Zero is unlimited. See per-account resource limits. | |
plugin | char(64) | NO | Authentication plugin used on connection. If empty, uses the default. | ||
authentication_string | text | NO | NULL | Authentication string for the authentication plugin. | |
password_expired | enum('N','Y') | NO | N | MySQL-compatibility option, not implemented in MariaDB. | |
is_role | enum('N','Y') | NO | N | Whether the user is a role. | |
default_role | char(80) | NO | N | Role which will be enabled on user login automatically. | |
max_statement_time | decimal(12,6) | NO | 0.000000 | If non-zero, how long queries can run before being killed automatically. | |
Field | Type | Null | Key | Default | Description |
The Acl_roles status variable indicates how many rows the mysql.user
table contains where is_role='Y'
.
The Acl_users status variable, indicates how many rows the mysql.user
table contains where is_role='N'
.
Authentication Plugin
When the plugin
column is empty, MariaDB defaults to authenticating accounts with either the mysql_native_password
or the mysql_old_password
plugins. It decides which based on the hash used in the value for the Password
column. When there's no password set or when the 4.1 password hash is used, (which is 41 characters long), MariaDB uses the mysql_native_password
plugin. The mysql_old_password
plugin is used with pre-4.1 password hashes, (which are 16 characters long).
MariaDB also supports the use of alternative authentication plugins. When the plugin
column is not empty for the given account, MariaDB uses it to authenticate connection attempts. The specific plugin then uses the value of either the Password
column or the authentication_string
column to authenticate the user.
A specific authentication plugin can be used for an account by providing the IDENTIFIED VIA authentication_plugin
clause with the CREATE USER, ALTER USER, or GRANT statements.
For example, the following statement would create an account that authenticates with the PAM authentication plugin:
CREATE USER foo2@test IDENTIFIED VIA pam;
If the specific authentication plugin uses the authentication_string
column, then this value for the account can be specified after a USING
or AS
keyword. For example, the PAM authentication plugin accepts a service name that would go into the authentication_string
column for the account:
CREATE USER foo2@test IDENTIFIED VIA pam USING 'mariadb';