Skip to content

Latest commit

 

History

History
248 lines (195 loc) · 6.83 KB

views.md

File metadata and controls

248 lines (195 loc) · 6.83 KB
title summary aliases
Views
Learn how to use views in TiDB.
/docs/dev/views/
/docs/dev/reference/sql/views/

Views

TiDB supports views. A view acts as a virtual table, whose schema is defined by the SELECT statement that creates the view. Using views has the following benefits:

  • Exposing only safe fields and data to users to ensure security of sensitive fields and data stored in the underlying table.
  • Defining complex queries that frequently appear as views to make complex queries easier and more convenient.

Query views

Querying a view is similar to querying an ordinary table. However, when TiDB queries a view, it actually queries the SELECT statement associated with the view.

Show metadata

To obtain the metadata of views, choose any of the following methods.

Use the SHOW CREATE TABLE view_name or SHOW CREATE VIEW view_name statement

Usage example:

{{< copyable "sql" >}}

show create view v;

This statement shows the CREATE VIEW statement corresponding to this view and the value of the character_set_client and collation_connection system variables when the view was created.

+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+----------------------+----------------------+
| View | Create View                                                                                                                                                         | character_set_client | collation_connection |
+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+----------------------+----------------------+
| v    | CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`127.0.0.1` SQL SECURITY DEFINER VIEW `v` (`a`) AS SELECT `s`.`a` FROM `test`.`t` LEFT JOIN `test`.`s` ON `t`.`a`=`s`.`a` | utf8                 | utf8_general_ci      |
+------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+----------------------+----------------------+
1 row in set (0.00 sec)

Query the INFORMATION_SCHEMA.VIEWS table

Usage example:

{{< copyable "sql" >}}

select * from information_schema.views;

You can view the relevant meta information of the view by querying this table, such as TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, VIEW_DEFINITION, CHECK_OPTION, IS_UPDATABLE, DEFINER, SECURITY_TYPE, CHARACTER_SET_CLIENT, and COLLATION_CONNECTION.

+---------------+--------------+------------+------------------------------------------------------------------------+--------------+--------------+----------------+---------------+----------------------+----------------------+
| TABLE_CATALOG | TABLE_SCHEMA | TABLE_NAME | VIEW_DEFINITION                                                        | CHECK_OPTION | IS_UPDATABLE | DEFINER        | SECURITY_TYPE | CHARACTER_SET_CLIENT | COLLATION_CONNECTION |
+---------------+--------------+------------+------------------------------------------------------------------------+--------------+--------------+----------------+---------------+----------------------+----------------------+
| def           | test         | v          | SELECT `s`.`a` FROM `test`.`t` LEFT JOIN `test`.`s` ON `t`.`a`=`s`.`a` | CASCADED     | NO           | root@127.0.0.1 | DEFINER       | utf8                 | utf8_general_ci      |
+---------------+--------------+------------+------------------------------------------------------------------------+--------------+--------------+----------------+---------------+----------------------+----------------------+
1 row in set (0.00 sec)

Use the HTTP APIs

Usage example:

{{< copyable "" >}}

curl http://127.0.0.1:10080/schema/test/v

By visiting http://{TiDBIP}:10080/schema/{db}/{view}, you can get all the metadata for the view.

{
 "id": 122,
 "name": {
  "O": "v",
  "L": "v"
 },
 "charset": "utf8",
 "collate": "utf8_general_ci",
 "cols": [
  {
   "id": 1,
   "name": {
    "O": "a",
    "L": "a"
   },
   "offset": 0,
   "origin_default": null,
   "default": null,
   "default_bit": null,
   "default_is_expr": false,
   "generated_expr_string": "",
   "generated_stored": false,
   "dependences": null,
   "type": {
    "Tp": 0,
    "Flag": 0,
    "Flen": 0,
    "Decimal": 0,
    "Charset": "",
    "Collate": "",
    "Elems": null
   },
   "state": 5,
   "comment": "",
   "hidden": false,
   "version": 0
  }
 ],
 "index_info": null,
 "fk_info": null,
 "state": 5,
 "pk_is_handle": false,
 "is_common_handle": false,
 "comment": "",
 "auto_inc_id": 0,
 "auto_id_cache": 0,
 "auto_rand_id": 0,
 "max_col_id": 1,
 "max_idx_id": 0,
 "update_timestamp": 416801600091455490,
 "ShardRowIDBits": 0,
 "max_shard_row_id_bits": 0,
 "auto_random_bits": 0,
 "pre_split_regions": 0,
 "partition": null,
 "compression": "",
 "view": {
  "view_algorithm": 0,
  "view_definer": {
   "Username": "root",
   "Hostname": "127.0.0.1",
   "CurrentUser": false,
   "AuthUsername": "root",
   "AuthHostname": "%"
  },
  "view_security": 0,
  "view_select": "SELECT `s`.`a` FROM `test`.`t` LEFT JOIN `test`.`s` ON `t`.`a`=`s`.`a`",
  "view_checkoption": 1,
  "view_cols": null
 },
 "sequence": null,
 "Lock": null,
 "version": 3,
 "tiflash_replica": null
}

Example

The following example creates a view, queries this view, and delete this view:

{{< copyable "sql" >}}

create table t(a int, b int);
Query OK, 0 rows affected (0.01 sec)

{{< copyable "sql" >}}

insert into t values(1, 1),(2,2),(3,3);
Query OK, 3 rows affected (0.00 sec)
Records: 3  Duplicates: 0  Warnings: 0

{{< copyable "sql" >}}

create table s(a int);
Query OK, 0 rows affected (0.01 sec)

{{< copyable "sql" >}}

insert into s values(2),(3);
Query OK, 2 rows affected (0.01 sec)
Records: 2  Duplicates: 0  Warnings: 0

{{< copyable "sql" >}}

create view v as select s.a from t left join s on t.a = s.a;
Query OK, 0 rows affected (0.01 sec)

{{< copyable "sql" >}}

select * from v;
+------+
| a    |
+------+
| NULL |
|    2 |
|    3 |
+------+
3 rows in set (0.00 sec)

{{< copyable "sql" >}}

drop view v;
Query OK, 0 rows affected (0.02 sec)

Limitations

Currently, views in TiDB are subject to the following limitations:

  • Materialized views are not supported yet.
  • Views in TiDB are read-only and do not support write operations such as UPDATE, INSERT, DELETE, and TRUNCATE.
  • For created views, the only supported DDL operation is DROP [VIEW | TABLE]

See also