20221109000000_test_schema.sql

  1CREATE TABLE "users" (
  2    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
  3    "github_login" VARCHAR,
  4    "admin" BOOLEAN,
  5    "email_address" VARCHAR(255) DEFAULT NULL,
  6    "invite_code" VARCHAR(64),
  7    "invite_count" INTEGER NOT NULL DEFAULT 0,
  8    "inviter_id" INTEGER REFERENCES users (id),
  9    "connected_once" BOOLEAN NOT NULL DEFAULT false,
 10    "created_at" TIMESTAMP NOT NULL DEFAULT now,
 11    "metrics_id" TEXT,
 12    "github_user_id" INTEGER
 13);
 14CREATE UNIQUE INDEX "index_users_github_login" ON "users" ("github_login");
 15CREATE UNIQUE INDEX "index_invite_code_users" ON "users" ("invite_code");
 16CREATE INDEX "index_users_on_email_address" ON "users" ("email_address");
 17CREATE INDEX "index_users_on_github_user_id" ON "users" ("github_user_id");
 18
 19CREATE TABLE "access_tokens" (
 20    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 21    "user_id" INTEGER REFERENCES users (id),
 22    "hash" VARCHAR(128)
 23);
 24CREATE INDEX "index_access_tokens_user_id" ON "access_tokens" ("user_id");
 25
 26CREATE TABLE "contacts" (
 27    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 28    "user_id_a" INTEGER REFERENCES users (id) NOT NULL,
 29    "user_id_b" INTEGER REFERENCES users (id) NOT NULL,
 30    "a_to_b" BOOLEAN NOT NULL,
 31    "should_notify" BOOLEAN NOT NULL,
 32    "accepted" BOOLEAN NOT NULL
 33);
 34CREATE UNIQUE INDEX "index_contacts_user_ids" ON "contacts" ("user_id_a", "user_id_b");
 35CREATE INDEX "index_contacts_user_id_b" ON "contacts" ("user_id_b");
 36
 37CREATE TABLE "rooms" (
 38    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 39    "live_kit_room" VARCHAR NOT NULL,
 40    "enviroment" VARCHAR,
 41    "channel_id" INTEGER REFERENCES channels (id) ON DELETE CASCADE
 42);
 43CREATE UNIQUE INDEX "index_rooms_on_channel_id" ON "rooms" ("channel_id");
 44
 45CREATE TABLE "projects" (
 46    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 47    "room_id" INTEGER REFERENCES rooms (id) ON DELETE CASCADE NOT NULL,
 48    "host_user_id" INTEGER REFERENCES users (id) NOT NULL,
 49    "host_connection_id" INTEGER,
 50    "host_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
 51    "unregistered" BOOLEAN NOT NULL DEFAULT FALSE
 52);
 53CREATE INDEX "index_projects_on_host_connection_server_id" ON "projects" ("host_connection_server_id");
 54CREATE INDEX "index_projects_on_host_connection_id_and_host_connection_server_id" ON "projects" ("host_connection_id", "host_connection_server_id");
 55
 56CREATE TABLE "worktrees" (
 57    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
 58    "id" INTEGER NOT NULL,
 59    "root_name" VARCHAR NOT NULL,
 60    "abs_path" VARCHAR NOT NULL,
 61    "visible" BOOL NOT NULL,
 62    "scan_id" INTEGER NOT NULL,
 63    "is_complete" BOOL NOT NULL DEFAULT FALSE,
 64    "completed_scan_id" INTEGER NOT NULL,
 65    PRIMARY KEY(project_id, id)
 66);
 67CREATE INDEX "index_worktrees_on_project_id" ON "worktrees" ("project_id");
 68
 69CREATE TABLE "worktree_entries" (
 70    "project_id" INTEGER NOT NULL,
 71    "worktree_id" INTEGER NOT NULL,
 72    "scan_id" INTEGER NOT NULL,
 73    "id" INTEGER NOT NULL,
 74    "is_dir" BOOL NOT NULL,
 75    "path" VARCHAR NOT NULL,
 76    "inode" INTEGER NOT NULL,
 77    "mtime_seconds" INTEGER NOT NULL,
 78    "mtime_nanos" INTEGER NOT NULL,
 79    "is_symlink" BOOL NOT NULL,
 80    "is_external" BOOL NOT NULL,
 81    "is_ignored" BOOL NOT NULL,
 82    "is_deleted" BOOL NOT NULL,
 83    "git_status" INTEGER,
 84    PRIMARY KEY(project_id, worktree_id, id),
 85    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
 86);
 87CREATE INDEX "index_worktree_entries_on_project_id" ON "worktree_entries" ("project_id");
 88CREATE INDEX "index_worktree_entries_on_project_id_and_worktree_id" ON "worktree_entries" ("project_id", "worktree_id");
 89
 90CREATE TABLE "worktree_repositories" (
 91    "project_id" INTEGER NOT NULL,
 92    "worktree_id" INTEGER NOT NULL,
 93    "work_directory_id" INTEGER NOT NULL,
 94    "branch" VARCHAR,
 95    "scan_id" INTEGER NOT NULL,
 96    "is_deleted" BOOL NOT NULL,
 97    PRIMARY KEY(project_id, worktree_id, work_directory_id),
 98    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE,
 99    FOREIGN KEY(project_id, worktree_id, work_directory_id) REFERENCES worktree_entries (project_id, worktree_id, id) ON DELETE CASCADE
100);
101CREATE INDEX "index_worktree_repositories_on_project_id" ON "worktree_repositories" ("project_id");
102CREATE INDEX "index_worktree_repositories_on_project_id_and_worktree_id" ON "worktree_repositories" ("project_id", "worktree_id");
103
104CREATE TABLE "worktree_settings_files" (
105    "project_id" INTEGER NOT NULL,
106    "worktree_id" INTEGER NOT NULL,
107    "path" VARCHAR NOT NULL,
108    "content" TEXT,
109    PRIMARY KEY(project_id, worktree_id, path),
110    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
111);
112CREATE INDEX "index_worktree_settings_files_on_project_id" ON "worktree_settings_files" ("project_id");
113CREATE INDEX "index_worktree_settings_files_on_project_id_and_worktree_id" ON "worktree_settings_files" ("project_id", "worktree_id");
114
115CREATE TABLE "worktree_diagnostic_summaries" (
116    "project_id" INTEGER NOT NULL,
117    "worktree_id" INTEGER NOT NULL,
118    "path" VARCHAR NOT NULL,
119    "language_server_id" INTEGER NOT NULL,
120    "error_count" INTEGER NOT NULL,
121    "warning_count" INTEGER NOT NULL,
122    PRIMARY KEY(project_id, worktree_id, path),
123    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
124);
125CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id" ON "worktree_diagnostic_summaries" ("project_id");
126CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id_and_worktree_id" ON "worktree_diagnostic_summaries" ("project_id", "worktree_id");
127
128CREATE TABLE "language_servers" (
129    "id" INTEGER NOT NULL,
130    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
131    "name" VARCHAR NOT NULL,
132    PRIMARY KEY(project_id, id)
133);
134CREATE INDEX "index_language_servers_on_project_id" ON "language_servers" ("project_id");
135
136CREATE TABLE "project_collaborators" (
137    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
138    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
139    "connection_id" INTEGER NOT NULL,
140    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
141    "user_id" INTEGER NOT NULL,
142    "replica_id" INTEGER NOT NULL,
143    "is_host" BOOLEAN NOT NULL
144);
145CREATE INDEX "index_project_collaborators_on_project_id" ON "project_collaborators" ("project_id");
146CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_and_replica_id" ON "project_collaborators" ("project_id", "replica_id");
147CREATE INDEX "index_project_collaborators_on_connection_server_id" ON "project_collaborators" ("connection_server_id");
148CREATE INDEX "index_project_collaborators_on_connection_id" ON "project_collaborators" ("connection_id");
149CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_connection_id_and_server_id" ON "project_collaborators" ("project_id", "connection_id", "connection_server_id");
150
151CREATE TABLE "room_participants" (
152    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
153    "room_id" INTEGER NOT NULL REFERENCES rooms (id),
154    "user_id" INTEGER NOT NULL REFERENCES users (id),
155    "answering_connection_id" INTEGER,
156    "answering_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
157    "answering_connection_lost" BOOLEAN NOT NULL,
158    "location_kind" INTEGER,
159    "location_project_id" INTEGER,
160    "initial_project_id" INTEGER,
161    "calling_user_id" INTEGER NOT NULL REFERENCES users (id),
162    "calling_connection_id" INTEGER NOT NULL,
163    "calling_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE SET NULL,
164    "participant_index" INTEGER
165);
166CREATE UNIQUE INDEX "index_room_participants_on_user_id" ON "room_participants" ("user_id");
167CREATE INDEX "index_room_participants_on_room_id" ON "room_participants" ("room_id");
168CREATE INDEX "index_room_participants_on_answering_connection_server_id" ON "room_participants" ("answering_connection_server_id");
169CREATE INDEX "index_room_participants_on_calling_connection_server_id" ON "room_participants" ("calling_connection_server_id");
170CREATE INDEX "index_room_participants_on_answering_connection_id" ON "room_participants" ("answering_connection_id");
171CREATE UNIQUE INDEX "index_room_participants_on_answering_connection_id_and_answering_connection_server_id" ON "room_participants" ("answering_connection_id", "answering_connection_server_id");
172
173CREATE TABLE "servers" (
174    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
175    "environment" VARCHAR NOT NULL
176);
177
178CREATE TABLE "followers" (
179    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
180    "room_id" INTEGER NOT NULL REFERENCES rooms (id) ON DELETE CASCADE,
181    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
182    "leader_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
183    "leader_connection_id" INTEGER NOT NULL,
184    "follower_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
185    "follower_connection_id" INTEGER NOT NULL
186);
187CREATE UNIQUE INDEX
188    "index_followers_on_project_id_and_leader_connection_server_id_and_leader_connection_id_and_follower_connection_server_id_and_follower_connection_id"
189ON "followers" ("project_id", "leader_connection_server_id", "leader_connection_id", "follower_connection_server_id", "follower_connection_id");
190CREATE INDEX "index_followers_on_room_id" ON "followers" ("room_id");
191
192CREATE TABLE "channels" (
193    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
194    "name" VARCHAR NOT NULL,
195    "created_at" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
196    "visibility" VARCHAR NOT NULL
197);
198
199CREATE TABLE IF NOT EXISTS "channel_chat_participants" (
200    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
201    "user_id" INTEGER NOT NULL REFERENCES users (id),
202    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
203    "connection_id" INTEGER NOT NULL,
204    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE
205);
206CREATE INDEX "index_channel_chat_participants_on_channel_id" ON "channel_chat_participants" ("channel_id");
207
208CREATE TABLE IF NOT EXISTS "channel_messages" (
209    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
210    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
211    "sender_id" INTEGER NOT NULL REFERENCES users (id),
212    "body" TEXT NOT NULL,
213    "sent_at" TIMESTAMP,
214    "nonce" BLOB NOT NULL
215);
216CREATE INDEX "index_channel_messages_on_channel_id" ON "channel_messages" ("channel_id");
217CREATE UNIQUE INDEX "index_channel_messages_on_sender_id_nonce" ON "channel_messages" ("sender_id", "nonce");
218
219CREATE TABLE "channel_message_mentions" (
220    "message_id" INTEGER NOT NULL REFERENCES channel_messages (id) ON DELETE CASCADE,
221    "start_offset" INTEGER NOT NULL,
222    "end_offset" INTEGER NOT NULL,
223    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
224    PRIMARY KEY(message_id, start_offset)
225);
226
227CREATE TABLE "channel_paths" (
228    "id_path" TEXT NOT NULL PRIMARY KEY,
229    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE
230);
231CREATE INDEX "index_channel_paths_on_channel_id" ON "channel_paths" ("channel_id");
232
233CREATE TABLE "channel_members" (
234    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
235    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
236    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
237    "admin" BOOLEAN NOT NULL DEFAULT false,
238    "role" VARCHAR,
239    "accepted" BOOLEAN NOT NULL DEFAULT false,
240    "updated_at" TIMESTAMP NOT NULL DEFAULT now
241);
242
243CREATE UNIQUE INDEX "index_channel_members_on_channel_id_and_user_id" ON "channel_members" ("channel_id", "user_id");
244
245CREATE TABLE "buffers" (
246    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
247    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
248    "epoch" INTEGER NOT NULL DEFAULT 0
249);
250
251CREATE INDEX "index_buffers_on_channel_id" ON "buffers" ("channel_id");
252
253CREATE TABLE "buffer_operations" (
254    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
255    "epoch" INTEGER NOT NULL,
256    "replica_id" INTEGER NOT NULL,
257    "lamport_timestamp" INTEGER NOT NULL,
258    "value" BLOB NOT NULL,
259    PRIMARY KEY(buffer_id, epoch, lamport_timestamp, replica_id)
260);
261
262CREATE TABLE "buffer_snapshots" (
263    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
264    "epoch" INTEGER NOT NULL,
265    "text" TEXT NOT NULL,
266    "operation_serialization_version" INTEGER NOT NULL,
267    PRIMARY KEY(buffer_id, epoch)
268);
269
270CREATE TABLE "channel_buffer_collaborators" (
271    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
272    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
273    "connection_id" INTEGER NOT NULL,
274    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
275    "connection_lost" BOOLEAN NOT NULL DEFAULT false,
276    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
277    "replica_id" INTEGER NOT NULL
278);
279
280CREATE INDEX "index_channel_buffer_collaborators_on_channel_id" ON "channel_buffer_collaborators" ("channel_id");
281CREATE UNIQUE INDEX "index_channel_buffer_collaborators_on_channel_id_and_replica_id" ON "channel_buffer_collaborators" ("channel_id", "replica_id");
282CREATE INDEX "index_channel_buffer_collaborators_on_connection_server_id" ON "channel_buffer_collaborators" ("connection_server_id");
283CREATE INDEX "index_channel_buffer_collaborators_on_connection_id" ON "channel_buffer_collaborators" ("connection_id");
284CREATE UNIQUE INDEX "index_channel_buffer_collaborators_on_channel_id_connection_id_and_server_id" ON "channel_buffer_collaborators" ("channel_id", "connection_id", "connection_server_id");
285
286
287CREATE TABLE "feature_flags" (
288    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
289    "flag" TEXT NOT NULL UNIQUE
290);
291
292CREATE INDEX "index_feature_flags" ON "feature_flags" ("id");
293
294
295CREATE TABLE "user_features" (
296    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
297    "feature_id" INTEGER NOT NULL REFERENCES feature_flags (id) ON DELETE CASCADE,
298    PRIMARY KEY (user_id, feature_id)
299);
300
301CREATE UNIQUE INDEX "index_user_features_user_id_and_feature_id" ON "user_features" ("user_id", "feature_id");
302CREATE INDEX "index_user_features_on_user_id" ON "user_features" ("user_id");
303CREATE INDEX "index_user_features_on_feature_id" ON "user_features" ("feature_id");
304
305
306CREATE TABLE "observed_buffer_edits" (
307    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
308    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
309    "epoch" INTEGER NOT NULL,
310    "lamport_timestamp" INTEGER NOT NULL,
311    "replica_id" INTEGER NOT NULL,
312    PRIMARY KEY (user_id, buffer_id)
313);
314
315CREATE UNIQUE INDEX "index_observed_buffers_user_and_buffer_id" ON "observed_buffer_edits" ("user_id", "buffer_id");
316
317CREATE TABLE IF NOT EXISTS "observed_channel_messages" (
318    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
319    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
320    "channel_message_id" INTEGER NOT NULL,
321    PRIMARY KEY (user_id, channel_id)
322);
323
324CREATE UNIQUE INDEX "index_observed_channel_messages_user_and_channel_id" ON "observed_channel_messages" ("user_id", "channel_id");
325
326CREATE TABLE "notification_kinds" (
327    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
328    "name" VARCHAR NOT NULL
329);
330
331CREATE UNIQUE INDEX "index_notification_kinds_on_name" ON "notification_kinds" ("name");
332
333CREATE TABLE "notifications" (
334    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
335    "created_at" TIMESTAMP NOT NULL default CURRENT_TIMESTAMP,
336    "recipient_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
337    "kind" INTEGER NOT NULL REFERENCES notification_kinds (id),
338    "entity_id" INTEGER,
339    "content" TEXT,
340    "is_read" BOOLEAN NOT NULL DEFAULT FALSE,
341    "response" BOOLEAN
342);
343
344CREATE INDEX
345    "index_notifications_on_recipient_id_is_read_kind_entity_id"
346    ON "notifications"
347    ("recipient_id", "is_read", "kind", "entity_id");