-
Notifications
You must be signed in to change notification settings - Fork 960
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Add more warehouses to database permissions (#3943)
## What are you changing in this pull request and why? The proposed changes are regarding this issue raised last week: #3901 It would be nice to have more warehouses within References / warehouse permissions with sample grants, this PR aims to follow the already existing [Snowflake](https://docs.getdbt.com/reference/snowflake-permissions) example and add Databricks, Redshift, and Postgres as well (skipping BigQuery due to their unique IAM access control management) #Resolves #3824 ## Checklist <!-- Uncomment if you're publishing docs for a prerelease version of dbt (delete if not applicable): - [ ] Add versioning components, as described in [Versioning Docs](https://github.com/dbt-labs/docs.getdbt.com/blob/current/contributing/single-sourcing-content.md#versioning-entire-pages) - [ ] Add a note to the prerelease version [Migration Guide](https://github.com/dbt-labs/docs.getdbt.com/tree/current/website/docs/guides/migration/versions) --> - [x] Review the [Content style guide](https://github.com/dbt-labs/docs.getdbt.com/blob/current/contributing/content-style-guide.md) and [About versioning](https://github.com/dbt-labs/docs.getdbt.com/blob/current/contributing/single-sourcing-content.md#adding-a-new-version) so my content adheres to these guidelines. - [x] Add a checklist item for anything that needs to happen before this PR is merged, such as "needs technical review" or "change base branch." Adding new pages (delete if not applicable): - [x] Add page to `website/sidebars.js` - [x] Provide a unique filename for the new page - [x] Needs to have a technical review, at least to verify the proposed changes are correct and possibly expand with other examples. - [x] Tested it locally (npm run)
- Loading branch information
Showing
12 changed files
with
294 additions
and
31 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
36 changes: 36 additions & 0 deletions
36
website/docs/reference/database-permissions/about-database-permissions.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,36 @@ | ||
--- | ||
title: "Database permissions" | ||
id: about-database-permissions | ||
description: "Database permissions are access rights and privileges granted to users or roles within a database management system." | ||
sidebar_label: "About database permissions" | ||
pagination_next: "reference/database-permissions/databricks-permissions" | ||
pagination_prev: null | ||
--- | ||
|
||
Database permissions are access rights and privileges granted to users or roles within a database or data platform. They help you specify what actions users or roles can perform on various database objects, like tables, views, schemas, or even the entire database. | ||
|
||
|
||
### Why are they useful | ||
|
||
- Database permissions are essential for security and data access control. | ||
- They ensure that only authorized users can perform specific actions. | ||
- They help maintain data integrity, prevent unauthorized changes, and limit exposure to sensitive data. | ||
- Permissions also support compliance with data privacy regulations and auditing. | ||
|
||
### How to use them | ||
|
||
- Users and administrators can grant and manage permissions at various levels (such as table, schema, and so on) using SQL statements or through the database system's interface. | ||
- Assign permissions to individual users or roles (groups of users) based on their responsibilities. | ||
- Typical permissions include "SELECT" (read), "INSERT" (add data), "UPDATE" (modify data), "DELETE" (remove data), and administrative rights like "CREATE" and "DROP." | ||
- Users should be assigned permissions that ensure they have the necessary access to perform their tasks without overextending privileges. | ||
|
||
Something to note is that each data platform provider might have different approaches and names for privileges. Refer to their documentation for more details. | ||
|
||
### Examples | ||
|
||
Refer to the following database permission pages for more info on examples and how to set up database permissions: | ||
|
||
- [Databricks](/reference/database-permissions/databricks-permissions) | ||
- [Postgres](/reference/database-permissions/postgres-permissions) | ||
- [Redshift](/reference/database-permissions/redshift-permissions) | ||
- [Snowflake](/reference/database-permissions/snowflake-permissions) |
20 changes: 20 additions & 0 deletions
20
website/docs/reference/database-permissions/databricks-permissions.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,20 @@ | ||
--- | ||
title: "Databricks permissions" | ||
--- | ||
|
||
In Databricks, permissions are used to control who can perform certain actions on different database objects. Use SQL statements to manage permissions in a Databricks database. | ||
|
||
## Example Databricks permissions | ||
|
||
The following example provides you with the SQL statements you can use to manage permissions. | ||
|
||
**Note** that you can grant permissions on `securable_objects` to `principals` (This can be user, service principal, or group). For example, `grant privilege_type` on `securable_object` to `principal`. | ||
|
||
``` | ||
grant all privileges on schema schema_name to principal; | ||
grant create table on schema schema_name to principal; | ||
grant create view on schema schema_name to principal; | ||
``` | ||
|
||
Check out the [official documentation](https://docs.databricks.com/en/data-governance/unity-catalog/manage-privileges/privileges.html#privilege-types-by-securable-object-in-unity-catalog) for more information. |
25 changes: 25 additions & 0 deletions
25
website/docs/reference/database-permissions/postgres-permissions.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,25 @@ | ||
--- | ||
title: "Postgres Permissions" | ||
--- | ||
|
||
|
||
In Postgres, permissions are used to control who can perform certain actions on different database objects. Use SQL statements to manage permissions in a Postgres database. | ||
|
||
## Example Postgres permissions | ||
|
||
The following example provides you with the SQL statements you can use to manage permissions. These examples allow you to run dbt smoothly without encountering permission issues, such as creating schemas, reading existing data, and accessing the information schema. | ||
|
||
**Note** that `database_name`, `database.schema_name`, and `user_name` are placeholders and you can replace them as needed for your organization's naming convention. | ||
|
||
``` | ||
grant usage on database database_name to user_name; | ||
grant create schema on database database_name to user_name; | ||
grant usage on schema database.schema_name to user_name; | ||
grant create table on schema database.schema_name to user_name; | ||
grant create view on schema database.schema_name to user_name; | ||
grant usage on all schemas in database database_name to user_name; | ||
grant select on all tables in database database_name to user_name; | ||
grant select on all views in database database_name to user_name; | ||
``` | ||
|
||
Check out the [official documentation](https://www.postgresql.org/docs/current/sql-grant.html) for more information. |
25 changes: 25 additions & 0 deletions
25
website/docs/reference/database-permissions/redshift-permissions.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,25 @@ | ||
--- | ||
title: "Redshift permissions" | ||
--- | ||
|
||
In Redshift, permissions are used to control who can perform certain actions on different database objects. Use SQL statements to manage permissions in a Redshift database. | ||
|
||
## Example Redshift permissions | ||
|
||
The following example provides you with the SQL statements you can use to manage permissions. | ||
|
||
**Note** that `database_name`, `database.schema_name`, and `user_name` are placeholders and you can replace them as needed for your organization's naming convention. | ||
|
||
|
||
``` | ||
grant usage on database database_name to user_name; | ||
grant create schema on database database_name to user_name; | ||
grant usage on schema database.schema_name to user_name; | ||
grant create table on schema database.schema_name to user_name; | ||
grant create view on schema database.schema_name to user_name; | ||
grant usage on all schemas in database database_name to user_name; | ||
grant select on all tables in database database_name to user_name; | ||
grant select on all views in database database_name to user_name; | ||
``` | ||
|
||
Check out the [official documentation](https://docs.aws.amazon.com/redshift/latest/dg/r_GRANT.html) for more information. |
154 changes: 154 additions & 0 deletions
154
website/docs/reference/database-permissions/snowflake-permissions.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,154 @@ | ||
--- | ||
title: "Snowflake permissions" | ||
--- | ||
|
||
In Snowflake, permissions are used to control who can perform certain actions on different database objects. Use SQL statements to manage permissions in a Snowflake database. | ||
|
||
## Set up Snowflake account | ||
|
||
This section explains how to set up permissions and roles within Snowflake. In Snowflake, you would perform these actions using SQL commands and set up your data warehouse and access control within Snowflake's ecosystem. | ||
|
||
1. Set up databases | ||
``` | ||
use role sysadmin; | ||
create database raw; | ||
create database analytics; | ||
``` | ||
2. Set up warehouses | ||
``` | ||
create warehouse loading | ||
warehouse_size = xsmall | ||
auto_suspend = 3600 | ||
auto_resume = false | ||
initially_suspended = true; | ||
create warehouse transforming | ||
warehouse_size = xsmall | ||
auto_suspend = 60 | ||
auto_resume = true | ||
initially_suspended = true; | ||
create warehouse reporting | ||
warehouse_size = xsmall | ||
auto_suspend = 60 | ||
auto_resume = true | ||
initially_suspended = true; | ||
``` | ||
|
||
3. Set up roles and warehouse permissions | ||
``` | ||
use role securityadmin; | ||
create role loader; | ||
grant all on warehouse loading to role loader; | ||
create role transformer; | ||
grant all on warehouse transforming to role transformer; | ||
create role reporter; | ||
grant all on warehouse reporting to role reporter; | ||
``` | ||
|
||
4. Create users, assigning them to their roles | ||
|
||
Every person and application gets a separate user and is assigned to the correct role. | ||
|
||
``` | ||
create user stitch_user -- or fivetran_user | ||
password = '_generate_this_' | ||
default_warehouse = loading | ||
default_role = loader; | ||
create user claire -- or amy, jeremy, etc. | ||
password = '_generate_this_' | ||
default_warehouse = transforming | ||
default_role = transformer | ||
must_change_password = true; | ||
create user dbt_cloud_user | ||
password = '_generate_this_' | ||
default_warehouse = transforming | ||
default_role = transformer; | ||
create user looker_user -- or mode_user etc. | ||
password = '_generate_this_' | ||
default_warehouse = reporting | ||
default_role = reporter; | ||
-- then grant these roles to each user | ||
grant role loader to user stitch_user; -- or fivetran_user | ||
grant role transformer to user dbt_cloud_user; | ||
grant role transformer to user claire; -- or amy, jeremy | ||
grant role reporter to user looker_user; -- or mode_user, periscope_user | ||
``` | ||
|
||
5. Let loader load data | ||
Give the role unilateral permission to operate on the raw database | ||
``` | ||
use role sysadmin; | ||
grant all on database raw to role loader; | ||
``` | ||
|
||
6. Let transformer transform data | ||
The transformer role needs to be able to read raw data. | ||
|
||
If you do this before you have any data loaded, you can run: | ||
``` | ||
grant usage on database raw to role transformer; | ||
grant usage on future schemas in database raw to role transformer; | ||
grant select on future tables in database raw to role transformer; | ||
grant select on future views in database raw to role transformer; | ||
``` | ||
If you already have data loaded in the raw database, make sure also you run the following to update the permissions | ||
``` | ||
grant usage on all schemas in database raw to role transformer; | ||
grant select on all tables in database raw to role transformer; | ||
grant select on all views in database raw to role transformer; | ||
``` | ||
transformer also needs to be able to create in the analytics database: | ||
``` | ||
grant all on database analytics to role transformer; | ||
``` | ||
7. Let reporter read the transformed data | ||
A previous version of this article recommended this be implemented through hooks in dbt, but this way lets you get away with a one-off statement. | ||
``` | ||
grant usage on database analytics to role reporter; | ||
grant usage on future schemas in database analytics to role reporter; | ||
grant select on future tables in database analytics to role reporter; | ||
grant select on future views in database analytics to role reporter; | ||
``` | ||
Again, if you already have data in your analytics database, make sure you run: | ||
``` | ||
grant usage on all schemas in database analytics to role reporter; | ||
grant select on all tables in database analytics to role transformer; | ||
grant select on all views in database analytics to role transformer; | ||
``` | ||
8. Maintain | ||
When new users are added, make sure you add them to the right role! Everything else should be inherited automatically thanks to those `future` grants. | ||
|
||
For more discussion and legacy information, refer to [this Discourse article](https://discourse.getdbt.com/t/setting-up-snowflake-the-exact-grant-statements-we-run/439). | ||
|
||
## Example Snowflake permissions | ||
|
||
The following example provides you with the SQL statements you can use to manage permissions. | ||
|
||
**Note** that `warehouse_name`, `database_name`, and `role_name` are placeholders and you can replace them as needed for your organization's naming convention. | ||
|
||
``` | ||
grant all on warehouse warehouse_name to role role_name; | ||
grant usage on database database_name to role role_name; | ||
grant create schema on database database_name to role role_name; | ||
grant usage on schema database.an_existing_schema to role role_name; | ||
grant create table on schema database.an_existing_schema to role role_name; | ||
grant create view on schema database.an_existing_schema to role role_name; | ||
grant usage on future schemas in database database_name to role role_name; | ||
grant monitor on future schemas in database database_name to role role_name; | ||
grant select on future tables in database database_name to role role_name; | ||
grant select on future views in database database_name to role role_name; | ||
grant usage on all schemas in database database_name to role role_name; | ||
grant monitor on all schemas in database database_name to role role_name; | ||
grant select on all tables in database database_name to role role_name; | ||
grant select on all views in database database_name to role role_name; | ||
``` | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file was deleted.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters