共用方式為


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 未指定任何運算式來計算新的變數值,則為 。

  • query

    具有下列限制的任何格式正確的查詢:

    如果查詢未傳回任何資料列,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...