Home > Articles > Data > MySQL

This chapter is from the book

This chapter is from the book

2.7. Obtaining Database Metadata

MySQL provides several ways to obtain database metadata—that is, information about databases and the objects in them:

  • SHOW statements such as SHOW DATABASES or SHOW TABLES
  • Tables in the INFORMATION_SCHEMA database
  • Command-line programs such as mysqlshow or mysqldump

The following sections describe how to use each of these information sources to access metadata.

2.7.1. Obtaining Metadata with SHOW

MySQL provides a SHOW statement that displays many types of database metadata. SHOW is helpful for keeping track of the contents of your databases and reminding yourself about the structure of your tables. The following examples demonstrate a few uses for SHOW statements.

List the databases you can access:

SHOW DATABASES;

Display the CREATE DATABASE statement for a database:

SHOW CREATE DATABASE db_name;

List the tables in the default database or a given database:

SHOW TABLES;
SHOW TABLES FROM db_name;

SHOW TABLES doesn’t show TEMPORARY tables.

Display the CREATE TABLE statement for a table:

SHOW CREATE TABLE tbl_name;

Display information about columns or indexes in a table:

SHOW COLUMNS FROM tbl_name;
SHOW INDEX FROM tbl_name;

The DESCRIBE tbl_name and EXPLAIN tbl_name statements are synonymous with SHOW COLUMNS FROM tbl_name.

Display descriptive information about tables in the default database or in a given database:

SHOW TABLE STATUS;
SHOW TABLE STATUS FROM db_name;

Several forms of the SHOW statement take a LIKE 'pattern' clause permitting a pattern to be given that limits the scope of the output. MySQL interprets 'pattern' as an SQL pattern that may include the ‘%’ and ‘_’ wildcard characters. For example, this statement displays the names of columns in the student table that begin with ‘s’:

mysql> SHOW COLUMNS FROM student LIKE 's%';
+------------+------------------+------+-----+---------+----------------+
| Field      | Type             | Null | Key | Default | Extra          |
+------------+------------------+------+-----+---------+----------------+
| sex        | enum('F','M')    | NO   |     | NULL    |                |
| student_id | int(10) unsigned | NO   | PRI | NULL    | auto_increment |
+------------+------------------+------+-----+---------+----------------+

To match a literal instance of a wildcard character in a LIKE pattern, precede it with a back-slash. This is commonly done to match a literal ‘_’, which occurs frequently in database, table, and column names.

Any SHOW statement that supports a LIKE clause can also be written to use a WHERE clause. The statement displays the same columns, but WHERE provides more flexibility about specifying which rows to return. The WHERE clause should refer to the SHOW statement column names. If the column name is a reserved word such as KEY, specify it as a quoted identifier. This statement determines which column in the student table is the primary key:

mysql> SHOW COLUMNS FROM student WHERE `Key` = `PRI`;
+------------+------------------+------+-----+---------+----------------+
| Field      | Type             | Null | Key | Default | Extra          |
+------------+------------------+------+-----+---------+----------------+
| student_id | int(10) unsigned | NO   | PRI | NULL    | auto_increment |
+------------+------------------+------+-----+---------+----------------+

It’s sometimes useful to be able to tell from within an application whether a given table exists. You can use SHOW TABLES to find out (unless the table is a TEMPORARY table):

SHOW TABLES LIKE 'tbl_name';
SHOW TABLES FROM db_name LIKE 'tbl_name';

If the SHOW TABLES statement lists information for the table, it exists. It’s also possible to determine table existence, even for TEMPORARY tables, with either of the following statements:

SELECT COUNT(*) FROM tbl_name;
SELECT * FROM tbl_name WHERE FALSE;

Each statement succeeds if the table exists, and fails if it doesn’t. The first statement is most appropriate for MyISAM tables, for which COUNT(*) with no WHERE clause is highly optimized. It’s not so good for InnoDB tables, which require a full scan to count the rows. The second statement is more general because it runs quickly for any storage engine. These statements are most suitable for use within application programming languages such as Perl or PHP because you can test the success or failure of the query and take action accordingly. They’re not especially useful in a batch script that you run from mysql because you can’t do anything if an error occurs except terminate (or ignore the error, but then there’s obviously no point in running the query at all). Another strategy, which works in any context without failure, is to query the INFORMATION_SCHEMA database. See Section 2.7.2, “Obtaining Metadata with INFORMATION_SCHEMA.”

To determine the storage engine for individual tables, you can use SHOW TABLE STATUS or SHOW CREATE TABLE. The output from either statement includes a storage engine indicator.

2.7.2. Obtaining Metadata with INFORMATION_SCHEMA

Another way to obtain information about databases is to access the INFORMATION_SCHEMA database. INFORMATION_SCHEMA is based on the SQL standard. That is, the access mechanism is standard, even though some of the content is MySQL-specific. This makes INFORMATION_SCHEMA more portable than the various SHOW statements, which are entirely MySQL-specific.

INFORMATION_SCHEMA is accessed through SELECT statements and can be used in a flexible manner. SHOW statements always display a fixed set of columns and you cannot capture the output in a table. With INFORMATION_SCHEMA, the SELECT statement can name specific output columns and a WHERE clause can specify any expression required to select the information that you want. Also, you can use joins or subqueries, and you can use CREATE TABLE ... SELECT or INSERT INTO ... SELECT to save the result of the retrieval in another table for further processing.

You can think of INFORMATION_SCHEMA as a virtual database in which the tables are views for different kinds of database metadata. To see what tables INFORMATION_SCHEMA contains, use SHOW TABLES:

