log.schema 2.9 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788
  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 referer (
  20. id INTEGER PRIMARY KEY AUTOINCREMENT,
  21. referer TEXT NOT NULL UNIQUE
  22. );
  23. CREATE TABLE IF NOT EXISTS requests (
  24. uuid TEXT PRIMARY KEY,
  25. date TEXT NOT NULL,
  26. host_id INTEGER NOT NULL REFERENCES seen_hosts(id) ON DELETE CASCADE,
  27. user_id INTEGER NOT NULL REFERENCES seen_users(id) ON DELETE CASCADE,
  28. route_id INTEGER NOT NULL REFERENCES seen_routes(id) ON DELETE CASCADE,
  29. referer_id INTEGER NOT NULL REFERENCES referer(id) ON DELETE CASCADE,
  30. response_code_id INTEGER NOT NULL REFERENCES response_code(id) ON DELETE RESTRICT
  31. );
  32. CREATE VIEW IF NOT EXISTS all_requests AS
  33. SELECT
  34. q.uuid,
  35. q.date,
  36. h.ip_address,
  37. u.user,
  38. r.method,
  39. r.route,
  40. f.referer,
  41. c.code
  42. FROM
  43. requests AS q
  44. JOIN
  45. seen_hosts AS h ON q.host_id = h.id
  46. JOIN
  47. seen_users AS u ON q.user_id = u.id
  48. JOIN
  49. seen_routes AS r ON q.route_id = r.id
  50. JOIN
  51. referer AS f ON q.referer_id = f.id
  52. JOIN
  53. response_code AS c on q.response_code_id = c.id;
  54. /* Make all_requests a writable view via triggers. We will always stomp the main row, as the last update will be what we want. */
  55. CREATE TRIGGER IF NOT EXISTS insert_all_requests INSTEAD OF INSERT ON all_requests BEGIN
  56. INSERT OR IGNORE INTO response_code (code) VALUES (NEW.code);
  57. INSERT OR IGNORE INTO seen_routes (route,method) VALUES (NEW.route, NEW.method);
  58. INSERT OR IGNORE INTO seen_users (user) VALUES (NEW.user);
  59. INSERT OR IGNORE INTO seen_hosts (ip_address) VALUES (NEW.ip_address);
  60. INSERT OR IGNORE INTO referer (referer) VALUES (NEW.referer);
  61. INSERT OR REPLACE INTO requests SELECT
  62. NEW.uuid,
  63. NEW.date,
  64. h.id AS host_id,
  65. u.id AS user_id,
  66. r.id AS route_id,
  67. f.id AS referer_id,
  68. c.id AS response_code_id
  69. FROM seen_hosts AS h
  70. JOIN seen_users AS u ON u.user = NEW.user
  71. JOIN seen_routes AS r ON r.route = NEW.route AND r.method = NEW.method
  72. JOIN referer AS f ON f.referer = NEW.referer
  73. JOIN response_code AS c ON c.code = NEW.code
  74. WHERE h.ip_address = NEW.ip_address;
  75. END;
  76. /* This is just to store various messages associated with requests, which are usually errors. */
  77. CREATE TABLE IF NOT EXISTS messages (
  78. uuid TEXT NOT NULL REFERENCES requests ON DELETE NO ACTION,
  79. message TEXT NOT NULL
  80. );