log.schema 2.4 KB

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