Skip to content
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

docs for DECLARE syntax #86

Open
wants to merge 28 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from 23 commits
Commits
Show all changes
28 commits
Select commit Hold shift + click to select a range
8e939c4
initial draft, more examples nad proper railroad tba
nwoolmer Nov 28, 2024
31959d6
Merge branch 'main' into nw_declare
nwoolmer Nov 28, 2024
61f9497
point at railroad
nwoolmer Nov 28, 2024
7935793
add missing FROM-TO
nwoolmer Nov 28, 2024
8b27de5
railroads
nwoolmer Nov 28, 2024
ab7b3eb
iterate
nwoolmer Nov 29, 2024
c78aebe
iterate
nwoolmer Nov 29, 2024
69f2ac7
Merge branch 'main' into nw_declare
nwoolmer Nov 29, 2024
5a81e08
swap to a limitations section, makes more sense
nwoolmer Nov 29, 2024
f800013
we will support subqueries as variables
nwoolmer Dec 2, 2024
847ab3f
amended docs, subqueries supported
nwoolmer Dec 2, 2024
e88c043
disclaimer
nwoolmer Dec 2, 2024
0a7aab1
add functions example
nwoolmer Dec 2, 2024
d8fc94e
Merge branch 'refs/heads/main' into nw_declare
nwoolmer Dec 2, 2024
98f5c16
Merge branch 'main' into nw_declare
goodroot Dec 2, 2024
8af3a1b
semicolons
nwoolmer Dec 4, 2024
4427545
Merge remote-tracking branch 'origin/nw_declare' into nw_declare
nwoolmer Dec 4, 2024
82124ba
example
nwoolmer Dec 4, 2024
dec9074
Merge branch 'main' into nw_declare
goodroot Dec 5, 2024
8dede5b
add sql frag
nwoolmer Dec 6, 2024
bddc2b5
Merge remote-tracking branch 'origin/nw_declare' into nw_declare
nwoolmer Dec 6, 2024
b0c769d
Update declare.md
nwoolmer Jan 7, 2025
115bea6
fix example
nwoolmer Jan 9, 2025
5900259
Apply suggestions from code review
nwoolmer Jan 9, 2025
9f3398a
Update declare.md
nwoolmer Jan 9, 2025
9c68266
psycopg example
nwoolmer Jan 9, 2025
fb6d61b
Merge branch 'main' into nw_declare
goodroot Jan 10, 2025
0a3628e
polish
goodroot Jan 10, 2025
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
2 changes: 2 additions & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -35,3 +35,5 @@ yarn-error.log*
.log
src/css/infima.css
.ignore

.yarn/sdks
289 changes: 289 additions & 0 deletions documentation/reference/sql/declare.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,289 @@
---
title: DECLARE keyword
sidebar_label: DECLARE
description: DECLARE SQL keyword reference documentation.
---

`DECLARE` is used to specify a series of variables bindings to be used
throughout your query.

This syntax is supported specifically for `SELECT` queries.

:::note

`DECLARE` was added to QuestDB in version 8.2.2 (TBD provisional).

Versions prior to this do not support this syntax.

:::

## Syntax

![Flow chart showing the syntax of the DECLARE keyword](/images/docs/diagrams/declare.svg)

## Mechanics

The `DECLARE` keyword comes before the `SELECT` clause in your query:

```questdb-sql title="Basic DECLARE" demo
DECLARE
@x := 5
SELECT @x;
```

Use the variable binding operator `:=` (walrus) to associate expressions to names.

In the above example, a single binding is declared, which states that the variable `@x` should
be replaced with the constant integer `5`.

The variables are resolved at parse-time, meaning that variable is no longer present
when the query is compiled. So the above example reduces to this simple query:

```questdb-sql title="basic DECLARE post-reduction" demo
SELECT 5;
```

| 5 |
|---|
| 5 |


:::note

It is easy to accidentally omit the `:` when writing variable binding expressions.

Don't confuse the `:=` operator with a simple equality `=`!

You should see an error message like this:
> expected variable assignment operator `:=`
>
:::

### Multiple bindings

You can declare multiple variables by setting the bind expressions with commas `,`:

```questdb-sql title="Multiple variable bindings" demo
DECLARE
@x := 5,
@y := 2
SELECT @x + @y;
```

