MySQL 5.1 Reference Manual  /  ...  /  mysqlshow — Display Database, Table, and Column Information

4.5.6 mysqlshow — Display Database, Table, and Column Information

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 13.7.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] groups of an option file. For information about option files used by MySQL programs, see Section 4.2.6, “Using Option Files”.

Table 4.8 mysqlshow Options

FormatDescriptionIntroduced
--bind-addressUse specified network interface to connect to MySQL Server5.1.22-ndb-6.3.4
--compressCompress all information sent between client and server
--countShow the number of rows per table
--debugWrite debugging log
--debug-checkPrint debugging information when program exits5.1.21
--debug-infoPrint debugging information, memory, and CPU statistics when program exits5.1.14
--default-character-setSpecify default character set
--defaults-extra-fileRead named option file in addition to usual option files
--defaults-fileRead only named option file
--defaults-group-suffixOption group suffix value
--helpDisplay help message and exit
--hostConnect to MySQL server on given host
--keysShow table indexes
--no-defaultsRead no option files
--passwordPassword to use when connecting to server
--pipeOn Windows, connect to server using named pipe
--portTCP/IP port number to use for connection
--print-defaultsPrint default options
--protocolConnection protocol to use
--shared-memory-base-nameThe name of shared memory to use for shared-memory connections
--show-table-typeShow a column indicating the table type
--socketFor connections to localhost, the Unix socket file to use
--sslEnable SSL for connection
--ssl-caPath of file that contains list of trusted SSL CAs
--ssl-capathPath of directory that contains trusted SSL CA certificates in PEM format
--ssl-certPath of file that contains X509 certificate in PEM format
--ssl-cipherList of permitted ciphers to use for SSL encryption
--ssl-keyPath of file that contains X509 key in PEM format
--ssl-verify-server-certVerify Common Name value in server certificate against host name used when connecting to server5.1.11
--statusDisplay extra information about each table
--userMySQL user name to use when connecting to server
--verboseVerbose mode
--versionDisplay version information and exit

  • --help, -?

    Display a help message and exit.

  • --bind-address=ip_address

    On a computer having multiple network interfaces, use this option to select which interface to use for connecting to the MySQL server.

    This option is supported only in the version of mysqlshow that is supplied with MySQL Cluster, beginning with MySQL Cluster NDB 6.3.4. It is not available in standard MySQL 5.1 releases.

  • --character-sets-dir=dir_name

    The directory where character sets are installed. See Section 10.5, “Character Set Configuration”.

  • --compress, -C

    Compress all information sent between the client and the server if both support compression.

  • --count

    Show the number of rows per table. This can be slow for non-MyISAM tables.

  • --debug[=debug_options], -# [debug_options]

    Write a debugging log. A typical debug_options string is d:t:o,file_name. The default is d:t:o.

  • --debug-check

    Print some debugging information when the program exits. This option was added in MySQL 5.1.21.

  • --debug-info

    Print debugging information and memory and CPU usage statistics when the program exits. This option was added in MySQL 5.1.14.

  • --default-character-set=charset_name

    Use charset_name as the default character set. See Section 10.5, “Character Set Configuration”.

  • --defaults-extra-file=file_name

    Read this option file after the global option file but (on Unix) before the user option file. If the file does not exist or is otherwise inaccessible, an error occurs. file_name is the full path name to the file.

  • --defaults-file=file_name

    Use only the given option file. If the file does not exist or is otherwise inaccessible, an error occurs. file_name is the full path name to the file.

  • --defaults-group-suffix=str

    Read not only the usual option groups, but also groups with the usual names and a suffix of str. For example, mysqlshow normally reads the [client] and [mysqlshow] groups. If the --defaults-group-suffix=_other option is given, mysqlshow also reads the [client_other] and [mysqlshow_other] groups.

  • --host=host_name, -h host_name

    Connect to the MySQL server on the given host.

  • --keys, -k

    Show table indexes.

  • --no-defaults

    Do not read any option files. If program startup fails due to reading unknown options from an option file, --no-defaults can be used to prevent them from being read.

  • --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 6.1.2.1, “End-User Guidelines for Password Security”. You can use an option file to avoid giving the password on the command line.

  • --pipe, -W

    On Windows, connect to the server using 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.

  • --print-defaults

    Print the program name and all options that it gets from option files.

  • --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 permissible values, see Section 4.2.2, “Connecting to the MySQL Server”.

  • --shared-memory-base-name=name

    On Windows, the shared-memory name to use, for connections made using shared memory to a local server. The default value is MYSQL. The shared-memory name is case sensitive.

    The server must be started with the --shared-memory option to enable shared-memory connections.

  • --show-table-type, -t

    Show a column indicating the table type, as in SHOW FULL TABLES. The type is BASE TABLE or VIEW.

  • --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.

  • --ssl*

    Options that begin with --ssl specify whether to connect to the server using SSL and indicate where to find SSL keys and certificates. See Section 6.3.6.5, “Command Options for Secure Connections”.

  • --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
  Posted by arjan muyen on June 18, 2004
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
  Posted by Nan Li on April 7, 2005
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 $*

  Posted by Arnoldas Brazys on November 16, 2010
Was searching how to describe all tables in database, here goes a one liner

echo "show tables;" | mysql table_name | grep -v "Tables_in_" | while read table; do echo "Table: $table"; (echo "describe $table" | mysql -t table_name); done >> show_tables_verbose.txt

  Posted by joshua sox on December 4, 2013
This script using mysqlshow will dump every user database to a folder marked by the current date. you can also dump system databases by using -u root -p password in the command. the paths created and used are relative so create a dir where you want to keep them and place the script inside.

#! /bin/bash
d=`date +%y%m%d`
db=$(mysqlshow | sed '1,/Databases/d' | awk '{print $2}')
mkdir -p $d-dump
cd $d-dump
for dbs in $db; do mysqldump $dbs > $d-$dbs.sql
wait
done
cd ../
exit

Sign Up Login You must be logged in to post a comment.