Disk Issues

Using Symbolic Links

You can move tables and databases from the database directory to other locations and replace them with symbolic links to the new locations. You might want to do this, for example, to move a database to a file system with more free space or increase the speed of your system by spreading your tables to different disk.

The recommended way to do this is to just symlink databases to a different disk. Symlink tables only as a last resort.

Using Symbolic Links for Databases on Unix

On Unix, the way to symlink a database is to first create a directory on some disk where you have free space and then create a symlink to it from the MySQL data directory.

shell> mkdir /dr1/databases/test
shell> ln -s /dr1/databases/test /path/to/datadir

MySQL doesn't support linking one directory to multiple databases. Replacing a database directory with a symbolic link will work fine as long as you don't make a symbolic link between databases. Suppose that you have a database db1 under the MySQL data directory, and then make a symlink db2 that points to db1:

shell> cd /path/to/datadir
shell> ln -s db1 db2

Now, for any table tbl_a in db1, there also appears to be a table tbl_a in db2. If one client updates db1.tbl_a and another client updates db2.tbl_a, there will be problems.

If you really need to do this, you can change one of the source files. The file to modify depends on your version of MySQL. For MySQL 4.0 and up, look for the following statement in the mysys/my_symlink.c file:

if (!(MyFlags & MY_RESOLVE_LINK) ||
    (!lstat(filename,&stat_buff) && S_ISLNK(stat_buff.st_mode)))

Before MySQL 4.0, look for this statement in the mysys/mf_format.c file:

if (flag & 32 || (!lstat(to,&stat_buff) && S_ISLNK(stat_buff.st_mode)))

Change the statement to this:

if (1)

On Windows, you can use internal symbolic links to directories by compiling MySQL with -DUSE_SYMDIR. This allows you to put different databases on different disks. See the section called “Using Symbolic Links for Databases on Windows”.

Using Symbolic Links for Tables on Unix

Before MySQL 4.0, you should not symlink tables unless you are very careful with them. The problem is that if you run ALTER TABLE, REPAIR TABLE, or OPTIMIZE TABLE on a symlinked table, the symlinks will be removed and replaced by the original files. This happens because these statements work by creating a temporary file in the database directory and replacing the original file with the temporary file when the statement operation is complete.

You should not symlink tables on systems that don't have a fully working realpath() call. (At least Linux and Solaris support realpath()). You can check whether your system supports symbolic links by issuing a SHOW VARIABLES LIKE 'have_symlink' statement.

In MySQL 4.0, symlinks are fully supported only for MyISAM tables. For other table types, you will probably get strange problems if you try to use symbolic links on files in the operating system with any of the preceding statements.

The handling of symbolic links for MyISAM tables in MySQL 4.0 works the following way:

  • In the data directory, you will always have the table definition file, the data file, and the index file. The data file and index file can be moved elsewhere and replaced in the data directory by symlinks. The definition file cannot.

  • You can symlink the data file and the index file independently to different directories.

  • The symlinking can be done manually from the command line with ln -s if mysqld is not running. With SQL, you can instruct the server to perform the symlinking by using the DATA DIRECTORY and INDEX DIRECTORY options to CREATE TABLE. See CREATE TABLE.

  • myisamchk will not replace a symlink with the data file or index file. It works directly on the file a symlink points to. Any temporary files are created in the directory where the data file or index file is located.

  • When you drop a table that is using symlinks, both the symlink and the file the symlink points to are dropped. This is a good reason why you should not run mysqld as root or allow users to have write access to the MySQL database directories.

  • If you rename a table with ALTER TABLE ... RENAME and you don't move the table to another database, the symlinks in the database directory are renamed to the new names and the data file and index file are renamed accordingly.

  • If you use ALTER TABLE ... RENAME to move a table to another database, the table is moved to the other database directory. The old symlinks and the files to which they pointed are deleted. In other words, the new table will not be symlinked.

  • If you are not using symlinks, you should use the --skip-symbolic-links option to mysqld to ensure that no one can use mysqld to drop or rename a file outside of the data directory.

SHOW CREATE TABLE doesn't report if a table has symbolic links prior to MySQL 4.0.15. This is also true for mysqldump, which uses SHOW CREATE TABLE to generate CREATE TABLE statements.

Table symlink operations that are not yet supported:

  • ALTER TABLE ignores the DATA DIRECTORY and INDEX DIRECTORY table options.

  • BACKUP TABLE and RESTORE TABLE don't respect symbolic links.

  • The .frm file must never be a symbolic link (as indicated previously, only the data and index files can be symbolic links). Attempting to do this (for example, to make synonyms) will produce incorrect results. Suppose that you have a database db1 under the MySQL data directory, a table tbl1 in this database, and in the db1 directory you make a symlink tbl2 that points to tbl1:

    shell> cd /path/to/datadir/db1
    shell> ln -s tbl1.frm tbl2.frm
    shell> ln -s tbl1.MYD tbl2.MYD
    shell> ln -s tbl1.MYI tbl2.MYI
    

    Now there will be problems if one thread reads db1.tbl1 and another thread updates db1.tbl2:

    • The query cache will be fooled (it will believe tbl1 has not been updated so will return out-of-date results).

    • ALTER statements on tbl2 will also fail.

Using Symbolic Links for Databases on Windows

Beginning with MySQL 3.23.16, the mysqld-max and mysql-max-nt servers for Windows are compiled with the -DUSE_SYMDIR option. This allows you to put a database directory on a different disk by setting up a symbolic link to it. This is similar to the way that symbolic links work on Unix, although the procedure for setting up the link is different.

As of MySQL 4.0, symbolic links are enabled by default. If you don't need them, you can disable them with the skip-symbolic-links option:

[mysqld]
skip-symbolic-links

Before MySQL 4.0, symbolic links are disabled by default. To enable them, you should put the following entry in your my.cnf or my.ini file:

[mysqld]
symbolic-links

On Windows, you make a symbolic link to a MySQL database by creating a file in the data directory that contains the path to the destination directory. The file should be named db_name.sym, where db_name is the database name.

Suppose that the MySQL data directory is C:\mysql\data and you want to have database foo located at D:\data\foo. Set up a symlink like this:

  1. Make sure that the D:\data\foo directory exists by creating it if necessary. If you already have a database directory named foo in the data directory, you should move it to D:\data. Otherwise, the symbolic link will be ineffective. To avoid problems, the server should not be running when you move the database directory.

  2. Create a file C:\mysql\data\foo.sym that contains the pathname D:\data\foo\.

After that, all tables created in the database foo will be created in D:\data\foo. Note that the symbolic link will not be used if a directory with the database name exists in the MySQL data directory.