CREATE VIEW

使用 CREATE VIEW 语句将 SELECT 语句保存为类似于表的可查询对象。TiDB 中的视图是非物化的,这意味着在查询视图时,TiDB 将在内部重写查询,以将视图定义与 SQL 查询结合起来。

语法图

  1. CreateViewStmt ::=
  2. 'CREATE' OrReplace ViewAlgorithm ViewDefiner ViewSQLSecurity 'VIEW' ViewName ViewFieldList 'AS' CreateViewSelectOpt ViewCheckOption
  3. OrReplace ::=
  4. ( 'OR' 'REPLACE' )?
  5. ViewAlgorithm ::=
  6. ( 'ALGORITHM' '=' ( 'UNDEFINED' | 'MERGE' | 'TEMPTABLE' ) )?
  7. ViewDefiner ::=
  8. ( 'DEFINER' '=' Username )?
  9. ViewSQLSecurity ::=
  10. ( 'SQL' 'SECURITY' ( 'DEFINER' | 'INVOKER' ) )?
  11. ViewName ::= TableName
  12. ViewFieldList ::=
  13. ( '(' Identifier ( ',' Identifier )* ')' )?
  14. ViewCheckOption ::=
  15. ( 'WITH' ( 'CASCADED' | 'LOCAL' ) 'CHECK' 'OPTION' )?

示例

  1. CREATE TABLE t1 (id INT NOT NULL PRIMARY KEY AUTO_INCREMENT, c1 INT NOT NULL);
  1. Query OK, 0 rows affected (0.11 sec)
  1. INSERT INTO t1 (c1) VALUES (1),(2),(3),(4),(5);
  1. Query OK, 5 rows affected (0.03 sec)
  2. Records: 5 Duplicates: 0 Warnings: 0
  1. CREATE VIEW v1 AS SELECT * FROM t1 WHERE c1 > 2;
  1. Query OK, 0 rows affected (0.11 sec)
  1. SELECT * FROM t1;
  1. +----+----+
  2. | id | c1 |
  3. +----+----+
  4. | 1 | 1 |
  5. | 2 | 2 |
  6. | 3 | 3 |
  7. | 4 | 4 |
  8. | 5 | 5 |
  9. +----+----+
  10. 5 rows in set (0.00 sec)
  1. SELECT * FROM v1;
  1. +----+----+
  2. | id | c1 |
  3. +----+----+
  4. | 3 | 3 |
  5. | 4 | 4 |
  6. | 5 | 5 |
  7. +----+----+
  8. 3 rows in set (0.00 sec)
  1. INSERT INTO t1 (c1) VALUES (6);
  1. Query OK, 1 row affected (0.01 sec)
  1. SELECT * FROM v1;
  1. +----+----+
  2. | id | c1 |
  3. +----+----+
  4. | 3 | 3 |
  5. | 4 | 4 |
  6. | 5 | 5 |
  7. | 6 | 6 |
  8. +----+----+
  9. 4 rows in set (0.00 sec)
  1. INSERT INTO v1 (c1) VALUES (7);
  1. ERROR 1105 (HY000): insert into view v1 is not supported now.

MySQL 兼容性

  • 目前 TiDB 中的任何视图都不可被插入,也不可被更新(即不支持 INSERT VIEW,也不支持 UPDATE VIEW)。WITH CHECK OPTION 只做了语法兼容但不生效。
  • 目前 TiDB 中的视图不支持 ALTER VIEW,但可以使用 CREATE OR REPLACE 替代。
  • 目前 ALGORITHM 字段在 TiDB 中只做了语法兼容但不生效,TiDB 目前只支持 MERGE 算法。

另请参阅