From 971d555dffb9d002eb5a9565dc4369b911d170b0 Mon Sep 17 00:00:00 2001 From: Jack Forgash <58153492+forgxyz@users.noreply.github.com> Date: Wed, 6 Dec 2023 13:12:46 -0700 Subject: [PATCH] update prod clone macro (#240) --- macros/sp_create_prod_clone.sql | 75 +++++++++------------------------ 1 file changed, 19 insertions(+), 56 deletions(-) diff --git a/macros/sp_create_prod_clone.sql b/macros/sp_create_prod_clone.sql index 65aaadd..0ab8bf9 100644 --- a/macros/sp_create_prod_clone.sql +++ b/macros/sp_create_prod_clone.sql @@ -8,63 +8,26 @@ as $$ snowflake.execute({sqlText: `BEGIN TRANSACTION;`}); try { - snowflake.execute({sqlText: `DROP DATABASE IF EXISTS ${DESTINATION_DB_NAME}`}); - snowflake.execute({sqlText: `CREATE DATABASE ${DESTINATION_DB_NAME} CLONE ${SOURCE_DB_NAME}`}); - snowflake.execute({sqlText: `DROP SCHEMA ${DESTINATION_DB_NAME}._INTERNAL`}); /* this only needs to be in prod */ + snowflake.execute({sqlText: `CREATE OR REPLACE DATABASE ${DESTINATION_DB_NAME} CLONE ${SOURCE_DB_NAME}`}); + snowflake.execute({sqlText: `DROP SCHEMA IF EXISTS ${DESTINATION_DB_NAME}._INTERNAL`}); /* this only needs to be in prod */ + snowflake.execute({sqlText: `GRANT USAGE ON DATABASE ${DESTINATION_DB_NAME} TO AWS_LAMBDA_ETHEREUM_API`}); - var existing_schemas = snowflake.execute({sqlText: `SELECT table_schema - FROM ${DESTINATION_DB_NAME}.INFORMATION_SCHEMA.TABLE_PRIVILEGES - WHERE grantor IS NOT NULL - GROUP BY 1;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL SCHEMAS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL FUNCTIONS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL PROCEDURES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL VIEWS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL STAGES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL TABLES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE FUNCTIONS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE PROCEDURES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE VIEWS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE STAGES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE TABLES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT USAGE ON ALL STAGES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE AWS_LAMBDA_ETHEREUM_API;`}); - while (existing_schemas.next()) { - var schema = existing_schemas.getColumnValue(1) - snowflake.execute({sqlText: `GRANT OWNERSHIP ON SCHEMA ${DESTINATION_DB_NAME}.${schema} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); - } + snowflake.execute({sqlText: `GRANT OWNERSHIP ON DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}) - var existing_tables = snowflake.execute({sqlText: `SELECT table_schema, table_name - FROM ${DESTINATION_DB_NAME}.INFORMATION_SCHEMA.TABLE_PRIVILEGES - WHERE grantor IS NOT NULL - GROUP BY 1,2;`}); - - while (existing_tables.next()) { - var schema = existing_tables.getColumnValue(1) - var table_name = existing_tables.getColumnValue(2) - snowflake.execute({sqlText: `GRANT OWNERSHIP ON TABLE ${DESTINATION_DB_NAME}.${schema}.${table_name} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); - } - - var existing_stages = snowflake.execute({sqlText: `SELECT stage_schema, stage_name - FROM ${DESTINATION_DB_NAME}.INFORMATION_SCHEMA.STAGES;`}); - - while (existing_stages.next()) { - var schema = existing_stages.getColumnValue(1) - var stage_name = existing_stages.getColumnValue(2) - snowflake.execute({sqlText: `GRANT OWNERSHIP ON STAGE ${DESTINATION_DB_NAME}.${schema}.${stage_name} to role ${ROLE_NAME} REVOKE CURRENT GRANTS;`}); - } - - var existing_functions = snowflake.execute({sqlText: `SELECT function_schema, function_name, concat('(',array_to_string(regexp_substr_all(argument_signature, 'VARCHAR|NUMBER|FLOAT|ARRAY|VARIANT|OBJECT|DOUBLE'),','),')') as argument_signature - FROM ${DESTINATION_DB_NAME}.INFORMATION_SCHEMA.FUNCTIONS;`}); - - while (existing_functions.next()) { - var schema = existing_functions.getColumnValue(1) - var function_name = existing_functions.getColumnValue(2) - var argument_signature = existing_functions.getColumnValue(3) - snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUNCTION ${DESTINATION_DB_NAME}.${schema}.${function_name}${argument_signature} to role ${ROLE_NAME} REVOKE CURRENT GRANTS;`}); - } - - var existing_procedures = snowflake.execute({sqlText: `SELECT procedure_schema, procedure_name, concat('(',array_to_string(regexp_substr_all(argument_signature, 'VARCHAR|NUMBER|FLOAT|ARRAY|VARIANT|OBJECT|DOUBLE'),','),')') as argument_signature - FROM ${DESTINATION_DB_NAME}.INFORMATION_SCHEMA.PROCEDURES;`}); - - while (existing_procedures.next()) { - var schema = existing_procedures.getColumnValue(1) - var procedure_name = existing_procedures.getColumnValue(2) - var argument_signature = existing_procedures.getColumnValue(3) - snowflake.execute({sqlText: `GRANT OWNERSHIP ON PROCEDURE ${DESTINATION_DB_NAME}.${schema}.${procedure_name}${argument_signature} to role ${ROLE_NAME} REVOKE CURRENT GRANTS;`}); - } - - snowflake.execute({sqlText: `GRANT OWNERSHIP ON DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}) - - var existing_tags = snowflake.execute({sqlText: `SHOW TAGS IN DATABASE ${DESTINATION_DB_NAME};`}); + var existing_tags = snowflake.execute({sqlText: `SHOW TAGS IN DATABASE ${DESTINATION_DB_NAME};`}); while (existing_tags.next()) { var schema = existing_tags.getColumnValue(4); var tag_name = existing_tags.getColumnValue(2) @@ -76,8 +39,8 @@ $$ snowflake.execute({sqlText: `ROLLBACK;`}); throw(err); } - + return true $$ -{%- endmacro %} \ No newline at end of file +{%- endmacro %}