cache_sqlite.go 14 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514
  1. package server
  2. import (
  3. "database/sql"
  4. "errors"
  5. "fmt"
  6. _ "github.com/mattn/go-sqlite3" // SQLite driver
  7. "log"
  8. "strings"
  9. "time"
  10. )
  11. // Messages cache
  12. const (
  13. createMessagesTableQuery = `
  14. BEGIN;
  15. CREATE TABLE IF NOT EXISTS messages (
  16. id INTEGER PRIMARY KEY AUTOINCREMENT,
  17. mid TEXT NOT NULL,
  18. time INT NOT NULL,
  19. topic TEXT NOT NULL,
  20. message TEXT NOT NULL,
  21. title TEXT NOT NULL,
  22. priority INT NOT NULL,
  23. tags TEXT NOT NULL,
  24. click TEXT NOT NULL,
  25. attachment_name TEXT NOT NULL,
  26. attachment_type TEXT NOT NULL,
  27. attachment_size INT NOT NULL,
  28. attachment_expires INT NOT NULL,
  29. attachment_url TEXT NOT NULL,
  30. attachment_owner TEXT NOT NULL,
  31. encoding TEXT NOT NULL,
  32. published INT NOT NULL
  33. );
  34. CREATE INDEX IF NOT EXISTS idx_mid ON messages (mid);
  35. CREATE INDEX IF NOT EXISTS idx_topic ON messages (topic);
  36. COMMIT;
  37. `
  38. insertMessageQuery = `
  39. INSERT INTO messages (mid, time, topic, message, title, priority, tags, click, attachment_name, attachment_type, attachment_size, attachment_expires, attachment_url, attachment_owner, encoding, published)
  40. VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
  41. `
  42. pruneMessagesQuery = `DELETE FROM messages WHERE time < ? AND published = 1`
  43. selectMessagesSinceTimeQuery = `
  44. SELECT mid, time, topic, message, title, priority, tags, click, attachment_name, attachment_type, attachment_size, attachment_expires, attachment_url, attachment_owner, encoding
  45. FROM messages
  46. WHERE topic = ? AND time >= ? AND published = 1
  47. ORDER BY time, id
  48. `
  49. selectMessagesSinceTimeIncludeScheduledQuery = `
  50. SELECT mid, time, topic, message, title, priority, tags, click, attachment_name, attachment_type, attachment_size, attachment_expires, attachment_url, attachment_owner, encoding
  51. FROM messages
  52. WHERE topic = ? AND time >= ?
  53. ORDER BY time, id
  54. `
  55. selectMessagesSinceIDQuery = `
  56. SELECT mid, time, topic, message, title, priority, tags, click, attachment_name, attachment_type, attachment_size, attachment_expires, attachment_url, attachment_owner, encoding
  57. FROM messages
  58. WHERE topic = ?
  59. AND published = 1
  60. AND id > (SELECT IFNULL(id,0) FROM messages WHERE mid = ?)
  61. ORDER BY time, id
  62. `
  63. selectMessagesSinceIDIncludeScheduledQuery = `
  64. SELECT mid, time, topic, message, title, priority, tags, click, attachment_name, attachment_type, attachment_size, attachment_expires, attachment_url, attachment_owner, encoding
  65. FROM messages
  66. WHERE topic = ?
  67. AND id > (SELECT IFNULL(id,0) FROM messages WHERE mid = ?)
  68. ORDER BY time, id
  69. `
  70. selectMessagesDueQuery = `
  71. SELECT mid, time, topic, message, title, priority, tags, click, attachment_name, attachment_type, attachment_size, attachment_expires, attachment_url, attachment_owner, encoding
  72. FROM messages
  73. WHERE time <= ? AND published = 0
  74. ORDER BY time, id
  75. `
  76. updateMessagePublishedQuery = `UPDATE messages SET published = 1 WHERE mid = ?`
  77. selectMessagesCountQuery = `SELECT COUNT(*) FROM messages`
  78. selectMessageCountForTopicQuery = `SELECT COUNT(*) FROM messages WHERE topic = ?`
  79. selectTopicsQuery = `SELECT topic FROM messages GROUP BY topic`
  80. selectAttachmentsSizeQuery = `SELECT IFNULL(SUM(attachment_size), 0) FROM messages WHERE attachment_owner = ? AND attachment_expires >= ?`
  81. selectAttachmentsExpiredQuery = `SELECT mid FROM messages WHERE attachment_expires > 0 AND attachment_expires < ?`
  82. )
  83. // Schema management queries
  84. const (
  85. currentSchemaVersion = 5
  86. createSchemaVersionTableQuery = `
  87. CREATE TABLE IF NOT EXISTS schemaVersion (
  88. id INT PRIMARY KEY,
  89. version INT NOT NULL
  90. );
  91. `
  92. insertSchemaVersion = `INSERT INTO schemaVersion VALUES (1, ?)`
  93. updateSchemaVersion = `UPDATE schemaVersion SET version = ? WHERE id = 1`
  94. selectSchemaVersionQuery = `SELECT version FROM schemaVersion WHERE id = 1`
  95. // 0 -> 1
  96. migrate0To1AlterMessagesTableQuery = `
  97. BEGIN;
  98. ALTER TABLE messages ADD COLUMN title TEXT NOT NULL DEFAULT('');
  99. ALTER TABLE messages ADD COLUMN priority INT NOT NULL DEFAULT(0);
  100. ALTER TABLE messages ADD COLUMN tags TEXT NOT NULL DEFAULT('');
  101. COMMIT;
  102. `
  103. // 1 -> 2
  104. migrate1To2AlterMessagesTableQuery = `
  105. ALTER TABLE messages ADD COLUMN published INT NOT NULL DEFAULT(1);
  106. `
  107. // 2 -> 3
  108. migrate2To3AlterMessagesTableQuery = `
  109. BEGIN;
  110. ALTER TABLE messages ADD COLUMN click TEXT NOT NULL DEFAULT('');
  111. ALTER TABLE messages ADD COLUMN attachment_name TEXT NOT NULL DEFAULT('');
  112. ALTER TABLE messages ADD COLUMN attachment_type TEXT NOT NULL DEFAULT('');
  113. ALTER TABLE messages ADD COLUMN attachment_size INT NOT NULL DEFAULT('0');
  114. ALTER TABLE messages ADD COLUMN attachment_expires INT NOT NULL DEFAULT('0');
  115. ALTER TABLE messages ADD COLUMN attachment_owner TEXT NOT NULL DEFAULT('');
  116. ALTER TABLE messages ADD COLUMN attachment_url TEXT NOT NULL DEFAULT('');
  117. COMMIT;
  118. `
  119. // 3 -> 4
  120. migrate3To4AlterMessagesTableQuery = `
  121. ALTER TABLE messages ADD COLUMN encoding TEXT NOT NULL DEFAULT('');
  122. `
  123. // 4 -> 5
  124. migrate4To5AlterMessagesTableQuery = `
  125. BEGIN;
  126. CREATE TABLE IF NOT EXISTS messages_new (
  127. id INTEGER PRIMARY KEY AUTOINCREMENT,
  128. mid TEXT NOT NULL,
  129. time INT NOT NULL,
  130. topic TEXT NOT NULL,
  131. message TEXT NOT NULL,
  132. title TEXT NOT NULL,
  133. priority INT NOT NULL,
  134. tags TEXT NOT NULL,
  135. click TEXT NOT NULL,
  136. attachment_name TEXT NOT NULL,
  137. attachment_type TEXT NOT NULL,
  138. attachment_size INT NOT NULL,
  139. attachment_expires INT NOT NULL,
  140. attachment_url TEXT NOT NULL,
  141. attachment_owner TEXT NOT NULL,
  142. encoding TEXT NOT NULL,
  143. published INT NOT NULL
  144. );
  145. CREATE INDEX IF NOT EXISTS idx_mid ON messages_new (mid);
  146. CREATE INDEX IF NOT EXISTS idx_topic ON messages_new (topic);
  147. INSERT
  148. INTO messages_new (
  149. mid, time, topic, message, title, priority, tags, click, attachment_name, attachment_type,
  150. attachment_size, attachment_expires, attachment_url, attachment_owner, encoding, published)
  151. SELECT
  152. id, time, topic, message, title, priority, tags, click, attachment_name, attachment_type,
  153. attachment_size, attachment_expires, attachment_url, attachment_owner, encoding, published
  154. FROM messages;
  155. DROP TABLE messages;
  156. ALTER TABLE messages_new RENAME TO messages;
  157. COMMIT;
  158. `
  159. )
  160. type sqliteCache struct {
  161. db *sql.DB
  162. }
  163. var _ cache = (*sqliteCache)(nil)
  164. func newSqliteCache(filename string) (*sqliteCache, error) {
  165. db, err := sql.Open("sqlite3", filename)
  166. if err != nil {
  167. return nil, err
  168. }
  169. if err := setupCacheDB(db); err != nil {
  170. return nil, err
  171. }
  172. return &sqliteCache{
  173. db: db,
  174. }, nil
  175. }
  176. func (c *sqliteCache) AddMessage(m *message) error {
  177. if m.Event != messageEvent {
  178. return errUnexpectedMessageType
  179. }
  180. published := m.Time <= time.Now().Unix()
  181. tags := strings.Join(m.Tags, ",")
  182. var attachmentName, attachmentType, attachmentURL, attachmentOwner string
  183. var attachmentSize, attachmentExpires int64
  184. if m.Attachment != nil {
  185. attachmentName = m.Attachment.Name
  186. attachmentType = m.Attachment.Type
  187. attachmentSize = m.Attachment.Size
  188. attachmentExpires = m.Attachment.Expires
  189. attachmentURL = m.Attachment.URL
  190. attachmentOwner = m.Attachment.Owner
  191. }
  192. _, err := c.db.Exec(
  193. insertMessageQuery,
  194. m.ID,
  195. m.Time,
  196. m.Topic,
  197. m.Message,
  198. m.Title,
  199. m.Priority,
  200. tags,
  201. m.Click,
  202. attachmentName,
  203. attachmentType,
  204. attachmentSize,
  205. attachmentExpires,
  206. attachmentURL,
  207. attachmentOwner,
  208. m.Encoding,
  209. published,
  210. )
  211. return err
  212. }
  213. func (c *sqliteCache) Messages(topic string, since sinceMarker, scheduled bool) ([]*message, error) {
  214. if since.IsNone() {
  215. return make([]*message, 0), nil
  216. }
  217. var rows *sql.Rows
  218. var err error
  219. if since.IsID() {
  220. if scheduled {
  221. rows, err = c.db.Query(selectMessagesSinceIDIncludeScheduledQuery, topic, since.ID())
  222. } else {
  223. rows, err = c.db.Query(selectMessagesSinceIDQuery, topic, since.ID())
  224. }
  225. } else {
  226. if scheduled {
  227. rows, err = c.db.Query(selectMessagesSinceTimeIncludeScheduledQuery, topic, since.Time().Unix())
  228. } else {
  229. rows, err = c.db.Query(selectMessagesSinceTimeQuery, topic, since.Time().Unix())
  230. }
  231. }
  232. if err != nil {
  233. return nil, err
  234. }
  235. return readMessages(rows)
  236. }
  237. func (c *sqliteCache) MessagesDue() ([]*message, error) {
  238. rows, err := c.db.Query(selectMessagesDueQuery, time.Now().Unix())
  239. if err != nil {
  240. return nil, err
  241. }
  242. return readMessages(rows)
  243. }
  244. func (c *sqliteCache) MarkPublished(m *message) error {
  245. _, err := c.db.Exec(updateMessagePublishedQuery, m.ID)
  246. return err
  247. }
  248. func (c *sqliteCache) MessageCount(topic string) (int, error) {
  249. rows, err := c.db.Query(selectMessageCountForTopicQuery, topic)
  250. if err != nil {
  251. return 0, err
  252. }
  253. defer rows.Close()
  254. var count int
  255. if !rows.Next() {
  256. return 0, errors.New("no rows found")
  257. }
  258. if err := rows.Scan(&count); err != nil {
  259. return 0, err
  260. } else if err := rows.Err(); err != nil {
  261. return 0, err
  262. }
  263. return count, nil
  264. }
  265. func (c *sqliteCache) Topics() (map[string]*topic, error) {
  266. rows, err := c.db.Query(selectTopicsQuery)
  267. if err != nil {
  268. return nil, err
  269. }
  270. defer rows.Close()
  271. topics := make(map[string]*topic)
  272. for rows.Next() {
  273. var id string
  274. if err := rows.Scan(&id); err != nil {
  275. return nil, err
  276. }
  277. topics[id] = newTopic(id)
  278. }
  279. if err := rows.Err(); err != nil {
  280. return nil, err
  281. }
  282. return topics, nil
  283. }
  284. func (c *sqliteCache) Prune(olderThan time.Time) error {
  285. _, err := c.db.Exec(pruneMessagesQuery, olderThan.Unix())
  286. return err
  287. }
  288. func (c *sqliteCache) AttachmentsSize(owner string) (int64, error) {
  289. rows, err := c.db.Query(selectAttachmentsSizeQuery, owner, time.Now().Unix())
  290. if err != nil {
  291. return 0, err
  292. }
  293. defer rows.Close()
  294. var size int64
  295. if !rows.Next() {
  296. return 0, errors.New("no rows found")
  297. }
  298. if err := rows.Scan(&size); err != nil {
  299. return 0, err
  300. } else if err := rows.Err(); err != nil {
  301. return 0, err
  302. }
  303. return size, nil
  304. }
  305. func (c *sqliteCache) AttachmentsExpired() ([]string, error) {
  306. rows, err := c.db.Query(selectAttachmentsExpiredQuery, time.Now().Unix())
  307. if err != nil {
  308. return nil, err
  309. }
  310. defer rows.Close()
  311. ids := make([]string, 0)
  312. for rows.Next() {
  313. var id string
  314. if err := rows.Scan(&id); err != nil {
  315. return nil, err
  316. }
  317. ids = append(ids, id)
  318. }
  319. if err := rows.Err(); err != nil {
  320. return nil, err
  321. }
  322. return ids, nil
  323. }
  324. func readMessages(rows *sql.Rows) ([]*message, error) {
  325. defer rows.Close()
  326. messages := make([]*message, 0)
  327. for rows.Next() {
  328. var timestamp, attachmentSize, attachmentExpires int64
  329. var priority int
  330. var id, topic, msg, title, tagsStr, click, attachmentName, attachmentType, attachmentURL, attachmentOwner, encoding string
  331. err := rows.Scan(
  332. &id,
  333. &timestamp,
  334. &topic,
  335. &msg,
  336. &title,
  337. &priority,
  338. &tagsStr,
  339. &click,
  340. &attachmentName,
  341. &attachmentType,
  342. &attachmentSize,
  343. &attachmentExpires,
  344. &attachmentURL,
  345. &attachmentOwner,
  346. &encoding,
  347. )
  348. if err != nil {
  349. return nil, err
  350. }
  351. var tags []string
  352. if tagsStr != "" {
  353. tags = strings.Split(tagsStr, ",")
  354. }
  355. var att *attachment
  356. if attachmentName != "" && attachmentURL != "" {
  357. att = &attachment{
  358. Name: attachmentName,
  359. Type: attachmentType,
  360. Size: attachmentSize,
  361. Expires: attachmentExpires,
  362. URL: attachmentURL,
  363. Owner: attachmentOwner,
  364. }
  365. }
  366. messages = append(messages, &message{
  367. ID: id,
  368. Time: timestamp,
  369. Event: messageEvent,
  370. Topic: topic,
  371. Message: msg,
  372. Title: title,
  373. Priority: priority,
  374. Tags: tags,
  375. Click: click,
  376. Attachment: att,
  377. Encoding: encoding,
  378. })
  379. }
  380. if err := rows.Err(); err != nil {
  381. return nil, err
  382. }
  383. return messages, nil
  384. }
  385. func setupCacheDB(db *sql.DB) error {
  386. // If 'messages' table does not exist, this must be a new database
  387. rowsMC, err := db.Query(selectMessagesCountQuery)
  388. if err != nil {
  389. return setupNewCacheDB(db)
  390. }
  391. rowsMC.Close()
  392. // If 'messages' table exists, check 'schemaVersion' table
  393. schemaVersion := 0
  394. rowsSV, err := db.Query(selectSchemaVersionQuery)
  395. if err == nil {
  396. defer rowsSV.Close()
  397. if !rowsSV.Next() {
  398. return errors.New("cannot determine schema version: cache file may be corrupt")
  399. }
  400. if err := rowsSV.Scan(&schemaVersion); err != nil {
  401. return err
  402. }
  403. rowsSV.Close()
  404. }
  405. // Do migrations
  406. if schemaVersion == currentSchemaVersion {
  407. return nil
  408. } else if schemaVersion == 0 {
  409. return migrateFrom0(db)
  410. } else if schemaVersion == 1 {
  411. return migrateFrom1(db)
  412. } else if schemaVersion == 2 {
  413. return migrateFrom2(db)
  414. } else if schemaVersion == 3 {
  415. return migrateFrom3(db)
  416. } else if schemaVersion == 4 {
  417. return migrateFrom4(db)
  418. }
  419. return fmt.Errorf("unexpected schema version found: %d", schemaVersion)
  420. }
  421. func setupNewCacheDB(db *sql.DB) error {
  422. if _, err := db.Exec(createMessagesTableQuery); err != nil {
  423. return err
  424. }
  425. if _, err := db.Exec(createSchemaVersionTableQuery); err != nil {
  426. return err
  427. }
  428. if _, err := db.Exec(insertSchemaVersion, currentSchemaVersion); err != nil {
  429. return err
  430. }
  431. return nil
  432. }
  433. func migrateFrom0(db *sql.DB) error {
  434. log.Print("Migrating cache database schema: from 0 to 1")
  435. if _, err := db.Exec(migrate0To1AlterMessagesTableQuery); err != nil {
  436. return err
  437. }
  438. if _, err := db.Exec(createSchemaVersionTableQuery); err != nil {
  439. return err
  440. }
  441. if _, err := db.Exec(insertSchemaVersion, 1); err != nil {
  442. return err
  443. }
  444. return migrateFrom1(db)
  445. }
  446. func migrateFrom1(db *sql.DB) error {
  447. log.Print("Migrating cache database schema: from 1 to 2")
  448. if _, err := db.Exec(migrate1To2AlterMessagesTableQuery); err != nil {
  449. return err
  450. }
  451. if _, err := db.Exec(updateSchemaVersion, 2); err != nil {
  452. return err
  453. }
  454. return migrateFrom2(db)
  455. }
  456. func migrateFrom2(db *sql.DB) error {
  457. log.Print("Migrating cache database schema: from 2 to 3")
  458. if _, err := db.Exec(migrate2To3AlterMessagesTableQuery); err != nil {
  459. return err
  460. }
  461. if _, err := db.Exec(updateSchemaVersion, 3); err != nil {
  462. return err
  463. }
  464. return migrateFrom3(db)
  465. }
  466. func migrateFrom3(db *sql.DB) error {
  467. log.Print("Migrating cache database schema: from 3 to 4")
  468. if _, err := db.Exec(migrate3To4AlterMessagesTableQuery); err != nil {
  469. return err
  470. }
  471. if _, err := db.Exec(updateSchemaVersion, 4); err != nil {
  472. return err
  473. }
  474. return migrateFrom4(db)
  475. }
  476. func migrateFrom4(db *sql.DB) error {
  477. log.Print("Migrating cache database schema: from 4 to 5")
  478. if _, err := db.Exec(migrate4To5AlterMessagesTableQuery); err != nil {
  479. return err
  480. }
  481. if _, err := db.Exec(updateSchemaVersion, 5); err != nil {
  482. return err
  483. }
  484. return nil // Update this when a new version is added
  485. }