00-latest-revision.sql 5.5 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182
  1. -- v0 -> v49: Latest revision
  2. CREATE TABLE "user" (
  3. mxid TEXT PRIMARY KEY,
  4. username TEXT UNIQUE,
  5. agent SMALLINT,
  6. device SMALLINT,
  7. management_room TEXT,
  8. space_room TEXT,
  9. phone_last_seen BIGINT,
  10. phone_last_pinged BIGINT,
  11. timezone TEXT
  12. );
  13. CREATE TABLE portal (
  14. jid TEXT,
  15. receiver TEXT,
  16. mxid TEXT UNIQUE,
  17. name TEXT NOT NULL,
  18. topic TEXT NOT NULL,
  19. avatar TEXT NOT NULL,
  20. avatar_url TEXT,
  21. encrypted BOOLEAN NOT NULL DEFAULT false,
  22. first_event_id TEXT,
  23. next_batch_id TEXT,
  24. relay_user_id TEXT,
  25. expiration_time BIGINT NOT NULL DEFAULT 0 CHECK (expiration_time >= 0 AND expiration_time < 4294967296),
  26. PRIMARY KEY (jid, receiver)
  27. );
  28. CREATE TABLE puppet (
  29. username TEXT PRIMARY KEY,
  30. displayname TEXT,
  31. name_quality SMALLINT,
  32. avatar TEXT,
  33. avatar_url TEXT,
  34. custom_mxid TEXT,
  35. access_token TEXT,
  36. next_batch TEXT,
  37. enable_presence BOOLEAN NOT NULL DEFAULT true,
  38. enable_receipts BOOLEAN NOT NULL DEFAULT true
  39. );
  40. -- only: postgres
  41. CREATE TYPE error_type AS ENUM ('', 'decryption_failed', 'media_not_found');
  42. CREATE TABLE message (
  43. chat_jid TEXT,
  44. chat_receiver TEXT,
  45. jid TEXT,
  46. mxid TEXT UNIQUE,
  47. sender TEXT,
  48. timestamp BIGINT,
  49. sent BOOLEAN,
  50. error error_type,
  51. type TEXT,
  52. broadcast_list_jid TEXT,
  53. PRIMARY KEY (chat_jid, chat_receiver, jid),
  54. FOREIGN KEY (chat_jid, chat_receiver) REFERENCES portal(jid, receiver) ON DELETE CASCADE
  55. );
  56. CREATE TABLE reaction (
  57. chat_jid TEXT,
  58. chat_receiver TEXT,
  59. target_jid TEXT,
  60. sender TEXT,
  61. mxid TEXT NOT NULL,
  62. jid TEXT NOT NULL,
  63. PRIMARY KEY (chat_jid, chat_receiver, target_jid, sender),
  64. FOREIGN KEY (chat_jid, chat_receiver, target_jid) REFERENCES message(chat_jid, chat_receiver, jid)
  65. ON DELETE CASCADE ON UPDATE CASCADE
  66. );
  67. CREATE TABLE disappearing_message (
  68. room_id TEXT,
  69. event_id TEXT,
  70. expire_in BIGINT NOT NULL,
  71. expire_at BIGINT,
  72. PRIMARY KEY (room_id, event_id)
  73. );
  74. CREATE TABLE user_portal (
  75. user_mxid TEXT,
  76. portal_jid TEXT,
  77. portal_receiver TEXT,
  78. last_read_ts BIGINT NOT NULL DEFAULT 0,
  79. in_space BOOLEAN NOT NULL DEFAULT false,
  80. PRIMARY KEY (user_mxid, portal_jid, portal_receiver),
  81. FOREIGN KEY (user_mxid) REFERENCES "user"(mxid) ON UPDATE CASCADE ON DELETE CASCADE,
  82. FOREIGN KEY (portal_jid, portal_receiver) REFERENCES portal(jid, receiver) ON UPDATE CASCADE ON DELETE CASCADE
  83. );
  84. CREATE TABLE backfill_queue (
  85. queue_id INTEGER PRIMARY KEY
  86. -- only: postgres
  87. GENERATED ALWAYS AS IDENTITY
  88. ,
  89. user_mxid TEXT,
  90. type INTEGER NOT NULL,
  91. priority INTEGER NOT NULL,
  92. portal_jid TEXT,
  93. portal_receiver TEXT,
  94. time_start TIMESTAMP,
  95. dispatch_time TIMESTAMP,
  96. completed_at TIMESTAMP,
  97. batch_delay INTEGER,
  98. max_batch_events INTEGER NOT NULL,
  99. max_total_events INTEGER,
  100. FOREIGN KEY (user_mxid) REFERENCES "user" (mxid) ON DELETE CASCADE ON UPDATE CASCADE,
  101. FOREIGN KEY (portal_jid, portal_receiver) REFERENCES portal(jid, receiver) ON DELETE CASCADE
  102. );
  103. CREATE TABLE backfill_state (
  104. user_mxid TEXT,
  105. portal_jid TEXT,
  106. portal_receiver TEXT,
  107. processing_batch BOOLEAN,
  108. backfill_complete BOOLEAN,
  109. first_expected_ts BIGINT,
  110. PRIMARY KEY (user_mxid, portal_jid, portal_receiver),
  111. FOREIGN KEY (user_mxid) REFERENCES "user" (mxid) ON DELETE CASCADE ON UPDATE CASCADE,
  112. FOREIGN KEY (portal_jid, portal_receiver) REFERENCES portal (jid, receiver) ON DELETE CASCADE
  113. );
  114. CREATE TABLE media_backfill_requests (
  115. user_mxid TEXT,
  116. portal_jid TEXT,
  117. portal_receiver TEXT,
  118. event_id TEXT,
  119. media_key bytea,
  120. status INTEGER,
  121. error TEXT,
  122. PRIMARY KEY (user_mxid, portal_jid, portal_receiver, event_id),
  123. FOREIGN KEY (user_mxid) REFERENCES "user"(mxid) ON UPDATE CASCADE ON DELETE CASCADE,
  124. FOREIGN KEY (portal_jid, portal_receiver) REFERENCES portal(jid, receiver) ON UPDATE CASCADE ON DELETE CASCADE
  125. );
  126. CREATE TABLE history_sync_conversation (
  127. user_mxid TEXT,
  128. conversation_id TEXT,
  129. portal_jid TEXT,
  130. portal_receiver TEXT,
  131. last_message_timestamp TIMESTAMP,
  132. archived BOOLEAN,
  133. pinned INTEGER,
  134. mute_end_time TIMESTAMP,
  135. disappearing_mode INTEGER,
  136. end_of_history_transfer_type INTEGER,
  137. ephemeral_Expiration INTEGER,
  138. marked_as_unread BOOLEAN,
  139. unread_count INTEGER,
  140. PRIMARY KEY (user_mxid, conversation_id),
  141. FOREIGN KEY (user_mxid) REFERENCES "user"(mxid) ON UPDATE CASCADE ON DELETE CASCADE,
  142. FOREIGN KEY (portal_jid, portal_receiver) REFERENCES portal(jid, receiver) ON UPDATE CASCADE ON DELETE CASCADE
  143. );
  144. CREATE TABLE history_sync_message (
  145. user_mxid TEXT,
  146. conversation_id TEXT,
  147. message_id TEXT,
  148. timestamp TIMESTAMP,
  149. data bytea,
  150. inserted_time TIMESTAMP,
  151. PRIMARY KEY (user_mxid, conversation_id, message_id),
  152. FOREIGN KEY (user_mxid) REFERENCES "user"(mxid) ON UPDATE CASCADE ON DELETE CASCADE,
  153. FOREIGN KEY (user_mxid, conversation_id) REFERENCES history_sync_conversation(user_mxid, conversation_id) ON DELETE CASCADE
  154. );