forked from Montreal-Analytics/dbt-snowflake-utils
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
feat: clone with new owner (Montreal-Analytics#27)
* feat: clone with new owner * chore: add more doc and comments * feat: simplify the functions * fix: update ownership model * rename macro * style * qualify macros * typos
- Loading branch information
Showing
9 changed files
with
247 additions
and
20 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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,35 @@ | ||
# 2-Step dbt Cloning Pattern | ||
|
||
_Credit: [This cloning pattern is inspired by Dan Gooden’s article here from the Airtasker Tribe blog.](https://medium.com/airtribe/test-sql-pipelines-against-production-clones-using-dbt-and-snowflake-2f8293722dd4)_ | ||
|
||
Cloning is a cost- and time-efficient way of developing dbt models on Snowflake but it can be challenging when your cloning needs traverse different environments with different access controls: i.e. you want to clone a production database for use in development. | ||
|
||
A solution for this is to run a 2-step cloning pattern: | ||
|
||
1. A production role clones the production database or schema and then changes the ownership of its sub-objects to a developer role, thus creating a developer clone of production. The cloned object is still owned by the production role (which preserves the privilege to drop or replace that clone), but now the developer role has full access of its sub-objects. | ||
2. Developer users use the developer role to clone that developer clone database or schema, thus creating a new personal developer clone for development. The developer role has full ownership of this cloned database and all its sub-objects. | ||
|
||
This pattern can be used for cloning a schema or a database. If all the dbt models are stored within a single schema, schema-level cloning is a good option. When dbt is configured to write data to multiple schemata, database-level cloning is a good, more production-like option. | ||
|
||
This patterns optimizes for the following: | ||
|
||
- **Access Control:** no need to compromise on your access control system, such as by allowing your developer role to have extensive access on production. This pattern takes environmental separation as a given. | ||
- **Flexible Availability:** step 1 can be run on any preferred schedule: the developer clone could be updated hourly, daily, weekly, or any other cadence. This first clone is ideally run after a complete execution of dbt for the freshest data possible. | ||
- **Developer Flexibility:** developers can take personal clones whenever they need to and can even take multiple clones if they have need of more than one concurrent development environment. These developer clones are ideally commonly rotated to keep data fresh and production-like. | ||
|
||
## Setup: | ||
|
||
1. Update one of your production jobs to include step 1 of the cloning pattern. Here is an example implementation for database-level cloning from production to production_clone: | ||
|
||
```bash | ||
dbt build && | ||
dbt run-operation clone_database \ | ||
--args "{'source_database': 'production', 'destination_database': 'production_clone', 'new_owner_role': 'developer_role'}" | ||
``` | ||
|
||
2. As needed, locally run step 2 of the cloning pattern to create or update personal development clones. Here is an example implementation for database-level cloning from production_clone to an ephemeral database called developer_clone_me: | ||
|
||
```bash | ||
dbt run-operation clone_database \ | ||
--args "{'source_database': 'production_clone', 'destination_database': 'developer_clone_me'}" | ||
``` |
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,64 @@ | ||
{# | ||
-- This macro clones the source database into the destination database and | ||
-- optionally grants ownership over it, its schemata, and its schemata's tables | ||
-- and views to a new owner. | ||
#} | ||
{% macro clone_database( | ||
source_database, | ||
destination_database, | ||
new_owner_role='' | ||
) %} | ||
|
||
{% if source_database and destination_database %} | ||
|
||
{{ (log("Cloning existing database " ~ source_database ~ | ||
" into database " ~ destination_database, info=True)) }} | ||
|
||
{% call statement('clone_database', fetch_result=True, auto_begin=False) -%} | ||
CREATE OR REPLACE DATABASE {{ destination_database }} | ||
CLONE {{ source_database }}; | ||
{%- endcall %} | ||
|
||
{%- set result = load_result('clone_database') -%} | ||
{{ log(result['data'][0][0], info=True)}} | ||
|
||
{% else %} | ||
|
||
{{ exceptions.raise_compiler_error("Invalid arguments. Missing source database and/or destination database") }} | ||
|
||
{% endif %} | ||
|
||
{% if new_owner_role != '' %} | ||
|
||
{% set list_schemas_query %} | ||
-- get all schemata within the cloned database to then iterate through them and | ||
-- change their ownership | ||
SELECT schema_name | ||
FROM {{ destination_database }}.information_schema.schemata | ||
WHERE schema_name != 'INFORMATION_SCHEMA' | ||
{% endset %} | ||
|
||
{% set results = run_query(list_schemas_query) %} | ||
|
||
{% if execute %} | ||
{# Return the first column #} | ||
{% set schemata_list = results.columns[0].values() %} | ||
{% else %} | ||
{% set schemata_list = [] %} | ||
{% endif %} | ||
|
||
{% for schema_name in schemata_list %} | ||
|
||
{{ snowflake_utils.grant_ownership_on_schema_objects(new_owner_role, schema_name, destination_database) }} | ||
|
||
{% endfor %} | ||
|
||
{{ log("Grant ownership on " ~ destination_database ~ " to " ~ new_owner_role, info=True)}} | ||
|
||
{% call statement('clone_database', fetch_result=True, auto_begin=False) -%} | ||
GRANT ALL PRIVILEGES ON DATABASE {{ destination_database }} TO {{ new_owner_role }}; | ||
{%- endcall %} | ||
|
||
{% endif %} | ||
|
||
{% endmacro %} |
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,23 @@ | ||
{# | ||
-- This macro drops a database. | ||
#} | ||
{% macro drop_database(database_name) %} | ||
|
||
{% if database_name %} | ||
|
||
{{ log("Dropping database " ~ database_name ~ "...", info=True) }} | ||
|
||
{% call statement('drop_database', fetch_result=True, auto_begin=False) -%} | ||
DROP DATABASE {{ database_name }} | ||
{%- endcall %} | ||
|
||
{%- set result = load_result('drop_database') -%} | ||
{{ log(result['data'][0][0], info=True)}} | ||
|
||
{% else %} | ||
|
||
{{ exceptions.raise_compiler_error("Invalid arguments. Missing database name") }} | ||
|
||
{% endif %} | ||
|
||
{% endmacro %} |
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,36 @@ | ||
{# | ||
-- This macro grants ownership over a schema's tables and views and is | ||
-- optionally called by the clone_schema and clone_database macros. | ||
#} | ||
{% macro grant_ownership_on_schema_objects( | ||
new_owner_role, | ||
destination_schema, | ||
destination_database=target.database | ||
) %} | ||
|
||
{% if new_owner_role and destination_schema %} | ||
|
||
{{ (log("Granting ownership on " ~ destination_database ~ "." ~ destination_schema ~ | ||
" and its tables and views to " ~ new_owner_role, info=True)) }} | ||
|
||
{% call statement('grant_ownership_on_schema_objects', fetch_result=True, auto_begin=False) -%} | ||
GRANT USAGE ON SCHEMA {{ destination_database }}.{{ destination_schema }} | ||
TO {{ new_owner_role }}; | ||
GRANT OWNERSHIP ON ALL TABLES IN SCHEMA {{ destination_database }}.{{ destination_schema }} | ||
TO {{ new_owner_role }} REVOKE CURRENT GRANTS; | ||
GRANT OWNERSHIP ON ALL VIEWS IN SCHEMA {{ destination_database }}.{{ destination_schema }} | ||
TO {{ new_owner_role }} REVOKE CURRENT GRANTS; | ||
GRANT ALL PRIVILEGES ON SCHEMA {{ destination_database }}.{{ destination_schema }} | ||
TO {{ new_owner_role }}; | ||
{%- endcall %} | ||
|
||
{%- set result = load_result('grant_ownership_on_schema_objects') -%} | ||
{{ log(result['data'][0][0], info=True)}} | ||
|
||
{% else %} | ||
|
||
{{ exceptions.raise_compiler_error("Invalid arguments. Missing new owner role and/or destination schema") }} | ||
|
||
{% endif %} | ||
|
||
{% endmacro %} |
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 |
---|---|---|
@@ -1,3 +1,3 @@ | ||
packages: | ||
- package: dbt-labs/dbt_utils | ||
version: ">=0.7.0" | ||
version: [">=0.7.0", "<1.1.0"] |