Skip to content

docs: sql variables #1234

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 3 commits into from
Sep 17, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
57 changes: 57 additions & 0 deletions docs/en/sql-reference/00-sql-reference/41-sql-variables.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
---
title: SQL Variables
sidebar_label: SQL Variables
---

SQL variables allow you to store and manage temporary data within a session.

## Variable DDL Commands

Databend provides the following DDL commands for using SQL variables:

- [SET VARIABLE](../10-sql-commands/00-ddl/15-variable/set-variable.md)
- [SHOW VARIABLES](../10-sql-commands/00-ddl/15-variable/show-variables.md)
- [UNSET VARIABLE](../10-sql-commands/00-ddl/15-variable/unset-variable.md)

The SHOW VARIABLES command has a corresponding table function, [SHOW_VARIABLES](../20-sql-functions/17-table-functions/show-variables.md), which provides the same information in a table format, allowing for more complex filtering and querying within SQL statements.

## Querying with Variables

This section explains how to effectively use variables in your queries, leveraging both `$` for value substitution and `IDENTIFIER` for accessing database objects like tables.

### Accessing Variables with `$` and `getvariable()`

You can reference the value of a variable within a SQL statement using either the `$` symbol or the `getvariable()` function. Both methods allow dynamic substitution, where the variable's value is directly embedded into the query at runtime.

```sql title='Example:'
-- Set a variable to use as a filter value
SET VARIABLE threshold = 100;

-- Use the variable in a query with $
SELECT * FROM sales WHERE amount > $threshold;

-- Alternatively, use the getvariable() function
SELECT * FROM sales WHERE amount > getvariable('threshold');
```

### Accessing Objects with `IDENTIFIER`

The `IDENTIFIER` keyword allows you to dynamically reference database objects whose names are stored in variables. Please note that accessing objects with `IDENTIFIER` is *not* supported by BendSQL yet.

```sql title='Example:'
-- Create a table with sales data
CREATE TABLE sales_data (region TEXT, sales_amount INT, month TEXT) AS
SELECT 'North', 5000, 'January' UNION ALL
SELECT 'South', 3000, 'January';

select * from sales_data;

-- Set variables for the table name and column name
SET VARIABLE table_name = 'sales_data';
SET VARIABLE column_name = 'sales_amount';

-- Use IDENTIFIER to dynamically reference the table and column in the query
SELECT region, IDENTIFIER($column_name)
FROM IDENTIFIER($table_name)
WHERE IDENTIFIER($column_name) > 4000;
```
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
{
"label": "Variable",
"position": 19
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
---
title: Variable
---
import IndexOverviewList from '@site/src/components/IndexOverviewList';

This page provides reference information for the variable-related commands in Databend.

<IndexOverviewList />
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
---
title: SET VARIABLE
---
import FunctionDescription from '@site/src/components/FunctionDescription';

<FunctionDescription description="Introduced or updated: v1.2.609"/>

Sets the value of one or more SQL variables within a session. The values can be simple constants, expressions, query results, or database objects.

## Syntax

```sql
-- Set one variable
SET VARIABLE <variable_name> = <expression>

-- Set more than one variable
SET VARIABLE (<variable1>, <variable2>, ...) = (<expression1>, <expression2>, ...)
```

## Examples

The following example sets a single variable:

```sql
-- sets variable a to the string 'databend'
SET VARIABLE a = 'databend';
```

The following example sets a variable with the table name and uses IDENTIFIER to dynamically query the table based on that variable:

```sql
CREATE TABLE monthly_sales(empid INT, amount INT, month TEXT) AS SELECT 1, 2, '3';

-- Set a variable 't' to the name of the table 'monthly_sales'
SET VARIABLE t = 'monthly_sales';

-- Use IDENTIFIER to dynamically reference the table name stored in the variable 't'
SELECT * FROM IDENTIFIER($t);

empid|amount|month|
-----+------+-----+
1| 2|3 |
```

The following example sets multiple variables from a query in a single statement. The query must return exactly one row, with the same number of values as the variables being set.

```sql
-- Sets variable a to 3 and b to 55
SET VARIABLE (a, b) = (SELECT 3, 55);
```

The following example sets multiple variables to constants:

```sql
-- Sets variable x to 'xx' and y to 'yy'
SET VARIABLE (x, y) = ('xx', 'yy');
```
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
---
title: SHOW VARIABLES
---
import FunctionDescription from '@site/src/components/FunctionDescription';

<FunctionDescription description="Introduced or updated: v1.2.634"/>

Displays all session variables and their details, such as names, values, and types.

See also: [SHOW_VARIABLES](/sql/sql-functions/table-functions/show-variables)

## Syntax

```sql
SHOW VARIABLES [ LIKE '<pattern>' | WHERE <expr> ]
```

## Examples

The following example lists all session variables with their values and types:

```sql
SHOW VARIABLES;

┌──────────────────────────┐
│ name │ value │ type │
├────────┼────────┼────────┤
│ a │ 3 │ UInt8 │
│ b │ 55 │ UInt8 │
│ x │ 'xx' │ String │
│ y │ 'yy' │ String │
└──────────────────────────┘
```

To filter and return only the variable named `a`, use one of the following queries:

```sql
SHOW VARIABLES LIKE 'a';

SHOW VARIABLES WHERE name = 'a';
```
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
---
title: UNSET VARIABLE
---
import FunctionDescription from '@site/src/components/FunctionDescription';

<FunctionDescription description="Introduced or updated: v1.2.609"/>

Removes one or more variables from the current session.

## Syntax

```sql
-- Remove one variable
UNSET VARIABLE <variable_name>

-- Remove more than one variable
UNSET VARIABLE (<variable1>, <variable2>, ...)
```

## Examples

The following example unsets a single variable:

```sql
-- Remove the variable a from the session
UNSET VARIABLE a;
```

The following example unsets multiple variables:

```sql
-- Remove variables x and y from the session
UNSET VARIABLE (x, y);
```
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
---
title: SHOW_VARIABLES
---
import FunctionDescription from '@site/src/components/FunctionDescription';

<FunctionDescription description="Introduced or updated: v1.2.634"/>

Displays all session variables and their details, such as names, values, and types.

See also: [SHOW VARIABLES](/sql/sql-commands/ddl/variable/show-variables)

## Syntax

```sql
SHOW_VARIABLES()
```

## Examples

```sql
SELECT name, value, type FROM SHOW_VARIABLES();

┌──────────────────────────┐
│ name │ value │ type │
├────────┼────────┼────────┤
│ y │ 'yy' │ String │
│ b │ 55 │ UInt8 │
│ x │ 'xx' │ String │
│ a │ 3 │ UInt8 │
└──────────────────────────┘
```
Loading