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 "impersonator_id" INTEGER REFERENCES users (id),
23 "hash" VARCHAR(128)
24);
25CREATE INDEX "index_access_tokens_user_id" ON "access_tokens" ("user_id");
26CREATE INDEX "index_access_tokens_impersonator_id" ON "access_tokens" ("impersonator_id");
27
28CREATE TABLE "contacts" (
29 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
30 "user_id_a" INTEGER REFERENCES users (id) NOT NULL,
31 "user_id_b" INTEGER REFERENCES users (id) NOT NULL,
32 "a_to_b" BOOLEAN NOT NULL,
33 "should_notify" BOOLEAN NOT NULL,
34 "accepted" BOOLEAN NOT NULL
35);
36CREATE UNIQUE INDEX "index_contacts_user_ids" ON "contacts" ("user_id_a", "user_id_b");
37CREATE INDEX "index_contacts_user_id_b" ON "contacts" ("user_id_b");
38
39CREATE TABLE "rooms" (
40 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
41 "live_kit_room" VARCHAR NOT NULL,
42 "environment" VARCHAR,
43 "channel_id" INTEGER REFERENCES channels (id) ON DELETE CASCADE
44);
45CREATE UNIQUE INDEX "index_rooms_on_channel_id" ON "rooms" ("channel_id");
46
47CREATE TABLE "projects" (
48 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
49 "room_id" INTEGER REFERENCES rooms (id) ON DELETE CASCADE NOT NULL,
50 "host_user_id" INTEGER REFERENCES users (id) NOT NULL,
51 "host_connection_id" INTEGER,
52 "host_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
53 "unregistered" BOOLEAN NOT NULL DEFAULT FALSE
54);
55CREATE INDEX "index_projects_on_host_connection_server_id" ON "projects" ("host_connection_server_id");
56CREATE INDEX "index_projects_on_host_connection_id_and_host_connection_server_id" ON "projects" ("host_connection_id", "host_connection_server_id");
57
58CREATE TABLE "worktrees" (
59 "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
60 "id" INTEGER NOT NULL,
61 "root_name" VARCHAR NOT NULL,
62 "abs_path" VARCHAR NOT NULL,
63 "visible" BOOL NOT NULL,
64 "scan_id" INTEGER NOT NULL,
65 "is_complete" BOOL NOT NULL DEFAULT FALSE,
66 "completed_scan_id" INTEGER NOT NULL,
67 PRIMARY KEY(project_id, id)
68);
69CREATE INDEX "index_worktrees_on_project_id" ON "worktrees" ("project_id");
70
71CREATE TABLE "worktree_entries" (
72 "project_id" INTEGER NOT NULL,
73 "worktree_id" INTEGER NOT NULL,
74 "scan_id" INTEGER NOT NULL,
75 "id" INTEGER NOT NULL,
76 "is_dir" BOOL NOT NULL,
77 "path" VARCHAR NOT NULL,
78 "inode" INTEGER NOT NULL,
79 "mtime_seconds" INTEGER NOT NULL,
80 "mtime_nanos" INTEGER NOT NULL,
81 "is_symlink" BOOL NOT NULL,
82 "is_external" BOOL NOT NULL,
83 "is_ignored" BOOL NOT NULL,
84 "is_deleted" BOOL NOT NULL,
85 "git_status" INTEGER,
86 PRIMARY KEY(project_id, worktree_id, id),
87 FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
88);
89CREATE INDEX "index_worktree_entries_on_project_id" ON "worktree_entries" ("project_id");
90CREATE INDEX "index_worktree_entries_on_project_id_and_worktree_id" ON "worktree_entries" ("project_id", "worktree_id");
91
92CREATE TABLE "worktree_repositories" (
93 "project_id" INTEGER NOT NULL,
94 "worktree_id" INTEGER NOT NULL,
95 "work_directory_id" INTEGER NOT NULL,
96 "branch" VARCHAR,
97 "scan_id" INTEGER NOT NULL,
98 "is_deleted" BOOL NOT NULL,
99 PRIMARY KEY(project_id, worktree_id, work_directory_id),
100 FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE,
101 FOREIGN KEY(project_id, worktree_id, work_directory_id) REFERENCES worktree_entries (project_id, worktree_id, id) ON DELETE CASCADE
102);
103CREATE INDEX "index_worktree_repositories_on_project_id" ON "worktree_repositories" ("project_id");
104CREATE INDEX "index_worktree_repositories_on_project_id_and_worktree_id" ON "worktree_repositories" ("project_id", "worktree_id");
105
106CREATE TABLE "worktree_settings_files" (
107 "project_id" INTEGER NOT NULL,
108 "worktree_id" INTEGER NOT NULL,
109 "path" VARCHAR NOT NULL,
110 "content" TEXT,
111 PRIMARY KEY(project_id, worktree_id, path),
112 FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
113);
114CREATE INDEX "index_worktree_settings_files_on_project_id" ON "worktree_settings_files" ("project_id");
115CREATE INDEX "index_worktree_settings_files_on_project_id_and_worktree_id" ON "worktree_settings_files" ("project_id", "worktree_id");
116
117CREATE TABLE "worktree_diagnostic_summaries" (
118 "project_id" INTEGER NOT NULL,
119 "worktree_id" INTEGER NOT NULL,
120 "path" VARCHAR NOT NULL,
121 "language_server_id" INTEGER NOT NULL,
122 "error_count" INTEGER NOT NULL,
123 "warning_count" INTEGER NOT NULL,
124 PRIMARY KEY(project_id, worktree_id, path),
125 FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
126);
127CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id" ON "worktree_diagnostic_summaries" ("project_id");
128CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id_and_worktree_id" ON "worktree_diagnostic_summaries" ("project_id", "worktree_id");
129
130CREATE TABLE "language_servers" (
131 "id" INTEGER NOT NULL,
132 "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
133 "name" VARCHAR NOT NULL,
134 PRIMARY KEY(project_id, id)
135);
136CREATE INDEX "index_language_servers_on_project_id" ON "language_servers" ("project_id");
137
138CREATE TABLE "project_collaborators" (
139 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
140 "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
141 "connection_id" INTEGER NOT NULL,
142 "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
143 "user_id" INTEGER NOT NULL,
144 "replica_id" INTEGER NOT NULL,
145 "is_host" BOOLEAN NOT NULL
146);
147CREATE INDEX "index_project_collaborators_on_project_id" ON "project_collaborators" ("project_id");
148CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_and_replica_id" ON "project_collaborators" ("project_id", "replica_id");
149CREATE INDEX "index_project_collaborators_on_connection_server_id" ON "project_collaborators" ("connection_server_id");
150CREATE INDEX "index_project_collaborators_on_connection_id" ON "project_collaborators" ("connection_id");
151CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_connection_id_and_server_id" ON "project_collaborators" ("project_id", "connection_id", "connection_server_id");
152
153CREATE TABLE "room_participants" (
154 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
155 "room_id" INTEGER NOT NULL REFERENCES rooms (id),
156 "user_id" INTEGER NOT NULL REFERENCES users (id),
157 "answering_connection_id" INTEGER,
158 "answering_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
159 "answering_connection_lost" BOOLEAN NOT NULL,
160 "location_kind" INTEGER,
161 "location_project_id" INTEGER,
162 "initial_project_id" INTEGER,
163 "calling_user_id" INTEGER NOT NULL REFERENCES users (id),
164 "calling_connection_id" INTEGER NOT NULL,
165 "calling_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE SET NULL,
166 "participant_index" INTEGER,
167 "role" TEXT
168);
169CREATE UNIQUE INDEX "index_room_participants_on_user_id" ON "room_participants" ("user_id");
170CREATE INDEX "index_room_participants_on_room_id" ON "room_participants" ("room_id");
171CREATE INDEX "index_room_participants_on_answering_connection_server_id" ON "room_participants" ("answering_connection_server_id");
172CREATE INDEX "index_room_participants_on_calling_connection_server_id" ON "room_participants" ("calling_connection_server_id");
173CREATE INDEX "index_room_participants_on_answering_connection_id" ON "room_participants" ("answering_connection_id");
174CREATE UNIQUE INDEX "index_room_participants_on_answering_connection_id_and_answering_connection_server_id" ON "room_participants" ("answering_connection_id", "answering_connection_server_id");
175
176CREATE TABLE "servers" (
177 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
178 "environment" VARCHAR NOT NULL
179);
180
181CREATE TABLE "followers" (
182 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
183 "room_id" INTEGER NOT NULL REFERENCES rooms (id) ON DELETE CASCADE,
184 "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
185 "leader_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
186 "leader_connection_id" INTEGER NOT NULL,
187 "follower_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
188 "follower_connection_id" INTEGER NOT NULL
189);
190CREATE UNIQUE INDEX
191 "index_followers_on_project_id_and_leader_connection_server_id_and_leader_connection_id_and_follower_connection_server_id_and_follower_connection_id"
192ON "followers" ("project_id", "leader_connection_server_id", "leader_connection_id", "follower_connection_server_id", "follower_connection_id");
193CREATE INDEX "index_followers_on_room_id" ON "followers" ("room_id");
194
195CREATE TABLE "channels" (
196 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
197 "name" VARCHAR NOT NULL,
198 "created_at" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
199 "visibility" VARCHAR NOT NULL,
200 "parent_path" TEXT
201);
202
203CREATE INDEX "index_channels_on_parent_path" ON "channels" ("parent_path");
204
205CREATE TABLE IF NOT EXISTS "channel_chat_participants" (
206 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
207 "user_id" INTEGER NOT NULL REFERENCES users (id),
208 "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
209 "connection_id" INTEGER NOT NULL,
210 "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE
211);
212CREATE INDEX "index_channel_chat_participants_on_channel_id" ON "channel_chat_participants" ("channel_id");
213
214CREATE TABLE IF NOT EXISTS "channel_messages" (
215 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
216 "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
217 "sender_id" INTEGER NOT NULL REFERENCES users (id),
218 "body" TEXT NOT NULL,
219 "sent_at" TIMESTAMP,
220 "nonce" BLOB NOT NULL
221);
222CREATE INDEX "index_channel_messages_on_channel_id" ON "channel_messages" ("channel_id");
223CREATE UNIQUE INDEX "index_channel_messages_on_sender_id_nonce" ON "channel_messages" ("sender_id", "nonce");
224
225CREATE TABLE "channel_message_mentions" (
226 "message_id" INTEGER NOT NULL REFERENCES channel_messages (id) ON DELETE CASCADE,
227 "start_offset" INTEGER NOT NULL,
228 "end_offset" INTEGER NOT NULL,
229 "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
230 PRIMARY KEY(message_id, start_offset)
231);
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");