From 384b05832f85d08736655a18a3210b34e9da1527 Mon Sep 17 00:00:00 2001 From: Yong Xu Date: Wed, 14 Aug 2024 17:41:21 -0400 Subject: [PATCH 1/5] SNOW-1621763 update example for na + spcs upgrade --- spcs-three-tier/README.md | 18 +++ spcs-three-tier/app/manifest.yml | 12 +- spcs-three-tier/app/setup.sql | 63 ++++---- spcs-three-tier/app_for_upgrade/manifest.yml | 48 ++++++ spcs-three-tier/app_for_upgrade/setup.sql | 151 +++++++++++++++++++ spcs-three-tier/prepare/consumer_setup.sql | 6 + spcs-three-tier/prepare/provider_setup.sql | 6 - spcs-three-tier/prepare/spcs_setup.sql | 5 - spcs-three-tier/register_callback.sql | 2 +- spcs-three-tier/setup.sh | 1 - 10 files changed, 267 insertions(+), 45 deletions(-) create mode 100644 spcs-three-tier/app_for_upgrade/manifest.yml create mode 100644 spcs-three-tier/app_for_upgrade/setup.sql delete mode 100644 spcs-three-tier/prepare/spcs_setup.sql diff --git a/spcs-three-tier/README.md b/spcs-three-tier/README.md index 0bc00d2..7e5ea72 100644 --- a/spcs-three-tier/README.md +++ b/spcs-three-tier/README.md @@ -123,6 +123,24 @@ See the [documentation](https://other-docs.snowflake.com/en/native-apps/provider 8. Click "Publish". + +#### Upgrade +In the provider account + +alter application package spcs_app_pkg add version v1 using @spcs_app_pkg.napp.app_stage; +alter application package spcs_app_pkg set default release directive version=v1 patch=0; + +add patch +alter application package spcs_app_pkg add patch for version v1 using @spcs_app_pkg.napp.app_stage; +alter application package spcs_app_pkg set default release directive version=v1 patch=1; + +add version v2 +alter application package spcs_app_pkg add version v2 using @spcs_app_pkg.napp.app_stage; +alter application package spcs_app_pkg set default release directive version=v2 patch=1; + +Check the status: +If you have multiple + ### Debugging There are some Stored Procedures to allow the Consumer to see the status and logs for the containers and services. These procedures are granted to the `app_admin` diff --git a/spcs-three-tier/app/manifest.yml b/spcs-three-tier/app/manifest.yml index 4f0f146..13b2be3 100644 --- a/spcs-three-tier/app/manifest.yml +++ b/spcs-three-tier/app/manifest.yml @@ -1,10 +1,10 @@ manifest_version: 1 version: - name: V1 + name: versioned_schema label: "First Version" configuration: - grant_callback: v1.create_services + grant_callback: versioned_schema.create_services artifacts: setup_script: setup.sql @@ -20,7 +20,7 @@ artifacts: - /spcs_app/napp/img_repo/eap_router lifecycle_callbacks: - version_initializer: v1.init + version_initializer: versioned_schema.init privileges: - BIND SERVICE ENDPOINT: @@ -39,13 +39,13 @@ references: - SELECT object_type: VIEW multi_valued: false - register_callback: v1.register_single_callback + register_callback: versioned_schema.register_single_callback - WIKIPEDIA_EAI: label: "Wikipedia Access Integration" description: "EAI for Egress from NA+SPCS" privileges: [USAGE] object_type: EXTERNAL_ACCESS_INTEGRATION - register_callback: v1.register_single_callback - configuration_callback: v1.get_configuration + register_callback: versioned_schema.register_single_callback + configuration_callback: versioned_schema.get_configuration required_at_setup: true \ No newline at end of file diff --git a/spcs-three-tier/app/setup.sql b/spcs-three-tier/app/setup.sql index 433b80e..9baf05b 100644 --- a/spcs-three-tier/app/setup.sql +++ b/spcs-three-tier/app/setup.sql @@ -3,11 +3,11 @@ CREATE APPLICATION ROLE IF NOT EXISTS app_user; CREATE SCHEMA IF NOT EXISTS app_public; GRANT USAGE ON SCHEMA app_public TO APPLICATION ROLE app_admin; GRANT USAGE ON SCHEMA app_public TO APPLICATION ROLE app_user; -CREATE OR ALTER VERSIONED SCHEMA v1; -GRANT USAGE ON SCHEMA v1 TO APPLICATION ROLE app_admin; +CREATE OR ALTER VERSIONED SCHEMA versioned_schema; +GRANT USAGE ON SCHEMA versioned_schema TO APPLICATION ROLE app_admin; -CREATE OR REPLACE PROCEDURE v1.register_single_callback(ref_name STRING, operation STRING, ref_or_alias STRING) +CREATE OR REPLACE PROCEDURE versioned_schema.register_single_callback(ref_name STRING, operation STRING, ref_or_alias STRING) RETURNS STRING LANGUAGE SQL AS $$ @@ -25,9 +25,9 @@ CREATE OR REPLACE PROCEDURE v1.register_single_callback(ref_name STRING, operati RETURN 'Operation ' || operation || ' succeeds.'; END; $$; -GRANT USAGE ON PROCEDURE v1.register_single_callback(STRING, STRING, STRING) TO APPLICATION ROLE app_admin; +GRANT USAGE ON PROCEDURE versioned_schema.register_single_callback(STRING, STRING, STRING) TO APPLICATION ROLE app_admin; -CREATE OR REPLACE PROCEDURE v1.get_configuration(ref_name STRING) +CREATE OR REPLACE PROCEDURE versioned_schema.get_configuration(ref_name STRING) RETURNS STRING LANGUAGE SQL AS @@ -47,26 +47,33 @@ BEGIN END; $$; -GRANT USAGE ON PROCEDURE v1.get_configuration(STRING) TO APPLICATION ROLE app_admin; +GRANT USAGE ON PROCEDURE versioned_schema.get_configuration(STRING) TO APPLICATION ROLE app_admin; -- The version initializer callback is executed after a successful installation, upgrade, or downgrade of an application object. --- In case the application fails to upgrade, the version initializer of the previous (successful) version will be executed so you +-- In case the application fails to upgrade, the version initializer of the previous (successful) version will be executed so you -- can clean up application state that may have been modified during the failed upgrade. -CREATE OR REPLACE PROCEDURE v1.init() -RETURNS STRING + +-- this is the first the version(version v1 patch 0) of the app package. We consider the case that when the +-- app is upgraded to next version and try to alter the services and it fails. In that case +-- it will fail back to version v1 patch 0 and call this procedure versioned_schema.init() to +-- restore the services and app can fully function. +CREATE OR REPLACE PROCEDURE versioned_schema.init() +RETURNS STRING LANGUAGE SQL -EXECUTE AS OWNER +EXECUTE AS OWNER AS $$ -BEGIN - ALTER SERVICE IF EXISTS app_public.frontend FROM SPECIFICATION_FILE='frontend.yaml'; - ALTER SERVICE IF EXISTS app_public.backend FROM SPECIFICATION_FILE='backend.yaml'; +BEGIN + --create services if not exist + call versioned_schema.create_services(); + --wait for 300 seconds, but it will stop if two services have READY status, + -- or any of the services has the FAILED status. + select system$wait_for_services(300, 'app_public.backend', 'app_public.frontend'); + RETURN 'init complete'; END $$; -GRANT USAGE ON PROCEDURE v1.init() TO APPLICATION ROLE app_admin; - -CREATE OR REPLACE PROCEDURE v1.start_backend(pool_name VARCHAR) +CREATE OR REPLACE PROCEDURE versioned_schema.start_backend(pool_name VARCHAR) RETURNS string LANGUAGE sql AS $$ @@ -78,9 +85,9 @@ BEGIN GRANT USAGE ON SERVICE app_public.backend TO APPLICATION ROLE app_user; END $$; -GRANT USAGE ON PROCEDURE v1.start_backend(VARCHAR) TO APPLICATION ROLE app_admin; +GRANT USAGE ON PROCEDURE versioned_schema.start_backend(VARCHAR) TO APPLICATION ROLE app_admin; -CREATE OR REPLACE PROCEDURE v1.start_frontend(pool_name VARCHAR) +CREATE OR REPLACE PROCEDURE versioned_schema.start_frontend(pool_name VARCHAR) RETURNS string LANGUAGE sql AS $$ @@ -95,10 +102,10 @@ BEGIN RETURN 'Service started. Check status, and when ready, get URL'; END $$; -GRANT USAGE ON PROCEDURE v1.start_frontend(VARCHAR) TO APPLICATION ROLE app_admin; +GRANT USAGE ON PROCEDURE versioned_schema.start_frontend(VARCHAR) TO APPLICATION ROLE app_admin; -CREATE OR REPLACE PROCEDURE v1.create_services(privileges array) +CREATE OR REPLACE PROCEDURE versioned_schema.create_services() RETURNS STRING LANGUAGE SQL AS @@ -114,11 +121,15 @@ CREATE OR REPLACE PROCEDURE v1.create_services(privileges array) MAX_NODES = 1 INSTANCE_FAMILY = CPU_X64_XS; - CALL v1.start_backend('backend_compute_pool'); - CALL v1.start_frontend('frontend_compute_pool'); + CALL versioned_schema.start_backend('backend_compute_pool'); + CALL versioned_schema.start_frontend('frontend_compute_pool'); + + # needed for installation from listing/cross account + GRANT SERVICE ROLE app_public.frontend!ALL_ENDPOINTS_USAGE TO APPLICATION ROLE app_admin; + + GRANT USAGE ON PROCEDURE versioned_schema.create_services( ) TO APPLICATION ROLE app_admin; END; $$; -GRANT USAGE ON PROCEDURE v1.create_services(array) TO APPLICATION ROLE app_admin; CREATE OR REPLACE PROCEDURE app_public.stop_app() @@ -133,7 +144,7 @@ END $$; GRANT USAGE ON PROCEDURE app_public.stop_app() TO APPLICATION ROLE app_admin; -CREATE OR REPLACE PROCEDURE v1.app_url() +CREATE OR REPLACE PROCEDURE versioned_schema.app_url() RETURNS string LANGUAGE sql AS @@ -146,8 +157,8 @@ BEGIN RETURN ingress_url; END $$; -GRANT USAGE ON PROCEDURE v1.app_url() TO APPLICATION ROLE app_admin; -GRANT USAGE ON PROCEDURE v1.app_url() TO APPLICATION ROLE app_user; +GRANT USAGE ON PROCEDURE versioned_schema.app_url() TO APPLICATION ROLE app_admin; +GRANT USAGE ON PROCEDURE versioned_schema.app_url() TO APPLICATION ROLE app_user; -- Support functions EXECUTE IMMEDIATE FROM 'support.sql'; \ No newline at end of file diff --git a/spcs-three-tier/app_for_upgrade/manifest.yml b/spcs-three-tier/app_for_upgrade/manifest.yml new file mode 100644 index 0000000..7ef61b2 --- /dev/null +++ b/spcs-three-tier/app_for_upgrade/manifest.yml @@ -0,0 +1,48 @@ +manifest_version: 2 +version: + name: versioned_schema + label: "Second Version" + +artifacts: + setup_script: setup.sql + + default_web_endpoint: + service: app_public.frontend + endpoint: app + + container_services: + images: + - /spcs_app/napp/img_repo/eap_frontend + - /spcs_app/napp/img_repo/eap_backend + - /spcs_app/napp/img_repo/eap_router + +lifecycle_callbacks: + version_initializer: versioned_schema.init + +privileges: + - BIND SERVICE ENDPOINT: + description: "Ability to create ingress URLs." + required_at_setup: true + - CREATE COMPUTE POOL: + required_at_setup: true + description: "Enable appplication to create its own compute pool(s)" + + +references: + - ORDERS_TABLE: + label: "Orders table" + description: "Orders table in TPC-H samples" + privileges: + - SELECT + object_type: VIEW + multi_valued: false + register_callback: versioned_schema.register_single_callback + + - WIKIPEDIA_EAI: + label: "Wikipedia Access Integration" + description: "EAI for Egress from NA+SPCS" + privileges: [USAGE] + object_type: EXTERNAL_ACCESS_INTEGRATION + register_callback: versioned_schema.register_single_callback + configuration_callback: versioned_schema.get_configuration + required_at_setup: true \ No newline at end of file diff --git a/spcs-three-tier/app_for_upgrade/setup.sql b/spcs-three-tier/app_for_upgrade/setup.sql new file mode 100644 index 0000000..401ac76 --- /dev/null +++ b/spcs-three-tier/app_for_upgrade/setup.sql @@ -0,0 +1,151 @@ +CREATE APPLICATION ROLE IF NOT EXISTS app_admin; +CREATE APPLICATION ROLE IF NOT EXISTS app_user; +CREATE SCHEMA IF NOT EXISTS app_public; +GRANT USAGE ON SCHEMA app_public TO APPLICATION ROLE app_admin; +GRANT USAGE ON SCHEMA app_public TO APPLICATION ROLE app_user; +CREATE OR ALTER VERSIONED SCHEMA versioned_schema; +GRANT USAGE ON SCHEMA versioned_schema TO APPLICATION ROLE app_admin; + + +CREATE OR REPLACE PROCEDURE versioned_schema.register_single_callback(ref_name STRING, operation STRING, ref_or_alias STRING) + RETURNS STRING + LANGUAGE SQL + AS $$ + BEGIN + CASE (operation) + WHEN 'ADD' THEN + SELECT system$set_reference(:ref_name, :ref_or_alias); + WHEN 'REMOVE' THEN + SELECT system$remove_reference(:ref_name); + WHEN 'CLEAR' THEN + SELECT system$remove_reference(:ref_name); + ELSE + RETURN 'Unknown operation: ' || operation; + END CASE; + RETURN 'Operation ' || operation || ' succeeds.'; + END; + $$; +GRANT USAGE ON PROCEDURE versioned_schema.register_single_callback(STRING, STRING, STRING) TO APPLICATION ROLE app_admin; + +CREATE OR REPLACE PROCEDURE versioned_schema.get_configuration(ref_name STRING) +RETURNS STRING +LANGUAGE SQL +AS +$$ +BEGIN + CASE (UPPER(ref_name)) + WHEN 'WIKIPEDIA_EAI' THEN + RETURN OBJECT_CONSTRUCT( + 'type', 'CONFIGURATION', + 'payload', OBJECT_CONSTRUCT( + 'host_ports', ARRAY_CONSTRUCT('upload.wikimedia.org'), + 'allowed_secrets', 'NONE') + )::STRING; + ELSE + RETURN ''; + END CASE; +END; +$$; + +GRANT USAGE ON PROCEDURE versioned_schema.get_configuration(STRING) TO APPLICATION ROLE app_admin; + +-- The version initializer callback is executed after a successful run of the setup script. +-- In case the versioned_schema.init() failed, the version initializer of the previous version will be executed +CREATE OR REPLACE PROCEDURE versioned_schema.init() +RETURNS STRING +LANGUAGE SQL +EXECUTE AS OWNER +AS +$$ +BEGIN + ALTER SERVICE IF EXISTS app_public.frontend FROM SPECIFICATION_FILE='frontend.yaml'; + ALTER SERVICE IF EXISTS app_public.backend FROM SPECIFICATION_FILE='backend.yaml'; + select system$wait_for_services(300, 'app_public.backend', 'app_public.frontend'); + RETURN 'init complete'; +END $$; + +CREATE OR REPLACE PROCEDURE versioned_schema.start_backend(pool_name VARCHAR) + RETURNS string + LANGUAGE sql + AS $$ +BEGIN + CREATE SERVICE IF NOT EXISTS app_public.backend + IN COMPUTE POOL Identifier(:pool_name) + FROM SPECIFICATION_FILE='backend.yaml' + QUERY_WAREHOUSE = 'WH_NAC'; + GRANT USAGE ON SERVICE app_public.backend TO APPLICATION ROLE app_user; +END +$$; +GRANT USAGE ON PROCEDURE versioned_schema.start_backend(VARCHAR) TO APPLICATION ROLE app_admin; + +CREATE OR REPLACE PROCEDURE versioned_schema.start_frontend(pool_name VARCHAR) + RETURNS string + LANGUAGE sql + AS $$ +BEGIN + CREATE SERVICE IF NOT EXISTS app_public.frontend + IN COMPUTE POOL Identifier(:pool_name) + FROM SPECIFICATION_FILE='frontend.yaml' + EXTERNAL_ACCESS_INTEGRATIONS=( reference('WIKIPEDIA_EAI') ); + + GRANT USAGE ON SERVICE app_public.frontend TO APPLICATION ROLE app_user; + + RETURN 'Service started. Check status, and when ready, get URL'; +END +$$; +GRANT USAGE ON PROCEDURE versioned_schema.start_frontend(VARCHAR) TO APPLICATION ROLE app_admin; + + +CREATE OR REPLACE PROCEDURE versioned_schema.create_services(privileges array) + RETURNS STRING + LANGUAGE SQL + AS + $$ + BEGIN + CREATE COMPUTE POOL IF NOT EXISTS frontend_compute_pool + MIN_NODES = 1 + MAX_NODES = 1 + INSTANCE_FAMILY = CPU_X64_XS; + + CREATE COMPUTE POOL IF NOT EXISTS backend_compute_pool + MIN_NODES = 1 + MAX_NODES = 1 + INSTANCE_FAMILY = CPU_X64_XS; + + CALL versioned_schema.start_backend('backend_compute_pool'); + CALL versioned_schema.start_frontend('frontend_compute_pool'); + END; +$$; +GRANT USAGE ON PROCEDURE versioned_schema.create_services(array) TO APPLICATION ROLE app_admin; + + +CREATE OR REPLACE PROCEDURE app_public.stop_app() + RETURNS string + LANGUAGE sql + AS +$$ +BEGIN + DROP SERVICE IF EXISTS app_public.backend; + DROP SERVICE IF EXISTS app_public.frontend; +END +$$; +GRANT USAGE ON PROCEDURE app_public.stop_app() TO APPLICATION ROLE app_admin; + +CREATE OR REPLACE PROCEDURE versioned_schema.app_url() + RETURNS string + LANGUAGE sql + AS +$$ +DECLARE + ingress_url VARCHAR; +BEGIN + SHOW ENDPOINTS IN SERVICE app_public.frontend; + SELECT "ingress_url" INTO :ingress_url FROM TABLE (RESULT_SCAN (LAST_QUERY_ID())) LIMIT 1; + RETURN ingress_url; +END +$$; +GRANT USAGE ON PROCEDURE versioned_schema.app_url() TO APPLICATION ROLE app_admin; +GRANT USAGE ON PROCEDURE versioned_schema.app_url() TO APPLICATION ROLE app_user; + +-- Support functions +EXECUTE IMMEDIATE FROM 'support.sql'; \ No newline at end of file diff --git a/spcs-three-tier/prepare/consumer_setup.sql b/spcs-three-tier/prepare/consumer_setup.sql index 2acbe91..22573c1 100644 --- a/spcs-three-tier/prepare/consumer_setup.sql +++ b/spcs-three-tier/prepare/consumer_setup.sql @@ -1,4 +1,10 @@ USE ROLE ACCOUNTADMIN; +CREATE ROLE IF NOT EXISTS nac; +GRANT CREATE APPLICATION ON ACCOUNT TO ROLE nac; +GRANT CREATE INTEGRATION ON ACCOUNT TO ROLE nac; +-- needed for app installation from a listing +GRANT IMPORT SHARE ON ACCOUNT TO nac; + -- (Mock) Consumer role GRANT ROLE nac TO ROLE ACCOUNTADMIN; CREATE WAREHOUSE IF NOT EXISTS wh_nac WITH WAREHOUSE_SIZE='XSMALL'; diff --git a/spcs-three-tier/prepare/provider_setup.sql b/spcs-three-tier/prepare/provider_setup.sql index fec5a88..7fdb5ab 100644 --- a/spcs-three-tier/prepare/provider_setup.sql +++ b/spcs-three-tier/prepare/provider_setup.sql @@ -16,12 +16,6 @@ USE ROLE naspcs_role; CREATE DATABASE IF NOT EXISTS spcs_app; CREATE SCHEMA IF NOT EXISTS spcs_app.napp; --- For Provider-side Testing -USE ROLE ACCOUNTADMIN; -CREATE ROLE IF NOT EXISTS nac; -GRANT CREATE APPLICATION ON ACCOUNT TO ROLE nac; -GRANT CREATE INTEGRATION ON ACCOUNT TO ROLE nac; - -- Create the Image Repository USE ROLE naspcs_role; CREATE IMAGE REPOSITORY IF NOT EXISTS spcs_app.napp.img_repo; diff --git a/spcs-three-tier/prepare/spcs_setup.sql b/spcs-three-tier/prepare/spcs_setup.sql deleted file mode 100644 index cd712e7..0000000 --- a/spcs-three-tier/prepare/spcs_setup.sql +++ /dev/null @@ -1,5 +0,0 @@ -USE ROLE ACCOUNTADMIN; -CREATE SECURITY INTEGRATION IF NOT EXISTS snowservices_ingress_oauth - TYPE=oauth - OAUTH_CLIENT=snowservices_ingress - ENABLED=true; \ No newline at end of file diff --git a/spcs-three-tier/register_callback.sql b/spcs-three-tier/register_callback.sql index 09a94c2..dd180a5 100755 --- a/spcs-three-tier/register_callback.sql +++ b/spcs-three-tier/register_callback.sql @@ -1,4 +1,4 @@ USE ROLE nac; USE WAREHOUSE wh_nac; GRANT USAGE ON WAREHOUSE wh_nac TO APPLICATION spcs_app_instance; -CALL spcs_app_instance.v1.register_single_callback('ORDERS_TABLE' , 'ADD', SYSTEM$REFERENCE('VIEW', 'NAC_TEST.DATA.ORDERS', 'PERSISTENT', 'SELECT')); +CALL spcs_app_instance.versioned_schema.register_single_callback('ORDERS_TABLE' , 'ADD', SYSTEM$REFERENCE('VIEW', 'NAC_TEST.DATA.ORDERS', 'PERSISTENT', 'SELECT')); diff --git a/spcs-three-tier/setup.sh b/spcs-three-tier/setup.sh index fb80d0a..3d6d84f 100755 --- a/spcs-three-tier/setup.sh +++ b/spcs-three-tier/setup.sh @@ -1,5 +1,4 @@ set -e -snow sql -f "prepare/spcs_setup.sql" snow sql -f "prepare/provider_setup.sql" snow sql -f "prepare/consumer_setup.sql" From 2b1ba2d63fe5ff62f0e1ca1f3fc7afae0335af94 Mon Sep 17 00:00:00 2001 From: Yong Xu Date: Sat, 17 Aug 2024 08:40:35 -0400 Subject: [PATCH 2/5] improve readme --- spcs-three-tier/README.md | 175 ++++++++++++++++++++++++-- spcs-three-tier/app/manifest.yml | 2 +- spcs-three-tier/app/setup.sql | 29 +++-- spcs-three-tier/register_callback.sql | 3 + 4 files changed, 184 insertions(+), 25 deletions(-) diff --git a/spcs-three-tier/README.md b/spcs-three-tier/README.md index 7e5ea72..4e9f9ff 100644 --- a/spcs-three-tier/README.md +++ b/spcs-three-tier/README.md @@ -53,7 +53,6 @@ Execute the shell script named `setup.sh` in the root folder: The setup script runs the following scripts: -- Snowpark Container Services setup (`spcs_setup.sql`) - Provider side setup (`provider_setup.sql`) - Consumer side setup (`consumer_setup.sql`) - Image repository setup by executing `make all` command @@ -125,21 +124,173 @@ See the [documentation](https://other-docs.snowflake.com/en/native-apps/provider #### Upgrade -In the provider account +Upgrades can be performed in two ways: -alter application package spcs_app_pkg add version v1 using @spcs_app_pkg.napp.app_stage; -alter application package spcs_app_pkg set default release directive version=v1 patch=0; +* Automated Upgrades: These occur when the provider updates the release directive on the application package, +triggering an automatic upgrade for all installed instances specified by the directive. -add patch -alter application package spcs_app_pkg add patch for version v1 using @spcs_app_pkg.napp.app_stage; -alter application package spcs_app_pkg set default release directive version=v1 patch=1; +* Manual Upgrades: These are initiated by the consumer, who manually runs the ALTER APPLICATION command to perform +the upgrade. -add version v2 -alter application package spcs_app_pkg add version v2 using @spcs_app_pkg.napp.app_stage; -alter application package spcs_app_pkg set default release directive version=v2 patch=1; +In this tutorial, we will focus on manual upgrades to demonstrate how the upgrade process works within the Native App Framework. The application is installed in the provider's account, so all commands will be executed within the provider's environment. + +##### Add version +```sql + alter application package spcs_app_pkg add version v1 using @spcs_app_pkg.napp.app_stage; +``` +##### Set release directive +```sql + alter application package spcs_app_pkg set default release directive version=v1 patch=0; +``` +##### manual upgrade +```sql + alter application app upgrade +``` +##### check application status +```sql + desc application app +``` +it will show the application's current version, patch, update_state and more. + +##### add version v2 and upgrade + +###### change endpoints +in frontend.yaml +change the endpoints from +```yaml +endpoints: + - name: app + port: 8000 + public: true +``` +to +```yaml +endpoints: + - name: app1 + port: 8003 + public: true + - name: app2 + port: 8004 + public: true +``` + +To upload the file into the stage @spcs_app_pkg.napp.app_stage, we can use snowsql such as + +```bash + snow sql -q 'put file:///DIRECTOR_TO_EXAMPLE/native-apps-examples/spcs-three-tier/app/* @spcs_app_pkg.napp.app_stage auto_compress=false overwrite=true' +``` +```sql + alter application package spcs_app_pkg add patch for version v1 using @spcs_app_pkg.napp.app_stage; + alter application package spcs_app_pkg set default release directive version=v1 patch=0; + alter application app upgrade; +``` +After that, you can show the service endpoints by +```sql + SHOW ENDPOINTS IN SERVICE spcs_app_instance.app_public.frontend; +``` +it will show as + +| Name | Port | Port Range | Protocol | Is_Public | Ingress_URL | +|------|------|------------|----------|-----------|--------------------------------------------------------------------------------| +| app1 | 8003 | | HTTP | true | c3xsbsr-sfengineering-na-spcs-p1-qa6.awsuswest2qa6.test-snowflakecomputing.app | +| app2 | 8004 | | HTTP | true | c3xsbsn-sfengineering-na-spcs-p1-qa6.awsuswest2qa6.test-snowflakecomputing.app | + + +##### add version v2 +```sql + alter application package spcs_app_pkg add version v2 using @spcs_app_pkg.napp.app_stage; + alter application package spcs_app_pkg set default release directive version=v2 patch=0; +``` +##### upgrade fails +change endpoints in the spec file `frontend.yaml` + ```yaml +endpoints: + - name: app1 + port: 8003 + public: true + - name: app2 + port: 8004 + public: true + - name: app3 + port: 8005 + public: true +``` +replace the PROCEDURE `CREATE OR REPLACE PROCEDURE versioned_schema.init()` into +```sql +CREATE OR REPLACE PROCEDURE versioned_schema.init() +RETURNS STRING +LANGUAGE SQL +EXECUTE AS OWNER +AS +$$ +DECLARE + can_create_compute_pool BOOLEAN; +BEGIN + SELECT SYSTEM$HOLD_PRIVILEGE_ON_ACCOUNT('create compute pool') INTO :can_create_compute_pool; + IF (:can_create_compute_pool) THEN + ALTER SERVICE IF EXISTS app_public.frontend FROM SPECIFICATION_FILE='frontend.yaml'; + ALTER SERVICE IF EXISTS app_public.backend FROM SPECIFICATION_FILE='backend.yaml'; + -- ALTER SERVICE is async. To minimize the downtime we need to wait until the services are ready. + SELECT system$wait_for_services(180, 'app_public.backend', 'app_public.frontend'); + + -- This SQL will trigger an error and the upgrade will fail + SELECT * FROM non_exists_table; + + END IF; + RETURN 'init complete'; +END $$; + +``` + +Then upgrade the app +```sql + alter application package spcs_app_pkg add version v2 using @spcs_app_pkg.napp.app_stage; + alter application package spcs_app_pkg set default release directive version=v2 patch=0; +``` +When querying +```sql + desc application app +``` +The table below shows part of the output. Please note that the upgrade_target_version is 2 and upgrade target patch +is 0. The update_state is failed, and it also gives the +upgrade_failure_reason. In this case, the app is running v1.1 version. + +| Property | Value | +|-----------------------------------|--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| +| name | SPCS_APP_INSTANCE | +| version | V1 | +| patch | 1 | +| created_on | 2024-08-30 13:42:58.250 -0700 | +| upgrade_state | FAILED | +| upgrade_target_version | 2 | +| upgrade_target_patch | 0 | +| upgrade_attempt | 3 | +| upgrade_started_on | 2024-09-02 06:23:37.210 -0700 | +| upgrade_attempted_on | 2024-09-02 06:25:17.247 -0700 | +| upgrade_failure_type | VERSION_SETUP | +| upgrade_failure_reason | "[ErrorCode 2003] Uncaught exception of type 'STATEMENT_ERROR' on line 171 at position 0 : Uncaught exception of type 'STATEMENT_ERROR' on line 12 at position 8 : SQL compilation error: Object 'NON_EXISTS_TABLE' does not exist or not authorized." | + +The failed SQL query `SELECT * FROM non_exists_table` occurs after the `ALTER SERVICE` statement. This raises concerns +about the service version, as it might suggest the services are running the version defined in v2.0. However, the +services are actually running version v1.1, which can be confirmed by executing the query `SHOW ENDPOINTS IN SERVICE +spcs_app_instance.app_public.frontend`. The secret is we put `ALTER SERVICE` command within the `version_initializer` +of the `lifecycle_callbacks`. This ensures that if the upgrade to the target version (v2.0) fails, the system will +invoke the `version_initializer` for the current version (v1.1), thereby reverting the services to the correct version. + +#### Handling Upgrade Failures + +Upgrade failures can occur for various reasons, often due to issues on the provider's side, such as errors in the setup script. When this happens, all upgrades may fail. To address this, you have a couple of options: + +* Rollback to a previous version: For example, in the scenario mentioned above, you can revert the release directive +to version v1.1 by running the following command: + +```sql + ALTER APPLICATION PACKAGE spcs_app_pkg SET DEFAULT RELEASE DIRECTIVE VERSION=v1.1 PATCH=0; +``` + +* Create a new version: Correct the errors and release a new version. After passing the necessary security review, +you can set this new version as the default release directive. However, be aware that the security review process can take some time. -Check the status: -If you have multiple ### Debugging There are some Stored Procedures to allow the Consumer to see the status diff --git a/spcs-three-tier/app/manifest.yml b/spcs-three-tier/app/manifest.yml index 13b2be3..325a42c 100644 --- a/spcs-three-tier/app/manifest.yml +++ b/spcs-three-tier/app/manifest.yml @@ -1,6 +1,6 @@ manifest_version: 1 version: - name: versioned_schema + name: v1 label: "First Version" configuration: diff --git a/spcs-three-tier/app/setup.sql b/spcs-three-tier/app/setup.sql index 9baf05b..f815fbc 100644 --- a/spcs-three-tier/app/setup.sql +++ b/spcs-three-tier/app/setup.sql @@ -6,7 +6,6 @@ GRANT USAGE ON SCHEMA app_public TO APPLICATION ROLE app_user; CREATE OR ALTER VERSIONED SCHEMA versioned_schema; GRANT USAGE ON SCHEMA versioned_schema TO APPLICATION ROLE app_admin; - CREATE OR REPLACE PROCEDURE versioned_schema.register_single_callback(ref_name STRING, operation STRING, ref_or_alias STRING) RETURNS STRING LANGUAGE SQL @@ -53,7 +52,7 @@ GRANT USAGE ON PROCEDURE versioned_schema.get_configuration(STRING) TO APPLICATI -- In case the application fails to upgrade, the version initializer of the previous (successful) version will be executed so you -- can clean up application state that may have been modified during the failed upgrade. --- this is the first the version(version v1 patch 0) of the app package. We consider the case that when the +-- this is the first version(version v1 patch 0) of the app package. We consider the case that when the -- app is upgraded to next version and try to alter the services and it fails. In that case -- it will fail back to version v1 patch 0 and call this procedure versioned_schema.init() to -- restore the services and app can fully function. @@ -63,13 +62,18 @@ LANGUAGE SQL EXECUTE AS OWNER AS $$ +DECLARE + can_create_compute_pool BOOLEAN; BEGIN - --create services if not exist - call versioned_schema.create_services(); - --wait for 300 seconds, but it will stop if two services have READY status, - -- or any of the services has the FAILED status. - select system$wait_for_services(300, 'app_public.backend', 'app_public.frontend'); - + select SYSTEM$HOLD_PRIVILEGE_ON_ACCOUNT('create compute pool') into :can_create_compute_pool; + IF (:can_create_compute_pool) THEN + ALTER SERVICE IF EXISTS app_public.frontend FROM SPECIFICATION_FILE='frontend.yaml'; + ALTER SERVICE IF EXISTS app_public.backend FROM SPECIFICATION_FILE='backend.yaml'; + -- ALTER SERVICE is async. To minimize the downtime we need to wait until the service are ready. + select system$wait_for_services(180, 'app_public.backend', 'app_public.frontend'); + -- this sql will trigger an error and the upgrade will fail + select * from non_exists_table; + END IF; RETURN 'init complete'; END $$; @@ -105,7 +109,7 @@ $$; GRANT USAGE ON PROCEDURE versioned_schema.start_frontend(VARCHAR) TO APPLICATION ROLE app_admin; -CREATE OR REPLACE PROCEDURE versioned_schema.create_services() +CREATE OR REPLACE PROCEDURE versioned_schema.create_services(privileges array) RETURNS STRING LANGUAGE SQL AS @@ -124,12 +128,13 @@ CREATE OR REPLACE PROCEDURE versioned_schema.create_services() CALL versioned_schema.start_backend('backend_compute_pool'); CALL versioned_schema.start_frontend('frontend_compute_pool'); - # needed for installation from listing/cross account + --needed for installation from listing/cross account + GRANT USAGE ON SERVICE app_public.frontend TO APPLICATION ROLE app_admin; GRANT SERVICE ROLE app_public.frontend!ALL_ENDPOINTS_USAGE TO APPLICATION ROLE app_admin; - - GRANT USAGE ON PROCEDURE versioned_schema.create_services( ) TO APPLICATION ROLE app_admin; END; $$; +GRANT USAGE ON PROCEDURE versioned_schema.create_services(array) TO APPLICATION ROLE app_admin; + CREATE OR REPLACE PROCEDURE app_public.stop_app() diff --git a/spcs-three-tier/register_callback.sql b/spcs-three-tier/register_callback.sql index dd180a5..74669ea 100755 --- a/spcs-three-tier/register_callback.sql +++ b/spcs-three-tier/register_callback.sql @@ -1,4 +1,7 @@ USE ROLE nac; USE WAREHOUSE wh_nac; GRANT USAGE ON WAREHOUSE wh_nac TO APPLICATION spcs_app_instance; + CALL spcs_app_instance.versioned_schema.register_single_callback('ORDERS_TABLE' , 'ADD', SYSTEM$REFERENCE('VIEW', 'NAC_TEST.DATA.ORDERS', 'PERSISTENT', 'SELECT')); +grant create compute pool on account to application spcs_app_instance; +grant bind service endpoint on account to application spcs_app_instance; \ No newline at end of file From 5b209e8cf47e61659b1cb95726905f9ace329e1f Mon Sep 17 00:00:00 2001 From: Yong Xu Date: Tue, 3 Sep 2024 08:50:56 -0400 Subject: [PATCH 3/5] readme format --- spcs-three-tier/README.md | 14 +++++++------- 1 file changed, 7 insertions(+), 7 deletions(-) diff --git a/spcs-three-tier/README.md b/spcs-three-tier/README.md index 4e9f9ff..1254ec6 100644 --- a/spcs-three-tier/README.md +++ b/spcs-three-tier/README.md @@ -123,7 +123,7 @@ See the [documentation](https://other-docs.snowflake.com/en/native-apps/provider 8. Click "Publish". -#### Upgrade +### Upgrade Upgrades can be performed in two ways: * Automated Upgrades: These occur when the provider updates the release directive on the application package, @@ -134,27 +134,27 @@ the upgrade. In this tutorial, we will focus on manual upgrades to demonstrate how the upgrade process works within the Native App Framework. The application is installed in the provider's account, so all commands will be executed within the provider's environment. -##### Add version +#### Add version ```sql alter application package spcs_app_pkg add version v1 using @spcs_app_pkg.napp.app_stage; ``` -##### Set release directive +#### Set release directive ```sql alter application package spcs_app_pkg set default release directive version=v1 patch=0; ``` -##### manual upgrade +#### manual upgrade ```sql alter application app upgrade ``` -##### check application status +#### check application status ```sql desc application app ``` it will show the application's current version, patch, update_state and more. -##### add version v2 and upgrade +#### add version v2 and upgrade -###### change endpoints +##### change endpoints in frontend.yaml change the endpoints from ```yaml From 12db83bb1fb11eb677660d27ad87c4ef8558ab1d Mon Sep 17 00:00:00 2001 From: Yong Xu Date: Wed, 18 Sep 2024 11:37:56 -0400 Subject: [PATCH 4/5] task to send app upgrade progress email. --- ...lication_upgrade_porgress_notification.sql | 206 ++++++++++++++++++ 1 file changed, 206 insertions(+) create mode 100644 spcs-three-tier/application_upgrade_porgress_notification.sql diff --git a/spcs-three-tier/application_upgrade_porgress_notification.sql b/spcs-three-tier/application_upgrade_porgress_notification.sql new file mode 100644 index 0000000..d42aa14 --- /dev/null +++ b/spcs-three-tier/application_upgrade_porgress_notification.sql @@ -0,0 +1,206 @@ +CREATE or replace NOTIFICATION INTEGRATION my_email_int + TYPE=EMAIL + ENABLED=TRUE + ALLOWED_RECIPIENTS=(); + create database if not exists app_upgrade_state_notification_db; +create schema if not exists sch; +create table if not exists app_upgrade_state_notification_db.sch.upgrade_state_notification( + CONSUMER_SNOWFLAKE_REGION varchar, PROVIDER_ACCOUNT_LOCATOR varchar,PACKAGE_NAME varchar, + VERSION varchar, PATCH int, UPGRADE_STATE varchar, NOTIFICATION_STATE varchar, UPDATE_AT timestamp); + +-- send notification email to app provider + +create or replace procedure app_upgrade_state_notification_db.sch.send_app_upgrade_notification(EMAIL varchar) + returns string + language javascript + comment = "set notification email to the app provider about the app upgrade progress" + execute as caller +AS +$$ + var query = ` select * from app_upgrade_state_notification_db.sch.upgrade_state_notification + where NOTIFICATION_STATE = 'NOT_SEND'; + `; + + var res = snowflake.createStatement({sqlText: query}).execute(); + var message_completed = ""; + var message_start = ""; + while(res.next()){ + var target = "In region " + res.getColumnValue("CONSUMER_SNOWFLAKE_REGION") + + " the app(s) installed from upgrade for version " + res.getColumnValue("VERSION") + + " patch " + res.getColumnValue("PATCH") + + " is " + if(res.getColumnValue("UPGRADE_STATE") == "UPGRATE_START"){ + message_start += target + "starting;\n"; + } else { + message_completed += target + "completed;\n"; + } + } +var message = message_start + message_completed; +if(message){ + + send_email_query = " call SYSTEM$SEND_EMAIL ('my_email_int', ' "+ EMAIL + "', 'Email Alert: APPs Upgrade Progress.', '" + message_start + message_completed + "')"; + + var send_email_res = snowflake.createStatement({sqlText: send_email_query}).execute(); + if(send_email_res.next()){ + if(send_email_res.getColumnValue(1) ===true){ + var update_query = `update app_upgrade_state_notification_db.sch.upgrade_state_notification + set NOTIFICATION_STATE = 'SENT' + where NOTIFICATION_STATE = 'NOT_SEND'; + `; + snowflake.createStatement({sqlText: update_query}).execute(); + } + } +} +return "DONE"; +$$; + +-- A notification email will send when +-- * the application starts to upgrade for a given snowflake region +-- * the application upgrade completes for a given snowflake region +-- * an application upgrade fails + +create or replace procedure app_upgrade_state_notification_db.sch.update_app_state_upgrade_notification(EMAIL varchar) + returns string + language javascript + comment = "update the upgrade_state_notification table when the app upgrade states changed based on the APPLICATION_STATE view" + execute as caller +AS +$$ +PROVIDER_ACCOUNT_LOCATOR = "PROVIDER_ACCOUNT_LOCATOR"; +const CONSUMER_SNOWFLAKE_REGION = "CONSUMER_SNOWFLAKE_REGION"; +const PACKAGE_NAME = "PACKAGE_NAME"; +const TARGET_UPGRADE_VERSION = "TARGET_UPGRADE_VERSION"; +const TARGET_UPGRADE_PATCH = "TARGET_UPGRADE_PATCH"; +const CURRENT_VERSION = "CURRENT_VERSION"; +const CURRENT_PATCH = "CURRENT_PATCH"; +const UPGRADE_STARTED_ON = "UPGRADE_STARTED_ON"; +const UPGRADE_STATE = "UPGRADE_STATE"; +const STATE_COMPLETED = "UPGRADE_COMPLETED"; +const STATE_START = "UPGRADE_START"; +const NOT_SEND = "NOT_SEND" +const SENT = "SENT" + +const keys_state = [CONSUMER_SNOWFLAKE_REGION, PROVIDER_ACCOUNT_LOCATOR, PACKAGE_NAME]; +const columns = keys_state.concat([CURRENT_VERSION, CURRENT_PATCH, TARGET_UPGRADE_VERSION, TARGET_UPGRADE_PATCH, UPGRADE_STARTED_ON, UPGRADE_STATE]); + +function getKey(row, keys){ + var keyString = ""; + for(var col of keys){ + keyString += (row[col] + ":"); + } + return keyString; +} + +function update_notification_table( to_update_row, version_patch, to_update_state ){ + var query = `select * from app_upgrade_state_notification_db.sch.upgrade_state_notification + where CONSUMER_SNOWFLAKE_REGION = ? and PROVIDER_ACCOUNT_LOCATOR = ? and PACKAGE_NAME = ? + and VERSION = ? and PATCH = ? ; + `; + var query_paras = [to_update_row[CONSUMER_SNOWFLAKE_REGION],to_update_row[PROVIDER_ACCOUNT_LOCATOR], + to_update_row[PACKAGE_NAME]].concat(version_patch).concat([NOT_SEND]); + var state_notification_rest = snowflake.createStatement({sqlText: query, binds: query_paras}).execute(); + if(state_notification_rest.next()){ + //not consider rollback case + if(state_notification_rest.getColumnValue(UPGRADE_STATE) == STATE_START && + to_updata_state == STATE_COMPLETED){ + + var update_query = ` + update app_upgrade_state_notification_db.sch.upgrade_state_notification + set UPGRADE_STATE = ? and UPGRADE_AT = CURRENT_TIMESTAMP() and NOTIFICATION_STATE = "NOT_SEND" + where CONSUMER_SNOWFLAKE_REGION = ? and PROVIDER_ACCOUNT_LOCATOR = ? and PACKAGE_NAME = ? + and VERSION = ? and PATCH = ? ; + `; + snowflake.createStatement({sqlText: update_query, binds: query_paras}).execute(); + } + } + else { + var insert_query = ` + INSERT INTO app_upgrade_state_notification_db.sch.upgrade_state_notification values(?, ?, ?, ?, ?, ?, ?, CURRENT_TIMESTAMP()); + `; + query_paras = query_paras.concat([NOT_SEND]); + snowflake.createStatement({sqlText: insert_query, binds: query_paras}).execute(); + } +} +const q = ` + select * from SNOWFLAKE.DATA_SHARING_USAGE.APPLICATION_STATE + where TARGET_UPGRADE_PATCH is not null + and UPGRADE_STATE != 'FAILED'; +`; +const stmt = snowflake.createStatement({sqlText: q}); +const res = stmt.execute(); +var state_result = {}; +while(res.next()){ + var row = {}; + for (var column of columns) { + row[column] = res.getColumnValue(column); + } + var key = getKey(row, keys_state); + state_result[key] = state_result[key] === undefined ? [row] : state_result[key].concate([row]); + } + + //sort the query result + for(const prop in state_result){ + var num_apps_for_pkg = state_result[prop].length; + var row_maybe_completed = {}; + var row_maybe_start = {}; + var target_for = []; + var completed_for = {}; + + // group the app state by region, app pkg account and app pkg name, current version/patch + for( var state_for_version of state_result[prop]){ + var key = getKey(state_for_version, ["CURRENT_VERSION", "CURRENT_PATCH"]); + completed_for[key] = completed_for[key] === undefined ? 1 : (completed_for[key] +1); + if(state_for_version["TARGET_UPGRADE_VERSION"]){ + if(state_for_version["UPGRADE_STATE"] == "FAILED"){ + // deal with failed + } + else { // suppose only one target version/patch. Actually it is possible with two or more target version/patches + target_for = [state_for_version["TARGET_UPGRADE_VERSION"], state_for_version["TARGET_UPGRADE_PATCH"]]; + row_maybe_completed = state_for_version; + } + } + if(Object.keys(row_maybe_completed).length ==0) { + row_maybe_completed = state_for_version; + } + } + + if(Object.keys(target_for).length >0){ + update_notification_table( row_maybe_completed, + [row_maybe_completed["TARGET_UPGRADE_VERSION"], row_maybe_completed["TARGET_UPGRADE_PATCH"]], STATE_START); + } + //should we consider the FAILED and DISABLED? + if(Object.keys(completed_for).length == 1){ + + var version_patch = Object.keys(completed_for)[0]; + // if all apps's current version/patch are the same, + // it means the upgrade for the version/patch is completed + if(completed_for[version_patch] && completed_for[version_patch] == num_apps_for_pkg){ + update_notification_table( row_maybe_completed, + [row_maybe_completed["CURRENT_VERSION"], row_maybe_completed["CURRENT_PATCH"]], STATE_COMPLETED); + } + }else if(Object.keys(completed_for).length == 2){ // there is a case that the two types of version/patch(eg. v1.0 and v1.1) are in COMPLETE state. In this case, we + // suppose the one version (v1.0) should be upgrade COMPLETED for all apps and the other one(v1.1) just start for upgrade + var version_patch1 = Object.keys(completed_for)[0]; + var version_patch2 = Object.keys(completed_for)[0]; + update_notification_table( row_maybe_completed, + [row_maybe_completed["CURRENT_VERSION"], row_maybe_completed["CURRENT_PATCH"]], STATE_START); + update_notification_table( row_maybe_completed, + [row_maybe_completed["CURRENT_VERSION"], row_maybe_completed["CURRENT_PATCH"]], STATE_START); + } + } +var call_send_email_query = "call app_upgrade_state_notification_db.sch.send_app_upgrade_notification('" + EMAIL + "')"; +//return call_send_email_query; + snowflake.createStatement({sqlText: call_send_email_query}).execute(); + +return "DONE"; +$$ +; + +call app_upgrade_state_notification_db.sch.update_app_state_upgrade_notification('yong.xu@snowflake.com'); + +CREATE OR REPLACE TASK app_upgrade_state_notification_db.sch.application_upgrade_notification_task + SCHEDULE = '720 minutes' --12 hours +AS call app_upgrade_state_notification_db.sch.update_app_state_upgrade_notification(); + +execute task app_upgrade_state_notification_db.sch.application_upgrade_notification_task; + From 4a754b3803953a39812accab39794dafec3d87eb Mon Sep 17 00:00:00 2001 From: Yong Xu Date: Mon, 23 Sep 2024 13:16:23 -0400 Subject: [PATCH 5/5] update readme --- spcs-three-tier/README.md | 155 +++++++------ spcs-three-tier/app_for_upgrade/manifest.yml | 48 ---- spcs-three-tier/app_for_upgrade/setup.sql | 151 ------------- ...lication_upgrade_porgress_notification.sql | 206 ------------------ 4 files changed, 85 insertions(+), 475 deletions(-) delete mode 100644 spcs-three-tier/app_for_upgrade/manifest.yml delete mode 100644 spcs-three-tier/app_for_upgrade/setup.sql delete mode 100644 spcs-three-tier/application_upgrade_porgress_notification.sql diff --git a/spcs-three-tier/README.md b/spcs-three-tier/README.md index 1254ec6..7c4bbb7 100644 --- a/spcs-three-tier/README.md +++ b/spcs-three-tier/README.md @@ -103,12 +103,19 @@ To clean up the Native App test install, you can execute `cleanup.sh`, which wil Your Native App is now ready on the Provider Side. You can make the Native App available for installation in other Snowflake Accounts by creating a version and release directive, then setting the default patch and Sharing the App in the Snowsight UI. - See the [documentation](https://other-docs.snowflake.com/en/native-apps/provider-publishing-app-package) for more information. -1. Navigate to the "Apps" tab and select "Packages" at the top. +Add the version and set the release directive in the provider account +```sql + ALTER APPLICATION PACKAGE spcs_app_pkg ADD VERSION v1 using @spcs_app_pkg.napp.app_stage; + ALTER APPLICATION PACKAGE spcs_app_pkg SET DEFAULT RELEASE DIRECTIVE VERSION=v1 PATCH=0; +``` + +Publish the app: -2. Now click on your App Package (`NA_SPCS_PYTHON_PKG`). +1. Navigate to the "Apps" tab and select "Packages" at the top. + spcs_app_pkg +2. Now click on your App Package (`spcs_app_pkg`). 3. From here you can click on "Set release default" and choose the latest patch (the largest number) for version `v1`. @@ -116,54 +123,39 @@ See the [documentation](https://other-docs.snowflake.com/en/native-apps/provider 5. Give the listing a title, choose "Only Specified Consumers", and click "Next". -6. For "What's in the listing?", select the App Package (`NA_SPCS_PYTHON_PKG`). Add a brief description. +6. For "What's in the listing?", select the App Package (`spcs_app_pkg`). Add a brief description. 7. Lastly, add the Consumer account identifier to the "Add consumer accounts". 8. Click "Publish". +### Install Native App in Consumer Account -### Upgrade + +### Upgrade a Native App Upgrades can be performed in two ways: -* Automated Upgrades: These occur when the provider updates the release directive on the application package, -triggering an automatic upgrade for all installed instances specified by the directive. +* Automated Upgrades: Triggered automatically when the provider updates the release directive on the application + package. All installed instances specified by the directive are upgraded automatically. -* Manual Upgrades: These are initiated by the consumer, who manually runs the ALTER APPLICATION command to perform -the upgrade. +* Manual Upgrades: Initiated by the consumer, who manually executes the ALTER APPLICATION command to perform the upgrade. -In this tutorial, we will focus on manual upgrades to demonstrate how the upgrade process works within the Native App Framework. The application is installed in the provider's account, so all commands will be executed within the provider's environment. +From the last step, we had an app called `spcs_app_instance` in the consumer account. -#### Add version -```sql - alter application package spcs_app_pkg add version v1 using @spcs_app_pkg.napp.app_stage; -``` -#### Set release directive -```sql - alter application package spcs_app_pkg set default release directive version=v1 patch=0; -``` -#### manual upgrade -```sql - alter application app upgrade -``` -#### check application status -```sql - desc application app -``` -it will show the application's current version, patch, update_state and more. +In this tutorial, we'll demonstrate the upgrade process within the Native App Framework. -#### add version v2 and upgrade +#### Add a Patch to Version v1 and Upgrade ##### change endpoints -in frontend.yaml -change the endpoints from +Update the endpoints in the frontend.yaml file. +Before: ```yaml endpoints: - name: app port: 8000 public: true ``` -to +After ```yaml endpoints: - name: app1 @@ -174,34 +166,48 @@ endpoints: public: true ``` -To upload the file into the stage @spcs_app_pkg.napp.app_stage, we can use snowsql such as +To upload the file into the stage @spcs_app_pkg.napp.app_stage, we can use snowsql: ```bash snow sql -q 'put file:///DIRECTOR_TO_EXAMPLE/native-apps-examples/spcs-three-tier/app/* @spcs_app_pkg.napp.app_stage auto_compress=false overwrite=true' ``` + +add a patch and set default release directive in the provider account ```sql alter application package spcs_app_pkg add patch for version v1 using @spcs_app_pkg.napp.app_stage; - alter application package spcs_app_pkg set default release directive version=v1 patch=0; - alter application app upgrade; + alter application package spcs_app_pkg set default release directive version=v1 patch=1; ``` -After that, you can show the service endpoints by + +#### Upgrade process +The app should automatically update to version v1.1 after several minutes or hours once the default release directive is set. + +For manual upgrades (immediate and synchronous), run the following in the consumer account: + ```sql - SHOW ENDPOINTS IN SERVICE spcs_app_instance.app_public.frontend; + alter application spcs_app_instance upgrade ``` -it will show as - -| Name | Port | Port Range | Protocol | Is_Public | Ingress_URL | -|------|------|------------|----------|-----------|--------------------------------------------------------------------------------| -| app1 | 8003 | | HTTP | true | c3xsbsr-sfengineering-na-spcs-p1-qa6.awsuswest2qa6.test-snowflakecomputing.app | -| app2 | 8004 | | HTTP | true | c3xsbsn-sfengineering-na-spcs-p1-qa6.awsuswest2qa6.test-snowflakecomputing.app | +#### Check Application Status +To check the status of the application, including the current version and patch: +```sql + desc application app +``` +This will display the application's current version, patch, upgrade state, and more. -##### add version v2 +To verify that the updated services are deployed: ```sql - alter application package spcs_app_pkg add version v2 using @spcs_app_pkg.napp.app_stage; - alter application package spcs_app_pkg set default release directive version=v2 patch=0; + SHOW ENDPOINTS IN SERVICE spcs_app_instance.app_public.frontend; ``` -##### upgrade fails +**Expected output:** + +| Name | Port | Port Range | Protocol | Is_Public | Ingress_URL | +|------|------|------------|----------|-----------|--------------| +| app1 | 8003 | | HTTP | true | [app1-url] | +| app2 | 8004 | | HTTP | true | [app1-url] | + + +##### upgrades to version v2 and fails + change endpoints in the spec file `frontend.yaml` ```yaml endpoints: @@ -230,66 +236,75 @@ BEGIN IF (:can_create_compute_pool) THEN ALTER SERVICE IF EXISTS app_public.frontend FROM SPECIFICATION_FILE='frontend.yaml'; ALTER SERVICE IF EXISTS app_public.backend FROM SPECIFICATION_FILE='backend.yaml'; - -- ALTER SERVICE is async. To minimize the downtime we need to wait until the services are ready. + + -- ALTER SERVICE is async process. To minimize the downtime we need to wait until the services are ready. SELECT system$wait_for_services(180, 'app_public.backend', 'app_public.frontend'); - -- This SQL will trigger an error and the upgrade will fail + -- Trigger an error SELECT * FROM non_exists_table; - + END IF; RETURN 'init complete'; END $$; ``` -Then upgrade the app +###### Add Version v2 and Attempt the Upgrade + +In the provider account ```sql alter application package spcs_app_pkg add version v2 using @spcs_app_pkg.napp.app_stage; alter application package spcs_app_pkg set default release directive version=v2 patch=0; ``` -When querying +In the consumer account +```sql + alter application spcs_app_instance upgrade; +``` +Check the application’s upgrade status in the consumer account: ```sql desc application app ``` -The table below shows part of the output. Please note that the upgrade_target_version is 2 and upgrade target patch -is 0. The update_state is failed, and it also gives the -upgrade_failure_reason. In this case, the app is running v1.1 version. +The table below shows part of the output. Please note that the `upgrade_target_version` is `v2` and +`upgrade_target_patch` is `0`. The `update_state` is `FAILED`, and it also gives the +`upgrade_failure_reason`. In this case, the app remains on the previous version (v1.1). | Property | Value | |-----------------------------------|--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| | name | SPCS_APP_INSTANCE | | version | V1 | | patch | 1 | -| created_on | 2024-08-30 13:42:58.250 -0700 | | upgrade_state | FAILED | | upgrade_target_version | 2 | | upgrade_target_patch | 0 | | upgrade_attempt | 3 | -| upgrade_started_on | 2024-09-02 06:23:37.210 -0700 | -| upgrade_attempted_on | 2024-09-02 06:25:17.247 -0700 | | upgrade_failure_type | VERSION_SETUP | | upgrade_failure_reason | "[ErrorCode 2003] Uncaught exception of type 'STATEMENT_ERROR' on line 171 at position 0 : Uncaught exception of type 'STATEMENT_ERROR' on line 12 at position 8 : SQL compilation error: Object 'NON_EXISTS_TABLE' does not exist or not authorized." | -The failed SQL query `SELECT * FROM non_exists_table` occurs after the `ALTER SERVICE` statement. This raises concerns -about the service version, as it might suggest the services are running the version defined in v2.0. However, the -services are actually running version v1.1, which can be confirmed by executing the query `SHOW ENDPOINTS IN SERVICE -spcs_app_instance.app_public.frontend`. The secret is we put `ALTER SERVICE` command within the `version_initializer` -of the `lifecycle_callbacks`. This ensures that if the upgrade to the target version (v2.0) fails, the system will -invoke the `version_initializer` for the current version (v1.1), thereby reverting the services to the correct version. +##### Version Initializer for SPCS Service Upgrade + +The failed SQL query `SELECT * FROM non_exists_table` occurs **after** the `ALTER SERVICE` statement in v2.0, but the +`ALTER SERVICE` command still runs successfully. This raises concerns about the service version: although the services might appear to be running version `v2.0`, they are actually running version `v1.1`. + +The key is the `ALTER SERVICE` command is inside the `version_initializer` of the `lifecycle_callbacks`. If the upgrade to version `v2.0` fails, the system will invoke the `version_initializer` for the current version (`v1.1`), effectively reverting the services to the correct version. + +**Important Tips for the `version_initializer` Callback Procedure**: +- The callback procedure should reside in a **versioned schema**. +- Code/SQL responsible for creating and altering SPCS services must be included **within the callback procedure** to ensure proper rollback in the event of upgrade failure. +- If the `ALTER SERVICE` command is not placed inside `version_initializer`, the services might remain in version `v2.0`, even after an upgrade failure. + +--- -#### Handling Upgrade Failures +##### Handling Upgrade Failures -Upgrade failures can occur for various reasons, often due to issues on the provider's side, such as errors in the setup script. When this happens, all upgrades may fail. To address this, you have a couple of options: +Upgrade failures can happen due to issues on the provider's side, such as errors in the setup script. In such cases, upgrades might fail for all consumers. To handle this, you have a few options: -* Rollback to a previous version: For example, in the scenario mentioned above, you can revert the release directive -to version v1.1 by running the following command: +* Rollback to a previous version: In the scenario described above, you can revert the release directive to version `v1.1` by running the following command: ```sql - ALTER APPLICATION PACKAGE spcs_app_pkg SET DEFAULT RELEASE DIRECTIVE VERSION=v1.1 PATCH=0; + ALTER APPLICATION PACKAGE spcs_app_pkg SET DEFAULT RELEASE DIRECTIVE VERSION=v1 PATCH=1; ``` -* Create a new version: Correct the errors and release a new version. After passing the necessary security review, -you can set this new version as the default release directive. However, be aware that the security review process can take some time. +* Create a new version: Correct the errors and release a new version. After passing the necessary security review, you can set this new version as the default release directive. However, be aware that the security review process can take some time. ### Debugging diff --git a/spcs-three-tier/app_for_upgrade/manifest.yml b/spcs-three-tier/app_for_upgrade/manifest.yml deleted file mode 100644 index 7ef61b2..0000000 --- a/spcs-three-tier/app_for_upgrade/manifest.yml +++ /dev/null @@ -1,48 +0,0 @@ -manifest_version: 2 -version: - name: versioned_schema - label: "Second Version" - -artifacts: - setup_script: setup.sql - - default_web_endpoint: - service: app_public.frontend - endpoint: app - - container_services: - images: - - /spcs_app/napp/img_repo/eap_frontend - - /spcs_app/napp/img_repo/eap_backend - - /spcs_app/napp/img_repo/eap_router - -lifecycle_callbacks: - version_initializer: versioned_schema.init - -privileges: - - BIND SERVICE ENDPOINT: - description: "Ability to create ingress URLs." - required_at_setup: true - - CREATE COMPUTE POOL: - required_at_setup: true - description: "Enable appplication to create its own compute pool(s)" - - -references: - - ORDERS_TABLE: - label: "Orders table" - description: "Orders table in TPC-H samples" - privileges: - - SELECT - object_type: VIEW - multi_valued: false - register_callback: versioned_schema.register_single_callback - - - WIKIPEDIA_EAI: - label: "Wikipedia Access Integration" - description: "EAI for Egress from NA+SPCS" - privileges: [USAGE] - object_type: EXTERNAL_ACCESS_INTEGRATION - register_callback: versioned_schema.register_single_callback - configuration_callback: versioned_schema.get_configuration - required_at_setup: true \ No newline at end of file diff --git a/spcs-three-tier/app_for_upgrade/setup.sql b/spcs-three-tier/app_for_upgrade/setup.sql deleted file mode 100644 index 401ac76..0000000 --- a/spcs-three-tier/app_for_upgrade/setup.sql +++ /dev/null @@ -1,151 +0,0 @@ -CREATE APPLICATION ROLE IF NOT EXISTS app_admin; -CREATE APPLICATION ROLE IF NOT EXISTS app_user; -CREATE SCHEMA IF NOT EXISTS app_public; -GRANT USAGE ON SCHEMA app_public TO APPLICATION ROLE app_admin; -GRANT USAGE ON SCHEMA app_public TO APPLICATION ROLE app_user; -CREATE OR ALTER VERSIONED SCHEMA versioned_schema; -GRANT USAGE ON SCHEMA versioned_schema TO APPLICATION ROLE app_admin; - - -CREATE OR REPLACE PROCEDURE versioned_schema.register_single_callback(ref_name STRING, operation STRING, ref_or_alias STRING) - RETURNS STRING - LANGUAGE SQL - AS $$ - BEGIN - CASE (operation) - WHEN 'ADD' THEN - SELECT system$set_reference(:ref_name, :ref_or_alias); - WHEN 'REMOVE' THEN - SELECT system$remove_reference(:ref_name); - WHEN 'CLEAR' THEN - SELECT system$remove_reference(:ref_name); - ELSE - RETURN 'Unknown operation: ' || operation; - END CASE; - RETURN 'Operation ' || operation || ' succeeds.'; - END; - $$; -GRANT USAGE ON PROCEDURE versioned_schema.register_single_callback(STRING, STRING, STRING) TO APPLICATION ROLE app_admin; - -CREATE OR REPLACE PROCEDURE versioned_schema.get_configuration(ref_name STRING) -RETURNS STRING -LANGUAGE SQL -AS -$$ -BEGIN - CASE (UPPER(ref_name)) - WHEN 'WIKIPEDIA_EAI' THEN - RETURN OBJECT_CONSTRUCT( - 'type', 'CONFIGURATION', - 'payload', OBJECT_CONSTRUCT( - 'host_ports', ARRAY_CONSTRUCT('upload.wikimedia.org'), - 'allowed_secrets', 'NONE') - )::STRING; - ELSE - RETURN ''; - END CASE; -END; -$$; - -GRANT USAGE ON PROCEDURE versioned_schema.get_configuration(STRING) TO APPLICATION ROLE app_admin; - --- The version initializer callback is executed after a successful run of the setup script. --- In case the versioned_schema.init() failed, the version initializer of the previous version will be executed -CREATE OR REPLACE PROCEDURE versioned_schema.init() -RETURNS STRING -LANGUAGE SQL -EXECUTE AS OWNER -AS -$$ -BEGIN - ALTER SERVICE IF EXISTS app_public.frontend FROM SPECIFICATION_FILE='frontend.yaml'; - ALTER SERVICE IF EXISTS app_public.backend FROM SPECIFICATION_FILE='backend.yaml'; - select system$wait_for_services(300, 'app_public.backend', 'app_public.frontend'); - RETURN 'init complete'; -END $$; - -CREATE OR REPLACE PROCEDURE versioned_schema.start_backend(pool_name VARCHAR) - RETURNS string - LANGUAGE sql - AS $$ -BEGIN - CREATE SERVICE IF NOT EXISTS app_public.backend - IN COMPUTE POOL Identifier(:pool_name) - FROM SPECIFICATION_FILE='backend.yaml' - QUERY_WAREHOUSE = 'WH_NAC'; - GRANT USAGE ON SERVICE app_public.backend TO APPLICATION ROLE app_user; -END -$$; -GRANT USAGE ON PROCEDURE versioned_schema.start_backend(VARCHAR) TO APPLICATION ROLE app_admin; - -CREATE OR REPLACE PROCEDURE versioned_schema.start_frontend(pool_name VARCHAR) - RETURNS string - LANGUAGE sql - AS $$ -BEGIN - CREATE SERVICE IF NOT EXISTS app_public.frontend - IN COMPUTE POOL Identifier(:pool_name) - FROM SPECIFICATION_FILE='frontend.yaml' - EXTERNAL_ACCESS_INTEGRATIONS=( reference('WIKIPEDIA_EAI') ); - - GRANT USAGE ON SERVICE app_public.frontend TO APPLICATION ROLE app_user; - - RETURN 'Service started. Check status, and when ready, get URL'; -END -$$; -GRANT USAGE ON PROCEDURE versioned_schema.start_frontend(VARCHAR) TO APPLICATION ROLE app_admin; - - -CREATE OR REPLACE PROCEDURE versioned_schema.create_services(privileges array) - RETURNS STRING - LANGUAGE SQL - AS - $$ - BEGIN - CREATE COMPUTE POOL IF NOT EXISTS frontend_compute_pool - MIN_NODES = 1 - MAX_NODES = 1 - INSTANCE_FAMILY = CPU_X64_XS; - - CREATE COMPUTE POOL IF NOT EXISTS backend_compute_pool - MIN_NODES = 1 - MAX_NODES = 1 - INSTANCE_FAMILY = CPU_X64_XS; - - CALL versioned_schema.start_backend('backend_compute_pool'); - CALL versioned_schema.start_frontend('frontend_compute_pool'); - END; -$$; -GRANT USAGE ON PROCEDURE versioned_schema.create_services(array) TO APPLICATION ROLE app_admin; - - -CREATE OR REPLACE PROCEDURE app_public.stop_app() - RETURNS string - LANGUAGE sql - AS -$$ -BEGIN - DROP SERVICE IF EXISTS app_public.backend; - DROP SERVICE IF EXISTS app_public.frontend; -END -$$; -GRANT USAGE ON PROCEDURE app_public.stop_app() TO APPLICATION ROLE app_admin; - -CREATE OR REPLACE PROCEDURE versioned_schema.app_url() - RETURNS string - LANGUAGE sql - AS -$$ -DECLARE - ingress_url VARCHAR; -BEGIN - SHOW ENDPOINTS IN SERVICE app_public.frontend; - SELECT "ingress_url" INTO :ingress_url FROM TABLE (RESULT_SCAN (LAST_QUERY_ID())) LIMIT 1; - RETURN ingress_url; -END -$$; -GRANT USAGE ON PROCEDURE versioned_schema.app_url() TO APPLICATION ROLE app_admin; -GRANT USAGE ON PROCEDURE versioned_schema.app_url() TO APPLICATION ROLE app_user; - --- Support functions -EXECUTE IMMEDIATE FROM 'support.sql'; \ No newline at end of file diff --git a/spcs-three-tier/application_upgrade_porgress_notification.sql b/spcs-three-tier/application_upgrade_porgress_notification.sql deleted file mode 100644 index d42aa14..0000000 --- a/spcs-three-tier/application_upgrade_porgress_notification.sql +++ /dev/null @@ -1,206 +0,0 @@ -CREATE or replace NOTIFICATION INTEGRATION my_email_int - TYPE=EMAIL - ENABLED=TRUE - ALLOWED_RECIPIENTS=(); - create database if not exists app_upgrade_state_notification_db; -create schema if not exists sch; -create table if not exists app_upgrade_state_notification_db.sch.upgrade_state_notification( - CONSUMER_SNOWFLAKE_REGION varchar, PROVIDER_ACCOUNT_LOCATOR varchar,PACKAGE_NAME varchar, - VERSION varchar, PATCH int, UPGRADE_STATE varchar, NOTIFICATION_STATE varchar, UPDATE_AT timestamp); - --- send notification email to app provider - -create or replace procedure app_upgrade_state_notification_db.sch.send_app_upgrade_notification(EMAIL varchar) - returns string - language javascript - comment = "set notification email to the app provider about the app upgrade progress" - execute as caller -AS -$$ - var query = ` select * from app_upgrade_state_notification_db.sch.upgrade_state_notification - where NOTIFICATION_STATE = 'NOT_SEND'; - `; - - var res = snowflake.createStatement({sqlText: query}).execute(); - var message_completed = ""; - var message_start = ""; - while(res.next()){ - var target = "In region " + res.getColumnValue("CONSUMER_SNOWFLAKE_REGION") - + " the app(s) installed from upgrade for version " + res.getColumnValue("VERSION") - + " patch " + res.getColumnValue("PATCH") - + " is " - if(res.getColumnValue("UPGRADE_STATE") == "UPGRATE_START"){ - message_start += target + "starting;\n"; - } else { - message_completed += target + "completed;\n"; - } - } -var message = message_start + message_completed; -if(message){ - - send_email_query = " call SYSTEM$SEND_EMAIL ('my_email_int', ' "+ EMAIL + "', 'Email Alert: APPs Upgrade Progress.', '" + message_start + message_completed + "')"; - - var send_email_res = snowflake.createStatement({sqlText: send_email_query}).execute(); - if(send_email_res.next()){ - if(send_email_res.getColumnValue(1) ===true){ - var update_query = `update app_upgrade_state_notification_db.sch.upgrade_state_notification - set NOTIFICATION_STATE = 'SENT' - where NOTIFICATION_STATE = 'NOT_SEND'; - `; - snowflake.createStatement({sqlText: update_query}).execute(); - } - } -} -return "DONE"; -$$; - --- A notification email will send when --- * the application starts to upgrade for a given snowflake region --- * the application upgrade completes for a given snowflake region --- * an application upgrade fails - -create or replace procedure app_upgrade_state_notification_db.sch.update_app_state_upgrade_notification(EMAIL varchar) - returns string - language javascript - comment = "update the upgrade_state_notification table when the app upgrade states changed based on the APPLICATION_STATE view" - execute as caller -AS -$$ -PROVIDER_ACCOUNT_LOCATOR = "PROVIDER_ACCOUNT_LOCATOR"; -const CONSUMER_SNOWFLAKE_REGION = "CONSUMER_SNOWFLAKE_REGION"; -const PACKAGE_NAME = "PACKAGE_NAME"; -const TARGET_UPGRADE_VERSION = "TARGET_UPGRADE_VERSION"; -const TARGET_UPGRADE_PATCH = "TARGET_UPGRADE_PATCH"; -const CURRENT_VERSION = "CURRENT_VERSION"; -const CURRENT_PATCH = "CURRENT_PATCH"; -const UPGRADE_STARTED_ON = "UPGRADE_STARTED_ON"; -const UPGRADE_STATE = "UPGRADE_STATE"; -const STATE_COMPLETED = "UPGRADE_COMPLETED"; -const STATE_START = "UPGRADE_START"; -const NOT_SEND = "NOT_SEND" -const SENT = "SENT" - -const keys_state = [CONSUMER_SNOWFLAKE_REGION, PROVIDER_ACCOUNT_LOCATOR, PACKAGE_NAME]; -const columns = keys_state.concat([CURRENT_VERSION, CURRENT_PATCH, TARGET_UPGRADE_VERSION, TARGET_UPGRADE_PATCH, UPGRADE_STARTED_ON, UPGRADE_STATE]); - -function getKey(row, keys){ - var keyString = ""; - for(var col of keys){ - keyString += (row[col] + ":"); - } - return keyString; -} - -function update_notification_table( to_update_row, version_patch, to_update_state ){ - var query = `select * from app_upgrade_state_notification_db.sch.upgrade_state_notification - where CONSUMER_SNOWFLAKE_REGION = ? and PROVIDER_ACCOUNT_LOCATOR = ? and PACKAGE_NAME = ? - and VERSION = ? and PATCH = ? ; - `; - var query_paras = [to_update_row[CONSUMER_SNOWFLAKE_REGION],to_update_row[PROVIDER_ACCOUNT_LOCATOR], - to_update_row[PACKAGE_NAME]].concat(version_patch).concat([NOT_SEND]); - var state_notification_rest = snowflake.createStatement({sqlText: query, binds: query_paras}).execute(); - if(state_notification_rest.next()){ - //not consider rollback case - if(state_notification_rest.getColumnValue(UPGRADE_STATE) == STATE_START && - to_updata_state == STATE_COMPLETED){ - - var update_query = ` - update app_upgrade_state_notification_db.sch.upgrade_state_notification - set UPGRADE_STATE = ? and UPGRADE_AT = CURRENT_TIMESTAMP() and NOTIFICATION_STATE = "NOT_SEND" - where CONSUMER_SNOWFLAKE_REGION = ? and PROVIDER_ACCOUNT_LOCATOR = ? and PACKAGE_NAME = ? - and VERSION = ? and PATCH = ? ; - `; - snowflake.createStatement({sqlText: update_query, binds: query_paras}).execute(); - } - } - else { - var insert_query = ` - INSERT INTO app_upgrade_state_notification_db.sch.upgrade_state_notification values(?, ?, ?, ?, ?, ?, ?, CURRENT_TIMESTAMP()); - `; - query_paras = query_paras.concat([NOT_SEND]); - snowflake.createStatement({sqlText: insert_query, binds: query_paras}).execute(); - } -} -const q = ` - select * from SNOWFLAKE.DATA_SHARING_USAGE.APPLICATION_STATE - where TARGET_UPGRADE_PATCH is not null - and UPGRADE_STATE != 'FAILED'; -`; -const stmt = snowflake.createStatement({sqlText: q}); -const res = stmt.execute(); -var state_result = {}; -while(res.next()){ - var row = {}; - for (var column of columns) { - row[column] = res.getColumnValue(column); - } - var key = getKey(row, keys_state); - state_result[key] = state_result[key] === undefined ? [row] : state_result[key].concate([row]); - } - - //sort the query result - for(const prop in state_result){ - var num_apps_for_pkg = state_result[prop].length; - var row_maybe_completed = {}; - var row_maybe_start = {}; - var target_for = []; - var completed_for = {}; - - // group the app state by region, app pkg account and app pkg name, current version/patch - for( var state_for_version of state_result[prop]){ - var key = getKey(state_for_version, ["CURRENT_VERSION", "CURRENT_PATCH"]); - completed_for[key] = completed_for[key] === undefined ? 1 : (completed_for[key] +1); - if(state_for_version["TARGET_UPGRADE_VERSION"]){ - if(state_for_version["UPGRADE_STATE"] == "FAILED"){ - // deal with failed - } - else { // suppose only one target version/patch. Actually it is possible with two or more target version/patches - target_for = [state_for_version["TARGET_UPGRADE_VERSION"], state_for_version["TARGET_UPGRADE_PATCH"]]; - row_maybe_completed = state_for_version; - } - } - if(Object.keys(row_maybe_completed).length ==0) { - row_maybe_completed = state_for_version; - } - } - - if(Object.keys(target_for).length >0){ - update_notification_table( row_maybe_completed, - [row_maybe_completed["TARGET_UPGRADE_VERSION"], row_maybe_completed["TARGET_UPGRADE_PATCH"]], STATE_START); - } - //should we consider the FAILED and DISABLED? - if(Object.keys(completed_for).length == 1){ - - var version_patch = Object.keys(completed_for)[0]; - // if all apps's current version/patch are the same, - // it means the upgrade for the version/patch is completed - if(completed_for[version_patch] && completed_for[version_patch] == num_apps_for_pkg){ - update_notification_table( row_maybe_completed, - [row_maybe_completed["CURRENT_VERSION"], row_maybe_completed["CURRENT_PATCH"]], STATE_COMPLETED); - } - }else if(Object.keys(completed_for).length == 2){ // there is a case that the two types of version/patch(eg. v1.0 and v1.1) are in COMPLETE state. In this case, we - // suppose the one version (v1.0) should be upgrade COMPLETED for all apps and the other one(v1.1) just start for upgrade - var version_patch1 = Object.keys(completed_for)[0]; - var version_patch2 = Object.keys(completed_for)[0]; - update_notification_table( row_maybe_completed, - [row_maybe_completed["CURRENT_VERSION"], row_maybe_completed["CURRENT_PATCH"]], STATE_START); - update_notification_table( row_maybe_completed, - [row_maybe_completed["CURRENT_VERSION"], row_maybe_completed["CURRENT_PATCH"]], STATE_START); - } - } -var call_send_email_query = "call app_upgrade_state_notification_db.sch.send_app_upgrade_notification('" + EMAIL + "')"; -//return call_send_email_query; - snowflake.createStatement({sqlText: call_send_email_query}).execute(); - -return "DONE"; -$$ -; - -call app_upgrade_state_notification_db.sch.update_app_state_upgrade_notification('yong.xu@snowflake.com'); - -CREATE OR REPLACE TASK app_upgrade_state_notification_db.sch.application_upgrade_notification_task - SCHEDULE = '720 minutes' --12 hours -AS call app_upgrade_state_notification_db.sch.update_app_state_upgrade_notification(); - -execute task app_upgrade_state_notification_db.sch.application_upgrade_notification_task; -