MySQL Tipps und Tricks
From Lolly's Wiki
Oneliner
All grants
# mysql --skip-column-names --batch --execute 'select concat_ws("@",user,host) from mysql.user' | xargs -n 1 -i mysql --execute 'show grants for {}'
InnoDB space
Per database
mysql> select table_schema as database_name, sum(round(data_length/1024/1024,2)) as total_size_mb from information_schema.tables where engine like 'innodb' group by table_schema order by total_size_mb;
Per table
mysql> select table_schema as database_name,table_name,round(data_length/1024/1024,2) as size_mb from information_schema.tables order by size_mb;
Logging
If you use SET GLOBAL it is just for the moment.
Don't forget to add it in your my.cnf to make it permanent!
What can I log?
The interesting variables here are:
- log_queries_not_using_indexes
- log_slave_updates
- log_slow_queries
- general_log
Choose logging destination FILE/TABLE/NONE
This affects general_log and slow_query_log.
- Log to the table mysql.slow_log and mysql.general_log
mysql> SET GLOBAL log_output=TABLE;
- Log to the table mysql.slow_log and mysql.general_log
mysql> SET GLOBAL log_output=TABLE;
- Both: tables and files
mysql> SET GLOBAL log_output = 'TABLE,FILE';
- None, if NONE appears in the log_output destinations there is no logging
mysql> SET GLOBAL log_output = 'TABLE,FILE,NONE';
is equal to
mysql> SET GLOBAL log_output = 'NONE';
Enable/disable general logging
mysql> SET GLOBAL general_log_file = '/var/lib/mysql/general.log';
Query OK, 0 rows affected (0.00 sec)
mysql> SET GLOBAL general_log = 'ON';
Query OK, 0 rows affected (0.00 sec)
mysql> SET GLOBAL general_log = 'OFF';
Query OK, 0 rows affected (0.00 sec)
Enable/disable logging of slow queries
mysql> SET GLOBAL slow_query_log_file = '/var/lib/mysql/slow-query.log';
Query OK, 0 rows affected (0.00 sec)
mysql> SET GLOBAL slow_query_log = 'ON';
Query OK, 0 rows affected (0.00 sec)
mysql> SET GLOBAL slow_query_log = 'OFF';
Query OK, 0 rows affected (0.00 sec)
Filesystems for MySQL
ext3/ext4
Mountoptions are:
- noatime
- data=writeback (best performance , only metadata is logged)
- data=ordered (ok performance , recording metadata and grouping metadata related to the data changes)
- data=journal (worst performance, but best data protection, ext3 default mode, recording metadata and all data)
Raw devices with InnoDB
Take a look at setting device permissions via udev first.
# lvs vg-data
LV VG Attr LSize Pool Origin Data% Move Log Copy% Convert
lv-rawdisk-innodb01 vg-data -wi-a---- 25.00g
# fdisk -l /dev/vg-data/lv-rawdisk-innodb01
Disk /dev/vg-data/lv-rawdisk-innodb01: 26.8 GB, 26843545600 bytes
255 heads, 63 sectors/track, 3263 cylinders, total 52428800 sectors
Units = sectors of 1 * 512 = 512 bytes
Sector size (logical/physical): 512 bytes / 512 bytes
I/O size (minimum/optimal): 512 bytes / 512 bytes
Disk identifier: 0x00000000
# bc -l
26843545600/(1024*1024*1024)
25.00000000000000000000
Yes... really 25GB!
Add your logical volume to your configuration /etc/mysql/conf.d/innodb.cnf :
[mysqld]
# InnoDB raw disks
innodb_data_home_dir=
innodb_data_file_path=/dev/vg-data/lv-rawdisk-innodb01:25Gnewraw
Do not forget apparmor! Like I did.. :-D
InnoDB: Operating system error number 13 in a file operation.
InnoDB: The error means mysqld does not have the access rights to
InnoDB: the directory.
InnoDB: File name /dev/dm-0
InnoDB: File operation call: 'open'.
InnoDB: Cannot continue operation.
Add your raw device to the apparmor config in /etc/apparmor.d/local/usr.sbin.mysqld :
# Site-specific additions and overrides for usr.sbin.mysqld.
# For more details, please see /etc/apparmor.d/local/README.
/dev/dm-* rwk,
Reload apparmor:
# service apparmor reload
Another try!
# service mysql start
InnoDB: The first specified data file /dev/vg-data/lv-rawdisk-innodb01 did not exist:
InnoDB: a new database to be created!
150812 15:48:23 InnoDB: Setting file /dev/vg-data/lv-rawdisk-innodb01 size to 25600 MB
InnoDB: Database physically writes the file full: wait...
InnoDB: Progress in MB: 100 200 300 400 500 600 700 800 900 1000 1100 1200 ...
Much better!
Analyse
mysql> select * from <tablename> PROCEDURE ANALYSE();