• Skip to main content
  • Skip to primary sidebar

DBA Diaries

Thoughts and experiences of a DBA working with SQL Server and MySQL

MySQL SHOW USERS? – How to List All MySQL Users and Privileges

June 16, 2014 by Andy Hayes 2 Comments

mysql show usersThere are a number of useful SHOW commands in MySQL. Sadly, there isn’t one for mysql SHOW USERS nor is there one for mysql LIST USERS. This is a little inconsistent when you consider that there are other commands such as SHOW DATABASES, SHOW VARIABLES, SHOW TABLES, SHOW GRANTS and others.

However there are ways to do it. You can get back a list of MySQL user accounts by querying the mysql.users table and if you want to find out which privileges each MySQL user has, then this is possible as well.

So let us take a look at what is possible….

Querying mysql.users

You can get back a list of users by running a simple select statement against the mysql.user table.

On my test system, this returns 3 records. As you can see, two of them are for user root.

SELECT * FROM mysql.user;
+------+
| user |
+------+
| andy |
| root |
| root |
+------+
3 rows in set (0.00 sec) 

This is because root can connect from multiple hosts.

SELECT user, host FROM mysql.user;
+------+-----------+
| user | host      |
+------+-----------+
| andy | {3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}         |
| root | {3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}         |
| root | localhost |
+------+-----------+
3 rows in set (0.00 sec)

Show privileges for a specific MySQL user using SHOW GRANTS

In order to do this, you can use SHOW GRANTS

SHOW GRANTS FOR 'root'@'localhost';
+------------------------------------------------------+
| Grants for root@localhost                            |
+------------------------------------------------------+
| GRANT ALL PRIVILEGES ON *.* TO 'root'@'localhost'....|
+------------------------------------------------------+
1 row in set (0.00 sec)

Show user privileges for all MySQL users using SHOW GRANTS

You first have to build up a list of SHOW GRANTS statements for each user in your mysql.users table.

