Description:
Trying to set up triggers on mysql.user table to audit password changes.  After setting up the triggers, some DCL statements (e.g., CREATE USER, GRANT) fail and cause the server to crash.  Server cannot be restarted until .TRG and .TRN files are removed.
How to repeat:
mysql> use mysql;
--Create the table for tracking the last time a user changes his password
mysql> CREATE TABLE password_history (Host char(60) character set utf8 collate utf8_bin NOT NULL default '', User char(16) character set utf8 collate utf8_bin NOT NULL default '', LastChange timestamp NOT NULL default CURRENT_TIMESTAMP, PRIMARY KEY  (Host,User));
--create triggers to update the password_history table
mysql> delimiter //
mysql> CREATE TRIGGER user_au AFTER UPDATE
ON user FOR EACH ROW
BEGIN
   IF NEW.Password != OLD.Password THEN
      INSERT INTO mysql.password_history (Host, User) VALUES (NEW.Host, NEW.User) ON DUPLICATE KEY UPDATE LastChange=CURRENT_TIMESTAMP;
   END IF;
END;
//
mysql> CREATE TRIGGER user_ai AFTER INSERT
ON user FOR EACH ROW
BEGIN
   INSERT INTO mysql.password_history (Host, User) VALUES (NEW.Host, NEW.User) ON DUPLICATE KEY UPDATE LastChange=CURRENT_TIMESTAMP;
END;
//
mysql> delimiter ;
--populate the password_history table with initial values
mysql> INSERT INTO password_history (Host, User) SELECT Host, User FROM user;
--view the current timestamp for our root user
mysql> SELECT * FROM password_history WHERE User = 'root' AND Host = 'localhost'\G
*************************** 1. row ***************************
      Host: localhost
      User: root
LastChange: 2006-03-20 12:07:37
1 row in set (0.00 sec)
--create a clone of the root user using DML
mysql> CREATE TEMPORARY TABLE x LIKE user;
mysql> INSERT INTO x SELECT * FROM user WHERE User = 'root' AND Host = 'localhost';
mysql> UPDATE x SET User = 'roottest';
mysql> INSERT INTO user SELECT * FROM x;
--verify that the trigger fired when the roottest user was created
mysql> SELECT * FROM password_history WHERE USER = 'roottest' AND Host = 'localhost'\G
*************************** 1. row ***************************
      Host: localhost
      User: roottest
