The mysqlshow client can be used to quickly see which databases exist, their tables, or a table's columns or indexes.
mysqlshow provides a command-line interface
to several SQL SHOW
statements.
See Section 12.4.5, “SHOW
Syntax”. The same information can be obtained
by using those statements directly. For example, you can issue
them from the mysql client program.
Invoke mysqlshow like this:
shell> mysqlshow [options
] [db_name
[tbl_name
[col_name
]]]
If no database is given, a list of database names is shown.
If no table is given, all matching tables in the database are shown.
If no column is given, all matching columns and column types in the table are shown.
The output displays only the names of those databases, tables, or columns for which you have some privileges.
If the last argument contains shell or SQL wildcard characters
(“*
”,
“?
”,
“%
”, or
“_
”), only those names that are
matched by the wildcard are shown. If a database name contains
any underscores, those should be escaped with a backslash (some
Unix shells require two) to get a list of the proper tables or
columns. “*
” and
“?
” characters are converted
into SQL “%
” and
“_
” wildcard characters. This
might cause some confusion when you try to display the columns
for a table with a “_
” in the
name, because in this case, mysqlshow shows
you only the table names that match the pattern. This is easily
fixed by adding an extra “%
”
last on the command line as a separate argument.
mysqlshow supports the following options,
which can be specified on the command line or in the
[mysqlshow]
and [client]
option file groups. mysqlshow also supports
the options for processing option files described at
Section 4.2.3.3.1, “Command-Line Options that Affect Option-File Handling”.
Table 4.7. mysqlshow
Options
Format | Config File | Description | Introduction | Deprecated | Removed |
---|---|---|---|---|---|
--compress | compress | Compress all information sent between the client and the server | |||
--count | count | Show the number of rows per table | 5.0.6 | ||
--debug[=debug_options] | debug | Write a debugging log | |||
--default-character-set=charset_name | default-character-set | Use charset_name as the default character set | |||
--help | Display help message and exit | ||||
--host=host_name | host | Connect to the MySQL server on the given host | |||
--keys | keys | Show table indexes | |||
--password[=password] | password | The password to use when connecting to the server | |||
--pipe | On Windows, connect to server via a named pipe | ||||
--port=port_num | port | The TCP/IP port number to use for the connection | |||
--protocol=type | protocol | The connection protocol to use | |||
--show-table-type | Show a column indicating the table type | 5.0.4 | |||
--socket=path | socket | For connections to localhost | |||
--ssl-ca=file_name | ssl-ca | The path to a file that contains a list of trusted SSL CAs | |||
--ssl-capath=directory_name | ssl-capath | The path to a directory that contains trusted SSL CA certificates in PEM format | |||
--ssl-cert=file_name | ssl-cert | The name of the SSL certificate file to use for establishing a secure connection | |||
--ssl-cipher=cipher_list | ssl-cipher | A list of allowable ciphers to use for SSL encryption | |||
--ssl-key=file_name | ssl-key | The name of the SSL key file to use for establishing a secure connection | |||
--ssl-verify-server-cert | ssl-verify-server-cert | The server's Common Name value in its certificate is verified against the host name used when connecting to the server | |||
--status | status | Display extra information about each table | |||
--user=user_name, | user | The MySQL user name to use when connecting to the server | |||
--verbose | Verbose mode | ||||
--version | Display version information and exit |
--help
,
-?
Display a help message and exit.
The directory where character sets are installed. See Section 9.5, “Character Set Configuration”.
--compress
,
-C
Compress all information sent between the client and the server if both support compression.
Show the number of rows per table. This can be slow for
non-MyISAM
tables. This option was added
in MySQL 5.0.6.
--debug[=
,
debug_options
]-#
[
debug_options
]
Write a debugging log. A typical
debug_options
string is
'd:t:o,
.
The default is file_name
''d:t:o'
.
--default-character-set=
charset_name
Use charset_name
as the default
character set. See Section 9.5, “Character Set Configuration”.
--host=
,
host_name
-h
host_name
Connect to the MySQL server on the given host.
--keys
,
-k
Show table indexes.
--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,
mysqlshow prompts for one.
Specifying a password on the command line should be considered insecure. See Section 5.3.2.2, “End-User Guidelines for Password Security”. You can use an option file to avoid giving the password on the command line. You can use an option file to avoid giving the password on the command line.
--pipe
,
-W
On Windows, connect to the server via a named pipe. This option applies only if the server supports named-pipe connections.
--port=
,
port_num
-P
port_num
The TCP/IP port number to use for the connection.
--protocol={TCP|SOCKET|PIPE|MEMORY}
The connection protocol to use for connecting to the server. It is useful when the other connection parameters normally would cause a protocol to be used other than the one you want. For details on the allowable values, see Section 4.2.2, “Connecting to the MySQL Server”.
Show a column indicating the table type, as in SHOW
FULL TABLES
. The type is BASE
TABLE
or VIEW
. This option was
added in MySQL 5.0.4.
--socket=
,
path
-S
path
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.5.6.3, “SSL Command Options”.
--status
,
-i
Display extra information about each table.
--user=
,
user_name
-u
user_name
The MySQL user name to use when connecting to the server.
--verbose
,
-v
Verbose mode. Print more information about what the program does. This option can be used multiple times to increase the amount of information.
--version
,
-V
Display version information and exit.
User Comments
I needed to drop 38 tables on database php1 and could not find a metadata table on which I could execute SQL like: delete from metadata where table_name like 'phpbb208%'
Workaround-Solution:
mysqlshow -uroot -p php1 phpbb208\\_% |sed 's/[|+-]//g'|sed 's/[ ]*$/,/'>drop208.sql
(**note the \\ to get the phpbb208_% wildcard**)
provided me the table_name, table_name, ... list
editing drop208.sql and adding 'drop table' provided me the complete drop-statement.
mysql php1 -u root -p < drop208.sql
Done
Another example use of mysqlshow.
I wanted to have all the tables in a database that contains a certain field.
Here is the bash shell script I wrote:
#!/bin/sh
#This scripts returns all the tables in a database that contains some field
function usage
{
echo "Usage: $0 USER DB COLUMN"
}
function ExistsColumn
{
local USER=$1
local DB=$2
local TABLE=$3
local COLUMN=$4
SEARCH_RESULT=$(mysqlshow -u ${USER} ${DB} ${TABLE} ${COLUMN} | awk '{ if ( NR == 5) print $2 }')
if [ "${COLUMN}" = "${SEARCH_RESULT}" ];
then
echo "true";
else
echo "false";
fi
}
function main
{
local USER=$1
local DB=$2
local COLUMN=$3
if [[ "${USER}" = "" || "${DB}" = "" || "${COLUMN}" = "" ]];
then
usage
exit 1
fi
all_tables=$(mysqlshow -u ${USER} ${DB} | \
awk '{ if (NR >4 ) print $_}' | \
sed -e 's/[|+-]//g; /^$/d ' | \
xargs )
for TABLE in ${all_tables}; do
if [ "true" = "$(ExistsColumn $USER $DB $TABLE $COLUMN)" ];
then
echo $TABLE
fi
done
}
main $*
Add your own comment.