| column |
|--------|
| 7 |

### Variables as functions

A variable need not be just a constant, it could be a function call,
and variables with function values can be nested:

```questdb-sql title="declaring function variable" demo
DECLARE
@today := today(),
@start := interval_start(@today),
@end := interval_end(@today)
SELECT @today = interval(@start, @end);
```

| column |
|--------|
| true |


### Declarations in subqueries

Declarations made in parent queries are available in subqueries.

```questdb-sql title="variable shadowing" demo
DECLARE
@x := 5
SELECT y FROM (
SELECT @x AS y
);
```

| y |
|---|
| 5 |

#### Shadowing

If a subquery declares a variable of the same name, then the variable is shadowed
and takes on the new value. However, any queries above this subquery are unaffected - the
variable bind is not globally mutated.

```questdb-sql title="variable shadowing" demo
DECLARE
@x := 5
SELECT @x + y FROM (
DECLARE @x := 10
SELECT @x AS y
);
```

| column |
|--------|
| 15 |

### Declarations as subqueries

Declarations themselves can be subqueries. We suggest that this
is not overused, as removing the subquery definition from its execution
location may make queries harder to debug.

Nevertheless, it is possible to define a variable as a subquery:

```questdb-sql title="table cursor as a variable" demo
DECLARE
@subquery := (SELECT timestamp FROM trades)
SELECT * FROM @subquery;
```

You can even use already-declared variables to define your subquery variable:

```questdb-sql title="nesting decls inside decl subqueries" demo
DECLARE
@timestamp := timestamp,
@symbol := symbol,
@subquery := (SELECT @timestamp, @symbol FROM trades)
SELECT * FROM @subquery;
```

### Declarations in CTEs

Naturally, `DECLARE` also works with CTEs:

```questdb-sql title="declarations inside CTEs" demo
DECLARE
@x := 5
WITH first AS (
DECLARE @x := 10
SELECT @x as a -- a = 10
),
second AS (
DECLARE @y := 4
SELECT
@x + @y as b, -- b = 5 + 4 = 9
a -- a = 10
FROM first
)
SELECT a, b
FROM second;
```

| a | b |
|----|---|
| 10 | 9 |


### Bind variables

`DECLARE` syntax will work with prepared statements over PG Wire, so long as the client library
does not perform syntax validation that rejects the `DECLARE` syntax.


```questdb-sql
DECLARE @x := ?, @y := ?
SELECT @x::int + @y::int;

-- Then bind the following values: (1, 2)
```

| column |
|--------|
| 3 |

This can be useful to minimise repeated bind variables. For example, rather than passing the same value to multiple positional arguments,
you could instead use a declared variable and send a single bind variable:


```questdb-sql
-- instead of this:
SELECT ? as name, id FROM users WHERE name = ?;

-- do this:
DECLARE @name := '?'
nwoolmer marked this conversation as resolved.
Show resolved Hide resolved
SELECT @name as name, id FROM users WHERE name = @name;
```

nwoolmer marked this conversation as resolved.
Show resolved Hide resolved
## Limitations

Most basic expressions are supported, and we provide examples later in this document. We suggest
you use variables to simplify repeated constants within your code, and minimise
how many places you need to update the constant.

However, not all expressions are supported. The following are explicitly disallowed:

### Bracket lists

```questdb-sql title="bracket lists are not allowed"
DECLARE
@symbols := ('BTC-USD', 'ETH-USD')
SELECT timestamp, price, symbol
FROM trades
WHERE symbol IN @symbols;

-- error: unexpected bind expression - bracket lists not supported
```

### SQL statement fragments

