Documentation Home
MySQL 9.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 40.0Mb
PDF (A4) - 40.1Mb
Man Pages (TGZ) - 258.8Kb
Man Pages (Zip) - 365.9Kb
Info (Gzip) - 4.0Mb
Info (Zip) - 4.0Mb


MySQL 9.0 Reference Manual  /  ...  /  The INFORMATION_SCHEMA VIEWS Table

28.3.47 The INFORMATION_SCHEMA VIEWS Table

The VIEWS table provides information about views in databases. You must have the SHOW VIEW privilege to access this table.

The VIEWS table has these columns:

  • TABLE_CATALOG

    The name of the catalog to which the view belongs. This value is always def.

  • TABLE_SCHEMA

    The name of the schema (database) to which the view belongs.

  • TABLE_NAME

    The name of the view.

  • VIEW_DEFINITION

    The SELECT statement that provides the definition of the view. This column has most of what you see in the Create Table column that SHOW CREATE VIEW produces. Skip the words before SELECT and skip the words WITH CHECK OPTION. Suppose that the original statement was:

    CREATE VIEW v AS
      SELECT s2,s1 FROM t
      WHERE s1 > 5
      ORDER BY s1
      WITH CHECK OPTION;

    Then the view definition looks like this:

    SELECT s2,s1 FROM t WHERE s1 > 5 ORDER BY s1
  • CHECK_OPTION

    The value of the CHECK_OPTION attribute. The value is one of NONE, CASCADE, or LOCAL.

  • IS_UPDATABLE

    MySQL sets a flag, called the view updatability flag, at CREATE VIEW time. The flag is set to YES (true) if UPDATE and DELETE (and similar operations) are legal for the view. Otherwise, the flag is set to NO (false). The IS_UPDATABLE column in the VIEWS table displays the status of this flag. It means that the server always knows whether a view is updatable.

    If a view is not updatable, statements such UPDATE, DELETE, and INSERT are illegal and are rejected. (Even if a view is updatable, it might not be possible to insert into it; for details, refer to Section 27.6.3, “Updatable and Insertable Views”.)

  • DEFINER

    The account of the user who created the view, in 'user_name'@'host_name' format.

  • SECURITY_TYPE

    The view SQL SECURITY characteristic. The value is one of DEFINER or INVOKER.

  • CHARACTER_SET_CLIENT

    The session value of the character_set_client system variable when the view was created.

  • COLLATION_CONNECTION

    The session value of the collation_connection system variable when the view was created.

Notes

MySQL permits different sql_mode settings to tell the server the type of SQL syntax to support. For example, you might use the ANSI SQL mode to ensure MySQL correctly interprets the standard SQL concatenation operator, the double bar (||), in your queries. If you then create a view that concatenates items, you might worry that changing the sql_mode setting to a value different from ANSI could cause the view to become invalid. But this is not the case. No matter how you write out a view definition, MySQL always stores it the same way, in a canonical form. Here is an example that shows how the server changes a double bar concatenation operator to a CONCAT() function:

mysql> SET sql_mode = 'ANSI';
Query OK, 0 rows affected (0.00 sec)

mysql> CREATE VIEW test.v AS SELECT 'a' || 'b' as col1;
Query OK, 0 rows affected (0.00 sec)

mysql> SELECT VIEW_DEFINITION FROM INFORMATION_SCHEMA.VIEWS
       WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME = 'v';
+----------------------------------+
| VIEW_DEFINITION                  |
+----------------------------------+
| select concat('a','b') AS `col1` |
+----------------------------------+
1 row in set (0.00 sec)

The advantage of storing a view definition in canonical form is that changes made later to the value of sql_mode do not affect the results from the view. However, an additional consequence is that comments prior to SELECT are stripped from the definition by the server.