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 CURRENT_TIMESTAMP,
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 "impersonated_user_id" INTEGER REFERENCES users (id),
23 "hash" VARCHAR(128)
24);
25CREATE INDEX "index_access_tokens_user_id" ON "access_tokens" ("user_id");
26
27CREATE TABLE "contacts" (
28 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
29 "user_id_a" INTEGER REFERENCES users (id) NOT NULL,
30 "user_id_b" INTEGER REFERENCES users (id) NOT NULL,
31 "a_to_b" BOOLEAN NOT NULL,
32 "should_notify" BOOLEAN NOT NULL,
33 "accepted" BOOLEAN NOT NULL
34);
35CREATE UNIQUE INDEX "index_contacts_user_ids" ON "contacts" ("user_id_a", "user_id_b");
36CREATE INDEX "index_contacts_user_id_b" ON "contacts" ("user_id_b");
37
38CREATE TABLE "rooms" (
39 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
40 "live_kit_room" VARCHAR NOT NULL,
41 "environment" VARCHAR,
42 "channel_id" INTEGER REFERENCES channels (id) ON DELETE CASCADE
43);
44CREATE UNIQUE INDEX "index_rooms_on_channel_id" ON "rooms" ("channel_id");
45
46CREATE TABLE "projects" (
47 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
48 "room_id" INTEGER REFERENCES rooms (id) ON DELETE CASCADE NOT NULL,
49 "host_user_id" INTEGER REFERENCES users (id) NOT NULL,
50 "host_connection_id" INTEGER,
51 "host_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
52 "unregistered" BOOLEAN NOT NULL DEFAULT FALSE
53);
54CREATE INDEX "index_projects_on_host_connection_server_id" ON "projects" ("host_connection_server_id");
55CREATE INDEX "index_projects_on_host_connection_id_and_host_connection_server_id" ON "projects" ("host_connection_id", "host_connection_server_id");
56
57CREATE TABLE "worktrees" (
58 "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
59 "id" INTEGER NOT NULL,
60 "root_name" VARCHAR NOT NULL,
61 "abs_path" VARCHAR NOT NULL,
62 "visible" BOOL NOT NULL,
63 "scan_id" INTEGER NOT NULL,
64 "is_complete" BOOL NOT NULL DEFAULT FALSE,
65 "completed_scan_id" INTEGER NOT NULL,
66 PRIMARY KEY(project_id, id)
67);
68CREATE INDEX "index_worktrees_on_project_id" ON "worktrees" ("project_id");
69
70CREATE TABLE "worktree_entries" (
71 "project_id" INTEGER NOT NULL,
72 "worktree_id" INTEGER NOT NULL,
73 "scan_id" INTEGER NOT NULL,
74 "id" INTEGER NOT NULL,
75 "is_dir" BOOL NOT NULL,
76 "path" VARCHAR NOT NULL,
77 "inode" INTEGER NOT NULL,
78 "mtime_seconds" INTEGER NOT NULL,
79 "mtime_nanos" INTEGER NOT NULL,
80 "is_symlink" BOOL NOT NULL,
81 "is_external" BOOL NOT NULL,
82 "is_ignored" BOOL NOT NULL,
83 "is_deleted" BOOL NOT NULL,
84 "git_status" INTEGER,
85 PRIMARY KEY(project_id, worktree_id, id),
86 FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
87);
88CREATE INDEX "index_worktree_entries_on_project_id" ON "worktree_entries" ("project_id");
89CREATE INDEX "index_worktree_entries_on_project_id_and_worktree_id" ON "worktree_entries" ("project_id", "worktree_id");
90
91CREATE TABLE "worktree_repositories" (
92 "project_id" INTEGER NOT NULL,
93 "worktree_id" INTEGER NOT NULL,
94 "work_directory_id" INTEGER NOT NULL,
95 "branch" VARCHAR,
96 "scan_id" INTEGER NOT NULL,
97 "is_deleted" BOOL NOT NULL,
98 PRIMARY KEY(project_id, worktree_id, work_directory_id),
99 FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE,
100 FOREIGN KEY(project_id, worktree_id, work_directory_id) REFERENCES worktree_entries (project_id, worktree_id, id) ON DELETE CASCADE
101);
102CREATE INDEX "index_worktree_repositories_on_project_id" ON "worktree_repositories" ("project_id");
103CREATE INDEX "index_worktree_repositories_on_project_id_and_worktree_id" ON "worktree_repositories" ("project_id", "worktree_id");
104
105CREATE TABLE "worktree_settings_files" (
106 "project_id" INTEGER NOT NULL,
107 "worktree_id" INTEGER NOT NULL,
108 "path" VARCHAR NOT NULL,
109 "content" TEXT,
110 PRIMARY KEY(project_id, worktree_id, path),
111 FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
112);
113CREATE INDEX "index_worktree_settings_files_on_project_id" ON "worktree_settings_files" ("project_id");
114CREATE INDEX "index_worktree_settings_files_on_project_id_and_worktree_id" ON "worktree_settings_files" ("project_id", "worktree_id");
115
116CREATE TABLE "worktree_diagnostic_summaries" (
117 "project_id" INTEGER NOT NULL,
118 "worktree_id" INTEGER NOT NULL,
119 "path" VARCHAR NOT NULL,
120 "language_server_id" INTEGER NOT NULL,
121 "error_count" INTEGER NOT NULL,
122 "warning_count" INTEGER NOT NULL,
123 PRIMARY KEY(project_id, worktree_id, path),
124 FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
125);
126CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id" ON "worktree_diagnostic_summaries" ("project_id");
127CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id_and_worktree_id" ON "worktree_diagnostic_summaries" ("project_id", "worktree_id");
128
129CREATE TABLE "language_servers" (
130 "id" INTEGER NOT NULL,
131 "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
132 "name" VARCHAR NOT NULL,
133 PRIMARY KEY(project_id, id)
134);
135CREATE INDEX "index_language_servers_on_project_id" ON "language_servers" ("project_id");
136
137CREATE TABLE "project_collaborators" (
138 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
139 "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
140 "connection_id" INTEGER NOT NULL,
141 "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
142 "user_id" INTEGER NOT NULL,
143 "replica_id" INTEGER NOT NULL,
144 "is_host" BOOLEAN NOT NULL
145);
146CREATE INDEX "index_project_collaborators_on_project_id" ON "project_collaborators" ("project_id");
147CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_and_replica_id" ON "project_collaborators" ("project_id", "replica_id");
148CREATE INDEX "index_project_collaborators_on_connection_server_id" ON "project_collaborators" ("connection_server_id");
149CREATE INDEX "index_project_collaborators_on_connection_id" ON "project_collaborators" ("connection_id");
150CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_connection_id_and_server_id" ON "project_collaborators" ("project_id", "connection_id", "connection_server_id");
151
152CREATE TABLE "room_participants" (
153 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
154 "room_id" INTEGER NOT NULL REFERENCES rooms (id),
155 "user_id" INTEGER NOT NULL REFERENCES users (id),
156 "answering_connection_id" INTEGER,
157 "answering_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
158 "answering_connection_lost" BOOLEAN NOT NULL,
159 "location_kind" INTEGER,
160 "location_project_id" INTEGER,
161 "initial_project_id" INTEGER,
162 "calling_user_id" INTEGER NOT NULL REFERENCES users (id),
163 "calling_connection_id" INTEGER NOT NULL,
164 "calling_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE SET NULL,
165 "participant_index" INTEGER,
166 "role" TEXT,
167 "in_call" BOOLEAN NOT NULL DEFAULT FALSE
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 "requires_zed_cla" BOOLEAN NOT NULL DEFAULT FALSE
202);
203
204CREATE INDEX "index_channels_on_parent_path" ON "channels" ("parent_path");
205
206CREATE TABLE IF NOT EXISTS "channel_chat_participants" (
207 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
208 "user_id" INTEGER NOT NULL REFERENCES users (id),
209 "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
210 "connection_id" INTEGER NOT NULL,
211 "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE
212);
213CREATE INDEX "index_channel_chat_participants_on_channel_id" ON "channel_chat_participants" ("channel_id");
214
215CREATE TABLE IF NOT EXISTS "channel_messages" (
216 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
217 "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
218 "sender_id" INTEGER NOT NULL REFERENCES users (id),
219 "body" TEXT NOT NULL,
220 "sent_at" TIMESTAMP,
221 "nonce" BLOB NOT NULL,
222 "reply_to_message_id" INTEGER DEFAULT NULL
223);
224CREATE INDEX "index_channel_messages_on_channel_id" ON "channel_messages" ("channel_id");
225CREATE UNIQUE INDEX "index_channel_messages_on_sender_id_nonce" ON "channel_messages" ("sender_id", "nonce");
226
227CREATE TABLE "channel_message_mentions" (
228 "message_id" INTEGER NOT NULL REFERENCES channel_messages (id) ON DELETE CASCADE,
229 "start_offset" INTEGER NOT NULL,
230 "end_offset" INTEGER NOT NULL,
231 "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
232 PRIMARY KEY(message_id, start_offset)
233);
234
235CREATE TABLE "channel_members" (
236 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
237 "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
238 "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
239 "admin" BOOLEAN NOT NULL DEFAULT false,
240 "role" VARCHAR,
241 "accepted" BOOLEAN NOT NULL DEFAULT false,
242 "updated_at" TIMESTAMP NOT NULL DEFAULT now
243);
244
245CREATE UNIQUE INDEX "index_channel_members_on_channel_id_and_user_id" ON "channel_members" ("channel_id", "user_id");
246
247CREATE TABLE "buffers" (
248 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
249 "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
250 "epoch" INTEGER NOT NULL DEFAULT 0
251);
252
253CREATE INDEX "index_buffers_on_channel_id" ON "buffers" ("channel_id");
254
255CREATE TABLE "buffer_operations" (
256 "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
257 "epoch" INTEGER NOT NULL,
258 "replica_id" INTEGER NOT NULL,
259 "lamport_timestamp" INTEGER NOT NULL,
260 "value" BLOB NOT NULL,
261 PRIMARY KEY(buffer_id, epoch, lamport_timestamp, replica_id)
262);
263
264CREATE TABLE "buffer_snapshots" (
265 "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
266 "epoch" INTEGER NOT NULL,
267 "text" TEXT NOT NULL,
268 "operation_serialization_version" INTEGER NOT NULL,
269 PRIMARY KEY(buffer_id, epoch)
270);
271
272CREATE TABLE "channel_buffer_collaborators" (
273 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
274 "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
275 "connection_id" INTEGER NOT NULL,
276 "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
277 "connection_lost" BOOLEAN NOT NULL DEFAULT false,
278 "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
279 "replica_id" INTEGER NOT NULL
280);
281
282CREATE INDEX "index_channel_buffer_collaborators_on_channel_id" ON "channel_buffer_collaborators" ("channel_id");
283CREATE UNIQUE INDEX "index_channel_buffer_collaborators_on_channel_id_and_replica_id" ON "channel_buffer_collaborators" ("channel_id", "replica_id");
284CREATE INDEX "index_channel_buffer_collaborators_on_connection_server_id" ON "channel_buffer_collaborators" ("connection_server_id");
285CREATE INDEX "index_channel_buffer_collaborators_on_connection_id" ON "channel_buffer_collaborators" ("connection_id");
286CREATE 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");
287
288
289CREATE TABLE "feature_flags" (
290 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
291 "flag" TEXT NOT NULL UNIQUE
292);
293
294CREATE INDEX "index_feature_flags" ON "feature_flags" ("id");
295
296
297CREATE TABLE "user_features" (
298 "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
299 "feature_id" INTEGER NOT NULL REFERENCES feature_flags (id) ON DELETE CASCADE,
300 PRIMARY KEY (user_id, feature_id)
301);
302
303CREATE UNIQUE INDEX "index_user_features_user_id_and_feature_id" ON "user_features" ("user_id", "feature_id");
304CREATE INDEX "index_user_features_on_user_id" ON "user_features" ("user_id");
305CREATE INDEX "index_user_features_on_feature_id" ON "user_features" ("feature_id");
306
307
308CREATE TABLE "observed_buffer_edits" (
309 "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
310 "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
311 "epoch" INTEGER NOT NULL,
312 "lamport_timestamp" INTEGER NOT NULL,
313 "replica_id" INTEGER NOT NULL,
314 PRIMARY KEY (user_id, buffer_id)
315);
316
317CREATE UNIQUE INDEX "index_observed_buffers_user_and_buffer_id" ON "observed_buffer_edits" ("user_id", "buffer_id");
318
319CREATE TABLE IF NOT EXISTS "observed_channel_messages" (
320 "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
321 "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
322 "channel_message_id" INTEGER NOT NULL,
323 PRIMARY KEY (user_id, channel_id)
324);
325
326CREATE UNIQUE INDEX "index_observed_channel_messages_user_and_channel_id" ON "observed_channel_messages" ("user_id", "channel_id");
327
328CREATE TABLE "notification_kinds" (
329 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
330 "name" VARCHAR NOT NULL
331);
332
333CREATE UNIQUE INDEX "index_notification_kinds_on_name" ON "notification_kinds" ("name");
334
335CREATE TABLE "notifications" (
336 "id" INTEGER PRIMARY KEY AUTOINCREMENT,
337 "created_at" TIMESTAMP NOT NULL default CURRENT_TIMESTAMP,
338 "recipient_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
339 "kind" INTEGER NOT NULL REFERENCES notification_kinds (id),
340 "entity_id" INTEGER,
341 "content" TEXT,
342 "is_read" BOOLEAN NOT NULL DEFAULT FALSE,
343 "response" BOOLEAN
344);
345
346CREATE INDEX
347 "index_notifications_on_recipient_id_is_read_kind_entity_id"
348 ON "notifications"
349 ("recipient_id", "is_read", "kind", "entity_id");
350
351CREATE TABLE contributors (
352 user_id INTEGER REFERENCES users(id),
353 signed_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
354 PRIMARY KEY (user_id)
355);
356
357CREATE TABLE extensions (
358 id INTEGER PRIMARY KEY AUTOINCREMENT,
359 external_id TEXT NOT NULL,
360 name TEXT NOT NULL,
361 latest_version TEXT NOT NULL,
362 total_download_count INTEGER NOT NULL DEFAULT 0
363);
364
365CREATE TABLE extension_versions (
366 extension_id INTEGER REFERENCES extensions(id),
367 version TEXT NOT NULL,
368 published_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
369 authors TEXT NOT NULL,
370 repository TEXT NOT NULL,
371 description TEXT NOT NULL,
372 download_count INTEGER NOT NULL DEFAULT 0,
373 PRIMARY KEY (extension_id, version)
374);
375
376CREATE UNIQUE INDEX "index_extensions_external_id" ON "extensions" ("external_id");
377CREATE INDEX "index_extensions_total_download_count" ON "extensions" ("total_download_count");