log.schema 2.5 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576
  1. CREATE TABLE IF NOT EXISTS seen_hosts (
  2. id INTEGER PRIMARY KEY AUTOINCREMENT,
  3. ip_address TEXT NOT NULL UNIQUE
  4. );
  5. CREATE TABLE IF NOT EXISTS seen_users (
  6. id INTEGER PRIMARY KEY AUTOINCREMENT,
  7. user TEXT NOT NULL UNIQUE
  8. );
  9. CREATE TABLE IF NOT EXISTS seen_routes (
  10. id INTEGER PRIMARY KEY AUTOINCREMENT,
  11. route TEXT NOT NULL,
  12. method TEXT NOT NULL,
  13. UNIQUE(route, method)
  14. );
  15. CREATE TABLE IF NOT EXISTS response_code (
  16. id INTEGER PRIMARY KEY AUTOINCREMENT,
  17. code INTEGER NOT NULL UNIQUE
  18. );
  19. CREATE TABLE IF NOT EXISTS requests (
  20. uuid TEXT PRIMARY KEY,
  21. date TEXT NOT NULL,
  22. host_id INTEGER NOT NULL REFERENCES seen_hosts(id) ON DELETE CASCADE,
  23. user_id INTEGER NOT NULL REFERENCES seen_users(id) ON DELETE CASCADE,
  24. route_id INTEGER NOT NULL REFERENCES seen_routes(id) ON DELETE CASCADE,
  25. response_code_id INTEGER NOT NULL REFERENCES response_code(id) ON DELETE RESTRICT
  26. );
  27. CREATE VIEW IF NOT EXISTS all_requests AS
  28. SELECT
  29. q.uuid,
  30. q.date,
  31. h.ip_address,
  32. u.user,
  33. r.method,
  34. r.route,
  35. c.code
  36. FROM
  37. requests AS q
  38. JOIN
  39. seen_hosts AS h ON q.host_id = h.id
  40. JOIN
  41. seen_users AS u ON q.user_id = u.id
  42. JOIN
  43. seen_routes AS r ON q.route_id = r.id
  44. JOIN
  45. response_code AS c on q.response_code_id = c.id;
  46. /* Make all_requests a writable view via triggers. We will always stomp the main row, as the last update will be what we want. */
  47. CREATE TRIGGER IF NOT EXISTS insert_all_requests INSTEAD OF INSERT ON all_requests BEGIN
  48. INSERT OR IGNORE INTO response_code (code) VALUES (NEW.code);
  49. INSERT OR IGNORE INTO seen_routes (route,method) VALUES (NEW.route, NEW.method);
  50. INSERT OR IGNORE INTO seen_users (user) VALUES (NEW.user);
  51. INSERT OR IGNORE INTO seen_hosts (ip_address) VALUES (NEW.ip_address);
  52. INSERT OR REPLACE INTO requests SELECT
  53. NEW.uuid,
  54. NEW.date,
  55. h.id AS host_id,
  56. u.id AS user_id,
  57. r.id AS route_id,
  58. c.id AS response_code_id
  59. FROM seen_hosts AS h
  60. JOIN seen_users AS u ON u.user = NEW.user
  61. JOIN seen_routes AS r ON r.route = NEW.route AND r.method = NEW.method
  62. JOIN response_code AS c ON c.code = NEW.code
  63. WHERE h.ip_address = NEW.ip_address;
  64. END;
  65. /* This is just to store various messages associated with requests, which are usually errors. */
  66. CREATE TABLE IF NOT EXISTS messages (
  67. uuid TEXT NOT NULL REFERENCES requests ON DELETE NO ACTION,
  68. message TEXT NOT NULL
  69. );