WHERE keyword
WHERE clause filters data. Filter expressions are required to return boolean
result.
QuestDB includes a JIT compiler for SQL queries which contain WHERE clauses.
Syntax#
The general syntax is as follows. Specific filters have distinct syntaxes detailed thereafter.
Logical operators#
QuestDB supports AND, OR, NOT as logical operators and can assemble
conditions using brackets ().
Symbol and string#
QuestDB can filter strings and symbols based on equality, inequality, and regular expression patterns.
Exact match#
Evaluates match of a string or symbol.
| name | age |
|---|---|
| John | 31 |
| John | 45 |
| ... | ... |
Does NOT match#
Evaluates mismatch of a string or symbol.
| name | age |
|---|---|
| Tim | 31 |
| Tom | 45 |
| ... | ... |
Regular expression match#
Evaluates match against a regular expression defined using java.util.regex patterns.
| name | age |
|---|---|
| Joe | 31 |
| Jonathan | 45 |
| ... | ... |
Regular expression does NOT match#
Evaluates mismatch against a regular expression defined using java.util.regex patterns.
| name | age |
|---|---|
| Tim | 31 |
| Tom | 45 |
| ... | ... |
List search#
Evaluates match or mismatch against a list of elements.
| name | age |
|---|---|
| Tim | 31 |
| Tom | 45 |
| ... | ... |
| name | age |
|---|---|
| Aaron | 31 |
| Amelie | 45 |
| ... | ... |
Numeric#
QuestDB can filter numeric values based on equality, inequality, comparison, and proximity.
note
For timestamp filters, we recommend the timestamp search notation which is faster and less verbose.
Equality, inequality and comparison#
Boolean#
Using the columnName will return true values. To return false values,
precede the column name with the NOT operator.
| userId | isActive |
|---|---|
| 12532 | true |
| 38572 | true |
| ... | ... |
| userId | isActive |
|---|---|
| 876534 | false |
| 43234 | false |
| ... | ... |
Timestamp and date#
QuestDB supports both its own timestamp search notation and standard search based on inequality. This section describes the use of the timestamp search notation which is efficient and fast but requires a designated timestamp.
If a table does not have a designated timestamp applied during table creation, one may be applied dynamically during a select operation.
Native timestamp format#
QuestDB automatically recognizes strings formatted as ISO timestamp as a
timestamp type. The following are valid examples of strings parsed as
timestamp types:
| Valid STRING Format | Resulting Timestamp |
|---|---|
| 2010-01-12T12:35:26.123456+01:30 | 2010-01-12T11:05:26.123456Z |
| 2010-01-12T12:35:26.123456+01 | 2010-01-12T11:35:26.123456Z |
| 2010-01-12T12:35:26.123456Z | 2010-01-12T12:35:26.123456Z |
| 2010-01-12T12:35:26.12345 | 2010-01-12T12:35:26.123450Z |
| 2010-01-12T12:35:26.1234 | 2010-01-12T12:35:26.123400Z |
| 2010-01-12T12:35:26.123 | 2010-01-12T12:35:26.123000Z |
| 2010-01-12T12:35:26.12 | 2010-01-12T12:35:26.120000Z |
| 2010-01-12T12:35:26.1 | 2010-01-12T12:35:26.100000Z |
| 2010-01-12T12:35:26 | 2010-01-12T12:35:26.000000Z |
| 2010-01-12T12:35 | 2010-01-12T12:35:00.000000Z |
| 2010-01-12T12 | 2010-01-12T12:00:00.000000Z |
| 2010-01-12 | 2010-01-12T00:00:00.000000Z |
| 2010-01 | 2010-01-01T00:00:00.000000Z |
| 2010 | 2010-01-01T00:00:00.000000Z |
| 2010-01-12 12:35:26.123456-02:00 | 2010-01-12T14:35:26.123456Z |
| 2010-01-12 12:35:26.123456Z | 2010-01-12T12:35:26.123456Z |
| 2010-01-12 12:35:26.123 | 2010-01-12T12:35:26.123000Z |
| 2010-01-12 12:35:26.12 | 2010-01-12T12:35:26.120000Z |
| 2010-01-12 12:35:26.1 | 2010-01-12T12:35:26.100000Z |
| 2010-01-12 12:35:26 | 2010-01-12T12:35:26.000000Z |
| 2010-01-12 12:35 | 2010-01-12T12:35:00.000000Z |
Exact timestamp#
Syntax#
| ts | score |
|---|---|
| 2010-01-12T00:02:26.000Z | 2.4 |
| 2010-01-12T00:02:26.000Z | 3.1 |
| ... | ... |
| ts | score |
|---|---|
| 2010-01-12T00:02:26.000000Z | 2.4 |
| 2010-01-12T00:02:26.000000Z | 3.1 |
| ... | ... |
Time range#
Returns results within a defined range.
Syntax#
| ts | score |
|---|---|
| 2018-01-01T00:0000.000000Z | 123.4 |
| ... | ... |
| 2018-12-31T23:59:59.999999Z | 115.8 |
| ts | score |
|---|---|
| 2018-05-23T12:15:00.000000Z | 123.4 |
| ... | ... |
| 2018-05-23T12:15:59.999999Z | 115.8 |
Time range with modifier#
You can apply a modifier to further customize the range. The modifier extends the upper bound of the original timestamp based on the modifier parameter. An optional interval with occurrence can be set, to apply the search in the given time range repeatedly, for a set number of times.
Syntax#
timestampis the original time range for the query.modifieris a signed integer modifying the upper bound applying to thetimestamp:- A
positivevalue extends the selected period. - A
negativevalue reduces the selected period.
- A
intervalis an unsigned integer indicating the desired interval period for the time range.repetitionis an unsigned integer indicating the number of times the interval should be applied.
Examples#
Modifying the range:
The range is 2018. The modifier extends the upper bound (originally 31 Dec 2018) by one month.
| ts | score |
|---|---|
| 2018-01-01T00:00:00.000000Z | 123.4 |
| ... | ... |
| 2019-01-31T23:59:59.999999Z | 115.8 |
The range is Jan 2018. The modifier reduces the upper bound (originally 31 Jan 2018) by 3 days.
| ts | score |
|---|---|
| 2018-01-01T00:00:00.000000Z | 123.4 |
| ... | ... |
| 2018-01-28T23:59:59.999999Z | 113.8 |
Modifying the interval:
The range is extended by one day from Jan 1 2018, with a one-year interval, repeated twice. This means that the query searches for results on Jan 1-2 in 2018 and in 2019:
| ts | score |
|---|---|
| 2018-01-01T00:00:00.000000Z | 123.4 |
| ... | ... |
| 2018-01-02T23:59:59.999999Z | 110.3 |
| 2019-01-01T00:00:00.000000Z | 128.7 |
| ... | ... |
| 2019-01-02T23:59:59.999999Z | 103.8 |
IN with multiple arguments#
Syntax#
IN with more than 1 argument is treated as standard SQL IN. It is a
shorthand of multiple OR conditions, i.e. the following query:
is equivalent to:
| ts | value |
|---|---|
| 2018-01-01T00:00:00.000000Z | 123.4 |
| 2018-01-01T12:00:00.000000Z | 589.1 |
| 2018-01-02T00:00:00.000000Z | 131.5 |
BETWEEN#
Syntax#
For non-standard ranges, users can explicitly specify the target range using the
BETWEEN operator. As with standard SQL, both upper and lower bounds of
BETWEEN are inclusive, and the order of lower and upper bounds is not
important so that BETWEEN X AND Y is equivalent to BETWEEN Y AND X.
| ts | value |
|---|---|
| 2018-01-01T00:00:23.000000Z | 123.4 |
| ... | ... |
| 2018-01-01T00:00:23.500000Z | 131.5 |
BETWEEN can accept non-constant bounds, for example, the following query will
return all records older than one year before the current date: