SET VARIABLE

适用于:勾选“是” Databricks SQL 勾选“是” Databricks Runtime 14.1 及更高版本

修改一个或多个临时变量的值。

若要设置配置参数,请使用 SET

语法

SET { VAR | VARIABLE } { variable_name = { expression | DEFAULT } } [, ...]

SET { VAR | VARIABLE } ( variable_name [, ...] ) = ( query ) }

参数

  • variable_name

    指定临时变量的名称。

    如果找不到该变量,Azure Databricks 会引发 UNRESOLVED_VARIABLE 错误。

    如果指定重复变量,Azure Databricks 会引发 DUPLICATE_ASSIGNMENTS 错误。

  • expression

    计算新变量值的任何格式良好的表达式。

  • DEFAULT

    如果未指定任何表达式来计算新变量值,则使用变量的默认表达式或 NULL

  • 查询

    具有以下限制的任何格式正确的查询:

    如果查询不返回任何行,Azure Databricks 会将所有指定的变量设置为 NULL

    可以使用 DEFAULT 关键字而不是 select-list 表达式将变量设置为其默认值。

示例

> DECLARE VARIABLE myvar1 INT DEFAULT 7;
> DECLARE VARIABLE myvar2 STRING DEFAULT 'hello';

-- Set a SQL variable to a value
> SET VAR myvar1 = 5;
> VALUES (myvar1);
  5

-- Set a SQL variable back to DEFAULT
> SET VARIABLE myvar1 = DEFAULT;
> VALUES (myvar1);
  7

-- Set a SQL variable to the result of a scalar subquery.
> SET VARIABLE myvar1 = (SELECT max(c1) FROM VALUES(1), (2) AS T(c1));
> VALUES (myvar1);
  2

-- Set multiple variables from a query
> SET VAR (myvar1, myvar2) = (VALUES(10, 'world'));
> VALUES (myvar1, myvar2);
  10   world

-- Set multiple variables from expressions
> SET VAR myvar1 = 11, myvar2 = 'hello';
> VALUES (myvar1, myvar2);
  11   hello

-- Set multiple variables based on a query
> SET VARIABLE (myvar1, myvar2)
    = (SELECT max(c1), CAST(min(c1) AS STRING) FROM VALUES(1), (2) AS T(c1));
> VALUES (myvar1, myvar2);
  2    1

-- Assign NULLs on empty query
> SET VAR (myvar1, myvar2)
    = (SELECT max(c1), CAST(min(c1) AS STRING) FROM VALUES(1), (2) AS T(c1) HAVING max(c1) = 0);
> VALUES (myvar1, myvar2);
  NULL  NULL

-- Using a variable with an IDENTIFIER clause
> DECLARE colname STRING;
> SET VAR colname = 'c1';
> SELECT IDENTIFIER(colname) FROM VALUES(1, 2) AS T(c1, c2);
  1

> SET VARIABLE colname = 'c2';
> SELECT IDENTIFIER(colname) FROM VALUES(1, 2) AS T(c1, c2);
  2

-- Variable defaults are recomputed
> DECLARE VARIABLE val DEFAULT RAND();
> SELECT val;
  0.1234...

> SET VARIABLE val = DEFAULT;
> SELECT val;
  0.9876...