-
Notifications
You must be signed in to change notification settings - Fork 27
/
db-worker.ts
520 lines (502 loc) · 18.8 KB
/
db-worker.ts
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
/* eslint-disable jsdoc/require-param */
/* eslint-disable jsdoc/require-returns */
/* eslint-disable @typescript-eslint/no-explicit-any */
/* eslint-disable no-inner-declarations */
import { parentPort } from "worker_threads"
import { Database } from "bun:sqlite"
import { Queue } from "@datastructures-js/queue"
const defaultDbOptions = { strict: true }
let db = new Database("server.db", defaultDbOptions)
let dbClosed = false
export type LiveChatMessage = {
messageId: number,
sendDate: number,
channel: string,
message: string,
senderIntId: number,
repliesTo: number|null,
deletionId: number|null
}
export type LiveChatReaction = {
messageId: number,
reaction: string,
senderIntId: number
}
export type PlaceChatMessage = {
messageId: number,
sendDate: number,
message: string,
senderIntId: number,
x: number,
y: number
}
export type Ban = {
banId: number,
userIntId: number,
startDate: number,
finishDate: number,
moderatorIntId: number,
reason: string,
userAppeal: string,
appealRejected: number
}
export type Mute = {
muteId: number,
startDate: number,
finishDate: number,
userIntId: number,
moderatorIntId: number,
reason: string,
userAppeal: string,
appealRejected: number
}
export type User = {
intId: number,
chatName: string,
token: string,
lastJoined: number,
pixelsPlaced: number,
playTimeSeconds: number
}
export type KnownIp = {
userIntId: number,
ip: string,
userAgent: string,
lastUsed: number
}
export type UserVip = {
userIntId: number,
keyHash: string,
lastUsed: number
}
export type DeletionMessageInfo = {
messageId: number,
reason: string,
moderatorIntId: number
}
export type DeletionInsert = {
moderatorIntId: number,
reason: string,
deletionDate: number
}
export type LiveChatDeletion = {
deletionId: number,
moderatorIntId: number,
reason: string,
deletionDate: number
}
export type LiveChatReport = {
reportId: number,
reporterId: number,
messageId: number,
reason: string,
reportDate: number
}
export type Linkage = {
userIntId: number,
accountId: number,
linkDate: number
}
type LiveChatUpdateDeletion = { deletionId: number, messageId: number }
export type AuthenticateUser = { token: string, ip: string, userAgent: string }
export type DbInternals = {
setUserChatName: (data: { newName: string, intId: number }) => void,
getUserChatName: (intId: number) => string|null,
authenticateUser: (data: AuthenticateUser) => number|null,
getLiveChatHistory: (data: { messageId: number, count: number, before: boolean, channel: string, includeDeleted?: boolean }) => LiveChatMessage[],
updatePixelPlace: (intId: number) => void,
getMaxLiveChatId: () => number,
getMaxPlaceChatId: () => number,
commitShutdown: () => boolean,
insertLiveChat: (data: LiveChatMessage) => void,
addLiveChatReaction: (data: { messageId: number, reaction: string, senderIntId: number }) => void
deleteLiveChat: (data: DeletionMessageInfo) => void,
insertPlaceChat: (data: PlaceChatMessage) => void,
updateUserVip: (data: { intId: number, codeHash: string}) => void,
insertLiveChatReport: (data: { reporterId: number, messageId: number, reason: string }) => void,
getLiveChatMessage: (intId: number) => LiveChatMessage|null,
exec: (data: { stmt: string, params: any }) => any[]|null,
reInitialise: () => void
}
const createLiveChatMessages = `
CREATE TABLE IF NOT EXISTS LiveChatMessages (
messageId INTEGER PRIMARY KEY,
sendDate INTEGER,
channel TEXT,
message TEXT,
senderIntId INTEGER,
repliesTo INTEGER,
deletionId INTEGER,
FOREIGN KEY (repliesTo) REFERENCES LiveChatMessages(messageId),
FOREIGN KEY (senderIntId) REFERENCES Users(intId),
FOREIGN KEY (deletionId) REFERENCES LiveChatDeletions(deletionId)
)
`
db.exec(createLiveChatMessages)
const createLiveChatReactions = `
CREATE TABLE IF NOT EXISTS LiveChatReactions (
messageId INTEGER,
reaction TEXT,
senderIntId INTEGER,
FOREIGN KEY (messageId) REFERENCES LiveChatMessages(messageId),
FOREIGN KEY (senderIntId) REFERENCES Users(intId)
)
`
db.exec(createLiveChatReactions)
const createPlaceChatMessages = `
CREATE TABLE IF NOT EXISTS PlaceChatMessages (
messageId INTEGER PRIMARY KEY,
sendDate INTEGER,
message TEXT,
senderIntId INTEGER,
x INTEGER,
y INTEGER,
FOREIGN KEY (senderIntId) REFERENCES Users(intId)
)
`
db.exec(createPlaceChatMessages)
const createBans = `
CREATE TABLE IF NOT EXISTS Bans (
banId INTEGER PRIMARY KEY,
userIntId INTEGER UNIQUE,
startDate INTEGER,
finishDate INTEGER,
moderatorIntId INTEGER,
reason TEXT,
userAppeal TEXT,
appealRejected INTEGER,
FOREIGN KEY (userIntId) REFERENCES Users(intId),
FOREIGN KEY (moderatorIntId) REFERENCES Users(intId)
)
`
db.exec(createBans)
const createMutes = `
CREATE TABLE IF NOT EXISTS Mutes (
muteId INTEGER PRIMARY KEY,
startDate INTEGER,
finishDate INTEGER,
userIntId INTEGER UNIQUE,
moderatorIntId INTEGER,
reason TEXT,
userAppeal TEXT,
appealRejected INTEGER,
FOREIGN KEY (userIntId) REFERENCES Users(intId),
FOREIGN KEY (moderatorIntId) REFERENCES Users(intId)
)
`
db.exec(createMutes)
const createUsers = `
CREATE TABLE IF NOT EXISTS Users (
intId INTEGER PRIMARY KEY,
chatName TEXT,
token TEXT NOT NULL,
lastJoined INTEGER,
pixelsPlaced INTEGER,
playTimeSeconds INTEGER
)
`
db.exec(createUsers)
const createKnownIps = `
CREATE TABLE IF NOT EXISTS KnownIps (
userIntId INTEGER NOT NULL,
ip TEXT NOT NULL,
lastUsed INTEGER,
userAgent TEXT,
FOREIGN KEY (userIntId) REFERENCES Users(intId)
)
` // ip and userIntId combined form a composite key to identify a record
db.exec(createKnownIps)
const createVips = `
CREATE TABLE IF NOT EXISTS UserVips (
userIntId INTEGER NOT NULL,
keyHash TEXT NOT NULL,
lastUsed INTEGER,
FOREIGN KEY(userIntId) REFERENCES Users(intId)
)
`
db.exec(createVips)
const createLiveChatDeletions = `
CREATE TABLE IF NOT EXISTS LiveChatDeletions (
deletionId INTEGER PRIMARY KEY,
moderatorIntId INTEGER NOT NULL,
reason TEXT,
deletionDate INTEGER,
FOREIGN KEY (moderatorIntId) REFERENCES Users(intId)
)
`
db.exec(createLiveChatDeletions)
const createLiveChatReports = `
CREATE TABLE IF NOT EXISTS LiveChatReports (
reportId INTEGER PRIMARY KEY,
reporterId INTEGER NOT NULL,
messageId INTEGER NOT NULL,
reason TEXT,
reportDate INTEGER,
FOREIGN KEY (reporterId) REFERENCES Users(intId),
FOREIGN KEY (messageId) REFERENCES LiveChatMessages(messageId)
)
`
db.exec(createLiveChatReports)
const createLinkages = `
CREATE TABLE IF NOT EXISTS Linkages (
userIntId INTEGER UNIQUE,
accountId INTEGER,
linkDate INTEGER,
FOREIGN KEY (userIntId) REFERENCES Users(intId)
)
`
db.exec(createLinkages)
export type LiveChatHistoryMessage = LiveChatMessage & {
chatName: string,
reactions: Map<string, number[]>
}
export type LiveChatHistoryParams = {
channel: string|null,
count: number|null,
messageId: number|null,
}
const insertLiveChat = db.query<void, LiveChatMessage>(`
INSERT INTO LiveChatMessages (messageId, message, sendDate, channel, senderIntId, repliesTo, deletionId)
VALUES ($messageId, $message, $sendDate, $channel, $senderIntId, $repliesTo, $deletionId)`)
const insertPlaceChat = db.query<void, PlaceChatMessage>(`
INSERT INTO PlaceChatMessages (messageId, message, sendDate, senderIntId, x, y)
VALUES ($messageId, $message, $sendDate, $senderIntId, $x, $y)`)
const updatePixelPlaces = db.query<void, [number, number]>(`
UPDATE Users SET pixelsPlaced = pixelsPlaced + ?1 WHERE intId = ?2`)
interface PublicQueue<T> extends Queue<T> {
_elements: T[],
isEmpty(): boolean,
dequeue(): T|undefined,
push(item:T): any
}
const pixelPlaces = new Map<number, number>() // intId, count
// Some chicanery to bypass them hiding _elements from the definition
const liveChatInserts:PublicQueue<LiveChatMessage> = new Queue<LiveChatMessage>()
const placeChatInserts = new Queue<PlaceChatMessage>()
/**
* Bulk insert live chat messages, pixel places and place chats on an interval loop
*/
function performBulkInsertions() {
// insert all new pixel places
db.transaction(() => {
for (const placePair of pixelPlaces) {
updatePixelPlaces.run(placePair[1], placePair[0])
pixelPlaces.delete(placePair[0])
}
})()
// insert all new chats
db.transaction(() => {
while (!liveChatInserts.isEmpty()) {
const data = liveChatInserts.dequeue()
if (data) {
insertLiveChat.run(data)
}
}
while (!placeChatInserts.isEmpty()) {
const data = placeChatInserts.dequeue()
if (data) {
insertPlaceChat.run(data)
}
}
})()
}
setInterval(performBulkInsertions, 10000)
const internal: DbInternals = {
setUserChatName: function({ newName, intId }) {
const updateQuery = db.query("UPDATE Users SET chatName = ?1 WHERE intId = ?2")
updateQuery.run(newName, intId)
},
getUserChatName: function(intId) {
const getNameQuery = db.query<User, number>("SELECT chatName FROM Users WHERE intId = ?1")
const result = getNameQuery.get(intId)
return result ? result.chatName : null
},
authenticateUser: function({ token, ip, userAgent }) {
const selectUser = db.query<User, string>("SELECT * FROM Users WHERE token = ?1")
const epochMs = Date.now()
let user = selectUser.get(token)
if (!user) { // Create new user
const insertUser = db.query<User, [string, number, number, number]>(
"INSERT INTO Users (token, lastJoined, pixelsPlaced, playTimeSeconds) VALUES (?1, ?2, ?3, ?4) RETURNING *")
user = insertUser.get(token, epochMs, 0, 0)
if (user == null) return null
}
else { // Update last joined
const updateUser = db.query("UPDATE Users SET lastJoined = ?1 WHERE intId = ?2")
updateUser.run(epochMs, user.intId)
}
// Add known IP if not already there
const getIpsQuery = db.query<KnownIp, [number, string, string]>("SELECT * FROM KnownIps WHERE userIntId = ?1 AND ip = ?2 AND userAgent = ?3")
const ipExists = getIpsQuery.get(user.intId, ip, userAgent)
if (ipExists) { // Update last used
const updateIp = db.query<void, [number, number, string, string]>("UPDATE KnownIps SET lastUsed = ?1 WHERE userIntId = ?2 AND ip = ?3 AND userAgent = ?4")
updateIp.run(epochMs, user.intId, ip, userAgent)
}
else { // Create new
const createIp = db.query<void, [number, string, string, number]>("INSERT INTO KnownIps (userIntId, ip, userAgent, lastUsed) VALUES (?1, ?2, ?3, ?4)")
createIp.run(user.intId, ip, userAgent, epochMs)
}
return user.intId
},
getLiveChatHistory: function({ channel, includeDeleted, before, messageId, count }) {
const liveChatMessageId = internal.getMaxLiveChatId()
const params:LiveChatHistoryParams = { channel: null, count: null, messageId: null }
let query = `
SELECT LiveChatMessages.*, Users.chatName AS chatName
FROM LiveChatMessages
INNER JOIN Users ON LiveChatMessages.senderIntId = Users.intId
`
const conditions = []
if (channel) {
conditions.push("channel = $channel")
params.channel = channel
}
if (!includeDeleted) {
conditions.push("deletionId IS NULL")
}
if (before) {
messageId = Math.min(liveChatMessageId, messageId)
count = Math.min(liveChatMessageId, count)
if (messageId === 0) {
query += conditions.length ? "WHERE " + conditions.join(" AND ") + " " : ""
query += "ORDER BY messageId DESC LIMIT $count"
params.count = count
} else {
conditions.push("messageId < $messageId")
query += "WHERE " + conditions.join(" AND ") + " ORDER BY messageId DESC LIMIT $count"
params.messageId = messageId
params.count = count
}
} else {
count = Math.min(liveChatMessageId - messageId, count)
conditions.push("messageId > $messageId")
query += "WHERE " + conditions.join(" AND ") + " ORDER BY messageId ASC LIMIT $count"
params.messageId = messageId
params.count = count
}
const history = []
const messagesStmt = db.query<LiveChatHistoryMessage, LiveChatHistoryParams>(query)
for (const message of messagesStmt.iterate(params)) {
message.reactions = new Map<string, number[]>()
const reactionsQuery = db.query<LiveChatReaction, [number]>("SELECT * FROM LiveChatReactions WHERE messageId = ?1")
for (const reaction of reactionsQuery.iterate(message.messageId)) {
if (!message.reactions.has(reaction.reaction)) {
message.reactions.set(reaction.reaction, [])
}
message.reactions.get(reaction.reaction)?.push(reaction.senderIntId)
}
history.push(message)
}
return history
},
updatePixelPlace: function(intId) {
pixelPlaces.set(intId, (pixelPlaces.get(intId)||0) + 1)
},
getMaxLiveChatId: function() {
const getMaxMessageId = db.query<{ maxMessageId: number }, any>("SELECT MAX(messageId) AS maxMessageId FROM LiveChatMessages")
const maxMessageId = getMaxMessageId.get()?.maxMessageId || 0
return maxMessageId
},
getMaxPlaceChatId: function() {
const getMaxMessageId = db.query<{ maxMessageId: number }, any>("SELECT MAX(messageId) AS maxMessageId FROM PlaceChatMessages")
const maxMessageId = getMaxMessageId.get()?.maxMessageId || 0
return maxMessageId
},
commitShutdown: function() {
if (!dbClosed) {
dbClosed = true
performBulkInsertions()
db.close()
return true
}
return false
},
/* Send date is seconds unix epoch offset */
insertLiveChat: function(data) {
data.repliesTo = null
data.deletionId = null
liveChatInserts.push(data)
},
// Messages may or may not be in the DB by the time they are being asked to be deleted due to periodic transactions
deleteLiveChat: function({ moderatorIntId, reason, messageId }) {
const deletionQuery = db.query<LiveChatDeletion, DeletionInsert>(
"INSERT INTO LiveChatDeletions (moderatorIntId, reason, deletionDate) VALUES ($moderatorIntId, $reason, $deletionDate) RETURNING *")
const deletion = deletionQuery.get({ moderatorIntId, reason, deletionDate: Date.now() })
if (deletion == null) {
return
}
// If pending to be inserted into DB we can update the record in preflight
for (const messageData of liveChatInserts._elements) {
if (messageData.messageId === messageId) {
messageData.deletionId = deletion.deletionId
return
}
}
const query = db.query<void, LiveChatUpdateDeletion>("UPDATE LiveChatMessages SET deletionId = $deletionId WHERE messageId = $messageId")
const deletionUpdate:LiveChatUpdateDeletion = { deletionId: deletion.deletionId, messageId }
query.run(deletionUpdate)
},
insertPlaceChat: function(data) {
placeChatInserts.push(data)
},
updateUserVip: function({ intId, codeHash }) {
const epochMs = Date.now()
const getKeysQuery = db.query("SELECT * FROM UserVips WHERE userIntId = ?1 AND keyHash = ?2")
const keyExists = getKeysQuery.get(intId, codeHash)
if (keyExists) {
const updateKeysQuery = db.query("UPDATE UserVips SET lastUsed = ?1 WHERE userIntId = ?2 AND keyHash = ?3")
updateKeysQuery.run(epochMs, intId, codeHash)
}
else {
const createVipQuery = db.query("INSERT INTO UserVips (userIntId, keyHash, lastUsed) VALUES (?1, ?2, ?3)")
createVipQuery.run(intId, codeHash, epochMs)
}
},
insertLiveChatReport: function({ reporterId, messageId, reason }) {
const insertReportQuery = db.query("INSERT INTO LiveChatReports (reporterId, messageId, reason, reportDate) VALUES (?1, ?2, ?3, ?4)")
insertReportQuery.run(reporterId, messageId, reason, Date.now())
},
addLiveChatReaction: function({ messageId, reaction, senderIntId }) {
// Message does not directly reference reaction so it is OK if message has not been inserted into DB yet (due to message bulk transactions)
const insertReactionQuery = db.query("INSERT INTO LiveChatReactions (messageId, reaction, senderIntId) VALUES (?1, ?2, ?3)")
insertReactionQuery.run(messageId, reaction, senderIntId)
},
getLiveChatMessage: function(intId) {
// Message may not be in the DB yet if recently sent so getting a message requires some logic
const getMessageQuery = db.query<LiveChatMessage, number>("SELECT * FROM LiveChatMessages WHERE messageId = ?1")
const message = getMessageQuery.get(intId)
if (message != null) {
return message
}
for (const pendingMessage of liveChatInserts._elements) {
if (pendingMessage.messageId == intId) {
return pendingMessage
}
}
return null
},
exec: function({ stmt, params }) {
try {
const query = db.query(stmt)
return (typeof params[Symbol.iterator] === "function"
? query.all(...params)
: query.all(params))
}
catch(err) {
console.log("Could not exec DB query: ", err)
return null
}
},
reInitialise: function() { // Re-create the DB
internal.commitShutdown()
db = new Database("server.db", defaultDbOptions)
dbClosed = false
}
}
parentPort?.on("message", (message) => {
const result = internal[message.call] && internal[message.call](message.data)
parentPort?.postMessage({ handle: message.handle, data: result })
})
self.addEventListener("error", event => {
console.error("Uncaught exception in DB worker:", event.error)
})