feat(v3): Parameterized queries with SQL and InfluxQL (#5394)

* feat(dedicated): Parameterized queries for SQL and InfluxQL using the native Flight RPC API

* feat(v3): Parameterized queries for SQL and InfluxQL

* feat(v3): Parameterized queries for SQL and InfluxQL

* feat(v3): Dedicated: Parameterized queries for SQL and InfluxQL

* feat(v3): Serverless: Parameterized queries for SQL and InfluxQL

* feat(v3): Clustered: Parameterized queries for SQL and InfluxQL

* feat(v3): Cleanup parameterized queries

* Apply suggestions from code review

Co-authored-by: Scott Anderson <sanderson@users.noreply.github.com>

* Apply suggestions from code review

Co-authored-by: Scott Anderson <sanderson@users.noreply.github.com>

* Apply suggestions from code review

Co-authored-by: Scott Anderson <sanderson@users.noreply.github.com>

* Update content/influxdb/cloud-dedicated/reference/influxql/time-and-timezone.md

* Update content/influxdb/cloud-dedicated/reference/influxql/time-and-timezone.md

* Update content/influxdb/cloud-dedicated/reference/influxql/time-and-timezone.md

* Influxctl v2.7.1 (#5395)

* Release influxctl v2.7.1

* Update change logs

* feat(v3): Parameterized queries: Add references to time and data types pages

* feat(v3): InfluxQL parameterized queries data types

* feat(v3): InfluxQL parameterized queries data types

* feat(v3): Note that you can't parameterize identifiers in queries

* feat(v3): Parameterized queries restrictions

---------

Co-authored-by: Scott Anderson <sanderson@users.noreply.github.com>
Co-authored-by: Joshua Powers <powersj@fastmail.com>
5306-link-broken-doesnt-exist
Jason Stirnaman 2024-03-29 11:11:52 -05:00 committed by GitHub
parent f47631ae0c
commit 8f3947ec92
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
14 changed files with 2230 additions and 89 deletions

View File

@ -120,6 +120,7 @@ SELECT * FROM home WHERE time >= now() - 30d
``` ```
##### Query one day of data data from a week ago ##### Query one day of data data from a week ago
```sql ```sql
SELECT * SELECT *
FROM home FROM home
@ -213,5 +214,3 @@ SELECT temp AS temperature, hum AS "humidity (%)" FROM home
When aliasing columns in **InfluxQL**, use the `AS` clause and an [identifier](/influxdb/cloud-dedicated/reference/influxql/#identifiers). When aliasing columns in **InfluxQL**, use the `AS` clause and an [identifier](/influxdb/cloud-dedicated/reference/influxql/#identifiers).
When [aliasing columns in **SQL**](/influxdb/cloud-dedicated/query-data/sql/basic-query/#alias-queried-fields-and-tags), you can use the `AS` clause to define the alias, but it isn't necessary. When [aliasing columns in **SQL**](/influxdb/cloud-dedicated/query-data/sql/basic-query/#alias-queried-fields-and-tags), you can use the `AS` clause to define the alias, but it isn't necessary.
{{% /note %}} {{% /note %}}

View File

@ -0,0 +1,354 @@
---
title: Use parameterized queries with InfluxQL
description: >
Use parameterized queries to prevent injection attacks and make queries more reusable.
weight: 404
menu:
influxdb_cloud_dedicated:
name: Parameterized queries
parent: Query with InfluxQL
identifier: parameterized-queries-influxql
influxdb/cloud-dedicated/tags: [query, security, influxql]
list_code_example: |
##### Using Go and the influxdb3-go client
```go
// Use the $parameter syntax to reference parameters in a query.
// The following InfluxQL query contains $room and $min_time parameters.
query := `
SELECT * FROM home
WHERE time >= $min_time
AND temp >= $min_temp
AND room = $room`
// Assign parameter names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
"min_time": "2024-03-18 00:00:00.00",
}
// Call the client's function to query InfluxDB with parameters and the
// the InfluxQL QueryType.
iterator, err := client.QueryWithParameters(context.Background(),
query,
parameters,
influxdb3.WithQueryType(influxdb3.InfluxQL))
```
---
Parameterized queries in {{% product-name %}} let you dynamically and safely change values in a query.
If your application code allows user input to customize values or expressions in a query, use a parameterized query to make sure untrusted input is processed strictly as data and not executed as code.
Parameterized queries:
- help prevent injection attacks, which can occur if input is executed as code
- help make queries more reusable
{{% note %}}
#### Prevent injection attacks
For more information on security and query parameterization,
see the [OWASP SQL Injection Prevention Cheat Sheet](https://cheatsheetseries.owasp.org/cheatsheets/SQL_Injection_Prevention_Cheat_Sheet.html#defense-option-1-prepared-statements-with-parameterized-queries).
{{% /note %}}
In InfluxDB v3, a parameterized query is an InfluxQL or SQL query that contains one or more named parameter placeholdersvariables that represent input data.
- [Use parameters in `WHERE` expressions](#use-parameters-in-where-expressions)
- [Parameter data types](#parameter-data-types)
- [Data type examples](#data-type-examples)
- [Time expressions](#time-expressions)
- [Not compatible with parameters](#not-compatible-with-parameters)
- [Parameterize an SQL query](#parameterize-an-sql-query)
- [Execute parameterized InfluxQL queries](#execute-parameterized-influxql-queries)
- [Use InfluxDB Flight RPC clients](#use-influxdb-flight-rpc-clients)
- [Client support for parameterized queries](#client-support-for-parameterized-queries)
- [Not supported](#not-supported)
{{% note %}}
#### Parameters only supported in `WHERE` expressions
InfluxDB v3 supports parameters in `WHERE` clause **predicate expressions**.
Parameter values must be one of the [allowed parameter data types](#parameter-data-types).
If you use parameters in other expressions or clauses,
such as function arguments, `SELECT`, or `GROUP BY`, then your query might not work as you expect.
{{% /note %}}
## Use parameters in `WHERE` expressions
You can use parameters in `WHERE` clause **predicate expressions**-for example, the following query contains a `$temp` parameter:
```sql
SELECT * FROM measurement WHERE temp > $temp
```
When executing a query, you specify parameter name-value pairs.
The value that you assign to a parameter must be one of the [parameter data types](#parameter-data-types).
```go
{"temp": 22.0}
```
The InfluxDB Querier parses the query text with the parameter placeholders, and then generates query plans that replace the placeholders with the values that you provide.
This separation of query structure from input data ensures that input is treated as one of the allowed [data types](#parameter-data-types) and not as executable code.
## Parameter data types
A parameter value can be one of the following data types:
- Null
- Boolean
- Unsigned integer (`u_int64`)
- Integer (`int64`)
- Double (`float64`)
- String
### Data type examples
```js
{
"string": "Living Room",
"double": 3.14,
"unsigned_integer": 1234,
"integer": -1234,
"boolean": false,
"null": Null,
}
```
### Time expressions
To parameterize time bounds, substitute a parameter for a timestamp literal--for example:
```sql
SELECT *
FROM home
WHERE time >= $min_time
```
For the parameter value, specify the timestamp literal as a string--for example:
{{% influxdb/custom-timestamps %}}
```go
// Assign a timestamp string literal to the min_time parameter.
parameters := influxdb3.QueryParameters{
"min_time": "2022-01-01 00:00:00.00",
}
```
{{% /influxdb/custom-timestamps %}}
InfluxDB executes the query as the following:
{{% influxdb/custom-timestamps %}}
```sql
SELECT *
FROM home
WHERE time >= '2022-01-01 00:00:00.00'
```
{{% /influxdb/custom-timestamps %}}
### Not compatible with parameters
If you use parameters for the following, your query might not work as you expect:
- In clauses other than `WHERE`, such as `SELECT` or `GROUP BY`
- As function arguments, such as `avg($temp)`
- In place of identifiers, such as column or table names
- In place of duration literals, such as `time > now() - $min_duration`
## Parameterize an SQL query
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/cloud-dedicated/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/cloud-dedicated/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} database before running the example queries.
{{% /note %}}
To use a parameterized query, do the following:
1. In your query text, use the `$parameter` syntax to reference a parameter name--for example,
the following query contains `$room` and `$min_temp` parameter placeholders:
```sql
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= $min_temp
AND room = $room
```
2. Provide a value for each parameter name.
If you don't assign a value for a parameter, InfluxDB returns an error.
The syntax for providing parameter values depends on the client you use--for example:
<!-- I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
<!------------------------ BEGIN GO ------------------------------------------->
```go
// Define a QueryParameters struct--a map of parameters to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
```
<!-------------------------- END GO ------------------------------------------->
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
After InfluxDB receives your request and parses the query, it executes the query as
```sql
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= 20.0
AND room = 'Kitchen'
```
## Execute parameterized InfluxQL queries
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/cloud-dedicated/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/cloud-dedicated/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} database before running the example queries.
{{% /note %}}
### Use InfluxDB Flight RPC clients
Using the InfluxDB v3 native Flight RPC protocol and supported clients, you can send a parameterized query and a list of parameter name-value pairs.
InfluxDB Flight clients that support parameterized queries pass the parameter name-value pairs in a Flight ticket `params` field.
The following examples show how to use client libraries to execute parameterized InfluxQL queries:
<!-- Using code-tabs because I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
```go
import (
"context"
"fmt"
"io"
"os"
"text/tabwriter"
"time"
"github.com/apache/arrow/go/v14/arrow"
"github.com/InfluxCommunity/influxdb3-go/influxdb3"
)
func Query(query string, parameters influxdb3.QueryParameters,
options influxdb3.QueryOptions) error {
url := os.Getenv("INFLUX_HOST")
token := os.Getenv("INFLUX_TOKEN")
database := os.Getenv("INFLUX_DATABASE")
// Instantiate the influxdb3 client.
client, err := influxdb3.New(influxdb3.ClientConfig{
Host: url,
Token: token,
Database: database,
})
if err != nil {
panic(err)
}
// Ensure the client is closed after the Query function finishes.
defer func(client *influxdb3.Client) {
err := client.Close()
if err != nil {
panic(err)
}
}(client)
// Call the client's QueryWithParameters function.
// Provide the query, parameters, and the InfluxQL QueryType option.
iterator, err := client.QueryWithParameters(context.Background(), query,
parameters, influxdb3.WithQueryType(options.QueryType))
// Create a buffer for storing rows as you process them.
w := tabwriter.NewWriter(io.Discard, 4, 4, 1, ' ', 0)
w.Init(os.Stdout, 0, 8, 0, '\t', 0)
fmt.Fprintf(w, "time\troom\tco\thum\ttemp\n")
// Format and write each row to the buffer.
// Process each row as key-value pairs.
for iterator.Next() {
row := iterator.Value()
// Use Go arrow and time packages to format unix timestamp
// as a time with timezone layout (RFC3339 format)
time := (row["time"].(arrow.Timestamp)).
ToTime(arrow.Nanosecond).Format(time.RFC3339)
fmt.Fprintf(w, "%s\t%s\t%d\t%.1f\t%.1f\n",
time, row["room"], row["co"], row["hum"], row["temp"])
}
w.Flush()
return nil
}
func main() {
// Use the $placeholder syntax in a query to reference parameter placeholders
// for input data.
// The following InfluxQL query contains the placeholders $room and $min_temp.
query := `
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= $min_temp
AND room = $room`
// Define a QueryParameters struct--a map of placeholder names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
Query(query, parameters, influxdb3.QueryOptions{
QueryType: influxdb3.InfluxQL,
})
}
```
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
## Client support for parameterized queries
- Not all [InfluxDB v3 Flight clients](/influxdb/cloud-dedicated/reference/client-libraries/v3/) support parameterized queries.
- InfluxDB doesn't currently support parameterized queries or DataFusion prepared statements for Flight SQL or Flight SQL clients.
- InfluxDB v3 SQL and InfluxQL parameterized queries arent supported in InfluxDB v1 and v2 clients.
## Not supported
Currently, parameterized queries in {{% product-name %}} don't provide the following:
- support for DataFusion prepared statements
- query caching, optimization, or performance benefits

View File

@ -0,0 +1,346 @@
---
title: Use parameterized queries with SQL
description: >
Use parameterized queries to prevent injection attacks and make queries more reusable.
weight: 404
menu:
influxdb_cloud_dedicated:
name: Parameterized queries
parent: Query with SQL
identifier: parameterized-queries-sql
influxdb/cloud-dedicated/tags: [query, security, sql]
list_code_example: |
##### Using Go and the influxdb3-go client
```go
// Use the $parameter syntax to reference parameters in a query.
// The following SQL query contains $room and $min_temp placeholders.
query := `
SELECT * FROM home
WHERE time >= $min_time
AND temp >= $min_temp
AND room = $room`
// Assign parameter names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
"min_time": "2024-03-18 00:00:00.00",
}
// Call the client's function to query InfluxDB with parameters.
iterator, err := client.QueryWithParameters(context.Background(), query, parameters)
```
---
Parameterized queries in {{% product-name %}} let you dynamically and safely change values in a query.
If your application code allows user input to customize values or expressions in a query, use a parameterized query to make sure untrusted input is processed strictly as data and not executed as code.
Parameterized queries:
- help prevent injection attacks, which can occur if input is executed as code
- help make queries more reusable
{{% note %}}
#### Prevent injection attacks
For more information on security and query parameterization,
see the [OWASP SQL Injection Prevention Cheat Sheet](https://cheatsheetseries.owasp.org/cheatsheets/SQL_Injection_Prevention_Cheat_Sheet.html#defense-option-1-prepared-statements-with-parameterized-queries).
{{% /note %}}
In InfluxDB v3, a parameterized query is an InfluxQL or SQL query that contains one or more named parameter placeholdersvariables that represent input data.
- [Use parameters in `WHERE` expressions](#use-parameters-in-where-expressions)
- [Parameter data types](#parameter-data-types)
- [Data type examples](#data-type-examples)
- [Time expressions](#time-expressions)
- [Not compatible with parameters](#not-compatible-with-parameters)
- [Parameterize an SQL query](#parameterize-an-sql-query)
- [Execute parameterized SQL queries](#execute-parameterized-sql-queries)
- [Use InfluxDB Flight RPC clients](#use-influxdb-flight-rpc-clients)
- [Client support for parameterized queries](#client-support-for-parameterized-queries)
- [Not supported](#not-supported)
{{% note %}}
#### Parameters only supported in `WHERE` expressions
InfluxDB v3 supports parameters in `WHERE` clause **predicate expressions**.
Parameter values must be one of the [allowed parameter data types](#parameter-data-types).
If you use parameters in other expressions or clauses,
such as function arguments, `SELECT`, or `GROUP BY`, then your query might not work as you expect.
{{% /note %}}
## Use parameters in `WHERE` expressions
You can use parameters in `WHERE` clause **predicate expressions**-for example, the following query contains a `$temp` parameter:
```sql
SELECT * FROM measurement WHERE temp > $temp
```
When executing a query, you specify parameter name-value pairs.
The value that you assign to a parameter must be one of the [parameter data types](#parameter-data-types).
```go
{"temp": 22.0}
```
The InfluxDB Querier parses the query text with the parameter placeholders, and then generates query plans that replace the placeholders with the values that you provide.
This separation of query structure from input data ensures that input is treated as one of the allowed [data types](#parameter-data-types) and not as executable code.
## Parameter data types
A parameter value can be one of the following data types:
- Null
- Boolean
- Unsigned integer (`u_int64`)
- Integer (`int64`)
- Double (`float64`)
- String
### Data type examples
```js
{
"string": "Living Room",
"double": 3.14,
"unsigned_integer": 1234,
"integer": -1234,
"boolean": false,
"null": Null,
}
```
### Time expressions
To parameterize time bounds, substitute a parameter for a timestamp literal--for example:
```sql
SELECT *
FROM home
WHERE time >= $min_time
```
For the parameter value, specify the timestamp literal as a string--for example:
{{% influxdb/custom-timestamps %}}
```go
// Assign a timestamp string literal to the min_time parameter.
parameters := influxdb3.QueryParameters{
"min_time": "2022-01-01 00:00:00.00",
}
```
{{% /influxdb/custom-timestamps %}}
InfluxDB executes the query as the following:
{{% influxdb/custom-timestamps %}}
```sql
SELECT *
FROM home
WHERE time >= '2022-01-01 00:00:00.00'
```
{{% /influxdb/custom-timestamps %}}
### Not compatible with parameters
If you use parameters for the following, your query might not work as you expect:
- In clauses other than `WHERE`, such as `SELECT` or `GROUP BY`
- As function arguments, such as `avg($temp)`
- In place of identifiers, such as column or table names
- In place of duration literals, such as `INTERVAL $minutes`
## Parameterize an SQL query
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/cloud-dedicated/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/cloud-dedicated/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} database before running the example queries.
{{% /note %}}
To use a parameterized query, do the following:
1. In your query text, use the `$parameter` syntax to reference a parameter name--for example,
the following query contains `$room` and `$min_temp` parameter placeholders:
```sql
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= $min_temp
AND room = $room
```
2. Provide a value for each parameter name.
If you don't assign a value for a parameter, InfluxDB returns an error.
The syntax for providing parameter values depends on the client you use--for example:
<!-- I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
<!------------------------ BEGIN GO ------------------------------------------->
```go
// Define a QueryParameters struct--a map of parameters to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
```
<!-------------------------- END GO ------------------------------------------->
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
After InfluxDB receives your request and parses the query, it executes the query as
```sql
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= 20.0
AND room = 'Kitchen'
```
## Execute parameterized SQL queries
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/cloud-dedicated/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/cloud-dedicated/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} database before running the example queries.
{{% /note %}}
### Use InfluxDB Flight RPC clients
Using the InfluxDB v3 native Flight RPC protocol and supported clients, you can send a parameterized query and a list of parameter name-value pairs.
InfluxDB Flight clients that support parameterized queries pass the parameter name-value pairs in a Flight ticket `params` field.
The following examples show how to use client libraries to execute parameterized SQL queries:
<!-- Using code-tabs because I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
```go
import (
"context"
"fmt"
"io"
"os"
"text/tabwriter"
"time"
"github.com/apache/arrow/go/v14/arrow"
"github.com/InfluxCommunity/influxdb3-go/influxdb3"
)
func Query(query string, parameters influxdb3.QueryParameters) error {
url := os.Getenv("INFLUX_HOST")
token := os.Getenv("INFLUX_TOKEN")
database := os.Getenv("INFLUX_DATABASE")
// Instantiate the influxdb3 client.
client, err := influxdb3.New(influxdb3.ClientConfig{
Host: url,
Token: token,
Database: database,
})
if err != nil {
panic(err)
}
// Ensure the client is closed after the Query function finishes.
defer func(client *influxdb3.Client) {
err := client.Close()
if err != nil {
panic(err)
}
}(client)
// Call the client's QueryWithParameters function.
// Provide the query and parameters. The default QueryType is SQL.
iterator, err := client.QueryWithParameters(context.Background(), query,
parameters)
// Create a buffer for storing rows as you process them.
w := tabwriter.NewWriter(io.Discard, 4, 4, 1, ' ', 0)
w.Init(os.Stdout, 0, 8, 0, '\t', 0)
fmt.Fprintf(w, "time\troom\tco\thum\ttemp\n")
// Format and write each row to the buffer.
// Process each row as key-value pairs.
for iterator.Next() {
row := iterator.Value()
// Use Go arrow and time packages to format unix timestamp
// as a time with timezone layout (RFC3339 format)
time := (row["time"].(arrow.Timestamp)).
ToTime(arrow.Nanosecond).Format(time.RFC3339)
fmt.Fprintf(w, "%s\t%s\t%d\t%.1f\t%.1f\n",
time, row["room"], row["co"], row["hum"], row["temp"])
}
w.Flush()
return nil
}
func main() {
// Use the $placeholder syntax in a query to reference parameter placeholders
// for input data.
// The following SQL query contains the placeholders $room and $min_temp.
query := `
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= $min_temp
AND room = $room`
// Define a QueryParameters struct--a map of placeholder names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
}
```
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
## Client support for parameterized queries
- Not all [InfluxDB v3 Flight clients](/influxdb/cloud-dedicated/reference/client-libraries/v3/) support parameterized queries.
- InfluxDB doesn't currently support parameterized queries or DataFusion prepared statements for Flight SQL or Flight SQL clients.
- InfluxDB v3 SQL and InfluxQL parameterized queries arent supported in InfluxDB v1 and v2 clients.
## Not supported
Currently, parameterized queries in {{% product-name %}} don't provide the following:
- support for DataFusion prepared statements
- query caching, optimization, or performance benefits

View File

@ -27,6 +27,7 @@ You can review the following ways to work with time and timestamps in your Influ
- [Notable behaviors](#notable-behaviors) - [Notable behaviors](#notable-behaviors)
- [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges) - [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges)
- [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause) - [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause)
- [Cannot use parameters for durations](#cannot-use-parameters-for-durations)
## Time syntax ## Time syntax
@ -81,7 +82,7 @@ InfluxQL requires a whitespace between the `+` operators `-` and the duration li
## Query time range ## Query time range
To specify the time range of a query, use conditional expressions in the To specify the time range of a query, use conditional expressions in the
[`WHERE` clause](/inflxudb/cloud-dedicated/reference/influxql/where/) that [`WHERE` clause](/inflxudb/cloud-dedicated/reference/influxql/where/) that
compare the value of the `time` column to an absolute timestamp or a relative compare the value of the `time` column to an absolute timestamp or a relative
timestamp. timestamp.
@ -151,7 +152,7 @@ WHERE
AND time <= '2022-01-01T12:00:00Z' AND time <= '2022-01-01T12:00:00Z'
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
@ -178,9 +179,9 @@ WHERE
AND time <= '2022-01-01 12:00:00' AND time <= '2022-01-01 12:00:00'
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -206,9 +207,9 @@ WHERE
AND time <= 1641038400000000000 AND time <= 1641038400000000000
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -233,9 +234,9 @@ WHERE
AND time <= 1641038400s AND time <= 1641038400s
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -255,9 +256,9 @@ name: home
SELECT * FROM home WHERE time >= '2022-01-01T20:00:00Z' - 2h SELECT * FROM home WHERE time >= '2022-01-01T20:00:00Z' - 2h
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :---------- | ---: | | :------------------- | --: | ---: | :---------- | ---: |
@ -343,6 +344,7 @@ name: home
- [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges) - [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges)
- [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause) - [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause)
- [Cannot use parameters for durations](#cannot-use-parameters-for-durations)
### Cannot query multiple time ranges ### Cannot query multiple time ranges
@ -372,3 +374,8 @@ between `1677-09-21T00:12:43.145224193Z` and
To query data with timestamps that occur in the future (after `now()`), To query data with timestamps that occur in the future (after `now()`),
provide an explicit upper bound in the `WHERE` clause. provide an explicit upper bound in the `WHERE` clause.
### Cannot use parameters for durations
Currently, InfluxDB doesn't support using parameters for durations in
[parameterized queries](/influxdb/cloud-dedicated/query-data/parameterized-queries/).

View File

@ -19,17 +19,18 @@ In InfluxDB's SQL implementation, a **measurement** is structured as a table,
and **tags**, **fields** and **timestamps** are exposed as columns. and **tags**, **fields** and **timestamps** are exposed as columns.
DataFusion uses the [Arrow](https://arrow.apache.org/) type system for query execution. DataFusion uses the [Arrow](https://arrow.apache.org/) type system for query execution.
Data types stored in InfluxDB's storage engine are mapped to SQL data types at query time. Data types stored in InfluxDB's storage engine are mapped to SQL data types at query time.
{{% note %}} {{% note %}}
When performing casting operations, cast to the **name** of the data type, not the actual data type. When performing casting operations, cast to the **name** of the data type, not the actual data type.
Names and identifiers in SQL are _case-insensitive_ by default. For example: Names and identifiers in SQL are _case-insensitive_ by default. For example:
```sql ```sql
SELECT SELECT
'99'::BIGINT, '99'::BIGINT,
'2019-09-18T00:00:00Z'::timestamp '2019-09-18T00:00:00Z'::timestamp
``` ```
{{% /note %}} {{% /note %}}
- [String types](#string-types) - [String types](#string-types)
@ -39,9 +40,10 @@ SELECT
- [Floats](#floats) - [Floats](#floats)
- [Date and time data types](#date-and-time-data-types) - [Date and time data types](#date-and-time-data-types)
- [Timestamp](#timestamp) - [Timestamp](#timestamp)
- [Interval ](#interval-) - [Interval](#interval)
- [Boolean types](#boolean-types) - [Boolean types](#boolean-types)
- [Unsupported SQL types](#unsupported-sql-types) - [Unsupported SQL types](#unsupported-sql-types)
- [Data types compatible with parameters](#data-types-compatible-with-parameters)
## String types ## String types
@ -74,7 +76,7 @@ The following numeric types are supported:
InfluxDB SQL supports the 64-bit signed integers: InfluxDB SQL supports the 64-bit signed integers:
**Minimum signed integer**: `-9223372036854775808` **Minimum signed integer**: `-9223372036854775808`
**Maximum signed integer**: `9223372036854775807` **Maximum signed integer**: `9223372036854775807`
##### Example integer literals ##### Example integer literals
@ -89,7 +91,7 @@ InfluxDB SQL supports the 64-bit signed integers:
InfluxDB SQL supports the 64-bit unsigned integers: InfluxDB SQL supports the 64-bit unsigned integers:
**Minimum unsigned integer**: `0` **Minimum unsigned integer**: `0`
**Maximum unsigned integer**: `18446744073709551615` **Maximum unsigned integer**: `18446744073709551615`
##### Example unsigned integer literals ##### Example unsigned integer literals
@ -127,14 +129,14 @@ InfluxDB SQL supports the following DATE/TIME data types:
### Timestamp ### Timestamp
A time type is a single point in time using nanosecond precision. A time type is a single point in time using nanosecond precision.
The following date and time formats are supported: The following date and time formats are supported:
```sql ```sql
YYYY-MM-DDT00:00:00.000Z YYYY-MM-DDT00:00:00.000Z
YYYY-MM-DDT00:00:00.000-00:00 YYYY-MM-DDT00:00:00.000-00:00
YYYY-MM-DD 00:00:00.000-00:00 YYYY-MM-DD 00:00:00.000-00:00
YYYY-MM-DDT00:00:00Z YYYY-MM-DDT00:00:00Z
YYYY-MM-DD 00:00:00.000 YYYY-MM-DD 00:00:00.000
YYYY-MM-DD 00:00:00 YYYY-MM-DD 00:00:00
@ -151,9 +153,9 @@ YYYY-MM-DD 00:00:00
'2023-01-02 03:04:06' '2023-01-02 03:04:06'
``` ```
### Interval ### Interval
The INTERVAL data type can be used with the following precision: The INTERVAL data type can be used with the following precision:
- nanosecond - nanosecond
- microsecond - microsecond
@ -161,7 +163,7 @@ The INTERVAL data type can be used with the following precision:
- second - second
- minute - minute
- hour - hour
- day - day
- week - week
- month - month
- year - year
@ -176,7 +178,7 @@ INTERVAL '2 days 1 hour 31 minutes'
## Boolean types ## Boolean types
Booleans store TRUE or FALSE values. Booleans store TRUE or FALSE values.
| Name | Data type | Description | | Name | Data type | Description |
| :------ | :-------- | :------------------- | | :------ | :-------- | :------------------- |
@ -208,3 +210,8 @@ The following SQL types are not currently supported:
- SET - SET
- DATETIME - DATETIME
- BYTEA - BYTEA
## Data types compatible with parameters
For information about data types that can be substituted by parameters,
see how to [use parameterized queries with SQL](/influxdb/cloud-dedicated/query-data/sql/parameterized-queries/).

View File

@ -0,0 +1,354 @@
---
title: Use parameterized queries with InfluxQL
description: >
Use parameterized queries to prevent injection attacks and make queries more reusable.
weight: 404
menu:
influxdb_cloud_serverless:
name: Parameterized queries
parent: Query with InfluxQL
identifier: parameterized-queries-influxql
influxdb/cloud-serverless/tags: [query, security, influxql]
list_code_example: |
##### Using Go and the influxdb3-go client
```go
// Use the $parameter syntax to reference parameters in a query.
// The following InfluxQL query contains $room and $min_time parameters.
query := `
SELECT * FROM home
WHERE time >= $min_time
AND temp >= $min_temp
AND room = $room`
// Assign parameter names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
"min_time": "2024-03-18 00:00:00.00",
}
// Call the client's function to query InfluxDB with parameters and the
// the InfluxQL QueryType.
iterator, err := client.QueryWithParameters(context.Background(),
query,
parameters,
influxdb3.WithQueryType(influxdb3.InfluxQL))
```
---
Parameterized queries in {{% product-name %}} let you dynamically and safely change values in a query.
If your application code allows user input to customize values or expressions in a query, use a parameterized query to make sure untrusted input is processed strictly as data and not executed as code.
Parameterized queries:
- help prevent injection attacks, which can occur if input is executed as code
- help make queries more reusable
{{% note %}}
#### Prevent injection attacks
For more information on security and query parameterization,
see the [OWASP SQL Injection Prevention Cheat Sheet](https://cheatsheetseries.owasp.org/cheatsheets/SQL_Injection_Prevention_Cheat_Sheet.html#defense-option-1-prepared-statements-with-parameterized-queries).
{{% /note %}}
In InfluxDB v3, a parameterized query is an InfluxQL or SQL query that contains one or more named parameter placeholdersvariables that represent input data.
- [Use parameters in `WHERE` expressions](#use-parameters-in-where-expressions)
- [Parameter data types](#parameter-data-types)
- [Data type examples](#data-type-examples)
- [Time expressions](#time-expressions)
- [Not compatible with parameters](#not-compatible-with-parameters)
- [Parameterize an SQL query](#parameterize-an-sql-query)
- [Execute parameterized InfluxQL queries](#execute-parameterized-influxql-queries)
- [Use InfluxDB Flight RPC clients](#use-influxdb-flight-rpc-clients)
- [Client support for parameterized queries](#client-support-for-parameterized-queries)
- [Not supported](#not-supported)
{{% note %}}
#### Parameters only supported in `WHERE` expressions
InfluxDB v3 supports parameters in `WHERE` clause **predicate expressions**.
Parameter values must be one of the [allowed parameter data types](#parameter-data-types).
If you use parameters in other expressions or clauses,
such as function arguments, `SELECT`, or `GROUP BY`, then your query might not work as you expect.
{{% /note %}}
## Use parameters in `WHERE` expressions
You can use parameters in `WHERE` clause **predicate expressions**-for example, the following query contains a `$temp` parameter:
```sql
SELECT * FROM measurement WHERE temp > $temp
```
When executing a query, you specify parameter name-value pairs.
The value that you assign to a parameter must be one of the [parameter data types](#parameter-data-types).
```go
{"temp": 22.0}
```
The InfluxDB Querier parses the query text with the parameter placeholders, and then generates query plans that replace the placeholders with the values that you provide.
This separation of query structure from input data ensures that input is treated as one of the allowed [data types](#parameter-data-types) and not as executable code.
## Parameter data types
A parameter value can be one of the following data types:
- Null
- Boolean
- Unsigned integer (`u_int64`)
- Integer (`int64`)
- Double (`float64`)
- String
### Data type examples
```js
{
"string": "Living Room",
"double": 3.14,
"unsigned_integer": 1234,
"integer": -1234,
"boolean": false,
"null": Null,
}
```
### Time expressions
To parameterize time bounds, substitute a parameter for a timestamp literal--for example:
```sql
SELECT *
FROM home
WHERE time >= $min_time
```
For the parameter value, specify the timestamp literal as a string--for example:
{{% influxdb/custom-timestamps %}}
```go
// Assign a timestamp string literal to the min_time parameter.
parameters := influxdb3.QueryParameters{
"min_time": "2022-01-01 00:00:00.00",
}
```
{{% /influxdb/custom-timestamps %}}
InfluxDB executes the query as the following:
{{% influxdb/custom-timestamps %}}
```sql
SELECT *
FROM home
WHERE time >= '2022-01-01 00:00:00.00'
```
{{% /influxdb/custom-timestamps %}}
### Not compatible with parameters
If you use parameters for the following, your query might not work as you expect:
- In clauses other than `WHERE`, such as `SELECT` or `GROUP BY`
- As function arguments, such as `avg($temp)`
- In place of identifiers, such as column or table names
- In place of duration literals, such as `time > now() - $min_duration`
## Parameterize an SQL query
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/cloud-serverless/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/cloud-serverless/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} bucket before running the example queries.
{{% /note %}}
To use a parameterized query, do the following:
1. In your query text, use the `$parameter` syntax to reference a parameter name--for example,
the following query contains `$room` and `$min_temp` parameter placeholders:
```sql
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= $min_temp
AND room = $room
```
2. Provide a value for each parameter name.
If you don't assign a value for a parameter, InfluxDB returns an error.
The syntax for providing parameter values depends on the client you use--for example:
<!-- I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
<!------------------------ BEGIN GO ------------------------------------------->
```go
// Define a QueryParameters struct--a map of parameters to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
```
<!-------------------------- END GO ------------------------------------------->
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
After InfluxDB receives your request and parses the query, it executes the query as
```sql
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= 20.0
AND room = 'Kitchen'
```
## Execute parameterized InfluxQL queries
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/cloud-serverless/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/cloud-serverless/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} bucket before running the example queries.
{{% /note %}}
### Use InfluxDB Flight RPC clients
Using the InfluxDB v3 native Flight RPC protocol and supported clients, you can send a parameterized query and a list of parameter name-value pairs.
InfluxDB Flight clients that support parameterized queries pass the parameter name-value pairs in a Flight ticket `params` field.
The following examples show how to use client libraries to execute parameterized InfluxQL queries:
<!-- Using code-tabs because I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
```go
import (
"context"
"fmt"
"io"
"os"
"text/tabwriter"
"time"
"github.com/apache/arrow/go/v14/arrow"
"github.com/InfluxCommunity/influxdb3-go/influxdb3"
)
func Query(query string, parameters influxdb3.QueryParameters,
options influxdb3.QueryOptions) error {
url := os.Getenv("INFLUX_HOST")
token := os.Getenv("INFLUX_TOKEN")
database := os.Getenv("INFLUX_BUCKET")
// Instantiate the influxdb3 client.
client, err := influxdb3.New(influxdb3.ClientConfig{
Host: url,
Token: token,
Database: database,
})
if err != nil {
panic(err)
}
// Ensure the client is closed after the Query function finishes.
defer func(client *influxdb3.Client) {
err := client.Close()
if err != nil {
panic(err)
}
}(client)
// Call the client's QueryWithParameters function.
// Provide the query, parameters, and the InfluxQL QueryType option.
iterator, err := client.QueryWithParameters(context.Background(), query,
parameters, influxdb3.WithQueryType(options.QueryType))
// Create a buffer for storing rows as you process them.
w := tabwriter.NewWriter(io.Discard, 4, 4, 1, ' ', 0)
w.Init(os.Stdout, 0, 8, 0, '\t', 0)
fmt.Fprintf(w, "time\troom\tco\thum\ttemp\n")
// Format and write each row to the buffer.
// Process each row as key-value pairs.
for iterator.Next() {
row := iterator.Value()
// Use Go arrow and time packages to format unix timestamp
// as a time with timezone layout (RFC3339 format)
time := (row["time"].(arrow.Timestamp)).
ToTime(arrow.Nanosecond).Format(time.RFC3339)
fmt.Fprintf(w, "%s\t%s\t%d\t%.1f\t%.1f\n",
time, row["room"], row["co"], row["hum"], row["temp"])
}
w.Flush()
return nil
}
func main() {
// Use the $placeholder syntax in a query to reference parameter placeholders
// for input data.
// The following InfluxQL query contains the placeholders $room and $min_temp.
query := `
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= $min_temp
AND room = $room`
// Define a QueryParameters struct--a map of placeholder names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
Query(query, parameters, influxdb3.QueryOptions{
QueryType: influxdb3.InfluxQL,
})
}
```
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
## Client support for parameterized queries
- Not all [InfluxDB v3 Flight clients](/influxdb/cloud-serverless/reference/client-libraries/v3/) support parameterized queries.
- InfluxDB doesn't currently support parameterized queries or DataFusion prepared statements for Flight SQL or Flight SQL clients.
- InfluxDB v3 SQL and InfluxQL parameterized queries arent supported in InfluxDB v1 and v2 clients.
## Not supported
Currently, parameterized queries in {{% product-name %}} don't provide the following:
- support for DataFusion prepared statements
- query caching, optimization, or performance benefits

View File

@ -0,0 +1,346 @@
---
title: Use parameterized queries with SQL
description: >
Use parameterized queries to prevent injection attacks and make queries more reusable.
weight: 404
menu:
influxdb_cloud_serverless:
name: Parameterized queries
parent: Query with SQL
identifier: parameterized-queries-sql
influxdb/cloud-serverless/tags: [query, security, sql]
list_code_example: |
##### Using Go and the influxdb3-go client
```go
// Use the $parameter syntax to reference parameters in a query.
// The following SQL query contains $room and $min_temp placeholders.
query := `
SELECT * FROM home
WHERE time >= $min_time
AND temp >= $min_temp
AND room = $room`
// Assign parameter names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
"min_time": "2024-03-18 00:00:00.00",
}
// Call the client's function to query InfluxDB with parameters.
iterator, err := client.QueryWithParameters(context.Background(), query, parameters)
```
---
Parameterized queries in {{% product-name %}} let you dynamically and safely change values in a query.
If your application code allows user input to customize values or expressions in a query, use a parameterized query to make sure untrusted input is processed strictly as data and not executed as code.
Parameterized queries:
- help prevent injection attacks, which can occur if input is executed as code
- help make queries more reusable
{{% note %}}
#### Prevent injection attacks
For more information on security and query parameterization,
see the [OWASP SQL Injection Prevention Cheat Sheet](https://cheatsheetseries.owasp.org/cheatsheets/SQL_Injection_Prevention_Cheat_Sheet.html#defense-option-1-prepared-statements-with-parameterized-queries).
{{% /note %}}
In InfluxDB v3, a parameterized query is an InfluxQL or SQL query that contains one or more named parameter placeholdersvariables that represent input data.
- [Use parameters in `WHERE` expressions](#use-parameters-in-where-expressions)
- [Parameter data types](#parameter-data-types)
- [Data type examples](#data-type-examples)
- [Time expressions](#time-expressions)
- [Not compatible with parameters](#not-compatible-with-parameters)
- [Parameterize an SQL query](#parameterize-an-sql-query)
- [Execute parameterized SQL queries](#execute-parameterized-sql-queries)
- [Use InfluxDB Flight RPC clients](#use-influxdb-flight-rpc-clients)
- [Client support for parameterized queries](#client-support-for-parameterized-queries)
- [Not supported](#not-supported)
{{% note %}}
#### Parameters only supported in `WHERE` expressions
InfluxDB v3 supports parameters in `WHERE` clause **predicate expressions**.
Parameter values must be one of the [allowed parameter data types](#parameter-data-types).
If you use parameters in other expressions or clauses,
such as function arguments, `SELECT`, or `GROUP BY`, then your query might not work as you expect.
{{% /note %}}
## Use parameters in `WHERE` expressions
You can use parameters in `WHERE` clause **predicate expressions**-for example, the following query contains a `$temp` parameter:
```sql
SELECT * FROM measurement WHERE temp > $temp
```
When executing a query, you specify parameter name-value pairs.
The value that you assign to a parameter must be one of the [parameter data types](#parameter-data-types).
```go
{"temp": 22.0}
```
The InfluxDB Querier parses the query text with the parameter placeholders, and then generates query plans that replace the placeholders with the values that you provide.
This separation of query structure from input data ensures that input is treated as one of the allowed [data types](#parameter-data-types) and not as executable code.
## Parameter data types
A parameter value can be one of the following data types:
- Null
- Boolean
- Unsigned integer (`u_int64`)
- Integer (`int64`)
- Double (`float64`)
- String
### Data type examples
```js
{
"string": "Living Room",
"double": 3.14,
"unsigned_integer": 1234,
"integer": -1234,
"boolean": false,
"null": Null,
}
```
### Time expressions
To parameterize time bounds, substitute a parameter for a timestamp literal--for example:
```sql
SELECT *
FROM home
WHERE time >= $min_time
```
For the parameter value, specify the timestamp literal as a string--for example:
{{% influxdb/custom-timestamps %}}
```go
// Assign a timestamp string literal to the min_time parameter.
parameters := influxdb3.QueryParameters{
"min_time": "2022-01-01 00:00:00.00",
}
```
{{% /influxdb/custom-timestamps %}}
InfluxDB executes the query as the following:
{{% influxdb/custom-timestamps %}}
```sql
SELECT *
FROM home
WHERE time >= '2022-01-01 00:00:00.00'
```
{{% /influxdb/custom-timestamps %}}
### Not compatible with parameters
If you use parameters for the following, your query might not work as you expect:
- In clauses other than `WHERE`, such as `SELECT` or `GROUP BY`
- As function arguments, such as `avg($temp)`
- In place of identifiers, such as column or table names
- In place of duration literals, such as `INTERVAL $minutes`
## Parameterize an SQL query
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/cloud-serverless/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/cloud-serverless/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} bucket before running the example queries.
{{% /note %}}
To use a parameterized query, do the following:
1. In your query text, use the `$parameter` syntax to reference a parameter name--for example,
the following query contains `$room` and `$min_temp` parameter placeholders:
```sql
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= $min_temp
AND room = $room
```
2. Provide a value for each parameter name.
If you don't assign a value for a parameter, InfluxDB returns an error.
The syntax for providing parameter values depends on the client you use--for example:
<!-- I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
<!------------------------ BEGIN GO ------------------------------------------->
```go
// Define a QueryParameters struct--a map of parameters to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
```
<!-------------------------- END GO ------------------------------------------->
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
After InfluxDB receives your request and parses the query, it executes the query as
```sql
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= 20.0
AND room = 'Kitchen'
```
## Execute parameterized SQL queries
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/cloud-serverless/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/cloud-serverless/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} bucket before running the example queries.
{{% /note %}}
### Use InfluxDB Flight RPC clients
Using the InfluxDB v3 native Flight RPC protocol and supported clients, you can send a parameterized query and a list of parameter name-value pairs.
InfluxDB Flight clients that support parameterized queries pass the parameter name-value pairs in a Flight ticket `params` field.
The following examples show how to use client libraries to execute parameterized SQL queries:
<!-- Using code-tabs because I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
```go
import (
"context"
"fmt"
"io"
"os"
"text/tabwriter"
"time"
"github.com/apache/arrow/go/v14/arrow"
"github.com/InfluxCommunity/influxdb3-go/influxdb3"
)
func Query(query string, parameters influxdb3.QueryParameters) error {
url := os.Getenv("INFLUX_HOST")
token := os.Getenv("INFLUX_TOKEN")
database := os.Getenv("INFLUX_BUCKET")
// Instantiate the influxdb3 client.
client, err := influxdb3.New(influxdb3.ClientConfig{
Host: url,
Token: token,
Database: database,
})
if err != nil {
panic(err)
}
// Ensure the client is closed after the Query function finishes.
defer func(client *influxdb3.Client) {
err := client.Close()
if err != nil {
panic(err)
}
}(client)
// Call the client's QueryWithParameters function.
// Provide the query and parameters. The default QueryType is SQL.
iterator, err := client.QueryWithParameters(context.Background(), query,
parameters)
// Create a buffer for storing rows as you process them.
w := tabwriter.NewWriter(io.Discard, 4, 4, 1, ' ', 0)
w.Init(os.Stdout, 0, 8, 0, '\t', 0)
fmt.Fprintf(w, "time\troom\tco\thum\ttemp\n")
// Format and write each row to the buffer.
// Process each row as key-value pairs.
for iterator.Next() {
row := iterator.Value()
// Use Go arrow and time packages to format unix timestamp
// as a time with timezone layout (RFC3339 format)
time := (row["time"].(arrow.Timestamp)).
ToTime(arrow.Nanosecond).Format(time.RFC3339)
fmt.Fprintf(w, "%s\t%s\t%d\t%.1f\t%.1f\n",
time, row["room"], row["co"], row["hum"], row["temp"])
}
w.Flush()
return nil
}
func main() {
// Use the $placeholder syntax in a query to reference parameter placeholders
// for input data.
// The following SQL query contains the placeholders $room and $min_temp.
query := `
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= $min_temp
AND room = $room`
// Define a QueryParameters struct--a map of placeholder names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
}
```
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
## Client support for parameterized queries
- Not all [InfluxDB v3 Flight clients](/influxdb/cloud-serverless/reference/client-libraries/v3/) support parameterized queries.
- InfluxDB doesn't currently support parameterized queries or DataFusion prepared statements for Flight SQL or Flight SQL clients.
- InfluxDB v3 SQL and InfluxQL parameterized queries arent supported in InfluxDB v1 and v2 clients.
## Not supported
Currently, parameterized queries in {{% product-name %}} don't provide the following:
- support for DataFusion prepared statements
- query caching, optimization, or performance benefits

View File

@ -27,6 +27,7 @@ You can review the following ways to work with time and timestamps in your Influ
- [Notable behaviors](#notable-behaviors) - [Notable behaviors](#notable-behaviors)
- [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges) - [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges)
- [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause) - [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause)
- [Cannot use parameters for durations](#cannot-use-parameters-for-durations)
## Time syntax ## Time syntax
@ -81,7 +82,7 @@ InfluxQL requires a whitespace between the `+` operators `-` and the duration li
## Query time range ## Query time range
To specify the time range of a query, use conditional expressions in the To specify the time range of a query, use conditional expressions in the
[`WHERE` clause](/inflxudb/cloud-serverless/reference/influxql/where/) that [`WHERE` clause](/inflxudb/cloud-serverless/reference/influxql/where/) that
compare the value of the `time` column to an absolute timestamp or a relative compare the value of the `time` column to an absolute timestamp or a relative
timestamp. timestamp.
@ -151,7 +152,7 @@ WHERE
AND time <= '2022-01-01T12:00:00Z' AND time <= '2022-01-01T12:00:00Z'
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
@ -178,9 +179,9 @@ WHERE
AND time <= '2022-01-01 12:00:00' AND time <= '2022-01-01 12:00:00'
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -206,9 +207,9 @@ WHERE
AND time <= 1641038400000000000 AND time <= 1641038400000000000
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -233,9 +234,9 @@ WHERE
AND time <= 1641038400s AND time <= 1641038400s
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -255,9 +256,9 @@ name: home
SELECT * FROM home WHERE time >= '2022-01-01T20:00:00Z' - 2h SELECT * FROM home WHERE time >= '2022-01-01T20:00:00Z' - 2h
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :---------- | ---: | | :------------------- | --: | ---: | :---------- | ---: |
@ -322,9 +323,9 @@ WHERE
tz('America/Chicago') tz('America/Chicago')
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------------ | --: | ---: | :------ | ---: | | :------------------------ | --: | ---: | :------ | ---: |
@ -343,6 +344,7 @@ name: home
- [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges) - [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges)
- [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause) - [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause)
- [Cannot use parameters for durations](#cannot-use-parameters-for-durations)
### Cannot query multiple time ranges ### Cannot query multiple time ranges
@ -372,3 +374,8 @@ between `1677-09-21T00:12:43.145224193Z` and
To query data with timestamps that occur in the future (after `now()`), To query data with timestamps that occur in the future (after `now()`),
provide an explicit upper bound in the `WHERE` clause. provide an explicit upper bound in the `WHERE` clause.
### Cannot use parameters for durations
Currently, InfluxDB doesn't support using parameters for durations in
[parameterized queries](/influxdb/cloud-serverless/query-data/parameterized-queries/).

View File

@ -19,17 +19,18 @@ In InfluxDB's SQL implementation, a **measurement** is structured as a table,
and **tags**, **fields** and **timestamps** are exposed as columns. and **tags**, **fields** and **timestamps** are exposed as columns.
DataFusion uses the [Arrow](https://arrow.apache.org/) type system for query execution. DataFusion uses the [Arrow](https://arrow.apache.org/) type system for query execution.
Data types stored in InfluxDB's storage engine are mapped to SQL data types at query time. Data types stored in InfluxDB's storage engine are mapped to SQL data types at query time.
{{% note %}} {{% note %}}
When performing casting operations, cast to the **name** of the data type, not the actual data type. When performing casting operations, cast to the **name** of the data type, not the actual data type.
Names and identifiers in SQL are _case-insensitive_ by default. For example: Names and identifiers in SQL are _case-insensitive_ by default. For example:
```sql ```sql
SELECT SELECT
'99'::BIGINT, '99'::BIGINT,
'2019-09-18T00:00:00Z'::timestamp '2019-09-18T00:00:00Z'::timestamp
``` ```
{{% /note %}} {{% /note %}}
- [String types](#string-types) - [String types](#string-types)
@ -39,9 +40,10 @@ SELECT
- [Floats](#floats) - [Floats](#floats)
- [Date and time data types](#date-and-time-data-types) - [Date and time data types](#date-and-time-data-types)
- [Timestamp](#timestamp) - [Timestamp](#timestamp)
- [Interval ](#interval-) - [Interval](#interval)
- [Boolean types](#boolean-types) - [Boolean types](#boolean-types)
- [Unsupported SQL types](#unsupported-sql-types) - [Unsupported SQL types](#unsupported-sql-types)
- [Data types compatible with parameters](#data-types-compatible-with-parameters)
## String types ## String types
@ -74,7 +76,7 @@ The following numeric types are supported:
InfluxDB SQL supports the 64-bit signed integers: InfluxDB SQL supports the 64-bit signed integers:
**Minimum signed integer**: `-9223372036854775808` **Minimum signed integer**: `-9223372036854775808`
**Maximum signed integer**: `9223372036854775807` **Maximum signed integer**: `9223372036854775807`
##### Example integer literals ##### Example integer literals
@ -89,7 +91,7 @@ InfluxDB SQL supports the 64-bit signed integers:
InfluxDB SQL supports the 64-bit unsigned integers: InfluxDB SQL supports the 64-bit unsigned integers:
**Minimum unsigned integer**: `0` **Minimum unsigned integer**: `0`
**Maximum unsigned integer**: `18446744073709551615` **Maximum unsigned integer**: `18446744073709551615`
##### Example unsigned integer literals ##### Example unsigned integer literals
@ -127,14 +129,14 @@ InfluxDB SQL supports the following DATE/TIME data types:
### Timestamp ### Timestamp
A time type is a single point in time using nanosecond precision. A time type is a single point in time using nanosecond precision.
The following date and time formats are supported: The following date and time formats are supported:
```sql ```sql
YYYY-MM-DDT00:00:00.000Z YYYY-MM-DDT00:00:00.000Z
YYYY-MM-DDT00:00:00.000-00:00 YYYY-MM-DDT00:00:00.000-00:00
YYYY-MM-DD 00:00:00.000-00:00 YYYY-MM-DD 00:00:00.000-00:00
YYYY-MM-DDT00:00:00Z YYYY-MM-DDT00:00:00Z
YYYY-MM-DD 00:00:00.000 YYYY-MM-DD 00:00:00.000
YYYY-MM-DD 00:00:00 YYYY-MM-DD 00:00:00
@ -151,9 +153,9 @@ YYYY-MM-DD 00:00:00
'2023-01-02 03:04:06' '2023-01-02 03:04:06'
``` ```
### Interval ### Interval
The INTERVAL data type can be used with the following precision: The INTERVAL data type can be used with the following precision:
- nanosecond - nanosecond
- microsecond - microsecond
@ -161,13 +163,14 @@ The INTERVAL data type can be used with the following precision:
- second - second
- minute - minute
- hour - hour
- day - day
- week - week
- month - month
- year - year
- century - century
##### Example interval literals ##### Example interval literals
```sql ```sql
INTERVAL '10 minutes' INTERVAL '10 minutes'
INTERVAL '1 year' INTERVAL '1 year'
@ -176,7 +179,7 @@ INTERVAL '2 days 1 hour 31 minutes'
## Boolean types ## Boolean types
Booleans store TRUE or FALSE values. Booleans store TRUE or FALSE values.
| Name | Data type | Description | | Name | Data type | Description |
| :------ | :-------- | :------------------- | | :------ | :-------- | :------------------- |
@ -208,3 +211,8 @@ The following SQL types are not currently supported:
- SET - SET
- DATETIME - DATETIME
- BYTEA - BYTEA
## Data types compatible with parameters
For information about data types that can be substituted by parameters,
see how to [use parameterized queries with SQL](/influxdb/cloud-serverless/query-data/sql/parameterized-queries/).

View File

@ -1,7 +1,7 @@
--- ---
title: WHERE clause title: WHERE clause
list_title: WHERE clause list_title: WHERE clause
description: > description: >
Use the `WHERE` clause to filter results based on fields, tags, or timestamps. Use the `WHERE` clause to filter results based on fields, tags, or timestamps.
menu: menu:
influxdb_cloud_serverless: influxdb_cloud_serverless:
@ -29,13 +29,13 @@ SELECT_clause FROM_clause WHERE <conditional_expression> [(AND|OR) <conditional_
## Examples ## Examples
Note that single quotes are required for string literals in the `WHERE` clause. Note that single quotes are required for string literals in the `WHERE` clause.
### Filter data based on field values ### Filter data based on field values
```sql ```sql
SELECT * SELECT *
FROM "h2o_feet" FROM "h2o_feet"
WHERE "water_level" >= 9.78 WHERE "water_level" >= 9.78
``` ```
@ -57,13 +57,12 @@ that are greater than or equal to 9.78.
{{% /expand %}} {{% /expand %}}
{{< /expand-wrapper >}} {{< /expand-wrapper >}}
### Filter data based on specific tag and field values ### Filter data based on specific tag and field values
```sql ```sql
SELECT * SELECT *
FROM "h2o_feet" FROM "h2o_feet"
WHERE "location" = 'santa_monica' and "level description" = 'below 3 feet' WHERE "location" = 'santa_monica' and "level description" = 'below 3 feet'
``` ```
{{< expand-wrapper >}} {{< expand-wrapper >}}
@ -83,13 +82,13 @@ and a `level description` field value that equals `below 3 feet`.
{{% /expand %}} {{% /expand %}}
{{< /expand-wrapper >}} {{< /expand-wrapper >}}
### Filter data within a specific time period ### Filter data within a specific time period
```sql ```sql
SELECT * SELECT *
FROM h2o_feet FROM h2o_feet
WHERE "location" = 'santa_monica' WHERE "location" = 'santa_monica'
AND "time" >= '2019-08-19T12:00:00Z'::timestamp AND "time" <= '2019-08-19T13:00:00Z'::timestamp AND "time" >= '2019-08-19T12:00:00Z'::timestamp AND "time" <= '2019-08-19T13:00:00Z'::timestamp
``` ```
{{< expand-wrapper >}} {{< expand-wrapper >}}

View File

@ -0,0 +1,354 @@
---
title: Use parameterized queries with InfluxQL
description: >
Use parameterized queries to prevent injection attacks and make queries more reusable.
weight: 404
menu:
influxdb_clustered:
name: Parameterized queries
parent: Query with InfluxQL
identifier: parameterized-queries-influxql
influxdb/clustered/tags: [query, security, influxql]
list_code_example: |
##### Using Go and the influxdb3-go client
```go
// Use the $parameter syntax to reference parameters in a query.
// The following InfluxQL query contains $room and $min_time parameters.
query := `
SELECT * FROM home
WHERE time >= $min_time
AND temp >= $min_temp
AND room = $room`
// Assign parameter names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
"min_time": "2024-03-18 00:00:00.00",
}
// Call the client's function to query InfluxDB with parameters and the
// the InfluxQL QueryType.
iterator, err := client.QueryWithParameters(context.Background(),
query,
parameters,
influxdb3.WithQueryType(influxdb3.InfluxQL))
```
---
Parameterized queries in {{% product-name %}} let you dynamically and safely change values in a query.
If your application code allows user input to customize values or expressions in a query, use a parameterized query to make sure untrusted input is processed strictly as data and not executed as code.
Parameterized queries:
- help prevent injection attacks, which can occur if input is executed as code
- help make queries more reusable
{{% note %}}
#### Prevent injection attacks
For more information on security and query parameterization,
see the [OWASP SQL Injection Prevention Cheat Sheet](https://cheatsheetseries.owasp.org/cheatsheets/SQL_Injection_Prevention_Cheat_Sheet.html#defense-option-1-prepared-statements-with-parameterized-queries).
{{% /note %}}
In InfluxDB v3, a parameterized query is an InfluxQL or SQL query that contains one or more named parameter placeholdersvariables that represent input data.
- [Use parameters in `WHERE` expressions](#use-parameters-in-where-expressions)
- [Parameter data types](#parameter-data-types)
- [Data type examples](#data-type-examples)
- [Time expressions](#time-expressions)
- [Not compatible with parameters](#not-compatible-with-parameters)
- [Parameterize an SQL query](#parameterize-an-sql-query)
- [Execute parameterized InfluxQL queries](#execute-parameterized-influxql-queries)
- [Use InfluxDB Flight RPC clients](#use-influxdb-flight-rpc-clients)
- [Client support for parameterized queries](#client-support-for-parameterized-queries)
- [Not supported](#not-supported)
{{% note %}}
#### Parameters only supported in `WHERE` expressions
InfluxDB v3 supports parameters in `WHERE` clause **predicate expressions**.
Parameter values must be one of the [allowed parameter data types](#parameter-data-types).
If you use parameters in other expressions or clauses,
such as function arguments, `SELECT`, or `GROUP BY`, then your query might not work as you expect.
{{% /note %}}
## Use parameters in `WHERE` expressions
You can use parameters in `WHERE` clause **predicate expressions**-for example, the following query contains a `$temp` parameter:
```sql
SELECT * FROM measurement WHERE temp > $temp
```
When executing a query, you specify parameter name-value pairs.
The value that you assign to a parameter must be one of the [parameter data types](#parameter-data-types).
```go
{"temp": 22.0}
```
The InfluxDB Querier parses the query text with the parameter placeholders, and then generates query plans that replace the placeholders with the values that you provide.
This separation of query structure from input data ensures that input is treated as one of the allowed [data types](#parameter-data-types) and not as executable code.
## Parameter data types
A parameter value can be one of the following data types:
- Null
- Boolean
- Unsigned integer (`u_int64`)
- Integer (`int64`)
- Double (`float64`)
- String
### Data type examples
```js
{
"string": "Living Room",
"double": 3.14,
"unsigned_integer": 1234,
"integer": -1234,
"boolean": false,
"null": Null,
}
```
### Time expressions
To parameterize time bounds, substitute a parameter for a timestamp literal--for example:
```sql
SELECT *
FROM home
WHERE time >= $min_time
```
For the parameter value, specify the timestamp literal as a string--for example:
{{% influxdb/custom-timestamps %}}
```go
// Assign a timestamp string literal to the min_time parameter.
parameters := influxdb3.QueryParameters{
"min_time": "2022-01-01 00:00:00.00",
}
```
{{% /influxdb/custom-timestamps %}}
InfluxDB executes the query as the following:
{{% influxdb/custom-timestamps %}}
```sql
SELECT *
FROM home
WHERE time >= '2022-01-01 00:00:00.00'
```
{{% /influxdb/custom-timestamps %}}
### Not compatible with parameters
If you use parameters for the following, your query might not work as you expect:
- In clauses other than `WHERE`, such as `SELECT` or `GROUP BY`
- As function arguments, such as `avg($temp)`
- In place of identifiers, such as column or table names
- In place of duration literals, such as `time > now() - $min_duration`
## Parameterize an SQL query
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/clustered/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/clustered/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} database before running the example queries.
{{% /note %}}
To use a parameterized query, do the following:
1. In your query text, use the `$parameter` syntax to reference a parameter name--for example,
the following query contains `$room` and `$min_temp` parameter placeholders:
```sql
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= $min_temp
AND room = $room
```
2. Provide a value for each parameter name.
If you don't assign a value for a parameter, InfluxDB returns an error.
The syntax for providing parameter values depends on the client you use--for example:
<!-- I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
<!------------------------ BEGIN GO ------------------------------------------->
```go
// Define a QueryParameters struct--a map of parameters to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
```
<!-------------------------- END GO ------------------------------------------->
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
After InfluxDB receives your request and parses the query, it executes the query as
```sql
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= 20.0
AND room = 'Kitchen'
```
## Execute parameterized InfluxQL queries
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/clustered/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/clustered/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} database before running the example queries.
{{% /note %}}
### Use InfluxDB Flight RPC clients
Using the InfluxDB v3 native Flight RPC protocol and supported clients, you can send a parameterized query and a list of parameter name-value pairs.
InfluxDB Flight clients that support parameterized queries pass the parameter name-value pairs in a Flight ticket `params` field.
The following examples show how to use client libraries to execute parameterized InfluxQL queries:
<!-- Using code-tabs because I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
```go
import (
"context"
"fmt"
"io"
"os"
"text/tabwriter"
"time"
"github.com/apache/arrow/go/v14/arrow"
"github.com/InfluxCommunity/influxdb3-go/influxdb3"
)
func Query(query string, parameters influxdb3.QueryParameters,
options influxdb3.QueryOptions) error {
url := os.Getenv("INFLUX_HOST")
token := os.Getenv("INFLUX_TOKEN")
database := os.Getenv("INFLUX_DATABASE")
// Instantiate the influxdb3 client.
client, err := influxdb3.New(influxdb3.ClientConfig{
Host: url,
Token: token,
Database: database,
})
if err != nil {
panic(err)
}
// Ensure the client is closed after the Query function finishes.
defer func(client *influxdb3.Client) {
err := client.Close()
if err != nil {
panic(err)
}
}(client)
// Call the client's QueryWithParameters function.
// Provide the query, parameters, and the InfluxQL QueryType option.
iterator, err := client.QueryWithParameters(context.Background(), query,
parameters, influxdb3.WithQueryType(options.QueryType))
// Create a buffer for storing rows as you process them.
w := tabwriter.NewWriter(io.Discard, 4, 4, 1, ' ', 0)
w.Init(os.Stdout, 0, 8, 0, '\t', 0)
fmt.Fprintf(w, "time\troom\tco\thum\ttemp\n")
// Format and write each row to the buffer.
// Process each row as key-value pairs.
for iterator.Next() {
row := iterator.Value()
// Use Go arrow and time packages to format unix timestamp
// as a time with timezone layout (RFC3339 format)
time := (row["time"].(arrow.Timestamp)).
ToTime(arrow.Nanosecond).Format(time.RFC3339)
fmt.Fprintf(w, "%s\t%s\t%d\t%.1f\t%.1f\n",
time, row["room"], row["co"], row["hum"], row["temp"])
}
w.Flush()
return nil
}
func main() {
// Use the $placeholder syntax in a query to reference parameter placeholders
// for input data.
// The following InfluxQL query contains the placeholders $room and $min_temp.
query := `
SELECT *
FROM home
WHERE time > now() - 7d
AND temp >= $min_temp
AND room = $room`
// Define a QueryParameters struct--a map of placeholder names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
Query(query, parameters, influxdb3.QueryOptions{
QueryType: influxdb3.InfluxQL,
})
}
```
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
## Client support for parameterized queries
- Not all [InfluxDB v3 Flight clients](/influxdb/clustered/reference/client-libraries/v3/) support parameterized queries.
- InfluxDB doesn't currently support parameterized queries or DataFusion prepared statements for Flight SQL or Flight SQL clients.
- InfluxDB v3 SQL and InfluxQL parameterized queries arent supported in InfluxDB v1 and v2 clients.
## Not supported
Currently, parameterized queries in {{% product-name %}} don't provide the following:
- support for DataFusion prepared statements
- query caching, optimization, or performance benefits

View File

@ -0,0 +1,346 @@
---
title: Use parameterized queries with SQL
description: >
Use parameterized queries to prevent injection attacks and make queries more reusable.
weight: 404
menu:
influxdb_clustered:
name: Parameterized queries
parent: Query with SQL
identifier: parameterized-queries-sql
influxdb/clustered/tags: [query, security, sql]
list_code_example: |
##### Using Go and the influxdb3-go client
```go
// Use the $parameter syntax to reference parameters in a query.
// The following SQL query contains $room and $min_temp placeholders.
query := `
SELECT * FROM home
WHERE time >= $min_time
AND temp >= $min_temp
AND room = $room`
// Assign parameter names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
"min_time": "2024-03-18 00:00:00.00",
}
// Call the client's function to query InfluxDB with parameters.
iterator, err := client.QueryWithParameters(context.Background(), query, parameters)
```
---
Parameterized queries in {{% product-name %}} let you dynamically and safely change values in a query.
If your application code allows user input to customize values or expressions in a query, use a parameterized query to make sure untrusted input is processed strictly as data and not executed as code.
Parameterized queries:
- help prevent injection attacks, which can occur if input is executed as code
- help make queries more reusable
{{% note %}}
#### Prevent injection attacks
For more information on security and query parameterization,
see the [OWASP SQL Injection Prevention Cheat Sheet](https://cheatsheetseries.owasp.org/cheatsheets/SQL_Injection_Prevention_Cheat_Sheet.html#defense-option-1-prepared-statements-with-parameterized-queries).
{{% /note %}}
In InfluxDB v3, a parameterized query is an InfluxQL or SQL query that contains one or more named parameter placeholdersvariables that represent input data.
- [Use parameters in `WHERE` expressions](#use-parameters-in-where-expressions)
- [Parameter data types](#parameter-data-types)
- [Data type examples](#data-type-examples)
- [Time expressions](#time-expressions)
- [Not compatible with parameters](#not-compatible-with-parameters)
- [Parameterize an SQL query](#parameterize-an-sql-query)
- [Execute parameterized SQL queries](#execute-parameterized-sql-queries)
- [Use InfluxDB Flight RPC clients](#use-influxdb-flight-rpc-clients)
- [Client support for parameterized queries](#client-support-for-parameterized-queries)
- [Not supported](#not-supported)
{{% note %}}
#### Parameters only supported in `WHERE` expressions
InfluxDB v3 supports parameters in `WHERE` clause **predicate expressions**.
Parameter values must be one of the [allowed parameter data types](#parameter-data-types).
If you use parameters in other expressions or clauses,
such as function arguments, `SELECT`, or `GROUP BY`, then your query might not work as you expect.
{{% /note %}}
## Use parameters in `WHERE` expressions
You can use parameters in `WHERE` clause **predicate expressions**-for example, the following query contains a `$temp` parameter:
```sql
SELECT * FROM measurement WHERE temp > $temp
```
When executing a query, you specify parameter name-value pairs.
The value that you assign to a parameter must be one of the [parameter data types](#parameter-data-types).
```go
{"temp": 22.0}
```
The InfluxDB Querier parses the query text with the parameter placeholders, and then generates query plans that replace the placeholders with the values that you provide.
This separation of query structure from input data ensures that input is treated as one of the allowed [data types](#parameter-data-types) and not as executable code.
## Parameter data types
A parameter value can be one of the following data types:
- Null
- Boolean
- Unsigned integer (`u_int64`)
- Integer (`int64`)
- Double (`float64`)
- String
### Data type examples
```js
{
"string": "Living Room",
"double": 3.14,
"unsigned_integer": 1234,
"integer": -1234,
"boolean": false,
"null": Null,
}
```
### Time expressions
To parameterize time bounds, substitute a parameter for a timestamp literal--for example:
```sql
SELECT *
FROM home
WHERE time >= $min_time
```
For the parameter value, specify the timestamp literal as a string--for example:
{{% influxdb/custom-timestamps %}}
```go
// Assign a timestamp string literal to the min_time parameter.
parameters := influxdb3.QueryParameters{
"min_time": "2022-01-01 00:00:00.00",
}
```
{{% /influxdb/custom-timestamps %}}
InfluxDB executes the query as the following:
{{% influxdb/custom-timestamps %}}
```sql
SELECT *
FROM home
WHERE time >= '2022-01-01 00:00:00.00'
```
{{% /influxdb/custom-timestamps %}}
### Not compatible with parameters
If you use parameters for the following, your query might not work as you expect:
- In clauses other than `WHERE`, such as `SELECT` or `GROUP BY`
- As function arguments, such as `avg($temp)`
- In place of identifiers, such as column or table names
- In place of duration literals, such as `INTERVAL $minutes`
## Parameterize an SQL query
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/clustered/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/clustered/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} database before running the example queries.
{{% /note %}}
To use a parameterized query, do the following:
1. In your query text, use the `$parameter` syntax to reference a parameter name--for example,
the following query contains `$room` and `$min_temp` parameter placeholders:
```sql
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= $min_temp
AND room = $room
```
2. Provide a value for each parameter name.
If you don't assign a value for a parameter, InfluxDB returns an error.
The syntax for providing parameter values depends on the client you use--for example:
<!-- I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
<!------------------------ BEGIN GO ------------------------------------------->
```go
// Define a QueryParameters struct--a map of parameters to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
```
<!-------------------------- END GO ------------------------------------------->
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
After InfluxDB receives your request and parses the query, it executes the query as
```sql
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= 20.0
AND room = 'Kitchen'
```
## Execute parameterized SQL queries
{{% note %}}
#### Sample data
The following examples use the
[Get started home sensor data](/influxdb/clustered/reference/sample-data/#get-started-home-sensor-data).
To run the example queries and return results,
[write the sample data](/influxdb/clustered/reference/sample-data/#write-the-home-sensor-data-to-influxdb)
to your {{% product-name %}} database before running the example queries.
{{% /note %}}
### Use InfluxDB Flight RPC clients
Using the InfluxDB v3 native Flight RPC protocol and supported clients, you can send a parameterized query and a list of parameter name-value pairs.
InfluxDB Flight clients that support parameterized queries pass the parameter name-value pairs in a Flight ticket `params` field.
The following examples show how to use client libraries to execute parameterized SQL queries:
<!-- Using code-tabs because I expect to add more client examples soon -->
{{< code-tabs-wrapper >}}
{{% code-tabs %}}
[Go](#)
{{% /code-tabs %}}
{{% code-tab-content %}}
```go
import (
"context"
"fmt"
"io"
"os"
"text/tabwriter"
"time"
"github.com/apache/arrow/go/v14/arrow"
"github.com/InfluxCommunity/influxdb3-go/influxdb3"
)
func Query(query string, parameters influxdb3.QueryParameters) error {
url := os.Getenv("INFLUX_HOST")
token := os.Getenv("INFLUX_TOKEN")
database := os.Getenv("INFLUX_DATABASE")
// Instantiate the influxdb3 client.
client, err := influxdb3.New(influxdb3.ClientConfig{
Host: url,
Token: token,
Database: database,
})
if err != nil {
panic(err)
}
// Ensure the client is closed after the Query function finishes.
defer func(client *influxdb3.Client) {
err := client.Close()
if err != nil {
panic(err)
}
}(client)
// Call the client's QueryWithParameters function.
// Provide the query and parameters. The default QueryType is SQL.
iterator, err := client.QueryWithParameters(context.Background(), query,
parameters)
// Create a buffer for storing rows as you process them.
w := tabwriter.NewWriter(io.Discard, 4, 4, 1, ' ', 0)
w.Init(os.Stdout, 0, 8, 0, '\t', 0)
fmt.Fprintf(w, "time\troom\tco\thum\ttemp\n")
// Format and write each row to the buffer.
// Process each row as key-value pairs.
for iterator.Next() {
row := iterator.Value()
// Use Go arrow and time packages to format unix timestamp
// as a time with timezone layout (RFC3339 format)
time := (row["time"].(arrow.Timestamp)).
ToTime(arrow.Nanosecond).Format(time.RFC3339)
fmt.Fprintf(w, "%s\t%s\t%d\t%.1f\t%.1f\n",
time, row["room"], row["co"], row["hum"], row["temp"])
}
w.Flush()
return nil
}
func main() {
// Use the $placeholder syntax in a query to reference parameter placeholders
// for input data.
// The following SQL query contains the placeholders $room and $min_temp.
query := `
SELECT *
FROM home
WHERE time > now() - INTERVAL '7 days'
AND temp >= $min_temp
AND room = $room`
// Define a QueryParameters struct--a map of placeholder names to input values.
parameters := influxdb3.QueryParameters{
"room": "Kitchen",
"min_temp": 20.0,
}
}
```
{{% /code-tab-content %}}
{{< /code-tabs-wrapper >}}
## Client support for parameterized queries
- Not all [InfluxDB v3 Flight clients](/influxdb/clustered/reference/client-libraries/v3/) support parameterized queries.
- InfluxDB doesn't currently support parameterized queries or DataFusion prepared statements for Flight SQL or Flight SQL clients.
- InfluxDB v3 SQL and InfluxQL parameterized queries arent supported in InfluxDB v1 and v2 clients.
## Not supported
Currently, parameterized queries in {{% product-name %}} don't provide the following:
- support for DataFusion prepared statements
- query caching, optimization, or performance benefits

View File

@ -27,6 +27,7 @@ You can review the following ways to work with time and timestamps in your Influ
- [Notable behaviors](#notable-behaviors) - [Notable behaviors](#notable-behaviors)
- [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges) - [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges)
- [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause) - [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause)
- [Cannot use parameters for durations](#cannot-use-parameters-for-durations)
## Time syntax ## Time syntax
@ -81,7 +82,7 @@ InfluxQL requires a whitespace between the `+` operators `-` and the duration li
## Query time range ## Query time range
To specify the time range of a query, use conditional expressions in the To specify the time range of a query, use conditional expressions in the
[`WHERE` clause](/inflxudb/clustered/reference/influxql/where/) that [`WHERE` clause](/inflxudb/clustered/reference/influxql/where/) that
compare the value of the `time` column to an absolute timestamp or a relative compare the value of the `time` column to an absolute timestamp or a relative
timestamp. timestamp.
@ -151,7 +152,7 @@ WHERE
AND time <= '2022-01-01T12:00:00Z' AND time <= '2022-01-01T12:00:00Z'
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
@ -178,9 +179,9 @@ WHERE
AND time <= '2022-01-01 12:00:00' AND time <= '2022-01-01 12:00:00'
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -206,9 +207,9 @@ WHERE
AND time <= 1641038400000000000 AND time <= 1641038400000000000
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -233,9 +234,9 @@ WHERE
AND time <= 1641038400s AND time <= 1641038400s
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :------ | ---: | | :------------------- | --: | ---: | :------ | ---: |
@ -255,9 +256,9 @@ name: home
SELECT * FROM home WHERE time >= '2022-01-01T20:00:00Z' - 2h SELECT * FROM home WHERE time >= '2022-01-01T20:00:00Z' - 2h
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------- | --: | ---: | :---------- | ---: | | :------------------- | --: | ---: | :---------- | ---: |
@ -320,9 +321,9 @@ WHERE
tz('America/Chicago') tz('America/Chicago')
``` ```
{{% influxql/table-meta %}} {{% influxql/table-meta %}}
name: home name: home
{{% /influxql/table-meta %}} {{% /influxql/table-meta %}}
| time | co | hum | room | temp | | time | co | hum | room | temp |
| :------------------------ | --: | ---: | :------ | ---: | | :------------------------ | --: | ---: | :------ | ---: |
@ -341,6 +342,7 @@ name: home
- [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges) - [Cannot query multiple time ranges](#cannot-query-multiple-time-ranges)
- [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause) - [Querying future data with a `GROUP BY time()` clause](#querying-future-data-with-a-group-by-time-clause)
- [Cannot use parameters for durations](#cannot-use-parameters-for-durations)
### Cannot query multiple time ranges ### Cannot query multiple time ranges
@ -370,3 +372,8 @@ between `1677-09-21T00:12:43.145224193Z` and
To query data with timestamps that occur in the future (after `now()`), To query data with timestamps that occur in the future (after `now()`),
provide an explicit upper bound in the `WHERE` clause. provide an explicit upper bound in the `WHERE` clause.
### Cannot use parameters for durations
Currently, InfluxDB doesn't support using parameters for durations in
[parameterized queries](/influxdb/clustered/query-data/parameterized-queries/).

View File

@ -19,17 +19,18 @@ In InfluxDB's SQL implementation, a **measurement** is structured as a table,
and **tags**, **fields** and **timestamps** are exposed as columns. and **tags**, **fields** and **timestamps** are exposed as columns.
DataFusion uses the [Arrow](https://arrow.apache.org/) type system for query execution. DataFusion uses the [Arrow](https://arrow.apache.org/) type system for query execution.
Data types stored in InfluxDB's storage engine are mapped to SQL data types at query time. Data types stored in InfluxDB's storage engine are mapped to SQL data types at query time.
{{% note %}} {{% note %}}
When performing casting operations, cast to the **name** of the data type, not the actual data type. When performing casting operations, cast to the **name** of the data type, not the actual data type.
Names and identifiers in SQL are _case-insensitive_ by default. For example: Names and identifiers in SQL are _case-insensitive_ by default. For example:
```sql ```sql
SELECT SELECT
'99'::BIGINT, '99'::BIGINT,
'2019-09-18T00:00:00Z'::timestamp '2019-09-18T00:00:00Z'::timestamp
``` ```
{{% /note %}} {{% /note %}}
- [String types](#string-types) - [String types](#string-types)
@ -39,9 +40,10 @@ SELECT
- [Floats](#floats) - [Floats](#floats)
- [Date and time data types](#date-and-time-data-types) - [Date and time data types](#date-and-time-data-types)
- [Timestamp](#timestamp) - [Timestamp](#timestamp)
- [Interval ](#interval-) - [Interval](#interval)
- [Boolean types](#boolean-types) - [Boolean types](#boolean-types)
- [Unsupported SQL types](#unsupported-sql-types) - [Unsupported SQL types](#unsupported-sql-types)
- [Data types compatible with parameters](#data-types-compatible-with-parameters)
## String types ## String types
@ -74,7 +76,7 @@ The following numeric types are supported:
InfluxDB SQL supports the 64-bit signed integers: InfluxDB SQL supports the 64-bit signed integers:
**Minimum signed integer**: `-9223372036854775808` **Minimum signed integer**: `-9223372036854775808`
**Maximum signed integer**: `9223372036854775807` **Maximum signed integer**: `9223372036854775807`
##### Example integer literals ##### Example integer literals
@ -89,7 +91,7 @@ InfluxDB SQL supports the 64-bit signed integers:
InfluxDB SQL supports the 64-bit unsigned integers: InfluxDB SQL supports the 64-bit unsigned integers:
**Minimum unsigned integer**: `0` **Minimum unsigned integer**: `0`
**Maximum unsigned integer**: `18446744073709551615` **Maximum unsigned integer**: `18446744073709551615`
##### Example unsigned integer literals ##### Example unsigned integer literals
@ -127,14 +129,14 @@ InfluxDB SQL supports the following DATE/TIME data types:
### Timestamp ### Timestamp
A time type is a single point in time using nanosecond precision. A time type is a single point in time using nanosecond precision.
The following date and time formats are supported: The following date and time formats are supported:
```sql ```sql
YYYY-MM-DDT00:00:00.000Z YYYY-MM-DDT00:00:00.000Z
YYYY-MM-DDT00:00:00.000-00:00 YYYY-MM-DDT00:00:00.000-00:00
YYYY-MM-DD 00:00:00.000-00:00 YYYY-MM-DD 00:00:00.000-00:00
YYYY-MM-DDT00:00:00Z YYYY-MM-DDT00:00:00Z
YYYY-MM-DD 00:00:00.000 YYYY-MM-DD 00:00:00.000
YYYY-MM-DD 00:00:00 YYYY-MM-DD 00:00:00
@ -151,9 +153,9 @@ YYYY-MM-DD 00:00:00
'2023-01-02 03:04:06' '2023-01-02 03:04:06'
``` ```
### Interval ### Interval
The INTERVAL data type can be used with the following precision: The INTERVAL data type can be used with the following precision:
- nanosecond - nanosecond
- microsecond - microsecond
@ -161,7 +163,7 @@ The INTERVAL data type can be used with the following precision:
- second - second
- minute - minute
- hour - hour
- day - day
- week - week
- month - month
- year - year
@ -176,7 +178,7 @@ INTERVAL '2 days 1 hour 31 minutes'
## Boolean types ## Boolean types
Booleans store TRUE or FALSE values. Booleans store TRUE or FALSE values.
| Name | Data type | Description | | Name | Data type | Description |
| :------ | :-------- | :------------------- | | :------ | :-------- | :------------------- |
@ -208,3 +210,8 @@ The following SQL types are not currently supported:
- SET - SET
- DATETIME - DATETIME
- BYTEA - BYTEA
## Data types compatible with parameters
For information about data types that can be substituted by parameters,
see how to [use parameterized queries with SQL](/influxdb/clustered/query-data/sql/parameterized-queries/).