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 NOT NULL,
 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);
 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    "in_call" BOOLEAN NOT NULL DEFAULT FALSE
169);
170CREATE UNIQUE INDEX "index_room_participants_on_user_id" ON "room_participants" ("user_id");
171CREATE INDEX "index_room_participants_on_room_id" ON "room_participants" ("room_id");
172CREATE INDEX "index_room_participants_on_answering_connection_server_id" ON "room_participants" ("answering_connection_server_id");
173CREATE INDEX "index_room_participants_on_calling_connection_server_id" ON "room_participants" ("calling_connection_server_id");
174CREATE INDEX "index_room_participants_on_answering_connection_id" ON "room_participants" ("answering_connection_id");
175CREATE UNIQUE INDEX "index_room_participants_on_answering_connection_id_and_answering_connection_server_id" ON "room_participants" ("answering_connection_id", "answering_connection_server_id");
176
177CREATE TABLE "servers" (
178    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
179    "environment" VARCHAR NOT NULL
180);
181
182CREATE TABLE "followers" (
183    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
184    "room_id" INTEGER NOT NULL REFERENCES rooms (id) ON DELETE CASCADE,
185    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
186    "leader_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
187    "leader_connection_id" INTEGER NOT NULL,
188    "follower_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
189    "follower_connection_id" INTEGER NOT NULL
190);
191CREATE UNIQUE INDEX
192    "index_followers_on_project_id_and_leader_connection_server_id_and_leader_connection_id_and_follower_connection_server_id_and_follower_connection_id"
193ON "followers" ("project_id", "leader_connection_server_id", "leader_connection_id", "follower_connection_server_id", "follower_connection_id");
194CREATE INDEX "index_followers_on_room_id" ON "followers" ("room_id");
195
196CREATE TABLE "channels" (
197    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
198    "name" VARCHAR NOT NULL,
199    "created_at" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
200    "visibility" VARCHAR NOT NULL,
201    "parent_path" TEXT NOT NULL,
202    "requires_zed_cla" BOOLEAN NOT NULL DEFAULT FALSE
203);
204
205CREATE INDEX "index_channels_on_parent_path" ON "channels" ("parent_path");
206
207CREATE TABLE IF NOT EXISTS "channel_chat_participants" (
208    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
209    "user_id" INTEGER NOT NULL REFERENCES users (id),
210    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
211    "connection_id" INTEGER NOT NULL,
212    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE
213);
214CREATE INDEX "index_channel_chat_participants_on_channel_id" ON "channel_chat_participants" ("channel_id");
215
216CREATE TABLE IF NOT EXISTS "channel_messages" (
217    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
218    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
219    "sender_id" INTEGER NOT NULL REFERENCES users (id),
220    "body" TEXT NOT NULL,
221    "sent_at" TIMESTAMP,
222    "edited_at" TIMESTAMP,
223    "nonce" BLOB NOT NULL,
224    "reply_to_message_id" INTEGER DEFAULT NULL
225);
226CREATE INDEX "index_channel_messages_on_channel_id" ON "channel_messages" ("channel_id");
227CREATE UNIQUE INDEX "index_channel_messages_on_sender_id_nonce" ON "channel_messages" ("sender_id", "nonce");
228
229CREATE TABLE "channel_message_mentions" (
230    "message_id" INTEGER NOT NULL REFERENCES channel_messages (id) ON DELETE CASCADE,
231    "start_offset" INTEGER NOT NULL,
232    "end_offset" INTEGER NOT NULL,
233    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
234    PRIMARY KEY(message_id, start_offset)
235);
236
237CREATE TABLE "channel_members" (
238    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
239    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
240    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
241    "role" VARCHAR NOT NULL,
242    "accepted" BOOLEAN NOT NULL DEFAULT false,
243    "updated_at" TIMESTAMP NOT NULL DEFAULT now
244);
245
246CREATE UNIQUE INDEX "index_channel_members_on_channel_id_and_user_id" ON "channel_members" ("channel_id", "user_id");
247
248CREATE TABLE "buffers" (
249    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
250    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
251    "epoch" INTEGER NOT NULL DEFAULT 0,
252    "latest_operation_epoch" INTEGER,
253    "latest_operation_replica_id" INTEGER,
254    "latest_operation_lamport_timestamp" INTEGER
255);
256
257CREATE INDEX "index_buffers_on_channel_id" ON "buffers" ("channel_id");
258
259CREATE TABLE "buffer_operations" (
260    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
261    "epoch" INTEGER NOT NULL,
262    "replica_id" INTEGER NOT NULL,
263    "lamport_timestamp" INTEGER NOT NULL,
264    "value" BLOB NOT NULL,
265    PRIMARY KEY(buffer_id, epoch, lamport_timestamp, replica_id)
266);
267
268CREATE TABLE "buffer_snapshots" (
269    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
270    "epoch" INTEGER NOT NULL,
271    "text" TEXT NOT NULL,
272    "operation_serialization_version" INTEGER NOT NULL,
273    PRIMARY KEY(buffer_id, epoch)
274);
275
276CREATE TABLE "channel_buffer_collaborators" (
277    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
278    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
279    "connection_id" INTEGER NOT NULL,
280    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
281    "connection_lost" BOOLEAN NOT NULL DEFAULT false,
282    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
283    "replica_id" INTEGER NOT NULL
284);
285
286CREATE INDEX "index_channel_buffer_collaborators_on_channel_id" ON "channel_buffer_collaborators" ("channel_id");
287CREATE UNIQUE INDEX "index_channel_buffer_collaborators_on_channel_id_and_replica_id" ON "channel_buffer_collaborators" ("channel_id", "replica_id");
288CREATE INDEX "index_channel_buffer_collaborators_on_connection_server_id" ON "channel_buffer_collaborators" ("connection_server_id");
289CREATE INDEX "index_channel_buffer_collaborators_on_connection_id" ON "channel_buffer_collaborators" ("connection_id");
290CREATE 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");
291
292
293CREATE TABLE "feature_flags" (
294    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
295    "flag" TEXT NOT NULL UNIQUE
296);
297
298CREATE INDEX "index_feature_flags" ON "feature_flags" ("id");
299
300
301CREATE TABLE "user_features" (
302    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
303    "feature_id" INTEGER NOT NULL REFERENCES feature_flags (id) ON DELETE CASCADE,
304    PRIMARY KEY (user_id, feature_id)
305);
306
307CREATE UNIQUE INDEX "index_user_features_user_id_and_feature_id" ON "user_features" ("user_id", "feature_id");
308CREATE INDEX "index_user_features_on_user_id" ON "user_features" ("user_id");
309CREATE INDEX "index_user_features_on_feature_id" ON "user_features" ("feature_id");
310
311
312CREATE TABLE "observed_buffer_edits" (
313    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
314    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
315    "epoch" INTEGER NOT NULL,
316    "lamport_timestamp" INTEGER NOT NULL,
317    "replica_id" INTEGER NOT NULL,
318    PRIMARY KEY (user_id, buffer_id)
319);
320
321CREATE UNIQUE INDEX "index_observed_buffers_user_and_buffer_id" ON "observed_buffer_edits" ("user_id", "buffer_id");
322
323CREATE TABLE IF NOT EXISTS "observed_channel_messages" (
324    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
325    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
326    "channel_message_id" INTEGER NOT NULL,
327    PRIMARY KEY (user_id, channel_id)
328);
329
330CREATE UNIQUE INDEX "index_observed_channel_messages_user_and_channel_id" ON "observed_channel_messages" ("user_id", "channel_id");
331
332CREATE TABLE "notification_kinds" (
333    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
334    "name" VARCHAR NOT NULL
335);
336
337CREATE UNIQUE INDEX "index_notification_kinds_on_name" ON "notification_kinds" ("name");
338
339CREATE TABLE "notifications" (
340    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
341    "created_at" TIMESTAMP NOT NULL default CURRENT_TIMESTAMP,
342    "recipient_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
343    "kind" INTEGER NOT NULL REFERENCES notification_kinds (id),
344    "entity_id" INTEGER,
345    "content" TEXT,
346    "is_read" BOOLEAN NOT NULL DEFAULT FALSE,
347    "response" BOOLEAN
348);
349
350CREATE INDEX
351    "index_notifications_on_recipient_id_is_read_kind_entity_id"
352    ON "notifications"
353    ("recipient_id", "is_read", "kind", "entity_id");
354
355CREATE TABLE contributors (
356    user_id INTEGER REFERENCES users(id),
357    signed_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
358    PRIMARY KEY (user_id)
359);
360
361CREATE TABLE extensions (
362    id INTEGER PRIMARY KEY AUTOINCREMENT,
363    external_id TEXT NOT NULL,
364    name TEXT NOT NULL,
365    latest_version TEXT NOT NULL,
366    total_download_count INTEGER NOT NULL DEFAULT 0
367);
368
369CREATE TABLE extension_versions (
370    extension_id INTEGER REFERENCES extensions(id),
371    version TEXT NOT NULL,
372    published_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
373    authors TEXT NOT NULL,
374    repository TEXT NOT NULL,
375    description TEXT NOT NULL,
376    schema_version INTEGER NOT NULL DEFAULT 0,
377    wasm_api_version TEXT,
378    download_count INTEGER NOT NULL DEFAULT 0,
379    PRIMARY KEY (extension_id, version)
380);
381
382CREATE UNIQUE INDEX "index_extensions_external_id" ON "extensions" ("external_id");
383CREATE INDEX "index_extensions_total_download_count" ON "extensions" ("total_download_count");
384
385CREATE TABLE rate_buckets (
386    user_id INT NOT NULL,
387    rate_limit_name VARCHAR(255) NOT NULL,
388    token_count INT NOT NULL,
389    last_refill TIMESTAMP WITHOUT TIME ZONE NOT NULL,
390    PRIMARY KEY (user_id, rate_limit_name),
391    FOREIGN KEY (user_id) REFERENCES users(id)
392);
393CREATE INDEX idx_user_id_rate_limit ON rate_buckets (user_id, rate_limit_name);
394
395CREATE TABLE hosted_projects (
396    id INTEGER PRIMARY KEY AUTOINCREMENT,
397    channel_id INTEGER NOT NULL REFERENCES channels(id),
398    name TEXT NOT NULL,
399    visibility TEXT NOT NULL,
400    deleted_at TIMESTAMP NULL
401);
402CREATE INDEX idx_hosted_projects_on_channel_id ON hosted_projects (channel_id);
403CREATE UNIQUE INDEX uix_hosted_projects_on_channel_id_and_name ON hosted_projects (channel_id, name) WHERE (deleted_at IS NULL);
404
405CREATE TABLE dev_servers (
406    id INTEGER PRIMARY KEY AUTOINCREMENT,
407    channel_id INTEGER NOT NULL REFERENCES channels(id),
408    name TEXT NOT NULL,
409    hashed_token TEXT NOT NULL
410);
411CREATE INDEX idx_dev_servers_on_channel_id ON dev_servers (channel_id);