SELECT CONCAT('SHOW GRANTS FOR ''',user,'''@''',host,''';') FROM mysql.user;

This will give you the following output.

+------------------------------------------------------+
| CONCAT('SHOW GRANTS FOR ''',user,'''@''',host,''';') |
+------------------------------------------------------+
| SHOW GRANTS FOR 'andy'@'{3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}';                          |
| SHOW GRANTS FOR 'root'@'{3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}';                          |
| SHOW GRANTS FOR 'root'@'localhost';                  |
+------------------------------------------------------+
3 rows in set (0.00 sec)

You could copy and paste each statement and execute each line to get a list. That is a bit fiddly and time consuming. One way of achieving this more quickly would be to output the results to a file and then read the file back in line by line.

You can use OUTFILE and SOURCE to do this.

SELECT CONCAT('SHOW GRANTS FOR ''',user,'''@''',host,''';') FROM mysql.user INTO outfile '/tmp/show_grants.txt';

Now read the file you have just produced

SOURCE /tmp/show_grants.txt

Produces the following output.

+--------------------------------------+
| Grants for andy@{3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}                    |
+--------------------------------------+
| GRANT USAGE ON *.* TO 'andy'@'{3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}' ....|
+--------------------------------------+
1 row in set (0.00 sec)

+--------------------------------------+
| Grants for root@{3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}                    |
+--------------------------------------+
| GRANT USAGE ON *.* TO 'root'@'{3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}' ....|
+--------------------------------------+
1 row in set (0.00 sec)

+-------------------------------------------------------+
| Grants for root@localhost                             |
+-------------------------------------------------------+
| GRANT ALL PRIVILEGES ON *.* TO 'root'@'localhost' ....|
+-------------------------------------------------------+
1 row in set (0.00 sec)

Using information_schema.user_privileges

Another way to list privileges for users would be to query user_privileges in information_schema

SELECT * FROM information_schema.user_privileges;
+--------------------+---------------+-------------------------+--------------+
| GRANTEE            | TABLE_CATALOG | PRIVILEGE_TYPE          | IS_GRANTABLE |
+--------------------+---------------+-------------------------+--------------+
| 'root'@'localhost' | NULL          | SELECT                  | YES          |
| 'root'@'localhost' | NULL          | INSERT                  | YES          |
| 'root'@'localhost' | NULL          | UPDATE                  | YES          |
| 'root'@'localhost' | NULL          | DELETE                  | YES          |
| 'root'@'localhost' | NULL          | CREATE                  | YES          |
| 'root'@'localhost' | NULL          | DROP                    | YES          |
| 'root'@'localhost' | NULL          | RELOAD                  | YES          |
| 'root'@'localhost' | NULL          | SHUTDOWN                | YES          |
| 'root'@'localhost' | NULL          | PROCESS                 | YES          |
| 'root'@'localhost' | NULL          | FILE                    | YES          |
| 'root'@'localhost' | NULL          | REFERENCES              | YES          |
| 'root'@'localhost' | NULL          | INDEX                   | YES          |
| 'root'@'localhost' | NULL          | ALTER                   | YES          |
| 'root'@'localhost' | NULL          | SHOW DATABASES          | YES          |
| 'root'@'localhost' | NULL          | SUPER                   | YES          |
| 'root'@'localhost' | NULL          | CREATE TEMPORARY TABLES | YES          |
| 'root'@'localhost' | NULL          | LOCK TABLES             | YES          |
| 'root'@'localhost' | NULL          | EXECUTE                 | YES          |
| 'root'@'localhost' | NULL          | REPLICATION SLAVE       | YES          |
| 'root'@'localhost' | NULL          | REPLICATION CLIENT      | YES          |
| 'root'@'localhost' | NULL          | CREATE VIEW             | YES          |
| 'root'@'localhost' | NULL          | SHOW VIEW               | YES          |
| 'root'@'localhost' | NULL          | CREATE ROUTINE          | YES          |
| 'root'@'localhost' | NULL          | ALTER ROUTINE           | YES          |
| 'root'@'localhost' | NULL          | CREATE USER             | YES          |
| 'root'@'localhost' | NULL          | EVENT                   | YES          |
| 'root'@'localhost' | NULL          | TRIGGER                 | YES          |
| 'root'@'{3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}'         | NULL          | USAGE                   | NO           |
| 'andy'@'{3a76cbff1b5ce5ace3bd34bbdd68f71285d81fb9af60114c7a6db80d3a8688de}'         | NULL          | USAGE                   | NO           |
+--------------------+---------------+-------------------------+--------------+
29 rows in set (0.00 sec)

Related Posts:

  • How to fix "conversion failed when converting date and/or time from character string"
    How to fix "conversion failed when converting date…
  • sql grouping sets
    Using SQL GROUPING SETS for Multiple GROUP BY…

Filed Under: All Articles, MySQL Administration Tagged With: mysql

About Andy Hayes

Andy Hayes is a DBA working with SQL Server since version 7.0. He has a wonderful wife and two beautiful children. He loves database technology, playing cricket, and blogging. He is passionate about sharing his experiences as a DBA and learning more to further his understanding and knowledge. You can follow me on Twitter, check out my Facebook page or follow me on Google+

Reader Interactions

Comments

  1. [email protected] says

    September 17, 2019 at 7:58 pm

    Thank You, very helpful.

    Reply
  2. srmes says

    May 19, 2021 at 11:12 am

    Nice idea on how to list all privileges
    If you don’t have OUTFILE permissions then you can run it from the command line

    mysql **flags to connect** -e”SELECT CONCAT(‘SHOW GRANTS FOR ”’,user,”’@”’,host,”’;’) FROM mysql.user” | awk “NR>1 { print }” | mysql **flags to connect** > /tmp/results.txt

    Reply

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Primary Sidebar

Categories

  • All Articles (84)
  • Career Development (8)
  • MySQL Administration (18)
  • MySQL Performance (2)
  • SQL Server Administration (24)
  • SQL Server News (3)
  • SQL Server Performance (14)
  • SQL Server Security (3)
  • SQL Tips and Tricks (21)

Top 10 Popular Posts

  • Using sp_change_users_login to fix SQL Server orphaned users
  • MySQL SHOW USERS? – How to List All MySQL Users and Privileges
  • How to shrink tempdb
  • How to Transfer Logins to Another SQL Server or Instance
  • How to Delete Millions of Rows using T-SQL with Reduced Impact
  • T-SQL – How to Select Top N Rows for Each Group Using ROW_NUMBER()
  • New T-SQL features in SQL Server 2012 – OFFSET and FETCH
  • How to Kill All MySQL Processes For a Specific User
  • Using exec sp_who2 to help with SQL Server troubleshooting
  • How to fix “conversion failed when converting date and/or time from character string”

Recent Posts

  • How to fix “conversion failed when converting date and/or time from character string”
  • Using SQL GROUPING SETS for Multiple GROUP BY Queries in a Single Query
  • How to Setup MySQL Master Master Replication
  • How To Use SQL to Convert a STRING to an INT
  • How to set up MySQL Replication Tutorial

Search

Connect

  • Twitter
  • Facebook
  • RSS

About

  • Cookie Policy
  • Disclaimer
  • About
Copyright ©