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 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,
 49    "host_user_id" INTEGER REFERENCES users (id),
 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    "hosted_project_id" INTEGER REFERENCES hosted_projects (id),
 54    "dev_server_project_id" INTEGER REFERENCES dev_server_projects(id)
 55);
 56CREATE INDEX "index_projects_on_host_connection_server_id" ON "projects" ("host_connection_server_id");
 57CREATE INDEX "index_projects_on_host_connection_id_and_host_connection_server_id" ON "projects" ("host_connection_id", "host_connection_server_id");
 58
 59CREATE TABLE "worktrees" (
 60    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
 61    "id" INTEGER NOT NULL,
 62    "root_name" VARCHAR NOT NULL,
 63    "abs_path" VARCHAR NOT NULL,
 64    "visible" BOOL NOT NULL,
 65    "scan_id" INTEGER NOT NULL,
 66    "is_complete" BOOL NOT NULL DEFAULT FALSE,
 67    "completed_scan_id" INTEGER NOT NULL,
 68    PRIMARY KEY(project_id, id)
 69);
 70CREATE INDEX "index_worktrees_on_project_id" ON "worktrees" ("project_id");
 71
 72CREATE TABLE "worktree_entries" (
 73    "project_id" INTEGER NOT NULL,
 74    "worktree_id" INTEGER NOT NULL,
 75    "scan_id" INTEGER NOT NULL,
 76    "id" INTEGER NOT NULL,
 77    "is_dir" BOOL NOT NULL,
 78    "path" VARCHAR NOT NULL,
 79    "inode" INTEGER NOT NULL,
 80    "mtime_seconds" INTEGER NOT NULL,
 81    "mtime_nanos" INTEGER NOT NULL,
 82    "is_symlink" BOOL NOT NULL,
 83    "is_external" BOOL NOT NULL,
 84    "is_ignored" BOOL NOT NULL,
 85    "is_deleted" BOOL NOT NULL,
 86    "git_status" INTEGER,
 87    PRIMARY KEY(project_id, worktree_id, id),
 88    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
 89);
 90CREATE INDEX "index_worktree_entries_on_project_id" ON "worktree_entries" ("project_id");
 91CREATE INDEX "index_worktree_entries_on_project_id_and_worktree_id" ON "worktree_entries" ("project_id", "worktree_id");
 92
 93CREATE TABLE "worktree_repositories" (
 94    "project_id" INTEGER NOT NULL,
 95    "worktree_id" INTEGER NOT NULL,
 96    "work_directory_id" INTEGER NOT NULL,
 97    "branch" VARCHAR,
 98    "scan_id" INTEGER NOT NULL,
 99    "is_deleted" BOOL NOT NULL,
100    PRIMARY KEY(project_id, worktree_id, work_directory_id),
101    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE,
102    FOREIGN KEY(project_id, worktree_id, work_directory_id) REFERENCES worktree_entries (project_id, worktree_id, id) ON DELETE CASCADE
103);
104CREATE INDEX "index_worktree_repositories_on_project_id" ON "worktree_repositories" ("project_id");
105CREATE INDEX "index_worktree_repositories_on_project_id_and_worktree_id" ON "worktree_repositories" ("project_id", "worktree_id");
106
107CREATE TABLE "worktree_settings_files" (
108    "project_id" INTEGER NOT NULL,
109    "worktree_id" INTEGER NOT NULL,
110    "path" VARCHAR NOT NULL,
111    "content" TEXT,
112    PRIMARY KEY(project_id, worktree_id, path),
113    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
114);
115CREATE INDEX "index_worktree_settings_files_on_project_id" ON "worktree_settings_files" ("project_id");
116CREATE INDEX "index_worktree_settings_files_on_project_id_and_worktree_id" ON "worktree_settings_files" ("project_id", "worktree_id");
117
118CREATE TABLE "worktree_diagnostic_summaries" (
119    "project_id" INTEGER NOT NULL,
120    "worktree_id" INTEGER NOT NULL,
121    "path" VARCHAR NOT NULL,
122    "language_server_id" INTEGER NOT NULL,
123    "error_count" INTEGER NOT NULL,
124    "warning_count" INTEGER NOT NULL,
125    PRIMARY KEY(project_id, worktree_id, path),
126    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
127);
128CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id" ON "worktree_diagnostic_summaries" ("project_id");
129CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id_and_worktree_id" ON "worktree_diagnostic_summaries" ("project_id", "worktree_id");
130
131CREATE TABLE "language_servers" (
132    "id" INTEGER NOT NULL,
133    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
134    "name" VARCHAR NOT NULL,
135    PRIMARY KEY(project_id, id)
136);
137CREATE INDEX "index_language_servers_on_project_id" ON "language_servers" ("project_id");
138
139CREATE TABLE "project_collaborators" (
140    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
141    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
142    "connection_id" INTEGER NOT NULL,
143    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
144    "user_id" INTEGER NOT NULL,
145    "replica_id" INTEGER NOT NULL,
146    "is_host" BOOLEAN NOT NULL
147);
148CREATE INDEX "index_project_collaborators_on_project_id" ON "project_collaborators" ("project_id");
149CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_and_replica_id" ON "project_collaborators" ("project_id", "replica_id");
150CREATE INDEX "index_project_collaborators_on_connection_server_id" ON "project_collaborators" ("connection_server_id");
151CREATE INDEX "index_project_collaborators_on_connection_id" ON "project_collaborators" ("connection_id");
152CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_connection_id_and_server_id" ON "project_collaborators" ("project_id", "connection_id", "connection_server_id");
153
154CREATE TABLE "room_participants" (
155    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
156    "room_id" INTEGER NOT NULL REFERENCES rooms (id),
157    "user_id" INTEGER NOT NULL REFERENCES users (id),
158    "answering_connection_id" INTEGER,
159    "answering_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
160    "answering_connection_lost" BOOLEAN NOT NULL,
161    "location_kind" INTEGER,
162    "location_project_id" INTEGER,
163    "initial_project_id" INTEGER,
164    "calling_user_id" INTEGER NOT NULL REFERENCES users (id),
165    "calling_connection_id" INTEGER NOT NULL,
166    "calling_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE SET NULL,
167    "participant_index" INTEGER,
168    "role" TEXT,
169    "in_call" BOOLEAN NOT NULL DEFAULT FALSE
170);
171CREATE UNIQUE INDEX "index_room_participants_on_user_id" ON "room_participants" ("user_id");
172CREATE INDEX "index_room_participants_on_room_id" ON "room_participants" ("room_id");
173CREATE INDEX "index_room_participants_on_answering_connection_server_id" ON "room_participants" ("answering_connection_server_id");
174CREATE INDEX "index_room_participants_on_calling_connection_server_id" ON "room_participants" ("calling_connection_server_id");
175CREATE INDEX "index_room_participants_on_answering_connection_id" ON "room_participants" ("answering_connection_id");
176CREATE UNIQUE INDEX "index_room_participants_on_answering_connection_id_and_answering_connection_server_id" ON "room_participants" ("answering_connection_id", "answering_connection_server_id");
177
178CREATE TABLE "servers" (
179    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
180    "environment" VARCHAR NOT NULL
181);
182
183CREATE TABLE "followers" (
184    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
185    "room_id" INTEGER NOT NULL REFERENCES rooms (id) ON DELETE CASCADE,
186    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
187    "leader_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
188    "leader_connection_id" INTEGER NOT NULL,
189    "follower_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
190    "follower_connection_id" INTEGER NOT NULL
191);
192CREATE UNIQUE INDEX
193    "index_followers_on_project_id_and_leader_connection_server_id_and_leader_connection_id_and_follower_connection_server_id_and_follower_connection_id"
194ON "followers" ("project_id", "leader_connection_server_id", "leader_connection_id", "follower_connection_server_id", "follower_connection_id");
195CREATE INDEX "index_followers_on_room_id" ON "followers" ("room_id");
196
197CREATE TABLE "channels" (
198    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
199    "name" VARCHAR NOT NULL,
200    "created_at" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
201    "visibility" VARCHAR NOT NULL,
202    "parent_path" TEXT NOT NULL,
203    "requires_zed_cla" BOOLEAN NOT NULL DEFAULT FALSE
204);
205
206CREATE INDEX "index_channels_on_parent_path" ON "channels" ("parent_path");
207
208CREATE TABLE IF NOT EXISTS "channel_chat_participants" (
209    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
210    "user_id" INTEGER NOT NULL REFERENCES users (id),
211    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
212    "connection_id" INTEGER NOT NULL,
213    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE
214);
215CREATE INDEX "index_channel_chat_participants_on_channel_id" ON "channel_chat_participants" ("channel_id");
216
217CREATE TABLE IF NOT EXISTS "channel_messages" (
218    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
219    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
220    "sender_id" INTEGER NOT NULL REFERENCES users (id),
221    "body" TEXT NOT NULL,
222    "sent_at" TIMESTAMP,
223    "edited_at" TIMESTAMP,
224    "nonce" BLOB NOT NULL,
225    "reply_to_message_id" INTEGER DEFAULT NULL
226);
227CREATE INDEX "index_channel_messages_on_channel_id" ON "channel_messages" ("channel_id");
228CREATE UNIQUE INDEX "index_channel_messages_on_sender_id_nonce" ON "channel_messages" ("sender_id", "nonce");
229
230CREATE TABLE "channel_message_mentions" (
231    "message_id" INTEGER NOT NULL REFERENCES channel_messages (id) ON DELETE CASCADE,
232    "start_offset" INTEGER NOT NULL,
233    "end_offset" INTEGER NOT NULL,
234    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
235    PRIMARY KEY(message_id, start_offset)
236);
237
238CREATE TABLE "channel_members" (
239    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
240    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
241    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
242    "role" VARCHAR NOT NULL,
243    "accepted" BOOLEAN NOT NULL DEFAULT false,
244    "updated_at" TIMESTAMP NOT NULL DEFAULT now
245);
246
247CREATE UNIQUE INDEX "index_channel_members_on_channel_id_and_user_id" ON "channel_members" ("channel_id", "user_id");
248
249CREATE TABLE "buffers" (
250    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
251    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
252    "epoch" INTEGER NOT NULL DEFAULT 0,
253    "latest_operation_epoch" INTEGER,
254    "latest_operation_replica_id" INTEGER,
255    "latest_operation_lamport_timestamp" INTEGER
256);
257
258CREATE INDEX "index_buffers_on_channel_id" ON "buffers" ("channel_id");
259
260CREATE TABLE "buffer_operations" (
261    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
262    "epoch" INTEGER NOT NULL,
263    "replica_id" INTEGER NOT NULL,
264    "lamport_timestamp" INTEGER NOT NULL,
265    "value" BLOB NOT NULL,
266    PRIMARY KEY(buffer_id, epoch, lamport_timestamp, replica_id)
267);
268
269CREATE TABLE "buffer_snapshots" (
270    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
271    "epoch" INTEGER NOT NULL,
272    "text" TEXT NOT NULL,
273    "operation_serialization_version" INTEGER NOT NULL,
274    PRIMARY KEY(buffer_id, epoch)
275);
276
277CREATE TABLE "channel_buffer_collaborators" (
278    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
279    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
280    "connection_id" INTEGER NOT NULL,
281    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
282    "connection_lost" BOOLEAN NOT NULL DEFAULT false,
283    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
284    "replica_id" INTEGER NOT NULL
285);
286
287CREATE INDEX "index_channel_buffer_collaborators_on_channel_id" ON "channel_buffer_collaborators" ("channel_id");
288CREATE UNIQUE INDEX "index_channel_buffer_collaborators_on_channel_id_and_replica_id" ON "channel_buffer_collaborators" ("channel_id", "replica_id");
289CREATE INDEX "index_channel_buffer_collaborators_on_connection_server_id" ON "channel_buffer_collaborators" ("connection_server_id");
290CREATE INDEX "index_channel_buffer_collaborators_on_connection_id" ON "channel_buffer_collaborators" ("connection_id");
291CREATE 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");
292
293
294CREATE TABLE "feature_flags" (
295    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
296    "flag" TEXT NOT NULL UNIQUE
297);
298
299CREATE INDEX "index_feature_flags" ON "feature_flags" ("id");
300
301
302CREATE TABLE "user_features" (
303    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
304    "feature_id" INTEGER NOT NULL REFERENCES feature_flags (id) ON DELETE CASCADE,
305    PRIMARY KEY (user_id, feature_id)
306);
307
308CREATE UNIQUE INDEX "index_user_features_user_id_and_feature_id" ON "user_features" ("user_id", "feature_id");
309CREATE INDEX "index_user_features_on_user_id" ON "user_features" ("user_id");
310CREATE INDEX "index_user_features_on_feature_id" ON "user_features" ("feature_id");
311
312
313CREATE TABLE "observed_buffer_edits" (
314    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
315    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
316    "epoch" INTEGER NOT NULL,
317    "lamport_timestamp" INTEGER NOT NULL,
318    "replica_id" INTEGER NOT NULL,
319    PRIMARY KEY (user_id, buffer_id)
320);
321
322CREATE UNIQUE INDEX "index_observed_buffers_user_and_buffer_id" ON "observed_buffer_edits" ("user_id", "buffer_id");
323
324CREATE TABLE IF NOT EXISTS "observed_channel_messages" (
325    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
326    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
327    "channel_message_id" INTEGER NOT NULL,
328    PRIMARY KEY (user_id, channel_id)
329);
330
331CREATE UNIQUE INDEX "index_observed_channel_messages_user_and_channel_id" ON "observed_channel_messages" ("user_id", "channel_id");
332
333CREATE TABLE "notification_kinds" (
334    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
335    "name" VARCHAR NOT NULL
336);
337
338CREATE UNIQUE INDEX "index_notification_kinds_on_name" ON "notification_kinds" ("name");
339
340CREATE TABLE "notifications" (
341    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
342    "created_at" TIMESTAMP NOT NULL default CURRENT_TIMESTAMP,
343    "recipient_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
344    "kind" INTEGER NOT NULL REFERENCES notification_kinds (id),
345    "entity_id" INTEGER,
346    "content" TEXT,
347    "is_read" BOOLEAN NOT NULL DEFAULT FALSE,
348    "response" BOOLEAN
349);
350
351CREATE INDEX
352    "index_notifications_on_recipient_id_is_read_kind_entity_id"
353    ON "notifications"
354    ("recipient_id", "is_read", "kind", "entity_id");
355
356CREATE TABLE contributors (
357    user_id INTEGER REFERENCES users(id),
358    signed_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
359    PRIMARY KEY (user_id)
360);
361
362CREATE TABLE extensions (
363    id INTEGER PRIMARY KEY AUTOINCREMENT,
364    external_id TEXT NOT NULL,
365    name TEXT NOT NULL,
366    latest_version TEXT NOT NULL,
367    total_download_count INTEGER NOT NULL DEFAULT 0
368);
369
370CREATE TABLE extension_versions (
371    extension_id INTEGER REFERENCES extensions(id),
372    version TEXT NOT NULL,
373    published_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
374    authors TEXT NOT NULL,
375    repository TEXT NOT NULL,
376    description TEXT NOT NULL,
377    schema_version INTEGER NOT NULL DEFAULT 0,
378    wasm_api_version TEXT,
379    download_count INTEGER NOT NULL DEFAULT 0,
380    PRIMARY KEY (extension_id, version)
381);
382
383CREATE UNIQUE INDEX "index_extensions_external_id" ON "extensions" ("external_id");
384CREATE INDEX "index_extensions_total_download_count" ON "extensions" ("total_download_count");
385
386CREATE TABLE rate_buckets (
387    user_id INT NOT NULL,
388    rate_limit_name VARCHAR(255) NOT NULL,
389    token_count INT NOT NULL,
390    last_refill TIMESTAMP WITHOUT TIME ZONE NOT NULL,
391    PRIMARY KEY (user_id, rate_limit_name),
392    FOREIGN KEY (user_id) REFERENCES users(id)
393);
394CREATE INDEX idx_user_id_rate_limit ON rate_buckets (user_id, rate_limit_name);
395
396CREATE TABLE hosted_projects (
397    id INTEGER PRIMARY KEY AUTOINCREMENT,
398    channel_id INTEGER NOT NULL REFERENCES channels(id),
399    name TEXT NOT NULL,
400    visibility TEXT NOT NULL,
401    deleted_at TIMESTAMP NULL
402);
403CREATE INDEX idx_hosted_projects_on_channel_id ON hosted_projects (channel_id);
404CREATE UNIQUE INDEX uix_hosted_projects_on_channel_id_and_name ON hosted_projects (channel_id, name) WHERE (deleted_at IS NULL);
405
406CREATE TABLE dev_servers (
407    id INTEGER PRIMARY KEY AUTOINCREMENT,
408    user_id INTEGER NOT NULL REFERENCES users(id),
409    name TEXT NOT NULL,
410    ssh_connection_string TEXT,
411    hashed_token TEXT NOT NULL
412);
413
414CREATE TABLE dev_server_projects (
415    id INTEGER PRIMARY KEY AUTOINCREMENT,
416    dev_server_id INTEGER NOT NULL REFERENCES dev_servers(id),
417    paths TEXT NOT NULL
418);