-
Notifications
You must be signed in to change notification settings - Fork 53
/
queries.nim
590 lines (468 loc) · 16.7 KB
/
queries.nim
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
{.push raises: [].}
import std/[options, sequtils], stew/byteutils, sqlite3_abi, results
import chronicles
import
../../../common/databases/db_sqlite,
../../../common/databases/common,
../../../waku_core
const DbTable = "Message"
type SqlQueryStr = string
### SQLite column helper methods
proc queryRowWakuMessageCallback(
s: ptr sqlite3_stmt,
contentTopicCol, payloadCol, versionCol, timestampCol, metaCol: cint,
): WakuMessage =
let
topic = cast[ptr UncheckedArray[byte]](sqlite3_column_blob(s, contentTopicCol))
topicLength = sqlite3_column_bytes(s, contentTopicCol)
contentTopic = string.fromBytes(@(toOpenArray(topic, 0, topicLength - 1)))
p = cast[ptr UncheckedArray[byte]](sqlite3_column_blob(s, payloadCol))
m = cast[ptr UncheckedArray[byte]](sqlite3_column_blob(s, metaCol))
payloadLength = sqlite3_column_bytes(s, payloadCol)
metaLength = sqlite3_column_bytes(s, metaCol)
payload = @(toOpenArray(p, 0, payloadLength - 1))
version = sqlite3_column_int64(s, versionCol)
timestamp = sqlite3_column_int64(s, timestampCol)
meta = @(toOpenArray(m, 0, metaLength - 1))
return WakuMessage(
contentTopic: ContentTopic(contentTopic),
payload: payload,
version: uint32(version),
timestamp: Timestamp(timestamp),
meta: meta,
)
proc queryRowTimestampCallback(s: ptr sqlite3_stmt, timestampCol: cint): Timestamp =
let timestamp = sqlite3_column_int64(s, timestampCol)
return Timestamp(timestamp)
proc queryRowPubsubTopicCallback(
s: ptr sqlite3_stmt, pubsubTopicCol: cint
): PubsubTopic =
let
pubsubTopicPointer =
cast[ptr UncheckedArray[byte]](sqlite3_column_blob(s, pubsubTopicCol))
pubsubTopicLength = sqlite3_column_bytes(s, pubsubTopicCol)
pubsubTopic =
string.fromBytes(@(toOpenArray(pubsubTopicPointer, 0, pubsubTopicLength - 1)))
return pubsubTopic
proc queryRowWakuMessageHashCallback(
s: ptr sqlite3_stmt, hashCol: cint
): WakuMessageHash =
let
hashPointer = cast[ptr UncheckedArray[byte]](sqlite3_column_blob(s, hashCol))
hashLength = sqlite3_column_bytes(s, hashCol)
hash = fromBytes(toOpenArray(hashPointer, 0, hashLength - 1))
return hash
### SQLite queries
## Create table
proc createTableQuery(table: string): SqlQueryStr =
"CREATE TABLE IF NOT EXISTS " & table & " (" &
" messageHash BLOB NOT NULL PRIMARY KEY," & " pubsubTopic BLOB NOT NULL," &
" contentTopic BLOB NOT NULL," & " payload BLOB," & " version INTEGER NOT NULL," &
" timestamp INTEGER NOT NULL," & " meta BLOB" & ") WITHOUT ROWID;"
proc createTable*(db: SqliteDatabase): DatabaseResult[void] =
let query = createTableQuery(DbTable)
discard
?db.query(
query,
proc(s: ptr sqlite3_stmt) =
discard,
)
return ok()
## Create indices
proc createOldestMessageTimestampIndexQuery(table: string): SqlQueryStr =
"CREATE INDEX IF NOT EXISTS i_ts ON " & table & " (timestamp);"
proc createOldestMessageTimestampIndex*(db: SqliteDatabase): DatabaseResult[void] =
let query = createOldestMessageTimestampIndexQuery(DbTable)
discard
?db.query(
query,
proc(s: ptr sqlite3_stmt) =
discard,
)
return ok()
## Insert message
type InsertMessageParams* =
(seq[byte], seq[byte], seq[byte], seq[byte], int64, Timestamp, seq[byte])
proc insertMessageQuery(table: string): SqlQueryStr =
return
"INSERT INTO " & table &
"(messageHash, pubsubTopic, contentTopic, payload, version, timestamp, meta)" &
" VALUES (?, ?, ?, ?, ?, ?, ?);"
proc prepareInsertMessageStmt*(
db: SqliteDatabase
): SqliteStmt[InsertMessageParams, void] =
let query = insertMessageQuery(DbTable)
return
db.prepareStmt(query, InsertMessageParams, void).expect("this is a valid statement")
## Count table messages
proc countMessagesQuery(table: string): SqlQueryStr =
return "SELECT COUNT(*) FROM " & table
proc getMessageCount*(db: SqliteDatabase): DatabaseResult[int64] =
var count: int64
proc queryRowCallback(s: ptr sqlite3_stmt) =
count = sqlite3_column_int64(s, 0)
let query = countMessagesQuery(DbTable)
let res = db.query(query, queryRowCallback)
if res.isErr():
return err("failed to count number of messages in the database")
return ok(count)
## Get oldest message receiver timestamp
proc selectOldestMessageTimestampQuery(table: string): SqlQueryStr =
return "SELECT MIN(timestamp) FROM " & table
proc selectOldestTimestamp*(db: SqliteDatabase): DatabaseResult[Timestamp] {.inline.} =
var timestamp: Timestamp
proc queryRowCallback(s: ptr sqlite3_stmt) =
timestamp = queryRowTimestampCallback(s, 0)
let query = selectOldestMessageTimestampQuery(DbTable)
let res = db.query(query, queryRowCallback)
if res.isErr():
return err("failed to get the oldest receiver timestamp from the database")
return ok(timestamp)
## Get newest message receiver timestamp
proc selectNewestMessageTimestampQuery(table: string): SqlQueryStr =
return "SELECT MAX(timestamp) FROM " & table
proc selectNewestTimestamp*(db: SqliteDatabase): DatabaseResult[Timestamp] {.inline.} =
var timestamp: Timestamp
proc queryRowCallback(s: ptr sqlite3_stmt) =
timestamp = queryRowTimestampCallback(s, 0)
let query = selectNewestMessageTimestampQuery(DbTable)
let res = db.query(query, queryRowCallback)
if res.isErr():
return err("failed to get the newest receiver timestamp from the database")
return ok(timestamp)
## Delete messages older than timestamp
proc deleteMessagesOlderThanTimestampQuery(table: string, ts: Timestamp): SqlQueryStr =
return "DELETE FROM " & table & " WHERE timestamp < " & $ts
proc deleteMessagesOlderThanTimestamp*(
db: SqliteDatabase, ts: int64
): DatabaseResult[void] =
let query = deleteMessagesOlderThanTimestampQuery(DbTable, ts)
discard
?db.query(
query,
proc(s: ptr sqlite3_stmt) =
discard,
)
return ok()
## Delete oldest messages not within limit
proc deleteOldestMessagesNotWithinLimitQuery(table: string, limit: int): SqlQueryStr =
return
"DELETE FROM " & table & " WHERE (timestamp, messageHash) NOT IN (" &
" SELECT timestamp, messageHash FROM " & table &
" ORDER BY timestamp DESC, messageHash DESC" & " LIMIT " & $limit & ");"
proc deleteOldestMessagesNotWithinLimit*(
db: SqliteDatabase, limit: int
): DatabaseResult[void] =
# NOTE: The word `limit` here refers the store capacity/maximum number-of-messages allowed limit
let query = deleteOldestMessagesNotWithinLimitQuery(DbTable, limit = limit)
discard
?db.query(
query,
proc(s: ptr sqlite3_stmt) =
discard,
)
return ok()
## Select all messages
proc selectAllMessagesQuery(table: string): SqlQueryStr =
return
"SELECT messageHash, pubsubTopic, contentTopic, payload, version, timestamp, meta" &
" FROM " & table & " ORDER BY timestamp ASC"
proc selectAllMessages*(
db: SqliteDatabase
): DatabaseResult[seq[(WakuMessageHash, PubsubTopic, WakuMessage)]] =
## Retrieve all messages from the store.
var rows: seq[(WakuMessageHash, PubsubTopic, WakuMessage)]
proc queryRowCallback(s: ptr sqlite3_stmt) =
let
hash = queryRowWakuMessageHashCallback(s, hashCol = 0)
pubsubTopic = queryRowPubsubTopicCallback(s, pubsubTopicCol = 1)
wakuMessage = queryRowWakuMessageCallback(
s,
contentTopicCol = 2,
payloadCol = 3,
versionCol = 4,
timestampCol = 5,
metaCol = 6,
)
rows.add((hash, pubsubTopic, wakuMessage))
let query = selectAllMessagesQuery(DbTable)
db.query(query, queryRowCallback).isOkOr:
return err("select all messages failed: " & $error)
return ok(rows)
## Select all messages without data
proc selectAllMessageHashesQuery(table: string): SqlQueryStr =
return "SELECT messageHash" & " FROM " & table & " ORDER BY timestamp ASC"
proc selectAllMessageHashes*(db: SqliteDatabase): DatabaseResult[seq[WakuMessageHash]] =
## Retrieve all messages from the store.
var rows: seq[WakuMessageHash]
proc queryRowCallback(s: ptr sqlite3_stmt) =
let hash = queryRowWakuMessageHashCallback(s, hashCol = 0)
rows.add(hash)
let query = selectAllMessageHashesQuery(DbTable)
db.query(query, queryRowCallback).isOkOr:
return err("select all message hashes failed: " & $error)
return ok(rows)
## Select messages by history query with limit
proc combineClauses(clauses: varargs[Option[string]]): Option[string] =
let whereSeq = @clauses.filterIt(it.isSome()).mapIt(it.get())
if whereSeq.len <= 0:
return none(string)
var where: string = whereSeq[0]
for clause in whereSeq[1 ..^ 1]:
where &= " AND " & clause
return some(where)
proc prepareStmt(
db: SqliteDatabase, stmt: string
): DatabaseResult[SqliteStmt[void, void]] =
var s: RawStmtPtr
checkErr sqlite3_prepare_v2(db.env, stmt, stmt.len.cint, addr s, nil)
return ok(SqliteStmt[void, void](s))
proc execSelectMessageByHash(
s: SqliteStmt, hash: WakuMessageHash, onRowCallback: DataProc
): DatabaseResult[void] =
let s = RawStmtPtr(s)
checkErr bindParam(s, 1, toSeq(hash))
try:
while true:
let v = sqlite3_step(s)
case v
of SQLITE_ROW:
onRowCallback(s)
of SQLITE_DONE:
return ok()
else:
return err($sqlite3_errstr(v))
except Exception, CatchableError:
error "exception in execSelectMessageByHash", error = getCurrentExceptionMsg()
# release implicit transaction
discard sqlite3_reset(s) # same return information as step
discard sqlite3_clear_bindings(s) # no errors possible
proc selectTimestampByHashQuery(table: string): SqlQueryStr =
return "SELECT timestamp FROM " & table & " WHERE messageHash = (?)"
proc getCursorTimestamp(
db: SqliteDatabase, hash: WakuMessageHash
): DatabaseResult[Option[Timestamp]] =
var timestamp = none(Timestamp)
proc queryRowCallback(s: ptr sqlite3_stmt) =
timestamp = some(queryRowTimestampCallback(s, 0))
let query = selectTimestampByHashQuery(DbTable)
let dbStmt = ?db.prepareStmt(query)
?dbStmt.execSelectMessageByHash(hash, queryRowCallback)
dbStmt.dispose()
return ok(timestamp)
proc whereClause(
cursor: bool,
pubsubTopic: Option[PubsubTopic],
contentTopic: seq[ContentTopic],
startTime: Option[Timestamp],
endTime: Option[Timestamp],
hashes: seq[WakuMessageHash],
ascending: bool,
): Option[string] =
let cursorClause =
if cursor:
let comp = if ascending: ">" else: "<"
some("(timestamp, messageHash) " & comp & " (?, ?)")
else:
none(string)
let pubsubTopicClause =
if pubsubTopic.isNone():
none(string)
else:
some("pubsubTopic = (?)")
let contentTopicClause =
if contentTopic.len <= 0:
none(string)
else:
var where = "contentTopic IN ("
where &= "?"
for _ in 1 ..< contentTopic.len:
where &= ", ?"
where &= ")"
some(where)
let startTimeClause =
if startTime.isNone():
none(string)
else:
some("timestamp >= (?)")
let endTimeClause =
if endTime.isNone():
none(string)
else:
some("timestamp <= (?)")
let hashesClause =
if hashes.len <= 0:
none(string)
else:
var where = "messageHash IN ("
where &= "?"
for _ in 1 ..< hashes.len:
where &= ", ?"
where &= ")"
some(where)
return combineClauses(
cursorClause, pubsubTopicClause, contentTopicClause, startTimeClause, endTimeClause,
hashesClause,
)
proc execSelectMessagesWithLimitStmt(
s: SqliteStmt,
cursor: Option[(Timestamp, WakuMessageHash)],
pubsubTopic: Option[PubsubTopic],
contentTopic: seq[ContentTopic],
startTime: Option[Timestamp],
endTime: Option[Timestamp],
hashes: seq[WakuMessageHash],
onRowCallback: DataProc,
): DatabaseResult[void] =
let s = RawStmtPtr(s)
# Bind params
var paramIndex = 1
if cursor.isSome():
let (time, hash) = cursor.get()
checkErr bindParam(s, paramIndex, time)
paramIndex += 1
checkErr bindParam(s, paramIndex, toSeq(hash))
paramIndex += 1
if pubsubTopic.isSome():
let pubsubTopic = toBytes(pubsubTopic.get())
checkErr bindParam(s, paramIndex, pubsubTopic)
paramIndex += 1
for topic in contentTopic:
checkErr bindParam(s, paramIndex, topic.toBytes())
paramIndex += 1
for hash in hashes:
checkErr bindParam(s, paramIndex, toSeq(hash))
paramIndex += 1
if startTime.isSome():
let time = startTime.get()
checkErr bindParam(s, paramIndex, time)
paramIndex += 1
if endTime.isSome():
let time = endTime.get()
checkErr bindParam(s, paramIndex, time)
paramIndex += 1
try:
while true:
let v = sqlite3_step(s)
case v
of SQLITE_ROW:
onRowCallback(s)
of SQLITE_DONE:
return ok()
else:
return err($sqlite3_errstr(v))
except Exception, CatchableError:
error "exception in execSelectMessagesWithLimitStmt",
error = getCurrentExceptionMsg()
# release implicit transaction
discard sqlite3_reset(s) # same return information as step
discard sqlite3_clear_bindings(s) # no errors possible
proc selectMessagesWithLimitQuery(
table: string, where: Option[string], limit: uint, ascending = true
): SqlQueryStr =
let order = if ascending: "ASC" else: "DESC"
var query: string
query =
"SELECT messageHash, pubsubTopic, contentTopic, payload, version, timestamp, meta"
query &= " FROM " & table
if where.isSome():
query &= " WHERE " & where.get()
query &= " ORDER BY timestamp " & order & ", messageHash " & order
query &= " LIMIT " & $limit & ";"
return query
proc selectMessageHashesWithLimitQuery(
table: string, where: Option[string], limit: uint, ascending = true
): SqlQueryStr =
let order = if ascending: "ASC" else: "DESC"
var query = "SELECT messageHash FROM " & table
if where.isSome():
query &= " WHERE " & where.get()
query &= " ORDER BY timestamp " & order & ", messageHash " & order
query &= " LIMIT " & $limit & ";"
return query
proc selectMessagesByStoreQueryWithLimit*(
db: SqliteDatabase,
contentTopic: seq[ContentTopic],
pubsubTopic: Option[PubsubTopic],
cursor: Option[WakuMessageHash],
startTime: Option[Timestamp],
endTime: Option[Timestamp],
hashes: seq[WakuMessageHash],
limit: uint,
ascending: bool,
): DatabaseResult[seq[(WakuMessageHash, PubsubTopic, WakuMessage)]] =
var timeCursor = none((Timestamp, WakuMessageHash))
if cursor.isSome():
let hash: WakuMessageHash = cursor.get()
let timeOpt = ?getCursorTimestamp(db, hash)
if timeOpt.isNone():
return err("cursor not found")
timeCursor = some((timeOpt.get(), hash))
var rows: seq[(WakuMessageHash, PubsubTopic, WakuMessage)] = @[]
proc queryRowCallback(s: ptr sqlite3_stmt) =
let
hash = queryRowWakuMessageHashCallback(s, hashCol = 0)
pubsubTopic = queryRowPubsubTopicCallback(s, pubsubTopicCol = 1)
message = queryRowWakuMessageCallback(
s,
contentTopicCol = 2,
payloadCol = 3,
versionCol = 4,
timestampCol = 5,
metaCol = 6,
)
rows.add((hash, pubsubTopic, message))
let where = whereClause(
timeCursor.isSome(),
pubsubTopic,
contentTopic,
startTime,
endTime,
hashes,
ascending,
)
let query = selectMessagesWithLimitQuery(DbTable, where, limit, ascending)
let dbStmt = ?db.prepareStmt(query)
?dbStmt.execSelectMessagesWithLimitStmt(
timeCursor, pubsubTopic, contentTopic, startTime, endTime, hashes, queryRowCallback
)
dbStmt.dispose()
return ok(rows)
proc selectMessageHashesByStoreQueryWithLimit*(
db: SqliteDatabase,
contentTopic: seq[ContentTopic],
pubsubTopic: Option[PubsubTopic],
cursor: Option[WakuMessageHash],
startTime: Option[Timestamp],
endTime: Option[Timestamp],
hashes: seq[WakuMessageHash],
limit: uint,
ascending: bool,
): DatabaseResult[seq[(WakuMessageHash, PubsubTopic, WakuMessage)]] =
var timeCursor = none((Timestamp, WakuMessageHash))
if cursor.isSome():
let hash: WakuMessageHash = cursor.get()
let timeOpt = ?getCursorTimestamp(db, hash)
if timeOpt.isNone():
return err("cursor not found")
timeCursor = some((timeOpt.get(), hash))
var rows: seq[(WakuMessageHash, PubsubTopic, WakuMessage)] = @[]
proc queryRowCallback(s: ptr sqlite3_stmt) =
let hash = queryRowWakuMessageHashCallback(s, hashCol = 0)
rows.add((hash, "", WakuMessage()))
let where = whereClause(
timeCursor.isSome(),
pubsubTopic,
contentTopic,
startTime,
endTime,
hashes,
ascending,
)
let query = selectMessageHashesWithLimitQuery(DbTable, where, limit, ascending)
let dbStmt = ?db.prepareStmt(query)
?dbStmt.execSelectMessagesWithLimitStmt(
timeCursor, pubsubTopic, contentTopic, startTime, endTime, hashes, queryRowCallback
)
dbStmt.dispose()
return ok(rows)