1
1
# Order book analytics using arrays
2
2
3
- In the following examples, we'll use the table schema below. It is a bare-bones
4
- simplification of a realistic table, where we omit the otherwise essential
5
- columns such as the symbol of the financial instrument. The goal is to
6
- demonstrate the essential aspects of the analytical queries.
7
-
8
- The order book is stored in a 2D array with two rows: the top row are the
9
- prices, and the bottom row are the volumes at each price point.
3
+ In the following examples, we'll use the table schema below. The order book is
4
+ stored in a 2D array with two rows: the top row are the prices, and the bottom
5
+ row are the volumes at each price point.
10
6
11
7
``` questdb-sql
12
- CREATE TABLE order_book (
13
- ts TIMESTAMP,
14
- asks DOUBLE[][],
15
- bids DOUBLE[][]
16
- ) TIMESTAMP(ts) PARTITION BY HOUR;
8
+ CREATE TABLE market_data (
9
+ timestamp TIMESTAMP,
10
+ symbol SYMBOL,
11
+ bids DOUBLE[][],
12
+ asks DOUBLE[][]
13
+ ) TIMESTAMP(timestamp) PARTITION BY HOUR;
17
14
```
18
15
19
16
## Basic order book analytics
20
17
21
18
### What is the bid-ask spread at any moment?
22
19
23
20
``` questdb-sql
24
- SELECT ts, spread(bids[1][1], asks[1][1]) FROM order_book;
21
+ SELECT timestamp, spread(bids[1][1], asks[1][1]) spread
22
+ FROM market_data WHERE symbol='EURUSD';
25
23
```
26
24
27
25
#### Sample data and result
28
26
29
27
``` questdb-sql
30
- INSERT INTO order_book VALUES
31
- ('2025-07-01T12:00:00Z', ARRAY[ [10.1, 10 .2], [0, 0] ], ARRAY[ [9.3, 9 .2], [0, 0] ]),
32
- ('2025-07-01T12:00:01Z', ARRAY[ [10.3, 10.5 ], [0, 0] ], ARRAY[ [9.7, 9.4 ], [0, 0] ]);
28
+ INSERT INTO market_data VALUES
29
+ ('2025-07-01T12:00:00Z', 'EURUSD', ARRAY[ [9.3, 9 .2], [0, 0] ], ARRAY[ [10.1, 10 .2], [0, 0] ]),
30
+ ('2025-07-01T12:00:01Z', 'EURUSD', ARRAY[ [9.7, 9.4 ], [0, 0] ], ARRAY[ [10.3, 10.5 ], [0, 0] ]);
33
31
```
34
32
35
- | ts | spread |
33
+ | timestamp | spread |
36
34
| ------------------- | ------ |
37
35
| 2025-07-01T12:00:00 | 0.8 |
38
36
| 2025-07-01T12:00:01 | 0.6 |
39
37
40
38
### How much volume is available within 1% of the best price?
41
39
42
- ``` questdb-sql
43
- SELECT ts, array_sum(
44
- asks[2, 1:insertion_point(asks[1], 1.01 * asks[1, 1])]
45
- ) volume FROM order_book;
46
- ```
47
-
48
- In a dense query like this, you can use ` DECLARE ` for better legibility:
49
-
50
40
``` questdb-sql
51
41
DECLARE
52
42
@prices := asks[1],
@@ -55,21 +45,19 @@ DECLARE
55
45
@multiplier := 1.01,
56
46
@target_price := @multiplier * @best_price,
57
47
@relevant_volume_levels := @volumes[1:insertion_point(@prices, @target_price)]
58
- SELECT asks,
59
- ts,
60
- array_sum(@relevant_volume_levels) total_volume
61
- FROM order_book;
48
+ SELECT timestamp, array_sum(@relevant_volume_levels) total_volume
49
+ FROM market_data WHERE symbol='EURUSD';
62
50
```
63
51
64
52
#### Sample data and result
65
53
66
54
``` questdb-sql
67
- INSERT INTO order_book VALUES
68
- ('2025-07-01T12:00:00Z', ARRAY[ [10.00, 10.02, 10.04, 10.10, 10.12, 10.14], [10.0, 15, 13, 12, 18, 20] ], NULL ),
69
- ('2025-07-01T12:00:01Z', ARRAY[ [20.00, 20.02, 20.04, 20.10, 20.12, 20.14], [1.0, 5, 3, 2, 8, 10] ], NULL );
55
+ INSERT INTO market_data VALUES
56
+ ('2025-07-01T12:00:00Z', 'EURUSD', NULL, ARRAY[ [10.00, 10.02, 10.04, 10.10, 10.12, 10.14], [10.0, 15, 13, 12, 18, 20] ]),
57
+ ('2025-07-01T12:00:01Z', 'EURUSD', NULL, ARRAY[ [20.00, 20.02, 20.04, 20.10, 20.12, 20.14], [1.0, 5, 3, 2, 8, 10] ]);
70
58
```
71
59
72
- | ts | volume |
60
+ | timestamp | volume |
73
61
| ------------------- | ------ |
74
62
| 2025-07-01T12:00:00 | 50.0 |
75
63
| 2025-07-01T12:00:01 | 29.0 |
@@ -82,44 +70,54 @@ Find the order book level at which the price passes a threshold, and then sum
82
70
the sizes up to that level.
83
71
84
72
``` questdb-sql
85
- SELECT ts, array_sum(
86
- asks[2, 1:insertion_point(asks[1], asks[1,1] + 0.1)]) volume
87
- FROM order_book;
73
+ DECLARE
74
+ @prices := asks[1],
75
+ @volumes := asks[2],
76
+ @best_price := @prices[1],
77
+ @price_delta := 0.1,
78
+ @target_price := @best_price + @price_delta,
79
+ @relevant_volumes := @volumes[1:insertion_point(@prices, @target_price)]
80
+ SELECT timestamp, array_sum(@relevant_volumes) volume
81
+ FROM market_data WHERE symbol='EURUSD';
88
82
```
89
83
90
84
#### Sample data and result
91
85
92
86
``` questdb-sql
93
- INSERT INTO order_book VALUES
94
- ('2025-07-01T12:00:00Z', ARRAY[ [10.0, 10.02, 10.04, 10.10, 10.12, 10.14], [10.0, 15, 13, 12, 18, 20] ], NULL ),
95
- ('2025-07-01T12:00:01Z', ARRAY[ [10.0, 10.10, 10.12, 10.14, 10.16, 10.18], [1.0, 5, 3, 2, 8, 10] ], NULL );
87
+ INSERT INTO market_data VALUES
88
+ ('2025-07-01T12:00:00Z', 'EURUSD', NULL, ARRAY[ [10.0, 10.02, 10.04, 10.10, 10.12, 10.14], [10.0, 15, 13, 12, 18, 20] ]),
89
+ ('2025-07-01T12:00:01Z', 'EURUSD', NULL, ARRAY[ [10.0, 10.10, 10.12, 10.14, 10.16, 10.18], [1.0, 5, 3, 2, 8, 10] ]);
96
90
```
97
91
98
- | ts | volume |
92
+ | timestamp | volume |
99
93
| ------------------- | ------ |
100
94
| 2025-07-01T12:00:00 | 50.0 |
101
95
| 2025-07-01T12:00:01 | 6.0 |
102
96
103
97
### What price level will a buy order for the given volume reach?
104
98
105
99
``` questdb-sql
100
+ DECLARE
101
+ @prices := asks[1],
102
+ @volumes := asks[2],
103
+ @target_volume := 30.0
106
104
SELECT
107
- ts ,
108
- array_cum_sum(asks[2] ) cum_volumes,
109
- insertion_point(cum_volumes, 30.0 , true) target_level,
110
- asks[1, target_level] price
111
- FROM order_book ;
105
+ timestamp ,
106
+ array_cum_sum(@volumes ) cum_volumes,
107
+ insertion_point(cum_volumes, @target_volume , true) target_level,
108
+ @prices[ target_level] price
109
+ FROM market_data WHERE symbol='EURUSD' ;
112
110
```
113
111
114
112
#### Sample data and result
115
113
116
114
``` questdb-sql
117
- INSERT INTO order_book VALUES
118
- ('2025-07-01T12:00:00Z', ARRAY[ [10.0, 10.02, 10.04, 10.10, 10.12, 10.14], [10.0, 15, 13, 12, 18, 20] ], NULL ),
119
- ('2025-07-01T12:00:01Z', ARRAY[ [10.0, 10.02, 10.04, 10.10, 10.12, 10.14], [10.0, 5, 3, 12, 18, 20] ], NULL );
115
+ INSERT INTO market_data VALUES
116
+ ('2025-07-01T12:00:00Z', 'EURUSD', NULL, ARRAY[ [10.0, 10.02, 10.04, 10.10, 10.12, 10.14], [10.0, 15, 13, 12, 18, 20] ]),
117
+ ('2025-07-01T12:00:01Z', 'EURUSD', NULL, ARRAY[ [10.0, 10.02, 10.04, 10.10, 10.12, 10.14], [10.0, 5, 3, 12, 18, 20] ]);
120
118
```
121
119
122
- | ts | cum_volumes | target_level | price |
120
+ | timestamp | cum_volumes | target_level | price |
123
121
| ------------------- | ----------------------------- | ------------ | ----- |
124
122
| 2025-07-01T12:00:00 | [ 10.0, 25.0, 38.0, 50.0, ...] | 3 | 10.04 |
125
123
| 2025-07-01T12:00:01 | [ 10.0, 15.0, 18.0, 30.0, ...] | 4 | 10.10 |
@@ -136,70 +134,77 @@ sellers at the top of the book).
136
134
137
135
``` questdb-sql
138
136
SELECT
139
- ts , bids[2, 1] / asks[2, 1] imbalance
140
- FROM order_book ;
137
+ timestamp , bids[2, 1] / asks[2, 1] imbalance
138
+ FROM market_data WHERE symbol='EURUSD' ;
141
139
```
142
140
143
141
#### Sample data and result
144
142
145
143
``` questdb-sql
146
- INSERT INTO order_book VALUES
147
- ('2025-07-01T12:00:00Z', ARRAY[ [0.0,0], [10 .0, 15 ] ], ARRAY[ [0.0,0], [20 .0, 25 ] ]),
148
- ('2025-07-01T12:00:01Z', ARRAY[ [0.0,0], [15 .0, 2 ] ], ARRAY[ [0.0,0], [14 .0, 45 ] ]);
144
+ INSERT INTO market_data VALUES
145
+ ('2025-07-01T12:00:00Z', 'EURUSD', ARRAY[ [0.0,0], [20 .0, 25 ] ], ARRAY[ [0.0,0], [10 .0, 15 ] ]),
146
+ ('2025-07-01T12:00:01Z', 'EURUSD', ARRAY[ [0.0,0], [14 .0, 45 ] ], ARRAY[ [0.0,0], [15 .0, 2 ] ]);
149
147
```
150
148
151
- | ts | imbalance |
149
+ | timestamp | imbalance |
152
150
| ------------------- | --------- |
153
151
| 2025-07-01T12:00:00 | 2.0 |
154
152
| 2025-07-01T12:00:01 | 0.93 |
155
153
156
154
### Cumulative imbalance (Top 3 Levels)
157
155
158
156
``` questdb-sql
157
+ DECLARE
158
+ @bid_volumes := bids[2],
159
+ @ask_volumes := asks[2]
159
160
SELECT
160
- array_sum(asks[2, 1:4]) ask_vol,
161
- array_sum(bids[2, 1:4]) bid_vol,
161
+ timestamp,
162
+ array_sum(@bid_volumes[1:4]) bid_vol,
163
+ array_sum(@ask_volumes[1:4]) ask_vol,
162
164
bid_vol / ask_vol ratio
163
- FROM order_book ;
165
+ FROM market_data WHERE symbol='EURUSD' ;
164
166
```
165
167
166
168
#### Sample data and result
167
169
168
170
``` questdb-sql
169
- INSERT INTO order_book VALUES
170
- ('2025-07-01T12:00:00Z', ARRAY[ [0.0,0,0,0], [10 .0, 15, 13, 12 ] ], ARRAY[ [0.0,0,0,0], [20 .0, 25, 23, 22 ] ]),
171
- ('2025-07-01T12:00:01Z', ARRAY[ [0.0,0,0,0], [15 .0, 2, 20, 23 ] ], ARRAY[ [0.0,0,0,0], [14 .0, 45, 22, 5 ] ]);
171
+ INSERT INTO market_data VALUES
172
+ ('2025-07-01T12:00:00Z', 'EURUSD', ARRAY[ [0.0,0,0,0], [20 .0, 25, 23, 22 ] ], ARRAY[ [0.0,0,0,0], [10 .0, 15, 13, 12 ] ]),
173
+ ('2025-07-01T12:00:01Z', 'EURUSD', ARRAY[ [0.0,0,0,0], [14 .0, 45, 22, 5 ] ], ARRAY[ [0.0,0,0,0], [15 .0, 2, 20, 23 ] ]);
172
174
```
173
175
174
- | ts | ask_vol | bid_vol | ratio |
176
+ | timestamp | bid_vol | ask_vol | ratio |
175
177
| ------------------- | ------- | ------- | ----- |
176
- | 2025-07-01T12:00:00 | 38 .0 | 68 .0 | 1.79 |
177
- | 2025-07-01T12:00:01 | 37 .0 | 81 .0 | 2.19 |
178
+ | 2025-07-01T12:00:00 | 68 .0 | 38 .0 | 1.79 |
179
+ | 2025-07-01T12:00:01 | 81 .0 | 37 .0 | 2.19 |
178
180
179
181
### Detect quote stuffing/fading (Volume dropoff)
180
182
181
183
Detect where the order book thins out rapidly after the first two levels. This
182
184
signals lack of depth (fading) or fake orders (stuffing).
183
185
184
186
``` questdb-sql
187
+ DECLARE
188
+ @volumes := asks[2],
189
+ @dropoff_ratio := 3.0
185
190
SELECT * FROM (
186
191
SELECT
187
- ts ,
188
- array_avg(asks[2, 1:3]) top,
189
- array_avg(asks[2, 3:6]) deep
190
- FROM order_book )
191
- WHERE top > 3 * deep;
192
+ timestamp ,
193
+ array_avg(@volumes[ 1:3]) top,
194
+ array_avg(@volumes[ 3:6]) deep
195
+ FROM market_data WHERE symbol='EURUSD' )
196
+ WHERE top > @dropoff_ratio * deep;
192
197
```
193
198
194
199
#### Sample data and result
195
200
196
201
``` questdb-sql
197
- INSERT INTO order_book VALUES
198
- ('2025-07-01T12:00:00Z', ARRAY[ [0.0,0,0,0,0,0], [20.0, 15, 13, 12, 18, 20] ], NULL ),
199
- ('2025-07-01T12:00:01Z', ARRAY[ [0.0,0,0,0,0,0], [20.0, 25, 3, 7, 5, 2] ], NULL );
202
+ INSERT INTO market_data VALUES
203
+ ('2025-07-01T12:00:00Z', 'EURUSD', NULL, ARRAY[ [0.0,0,0,0,0,0], [20.0, 15, 13, 12, 18, 20] ]),
204
+ ('2025-07-01T12:00:01Z', 'EURUSD', NULL, ARRAY[ [0.0,0,0,0,0,0], [20.0, 25, 3, 7, 5, 2] ]);
200
205
```
201
206
202
- | ts | top | deep |
207
+ | timestamp | top | deep |
203
208
| ------------------- | ---- | ---- |
204
209
| 2025-07-01T12:00:01 | 22.5 | 5.0 |
205
210
@@ -209,55 +214,67 @@ Look for cases where the top bid/ask volume dropped compared to the prior
209
214
snapshot — potential order withdrawal ahead of adverse movement.
210
215
211
216
``` questdb-sql
217
+ DECLARE
218
+ @top_bid_volume := bids[2, 1],
219
+ @top_ask_volume := asks[2, 1],
220
+ @drop_ratio := 1.5
212
221
SELECT * FROM (
213
222
SELECT
214
- ts ts ,
215
- lag(asks[2, 1] ) OVER () prev_ask_vol ,
216
- asks[2, 1] curr_ask_vol ,
217
- lag(bids[2, 1] ) OVER () prev_bid_vol ,
218
- bids[2, 1] curr_bid_vol
219
- FROM order_book )
220
- WHERE prev_bid_vol > curr_bid_vol * 1.5 OR prev_ask_vol > curr_ask_vol * 1.5 ;
223
+ timestamp ,
224
+ lag(@top_bid_volume ) OVER () prev_bid_vol ,
225
+ @top_bid_volume curr_bid_vol ,
226
+ lag(@top_ask_volume ) OVER () prev_ask_vol ,
227
+ @top_ask_volume curr_ask_vol
228
+ FROM market_data WHERE symbol='EURUSD' )
229
+ WHERE prev_bid_vol > curr_bid_vol * @drop_ratio OR prev_ask_vol > curr_ask_vol * @drop_ratio ;
221
230
```
222
231
223
232
#### Sample data and result
224
233
225
234
``` questdb-sql
226
- INSERT INTO order_book VALUES
227
- ('2025-07-01T12:00:00Z', ARRAY[ [0.0], [10.0] ], ARRAY[ [0.0], [10.0] ]),
228
- ('2025-07-01T12:00:01Z', ARRAY[ [0.0], [ 9.0] ], ARRAY[ [0.0], [ 9.0] ]),
229
- ('2025-07-01T12:00:02Z', ARRAY[ [0.0], [ 4 .0] ], ARRAY[ [0.0], [ 8 .0] ]),
230
- ('2025-07-01T12:00:03Z', ARRAY[ [0.0], [ 4.0] ], ARRAY[ [0.0], [ 4.0] ]);
235
+ INSERT INTO market_data VALUES
236
+ ('2025-07-01T12:00:00Z', 'EURUSD', ARRAY[ [0.0], [10.0] ], ARRAY[ [0.0], [10.0] ]),
237
+ ('2025-07-01T12:00:01Z', 'EURUSD', ARRAY[ [0.0], [ 9.0] ], ARRAY[ [0.0], [ 9.0] ]),
238
+ ('2025-07-01T12:00:02Z', 'EURUSD', ARRAY[ [0.0], [ 8 .0] ], ARRAY[ [0.0], [ 4 .0] ]),
239
+ ('2025-07-01T12:00:03Z', 'EURUSD', ARRAY[ [0.0], [ 4.0] ], ARRAY[ [0.0], [ 4.0] ]);
231
240
```
232
241
233
- | ts | prev_ask_vol | curr_ask_vol | prev_bid_vol | curr_bid_vol |
242
+ | timestamp | prev_bid_vol | curr_bid_vol | prev_ask_vol | curr_ask_vol |
234
243
| ------------------- | ------------ | ------------ | ------------ | ------------ |
235
- | 2025-07-01T12:00:02 | 9.0 | 4 .0 | 9.0 | 8 .0 |
236
- | 2025-07-01T12:00:03 | 4 .0 | 4.0 | 8 .0 | 4.0 |
244
+ | 2025-07-01T12:00:02 | 9.0 | 8 .0 | 9.0 | 4 .0 |
245
+ | 2025-07-01T12:00:03 | 8 .0 | 4.0 | 4 .0 | 4.0 |
237
246
238
247
### Price-weighted volume imbalance
239
248
240
249
For each level, calculate the deviation from the mid price (midpoint between
241
250
best bid and best ask), and weight it by the volume at that level. This shows us
242
251
whether there's stronger buying or selling interest.
243
252
244
- ``` questdb-sql
253
+ ``` questdb-sql demo
254
+ DECLARE
255
+ @bid_prices := bids[1],
256
+ @bid_volumes := bids[2],
257
+ @ask_prices := asks[1],
258
+ @ask_volumes := asks[2],
259
+ @best_bid_price := bids[1, 1],
260
+ @best_ask_price := asks[1, 1]
245
261
SELECT
246
- round((asks[1][1] + bids[1][1]) / 2, 2) mid_price,
247
- (asks[1] - mid_price) * asks[2] weighted_ask_pressure,
248
- (mid_price - bids[1]) * bids[2] weighted_bid_pressure
249
- FROM order_book;
262
+ timestamp,
263
+ round((@best_bid_price + @best_ask_price) / 2, 2) mid_price,
264
+ (mid_price - @bid_prices) * @bid_volumes weighted_bid_pressure,
265
+ (@ask_prices - mid_price) * @ask_volumes weighted_ask_pressure
266
+ FROM market_data WHERE symbol='EURUSD';
250
267
```
251
268
252
269
#### Sample data and result
253
270
254
271
``` questdb-sql
255
- INSERT INTO order_book VALUES
256
- ('2025-07-01T12:00:00Z', ARRAY[ [6 .0, 6 .1], [15 .0, 25 ] ], ARRAY[ [5 .0, 5 .1], [10 .0, 20 ] ]),
257
- ('2025-07-01T12:00:01Z', ARRAY[ [6.2, 6.4 ], [20.0, 9 ] ], ARRAY[ [5.1, 5.2 ], [20.0, 25 ] ]);
272
+ INSERT INTO market_data VALUES
273
+ ('2025-07-01T12:00:00Z', 'EURUSD', ARRAY[ [5 .0, 5 .1], [10 .0, 20 ] ], ARRAY[ [6 .0, 6 .1], [15 .0, 25 ] ]),
274
+ ('2025-07-01T12:00:01Z', 'EURUSD', ARRAY[ [5.1, 5.2 ], [20.0, 25 ] ], ARRAY[ [6.2, 6.4 ], [20.0, 9 ] ]);
258
275
```
259
276
260
- | ts | mid_price | weighted_ask_pressure | weighted_bid_pressure |
277
+ | timestamp | mid_price | weighted_bid_pressure | weighted_ask_pressure |
261
278
| ------------------- | --------- | --------------------- | --------------------- |
262
- | 2025-07-01T12:00:00 | 5.5 | [ 7.5, 15 .0] | [ 5.0, 8 .0] |
263
- | 2025-07-01T12:00:01 | 5.65 | [ 11.0, 6.75 ] | [ 11.0, 11.25 ] |
279
+ | 2025-07-01T12:00:00 | 5.5 | [ 5.0, 8 .0] | [ 7.5, 15 .0] |
280
+ | 2025-07-01T12:00:01 | 5.65 | [ 11.0, 11.25 ] | [ 11.0, 6.75 ] |
0 commit comments