Table of Contents [+/-]
- 22.1 The INFORMATION_SCHEMA CHARACTER_SETS Table
- 22.2 The INFORMATION_SCHEMA COLLATIONS Table
- 22.3 The INFORMATION_SCHEMA COLLATION_CHARACTER_SET_APPLICABILITY Table
- 22.4 The INFORMATION_SCHEMA COLUMNS Table
- 22.5 The INFORMATION_SCHEMA COLUMN_PRIVILEGES Table
- 22.6 The INFORMATION_SCHEMA ENGINES Table
- 22.7 The INFORMATION_SCHEMA EVENTS Table
- 22.8 The INFORMATION_SCHEMA FILES Table
- 22.9 The INFORMATION_SCHEMA GLOBAL_STATUS and SESSION_STATUS Tables
- 22.10 The INFORMATION_SCHEMA GLOBAL_VARIABLES and SESSION_VARIABLES Tables
- 22.11 The INFORMATION_SCHEMA KEY_COLUMN_USAGE Table
- 22.12 The INFORMATION_SCHEMA ndb_transid_mysql_connection_map Table
- 22.13 The INFORMATION_SCHEMA OPTIMIZER_TRACE Table
- 22.14 The INFORMATION_SCHEMA PARAMETERS Table
- 22.15 The INFORMATION_SCHEMA PARTITIONS Table
- 22.16 The INFORMATION_SCHEMA PLUGINS Table
- 22.17 The INFORMATION_SCHEMA PROCESSLIST Table
- 22.18 The INFORMATION_SCHEMA PROFILING Table
- 22.19 The INFORMATION_SCHEMA REFERENTIAL_CONSTRAINTS Table
- 22.20 The INFORMATION_SCHEMA ROUTINES Table
- 22.21 The INFORMATION_SCHEMA SCHEMATA Table
- 22.22 The INFORMATION_SCHEMA SCHEMA_PRIVILEGES Table
- 22.23 The INFORMATION_SCHEMA STATISTICS Table
- 22.24 The INFORMATION_SCHEMA TABLES Table
- 22.25 The INFORMATION_SCHEMA TABLESPACES Table
- 22.26 The INFORMATION_SCHEMA TABLE_CONSTRAINTS Table
- 22.27 The INFORMATION_SCHEMA TABLE_PRIVILEGES Table
- 22.28 The INFORMATION_SCHEMA TRIGGERS Table
- 22.29 The INFORMATION_SCHEMA USER_PRIVILEGES Table
- 22.30 The INFORMATION_SCHEMA VIEWS Table
- 22.31 INFORMATION_SCHEMA Tables for InnoDB [+/-]
- 22.32 Extensions to SHOW Statements
INFORMATION_SCHEMA provides access to database
metadata, information about
the MySQL server such as the name of a database or table, the data
type of a column, or access privileges. Other terms that are
sometimes used for this information are
data dictionary and
system catalog.
Usage Notes for the INFORMATION_SCHEMA Database
INFORMATION_SCHEMA is a database within each
MySQL instance, the place that stores information about all the
other databases that the MySQL server maintains. The
INFORMATION_SCHEMA database contains several
read-only tables. They are actually views, not base tables, so there
are no files associated with them, and you cannot set triggers on
them. Also, there is no database directory with that name.
Although you can select INFORMATION_SCHEMA as the
default database with a USE
statement, you can only read the contents of tables, not perform
INSERT,
UPDATE, or
DELETE operations on them.
Example
Here is an example of a statement that retrieves information from
INFORMATION_SCHEMA:
mysql>SELECT table_name, table_type, engine->FROM information_schema.tables->WHERE table_schema = 'db5'->ORDER BY table_name;+------------+------------+--------+ | table_name | table_type | engine | +------------+------------+--------+ | fk | BASE TABLE | InnoDB | | fk2 | BASE TABLE | InnoDB | | goto | BASE TABLE | MyISAM | | into | BASE TABLE | MyISAM | | k | BASE TABLE | MyISAM | | kurs | BASE TABLE | MyISAM | | loop | BASE TABLE | MyISAM | | pk | BASE TABLE | InnoDB | | t | BASE TABLE | MyISAM | | t2 | BASE TABLE | MyISAM | | t3 | BASE TABLE | MyISAM | | t7 | BASE TABLE | MyISAM | | tables | BASE TABLE | MyISAM | | v | VIEW | NULL | | v2 | VIEW | NULL | | v3 | VIEW | NULL | | v56 | VIEW | NULL | +------------+------------+--------+ 17 rows in set (0.01 sec)
Explanation: The statement requests a list of all the tables in
database db5, showing just three pieces of
information: the name of the table, its type, and its storage
engine.
Character Set Considerations
The definition for character columns (for example,
TABLES.TABLE_NAME) is generally
VARCHAR( where N) CHARACTER SET
utf8N is at least 64.
MySQL uses the default collation for this character set
(utf8_general_ci) for all searches, sorts,
comparisons, and other string operations on such columns.
Because some MySQL objects are represented as files, searches in
INFORMATION_SCHEMA string columns can be affected
by file system case sensitivity. For more information, see
Section 11.1.8.8, “Collation and INFORMATION_SCHEMA Searches”.
INFORMATION_SCHEMA as Alternative to SHOW Statements
The SELECT ... FROM INFORMATION_SCHEMA statement
is intended as a more consistent way to provide access to the
information provided by the various
SHOW statements that MySQL supports
(SHOW DATABASES,
SHOW TABLES, and so forth). Using
SELECT has these advantages, compared
to SHOW:
It conforms to Codd's rules, because all access is done on tables.
You can use the familiar syntax of the
SELECTstatement, and only need to learn some table and column names.The implementor need not worry about adding keywords.
You can filter, sort, concatenate, and transform the results from
INFORMATION_SCHEMAqueries into whatever format your application needs, such as a data structure or a text representation to parse.This technique is more interoperable with other database systems. For example, Oracle Database users are familiar with querying tables in the Oracle data dictionary.
Because SHOW is familiar and widely
used, the SHOW statements remain as
an alternative. In fact, along with the implementation of
INFORMATION_SCHEMA, there are enhancements to
SHOW as described in
Section 22.32, “Extensions to SHOW Statements”.
Privileges
Each MySQL user has the right to access these tables, but can see
only the rows in the tables that correspond to objects for which the
user has the proper access privileges. In some cases (for example,
the ROUTINE_DEFINITION column in the
INFORMATION_SCHEMA.ROUTINES table),
users who have insufficient privileges see NULL.
These restrictions do not apply for
InnoDB tables; you can see them with
only the PROCESS privilege.
The same privileges apply to selecting information from
INFORMATION_SCHEMA and viewing the same
information through SHOW statements.
In either case, you must have some privilege on an object to see
information about it.
Performance Considerations
INFORMATION_SCHEMA queries that search for
information from more than one database might take a long time and
impact performance. To check the efficiency of a query, you can use
EXPLAIN. For information about using
EXPLAIN output to tune
INFORMATION_SCHEMA queries, see
Section 9.2.4, “Optimizing INFORMATION_SCHEMA Queries”.
Standards Considerations
The implementation for the INFORMATION_SCHEMA
table structures in MySQL follows the ANSI/ISO SQL:2003 standard
Part 11 Schemata. Our intent is approximate
compliance with SQL:2003 core feature F021 Basic
information schema.
Users of SQL Server 2000 (which also follows the standard) may
notice a strong similarity. However, MySQL has omitted many columns
that are not relevant for our implementation, and added columns that
are MySQL-specific. One such column is the ENGINE
column in the INFORMATION_SCHEMA.TABLES
table.
Although other DBMSs use a variety of names, like
syscat or system, the standard
name is INFORMATION_SCHEMA.
To avoid using any name that is reserved in the standard or in DB2,
SQL Server, or Oracle, we changed the names of some columns marked
“MySQL extension”. (For example, we changed
COLLATION to TABLE_COLLATION
in the TABLES table.) See the list of
reserved words near the end of this article:
https://web.archive.org/web/20070428032454/http://www.dbazine.com/db2/db2-disarticles/gulutzan5.
Conventions in the INFORMATION_SCHEMA Reference Sections
The following sections describe each of the tables and columns in
INFORMATION_SCHEMA. For each column, there are
three pieces of information:
“
INFORMATION_SCHEMAName” indicates the name for the column in theINFORMATION_SCHEMAtable. This corresponds to the standard SQL name unless the “Remarks” field says “MySQL extension.”“
SHOWName” indicates the equivalent field name in the closestSHOWstatement, if there is one.“Remarks” provides additional information where applicable. If this field is
NULL, it means that the value of the column is alwaysNULL. If this field says “MySQL extension,” the column is a MySQL extension to standard SQL.
Many sections indicate what SHOW
statement is equivalent to a SELECT
that retrieves information from
INFORMATION_SCHEMA. For
SHOW statements that display
information for the default database if you omit a FROM
clause, you can often
select information for the default database by adding an
db_nameAND TABLE_SCHEMA = SCHEMA() condition to the
WHERE clause of a query that retrieves
information from an INFORMATION_SCHEMA table.
For information about INFORMATION_SCHEMA tables
specific to the InnoDB storage engine,
see Section 22.31, “INFORMATION_SCHEMA Tables for InnoDB”.
For answers to questions that are often asked concerning the
INFORMATION_SCHEMA database, see
Section A.7, “MySQL 5.7 FAQ: INFORMATION_SCHEMA”.
This, i theorize, is because it uses the existing table cache to open and get information on tables, so in reality, all tables are closed when you execute the query in INFORMATION_SCHEMA (if you have many tables!).
http://en.latindevelopers.com/ivancp/2012/a-better-show-table-status/