LastChange: 2006-03-20 12:08:35
1 row in set (0.00 sec)
--now, create a user with DCL.  This will cause a server crash.
mysql> GRANT ALL ON *.* TO 'roottest2'@'localhost';
ERROR 2013 (HY000): Lost connection to MySQL server during query
mysql> show processlist;
ERROR 2006 (HY000): MySQL server has gone away
No connection. Trying to reconnect...
ERROR 2002 (HY000): Can't connect to local MySQL server through socket '/var/lib/mysql/mysql.sock' (2)
ERROR: 
Can't connect to the server
--View the .err log:
060320  9:12:49 [Note] /usr/sbin/mysqld: ready for connections.
Version: '5.0.19-standard'  socket: '/var/lib/mysql/mysql.sock'  port: 3306  MyS
QL Community Edition - Standard (GPL)
mysqld got signal 11;
This could be because you hit a bug. It is also possible that this binary
or one of the libraries it was linked against is corrupt, improperly built,
or misconfigured. This error can also be caused by malfunctioning hardware.
We will try our best to scrape up some info that will hopefully help diagnose
the problem, but since we have already crashed, something is definitely wrong
and this may fail.
key_buffer_size=402653184
read_buffer_size=2093056
max_used_connections=3
max_connections=200
threads_connected=1
It is possible that mysqld could use up to 
key_buffer_size + (read_buffer_size + sort_buffer_size)*max_connections = 121161
4 K
bytes of memory
Hope that's ok; if not, decrease some variables in the equation.
thd=0x8a8f248
Attempting backtrace. You can use the following information to find out
where mysqld died. If you see no messages after this, something went
terribly wrong...
Cannot determine thread, fp=0x1ad3ac, backtrace may not be correct.
Stack range sanity check OK, backtrace follows:
0x815d800
0xc9b7c8
0x8adf8f0
0x81e4231
0x817532c
0x817a230
0x8171443
0x8170f7d
0x81704c0
0xc95341
0xae16fe
New value of fp=(nil) failed sanity check, terminating stack trace!
Please read http://dev.mysql.com/doc/mysql/en/Using_stack_trace.html and follow 
instructions on how to resolve the stack trace. Resolved
stack trace is much more helpful in diagnosing the problem, so please do 
resolve it
Trying to get some variables.
Some pointers may be invalid and cause the dump to abort...
thd->query at 0x8adf148 = GRANT ALL ON *.* TO 'roottest2'@'localhost'
thd->thread_id=57
The manual page at http://www.mysql.com/doc/en/Crashing.html contains
information that should help you find out what is causing the crash.
Number of processes running now: 0
060320 12:09:06  mysqld restarted
060320 12:09:06  InnoDB: Database was not shut down normally!
InnoDB: Starting crash recovery.
InnoDB: Reading tablespace information from the .ibd files...
InnoDB: Restoring possible half-written data pages from the doublewrite
InnoDB: buffer...
060320 12:09:06  InnoDB: Starting log scan based on checkpoint at
InnoDB: log sequence number 0 47806.
InnoDB: Doing recovery: scanned up to log sequence number 0 47806
060320 12:09:06  InnoDB: Started; log sequence number 0 47806
060320 12:09:06 [ERROR] Fatal error: Can't open and lock privilege tables: Defin
er is not fully qualified
060320 12:09:06  mysqld ended
--to restart the server, have to delete the .TRG and .TRN files from the mysql/user directory:
cd /var/lib/mysql/mysql
rm user.TRG 
rm user_ai.TRN
rm user_au.TRN
--now the server will start
--CREATE USER also causes server crash (assuming triggers have been re-created, as above):
mysql> create user 'roottest3'@'%';
ERROR 2013 (HY000): Lost connection to MySQL server during query
--DROP triggers (either with DROP TRIGGER or deleting the .TRG and .TRN files) and the DCL works:
mysql> drop trigger user_au;
Query OK, 0 rows affected (0.00 sec)
mysql> drop trigger user_ai;
Query OK, 0 rows affected (0.09 sec)
mysql> GRANT ALL ON *.* TO 'roottest2'@'localhost';
Query OK, 0 rows affected (0.00 sec)
mysql> CREATE USER 'roottest3'@'localhost';
Query OK, 0 rows affected (0.00 sec)
Suggested fix:
Either fix the implementation of DCL (so that triggers on the grant tables fire as expected), or document in the mysql docs that triggers are not permitted on the mysql.* tables.  I highly recommend that we not resort to the latter, as triggers on the grant tables can allow basic user auditing, which is something MySQL lacks, compared to other databases.
  
 
 
 
 
 
 
 
 
 
Description: Trying to set up triggers on mysql.user table to audit password changes. After setting up the triggers, some DCL statements (e.g., CREATE USER, GRANT) fail and cause the server to crash. Server cannot be restarted until .TRG and .TRN files are removed. How to repeat: mysql> use mysql; --Create the table for tracking the last time a user changes his password mysql> CREATE TABLE password_history (Host char(60) character set utf8 collate utf8_bin NOT NULL default '', User char(16) character set utf8 collate utf8_bin NOT NULL default '', LastChange timestamp NOT NULL default CURRENT_TIMESTAMP, PRIMARY KEY (Host,User)); --create triggers to update the password_history table mysql> delimiter // mysql> CREATE TRIGGER user_au AFTER UPDATE ON user FOR EACH ROW BEGIN IF NEW.Password != OLD.Password THEN INSERT INTO mysql.password_history (Host, User) VALUES (NEW.Host, NEW.User) ON DUPLICATE KEY UPDATE LastChange=CURRENT_TIMESTAMP; END IF; END; // mysql> CREATE TRIGGER user_ai AFTER INSERT ON user FOR EACH ROW BEGIN INSERT INTO mysql.password_history (Host, User) VALUES (NEW.Host, NEW.User) ON DUPLICATE KEY UPDATE LastChange=CURRENT_TIMESTAMP; END; // mysql> delimiter ; --populate the password_history table with initial values mysql> INSERT INTO password_history (Host, User) SELECT Host, User FROM user; --view the current timestamp for our root user mysql> SELECT * FROM password_history WHERE User = 'root' AND Host = 'localhost'\G *************************** 1. row *************************** Host: localhost User: root LastChange: 2006-03-20 12:07:37 1 row in set (0.00 sec) --create a clone of the root user using DML mysql> CREATE TEMPORARY TABLE x LIKE user; mysql> INSERT INTO x SELECT * FROM user WHERE User = 'root' AND Host = 'localhost'; mysql> UPDATE x SET User = 'roottest'; mysql> INSERT INTO user SELECT * FROM x; --verify that the trigger fired when the roottest user was created mysql> SELECT * FROM password_history WHERE USER = 'roottest' AND Host = 'localhost'\G *************************** 1. row *************************** Host: localhost User: roottest LastChange: 2006-03-20 12:08:35 1 row in set (0.00 sec) --now, create a user with DCL. This will cause a server crash. mysql> GRANT ALL ON *.* TO 'roottest2'@'localhost'; ERROR 2013 (HY000): Lost connection to MySQL server during query mysql> show processlist; ERROR 2006 (HY000): MySQL server has gone away No connection. Trying to reconnect... ERROR 2002 (HY000): Can't connect to local MySQL server through socket '/var/lib/mysql/mysql.sock' (2) ERROR: Can't connect to the server --View the .err log: 060320 9:12:49 [Note] /usr/sbin/mysqld: ready for connections. Version: '5.0.19-standard' socket: '/var/lib/mysql/mysql.sock' port: 3306 MyS QL Community Edition - Standard (GPL) mysqld got signal 11; This could be because you hit a bug. It is also possible that this binary or one of the libraries it was linked against is corrupt, improperly built, or misconfigured. This error can also be caused by malfunctioning hardware. We will try our best to scrape up some info that will hopefully help diagnose the problem, but since we have already crashed, something is definitely wrong and this may fail. key_buffer_size=402653184 read_buffer_size=2093056 max_used_connections=3 max_connections=200 threads_connected=1 It is possible that mysqld could use up to key_buffer_size + (read_buffer_size + sort_buffer_size)*max_connections = 121161 4 K bytes of memory Hope that's ok; if not, decrease some variables in the equation. thd=0x8a8f248 Attempting backtrace. You can use the following information to find out where mysqld died. If you see no messages after this, something went terribly wrong... Cannot determine thread, fp=0x1ad3ac, backtrace may not be correct. Stack range sanity check OK, backtrace follows: 0x815d800 0xc9b7c8 0x8adf8f0 0x81e4231 0x817532c 0x817a230 0x8171443 0x8170f7d 0x81704c0 0xc95341 0xae16fe New value of fp=(nil) failed sanity check, terminating stack trace! Please read http://dev.mysql.com/doc/mysql/en/Using_stack_trace.html and follow instructions on how to resolve the stack trace. Resolved stack trace is much more helpful in diagnosing the problem, so please do resolve it Trying to get some variables. Some pointers may be invalid and cause the dump to abort... thd->query at 0x8adf148 = GRANT ALL ON *.* TO 'roottest2'@'localhost' thd->thread_id=57 The manual page at http://www.mysql.com/doc/en/Crashing.html contains information that should help you find out what is causing the crash. Number of processes running now: 0 060320 12:09:06 mysqld restarted 060320 12:09:06 InnoDB: Database was not shut down normally! InnoDB: Starting crash recovery. InnoDB: Reading tablespace information from the .ibd files... InnoDB: Restoring possible half-written data pages from the doublewrite InnoDB: buffer... 060320 12:09:06 InnoDB: Starting log scan based on checkpoint at InnoDB: log sequence number 0 47806. InnoDB: Doing recovery: scanned up to log sequence number 0 47806 060320 12:09:06 InnoDB: Started; log sequence number 0 47806 060320 12:09:06 [ERROR] Fatal error: Can't open and lock privilege tables: Defin er is not fully qualified 060320 12:09:06 mysqld ended --to restart the server, have to delete the .TRG and .TRN files from the mysql/user directory: cd /var/lib/mysql/mysql rm user.TRG rm user_ai.TRN rm user_au.TRN --now the server will start --CREATE USER also causes server crash (assuming triggers have been re-created, as above): mysql> create user 'roottest3'@'%'; ERROR 2013 (HY000): Lost connection to MySQL server during query --DROP triggers (either with DROP TRIGGER or deleting the .TRG and .TRN files) and the DCL works: mysql> drop trigger user_au; Query OK, 0 rows affected (0.00 sec) mysql> drop trigger user_ai; Query OK, 0 rows affected (0.09 sec) mysql> GRANT ALL ON *.* TO 'roottest2'@'localhost'; Query OK, 0 rows affected (0.00 sec) mysql> CREATE USER 'roottest3'@'localhost'; Query OK, 0 rows affected (0.00 sec) Suggested fix: Either fix the implementation of DCL (so that triggers on the grant tables fire as expected), or document in the mysql docs that triggers are not permitted on the mysql.* tables. I highly recommend that we not resort to the latter, as triggers on the grant tables can allow basic user auditing, which is something MySQL lacks, compared to other databases.