Skip to content

Commit 34a1cf1

Browse files
committed
Docs on VIEWs
1 parent 4ddc2cb commit 34a1cf1

File tree

15 files changed

+472
-49
lines changed

15 files changed

+472
-49
lines changed

ydb/docs/en/core/concepts/datamodel/_includes/index.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -5,3 +5,4 @@ This section describes the entities that {{ ydb-short-name }} uses within DBs. T
55
* [Directory](../dir.md)
66
* [Table](../table.md)
77
* [Topic](../../topic.md)
8+
* [View](../view.md)

ydb/docs/en/core/concepts/datamodel/toc_i.yaml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -6,3 +6,4 @@ items:
66
- { name: Secrets, href: secrets.md }
77
- { name: External tables, href: external_table.md }
88
- { name: External data source, href: external_data_source.md }
9+
- { name: View, href: view.md }
Lines changed: 76 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,76 @@
1+
# View
2+
3+
A view is basically a query that is stored in a database which enables you to treat the results of the query as a table. The view itself contains no data. The results of a view are generated every time you select from that view. Any changes in the underlying tables are reflected immediately in the view.
4+
5+
Views are often used to:
6+
- hide query complexity,
7+
- limit access to underlaying data*,
8+
- provide a backward compatible interface to emulate a table that used to exist, but whose schema has changed.
9+
10+
\* The scenario of creating a view to grant other users partial select privileges on a table that has sensitive data is not implemented yet. In {{ ydb-short-name }} view's stored query can only be executed on behalf of the user of the view. A user cannot select from a view that reads from a table that they don't have select privileges from. See `security_invoker` option description on the [CREATE VIEW](../../yql/reference/syntax/create_view.md) page for details.
11+
12+
## Creating a view
13+
14+
See [CREATE VIEW](../../yql/reference/syntax/create_view.md).
15+
16+
## Altering a view
17+
18+
See [ALTER VIEW](../../yql/reference/syntax/alter_view.md).
19+
20+
## Dropping a view
21+
22+
See [DROP VIEW](../../yql/reference/syntax/drop_view.md).
23+
24+
## View invalidation
25+
26+
If you drop a table that the view references, the view will become invalid. The queries through it will fail with an error of referencing a table that does not exist. The dependencies of views on the tables (and other views) are not tracked in any way at the moment. Select from a view is executed in the same manner as a select from a subquery would, without any prior checks of validity. You will know that the view's query became invalid only at the moment of its execution. This is going to change in the future releases. We are going to start tracking view's dependencies and the default behavior for dropping a table would be to forbid it if any view is referencing the table.
27+
28+
## Performance
29+
30+
Users might notice a little increase in the compilation time of the queries made using views compared to the compilation time of the same query, where views are substituted by their queries. It happens due to the fact that a statement reading from a view:
31+
```sql
32+
SELECT * FROM a_view;
33+
```
34+
is compiled similarly to a statement reading from a subquery:
35+
```sql
36+
SELECT * FROM (SELECT * FROM underlying_table);
37+
```
38+
but with an additional overhead of loading data from the schema object `a_view`.
39+
40+
Please note that if you execute the same query over and over again like:
41+
```sql
42+
-- execute multiple times
43+
SELECT * FROM hot_view;
44+
```
45+
compilation results will be cached on the {{ ydb-short-name }} server and you will not notice any decrease of performance of queries using views.
46+
47+
Execution time of the resulting compiled code for queries using views should always be exactly the same as for the queries directly reading data from the underlying tables.
48+
49+
## View redefinition lag
50+
51+
### Query compilation cache
52+
{{ ydb-short-name }} caches query compilation results on the server side for efficiency. For small queries like:
53+
```sql
54+
SELECT 1;
55+
```
56+
compilation can take up to a hundred times more CPU time than the execution. The cache entry is searched by the text of the query and some additional parameters such as a user SID.
57+
58+
The cache is updated by {{ ydb-short-name }} automatically to stay on track with the changes made to the objects that the query references. However, in the case of views the cache is not updated in the same transaction in which the object's definition has changed. It happens with a little delay.
59+
60+
### Problem statement
61+
62+
Imagine the following sitiuation:
63+
64+
Alice continiously executes the following query:
65+
```sql
66+
-- Alice's session
67+
SELECT * FROM some_view_which_is_going_to_be_redefined;
68+
```
69+
while Bob redefines the view's query like this:
70+
```sql
71+
-- Bob's session
72+
DROP VIEW some_view_which_is_going_to_be_redefined;
73+
CREATE VIEW some_view_which_is_going_to_be_redefined ...;
74+
```
75+
76+
The text of the Alice's query does not change, which means that the compilation will happen only once and the results are going to be taken from the cache since then. Bob changes the definition of the view and the cache entry for the Alice's query should theoretically be evicted from the cache in the same transaction, in which the view was redefined. However, this is not the case. The Alice's query will be recompiled with a little delay, which means that for a small period of time Alice's query will produce results inconsistent with the updated definition of the view. This is going to be fixed in the future releases.
Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,13 @@
1+
# ALTER VIEW
2+
3+
ALTER VIEW — change the definition of a view.
4+
5+
This feature is not supported yet. You can redefine a view like this:
6+
```sql
7+
DROP VIEW redifined_view;
8+
CREATE VIEW redifined_view ...;
9+
```
10+
11+
## See also
12+
13+
[CREATE VIEW](create_view), [DROP VIEW](drop_view)
Lines changed: 80 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,80 @@
1+
# CREATE VIEW
2+
3+
CREATE VIEW defines a view of a query.
4+
5+
A view is a logical representation of a table formed by the query, specified at the moment of the view's creation. The view does not physically store the table, but runs the query to produce the data whenever the view is selected from.
6+
7+
## Syntax
8+
9+
```sql
10+
CREATE VIEW name
11+
[ WITH ( view_option_name [= view_option_value] [, ... ] ) ]
12+
AS query
13+
```
14+
15+
### Parameters
16+
17+
* `name`
18+
19+
The name of the view to be created. The name must be distinct from the name of any other schema object.
20+
* `query`
21+
22+
The SELECT query, which will be used to produce the logical table the view represents.
23+
24+
`WITH ( view_option_name [= view_option_value] [, ... ] )`
25+
26+
This clause specifies optional parameters for a view. The following parameters are supported:
27+
28+
* `security_invoker` (Bool)
29+
30+
This option causes the underlying base relations to be checked against the privileges of the user of the view rather than the view owner.
31+
32+
## Notes
33+
34+
`security_invoker` option must be always set to true, because the default behavior for views is to execute the query on behalf of the view's creator, which is not supported yet.
35+
36+
The execution context of the view's query is different from the enclosing context of the SELECT from the view statement. It does not "see" previously defined PRAGMAs like TablePathPrefix, named expressions, etc. Most importantly, users must specify the tables (or views) they select from in the view's query by their schema-qualified names. You can see in the [examples](#examples) that the absolute path like `/domain/database/path/to/underlying_table` is used to specify the table, from which the view selects. We are going to change the context of the view's query compilation in the next releases.
37+
38+
The only way to specify the columns you want to see in the view is to select them in particular in the view's query. Star (\*) expansions in the view's query happens each time you recompile it. The columns returned by the following statement:
39+
```sql
40+
/*
41+
CREATE VIEW view_with_a_star WITH (security_invoker = TRUE) AS
42+
SELECT
43+
*
44+
FROM `/domain/database/path/to/underlying_table`;
45+
*/
46+
47+
SELECT * FROM view_with_a_star;
48+
```
49+
might change if the columns list of the `underlying_table` changes.
50+
51+
## Examples {#examples}
52+
53+
Create a view that will list only recent series from the series table:
54+
55+
```sql
56+
CREATE VIEW recent_series WITH (security_invoker = TRUE) AS
57+
SELECT
58+
*
59+
FROM `/domain/database/path/to/series`
60+
WHERE
61+
release_date > Date("2020-01-01");
62+
```
63+
64+
Create a view that will list the titles of the first episodes of the recent series:
65+
66+
```sql
67+
CREATE VIEW recent_series_first_episodes_titles WITH (security_invoker = TRUE) AS
68+
SELECT
69+
episodes.title AS first_episode
70+
FROM `/domain/database/path/to/recent_series`
71+
AS recent_series
72+
JOIN `/domain/database/path/to/episodes`
73+
AS episodes
74+
ON recent_series.series_id = episodes.series_id
75+
WHERE episodes.season_id = 1 AND episodes.episode_id = 1;
76+
```
77+
78+
## See also
79+
80+
[ALTER VIEW](alter_view), [DROP VIEW](drop_view)
Lines changed: 27 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,27 @@
1+
# DROP VIEW
2+
3+
DROP VIEW drops an existing view.
4+
5+
## Syntax
6+
7+
```sql
8+
DROP VIEW name
9+
```
10+
11+
### Parameters
12+
13+
* `name`
14+
15+
The name of the view to be deleted.
16+
17+
## Examples
18+
19+
The following command will drop the view named recent_series:
20+
21+
```sql
22+
DROP VIEW recent_series;
23+
```
24+
25+
## See also
26+
27+
[CREATE VIEW](create_view), [ALTER VIEW](alter_view)

ydb/docs/en/core/yql/reference/yql-core/syntax/toc_i.yaml

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -7,16 +7,19 @@ items:
77
- { name: ALTER TABLE, href: alter_table.md, when: feature_map_tables }
88
- { name: ALTER TOPIC, href: alter_topic.md, when: feature_topic_control_plane }
99
- { name: ALTER USER, href: alter-user.md, when: feature_user_and_group }
10+
- { name: ALTER VIEW, href: alter_view.md, when: feature_view }
1011
- { name: CREATE GROUP, href: create-group.md, when: feature_user_and_group }
1112
- { name: CREATE TABLE, href: create_table.md }
1213
- { name: CREATE TOPIC, href: create_topic.md, when: feature_topic_control_plane }
1314
- { name: CREATE USER, href: create-user.md, when: feature_user_and_group }
15+
- { name: CREATE VIEW, href: create_view.md, when: feature_view }
1416
- { name: DECLARE, href: declare.md }
1517
- { name: DELETE, href: delete.md, when: feature_map_tables }
1618
- { name: DISCARD, href: discard.md }
1719
- { name: DROP GROUP, href: drop-group.md, when: feature_user_and_group }
1820
- { name: DROP TABLE, href: drop_table.md }
1921
- { name: DROP USER, href: drop-user.md, when: feature_user_and_group }
22+
- { name: DROP VIEW, href: drop_view.md, when: feature_view }
2023
- { name: GROUP BY, href: group_by.md }
2124
- { name: EXPORT and IMPORT, href: export_import.md, when: feature_mapreduce }
2225
- { name: FLATTEN, href: flatten.md }

ydb/docs/presets.yaml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -19,6 +19,7 @@ default:
1919
feature_federated_queries: true
2020
# feature_topic_settings_reset: true
2121
# feature_logbroker: true
22+
feature_view: true
2223
ydb-full-name: YDB
2324
ydb-short-name: YDB
2425
yandex-cloud: Yandex.Cloud

ydb/docs/ru/core/concepts/datamodel/_includes/index.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -8,3 +8,4 @@
88
* [Секреты](../secrets.md)
99
* [Подключения к внешним БД](../external_data_source.md)
1010
* [Внешние источники данных](../external_table.md)
11+
* [Представления (VIEW)](../view.md)

ydb/docs/ru/core/concepts/datamodel/toc_i.yaml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -6,3 +6,4 @@ items:
66
- { name: Секреты, href: secrets.md }
77
- { name: Внешние источники данных, href: external_data_source.md }
88
- { name: Внешние таблицы, href: external_table.md }
9+
- { name: Представления, href: view.md }

0 commit comments

Comments
 (0)