EXECUTE IMMEDIATE FROM | Snowflake Documentation (original) (raw)

EXECUTE IMMEDIATE FROM executes the SQL statements specified in a file in a stage. The file can contain SQL statements or Snowflake Scripting blocks. The statements must be syntactically correct SQL statements.

You can use the EXECUTE IMMEDIATE FROM command to execute the statements in a file from any Snowflake session.

This feature provides a mechanism to control the deployment and management of your Snowflake objects and code. For example, you can execute a stored script to create a standard Snowflake environment for all your accounts. The configuration script might include statements that create users, roles, databases, and schemas for every new account.

Jinja2 templating

EXECUTE IMMEDIATE FROM can also execute a template file using the Jinja2 templating language. A template can contain variables and expressions, enabling the use of loops, conditionals, variable substitution, macros, and more. Templates can also include other templates and can import macros defined in other files located on a stage.

For more information about the templating language, see the Jinja2 documentation.

The template file to be executed must be:

Templating enables more flexible control structures and parameterization using environment variables. For example, you can use a template to dynamically choose the deployment target of the objects defined in the script. To use a template to render a SQL script, use the templating directive or add aUSING clause with at least one template variable.

Templating directive

You can use either one of the two templating directives.

The recommended directive uses valid SQL syntax:

Optionally, you can use the alternative directive:

Note

Only a byte order mark and up to 10 whitespace characters (newlines, tabs, spaces) may be placed in front of the directive. Any characters that come after the directive on the same line will be ignored.

Using content from staged files in a template

A template can load other staged files either directly through theSnowflakeFile APIor through Jinja2’s include,import, andinheritance features.

Files can be referenced by absolute paths:

{% include "@my_stage/path/to/my_template" %} {% import "@my_stage/path/to/my_template" as my_template %} {% extends "@my_stage/path/to/my_template" %} {{ SnowflakeFile.open("@my_stage/path/to/my_template", 'r', require_scoped_url = False).read() }}

Include, import, and extends also support relative paths while the SnowflakeFile API supports scoped Snowflake file URLs:

{% include "my_template" %} {% import "../my_template" as my_template %} {% extends "/path/to/my_template" %}

See also:

EXECUTE IMMEDIATE

Syntax

EXECUTE IMMEDIATE FROM { absoluteFilePath | relativeFilePath } [ USING ( => [ , => [ , ... ] ] ) ] [ DRY_RUN = { TRUE | FALSE } ]

Where:

Required parameters

Absolute file path (absoluteFilePath)

_namespace_

Database and/or schema in which the internal or external stage resides, in the form of _databasename_._schemaname_or _schemaname_. The namespace is optional if a database and schema are currently in use for the user session; otherwise, it is required.

_stagename_

Name of the internal or external stage.

_path_

Case-sensitive path to the file in the stage.

_filename_

Name of the file to execute. It must contain syntactically correct and valid SQL statements. Each statement must be separated by a semicolon.

Relative file path (relativeFilePath)

_path_

Case-sensitive relative path to the file in the stage. Relative paths support established conventions such as a leading /to indicate the root of a stage’s file system, ./ to refer to the current directory (the directory the parent file is located in) and ../ to refer to the parent directory. For more information, see Usage notes.

_filename_

Name of the file to execute. It must contain syntactically correct and valid SQL statements. Each statement must be separated by a semicolon.

Optional parameters

USING ( <key> => <value> [ , <key> => <value> [ , ... ] ] )

Allows you to pass one or more key-value pairs that can be used to parameterize template expansion. The key-value pairs must form a comma-separated list.

When the USING clause is present, the file is first rendered as a Jinja2 templatebefore being executed as a SQL script.

Where:

DRY_RUN = { TRUE | FALSE }

Specifies whether to preview the rendered file without executing it as a SQL script.

Default: FALSE

Returns

EXECUTE IMMEDIATE FROM returns:

Access control requirements

The USAGE privilege on the parent database and schema are required to perform operations on any object in a schema.

For instructions on creating a custom role with a specified set of privileges, see Creating custom roles.