```questdb-sql title="sql fragments are not allowed"
DECLARE
@x := FROM trades
SELECT 5 @x;

-- table and column names that are SQL keywords have to be enclosed in double quotes, such as "FROM"```
```

## Examples

### SAMPLE BY

```questdb-sql title="DECLARE with SAMPLE BY" demo
DECLARE
@period := 1m,
@window := '2024-11-25',
@symbol := 'ETH-USD'
SELECT
timestamp, symbol, side, sum(amount) as volume
FROM trades
WHERE side = 'sell'
AND timestamp IN @window
AND symbol = @symbol
SAMPLE BY @period
FILL(NULL);
```

| timestamp | symbol | side | volume |
|-----------------------------|---------|------|------------------|
| 2024-11-25T00:00:00.000000Z | ETH-USD | sell | 153.470574999999 |
| 2024-11-25T00:01:00.000000Z | ETH-USD | sell | 298.927738 |
| 2024-11-25T00:02:00.000000Z | ETH-USD | sell | 66.253058 |
| ... | ... | ... | ... |

### INSERT INTO SELECT

```questdb-sql
INSERT INTO trades SELECT * FROM
(
DECLARE
@x := now(),
@y := 'ETH-USD'
SELECT @x as timestamp, @y as symbol
);
nwoolmer marked this conversation as resolved.
Show resolved Hide resolved
```

### CREATE TABLE AS SELECT

```questdb-sql
CREATE TABLE trades AS (
DECLARE
@x := now(),
@y := 'ETH-USD'
SELECT @x as timestamp, @y as symbol, 123 as price
);
```

4 changes: 4 additions & 0 deletions documentation/reference/sql/sample-by.md
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,10 @@ use of the [FILL](#fill-options) keyword to specify a fill behavior.

![Flow chart showing the syntax of the SAMPLE BY keywords](/images/docs/diagrams/sampleBy.svg)

### FROM-TO keywords

![Flow chart showing the syntax of the FROM-TO keywords](/images/docs/diagrams/fromTo.svg)

### FILL keywords

![Flow chart showing the syntax of the FILL keyword](/images/docs/diagrams/fill.svg)
Expand Down
1 change: 1 addition & 0 deletions documentation/sidebars.js
Original file line number Diff line number Diff line change
Expand Up @@ -187,6 +187,7 @@ module.exports = {
type: "doc",
customProps: { tag: "Enterprise" },
},
"reference/sql/declare",
"reference/sql/distinct",
"reference/sql/drop",
{
Expand Down
16 changes: 12 additions & 4 deletions static/images/docs/diagrams/.railroad
Original file line number Diff line number Diff line change
Expand Up @@ -33,7 +33,11 @@ cancelQuery
::= 'CANCEL' 'QUERY' queryId

createTableDef
::= 'CREATE' 'TABLE' ('IF' 'NOT' 'EXISTS')? tableName
::= 'CREATE' (
('ATOMIC')?
|
('BATCH' number ('o3MaxLag' numberWithUnit)?) )
'TABLE' ('IF' 'NOT' 'EXISTS')? tableName
(
(
'(' columnName typeDef (',' columnName typeDef)* ')'
Expand Down Expand Up @@ -62,6 +66,10 @@ createServiceAccount
alterTable
::= 'ALTER' 'TABLE' tableName

declare
::= 'DECLARE' '@variable' ':=' expression ( ',' '@variable' ':=' expression )* withExpr? selectExpr


dropGroup
::= 'DROP' 'GROUP' ('IF' 'EXISTS')? groupName

Expand Down Expand Up @@ -95,14 +103,14 @@ tableTargetVolumeDef
::= ','? 'IN' 'VOLUME' "'"? secondaryVolumeAlias "'"?

insertInto
::= 'INSERT' ('batch' batchCount)?
::= 'INSERT' (('ATOMIC')? | ('BATCH' number ('o3MaxLag' numberWithUnit)?) )
'INTO' tableName ( ( '(' columnName (',' columnName)*) ')')?
( 'VALUES' ( ( '(' value ( ',' value)* ')' ) (',' '(' value ( ',' value)* ')' )* ) | 'SELECT' queryDef mainQuery )
';'

withAsInsert
::= ( 'WITH' subQueryName 'AS' '(' subQuery ')' ( ',' subQueryName 'AS' '(' subQuery ')' )* )?
'INSERT' ( 'batch' batchCount )? 'INTO' tableName 'SELECT' queryDef subQueryName ';'
::= ( 'WITH' subQueryName 'AS' '(' subQuery ')' ( ',' subQueryName 'AS' '(' subQuery ')' )* )?
'INSERT' (('ATOMIC')? | ('BATCH' number ('o3MaxLag' numberWithUnit)?) ) 'INTO' tableName 'SELECT' queryDef subQueryName ';'

insertCommitLagInto
::= 'INSERT' ('batch' batchCount 'commitLag' n ( 'us' | 's' | 'm' | 'h' | 'd' ))?
Expand Down
Loading
Loading