Skip to content

Commit

Permalink
Add definers for views (Attempt 2) (ClickHouse#60439)
Browse files Browse the repository at this point in the history
  • Loading branch information
pufit authored Feb 28, 2024
1 parent 90c9ae1 commit 330a206
Show file tree
Hide file tree
Showing 69 changed files with 1,317 additions and 350 deletions.
12 changes: 12 additions & 0 deletions docs/en/operations/server-configuration-parameters/settings.md
Original file line number Diff line number Diff line change
Expand Up @@ -2927,3 +2927,15 @@ If set to true, then alter operations will be surrounded by parentheses in forma
Type: Bool

Default: 0

## ignore_empty_sql_security_in_create_view_query {#ignore_empty_sql_security_in_create_view_query}

If true, ClickHouse doesn't write defaults for empty SQL security statement in CREATE VIEW queries.

:::note
This setting is only necessary for the migration period and will become obsolete in 24.4
:::

Type: Bool

Default: 1
18 changes: 18 additions & 0 deletions docs/en/operations/settings/settings.md
Original file line number Diff line number Diff line change
Expand Up @@ -5378,6 +5378,24 @@ SELECT map('a', range(number), 'b', number, 'c', 'str_' || toString(number)) as

Default value: `false`.

## default_normal_view_sql_security {#default_normal_view_sql_security}

Allows to set default `SQL SECURITY` option while creating a normal view. [More about SQL security](../../sql-reference/statements/create/view.md#sql_security).

The default value is `INVOKER`.

## default_materialized_view_sql_security {#default_materialized_view_sql_security}

Allows to set a default value for SQL SECURITY option when creating a materialized view. [More about SQL security](../../sql-reference/statements/create/view.md#sql_security).

The default value is `DEFINER`.

## default_view_definer {#default_view_definer}

Allows to set default `DEFINER` option while creating a view. [More about SQL security](../../sql-reference/statements/create/view.md#sql_security).

The default value is `CURRENT_USER`.

## max_partition_size_to_drop

Restriction on dropping partitions in query time. The value 0 means that you can drop partitions without any restrictions.
Expand Down
51 changes: 49 additions & 2 deletions docs/en/sql-reference/statements/create/view.md
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,9 @@ Creates a new view. Views can be [normal](#normal-view), [materialized](#materia
Syntax:

``` sql
CREATE [OR REPLACE] VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER cluster_name] AS SELECT ...
CREATE [OR REPLACE] VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER cluster_name]
[DEFINER = { user | CURRENT_USER }] [SQL SECURITY { DEFINER | INVOKER | NONE }]
AS SELECT ...
```

Normal views do not store any data. They just perform a read from another table on each access. In other words, a normal view is nothing more than a saved query. When reading from a view, this saved query is used as a subquery in the [FROM](../../../sql-reference/statements/select/from.md) clause.
Expand Down Expand Up @@ -52,7 +54,9 @@ SELECT * FROM view(column1=value1, column2=value2 ...)
## Materialized View

``` sql
CREATE MATERIALIZED VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER] [TO[db.]name] [ENGINE = engine] [POPULATE] AS SELECT ...
CREATE MATERIALIZED VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER] [TO[db.]name] [ENGINE = engine] [POPULATE]
[DEFINER = { user | CURRENT_USER }] [SQL SECURITY { DEFINER | INVOKER | NONE }]
AS SELECT ...
```

:::tip
Expand Down Expand Up @@ -91,6 +95,49 @@ Views look the same as normal tables. For example, they are listed in the result

To delete a view, use [DROP VIEW](../../../sql-reference/statements/drop.md#drop-view). Although `DROP TABLE` works for VIEWs as well.

## SQL security {#sql_security}

`DEFINER` and `SQL SECURITY` allow you to specify which ClickHouse user to use when executing the view's underlying query.
`SQL SECURITY` has three legal values: `DEFINER`, `INVOKER`, or `NONE`. You can specify any existing user or `CURRENT_USER` in the `DEFINER` clause.

The following table will explain which rights are required for which user in order to select from view.
Note that regardless of the SQL security option, in every case it is still required to have `GRANT SELECT ON <view>` in order to read from it.

| SQL security option | View | Materialized View |
|---------------------|-----------------------------------------------------------------|-------------------------------------------------------------------------------------------------------------------|
| `DEFINER alice` | `alice` must have a `SELECT` grant for the view's source table. | `alice` must have a `SELECT` grant for the view's source table and an `INSERT` grant for the view's target table. |
| `INVOKER` | User must have a `SELECT` grant for the view's source table. | `SQL SECURITY INVOKER` can't be specified for materialized views. |
| `NONE` | - | - |

:::note
`SQL SECURITY NONE` is a deprecated option. Any user with the rights to create views with `SQL SECURITY NONE` will be able to execute any arbitrary query.
Thus, it is required to have `GRANT ALLOW SQL SECURITY NONE TO <user>` in order to create a view with this option.
:::

If `DEFINER`/`SQL SECURITY` aren't specified, the default values are used:
- `SQL SECURITY`: `INVOKER` for normal views and `DEFINER` for materialized views ([configurable by settings](../../../operations/settings/settings.md#default_normal_view_sql_security))
- `DEFINER`: `CURRENT_USER` ([configurable by settings](../../../operations/settings/settings.md#default_view_definer))

If a view is attached without `DEFINER`/`SQL SECURITY` specified, the default value is `SQL SECURITY NONE` for the materialized view and `SQL SECURITY INVOKER` for the normal view.

To change SQL security for an existing view, use
```sql
ALTER TABLE MODIFY SQL SECURITY { DEFINER | INVOKER | NONE } [DEFINER = { user | CURRENT_USER }]
```

### Examples sql security
```sql
CREATE test_view
DEFINER = alice SQL SECURITY DEFINER
AS SELECT ...
```

```sql
CREATE test_view
SQL SECURITY INVOKER
AS SELECT ...
```

## Live View [Deprecated]

This feature is deprecated and will be removed in the future.
Expand Down
3 changes: 3 additions & 0 deletions docs/en/sql-reference/statements/grant.md
Original file line number Diff line number Diff line change
Expand Up @@ -114,6 +114,7 @@ Hierarchy of privileges:
- `ALTER VIEW`
- `ALTER VIEW REFRESH`
- `ALTER VIEW MODIFY QUERY`
- `ALTER VIEW MODIFY SQL SECURITY`
- [CREATE](#grant-create)
- `CREATE DATABASE`
- `CREATE TABLE`
Expand Down Expand Up @@ -307,6 +308,7 @@ Allows executing [ALTER](../../sql-reference/statements/alter/index.md) queries
- `ALTER VIEW` Level: `GROUP`
- `ALTER VIEW REFRESH`. Level: `VIEW`. Aliases: `ALTER LIVE VIEW REFRESH`, `REFRESH VIEW`
- `ALTER VIEW MODIFY QUERY`. Level: `VIEW`. Aliases: `ALTER TABLE MODIFY QUERY`
- `ALTER VIEW MODIFY SQL SECURITY`. Level: `VIEW`. Aliases: `ALTER TABLE MODIFY SQL SECURITY`

Examples of how this hierarchy is treated:

Expand Down Expand Up @@ -409,6 +411,7 @@ Allows a user to execute queries that manage users, roles and row policies.
- `SHOW_ROW_POLICIES`. Level: `GLOBAL`. Aliases: `SHOW POLICIES`, `SHOW CREATE ROW POLICY`, `SHOW CREATE POLICY`
- `SHOW_QUOTAS`. Level: `GLOBAL`. Aliases: `SHOW CREATE QUOTA`
- `SHOW_SETTINGS_PROFILES`. Level: `GLOBAL`. Aliases: `SHOW PROFILES`, `SHOW CREATE SETTINGS PROFILE`, `SHOW CREATE PROFILE`
- `ALLOW SQL SECURITY NONE`. Level: `GLOBAL`. Aliases: `CREATE SQL SECURITY NONE`, `SQL SECURITY NONE`, `SECURITY NONE`

The `ROLE ADMIN` privilege allows a user to assign and revoke any roles including those which are not assigned to the user with the admin option.

Expand Down
54 changes: 52 additions & 2 deletions docs/ru/sql-reference/statements/create/view.md
Original file line number Diff line number Diff line change
Expand Up @@ -11,7 +11,9 @@ sidebar_label: "Представление"
## Обычные представления {#normal}

``` sql
CREATE [OR REPLACE] VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER cluster_name] AS SELECT ...
CREATE [OR REPLACE] VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER cluster_name]
[DEFINER = { user | CURRENT_USER }] [SQL SECURITY { DEFINER | INVOKER | NONE }]
AS SELECT ...
```

Обычные представления не хранят никаких данных, они выполняют чтение данных из другой таблицы при каждом доступе. Другими словами, обычное представление — это не что иное, как сохраненный запрос. При чтении данных из представления этот сохраненный запрос используется как подзапрос в секции [FROM](../../../sql-reference/statements/select/from.md).
Expand All @@ -37,7 +39,9 @@ SELECT a, b, c FROM (SELECT ...)
## Материализованные представления {#materialized}

``` sql
CREATE MATERIALIZED VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER] [TO[db.]name] [ENGINE = engine] [POPULATE] AS SELECT ...
CREATE MATERIALIZED VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER] [TO[db.]name] [ENGINE = engine] [POPULATE]
[DEFINER = { user | CURRENT_USER }] [SQL SECURITY { DEFINER | INVOKER | NONE }]
AS SELECT ...
```

Материализованные (MATERIALIZED) представления хранят данные, преобразованные соответствующим запросом [SELECT](../../../sql-reference/statements/select/index.md).
Expand Down Expand Up @@ -66,6 +70,52 @@ CREATE MATERIALIZED VIEW [IF NOT EXISTS] [db.]table_name [ON CLUSTER] [TO[db.]na

Чтобы удалить представление, следует использовать [DROP VIEW](../../../sql-reference/statements/drop.md#drop-view). Впрочем, `DROP TABLE` тоже работает для представлений.

## SQL безопасность {#sql_security}

Параметры `DEFINER` и `SQL SECURITY` позволяют задать правило от имени какого пользователя будут выполняться запросы к таблицам, на которые ссылается представление.
Для `SQL SECURITY` допустимо три значения: `DEFINER`, `INVOKER`, или `NONE`.
Для `DEFINER` можно указать имя любого существующего пользователя или же `CURRENT_USER`.

Далее приведена таблица, объясняющая какие права необходимы каким пользователям при заданных параметрах SQL безопасности.
Обратите внимание, что, в независимости от заданных параметров SQL безопасности,
у пользователя должно быть право `GRANT SELECT ON <view>` для чтения из представления.

| SQL security option | View | Materialized View |
|---------------------|----------------------------------------------------------------------------------------------------|--------------------------------------------------------------------------------------------|
| `DEFINER alice` | У `alice` должно быть право `SELECT` на таблицу-источник. | У `alice` должны быть права `SELECT` на таблицу-источник и `INSERT` на таблицу-назначение. |
| `INVOKER` | У пользователя выполняющего запрос к представлению должно быть право `SELECT` на таблицу-источник. | Тип `SQL SECURITY INVOKER` не может быть указан для материализованных представлений. |
| `NONE` | - | - |

:::note
Тип `SQL SECURITY NONE` не безопасен для использования. Любой пользователь с правом создавать представления с `SQL SECURITY NONE` сможет исполнять любые запросы без проверки прав.
По умолчанию, у пользователей нет прав указывать `SQL SECURITY NONE`, однако, при необходимости, это право можно выдать с помощью `GRANT ALLOW SQL SECURITY NONE TO <user>`.
:::

Если `DEFINER`/`SQL SECURITY` не указан, будут использованы значения по умолчанию:
- `SQL SECURITY`: `INVOKER` для обычных представлений и `DEFINER` для материализованных ([изменяется в настройках](../../../operations/settings/settings.md#default_normal_view_sql_security))
- `DEFINER`: `CURRENT_USER` ([изменяется в настройках](../../../operations/settings/settings.md#default_view_definer))

Если представление подключается с помощью ключевого слова `ATTACH` и настройки SQL безопасности не были заданы,
то по умолчанию будет использоваться `SQL SECURITY NONE` для материализованных представлений и `SQL SECURITY INVOKER` для обычных.

Изменить параметры SQL безопасности возможно с помощью следующего запроса:
```sql
ALTER TABLE MODIFY SQL SECURITY { DEFINER | INVOKER | NONE } [DEFINER = { user | CURRENT_USER }]
```

### Примеры представлений с SQL безопасностью
```sql
CREATE test_view
DEFINER = alice SQL SECURITY DEFINER
AS SELECT ...
```

```sql
CREATE test_view
SQL SECURITY INVOKER
AS SELECT ...
```

## LIVE-представления [экспериментальный функционал] {#live-view}

:::note Важно
Expand Down
16 changes: 13 additions & 3 deletions src/Access/Common/AccessFlags.cpp
Original file line number Diff line number Diff line change
Expand Up @@ -103,6 +103,7 @@ namespace
const Flags & getColumnFlags() const { return all_flags_for_target[COLUMN]; }
const Flags & getDictionaryFlags() const { return all_flags_for_target[DICTIONARY]; }
const Flags & getNamedCollectionFlags() const { return all_flags_for_target[NAMED_COLLECTION]; }
const Flags & getUserNameFlags() const { return all_flags_for_target[USER_NAME]; }
const Flags & getAllFlagsGrantableOnGlobalLevel() const { return getAllFlags(); }
const Flags & getAllFlagsGrantableOnGlobalWithParameterLevel() const { return getGlobalWithParameterFlags(); }
const Flags & getAllFlagsGrantableOnDatabaseLevel() const { return all_flags_grantable_on_database_level; }
Expand All @@ -121,6 +122,7 @@ namespace
COLUMN,
DICTIONARY,
NAMED_COLLECTION,
USER_NAME,
};

struct Node;
Expand Down Expand Up @@ -300,7 +302,7 @@ namespace
collectAllFlags(child.get());

all_flags_grantable_on_table_level = all_flags_for_target[TABLE] | all_flags_for_target[DICTIONARY] | all_flags_for_target[COLUMN];
all_flags_grantable_on_global_with_parameter_level = all_flags_for_target[NAMED_COLLECTION];
all_flags_grantable_on_global_with_parameter_level = all_flags_for_target[NAMED_COLLECTION] | all_flags_for_target[USER_NAME];
all_flags_grantable_on_database_level = all_flags_for_target[DATABASE] | all_flags_grantable_on_table_level;
}

Expand Down Expand Up @@ -351,7 +353,7 @@ namespace
std::unordered_map<std::string_view, Flags> keyword_to_flags_map;
std::vector<Flags> access_type_to_flags_mapping;
Flags all_flags;
Flags all_flags_for_target[static_cast<size_t>(NAMED_COLLECTION) + 1];
Flags all_flags_for_target[static_cast<size_t>(USER_NAME) + 1];
Flags all_flags_grantable_on_database_level;
Flags all_flags_grantable_on_table_level;
Flags all_flags_grantable_on_global_with_parameter_level;
Expand All @@ -371,7 +373,11 @@ std::unordered_map<AccessFlags::ParameterType, AccessFlags> AccessFlags::splitIn
if (named_collection_flags)
result.emplace(ParameterType::NAMED_COLLECTION, named_collection_flags);

auto other_flags = (~AccessFlags::allNamedCollectionFlags()) & *this;
auto user_flags = AccessFlags::allUserNameFlags() & *this;
if (user_flags)
result.emplace(ParameterType::USER_NAME, user_flags);

auto other_flags = (~named_collection_flags & ~user_flags) & *this;
if (other_flags)
result.emplace(ParameterType::NONE, other_flags);

Expand All @@ -387,6 +393,9 @@ AccessFlags::ParameterType AccessFlags::getParameterType() const
if (AccessFlags::allNamedCollectionFlags().contains(*this))
return AccessFlags::NAMED_COLLECTION;

if (AccessFlags::allUserNameFlags().contains(*this))
return AccessFlags::USER_NAME;

throw Exception(ErrorCodes::MIXED_ACCESS_PARAMETER_TYPES, "Having mixed parameter types: {}", toString());
}

Expand All @@ -405,6 +414,7 @@ AccessFlags AccessFlags::allTableFlags() { return Helper::instance().getTableFla
AccessFlags AccessFlags::allColumnFlags() { return Helper::instance().getColumnFlags(); }
AccessFlags AccessFlags::allDictionaryFlags() { return Helper::instance().getDictionaryFlags(); }
AccessFlags AccessFlags::allNamedCollectionFlags() { return Helper::instance().getNamedCollectionFlags(); }
AccessFlags AccessFlags::allUserNameFlags() { return Helper::instance().getUserNameFlags(); }
AccessFlags AccessFlags::allFlagsGrantableOnGlobalLevel() { return Helper::instance().getAllFlagsGrantableOnGlobalLevel(); }
AccessFlags AccessFlags::allFlagsGrantableOnGlobalWithParameterLevel() { return Helper::instance().getAllFlagsGrantableOnGlobalWithParameterLevel(); }
AccessFlags AccessFlags::allFlagsGrantableOnDatabaseLevel() { return Helper::instance().getAllFlagsGrantableOnDatabaseLevel(); }
Expand Down
4 changes: 4 additions & 0 deletions src/Access/Common/AccessFlags.h
Original file line number Diff line number Diff line change
Expand Up @@ -57,6 +57,7 @@ class AccessFlags
{
NONE,
NAMED_COLLECTION,
USER_NAME,
};
ParameterType getParameterType() const;
std::unordered_map<ParameterType, AccessFlags> splitIntoParameterTypes() const;
Expand Down Expand Up @@ -103,6 +104,9 @@ class AccessFlags
/// Returns all the flags related to a named collection.
static AccessFlags allNamedCollectionFlags();

/// Returns all the flags related to a user.
static AccessFlags allUserNameFlags();

/// Returns all the flags which could be granted on the global level.
/// The same as allFlags().
static AccessFlags allFlagsGrantableOnGlobalLevel();
Expand Down
Loading

0 comments on commit 330a206

Please sign in to comment.