EXECUTE IMMEDIATE FROM¶
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.
- See also:
Note
Currently, file executions allow the creation of scoped transactions. This will change in the future.
Syntax¶
EXECUTE IMMEDIATE
FROM { absoluteFilePath | relativeFilePath }
Where:
absoluteFilePath ::= @[ <namespace>. ]<stage_name>/<path>/<filename>relativeFilePath ::= '[ { ./ | / | { ../ [ , ../, ... ] } } ]<path>/<filename>'
namespace
is the database and/or schema in which the internal or external stage resides, in the form ofdatabase_name.schema_name
orschema_name
. It is optional if a database and schema are currently in use within the user session; otherwise, it is required.
stage_name
is the name of the internal or external stage.
path
is a case-sensitive path to the file in the stage.
filename
is the name of the file to execute. It must contain syntactically correct and valid SQL statements. Statements must be separated by a semicolon.
Returns¶
EXECUTE IMMEDIATE FROM returns:
The result of the last statement in the file if all statements are successfully executed.
The error message, if any statement in the file failed.
If there is an error in any statement in the file, the EXECUTE IMMEDIATE FROM command fails and returns the error message of the failed statement.
Note
If the EXECUTE IMMEDIATE FROM command fails and returns an error message, any statements in the file prior to the failed statement have successfully completed.
Access Control Requirements¶
The role used to execute the EXECUTE IMMEDIATE FROM command must have the USAGE (external stage) or READ (internal stage) privilege on the stage where the file is located.
The role used to execute the file can only execute the statements in the file for which it has privileges. For example, if there is a CREATE TABLE statement in the file, the role must have the necessary privileges to create a table in the account or the statement fails.
Note that operating on any object in a schema also requires the USAGE privilege on the parent database and 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 on securable objects, see Overview of Access Control.
Usage Notes¶
The SQL statements in a file to be executed can include EXECUTE IMMEDIATE FROM statements:
Nested EXECUTE IMMEDIATE FROM statements can use relative file paths.
Relative paths are evaluated in respect to the stage and file path of the parent file. If the relative file path starts with
/
, the path starts at the root directory of the stage containing the parent file.For an example, see Basic Examples.
Relative file paths must be enclosed in single quotes.
The maximum execution depth for nested files is 5.
Absolute file paths can optionally be enclosed in single quotes.
The file to be executed cannot be larger than 10MB in size.
The file to be executed must be encoded in UTF-8.
The file to be executed must be uncompressed. If you use the PUT command to upload a file to an internal stage, you must explicitly set the AUTO_COMPRESS parameter to FALSE.
For example, upload
my_file.sql
tomy_stage
:PUT file://~/sql/scripts/my_file.sql @my_stage/scripts/ AUTO_COMPRESS=FALSE;
Examples¶
Basic Examples¶
This example executes the file create-inventory.sql
located in stage my_stage
.
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;
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);
Create an internal stage
my_stage
:CREATE STAGE my_stage;
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;
Execute the
create-inventory.sql
script located inmy_stage
:EXECUTE IMMEDIATE FROM @my_stage/scripts/create-inventory.sql;
Returns:
+----------+-------+ | SKU | PRICE | |----------+-------| | XYZ81974 | 50 | | XYZ34985 | 30 | | XYZ15324 | 15 | | XYZ12345 | 10 | +----------+-------+