-
Notifications
You must be signed in to change notification settings - Fork 21
/
database.rb
375 lines (323 loc) · 12.9 KB
/
database.rb
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
require 'sqlite3'
require 'singleton'
class Database
include Singleton
attr_reader :db
def initialize
self.setupDB(:file)
end
# Activate testmode, which means re-initializing the sqlite databases in memory
def testmode
self.setupDB(:memory)
end
def setupDB(mode)
if (mode == :file)
@db = SQLite3::Database.new "pipes.db"
else
@db = SQLite3::Database.new ":memory:"
end
begin
@db.execute 'CREATE TABLE IF NOT EXISTS users(
id INTEGER PRIMARY KEY AUTOINCREMENT,
email TEXT UNIQUE
);'
@db.execute 'CREATE TABLE IF NOT EXISTS plans(
plan TEXT,
user INTEGER,
subscription_id TEXT,
FOREIGN KEY (user) REFERENCES users(id) ON DELETE CASCADE
);'
@db.execute 'CREATE TABLE IF NOT EXISTS pipes(
id INTEGER PRIMARY KEY AUTOINCREMENT,
pipe TEXT,
title TEXT,
description TEXT,
user INTEGER,
preview TEXT,
public BOOLEAN DEFAULT 0,
publicdate INTEGER DEFAULT 0,
date INTEGER DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY(user) REFERENCES users(id)
);'
@db.execute "CREATE TABLE IF NOT EXISTS likes(
user INTEGER,
pipe INTEGER,
date INTEGER DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (user) REFERENCES users(id) ON DELETE CASCADE,
FOREIGN KEY (pipe) REFERENCES pipes(id) ON DELETE CASCADE,
UNIQUE(user, pipe)
);"
@db.execute "CREATE TABLE IF NOT EXISTS tags(
pipe INTEGER,
tag TEXT,
date INTEGER DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (pipe) REFERENCES pipes(id) ON DELETE CASCADE,
UNIQUE(tag, pipe)
);"
@db.execute "CREATE TABLE IF NOT EXISTS cache(
key TEXT PRIMARY KEY,
value TEXT,
date INTEGER DEFAULT CURRENT_TIMESTAMP
);"
rescue => error
warn "Error creating database: #{error}"
end
begin
@db.execute 'SELECT publicdate FROM pipes;'
rescue => error
@db.execute 'ALTER TABLE pipes ADD publicdate INTEGER DEFAULT 0;'
end
begin
@db.execute 'SELECT public FROM pipes;'
rescue => error
@db.execute 'ALTER TABLE pipes ADD public BOOLEAN DEFAULT 0;'
end
if (mode == :file)
@hookdb = SQLite3::Database.new "hooks.db"
else
@hookdb = SQLite3::Database.new ":memory:"
end
begin
@hookdb.execute 'CREATE TABLE IF NOT EXISTS hooks(
id INTEGER PRIMARY KEY AUTOINCREMENT,
content TEXT,
blockid TEXT,
date INTEGER DEFAULT CURRENT_TIMESTAMP
);'
@hookdb.execute 'CREATE INDEX IF NOT EXISTS hooks_blockid_idx ON hooks(blockid);'
rescue => error
warn "Error creating hook database: #{error}"
end
@db.execute 'PRAGMA foreign_keys = ON;'
@db.execute 'PRAGMA cache_size = 40000;'
@db.execute 'ANALYZE;'
@db.results_as_hash = true
@hookdb.execute 'PRAGMA foreign_keys = ON;'
@hookdb.execute 'PRAGMA cache_size = 40000;'
@hookdb.execute 'ANALYZE;'
@hookdb.results_as_hash = true
end
def storePipe(id: nil, pipe:, user:, preview:)
addUser(email: user)
if (id && id != '')
# Update existing pipe, but only if it is a pipe of the user
@db.execute('UPDATE pipes SET pipe = ?, preview = ? WHERE user = ? and id = ?', pipe, preview, self.getUserId(email: user), id)
self.uncache(key: id)
return id
else
@db.execute('INSERT INTO pipes(pipe, title, description, user, preview) VALUES(?, "unnamed", "", ?, ?)', pipe, self.getUserId(email: user), preview)
return @db.last_insert_row_id
end
end
def copyPipe(id:, user:)
@db.execute('INSERT INTO pipes(pipe, title, description, user, preview) SELECT pipe, title, description, user, preview FROM pipes WHERE id = ? AND user = ? ', id, self.getUserId(email: user))
return @db.last_insert_row_id
end
def getPipe(id:)
return @db.execute('SELECT *, pipes.pipe as pipe, group_concat(tag) AS tags FROM pipes LEFT JOIN tags ON (pipes.id = tags.pipe) WHERE id = ? GROUP BY pipes.id', id)[0]
end
def getPublicPipe(id:)
return @db.execute('SELECT * FROM pipes WHERE id = ? AND public = 1', id)[0]
end
def getPipes(user:)
begin
return @db.execute('SELECT *, group_concat(tag) AS tags FROM pipes LEFT JOIN tags ON (pipes.id = tags.pipe) WHERE user = ? GROUP BY pipes.id', self.getUserId(email: user))
rescue => e
warn "error getting pipes: #{e}"
return []
end
end
def getPublicPipes(order: nil, tag: nil)
begin
orderSQL = case order
when 'new' then 'ORDER BY pipes.publicdate DESC'
when 'likes' then 'ORDER BY COUNT(likes.pipe) DESC'
else ''
end
if tag.nil?
return @db.execute('SELECT pipes.id as id, pipes.user as user, pipes.pipe as pipe, title, description, preview, public, publicdate, pipes.date as date, COUNT(DISTINCT likes.user) AS likes, GROUP_CONCAT(DISTINCT tag) as tags FROM pipes LEFT JOIN likes ON (pipes.id = likes.pipe) LEFT JOIN tags ON (pipes.id = tags.pipe) WHERE public = 1 GROUP BY pipes.id ' + orderSQL)
else
return @db.execute('SELECT pipes.id as id, pipes.user as user, pipes.pipe as pipe, title, description, preview, public, publicdate, pipes.date as date, COUNT(DISTINCT likes.user) AS likes, GROUP_CONCAT(DISTINCT tag) as tags FROM pipes LEFT JOIN likes ON (pipes.id = likes.pipe) LEFT JOIN tags ON (pipes.id = tags.pipe) WHERE public = 1 AND tag = ? GROUP BY pipes.id ' + orderSQL, tag)
end
rescue => e
warn "error getting public pipes: #{e}"
return []
end
end
def addUser(email:)
@db.execute('INSERT OR IGNORE INTO users(email) VALUES (?)', email)
end
def getUserId(email:)
return @db.execute('SELECT id FROM users WHERE email = ?', email)[0]['id']
end
def cache(key:, value:)
begin
@db.execute("INSERT OR IGNORE INTO cache(key, value) VALUES(?, ?)", key, value)
@db.execute("UPDATE cache SET value = ?, date = strftime('%s','now') WHERE key = ?", value, key)
rescue => error
warn "cache: #{error}"
end
end
def getCache(key:)
begin
cached = @db.execute("SELECT value, date FROM cache WHERE key = ? LIMIT 1;", key)[0]
return cached['value'], cached['date']
rescue => error
warn "getCache: #{error} for #{key}"
end
end
def uncache(key:)
begin
@db.execute("DELETE FROM cache WHERE key LIKE ?", key.to_s + '%')
rescue => error
warn "uncache: #{error}"
end
end
# clean all cached entries older than 2 hours
def cleanCache()
begin
@db.execute("DELETE FROM cache WHERE CAST(date AS integer) < (CAST(strftime('%s', 'now') AS integer) - 7200);", )
@db.execute("VACUUM")
rescue => error
warn "cleaning cache: #{error}"
end
end
def setPipeTitle(id:, user:, title:)
begin
@db.execute('UPDATE pipes SET title = ? WHERE user = ? and id = ?', title.gsub(/<\/?[^>]*>/, ''), self.getUserId(email: user), id)
self.uncache(key: id)
return true
rescue => error
warn "setPipeTitle: #{error}"
end
return false
end
def sharePipe(id:, user:)
begin
@db.execute('UPDATE pipes SET public = 1 WHERE user = ? and id = ?', self.getUserId(email: user), id)
return true
rescue => error
warn "sharePipe: #{error}"
end
return false
end
def setPipeDescription(id:, user:, description:)
begin
@db.execute('UPDATE pipes SET description = ? WHERE user = ? and id = ?', description.gsub(/<\/?[^>]*>/, ''), self.getUserId(email: user), id)
return true
rescue => error
warn "setPipeDescription: #{error}"
end
return false
end
def unsharePipe(id:, user:)
begin
@db.execute('UPDATE pipes SET public = 0 WHERE user = ? and id = ?', self.getUserId(email: user), id)
return true
rescue => error
warn "unsharePipe: #{error}"
end
return false
end
def deletePipe(id:, user:)
begin
@db.execute('DELETE FROM pipes WHERE user = ? and id = ?', self.getUserId(email: user), id)
return true
rescue => error
warn "deletePipe: #{error}"
end
return false
end
def storeHook(content:, blockid:)
begin
@hookdb.execute("INSERT INTO hooks(content, blockid) VALUES(?, ?)", content, blockid)
rescue => error
warn "store hook: #{error}"
end
end
def getHooks(blockid:)
begin
return @hookdb.execute("SELECT * FROM hooks WHERE CAST(blockid AS TEXT) LIKE ?", blockid)
rescue => error
warn "get hooks: #{error}"
end
end
def cleanHooks()
begin
return @hookdb.execute("DELETE FROM hooks WHERE CAST(strftime('%s', date) AS INT) < ?", (Time.now - 3600).to_i)
rescue => error
warn "clean hooks: #{error}"
end
end
def changeMail(new:, old:)
begin
@db.execute("UPDATE users SET email = ? WHERE email LIKE ?", new, old)
return @db.changes == 1
rescue => error
warn "error changing users email: #{error}"
end
return false
end
def likePipe(user:, pipe:)
begin
return @db.execute("INSERT INTO likes(user, pipe) VALUES(?, ?)", self.getUserId(email: user), pipe)
rescue => error
warn "like pipe: #{error}"
end
end
def unlikePipe(user:, pipe:)
begin
return @db.execute("DELETE FROM likes WHERE user = ? AND pipe = ?", self.getUserId(email: user), pipe)
rescue => error
warn "unlike pipe: #{error}"
end
end
def getLikedPipes(user:)
begin
return [] if user.nil?
return @db.execute("SELECT pipe FROM likes WHERE user = ?", self.getUserId(email: user))
rescue => error
warn "get liked pipes: #{error}"
end
end
def getLikes(user:)
begin
return @db.execute("SELECT COUNT(likes.pipe) from pipes LEFT JOIN likes ON (pipes.id = likes.pipe) WHERE pipes.user = ? AND likes.user != ?", self.getUserId(email: user), self.getUserId(email: user))[0][0]
rescue => error
warn "get likes: #{error}"
end
return 0
end
def getTags()
begin
return @db.execute("SELECT DISTINCT(tag) as tag FROM tags;").map{|x| x['tag']}
rescue => error
warn "get tags: #{error}"
end
end
def addTag(user:, pipe:, tag:)
begin
if self.getPipe(id: pipe)['user'] == self.getUserId(email: user)
tag.split(',').each do |split_tag|
@db.execute("INSERT INTO tags(tag, pipe) VALUES(?, ?)", split_tag.gsub(/<\/?[^>]*>/, "").strip, pipe)
end
return true
end
rescue => error
warn "addTag: #{error}"
end
return false
end
def removeTag(user:, pipe:, tag:)
begin
if self.getPipe(id: pipe)['user'] == self.getUserId(email: user)
return @db.execute("DELETE FROM tags WHERE tag = ? AND pipe = ?", tag.gsub(/<\/?[^>]*>/, ""), pipe)
end
rescue => error
warn "removeTag: #{error}"
end
end
def getPlan(user:)
'selfhosted'
end
end