From 8e939c4c675c0e31808a52c9a9829cd8f8f5c67f Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Thu, 28 Nov 2024 17:37:59 +0000 Subject: [PATCH 01/20] initial draft, more examples nad proper railroad tba --- .gitignore | 2 + documentation/reference/sql/declare.md | 211 +++++++++++++++++++++++++ documentation/sidebars.js | 1 + 3 files changed, 214 insertions(+) create mode 100644 documentation/reference/sql/declare.md diff --git a/.gitignore b/.gitignore index 5e19b9d6..c7b3a98a 100644 --- a/.gitignore +++ b/.gitignore @@ -35,3 +35,5 @@ yarn-error.log* .log src/css/infima.css .ignore + +.yarn/sdks diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md new file mode 100644 index 00000000..82bc3aba --- /dev/null +++ b/documentation/reference/sql/declare.md @@ -0,0 +1,211 @@ +--- +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. + +## Syntax + +```mermaid +graph LR; + A[DECLARE] --> B[@variable] + B --> C[:=] + C --> D[expression] + D --> F[SELECT] + D --> E[,] + E --> B +``` + +## 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 variabls 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 | + + +T + +:::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 | + +### Validity of expressions + +Most basic expressions are supported, and we will provide examples later. 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: + +#### Subqueries + +```questdb-sql title="subqueries are not allowed" demo +DECLARE + @sub := (SELECT timestamp FROM trades) +SELECT * FROM @sub + +-- error: function, literal or constant is expected +``` + +#### Bracket lists + +```questdb-sql title="bracket lists are not allowed" demo +DECLARE + @symbols := ('BTC-USD', 'ETH-USD') +SELECT timestamp, price, symbol +FROM trades +WHERE symbol IN @symbols + +-- error: unexpected bind expression - bracket lists not supported +``` + +### Declarations in subqueries + +Declarations made in parent queries are available in subqueries. + +If a subquery declares a variable of the same name, then the variable is shadowed +and take 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 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 | + + +## 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 +) +``` + +## 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. + + + +```sql +DECLARE @x := ?, @y := ? +SELECT @x::int + @y::int + +-- Then bind the following values: (1, 2) +``` + +| column | +|--------| +| 3 | diff --git a/documentation/sidebars.js b/documentation/sidebars.js index c9cd4f6a..03434ae1 100644 --- a/documentation/sidebars.js +++ b/documentation/sidebars.js @@ -194,6 +194,7 @@ module.exports = { type: "doc", customProps: { tag: "Enterprise" }, }, + "reference/sql/declare", "reference/sql/distinct", "reference/sql/drop", { From 61f94979d281aa086dc46ab4533c2e70b64f1267 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Thu, 28 Nov 2024 18:56:24 +0000 Subject: [PATCH 02/20] point at railroad --- documentation/reference/sql/declare.md | 10 +--------- 1 file changed, 1 insertion(+), 9 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 82bc3aba..027c2631 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -11,15 +11,7 @@ This syntax is supported specifically for `SELECT` queries. ## Syntax -```mermaid -graph LR; - A[DECLARE] --> B[@variable] - B --> C[:=] - C --> D[expression] - D --> F[SELECT] - D --> E[,] - E --> B -``` +![Flow chart showing the syntax of the DECLARE keyword](/images/docs/diagrams/declare.svg) ## Mechanics From 79357937b5d7536fc663165b18c59c4b0feb4fe7 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Thu, 28 Nov 2024 18:57:48 +0000 Subject: [PATCH 03/20] add missing FROM-TO --- documentation/reference/sql/sample-by.md | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/documentation/reference/sql/sample-by.md b/documentation/reference/sql/sample-by.md index b1083a15..bdd1a008 100644 --- a/documentation/reference/sql/sample-by.md +++ b/documentation/reference/sql/sample-by.md @@ -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) From 8b27de5dd35207bda59e7b13012d04c8001f26ea Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Thu, 28 Nov 2024 19:12:33 +0000 Subject: [PATCH 04/20] railroads --- static/images/docs/diagrams/.railroad | 16 +- static/images/docs/diagrams/createTable.svg | 494 ++++++++++++++----- static/images/docs/diagrams/declare.svg | 91 ++++ static/images/docs/diagrams/fromTo.svg | 90 ++++ static/images/docs/diagrams/insert.svg | 208 +++++++- static/images/docs/diagrams/withAsInsert.svg | 184 ++++++- 6 files changed, 961 insertions(+), 122 deletions(-) create mode 100644 static/images/docs/diagrams/declare.svg create mode 100644 static/images/docs/diagrams/fromTo.svg diff --git a/static/images/docs/diagrams/.railroad b/static/images/docs/diagrams/.railroad index bd7d32f0..a8d735bd 100644 --- a/static/images/docs/diagrams/.railroad +++ b/static/images/docs/diagrams/.railroad @@ -32,7 +32,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)* ')' @@ -61,6 +65,10 @@ createServiceAccount alterTable ::= 'ALTER' 'TABLE' tableName +declare +::= 'DECLARE' '@variable' ':=' expression ( ',' '@variable' ':=' expression )* withExpr? selectExpr + + dropGroup ::= 'DROP' 'GROUP' ('IF' 'EXISTS')? groupName @@ -94,14 +102,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' ))? diff --git a/static/images/docs/diagrams/createTable.svg b/static/images/docs/diagrams/createTable.svg index 8430c765..9b76b3b1 100644 --- a/static/images/docs/diagrams/createTable.svg +++ b/static/images/docs/diagrams/createTable.svg @@ -1,124 +1,386 @@ - + + - + CREATE - - - TABLE - - - IF - - - NOT - - - EXISTS - - - tableName - - ( - - - columnName - - - typeDef - - , - - - ) - - - AS - - - ( - - - selectSql - - ) - - - , - - - castDef - - , - - - indexDef - - timestamp - - - ( - - - columnRef - - ) - - - PARTITION - - - BY - - - NONE - - - BYPASS - - - WAL - - - YEAR - - - MONTH - - - DAY - - - HOUR - - - BYPASS - - - WAL - - - WITH - - - tableParameter - - - tableTargetVolumeDef - - OWNED - - - BY - - - ownerName - - - \ No newline at end of file + + + ATOMIC + + + BATCH + + + + number + + + + o3MaxLag + + + + numberWithUnit + + + + TABLE + + + IF + + + NOT + + + EXISTS + + + + tableName + + + + ( + + + + columnName + + + + + typeDef + + + + , + + + ) + + + AS + + + ( + + + + selectSql + + + + ) + + + , + + + + castDef + + + + , + + + + indexDef + + + + timestamp + + + ( + + + + columnRef + + + + ) + + + PARTITION + + + BY + + + NONE + + + BYPASS + + + WAL + + + YEAR + + + MONTH + + + DAY + + + HOUR + + + BYPASS + + + WAL + + + WITH + + + + tableParameter + + + + + tableTargetVolumeDef + + + + OWNED + + + BY + + + + ownerName + + + + + diff --git a/static/images/docs/diagrams/declare.svg b/static/images/docs/diagrams/declare.svg new file mode 100644 index 00000000..367699a4 --- /dev/null +++ b/static/images/docs/diagrams/declare.svg @@ -0,0 +1,91 @@ + + + + + + + + + + DECLARE + + + @variable + + + := + + + + expression + + + + , + + + + withExpr + + + + + selectExpr + + + + + diff --git a/static/images/docs/diagrams/fromTo.svg b/static/images/docs/diagrams/fromTo.svg new file mode 100644 index 00000000..d55ce75e --- /dev/null +++ b/static/images/docs/diagrams/fromTo.svg @@ -0,0 +1,90 @@ + + + + + + + + + + + someSampleBySelectQuery... + + + + FROM + + + + lowerBound + + + + TO + + + + upperBound + + + + TO + + + + upperBound + + + + + diff --git a/static/images/docs/diagrams/insert.svg b/static/images/docs/diagrams/insert.svg index 674cfa55..8d999521 100644 --- a/static/images/docs/diagrams/insert.svg +++ b/static/images/docs/diagrams/insert.svg @@ -1 +1,207 @@ -INSERTbatchbatchCountINTOtableName(columnName,)VALUES(value,),SELECTqueryDefmainQuery; \ No newline at end of file + + + + + + + + + + INSERT + + + ATOMIC + + + BATCH + + + + number + + + + o3MaxLag + + + + numberWithUnit + + + + INTO + + + + tableName + + + + ( + + + + columnName + + + + , + + + ) + + + VALUES + + + ( + + + + value + + + + , + + + ) + + + , + + + SELECT + + + + queryDef + + + + + mainQuery + + + + ; + + + + diff --git a/static/images/docs/diagrams/withAsInsert.svg b/static/images/docs/diagrams/withAsInsert.svg index ab0a6b44..ff4e5420 100644 --- a/static/images/docs/diagrams/withAsInsert.svg +++ b/static/images/docs/diagrams/withAsInsert.svg @@ -1 +1,183 @@ -WITHsubQueryNameAS(subQuery),INSERTbatchbatchCountINTOtableNameSELECTqueryDefsubQueryName; \ No newline at end of file + + + + + + + + + + WITH + + + + subQueryName + + + + AS + + + ( + + + + subQuery + + + + ) + + + , + + + INSERT + + + ATOMIC + + + BATCH + + + + number + + + + o3MaxLag + + + + numberWithUnit + + + + INTO + + + + tableName + + + + SELECT + + + + queryDef + + + + + subQueryName + + + + ; + + + + From ab7b3eb25b978e550e7994c5cda41c1a859f74de Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Fri, 29 Nov 2024 11:22:25 +0000 Subject: [PATCH 05/20] iterate --- documentation/reference/sql/declare.md | 2 -- 1 file changed, 2 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 027c2631..293ddcf1 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -40,8 +40,6 @@ SELECT 5 | 5 | -T - :::note It is easy to accidentally omit the `:` when writing variable binding expressions. From c78aebec463b6dfcfce34eb4ac48958fc84bd7c0 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Fri, 29 Nov 2024 15:48:53 +0000 Subject: [PATCH 06/20] iterate --- documentation/reference/sql/declare.md | 41 +++++++++++++------------- 1 file changed, 21 insertions(+), 20 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 293ddcf1..29bcfeef 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -68,7 +68,7 @@ SELECT @x + @y ### Validity of expressions -Most basic expressions are supported, and we will provide examples later. We suggest +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. @@ -101,7 +101,7 @@ WHERE symbol IN @symbols Declarations made in parent queries are available in subqueries. If a subquery declares a variable of the same name, then the variable is shadowed -and take on the new value. However, any queries above this subquery are unaffected - the +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 @@ -146,6 +146,25 @@ FROM second | 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. + + +```sql +DECLARE @x := ?, @y := ? +SELECT @x::int + @y::int + +-- Then bind the following values: (1, 2) +``` + +| column | +|--------| +| 3 | + + + ## Examples ### SAMPLE BY @@ -181,21 +200,3 @@ INSERT INTO trades SELECT * FROM SELECT @x as timestamp, @y as symbol ) ``` - -## 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. - - - -```sql -DECLARE @x := ?, @y := ? -SELECT @x::int + @y::int - --- Then bind the following values: (1, 2) -``` - -| column | -|--------| -| 3 | From 5a81e08aabbfbf2f9cc59620dddacaadccb29f26 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Fri, 29 Nov 2024 16:01:30 +0000 Subject: [PATCH 07/20] swap to a limitations section, makes more sense --- documentation/reference/sql/declare.md | 61 ++++++++++++++------------ 1 file changed, 32 insertions(+), 29 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 29bcfeef..c8f1db27 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -66,35 +66,6 @@ SELECT @x + @y |--------| | 7 | -### Validity of expressions - -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: - -#### Subqueries - -```questdb-sql title="subqueries are not allowed" demo -DECLARE - @sub := (SELECT timestamp FROM trades) -SELECT * FROM @sub - --- error: function, literal or constant is expected -``` - -#### Bracket lists - -```questdb-sql title="bracket lists are not allowed" demo -DECLARE - @symbols := ('BTC-USD', 'ETH-USD') -SELECT timestamp, price, symbol -FROM trades -WHERE symbol IN @symbols - --- error: unexpected bind expression - bracket lists not supported -``` ### Declarations in subqueries @@ -200,3 +171,35 @@ INSERT INTO trades SELECT * FROM SELECT @x as timestamp, @y as symbol ) ``` + + +## 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: + +#### Subqueries + +```questdb-sql title="subqueries are not allowed" +DECLARE + @sub := (SELECT timestamp FROM trades) +SELECT * FROM @sub + +-- error: function, literal or constant is expected +``` + +#### 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 +``` \ No newline at end of file From f800013fcfa4e46c378596a20cdfd39b13d733d1 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Mon, 2 Dec 2024 15:58:45 +0000 Subject: [PATCH 08/20] we will support subqueries as variables --- documentation/reference/sql/declare.md | 36 ++++++++++++++++---------- 1 file changed, 23 insertions(+), 13 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index c8f1db27..bb6ee170 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -28,7 +28,7 @@ Use the variable binding operator `:=` (walrus) to associate expressions to name In the above example, a single binding is declared, which states that the variable `@x` should be replaced with the constant integer `5`. -The variabls are resolved at parse-time, meaning that variable is no longer present +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 @@ -88,7 +88,29 @@ SELECT @x + y FROM ( | ----- | | 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 @@ -172,26 +194,14 @@ INSERT INTO trades SELECT * FROM ) ``` - ## 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: -#### Subqueries - -```questdb-sql title="subqueries are not allowed" -DECLARE - @sub := (SELECT timestamp FROM trades) -SELECT * FROM @sub - --- error: function, literal or constant is expected -``` - #### Bracket lists ```questdb-sql title="bracket lists are not allowed" From 847ab3f33d6ac3dc2c4a187e733388e46c9ef272 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Mon, 2 Dec 2024 16:11:29 +0000 Subject: [PATCH 09/20] amended docs, subqueries supported --- documentation/reference/sql/declare.md | 58 ++++++++++++++++---------- 1 file changed, 36 insertions(+), 22 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index bb6ee170..51a7a606 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -71,6 +71,20 @@ SELECT @x + @y 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. @@ -85,8 +99,8 @@ SELECT @x + y FROM ( ``` | column | -| ----- | -| 15 | +|--------| +| 15 | ### Declarations as subqueries @@ -157,6 +171,26 @@ SELECT @x::int + @y::int | 3 | +## 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 +``` + ## Examples @@ -193,23 +227,3 @@ INSERT INTO trades SELECT * FROM SELECT @x as timestamp, @y as symbol ) ``` - -## 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 -``` \ No newline at end of file From e88c04365d17584d3df3e3e52ce139f4aae8d8e8 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Mon, 2 Dec 2024 16:22:21 +0000 Subject: [PATCH 10/20] disclaimer --- documentation/reference/sql/declare.md | 8 ++++++++ 1 file changed, 8 insertions(+) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 51a7a606..c8f97e2a 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -9,6 +9,14 @@ 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) From 0a7aab1500a76c3bbd4cd056024eb208b4cfba8c Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Mon, 2 Dec 2024 17:03:28 +0000 Subject: [PATCH 11/20] add functions example --- documentation/reference/sql/declare.md | 17 +++++++++++++++++ 1 file changed, 17 insertions(+) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index c8f97e2a..8ba680f9 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -74,6 +74,23 @@ SELECT @x + @y |--------| | 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 From 8af3a1b0eb6cf3b4cdab4b880cf4803dac076476 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Wed, 4 Dec 2024 13:48:48 +0000 Subject: [PATCH 12/20] semicolons --- documentation/reference/sql/declare.md | 38 +++++++++++++------------- 1 file changed, 19 insertions(+), 19 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 8ba680f9..2dbfac36 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -28,7 +28,7 @@ The `DECLARE` keyword comes before the `SELECT` clause in your query: ```questdb-sql title="Basic DECLARE" demo DECLARE @x := 5 -SELECT @x +SELECT @x; ``` Use the variable binding operator `:=` (walrus) to associate expressions to names. @@ -40,7 +40,7 @@ The variables are resolved at parse-time, meaning that variable is no longer pre when the query is compiled. So the above example reduces to this simple query: ```questdb-sql title="basic DECLARE post-reduction" demo -SELECT 5 +SELECT 5; ``` | 5 | @@ -67,7 +67,7 @@ You can declare multiple variables by setting the bind expressions with commas ` DECLARE @x := 5, @y := 2 -SELECT @x + @y +SELECT @x + @y; ``` | column | @@ -84,7 +84,7 @@ DECLARE @today := today(), @start := interval_start(@today), @end := interval_end(@today) -SELECT @today = interval(@start, @end) +SELECT @today = interval(@start, @end); ``` | column | @@ -101,7 +101,7 @@ DECLARE @x := 5 SELECT y FROM ( SELECT @x AS y -) +); ``` | y | @@ -120,7 +120,7 @@ DECLARE SELECT @x + y FROM ( DECLARE @x := 10 SELECT @x AS y -) +); ``` | column | @@ -138,7 +138,7 @@ 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 +SELECT * FROM @subquery; ``` You can even use already-declared variables to define your subquery variable: @@ -148,7 +148,7 @@ DECLARE @timestamp := timestamp, @symbol := symbol, @subquery := (SELECT @timestamp, @symbol FROM trades) -SELECT * FROM @subquery +SELECT * FROM @subquery; ``` ### Declarations in CTEs @@ -170,7 +170,7 @@ second AS ( FROM first ) SELECT a, b -FROM second +FROM second; ``` | a | b | @@ -184,9 +184,9 @@ FROM second does not perform syntax validation that rejects the `DECLARE` syntax. -```sql +```questdb-sql DECLARE @x := ?, @y := ? -SELECT @x::int + @y::int +SELECT @x::int + @y::int; -- Then bind the following values: (1, 2) ``` @@ -211,7 +211,7 @@ DECLARE @symbols := ('BTC-USD', 'ETH-USD') SELECT timestamp, price, symbol FROM trades -WHERE symbol IN @symbols +WHERE symbol IN @symbols; -- error: unexpected bind expression - bracket lists not supported ``` @@ -228,12 +228,12 @@ DECLARE @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); +FROM trades +WHERE side = 'sell' +AND timestamp IN @window +AND symbol = @symbol +SAMPLE BY @period +FILL(NULL); ``` | timestamp | symbol | side | volume | @@ -250,5 +250,5 @@ INSERT INTO trades SELECT * FROM ( DECLARE @x := now(), @y := 'ETH-USD' SELECT @x as timestamp, @y as symbol -) +); ``` From 82124baa3f60f92ab34f007ab8f593ce7b0290d9 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Wed, 4 Dec 2024 16:23:23 +0000 Subject: [PATCH 13/20] example --- documentation/reference/sql/declare.md | 16 +++++++++++++++- 1 file changed, 15 insertions(+), 1 deletion(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 2dbfac36..3d5f29aa 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -248,7 +248,21 @@ FILL(NULL); ```questdb-sql INSERT INTO trades SELECT * FROM ( - DECLARE @x := now(), @y := 'ETH-USD' + DECLARE + @x := now(), + @y := 'ETH-USD' SELECT @x as timestamp, @y as symbol ); ``` + +### 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 +); +``` + From 8dede5babf9e140b4e9f857a23385b393290d0a1 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Fri, 6 Dec 2024 12:46:32 +0000 Subject: [PATCH 14/20] add sql frag --- documentation/reference/sql/declare.md | 11 ++++++++++- 1 file changed, 10 insertions(+), 1 deletion(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 3d5f29aa..5472bd14 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -204,7 +204,7 @@ how many places you need to update the constant. However, not all expressions are supported. The following are explicitly disallowed: -#### Bracket lists +### Bracket lists ```questdb-sql title="bracket lists are not allowed" DECLARE @@ -216,6 +216,15 @@ 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 From b0c769d1b5fdf44bc3482d17c38fb6a84b4db211 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Tue, 7 Jan 2025 17:26:43 +0000 Subject: [PATCH 15/20] Update declare.md --- documentation/reference/sql/declare.md | 12 ++++++++++++ 1 file changed, 12 insertions(+) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 5472bd14..82f88673 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -195,6 +195,18 @@ SELECT @x::int + @y::int; |--------| | 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 := 'John Smith' +SELECT @name as name, id FROM users WHERE name = @name; +``` ## Limitations From 115bea6211b2326683fcb1b99261d5b53cf7ecda Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Thu, 9 Jan 2025 16:13:46 +0000 Subject: [PATCH 16/20] fix example --- documentation/reference/sql/declare.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 82f88673..960ad6aa 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -204,7 +204,7 @@ you could instead use a declared variable and send a single bind variable: SELECT ? as name, id FROM users WHERE name = ?; -- do this: -DECLARE @name := 'John Smith' +DECLARE @name := '?' SELECT @name as name, id FROM users WHERE name = @name; ``` From 5900259d46be5f547052526b8bd123c95c3c9a01 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Thu, 9 Jan 2025 16:19:31 +0000 Subject: [PATCH 17/20] Apply suggestions from code review --- documentation/reference/sql/declare.md | 13 +++++++++++-- 1 file changed, 11 insertions(+), 2 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 960ad6aa..87744e16 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -204,10 +204,18 @@ you could instead use a declared variable and send a single bind variable: SELECT ? as name, id FROM users WHERE name = ?; -- do this: -DECLARE @name := '?' +DECLARE @name := ? SELECT @name as name, id FROM users WHERE name = @name; ``` +Or for repeating columns: +```questdb-sql +DECLARE + @col = ?, + @symbol = ? +SELECT avg(@col), min(@col), max(@col) +FROM trades +WHERE symbol = @symbol ## Limitations Most basic expressions are supported, and we provide examples later in this document. We suggest @@ -267,7 +275,8 @@ FILL(NULL); ### INSERT INTO SELECT ```questdb-sql -INSERT INTO trades SELECT * FROM +INSERT INTO trades (timestamp, symbol) +SELECT * FROM ( DECLARE @x := now(), From 9f3398a393bdf7290aadfca3abaa60c05fc92f15 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Thu, 9 Jan 2025 16:21:10 +0000 Subject: [PATCH 18/20] Update declare.md --- documentation/reference/sql/declare.md | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 87744e16..1f04e001 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -215,7 +215,9 @@ DECLARE @symbol = ? SELECT avg(@col), min(@col), max(@col) FROM trades -WHERE symbol = @symbol +WHERE symbol = @symbol; + +``` ## Limitations Most basic expressions are supported, and we provide examples later in this document. We suggest From 9c682661de4490bf3b44caa87a29e2160bde5af7 Mon Sep 17 00:00:00 2001 From: Nick Woolmer <29717167+nwoolmer@users.noreply.github.com> Date: Thu, 9 Jan 2025 17:28:33 +0000 Subject: [PATCH 19/20] psycopg example from Javier --- documentation/reference/sql/declare.md | 22 ++++++++++++++++++++-- 1 file changed, 20 insertions(+), 2 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 1f04e001..2690f41c 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -224,9 +224,11 @@ Most basic expressions are supported, and we provide examples later in this docu you use variables to simplify repeated constants within your code, and minimise how many places you need to update the constant. +### Disallowed expressions + However, not all expressions are supported. The following are explicitly disallowed: -### Bracket lists +#### Bracket lists ```questdb-sql title="bracket lists are not allowed" DECLARE @@ -238,7 +240,7 @@ WHERE symbol IN @symbols; -- error: unexpected bind expression - bracket lists not supported ``` -### SQL statement fragments +#### SQL statement fragments ```questdb-sql title="sql fragments are not allowed" DECLARE @@ -248,6 +250,22 @@ SELECT 5 @x; -- table and column names that are SQL keywords have to be enclosed in double quotes, such as "FROM"``` ``` +### Language client support + +Some language SQL clients do not allow identifiers to be passed as if it was a normal value. One example is `psycopg`. +In this case, you should use an alternate API to splice in identifiers, for example: + + +```python title="psycopg" +cur.execute( + sql.SQL(""" + DECLARE @col := {} + SELECT max(@col), min(@col), avg(price) + FROM btc_trades; + """).format(sql.Identifier('price'))) +``` + + ## Examples ### SAMPLE BY From 0a3628e258cf7046b42eb2cb3de6c5cd4c28ca86 Mon Sep 17 00:00:00 2001 From: goodroot <9484709+goodroot@users.noreply.github.com> Date: Fri, 10 Jan 2025 13:04:07 -0800 Subject: [PATCH 20/20] polish --- documentation/reference/sql/declare.md | 70 ++++++++++++-------------- 1 file changed, 33 insertions(+), 37 deletions(-) diff --git a/documentation/reference/sql/declare.md b/documentation/reference/sql/declare.md index 2690f41c..8ffd04ff 100644 --- a/documentation/reference/sql/declare.md +++ b/documentation/reference/sql/declare.md @@ -4,18 +4,9 @@ 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. +`DECLARE` specifies a series of variable bindings 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. - -::: +This syntax is supported within `SELECT` queries. ## Syntax @@ -33,11 +24,23 @@ 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`. +:::tip + +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 `:=` + +::: + +The above example declares a single binding, which states that the variable `@x` is replaced with the constant integer `5`. + +The variables are resolved at parse-time, meaning that the variable is no longer present +when the query is compiled. -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: +So the above example reduces to this simple query: ```questdb-sql title="basic DECLARE post-reduction" demo SELECT 5; @@ -48,20 +51,9 @@ SELECT 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 `,`: +To declare multiple variables, set the bind expressions with commas `,`: ```questdb-sql title="Multiple variable bindings" demo DECLARE @@ -76,7 +68,7 @@ SELECT @x + @y; ### Variables as functions -A variable need not be just a constant, it could be a function call, +A variable need not be just a constant. It could also be a function call, and variables with function values can be nested: ```questdb-sql title="declaring function variable" demo @@ -111,7 +103,9 @@ SELECT y FROM ( #### 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 +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 @@ -129,8 +123,9 @@ SELECT @x + y FROM ( ### Declarations as subqueries -Declarations themselves can be subqueries. We suggest that this -is not overused, as removing the subquery definition from its execution +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: @@ -181,8 +176,7 @@ FROM second; ### 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. - +does not perform syntax validation that rejects the `DECLARE` syntax: ```questdb-sql DECLARE @x := ?, @y := ? @@ -195,7 +189,9 @@ SELECT @x::int + @y::int; |--------| | 3 | -This can be useful to minimise repeated bind variables. For example, rather than passing the same value to multiple positional arguments, +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: @@ -220,8 +216,9 @@ WHERE symbol = @symbol; ``` ## 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 +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. ### Disallowed expressions @@ -265,7 +262,6 @@ cur.execute( """).format(sql.Identifier('price'))) ``` - ## Examples ### SAMPLE BY