All MySQL versions are tested on many platforms before they are released. This doesn't mean that there isn't any bugs in MySQL, but that if there are bugs they are very few and can be hard to find. If you have a problem, it will always help if you try to find out exactly what crashes your system as you will have a much better chance of getting this fixed quickly.
First you should try to find out whether the problem is that the
mysqld
daemon dies or whether your problem has to do with your
client. You can check how long your mysqld
server has been up by
executing mysqladmin version
. If mysqld
has died, you may
find the reason for this in the file
`mysql-data-directory/'hostname'.err'.
Many crashes of MySQL is caused by corrupted index / data
files. MySQL will update the data on disk, with the
write()
system call, after every SQL statement and before the
client is notified about the result (this is not true if you are running
with delayed_key_writes
, in which case only the data is written).
This means that the data is safe even if mysqld crashes as the OS will
ensure that the not flushed data is written to disk.
You can force MySQL to sync everything to disk by starting
mysqld
with --flush
.
The above means that normally you shouldn't get corrupted tables unless:
mysqld
or the machine in the middle
of an update.
mysqld
that caused it do die in the
middle of an update.
mysqld
servers on the same data on a
system that doesn't support good file system locks (normally handled by
the lockd
deamon.) or if you are running one or more of the
multiple servers with --skip-locking
ALTER TABLE
on a
repaired copy of the table!
Since it is very difficult to know why something is crashing, first try to check whether or not things that work for others crash for you. Please try the following things:
mysqld
daemon with mysqladmin shutdown
, run
myisamchk --silent --force */*.MYI
on all tables and restart the
mysqld
daemon. This will ensure that you are running from a clean
state. See section 14 Maintaining a MySQL installation.
mysqld --log
and try to determine from the information in the log
whether or not some specific query kills the server. 95% of all bugs are
related to a particular query! Normally this is one of the last queries in
the log file just before MySQL restarted.
You may be able to verify this using the following procedure:
mysqladmin shutdown
)
myisamchk -s */*.MYI
to verify that all tables
are correct. If any table is corrupted, repair it with
myisamchk -r path-to-table.MYI
.
safe_mysql --log
.
mysqld
now dies, you can test if the problem is a specific
query by restoring the backup and executing mysql <
mysql-log-file
. You can of course do the last test in some other
directory than the standard MySQL database directory by
starting another MySQL server with safe_mysqld
--data=path-to-backup-directory
.
fork_test.pl
and fork2_test.pl
.
--with-debug
option to
configure
and then recompile. See section G.1 Debugging a MySQL server.
--skip-locking
option to mysqld
. On some systems, the
lockd
lock manager does not work properly; the --skip-locking
option tells mysqld
not to use external locking. (This means that you
cannot run 2 mysqld
servers on the same data and that you must be
careful if you use myisamchk
, but it may be instructive to try the
option as a test.)
mysqladmin -u root processlist
when mysqld
appears to be running but not responding? Sometimes mysqld
is not
comatose even though you might think so. The problem may be that all
connections are in use, or there may be some internal lock problem.
mysqladmin processlist
will usually be able to make a connection even
in these cases, and can provide useful information about the current number
of connections and their status.
mysqladmin -i 5 status
in a separate window to produce statistics while you run your other queries.
mysqld
from gdb
(or another debugger).
back
(or the backtrace command in your debugger) when
mysqld
core dumps.
BLOB/TEXT
columns (but only VARCHAR
columns) you
can try to change all VARCHAR
to CHAR
with ALTER
TABLE
. This will force MySQL to use fixed size rows. Fixed
size rows take a little extra place, but are much more tolerant for
corruption!
The current dynamic row code has been in use at TCX for at least 3
years without any problems, but by nature dynamic length rows are more
prone to errors so it may be a good idea to try if the above helps!
MySQL server has gone away
error
This section also covers the related Lost connection to server
during query
error.
The most common reason for the MySQL server has gone away
error
is that the server timed out and closed the connection. By default, the
server closes the connection after 8 hours if nothing has happened. You
can change the time limit with by setting the wait_timeout
variable when
you start mysqld.
You can check that the MySQL hasn't died by executing
mysqladmin version
and examining the uptime.
If you have a script, you just have to issue the query again for the client to do an automatic reconnection.
You normally can get the following error codes in this case (which one you get is OS-dependent):
CR_SERVER_GONE_ERROR | The client couldn't send a question to the server. |
CR_SERVER_LOST | The client didn't get an error when writing to the server, but it didn't get a full answer (or any answer) to the question. |
You can also get these errors if you send a query to the server that is
incorrect or too large. If mysqld
gets a packet that is too large
or out of order, it assumes that something has gone wrong with the client and
closes the connection. If you need big queries (for example, if you are
working with big BLOB
columns), you can increase the query limit by
starting mysqld
with the -O max_allowed_packet=#
option
(default 1M). The extra memory is allocated on demand, so mysqld
will
use more memory only when you issue a big query or when mysqld
must
return a big result row!
Can't connect to [local] MySQL server
error
A MySQL client on Unix can connect to the mysqld
server in two
different ways: Unix sockets, which connect through a file in the file
system (default `/tmp/mysqld.sock'), or TCP/IP, which connects
through a port number. Unix sockets are faster than TCP/IP but can only
be used when connecting to a server on the same computer. Unix sockets
are used if you don't specify a hostname or if you specify the special
hostname localhost
.
On Windows you can connect only with TCP/IP if the mysqld
server
is running on Win95/Win98. If it's running on NT, you can also connect
with named pipes. The name of the named pipe is MySQL
. If you
don't give a hostname when connecting to mysqld
, a MySQL client
will first try to connect to the named pipe and if this doesn't work it
will connect to the TCP/IP port. You can force the use of named pipes
on Windows by using .
as the hostname.
The error (2002) Can't connect to ...
normally means that there
isn't a MySQL server running on the system or that you are
using a wrong socket file or TCP/IP port when trying to connect to the
mysqld
server.
Start by checking (using ps
or the task manager on windows) that
there is a process running named mysqld
on your server! If there
isn't any mysqld
process, you should start one. See section 4.15.2 Problems starting the MySQL server.
If a mysqld
process is running, you can check the server by
trying these different connections (the port number and socket pathname
might be different in your setup, of course):
shell> mysqladmin version shell> mysqladmin variables shell> mysqladmin -h `hostname` version variables shell> mysqladmin -h `hostname` --port=3306 version shell> mysqladmin -h 'ip for your host' version shell> mysqladmin --socket=/tmp/mysql.sock version
Note the use of backquotes rather than forward quotes with the hostname
command; these cause the output of hostname
(i.e., the current
hostname) to be substituted into the mysqladmin
command.
Here are some reasons the Can't connect to local MySQL server
error might occur:
mysqld
is not running.
mysqld
uses the MIT-pthreads package.
See section 4.2 Operating systems supported by MySQL.
However, MIT-pthreads doesn't support Unix sockets, so on such a system you
must always specify the hostname explicitly when connecting to the server.
Try using this command to check the connection to the server:
shell> mysqladmin -h `hostname` version
mysqld
uses (default
`/tmp/mysqld.sock'). You might have a cron
job that removes the
MySQL socket (e.g., a job that removes old files from the `/tmp'
directory). You can always run mysqladmin version
and
check that the socket mysqladmin
is trying to use really exists.
The fix in this case is to change the cron
job to not remove
`mysqld.sock' or to place the socket somewhere else. You can specify
a different socket location at MySQL configuration time with this
command:
shell> ./configure --with-unix-socket-path=/path/to/socketYou can also start
safe_mysqld
with the
--socket=/path/to/socket
option and set the environment variable
MYSQL_UNIX_PORT
to the socket pathname before starting your
MySQL clients. @item You have started the mysqld
server with
the --socket=/path/to/socket
option. If you change the socket
pathname for the server, you must also notify the MySQL clients
about the new path. You can do this by setting the environment variable
MYSQL_UNIX_PORT
to the socket pathname or by providing the socket path
as an argument to the clients. You can test the socket with this command:
shell> mysqladmin --socket=/path/to/socket version
mysqld
threads (for example with the
mysql_zap
script before you can start a new MySQL
server. See section 19.1 What to do if MySQL keeps crashing.
If you get the error message Can't connect to MySQL server on
some_hostname
, you can try the following things to find out what is the
problem:
telnet your-host-name
tcp-ip-port-number
and press RETURN
a couple of times. If there
is a MySQL server running on this port you should get a
responses that includes the version number of the running MySQL
server. If you get an error like telnet: Unable to connect to
remote host: Connection refused
, then there is no server running on the
used port.
mysqld
daemon on the local machine and check
the TCP/IP port that mysqld it's configured to use (variable port
) with
mysqladmin variables
.
mysqld
server is not started with the
--skip-networking
option.
Host '...' is blocked
errorIf you get a error like this:
Host 'hostname' is blocked because of many connection errors. Unblock with 'mysqladmin flush-hosts'
This means that mysqld
has gotten a lot (max_connect_errors
)
of connect requests from the host 'hostname'
that have been interrupted
in the middle. After max_connect_errors
failed requests, mysqld
assumes that something is wrong (like a attack from a cracker), and
blocks the site from further connections until someone executes the command
mysqladmin flush-hosts
.
By default, mysqld
blocks a host after 10 connection errors.
You can easily adjust this by starting the server like this:
shell> safe_mysqld -O max_connect_errors=10000 &
Note that if you get this error message for a given host, you should first
check that there isn't anything wrong with TCP/IP connections from that
host. If your TCP/IP connections aren't working, it won't do you any good to
increase the value of the max_connect_errors
variable!
Too many connections
error
If you get the error Too many connections
when you try to connect
to MySQL, this means that there is already max_connections
clients connected to the mysqld
server.
If you need more connections than the default (100), then you should restart
mysqld
with a bigger value for the max_connections
variable.
Note that mysqld
actually allows (max_connections
+1) clients to connect.
The last connection is reserved for a user with the process privilege.
By not giving this privilege to normal users (they shouldn't need this), an
administrator with this privilege can login and use SHOW PROCESSLIST
to find out what could be wrong. See section 7.21 SHOW
syntax (Get information about tables, columns,...).
Out of memory
errorIf you issue a query and get something like the following error:
mysql: Out of memory at line 42, 'malloc.c' mysql: needed 8136 byte (8k), memory in use: 12481367 bytes (12189k) ERROR 2008: MySQL client ran out of memory
Note that the error refers to the MySQL client mysql
. The
reason for this error is simply that the client does not have enough memory to
store the whole result.
To remedy the problem, first check that your query is correct. Is it
reasonable that it should return so many rows? If so,
you can use mysql --quick
, which uses mysql_use_result()
to retrieve the result set. This places less of a load on the client (but
more on the server).
Packet too large
error
When a MySQL client or the mysqld
server gets a packet bigger
than max_allowed_packet
bytes, it issues a Packet too large
error and closes the connection.
If you are using the mysql
client, you may specify a bigger buffer by
starting the client with mysql --set-variable=max_allowed_packet=8M
.
If you are using other clients that do not allow you to specify the maximum
packet size (such as DBI
), you need to set the packet size when you
start the server. You cau use a command-line option to mysqld
to set
max_allowed_packet
to a larger size. For example, if you are
expecting to store the full length of a BLOB
into a table, you'll need
to start the server with the --set-variable=max_allowed_packet=24M
option.
The table is full
error
This error occurs when an in-memory temporary table becomes larger than
tmp_table_size
bytes. To avoid this problem, you can use the
-O tmp_table_size=#
option to mysqld
to increase the
temporary table size, or use the SQL option SQL_BIG_TABLES
before
you issue the problematic query. See section 7.25 SET
syntax.
You can also start mysqld
with the --big-tables
option.
This is exactly the same as using SQL_BIG_TABLES
for all queries.
Commands out of sync
error in client
If you get Commands out of sync; You can't run this command now
in your client code, you are calling client functions in the wrong order!
This can happen, for example, if you are using mysql_use_result()
and
try to execute a new query before you have called mysql_free_result()
.
It can also happen if you try to execute two queries that return data without
a mysql_use_result()
or mysql_store_result()
in between.
Ignoring user
errorIf you get the following error:
Found wrong password for user: 'some_user@some_host'; Ignoring user
This means that when mysqld
was started or when it reloaded the
permissions tables, it found an entry in the user
table with
an invalid password. As a result, the entry is simply ignored by the
permission system.
Possible causes of and fixes for this problem:
mysqld
with an old
user
table.
You can check this by executing mysqlshow mysql user
to see if
the password field is shorter than 16 characters. If so, you can correct this
condition by running the scripts/add_long_password
script.
mysqld
with the --old-protocol
option.
Update the user in the user
table with a new password or
restart mysqld
with --old-protocol
.
user
table without using the
PASSWORD()
function. Use mysql
to update the user in the
user
table with a new password. Make sure to use the PASSWORD()
function:
mysql> update user set password=PASSWORD('your password') where user='XXX';
Table 'xxx' doesn't exist
error
If you get the error Table 'xxx' doesn't exist
or Can't
find file: 'xxx' (errno: 2)
, this means that no table exists
in the current database with the name xxx
.
Note that as MySQL uses directories and files to store databases and tables, the database and table names are case sensitive! (On Win32 the databases and tables names are not case sensitive, but all references to a given table within a query must use the same case!)
You can check which tables you have in the current database with
SHOW TABLES
. See section 7.21 SHOW
syntax (Get information about tables, columns,...).
When a disk full condition occurs, MySQL does the following:
To alleviate the problem, you can take the following actions:
mysqladmin kill
to the thread.
The thread will be aborted the next time it checks the disk (in 1 minute).
The mysql
client typically is used interactively, like this:
shell> mysql database
However, it's also possible to put your SQL commands in a file and tell
mysql
to read its input from that file. To do so, create a text
file `text_file' that contains the commands you wish to execute.
Then invoke mysql
as shown below:
shell> mysql database < text_file
You can also start your text file with a USE db_name
statement. In
this case, it is unnecessary to specify the database name on the command
line:
shell> mysql < text_file
See section 13.1 Overview of the different MySQL programs.
MySQL uses the value of the TMPDIR
environment variable as
the pathname of the directory in which to store temporary files. If you don't
have TMPDIR
set, MySQL uses the system default, which is
normally `/tmp' or `/usr/tmp'. If the file system containing your
temporary file directory is too small, you should edit safe_mysqld
to
set TMPDIR
to point to a directory in a file system where you have
enough space! You can also set the temporary directory using the
--tmpdir
option to mysqld
.
MySQL creates all temporary files as ``hidden files''. This ensures
that the temporary files will be removed if mysqld
is terminated. The
disadvantage of using hidden files is that you will not see a big temporary
file that fills up the file system in which the temporary file directory is
located.
When sorting (ORDER BY
or GROUP BY
), MySQL normally
uses one or two temporary files. The maximum disk-space needed is:
(length of what is sorted + sizeof(database pointer)) * number of matched rows * 2
sizeof(database pointer)
is usually 4, but may grow in the future for
really big tables.
For some SELECT
queries, MySQL also creates temporary SQL
tables. These are not hidden and have names of the form `SQL_*'.
ALTER TABLE
and OPTIMIZE TABLE
create a temporary table in the
same directory as the original table.
If you have problems with the fact that anyone can delete the
MySQL communication socket `/tmp/mysql.sock', you can,
on most versions of Unix, protect your `/tmp' file system by setting
the sticky
bit on it. Log in as root
and do the following:
shell> chmod +t /tmp
This will protect your `/tmp' file system so that files can be deleted
only by their owners or the superuser (root
).
You can check if the sticky
bit is set by executing ls -ld /tmp
.
If the last permission bit is t
, the bit is set.
Access denied
error
See section 6.8 How the privilege system works. And especially see section 6.15 Causes of Access denied
errors.
The MySQL server mysqld
can be started and run by any user.
In order to change mysqld
to run as Unix user user_name
, you must
do the following:
mysqladmin shutdown
).
user_name
has
privileges to read and write files in them (you may need to do this as
the Unix root
user):
shell> chown -R user_name /path/to/mysql/datadirIf directories or files within the MySQL data directory are symlinks, you'll also need to follow those links and change the directories and files they point to.
chown -R
may not follow symlinks for
you.
user_name
, or, if you are using
MySQL 3.22 or later, start mysqld
as the Unix root
user and use the --user=user_name
option. mysqld
will switch
to run as Unix user user_name
before accepting any connections.
mysql.server
script to start mysqld
when
the system is rebooted, you should edit mysql.server
to use su
to run mysqld
as user user_name
, or to invoke mysqld
with the --user
option. (No changes to safe_mysqld
are
necessary.)
At this point, your mysqld
process should be running fine and dandy as
the Unix user user_name
. One thing hasn't changed, though: the
contents of the permissions tables. By default (right after running the
permissions table install script mysql_install_db
), the MySQL
user root
is the only user with permission to access the mysql
database or to create or drop databases. Unless you have changed those
permissions, they still hold. This shouldn't stop you from accessing
MySQL as the MySQL root
user when you're logged in
as a Unix user other than root
; just specify the -u root
option
to the client program.
Note that accessing MySQL as root
, by supplying -u
root
on the command line, has nothing to do with MySQL running
as the Unix root
user, or, indeed, as other Unix user. The access
permissions and user names of MySQL are completely separate from
Unix user names. The only connection with Unix user names is that if you
don't provide a -u
option when you invoke a client program, the client
will try to connect using your Unix login name as your MySQL user
name.
If your Unix box itself isn't secured, you should probably at least put a
password on the MySQL root
users in the access tables.
Otherwise, any user with an account on that machine can run mysql -u
root db_name
and do whatever he likes.
If you have forgotten the root
user password for MySQL, you
can restore it with the following procedure.
kill
(not kill
-9
) to the mysqld
server. The pid is stored in a .pid
file which is normally in the MySQL database directory:
kill `cat /mysql-data-directory/hostname.pid`You must be either the UNIX
root
user or the same user the server
runs as to do this.
mysqld
with the --skip-grant-tables
option.
mysql -h hostname mysql
and change
the password with a GRANT
command. See section 7.26 GRANT
and REVOKE
syntax.
You can also do this with
mysqladmin -h hostname -u user password 'new password'
mysqladmin -h hostname
flush-privileges
or with the SQL command FLUSH PRIVILEGES
.
If you have problems with file permissions, for example, if mysql
issues the following error message when you create a table:
ERROR: Can't find file: 'path/with/filename.frm' (Errcode: 13)
Then the environment variable UMASK
might be set incorrectly when
mysqld
starts up. The default umask value is 0660
. You can
change this behavior by starting safe_mysqld
as follows:
shell> UMASK=384 # = 600 in octal shell> export UMASK shell> /path/to/safe_mysqld &
If you get ERROR '...' not found (errno: 23)
, Can't open
file: ... (errno: 24)
or any other error with errno 23
or
errno 24
from MySQL, it means that you haven't allocated
enough file descriptors for MySQL. You can use the
perror
utility to get a description of what the error number
means:
shell> perror 23 File table overflow shell> perror 24 Too many open files
The problem here is that mysqld
is trying to keep open too many
files simultaneously. You can either tell mysqld
not to open so
many files at once, or increase the number of file descriptors
available to mysqld
.
To tell mysqld
to keep open fewer files at a time, you can make the
table cache smaller by using the -O table_cache=32
option
to safe_mysqld
(the default value is 64). Reducing the value of
max_connections
will also reduce the number of open files (the default
value is 90).
To change the number of file descriptors available to mysqld
, modify
the safe_mysqld
script. There is a commented-out line
ulimit -n 256
in the script. You can remove the '#'
character
to uncomment this line, and change the number 256 to change the number of
file descriptors available to mysqld
.
ulimit
can increase the number of file descriptors, but only up to the
limit imposed by the operating system. If you need to increase the OS limit
on the number of file descriptors available to each process, consult the
documentation for your operating system.
Note that if you run the tcsh
shell, ulimit
will not work!
tcsh
will also report incorrect values when you ask for the current
limits! In this case you should start safe_mysqld
with sh
!
DATE
columns
The format of a DATE
value is 'YYYY-MM-DD'
. According to ANSI
SQL, no other format is allowed. You should use this format in UPDATE
expressions and in the WHERE clause of SELECT
statements. For
example:
mysql> SELECT * FROM tbl_name WHERE date >= '1997-05-05';
As a convenience, MySQL automatically converts a date to a number if
the date is used in a numeric context (and vice versa). It is also smart
enough to allow a ``relaxed'' string form when updating and in a WHERE
clause that compares a date to a TIMESTAMP
, DATE
or a
DATETIME
column. (Relaxed form means that any punctuation character
may be used as the separator between parts. For example, '1998-08-15'
and '1998#08#15'
are equivalent.) MySQL can also convert a
string containing no separators (such as '19980815'
), provided it
makes sense as a date.
The special date '0000-00-00'
can be stored and retrieved as
'0000-00-00'.
When using a '0000-00-00'
date through
MyODBC, it will automatically be converted to NULL
in
MyODBC 2.50.12 and above, because ODBC can't handle this kind of
date.
Since MySQL performs the conversions described above, the following statements work:
mysql> INSERT INTO tbl_name (idate) VALUES (19970505); mysql> INSERT INTO tbl_name (idate) VALUES ('19970505'); mysql> INSERT INTO tbl_name (idate) VALUES ('97-05-05'); mysql> INSERT INTO tbl_name (idate) VALUES ('1997.05.05'); mysql> INSERT INTO tbl_name (idate) VALUES ('1997 05 05'); mysql> INSERT INTO tbl_name (idate) VALUES ('0000-00-00'); mysql> SELECT idate FROM tbl_name WHERE idate >= '1997-05-05'; mysql> SELECT idate FROM tbl_name WHERE idate >= 19970505; mysql> SELECT mod(idate,100) FROM tbl_name WHERE idate >= 19970505; mysql> SELECT idate FROM tbl_name WHERE idate >= '19970505';
However, the following will not work:
mysql> SELECT idate FROM tbl_name WHERE STRCMP(idate,'19970505')=0;
STRCMP()
is a string function, so it converts idate
to
a string and performs a string comparison. It does not convert
'19970505'
to a date and perform a date comparison.
Note that MySQL does no checking whether or not the date is
correct. If you store an incorrect date, such as '1998-2-31'
, the
wrong date will be stored. If the date cannot be converted to any reasonable
value, a 0
is stored in the DATE
field. This is mainly a speed
issue and we think it is up to the application to check the dates, and not
the server.
If you have a problem with SELECT NOW()
returning values in GMT and
not your local time, you have to set the TZ
environment variable to
your current timezone. This should be done for the environment in which
the server runs, for example in safe_mysqld
or mysql.server
.
By default, MySQL searches are case-insensitive (although there are
some character sets that are never case insensitive, such as czech
).
That means that if you search with col_name LIKE 'a%'
, you will get all
column values that start with A
or a
. If you want to make this
search case-sensitive, use something like INDEX(col_name, "A")=0
to
check a prefix. Or use STRCMP(col_name, "A") = 0
if the column value
must be exactly "A"
.
Simple comparison operations (>=, >, = , < , <=
, sorting and
grouping) are based on each character's ``sort value''. Characters with
the same sort value (like E, e and 'e) are treated as the same character!
LIKE
comparisons are done on the uppercase value of each character
(E == e but E <> 'e)
If you want a column always to be treated in case-sensitive fashion,
declare it as BINARY
. See section 7.7 CREATE TABLE
syntax.
If you are using Chinese data in the so-called big5 encoding, you want to
make all character columns BINARY
. This works because the sorting
order of big5 encoding characters is based on the order of ASCII codes.
NULL
values
The concept of the NULL
value is a common source of confusion for
newcomers to SQL, who often think that NULL
is the same thing as an
empty string ''
. This is not the case! For example, the following
statements are completely different:
mysql> INSERT INTO my_table (phone) VALUES (NULL); mysql> INSERT INTO my_table (phone) VALUES ("");
Both statements insert a value into the phone
column, but the first
inserts a NULL
value and the second inserts an empty string. The
meaning of the first can be regarded as ``phone number is not known'' and the
meaning of the second can be regarded as ``she has no phone''.
In SQL, the NULL
value is always false in comparison to any
other value, even NULL
. An expression that contains NULL
always produces a NULL
value unless otherwise indicated in
the documentation for the operators and functions involved in the
expression. All columns in the following example return NULL
:
mysql> SELECT NULL,1+NULL,CONCAT('Invisible',NULL);
If you want to search for column values that are NULL
, you
cannot use the =NULL
test. The following statement returns no
rows, because expr = NULL
is FALSE, for any expression:
mysql> SELECT * FROM my_table WHERE phone = NULL;
To look for NULL
values, you must use the IS NULL
test.
The following shows how to find the NULL
phone number and the
empty phone number:
mysql> SELECT * FROM my_table WHERE phone IS NULL; mysql> SELECT * FROM my_table WHERE phone = "";
In MySQL, as in many other SQL servers, you can't index
columns that can have NULL
values. You must declare such columns
NOT NULL
. Conversely, you cannot insert NULL
into an indexed
column.
When reading data with LOAD DATA INFILE
, empty columns are updated
with ''
. If you want a NULL
value in a column, you should use
\N
in the text file. The literal word 'NULL'
may also be used
under some circumstances.
See section 7.16 LOAD DATA INFILE
syntax.
When using ORDER BY
, NULL
values are presented first. If you
sort in descending order using DESC
, NULL
values are presented
last. When using GROUP BY
, all NULL
values are regarded as
equal.
To help with NULL
handling, you can use the IS NULL
and
IS NOT NULL
operators and the IFNULL()
function.
For some column types, NULL
values are handled specially. If you
insert NULL
into the first TIMESTAMP
column of a table, the
current date and time is inserted. If you insert NULL
into an
AUTO_INCREMENT
column, the next number in the sequence is inserted.
alias
You can use alias to refer to a column in the GROUP BY
,
ORDER BY
or in the HAVING
part. Aliases can also be used
to give columns more better names:
SELECT SQRT(a*b) as rt FROM table_name GROUP BY rt HAVING rt > 0; SELECT id,COUNT(*) AS cnt FROM table_name GROUP BY id HAVING cnt > 0; SELECT id AS "Customer identity" FROM table_name;
Note that you ANSI SQL doesn't allow you to refer to an alias in a
WHERE
clause. This is because that when the WHERE
code is
executed the column value may not yet be determinated. For example the
following query is illegal:
SELECT id,COUNT(*) AS cnt FROM table_name WHERE cnt > 0 GROUP BY id;
The WHERE
statement is executed to determinate which rows should
be included in the GROUP BY
part while HAVING
is used to
decide which rows from the result set should be used.
As MySQL doesn't support sub-selects or use of more than one table
in the DELETE
statement, you should use the following approach to
delete rows from 2 related tables:
SELECT
the rows based on some WHERE
condition in the main table.
DELETE
the rows in the main table based on the same condition.
DELETE FROM related_table WHERE related_column IN (selected_rows)
If the total number of characters in the query with
related_column
is more than 1,048,576 (the default value of
max_allowed_packet
, you should split it into smaller parts and
execute multiple DELETE
statements. You will probably get the
fastest DELETE
by only deleting 100-1000 related_column
id's per time if the related_column
is an index. If the
related_column
isn't an index, the speed is independent of the
number of arguments in the IN
clause.
If you have a complicated query with many tables that doesn't return any rows, you should use the following procedure to find out what is wrong with your query:
EXPLAIN
and check if you can find something that is
obviously wrong. See section 7.22 EXPLAIN
syntax (Get information about a SELECT
).
WHERE
clause.
LIMIT 10
with the query.
SELECT
for the column that should have matched a row,
against the table that was last removed from the query.
FLOAT
or DOUBLE
columns with numbers that
have decimals, you can't use =
! This problem is common in most
computer languages because floating point values are not exact values.
mysql> SELECT * FROM table_name WHERE float_column=3.5; -> mysql> SELECT * FROM table_name WHERE float_column between 3.45 and 3.55;In most cases, changing the
FLOAT
to a DOUBLE
will fix this!
mysql test < query.sql
that shows your problems.
You can create a test file with mysqldump --quick database tables > query.sql
. Take the file up in a editor, remove some insert lines (if there are
too many of these) and add your select statement last in the file.
Test that you still have your problem by doing:
shell> mysqladmin create test2 shell> mysql test2 < query.sqlPost the test file using
mysqlbug
to mysql@lists.mysql.com.
ALTER TABLE
.
If ALTER TABLE
dies with an error like this:
Error on rename of './database/name.frm' to './database/B-a.frm' (Errcode: 17)
The problem may be that MySQL has crashed in a previous ALTER
TABLE
and there is an old table named `A-something' or
`B-something' lying around. In this case, go to the MySQL data
directory and delete all files that have names starting with A-
or
B-
. (You may want to move them elsewhere instead of deleting them).
ALTER TABLE
works the following way:
If something goes wrong with the renaming operation, MySQL tries to undo the changes. If something goes seriously wrong (this shouldn't happen, of course), MySQL may leave the old table as `B-xxx' but a simple rename should get your data back.
The whole point of SQL is to abstract the application from the data storage format. You should always specify the order in wish you wish to retrieve your data. For example:
SELECT col_name1, col_name2, col_name3 FROM tbl_name;
will return columns in the order col_name1
, col_name2
, col_name3
, whereas:
SELECT col_name1, col_name3, col_name2 FROM tbl_name;
will return columns in the order col_name1
, col_name3
, col_name2
.
You should NEVER, in an application, use SELECT *
and
retrieve the columns based on their position, because the order in which columns are
returned CANNOT be guaranteed over time; A simple change to
your database may cause your application to fail rather dramatically.
If you want to change the order of columns anyway, you can do it as follows:
INSERT INTO new_table SELECT fields-in-new_table-order FROM old_table
.
old_table
ALTER TABLE new_table RENAME old_table
Go to the first, previous, next, last section, table of contents.