- MySQL Naming Rules
- The Server SQL Mode
- Character Set Support
- Selecting, Creating, Dropping, and Altering Databases
- Creating, Dropping, Indexing, and Altering Tables
- Getting Information About Databases and Tables
- Performing Multiple-Table Retrievals with Joins
- Performing Multiple-Table Retrievals with Subqueries
- Performing Multiple-Table Retrievals with UNION
- Multiple-Table Deletes and Updates
- Performing Transactions
- Foreign Keys and Referential Integrity
- Using FULLTEXT Searches
- New Features in MySQL 5.0
Getting Information About Databases and Tables
MySQL provides a SHOW statement that has several variant forms that display information about databases and the tables in them. SHOW is helpful for keeping track of the contents of your databases and for reminding yourself about the structure of your tables:
-
List the databases managed by the server:
SHOW DATABASES;
Display the CREATE DATABASE statement for a database:
SHOW CREATE DATABASE db_name;
List the tables in the current database or in a given database:
SHOW TABLES; SHOW TABLES FROM db_name;
Note that 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 current 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 allowing 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 tables in the current database that begin with 'geo':
SHOW TABLES LIKE 'geo%';
To match a literal instance of a wildcard character in a LIKE pattern, precede it with a backslash. Generally, this is done to match a literal '_', which occurs frequently in database, table, and column names.
The mysqlshow command provides some of the same information as the SHOW statement, which allows 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 allows you to see the structure of your tables in the form of a CREATE TABLE statement (much like SHOW CREATE TABLE). When using mysqldump to review table structure, be sure to 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 list only the database name without any table names, mysqldump displays the structure for all tables in the database. Otherwise it shows information for the named tables.
For both mysqlshow and mysqldump, you can specify the usual connection parameter options, such as --host, --user, or --password.
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 (but remember that SHOW TABLES does not list TEMPORARY tables):
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 0;
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 or BDB 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).
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.
Beginning with version 5.0.2, MySQL implements INFORMATION_SCHEMA, which provides another way to obtain information about databases (that is, database metadata). 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 to specify exactly what information you require. Also, you can use joins or subqueries, and you can save the result of the retrieval in another table for further processing.
You can think of INFORMATION_SCHEMA as a virtual database where the various tables within it 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 | +---------------------------------------+ | SCHEMATA | | TABLES | | COLUMNS | | CHARACTER_SETS | | COLLATIONS | | COLLATION_CHARACTER_SET_APPLICABILITY | | ROUTINES | | STATISTICS | | VIEWS | | USER_PRIVILEGES | | SCHEMA_PRIVILEGES | | TABLE_PRIVILEGES | | COLUMN_PRIVILEGES | | TABLE_CONSTRAINTS | | KEY_COLUMN_USAGE | +---------------------------------------+
To determine the columns contained in a given table, use SHOW COLUMNS or DESCRIBE:
mysql> DESCRIBE INFORMATION_SCHEMA.CHARACTER_SETS; +----------------------+-------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +----------------------+-------------+------+-----+---------+-------+ | CHARACTER_SET_NAME | varchar(64) | NO | | | | | DEFAULT_COLLATE_NAME | varchar(64) | NO | | | | | DESCRIPTION | varchar(60) | NO | | | | | MAXLEN | bigint(3) | NO | | 0 | | +----------------------+-------------+------+-----+---------+-------+
To display information from a table, use a SELECT statement. The general query to see all the columns in any given INFORMATION_SCHEMA table is as follows:
SELECT * FROM INFORMATION_SCHEMA.tbl_name;
Neither INFORMATION_SCHEMA nor any of its table or column names are case sensitive.
You can provide a WHERE clause to be specific about what you want to see. Here is a simple example that uses INFORMATION_SCHEMA to list information about the sampdb.member table:
mysql> SELECT * FROM INFORMATION_SCHEMA.TABLES -> WHERE TABLE_SCHEMA='sampdb' AND TABLE_NAME='member'\G *************************** 1. row *************************** TABLE_CATALOG: NULL TABLE_SCHEMA: sampdb TABLE_NAME: member TABLE_TYPE: BASE TABLE ENGINE: MyISAM VERSION: 10 ROW_FORMAT: Dynamic TABLE_ROWS: 102 AVG_ROW_LENGTH: 137 DATA_LENGTH: 14000 MAX_DATA_LENGTH: 4294967295 INDEX_LENGTH: 2048 DATA_FREE: 0 AUTO_INCREMENT: 103 CREATE_TIME: 2005-01-20 22:38:03 UPDATE_TIME: 2005-01-20 22:38:23 CHECK_TIME: NULL TABLE_COLLATION: latin1_swedish_ci CHECKSUM: NULL CREATE_OPTIONS: TABLE_COMMENT:
The following list describes the tables in INFORMATION_SCHEMA.
-
SCHEMATA
-
TABLES
-
COLUMNS
-
STATISTICS
-
Information about table index characteristics
-
SCHEMA_PRIVILEGES
-
TABLE_PRIVILEGES
-
COLUMN_PRIVILEGES
-
USER_PRIVILEGES
-
CHARACTER_SETS
-
COLLATIONS
-
COLLATION_CHARACTER_SET_APPLICABILITY
-
TABLE_CONSTRAINTS
-
KEY_COLUMN_USAGE
-
ROUTINES
-
VIEWS
Information about databases
Information about tables in each database
Information about columns in each table
Database privilege information from the mysql.db table
Table privilege information from the mysql.tables_priv table
Column privilege information from the mysql.columns_priv table
Global privilege information from the mysql.user table
Information about supported character sets
Information about collations for each supported character set
Maps each collation to its character set
Information about tables that have constraints such as unique-valued indexes or foreign keys
Information about columns that have key constraints such as unique-valued indexes or foreign keys
Information about stored procedures and functions
Information about views
Other INFORMATION_SCHEMA tables might be implemented over time. See the MySQL Reference Manual for the current list of tables.
Along with the implementation of INFORMATION_SCHEMA, several SHOW statements have been extended in MySQL 5.0 to allow a WHERE clause. Even though each SHOW statement still displays a fixed set of columns, WHERE provides more flexibility about specifying which rows to return. The WHERE clause should refer to the columns displayed by the SHOW statement. The WHERE capability has been added to the following SHOW statements:
SHOW DATABASES SHOW TABLES SHOW OPEN TABLES SHOW COLUMNS SHOW KEYS SHOW VARIABLES SHOW STATUS SHOW TABLE STATUS SHOW PROCEDURE STATUS SHOW FUNCTION STATUS SHOW CHARACTER SET SHOW COLLATION