For general information about roles and privilege grants for performing SQL actions onsecurable objects, see Overview of Access Control.

Usage notes

Templating usage notes

Troubleshooting EXECUTE IMMEDIATE FROM errors

This section contains some common errors that result from an EXECUTE IMMEDIATE FROM statement and how you can resolve them.

File errors

Error 001501 (02000): File '<directory_name>' not found in stage '<stage_name>'.
Cause There are multiple causes for this error: The file does not exist. The file name is the root of a directory. For example @stage_name/scripts/.
Solution Verify the name of the file and confirm the file exists. Executing all the files in a directory is not supported.
Error 001503 (42601): Relative file references like '<filename.sql>' cannot be used in top-level EXECUTE IMMEDIATE calls.
Cause The statement was executed using a relative file path outside of a file execution.
Solution A relative file path can only be used in EXECUTE IMMEDIATE FROM statements in a file. Use theabsolute file path for the file. For more information, seeUsage notes.
Error 001003 (42000): SQL compilation error: syntax error line at position unexpected ''.
Cause The file contains SQL syntax errors.
Solution Fix the syntax errors in the file and reupload the file to the stage.

Stage errors

Error 002003 (02000): SQL compilation error: Stage '<stage_name>' does not exist or not authorized.
Cause The stage does not exist or you do not have access to the stage.
Solution Verify the name of the stage and confirm the stage exists. Execute the statement using a role that has the required privileges to access the stage. For more information, seeAccess control requirements.

Access control errors

Error 003001 (42501): Uncaught exception of type 'STATEMENT_ERROR' in file <file_name> on line at position : SQL access control error: Insufficient privileges to operate on schema '<schema_name>'
Cause The role used to execute the statement does not have the privileges required to execute some or all of the statements in the file.
Solution Use a role that has the appropriate privileges to execute the statements in the file. For more information, seeAccess control requirements.

See also: Stage errors.

Templating errors

Error 001003 (42000): SQL compilation error: syntax error line [n] at position [m] unexpected '{'.
Cause The file contains templating constructs (for example, {{ table_name }}) but is not rendered using the templating engine. If the template is not rendered, the lines of text in the template are executed as SQL statements. The templating constructs in the file are likely to result in SQL syntax errors.
Solution Add a templating directive or re-execute the statement with theUSING clause and specify at least one template variable.
Error 000005 (XX000): Python Interpreter Error: jinja2.exceptions.UndefinedError: '' is undefined in template processing
Cause If any variables used in the template are left unspecified in the USING clause, an error occurs.
Solution Verify the names and number of variables in the template and update the USING clause to include values for all template variables.
Error 001510 (42601): Unable to use value of template variable ''
Cause The value for the variable key is an unsupported type.
Solution Verify that you are using a supported parameter type for the template variable value. For more information, see theTemplating usage notes.
Error 001518 (42601): Size of expanded template exceeds limit of 100,000 bytes.
Cause The size of the rendered template exceeds the current limit.
Solution Split your templated file into multiple smaller templates and add a new script to execute them sequentially, while passing down template variables to the nested scripts.

Examples

Basic example

This example executes the file create-inventory.sql located in stage my_stage.

  1. Create a file named create-inventory.sql with the following statements:
    CREATE OR REPLACE TABLE my_inventory(
    sku VARCHAR,
    price NUMBER
    );
    EXECUTE IMMEDIATE FROM './insert-inventory.sql';
    SELECT sku, price
    FROM my_inventory
    ORDER BY price DESC;
  2. Create a file named insert-inventory.sql with the following statements:
    INSERT INTO my_inventory
    VALUES ('XYZ12345', 10.00),
    ('XYZ81974', 50.00),
    ('XYZ34985', 30.00),
    ('XYZ15324', 15.00);
  3. Create an internal stage my_stage:
  4. Upload both local files to the stage using the PUT command:
    PUT file:///sql/scripts/create-inventory.sql @my_stage/scripts/
    AUTO_COMPRESS=FALSE;
    PUT file://
    /sql/scripts/insert-inventory.sql @my_stage/scripts/
    AUTO_COMPRESS=FALSE;
  5. Execute the create-inventory.sql script located in my_stage:
    EXECUTE IMMEDIATE FROM @my_stage/scripts/create-inventory.sql;
    Returns:
    +----------+-------+
    | SKU | PRICE |
    |----------+-------|
    | XYZ81974 | 50 |
    | XYZ34985 | 30 |
    | XYZ15324 | 15 |
    | XYZ12345 | 10 |
    +----------+-------+