mysql> SHOW TABLES IN INFORMATION_SCHEMA;
+---------------------------------------+
| Tables_in_information_schema          |
+---------------------------------------+
| CHARACTER_SETS                        |
| COLLATIONS                            |
| COLLATION_CHARACTER_SET_APPLICABILITY |
| COLUMNS                               |
| COLUMN_PRIVILEGES                     |
| ENGINES                               |
| EVENTS                                |

| FILES                                 |
| GLOBAL_STATUS                         |
| GLOBAL_VARIABLES                      |
| KEY_COLUMN_USAGE                      |
| PARAMETERS                            |
| PARTITIONS                            |
| PLUGINS                               |
| PROCESSLIST                           |
| PROFILING                             |
| REFERENTIAL_CONSTRAINTS               |
| ROUTINES                              |
| SCHEMATA                              |
| SCHEMA_PRIVILEGES                     |
| SESSION_STATUS                        |
| SESSION_VARIABLES                     |
| STATISTICS                            |
| TABLES                                |
| TABLESPACES                           |
| TABLE_CONSTRAINTS                     |
| TABLE_PRIVILEGES                      |
| TRIGGERS                              |
| USER_PRIVILEGES                       |
| VIEWS                                 |
+---------------------------------------+

The following list briefly describes some of the INFORMATION_SCHEMA tables just shown:

  • SCHEMATA, TABLES, VIEWS, ROUTINES, TRIGGERS, EVENTS, PARAMETERS, PARTITIONS, COLUMNS

    Information about databases; tables, views, stored routines, triggers, and events within databases; routine parameters; table partitions; and columns within tables

  • FILES

    Information about the files used to store tablespace data

  • TABLE_CONSTRAINTS, KEY_COLUMN_USAGE

    Information about tables and columns that have constraints such as unique-valued indexes or foreign keys

  • STATISTICS

    Information about table index characteristics

  • REFERENTIAL_CONSTRAINTS

    Information about foreign keys

  • CHARACTER_SETS, COLLATIONS, COLLATION_CHARACTER_SET_APPLICABILITY

    Information about supported character sets, collations for each character set, and mapping from each collation to its character set

  • ENGINES, PLUGINS

    Information about storage engines and server plugins

  • USER_PRIVILEGES, SCHEMA_PRIVILEGES, TABLE_PRIVILEGES, COLUMN_PRIVILEGES

    Global, database, table, and column privilege information from the user, db, tables_priv, and columns_priv tables in the mysql database

  • GLOBAL_VARIABLES, SESSION_VARIABLES, GLOBAL_STATUS, SESSION_STATUS

    Global and session values of system and status variables

  • PROCESSLIST

    Information about the threads executing within the server

Individual storage engines may add their own tables to INFORMATION_SCHEMA. For example, InnoDB does this.

To determine the columns contained in a given INFORMATION_SCHEMA table, use SHOW COLUMNS or DESCRIBE:

mysql> DESCRIBE INFORMATION_SCHEMA.CHARACTER_SETS;
+----------------------+-------------+------+-----+---------+-------+
| Field                | Type        | Null | Key | Default | Extra |
+----------------------+-------------+------+-----+---------+-------+
| CHARACTER_SET_NAME   | varchar(32) | NO   |     |         |       |
| DEFAULT_COLLATE_NAME | varchar(32) | NO   |     |         |       |
| DESCRIPTION          | varchar(60) | NO   |     |         |       |
| MAXLEN               | bigint(3)   | NO   |     | 0       |       |
+----------------------+-------------+------+-----+---------+-------+

To display information from a table, use a SELECT statement. (Neither INFORMATION_SCHEMA nor any of its table or column names are case sensitive.) The general query to see all the columns in any given INFORMATION_SCHEMA table is as follows:

SELECT * FROM INFORMATION_SCHEMA.tbl_name;

Include a WHERE clause to be specific about what you want to see.

The preceding section described the use of SHOW statements to determine whether a table exists or which storage engine it uses. INFORMATION_SCHEMA tables can provide the same information. This query uses INFORMATION_SCHEMA to test for the existence of a particular table, returning 1 or 0 to indicate that the table does or does not exist, respectively:

mysql> SELECT COUNT(*) FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA='sampdb' AND TABLE_NAME='member';
+----------+
| COUNT(*) |
+----------+
|        1 |
+----------+

Use this query to check which storage engine a table uses:

mysql> SELECT ENGINE FROM INFORMATION_SCHEMA.TABLES
    -> WHERE TABLE_SCHEMA='sampdb' AND TABLE_NAME='student';
+--------+
| ENGINE |
+--------+
| InnoDB |
+--------+

2.7.3. Obtaining Metadata from the Command Line

The mysqlshow command provides some of the same information as certain SHOW statements, which enables you to get database and table information at your command prompt.

List databases managed by the server:

% mysqlshow

List tables in a database:

% mysqlshow db_name

Display information about columns in a table:

% mysqlshow db_name tbl_name

Display information about indexes in a table:

% mysqlshow --keys db_name tbl_name

Display descriptive information about tables in a database:

% mysqlshow --status db_name

The mysqldump client program enables you to see the structure of your tables in the form of a CREATE TABLE statement (much like SHOW CREATE TABLE). If you use mysqldump to review table structure, invoke it with the --no-data option so that you don’t get swamped with your table’s data!

% mysqldump --no-data db_name [tbl_name] ...

If you specify only the database name with no table names, mysqldump displays the structure for all tables in the database. Otherwise, it shows information only for the named tables.

For both mysqlshow and mysqldump, specify the usual connection parameter options as necessary, such as --host, --user, or --password.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020