You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
docs(ASOF JOIN): Clarify timestamp control and precedence (#197)
Rework the `ASOF JOIN` timestamp documentation to address the common
misuse of the `timestamp(ts)` syntax.
The guide now clarifies that the designated timestamp is inherited by
default. The standard method for joining on a different column is to use
an `ORDER BY` clause in a subquery, which implicitly sets a new
timestamp for the join.
The `timestamp(ts)` syntax is now correctly framed as an expert-level
performance hint, used only to assert a pre-sorted order on data that
lacks a designated timestamp.
---------
Co-authored-by: goodroot <9484709+goodroot@users.noreply.github.com>
Copy file name to clipboardExpand all lines: documentation/reference/sql/asof-join.md
+76-16Lines changed: 76 additions & 16 deletions
Display the source diff
Display the rich diff
Original file line number
Diff line number
Diff line change
@@ -327,31 +327,91 @@ Result:
327
327
328
328
</div>
329
329
330
-
### Timestamp considerations
330
+
### How ASOF JOIN uses timestamps
331
331
332
-
`ASOF` join can be performed only on tables or result sets that are ordered by
333
-
time. When a table is created with a
334
-
[designated timestamp](/docs/concept/designated-timestamp/) the order of records
335
-
is enforced and the timestamp column name is in the table metadata. `ASOF` join
336
-
uses this timestamp column from metadata.
332
+
`ASOF JOIN` requires tables or subqueries to be ordered by time. The best way to meet this requirement is to use a
333
+
[designated timestamp](/docs/concept/designated-timestamp/), which is set when you create a table.
334
+
This not only enforces the chronological order of your data but also tells QuestDB which column to use for time-series
335
+
operations automatically.
337
336
338
-
:::caution
337
+
#### Default behavior
339
338
340
-
`ASOF` join requires that the tables or subqueries have designated timestamps. This means
341
-
they have an ascending order timestamp column, which may need to be specified with `timestamp(ts)`. See below!
339
+
By default, an `ASOF JOIN` will always use the designated timestamp of the tables involved.
342
340
343
-
:::
341
+
This behavior is so fundamental that it extends to subqueries in a unique way: even if you do not explicitly SELECT the
342
+
designated timestamp column in a subquery, QuestDB implicitly propagates it. The join is performed correctly under the
343
+
hood using this hidden timestamp, which is then omitted from the final result set.
344
344
345
-
In case tables do not have a designated timestamp column, but data is in
346
-
chronological order, timestamp columns can be specified at runtime:
345
+
This makes most `ASOF JOIN` queries simple and intuitive.
347
346
348
-
```questdb-sql
347
+
```questdb-sql title="ASOF JOIN with designated timestamp"
348
+
-- The 'trades' table has 'trade_ts' as its designated timestamp.
349
+
-- Even though 'trade_ts' is not selected in the subquery,
350
+
-- it is used implicitly for the ASOF JOIN.
351
+
WITH trades_subset AS (
352
+
SELECT symbol, price, amount FROM trades
353
+
)
349
354
SELECT *
350
-
FROM (a timestamp(ts))
351
-
ASOF JOIN (b timestamp (ts));
355
+
FROM trades_subset ASOF JOIN quotes ON (symbol);
352
356
```
353
357
354
-
### SQL Performance Hints for ASOF JOIN
358
+
In more complicated subqueries, the implicit propagation of the designated timestamp may not work QuestDB responses with an error
359
+
`left side of time series join has no timestamp`. In such cases, your subquery should explicitly include the designated
360
+
timestamp column in the `SELECT` clause to ensure it is used for the join.
361
+
362
+
#### The standard override method: Using ORDER BY
363
+
364
+
The easiest and safest way to join on a different timestamp column is to use an `ORDER BY ... ASC` clause in your subquery.
365
+
366
+
When you sort a subquery by a `TIMESTAMP` column, QuestDB makes that column the new designated timestamp for the subquery's results. The subsequent `ASOF JOIN` will automatically detect and use this new timestamp.
367
+
368
+
Example: Joining on `ingestion_time` instead of the default `trade_ts`
369
+
370
+
```questdb-sql title="ASOF JOIN with custom timestamp"
371
+
WITH trades_ordered_by_ingestion AS (
372
+
SELECT symbol, price, ingestion_time
373
+
FROM trades
374
+
WHERE symbol = 'QDB'
375
+
-- This ORDER BY clause tells QuestDB to use 'ingestion_time'
376
+
-- as the new designated timestamp for this subquery.
377
+
ORDER BY ingestion_time ASC
378
+
)
379
+
-- No extra syntax is needed here. The ASOF JOIN automatically uses
380
+
-- the new designated timestamp from the subquery.
381
+
SELECT *
382
+
FROM trades_ordered_by_ingestion
383
+
ASOF JOIN quotes ON (symbol);
384
+
```
385
+
386
+
#### Using the timestamp() syntax
387
+
388
+
The `timestamp()` syntax is an expert-level hint for the query engine. It should only be used to manually assign a
389
+
timestamp to a dataset that does not have one, without forcing a sort.
390
+
391
+
You should only use this when you can guarantee that your data is already sorted by that timestamp column. Using
392
+
`timestamp()` incorrectly on unsorted data will lead to incorrect join results.
393
+
394
+
The primary use case is performance optimization on a table that has no designated timestamp in its schema, but where
395
+
you know the data is physically stored in chronological order. Using the `timestamp()` hint avoids a costly ORDER BY
396
+
operation.
397
+
398
+
```questdb-sql title="ASOF JOIN with timestamp()"
399
+
-- Use this ONLY IF 'my_unsorted_table' has NO designated timestamp,
400
+
-- but you can guarantee its data is already physically ordered by 'event_time'.
401
+
402
+
SELECT *
403
+
FROM (my_unsorted_table timestamp(event_time))
404
+
ASOF JOIN another_table ON (symbol);
405
+
```
406
+
407
+
To summarize:
408
+
409
+
1. By default, the table's designated timestamp is used.
410
+
2. To join on a different column, the standard method is to `ORDER BY` that column in a subquery.
411
+
3. Use the `timestamp()` syntax as an expert-level hint to avoid a sort on a table with no designated timestamp, if and
412
+
only if you are certain the data is already sorted.
413
+
414
+
### SQL performance hints for ASOF JOIN
355
415
356
416
QuestDB supports SQL hints that can optimize non-keyed ASOF join performance when filters are applied to the joined table:
0 commit comments