- 类别:
系统函数 (系统信息)
SYSTEM$SET_RETURN_VALUE¶
显式设置任务的返回值。
在 任务图 中,任务可以调用此函数来设置返回值。将此任务标识为前置任务的另一个任务(在任务定义中使用 AFTER
关键字)可以使用 SYSTEM$GET_PREDECESSOR_RETURN_VALUE 检索前置任务设置的返回值。
语法¶
SYSTEM$SET_RETURN_VALUE( '<string_expression>' )
string_expression
实参的值可以是字符串字面量或变量;例如 SYSTEM$SET_RETURN_VALUE(:VARIABLE)
。
实参¶
string_expression
要设置为返回值的字符串。字符串大小必须 <= 10 kB(使用 UTF8 编码时)。
示例¶
创建设置返回值的任务。创建在前置任务任务完成后运行的第二个子任务。子任务检索由前置任务设置的返回值(通过调用 SYSTEM$GET_PREDECESSOR_RETURN_VALUE)并将其插入表行:
-- Create a table to store the return values. CREATE OR REPLACE TABLE return_values (str VARCHAR); -- Create a task that sets the return value for the task. CREATE TASK set_return_value WAREHOUSE=return_task_wh SCHEDULE='1 MINUTE' AS CALL SYSTEM$SET_RETURN_VALUE('The quick brown fox jumps over the lazy dog'); -- Create a task that identifies the first task as the predecessor task and retrieves the return value set for that task. CREATE TASK get_return_value WAREHOUSE=return_task_wh AFTER set_return_value AS INSERT INTO return_values VALUES(SYSTEM$GET_PREDECESSOR_RETURN_VALUE()); -- Note that if there are multiple predecessor tasks that are enabled, you must specify the name of the task to retrieve the return value for that task. CREATE TASK get_return_value_by_pred WAREHOUSE=return_task_wh AFTER set_return_value AS INSERT INTO return_values VALUES(SYSTEM$GET_PREDECESSOR_RETURN_VALUE('SET_RETURN_VALUE')); -- Resume task (using ALTER TASK ... RESUME). -- Wait for task to run on schedule. SELECT DISTINCT(str) FROM return_values; +-----------------------------------------------+ | STR | +-----------------------------------------------+ | The quick brown fox jumps over the lazy dog | +-----------------------------------------------+ SELECT DISTINCT(RETURN_VALUE) FROM TABLE(information_schema.task_history()) WHERE RETURN_VALUE IS NOT NULL; +-----------------------------------------------+ | RETURN_VALUE | +-----------------------------------------------+ | The quick brown fox jumps over the lazy dog | +-----------------------------------------------+
示例 2:使用单独的存储过程调用¶
与第一个示例类似,但设置任务的返回值,并通过调用单独的存储过程来检索它:
-- Create a table to store the return values.
CREATE OR REPLACE TABLE return_values_sp (str VARCHAR);
-- Create a stored procedure that sets the return value for the task.
CREATE OR REPLACE PROCEDURE set_return_value_sp()
RETURNS STRING
LANGUAGE JAVASCRIPT
EXECUTE AS CALLER
AS $$
var stmt = snowflake.createStatement({sqlText:`CALL SYSTEM$SET_RETURN_VALUE('The quick brown fox jumps over the lazy dog');`});
var res = stmt.execute();
$$;
-- Create a stored procedure that inserts the return value for the predecessor task into the 'return_values_sp' table.
CREATE OR REPLACE PROCEDURE get_return_value_sp()
RETURNS STRING
LANGUAGE JAVASCRIPT
EXECUTE AS CALLER
AS $$
var stmt = snowflake.createStatement({sqlText:`INSERT INTO return_values_sp VALUES(SYSTEM$GET_PREDECESSOR_RETURN_VALUE());`});
var res = stmt.execute();
$$;
-- Create a task that calls the set_return_value stored procedure.
CREATE TASK set_return_value_t
WAREHOUSE=warehouse1
SCHEDULE='1 MINUTE'
AS
CALL set_return_value_sp();
-- Create a task that calls the get_return_value stored procedure.
CREATE TASK get_return_value_t
WAREHOUSE=warehouse1
AFTER set_return_value_t
AS
CALL get_return_value_sp();
-- Resume task.
-- Wait for task to run on schedule.
SELECT DISTINCT(str) FROM return_values_sp;
+-----------------------------------------------+
| STR |
+-----------------------------------------------+
| The quick brown fox jumps over the lazy dog |
+-----------------------------------------------+
SELECT DISTINCT(RETURN_VALUE)
FROM TABLE(information_schema.task_history())
WHERE RETURN_VALUE IS NOT NULL;
+-----------------------------------------------+
| RETURN_VALUE |
+-----------------------------------------------+
| The quick brown fox jumps over the lazy dog |
+-----------------------------------------------+
示例 3:使用变量来设置返回值¶
以下示例演示如何根据任务的执行动态生成返回值,并使用变量来设置返回值。在此示例中,任务将数据从流加载到登录表中,并设置返回值,以指示加载的行数:
CREATE OR REPLACE TASK load_raw_data
WAREHOUSE = 'WH'
WHEN
SYSTEM$STREAM_HAS_DATA('NEW_WEATHER_DATA')
AS
DECLARE
rows_loaded NUMBER;
result_string VARCHAR;
BEGIN
INSERT INTO raw_weather_data ( -- our landing table
row_id)
SELECT
row_id
FROM
new_weather_data -- our source stream
;
-- to see the number of rows loaded in the UI
rows_loaded := (SELECT $1 FROM TABLE(RESULT_SCAN(LAST_QUERY_ID())));
result_string := :rows_loaded || ' rows loaded into RAW_WEATHER_DATA';
-- show result string as task return value
CALL SYSTEM$SET_RETURN_VALUE(:result_string);
END;