A simple template example

  1. Create a template file setup.sql with two variables and the templating directive:
    --!jinja
    CREATE SCHEMA {{env}};
    CREATE TABLE RAW (COL OBJECT)
    DATA_RETENTION_TIME_IN_DAYS = {{retention_time}};
  2. Create a stage — optional if you already have a stage to which you can upload files.
    For example, create an internal stage in Snowflake:
  3. Upload the file to your stage.
    For example, use the PUT command from your local environment to upload file setup.sqlto stage my_stage:
    PUT file://path/to/setup.sql @my_stage/scripts/
    AUTO_COMPRESS=FALSE;
  4. Execute the file setup.sql:
    EXECUTE IMMEDIATE FROM @my_stage/scripts/setup.sql
    USING (env=>'dev', retention_time=>0);

A template example with macros, conditionals, loops, and imports

  1. Create a template file containing a macro definition.
    For example, create a file macros.jinja in your local environment:
    {%- macro get_environments(deployment_type) -%}
    {%- if deployment_type == 'prod' -%}
    {{ "prod1,prod2" }}
    {%- else -%}
    {{ "dev,qa,staging" }}
    {%- endif -%}
    {%- endmacro -%}
  2. Create a template file and add the templating directive (--!jinja2) to the top of the file.
    After the templating directive, add an import statement to import the macro defined in the file that you created in the previous step. For example, create a file setup-env.sql in your local environment:
    --!jinja2
    {% from "macros.jinja" import get_environments %}
    {%- set environments = get_environments(DEPLOYMENT_TYPE).split(",") -%}
    {%- for environment in environments -%}
    CREATE DATABASE {{ environment }}_db;
    USE DATABASE {{ environment }}_db;
    CREATE TABLE {{ environment }}_orders (
    id NUMBER,
    item VARCHAR,
    quantity NUMBER);
    CREATE TABLE {{ environment }}_customers (
    id NUMBER,
    name VARCHAR);
    {% endfor %}
  3. Create a stage — optional if you already have a stage to which you can upload files.
    For example, create an internal stage in Snowflake:
  4. Upload the file to your stage.
    For example, use the PUT command from your local environment to upload the filessetup-env.sql and macros.jinja to the stage my_stage:
    PUT file://path/to/setup-env.sql @my_stage/scripts/
    AUTO_COMPRESS=FALSE;
    PUT file://path/to/macros.jinja @my_stage/scripts/
    AUTO_COMPRESS=FALSE;
  5. Preview the SQL statements rendered by the template to check for any problems with your Jinja2 code:
    EXECUTE IMMEDIATE FROM @my_stage/scripts/setup-env.sql
    USING (DEPLOYMENT_TYPE => 'prod') DRY_RUN = TRUE;
    Returns:
    +----------------------------------+
    rendered file contents
    --!jinja2
    CREATE DATABASE prod1_db;
    USE DATABASE prod1_db;
    CREATE TABLE prod1_orders (
    id NUMBER,
    item VARCHAR,
    quantity NUMBER);
    CREATE TABLE prod1_customers (
    id NUMBER,
    name VARCHAR);
    CREATE DATABASE prod2_db;
    USE DATABASE prod2_db;
    CREATE TABLE prod2_orders (
    id NUMBER,
    item VARCHAR,
    quantity NUMBER);
    CREATE TABLE prod2_customers (
    id NUMBER,
    name VARCHAR);

+----------------------------------+ 6. Execute the file setup-env.sql:
EXECUTE IMMEDIATE FROM @my_stage/scripts/setup-env.sql
USING (DEPLOYMENT_TYPE => 'prod');