Friday, November 30, 2012

MySQL user authentication

I was looking around on the MySQL forums when I ran across this post and it got me thinking. First, thank you to Scott for helping in the community forum.  But also about how some still have issues with MySQL user authentication. So I thought I would put together a simple quick post about MySQL user authentication.

The forum post I mentioned above talks about user connection issues and how a user "is likely the record that is getting used by MySQL."

Well, lets review a simple example to ensure that we always will know what user is being authenticated by MySQL.

First we build out a few options for users.

CREATE USER 'foo'@'localhost' IDENTIFIED BY 'some_pass';
CREATE USER '%'@'localhost' IDENTIFIED BY 'some_pass';
CREATE USER 'foo'@'%' IDENTIFIED BY 'some_pass';

GRANT SELECT, INSERT, DELETE ON *.* TO 'foo'@'localhost';
GRANT SELECT, INSERT, DELETE ON *.* TO '%'@'localhost';
GRANT SELECT, INSERT, DELETE ON *.* TO 'foo'@'%';
FLUSH PRIVILEGES;

mysql> select User, Host,Password, Select_priv, Insert_priv, Delete_priv From user Where User = 'foo'\G
*************************** 1. row ***************************
       User: foo
       Host: localhost
   Password: *BF06A06D69EC935E85659FCDED1F6A80426ABD3B
Select_priv: Y
Insert_priv: Y
Delete_priv: Y
*************************** 2. row ***************************
       User: foo
       Host: %
   Password: *BF06A06D69EC935E85659FCDED1F6A80426ABD3B
Select_priv: Y
Insert_priv: Y
Delete_priv: Y


Some might look at this and say that we have a duplicate user and that localhost is not needed, so their 1st reaction is to remove it.


DROP USER 'foo'@'localhost';


Then they end up have user permission/connection issues and are confused as to why?

Always use "CURRENT_USER();" so you can see who your  being authenticated as. USER() -- is the name given by the client.



mysql> SELECT USER(),  CURRENT_USER();
+---------------+----------------+
| USER()        | CURRENT_USER() |
+---------------+----------------+
| foo@localhost | foo@%          |
+---------------+----------------+


So based on the CURRENT_USER result we realize that we need to look at other accounts.

mysql> select User, Host,Password, Select_priv, Insert_priv, Delete_priv From user Where Host = 'localhost'\G
*************************** 1. row ***************************
       User: %
       Host: localhost
   Password: *BF06A06D69EC935E85659FCDED1F6A80426ABD3B
Select_priv: Y
Insert_priv: Y
Delete_priv: Y
*************************** 2. row ***************************
       User: root
       Host: localhost
   Password: *2447D497B9A6A15F2776055CB2D1E9F86758182F
Select_priv: Y
Insert_priv: Y
Delete_priv: Y



The problem was not 'foo'@'localhost'  but instead the problem is '%'@'localhost'. MySQL will authenticate on Host 1st before it checks the User. So since it found a quick match to '%'@'localhost' we ended up with:


mysql -u foo -p

SELECT  CURRENT_USER();
+----------------+
| CURRENT_USER() |
+----------------+
| foo@%          |
+----------------+


Using '%'@'localhost' is never a good idea in my opinion. You always want to lock the database down to User and Host/ip. A wild card as part of an IP address I am ok with as well. ie: 'foo'@'192.168.0.%'

This is a very simple example but the point is still a valid one. Control the permission, users and hosts with a watchful eye.


Keep in mind the mysql_secure_installation options for a more secure server as well.


# mysql_secure_installation


NOTE: RUNNING ALL PARTS OF THIS SCRIPT IS RECOMMENDED FOR ALL MySQL SERVERS IN PRODUCTION USE!  PLEASE READ EACH STEP CAREFULLY!


In order to log into MySQL to secure it, we'll need the current
password for the root user.  If you've just installed MySQL, and
you haven't set the root password yet, the password will be blank,
so you should just press enter here.

Enter current password for root (enter for none):
OK, successfully used password, moving on...

Setting the root password ensures that nobody can log into the MySQL
root user without the proper authorisation.

You already have a root password set, so you can safely answer 'n'.

Change the root password? [Y/n] n
 ... skipping.

By default, a MySQL installation has an anonymous user, allowing anyone
to log into MySQL without having to have a user account created for
them.  This is intended only for testing, and to make the installation
go a bit smoother.  You should remove them before moving into a
production environment.

Remove anonymous users? [Y/n] y
 ... Success!

Normally, root should only be allowed to connect from 'localhost'.  This
ensures that someone cannot guess at the root password from the network.

Disallow root login remotely? [Y/n] y
 ... Success!

By default, MySQL comes with a database named 'test' that anyone can
access.  This is also intended only for testing, and should be removed
before moving into a production environment.

Remove test database and access to it? [Y/n] y
 - Dropping test database...
 ... Success!
 - Removing privileges on test database...
 ... Success!

Reloading the privilege tables will ensure that all changes made so far
will take effect immediately.

Reload privilege tables now? [Y/n] y
 ... Success!

Cleaning up...



All done!  If you've completed all of the above steps, your MySQL
installation should now be secure.

Thanks for using MySQL!



Helpful urls :