mysql is a simple SQL shell (with GNU
readline
capabilities). It supports
interactive and non-interactive use. When used interactively,
query results are presented in an ASCII-table format. When
used non-interactively (for example, as a filter), the result
is presented in tab-separated format. The output format can be
changed using command options.
If you have problems due to insufficient memory for large
result sets, use the --quick
option. This
forces mysql to retrieve results from the
server a row at a time rather than retrieving the entire
result set and buffering it in memory before displaying it.
This is done by returning the result set using the
mysql_use_result()
C API function in the
client/server library rather than
mysql_store_result()
.
Using mysql is very easy. Invoke it from the prompt of your command interpreter as follows:
shell> mysql db_name
Or:
shell> mysql --user=user_name
--password=your_password
db_name
Then type an SQL statement, end it with
‘;
’, \g
, or
\G
and press Enter.
You can execute SQL statements in a script file (batch file) like this:
shell> mysql db_name
< script.sql
> output.tab
mysql supports the following options:
Display a help message and exit.
Enable automatic rehashing. This option is on by default,
which enables table and column name completion. Use
--skip-auto-rehash
to disable rehashing.
That causes mysql to start faster, but
you must issue the rehash
command if
you want to use table and column name completion.
Print results using tab as the column separator, with each row on a new line. With this option, mysql does not use the history file.
The directory where character sets are installed. See Section 5.11.1, “The Character Set Used for Data and Sorting”.
Write column names in results.
Compress all information sent between the client and the server if both support compression.
--database=
,
db_name
-D
db_name
The database to use. This is useful primarily in an option file.
--debug[=
,
debug_options
]-#
[
debug_options
]
Write a debugging log. The
debug_options
string often is
'd:t:o,
.
The default is
file_name
''d:t:o,/tmp/mysql.trace'
.
Print some debugging information when the program exits.
--default-character-set=
charset_name
Use charset_name
as the default
character set. See Section 5.11.1, “The Character Set Used for Data and Sorting”.
Set the statement delimiter. The default is the semicolon
character (‘;
’).
--execute=
,
statement
-e
statement
Execute the statement and quit. The default output format
is like that produced with --batch
. See
Section 4.3.1, “Using Options on the Command Line”, for some examples.
Continue even if an SQL error occurs.
--host=
,
host_name
-h
host_name
Connect to the MySQL server on the given host.
Produce HTML output.
Ignore spaces after function names. The effect of this is
described in the discussion for the
IGNORE_SPACE
SQL mode (see
Section 5.2.5, “The Server SQL Mode”).
Write line numbers for errors. Disable this with
--skip-line-numbers
.
Enable or disable LOCAL
capability for
LOAD DATA INFILE
. With no value, the
option enables LOCAL
. The option may be
given as --local-infile=0
or
--local-infile=1
to explicitly disable or
enable LOCAL
. Enabling
LOCAL
has no effect if the server does
not also support it.
Enable named mysql commands.
Long-format commands are allowed, not just short-format
commands. For example, quit
and
\q
both are recognized. Use
--skip-named-commands
to disable named
commands. See Section 8.6.2, “mysql Commands”.
Deprecated form of -skip-auto-rehash
. See
the description for --auto-rehash
.
Do not beep when errors occur.
Disable named commands. Use the \*
form
only, or use named commands only at the beginning of a
line ending with a semicolon
(‘;
’).
mysql starts with this option
enabled by default. However, even
with this option, long-format commands still work from the
first line. See Section 8.6.2, “mysql Commands”.
Deprecated form of --skip-pager
. See the
--pager
option.
Do not copy output to a file. Section 8.6.2, “mysql Commands”, discusses tee files further.
Ignore statements except those for the default database named on the command line. This is useful for skipping updates to other databases in the binary log.
Use the given command for paging query output. If the
command is omitted, the default pager is the value of your
PAGER
environment variable. Valid
pagers are less,
more, cat [>
filename], and so forth. This option works only
on Unix. It does not work in batch mode. To disable
paging, use --skip-pager
.
Section 8.6.2, “mysql Commands”, discusses output paging
further.
--password[=
,
password
]-p[
password
]
The password to use when connecting to the server. If you
use the short option form (-p
), you
cannot have a space between the
option and the password. If you omit the
password
value following the
--password
or -p
option
on the command line, you are prompted for one.
Specifying a password on the command line should be considered insecure. See Section 5.9.6, “Keeping Your Password Secure”.
The TCP/IP port number to use for the connection.
Set the prompt to the specified format. The default is
mysql>
. The special sequences that
the prompt can contain are described in
Section 8.6.2, “mysql Commands”.
--protocol={TCP|SOCKET|PIPE|MEMORY}
The connection protocol to use.
Do not cache each query result, print each row as it is received. This may slow down the server if the output is suspended. With this option, mysql does not use the history file.
Write column values without escape conversion. Often used
with the --batch
option.
If the connection to the server is lost, automatically try
to reconnect. A single reconnect attempt is made each time
the connection is lost. To suppress reconnection behavior,
use --skip-reconnect
.
--safe-updates
,
--i-am-a-dummy
, -U
Allow only those UPDATE
and
DELETE
statements that specify which
rows to modify by using key values. If you have set this
option in an option file, you can override it by using
--safe-updates
on the command line. See
Section 8.6.5, “mysql Tips”, for more information about
this option.
Do not send passwords to the server in old (pre-4.1.1) format. This prevents connections except for servers that use the newer password format.
Cause warnings to be shown after each statement if there are any. This option applies to interactive and batch mode. This option was added in MySQL 5.0.6.
Ignore SIGINT
signals (typically the
result of typing Control-C).
Silent mode. Produce less output. This option can be given multiple times to produce less and less output.
Do not write column names in results.
Do not write line numbers for errors. Useful when you want to compare result files that include error messages.
For connections to localhost
, the Unix
socket file to use, or, on Windows, the name of the named
pipe to use.
Options that begin with --ssl
specify
whether to connect to the server via SSL and indicate
where to find SSL keys and certificates. See
Section 5.9.7.3, “SSL Command Options”.
Display output in table format. This is the default for interactive use, but can be used to produce table output in batch mode.
Append a copy of output to the given file. This option does not work in batch mode. in Section 8.6.2, “mysql Commands”, discusses tee files further.
Flush the buffer after each query.
--user=
,
user_name
-u
user_name
The MySQL username to use when connecting to the server.
Verbose mode. Produce more output about what the program
does. This option can be given multiple times to produce
more and more output. (For example, -v -v
-v
produces table output format even in batch
mode.)
Display version information and exit.
Print query output rows vertically (one line per column
value). Without this option, you can specify vertical
output for individual statements by terminating them with
\G
.
If the connection cannot be established, wait and retry instead of aborting.
Produce XML output.
You can also set the following variables by using
--
syntax:
var_name
=value
The number of seconds before connection timeout. (Default
value is 0
.)
The maximum packet length to send to or receive from the server. (Default value is 16MB.)
The automatic limit for rows in a join when using
--safe-updates
. (Default value is
1,000,000.)
The buffer size for TCP/IP and socket communication. (Default value is 16KB.)
The automatic limit for SELECT
statements when using --safe-updates
.
(Default value is 1,000.)
It is also possible to set variables by using
--set-variable=
or var_name
=value
-O
syntax. This syntax is deprecated.
var_name
=value
On Unix, the mysql client writes a record
of executed statements to a history file. By default, the
history file is named .mysql_history
and
is created in your home directory. To specify a different
file, set the value of the MYSQL_HISTFILE
environment variable.
If you do not want to maintain a history file, first remove
.mysql_history
if it exists, and then use
either of the following techniques:
Set the MYSQL_HISTFILE
variable to
/dev/null
. To cause this setting to
take effect each time you log in, put the setting in one
of your shell's startup files.
Create .mysql_history
as a symbolic
link to /dev/null
:
shell> ln -s /dev/null $HOME/.mysql_history
You need do this only once.
mysql sends each SQL statement that you
issue to the server to be executed. There is also a set of
commands that mysql itself interprets. For
a list of these commands, type help
or
\h
at the mysql>
prompt:
mysql> help
List of all MySQL commands:
Note that all text commands must be first on line and end with ';'
? (\?) Synonym for `help'.
clear (\c) Clear command.
connect (\r) Reconnect to the server. Optional arguments are db and host.
delimiter (\d) Set statement delimiter. NOTE: Takes the rest of the line as
new delimiter.
edit (\e) Edit command with $EDITOR.
ego (\G) Send command to mysql server, display result vertically.
exit (\q) Exit mysql. Same as quit.
go (\g) Send command to mysql server.
help (\h) Display this help.
nopager (\n) Disable pager, print to stdout.
notee (\t) Don't write into outfile.
pager (\P) Set PAGER [to_pager]. Print the query results via PAGER.
print (\p) Print current command.
prompt (\R) Change your mysql prompt.
quit (\q) Quit mysql.
rehash (\#) Rebuild completion hash.
source (\.) Execute an SQL script file. Takes a file name as an argument.
status (\s) Get status information from the server.
system (\!) Execute a system shell command.
tee (\T) Set outfile [to_outfile]. Append everything into given
outfile.
use (\u) Use another database. Takes database name as argument.
charset (\C) Switch to another charset. Might be needed for processing binlog with multi-byte charsets.
warnings (\W) Show warnings after every statement.
nowarning (\w) Don't show warnings after every statement.
For server side help, type 'help contents'
Each command has both a long and short form. The long form is not case sensitive; the short form is. The long form can be followed by an optional semicolon terminator, but the short form should not.
If you provide an argument to the help
command, mysql uses it as a search string
to access server-side help from the contents of the MySQL
Reference Manual. For more information, see
Section 8.6.3, “mysql Server-Side Help”.
In the delimiter
command, you should avoid
the use of the backslash (‘\
’)
character because that is the escape character for MySQL.
The edit, nopager, pager, and system commands work only in Unix.
The status
command provides some
information about the connection and the server you are using.
If you are running in --safe-updates
mode,
status
also prints the values for the
mysql variables that affect your queries.
To log queries and their output, use the
tee command. All the data displayed on the
screen is appended into a given file. This can be very useful
for debugging purposes also. You can enable this feature on
the command line with the --tee
option, or
interactively with the tee command. The
tee file can be disabled interactively with
the notee command. Executing
tee again re-enables logging. Without a
parameter, the previous file is used. Note that
tee flushes query results to the file after
each statement, just before mysql prints
its next prompt.
By using the --pager
option, it is possible
to browse or search query results in interactive mode with
Unix programs such as less,
more, or any other similar program. If you
specify no value for the option, mysql
checks the value of the PAGER
environment
variable and sets the pager to that. Output paging can be
enabled interactively with the pager
command and disabled with nopager. The
command takes an optional argument; if given, the paging
program is set to that. With no argument, the pager is set to
the pager that was set on the command line, or
stdout
if no pager was specified.
Output paging works only in Unix because it uses the
popen()
function, which does not exist on
Windows. For Windows, the tee option can be
used instead to save query output, although this is not as
convenient as pager for browsing output in
some situations.
Here are a few tips about the pager command:
You can use it to write to a file and the results go only to the file:
mysql> pager cat > /tmp/log.txt
You can also pass any options for the program that you want to use as your pager:
mysql> pager less -n -i -S
In the preceding example, note the -S
option. You may find it very useful for browsing wide
query results. Sometimes a very wide result set is
difficult to read on the screen. The -S
option to less can make the result set
much more readable because you can scroll it horizontally
using the left-arrow and right-arrow keys. You can also
use -S
interactively within
less to switch the horizontal-browse
mode on and off. For more information, read the
less manual page:
shell> man less
You can specify very complex pager commands for handling query output:
mysql>pager cat | tee /dr1/tmp/res.txt \
| tee /dr2/tmp/res2.txt | less -n -i -S
In this example, the command would send query results to
two files in two different directories on two different
filesystems mounted on /dr1
and
/dr2
, yet still display the results
onscreen via less.
You can also combine the tee and pager functions. Have a tee file enabled and pager set to less, and you are able to browse the results using the less program and still have everything appended into a file the same time. The difference between the Unix tee used with the pager command and the mysql built-in tee command is that the built-in tee works even if you do not have the Unix tee available. The built-in tee also logs everything that is printed on the screen, whereas the Unix tee used with pager does not log quite that much. Additionally, tee file logging can be turned on and off interactively from within mysql. This is useful when you want to log some queries to a file, but not others.
The default mysql>
prompt can be
reconfigured. The string for defining the prompt can contain
the following special sequences:
Option | Description |
\v | The server version |
\d | The default database |
\h | The server host |
\p | The current TCP/IP port or socket file |
\u | Your username |
\U | Your full
account name |
\\ | A literal ‘\ ’ backslash character |
\n | A newline character |
\t | A tab character |
\ | A space (a space follows the backslash) |
\_ | A space |
\R | The current time, in 24-hour military time (0-23) |
\r | The current time, standard 12-hour time (1-12) |
\m | Minutes of the current time |
\y | The current year, two digits |
\Y | The current year, four digits |
\D | The full current date |
\s | Seconds of the current time |
\w | The current day of the week in three-letter format (Mon, Tue, …) |
\P | am/pm |
\o | The current month in numeric format |
\O | The current month in three-letter format (Jan, Feb, …) |
\c | A counter that increments for each statement you issue |
\S | Semicolon |
\' | Single quote |
\" | Double quote |
‘\
’ followed by any other
letter just becomes that letter.
If you specify the prompt
command with no
argument, mysql resets the prompt to the
default of mysql>
.
You can set the prompt in several ways:
Use an environment variable. You can
set the MYSQL_PS1
environment variable
to a prompt string. For example:
shell> export MYSQL_PS1="(\u@\h) [\d]> "
Use a command-line option. You can
set the --prompt
option on the command
line to mysql. For example:
shell> mysql --prompt="(\u@\h) [\d]> "
(user@host) [database]>
Use an option file. You can set the
prompt
option in the
[mysql]
group of any MySQL option file,
such as /etc/my.cnf
or the
.my.cnf
file in your home directory.
For example:
[mysql] prompt=(\\u@\\h) [\\d]>\\_
In this example, note that the backslashes are doubled. If
you set the prompt using the prompt
option in an option file, it is advisable to double the
backslashes when using the special prompt options. There
is some overlap in the set of allowable prompt options and
the set of special escape sequences that are recognized in
option files. (These sequences are listed in
Section 4.3.2, “Using Option Files”.) The overlap may cause you
problems if you use single backslashes. For example,
\s
is interpreted as a space rather
than as the current seconds value. The following example
shows how to define a prompt within an option file to
include the current time in
HH:MM:SS>
format:
[mysql] prompt="\\r:\\m:\\s> "
Set the prompt interactively. You can
change your prompt interactively by using the
prompt
(or \R
)
command. For example:
mysql>prompt (\u@\h) [\d]>\_
PROMPT set to '(\u@\h) [\d]>\_' (user
@host
) [database
]> (user
@host
) [database
]> prompt Returning to default PROMPT of mysql> mysql>
mysql> help search_string
If you provide an argument to the help
command, mysql uses it as a search string
to access server-side help from the contents of the MySQL
Reference Manual. The proper operation of this command
requires that the help tables in the mysql
database be initialized with help topic information (see
Section 5.2.7, “MySQL Server-Side Help Support”).
If there is no match for the search string, the search fails:
mysql> help me
Nothing found
Please try to run 'help contents' for a list of all accessible topics
Use help contents to see a list of the help categories:
mysql> help contents
You asked for help about help category: "Contents"
For more information, type 'help <item>', where <item> is one of the
following categories:
Account Management
Administration
Data Definition
Data Manipulation
Data Types
Functions
Functions and Modifiers for Use with GROUP BY
Geographic Features
Language Structure
Storage Engines
Stored Routines
Table Maintenance
Transactions
Triggers
If the search string matches multiple items, mysql shows a list of matching topics:
mysql> help logs
Many help items for your request exist.
To make a more specific request, please type 'help <item>',
where <item> is one of the following topics:
SHOW
SHOW BINARY LOGS
SHOW ENGINE
SHOW LOGS
Use a topic as the search string to see the help entry for that topic:
mysql> help show binary logs
Name: 'SHOW BINARY LOGS'
Description:
Syntax:
SHOW BINARY LOGS
SHOW MASTER LOGS
Lists the binary log files on the server. This statement is used as
part of the procedure described in [purge-master-logs], that shows how
to determine which logs can be purged.
mysql> SHOW BINARY LOGS;
+---------------+-----------+
| Log_name | File_size |
+---------------+-----------+
| binlog.000015 | 724935 |
| binlog.000016 | 733481 |
+---------------+-----------+
The mysql client typically is used interactively, like this:
shell> mysql db_name
However, it is also possible to put your SQL statements in a
file and then tell mysql to read its input
from that file. To do so, create a text file
text_file
that contains the
statements you wish to execute. Then invoke
mysql as shown here:
shell> mysql db_name
< text_file
If you place a USE
statement as the
first statement in the file, it is unnecessary to specify the
database name on the command line:
db_name
shell> mysql < text_file
If you are already running mysql, you can
execute an SQL script file using the source
or \.
command:
mysql>source
mysql>file_name
\.
file_name
Sometimes you may want your script to display progress information to the user. For this you can insert statements like this:
SELECT '<info_to_display>' AS ' ';
The statement shown outputs
<info_to_display>
.
For more information about batch mode, see Section 3.5, “Using mysql in Batch Mode”.
This section describes some techniques that can help you use mysql more effectively.
Some query results are much more readable when displayed vertically, instead of in the usual horizontal table format. Queries can be displayed vertically by terminating the query with \G instead of a semicolon. For example, longer text values that include newlines often are much easier to read with vertical output:
mysql> SELECT * FROM mails WHERE LENGTH(txt) < 300 LIMIT 300,1\G
*************************** 1. row ***************************
msg_nro: 3068
date: 2000-03-01 23:29:50
time_zone: +0200
mail_from: Monty
reply: monty@no.spam.com
mail_to: "Thimble Smith" <tim@no.spam.com>
sbj: UTF-8
txt: >>>>> "Thimble" == Thimble Smith writes:
Thimble> Hi. I think this is a good idea. Is anyone familiar
Thimble> with UTF-8 or Unicode? Otherwise, I'll put this on my
Thimble> TODO list and see what happens.
Yes, please do that.
Regards,
Monty
file: inbox-jani-1
hash: 190402944
1 row in set (0.09 sec)
For beginners, a useful startup option is
--safe-updates
(or
--i-am-a-dummy
, which has the same effect).
It is helpful for cases when you might have issued a
DELETE FROM
statement but
forgotten the tbl_name
WHERE
clause. Normally,
such a statement deletes all rows from the table. With
--safe-updates
, you can delete rows only by
specifying the key values that identify them. This helps
prevent accidents.
When you use the --safe-updates
option,
mysql issues the following statement when
it connects to the MySQL server:
SET SQL_SAFE_UPDATES=1,SQL_SELECT_LIMIT=1000, SQL_MAX_JOIN_SIZE=1000000;
See Section 13.5.3, “SET
Syntax”.
The SET
statement has the following
effects:
You are not allowed to execute an
UPDATE
or DELETE
statement unless you specify a key constraint in the
WHERE
clause or provide a
LIMIT
clause (or both). For example:
UPDATEtbl_name
SETnot_key_column
=val
WHEREkey_column
=val
; UPDATEtbl_name
SETnot_key_column
=val
LIMIT 1;
The server limits all large SELECT
results to 1,000 rows unless the statement includes a
LIMIT
clause.
The server aborts multiple-table
SELECT
statements that probably need
to examine more than 1,000,000 row combinations.
To specify limits different from 1,000 and 1,000,000, you
can override the defaults by using the
--select_limit
and
--max_join_size
options:
shell> mysql --safe-updates --select_limit=500 --max_join_size=10000
If the mysql client loses its connection to the server while sending a query, it immediately and automatically tries to reconnect once to the server and send the query again. However, even if mysql succeeds in reconnecting, your first connection has ended and all your previous session objects and settings are lost: temporary tables, the autocommit mode, and user-defined and session variables. Also, any current transaction rolls back. This behavior may be dangerous for you, as in the following example where the server was shut down and restarted without you knowing it:
mysql>SET @a=1;
Query OK, 0 rows affected (0.05 sec) mysql>INSERT INTO t VALUES(@a);
ERROR 2006: MySQL server has gone away No connection. Trying to reconnect... Connection id: 1 Current database: test Query OK, 1 row affected (1.30 sec) mysql>SELECT * FROM t;
+------+ | a | +------+ | NULL | +------+ 1 row in set (0.05 sec)
The @a
user variable has been lost with
the connection, and after the reconnection it is undefined.
If it is important to have mysql
terminate with an error if the connection has been lost, you
can start the mysql client with the
--skip-reconnect
option.