- 2.1. The Server SQL Mode
- 2.2. MySQL Identifier Syntax and Naming Rules
- 2.3. Case Sensitivity in SQL Statements
- 2.4. Character Set Support
- 2.5. Selecting, Creating, Dropping, and Altering Databases
- 2.6. Creating, Dropping, Indexing, and Altering Tables
- 2.7. Obtaining Database Metadata
- 2.8. Performing Multiple-Table Retrievals with Joins
- 2.9. Performing Multiple-Table Retrievals with Subqueries
- 2.10. Performing Multiple-Table Retrievals with UNION
- 2.11. Multiple-Table Deletes and Updates
- 2.12. Performing Transactions
- 2.13. Foreign Keys and Referential Integrity
- 2.14. Using FULLTEXT Searches
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.