I say correct because there are several incorrect approaches to managing MySQL logs. In MySQL you have two important log files, the MySQL error log (configured with –log-error) and the MySQL slow query log (configured with –log-slow-queries or –slow-query-log and –slow-query-log-file which is available from 5.1.29).
The ideal management of these log files is different for each type of file.
The MySQL Error Log
With the error log you want to have one file showing a contiguous history of the server instance. This log provides valuable information over time and you should not discard this. You do NOT want to roll your error log. If for feel the content in the error log is too much, then these are errors you need to be addressing, and archiving after correcting. There are circumstances where error logs are rolled outside of your control.
The first is the FLUSH LOGS command. When this command is run, the error log is renamed to -old and a new log is created. For example:
$ ls -l log/error* -rw-rw---- 1 mysql root 1733 Feb 22 16:11 error.log $ mysql -uroot -p -e "FLUSH LOGS" $ ls -l log/error* -rw-rw---- 1 mysql mysql 0 Feb 22 18:08 error.log -rw-rw---- 1 mysql root 1733 Feb 22 16:11 error.log-old
What happens when you run this command again?
$ mysql -uroot -p -e "FLUSH LOGS" $ ls -l log/error* -rw-rw---- 1 mysql mysql 0 Feb 22 18:10 log/error.log -rw-rw---- 1 mysql mysql 0 Feb 22 18:08 log/error.log-old
You have now lost all valuable information in the error log, both the current log and the -old log are ZERO bytes in size.
The second example is the Ubuntu specific MySQL distribution on Ubuntu OS that logs MySQL information to the system error log (i.e. /var/log/syslog). You are then receiving a daily log rotate via the default OS log-rotate settings. You effectively lose information after 7 days. Here is what you will find on a stock Ubuntu server.
$ ls -l /var/log ... -rw-r----- 1 mysql adm 0 2008-05-28 20:33 mysql.err -rw-r----- 1 mysql adm 0 2008-05-28 20:33 mysql.log ... -rw-r----- 1 syslog adm 278480 2010-02-22 20:22 syslog -rw-r----- 1 syslog adm 366934 2010-02-22 06:25 syslog.0 -rw-r----- 1 syslog adm 21025 2010-02-21 06:27 syslog.1.gz -rw-r----- 1 syslog adm 18551 2010-02-20 06:47 syslog.2.gz -rw-r----- 1 syslog adm 20086 2010-02-19 06:25 syslog.3.gz -rw-r----- 1 syslog adm 17135 2010-02-18 06:40 syslog.4.gz -rw-r----- 1 syslog adm 19238 2010-02-17 06:32 syslog.5.gz -rw-r----- 1 syslog adm 16101 2010-02-16 06:34 syslog.6.gz
You have to troll the syslog files to find any mysql specific information, even that is not possible with one command.
$ grep syslog syslog.0 | grep mysql $ zcat syslog*gz | grep mysql Feb 16 22:12:20 db1 mysqld[21769]: 100216 22:12:20 [ERROR] /usr/sbin/mysqld: Incorrect key file for table '/tmp/#sql_5508_40.MYI'; try to repair it Feb 16 22:12:20 db1 mysqld[21769]: 100216 22:12:20 [ERROR] /usr/sbin/mysqld: Incorrect key file for table '/tmp/#sql_5508_33.MYI'; try to repair it Feb 16 22:30:15 db1 mysqld[21769]: 100216 22:19:13 [ERROR] /usr/sbin/mysqld: Incorrect key file for table '/tmp/#sql_5508_29.MYI'; try to repair it Feb 16 22:30:17 db1 mysqld[21769]: 100216 22:19:13 [ERROR] /usr/sbin/mysqld: Incorrect key file for table '/tmp/#sql_5508_44.MYI'; try to repair it ...
I’m lucky I looked, because tomorrow would have been too late to see these errors, as this is the oldest log file.
I place a disclaimer that if you have proper backups in place, these files are retrievable, but that takes time and effort which I consider unnecessary for a database server. The mysql log is one of the most important log files for this type of server, you want this information on the server.
The solution to this problem is easy in Ubuntu, always define the -log-error variable for the [mysqld] and [mysqld_safe] sections to a specific file, e.g. /var/log/mysql/mysql.log
The MySQL slow query log
With the slow query log, you DO want to rotate the log file produced. The best practice is to rotate this file daily. In addition you should both analyze the log file producing a top 5 or top 10 list of slow SQL queries each day. As load may not always predictable, it’s ideal to also analyze the combined logs of the past 7 days for cross reference.
The daily granularity allows you to track your load of slow performing queries more consistently and it also enables you verify more easily the impact of improvements made when they have been deployed.
Care needs to be taken to roll your log filed. Simply moving the log file will not work. For example.
A good tip to help in slow query SQL analysis is to
Comment your SQL (url)
$ mysql -uroot -p -e "select sleep(5)" $ tail -1 log/slow.log select sleep(5); $ ls -l log/slow* -rw-rw---- 1 mysql mysql 352 Feb 22 15:26 log/slow.log $ mv log/slow.log log/slow.log.1; touch log/slow.log $ ls -l log/slow* -rw-r--r-- 1 root root 0 Feb 22 15:26 log/slow.log -rw-rw---- 1 mysql mysql 352 Feb 22 15:26 log/slow.log.1 $ mysql -uroot -p -e "SELECT SLEEP(4)" $ ls -l log/slow* -rw-r--r-- 1 root root 0 Feb 22 15:26 log/slow.log -rw-rw---- 1 mysql mysql 533 Feb 22 16:01 log/slow.log.1 $ tail -1 log/slow.log.1 SELECT SLEEP(4);
As you can see, the slow log was not written to, but the previous file which has the same inode.
$ rm -f log/slow.log; mv log/slow.log.1 log/slow.log $ ls -l log/slow.log* -rw-rw---- 1 mysql mysql 533 Feb 22 16:01 log/slow.log $ cp log/slow.log log/slow.log.`date +%M`; > log/slow.log $ mysql -uroot -p -e "SELECT SLEEP(3)" $ ls -l log/slow.log* -rw-rw---- 1 mysql mysql 181 Feb 22 16:03 log/slow.log -rw-r----- 1 root root 533 Feb 22 16:03 log/slow.log.03 $ tail -1 log/slow.log SELECT SLEEP(3); $ cp log/slow.log log/slow.log.`date +%M`; > log/slow.log $ mysql -uroot -p -e "SELECT SLEEP(6)" $ ls -l log/slow.log* -rw-rw---- 1 mysql mysql 181 Feb 22 16:04 log/slow.log -rw-r----- 1 root root 533 Feb 22 16:03 log/slow.log.03 -rw-r----- 1 root root 181 Feb 22 16:04 log/slow.log.04 $ tail -1 log/slow.log SELECT SLEEP(6);
As you can see by copying and truncating you can perform an effective log rotate manually. Ideally you should config logrotate to manage this log.