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    "name" TEXT,
  7    "invite_code" VARCHAR(64),
  8    "invite_count" INTEGER NOT NULL DEFAULT 0,
  9    "inviter_id" INTEGER REFERENCES users (id),
 10    "connected_once" BOOLEAN NOT NULL DEFAULT false,
 11    "created_at" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
 12    "metrics_id" TEXT,
 13    "github_user_id" INTEGER NOT NULL,
 14    "accepted_tos_at" TIMESTAMP WITHOUT TIME ZONE,
 15    "github_user_created_at" TIMESTAMP WITHOUT TIME ZONE,
 16    "custom_llm_monthly_allowance_in_cents" INTEGER
 17);
 18
 19CREATE UNIQUE INDEX "index_users_github_login" ON "users" ("github_login");
 20
 21CREATE UNIQUE INDEX "index_invite_code_users" ON "users" ("invite_code");
 22
 23CREATE INDEX "index_users_on_email_address" ON "users" ("email_address");
 24
 25CREATE UNIQUE INDEX "index_users_on_github_user_id" ON "users" ("github_user_id");
 26
 27CREATE TABLE "access_tokens" (
 28    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 29    "user_id" INTEGER REFERENCES users (id) ON DELETE CASCADE,
 30    "impersonated_user_id" INTEGER REFERENCES users (id),
 31    "hash" VARCHAR(128)
 32);
 33
 34CREATE INDEX "index_access_tokens_user_id" ON "access_tokens" ("user_id");
 35
 36CREATE TABLE "contacts" (
 37    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 38    "user_id_a" INTEGER REFERENCES users (id) NOT NULL,
 39    "user_id_b" INTEGER REFERENCES users (id) NOT NULL,
 40    "a_to_b" BOOLEAN NOT NULL,
 41    "should_notify" BOOLEAN NOT NULL,
 42    "accepted" BOOLEAN NOT NULL
 43);
 44
 45CREATE UNIQUE INDEX "index_contacts_user_ids" ON "contacts" ("user_id_a", "user_id_b");
 46
 47CREATE INDEX "index_contacts_user_id_b" ON "contacts" ("user_id_b");
 48
 49CREATE TABLE "rooms" (
 50    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 51    "live_kit_room" VARCHAR NOT NULL,
 52    "environment" VARCHAR,
 53    "channel_id" INTEGER REFERENCES channels (id) ON DELETE CASCADE
 54);
 55
 56CREATE UNIQUE INDEX "index_rooms_on_channel_id" ON "rooms" ("channel_id");
 57
 58CREATE TABLE "projects" (
 59    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 60    "room_id" INTEGER REFERENCES rooms (id) ON DELETE CASCADE,
 61    "host_user_id" INTEGER REFERENCES users (id),
 62    "host_connection_id" INTEGER,
 63    "host_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
 64    "unregistered" BOOLEAN NOT NULL DEFAULT FALSE,
 65    "windows_paths" BOOLEAN NOT NULL DEFAULT FALSE
 66);
 67
 68CREATE INDEX "index_projects_on_host_connection_server_id" ON "projects" ("host_connection_server_id");
 69
 70CREATE INDEX "index_projects_on_host_connection_id_and_host_connection_server_id" ON "projects" ("host_connection_id", "host_connection_server_id");
 71
 72CREATE TABLE "worktrees" (
 73    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
 74    "id" INTEGER NOT NULL,
 75    "root_name" VARCHAR NOT NULL,
 76    "abs_path" VARCHAR NOT NULL,
 77    "visible" BOOL NOT NULL,
 78    "scan_id" INTEGER NOT NULL,
 79    "is_complete" BOOL NOT NULL DEFAULT FALSE,
 80    "completed_scan_id" INTEGER NOT NULL,
 81    PRIMARY KEY (project_id, id)
 82);
 83
 84CREATE INDEX "index_worktrees_on_project_id" ON "worktrees" ("project_id");
 85
 86CREATE TABLE "worktree_entries" (
 87    "project_id" INTEGER NOT NULL,
 88    "worktree_id" INTEGER NOT NULL,
 89    "scan_id" INTEGER NOT NULL,
 90    "id" INTEGER NOT NULL,
 91    "is_dir" BOOL NOT NULL,
 92    "path" VARCHAR NOT NULL,
 93    "canonical_path" TEXT,
 94    "inode" INTEGER NOT NULL,
 95    "mtime_seconds" INTEGER NOT NULL,
 96    "mtime_nanos" INTEGER NOT NULL,
 97    "is_external" BOOL NOT NULL,
 98    "is_ignored" BOOL NOT NULL,
 99    "is_deleted" BOOL NOT NULL,
100    "is_hidden" BOOL NOT NULL,
101    "git_status" INTEGER,
102    "is_fifo" BOOL NOT NULL,
103    PRIMARY KEY (project_id, worktree_id, id),
104    FOREIGN KEY (project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
105);
106
107CREATE INDEX "index_worktree_entries_on_project_id" ON "worktree_entries" ("project_id");
108
109CREATE INDEX "index_worktree_entries_on_project_id_and_worktree_id" ON "worktree_entries" ("project_id", "worktree_id");
110
111CREATE TABLE "project_repositories" (
112    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
113    "abs_path" VARCHAR,
114    "id" INTEGER NOT NULL,
115    "entry_ids" VARCHAR,
116    "legacy_worktree_id" INTEGER,
117    "branch" VARCHAR,
118    "scan_id" INTEGER NOT NULL,
119    "is_deleted" BOOL NOT NULL,
120    "current_merge_conflicts" VARCHAR,
121    "merge_message" VARCHAR,
122    "branch_summary" VARCHAR,
123    "head_commit_details" VARCHAR,
124    "remote_upstream_url" VARCHAR,
125    "remote_origin_url" VARCHAR,
126    PRIMARY KEY (project_id, id)
127);
128
129CREATE INDEX "index_project_repositories_on_project_id" ON "project_repositories" ("project_id");
130
131CREATE TABLE "project_repository_statuses" (
132    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
133    "repository_id" INTEGER NOT NULL,
134    "repo_path" VARCHAR NOT NULL,
135    "status" INT8 NOT NULL,
136    "status_kind" INT4 NOT NULL,
137    "first_status" INT4 NULL,
138    "second_status" INT4 NULL,
139    "scan_id" INT8 NOT NULL,
140    "is_deleted" BOOL NOT NULL,
141    PRIMARY KEY (project_id, repository_id, repo_path)
142);
143
144CREATE INDEX "index_project_repos_statuses_on_project_id" ON "project_repository_statuses" ("project_id");
145
146CREATE INDEX "index_project_repos_statuses_on_project_id_and_repo_id" ON "project_repository_statuses" ("project_id", "repository_id");
147
148CREATE TABLE "worktree_settings_files" (
149    "project_id" INTEGER NOT NULL,
150    "worktree_id" INTEGER NOT NULL,
151    "path" VARCHAR NOT NULL,
152    "content" TEXT,
153    "kind" VARCHAR,
154    PRIMARY KEY (project_id, worktree_id, path),
155    FOREIGN KEY (project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
156);
157
158CREATE INDEX "index_worktree_settings_files_on_project_id" ON "worktree_settings_files" ("project_id");
159
160CREATE INDEX "index_worktree_settings_files_on_project_id_and_worktree_id" ON "worktree_settings_files" ("project_id", "worktree_id");
161
162CREATE TABLE "worktree_diagnostic_summaries" (
163    "project_id" INTEGER NOT NULL,
164    "worktree_id" INTEGER NOT NULL,
165    "path" VARCHAR NOT NULL,
166    "language_server_id" INTEGER NOT NULL,
167    "error_count" INTEGER NOT NULL,
168    "warning_count" INTEGER NOT NULL,
169    PRIMARY KEY (project_id, worktree_id, path),
170    FOREIGN KEY (project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
171);
172
173CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id" ON "worktree_diagnostic_summaries" ("project_id");
174
175CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id_and_worktree_id" ON "worktree_diagnostic_summaries" ("project_id", "worktree_id");
176
177CREATE TABLE "language_servers" (
178    "id" INTEGER NOT NULL,
179    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
180    "name" VARCHAR NOT NULL,
181    "capabilities" TEXT NOT NULL,
182    "worktree_id" BIGINT,
183    PRIMARY KEY (project_id, id)
184);
185
186CREATE INDEX "index_language_servers_on_project_id" ON "language_servers" ("project_id");
187
188CREATE TABLE "project_collaborators" (
189    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
190    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
191    "connection_id" INTEGER NOT NULL,
192    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
193    "user_id" INTEGER NOT NULL,
194    "replica_id" INTEGER NOT NULL,
195    "is_host" BOOLEAN NOT NULL,
196    "committer_name" VARCHAR,
197    "committer_email" VARCHAR
198);
199
200CREATE INDEX "index_project_collaborators_on_project_id" ON "project_collaborators" ("project_id");
201
202CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_and_replica_id" ON "project_collaborators" ("project_id", "replica_id");
203
204CREATE INDEX "index_project_collaborators_on_connection_server_id" ON "project_collaborators" ("connection_server_id");
205
206CREATE INDEX "index_project_collaborators_on_connection_id" ON "project_collaborators" ("connection_id");
207
208CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_connection_id_and_server_id" ON "project_collaborators" (
209    "project_id",
210    "connection_id",
211    "connection_server_id"
212);
213
214CREATE TABLE "room_participants" (
215    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
216    "room_id" INTEGER NOT NULL REFERENCES rooms (id),
217    "user_id" INTEGER NOT NULL REFERENCES users (id),
218    "answering_connection_id" INTEGER,
219    "answering_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
220    "answering_connection_lost" BOOLEAN NOT NULL,
221    "location_kind" INTEGER,
222    "location_project_id" INTEGER,
223    "initial_project_id" INTEGER,
224    "calling_user_id" INTEGER NOT NULL REFERENCES users (id),
225    "calling_connection_id" INTEGER NOT NULL,
226    "calling_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE SET NULL,
227    "participant_index" INTEGER,
228    "role" TEXT,
229    "in_call" BOOLEAN NOT NULL DEFAULT FALSE
230);
231
232CREATE UNIQUE INDEX "index_room_participants_on_user_id" ON "room_participants" ("user_id");
233
234CREATE INDEX "index_room_participants_on_room_id" ON "room_participants" ("room_id");
235
236CREATE INDEX "index_room_participants_on_answering_connection_server_id" ON "room_participants" ("answering_connection_server_id");
237
238CREATE INDEX "index_room_participants_on_calling_connection_server_id" ON "room_participants" ("calling_connection_server_id");
239
240CREATE INDEX "index_room_participants_on_answering_connection_id" ON "room_participants" ("answering_connection_id");
241
242CREATE UNIQUE INDEX "index_room_participants_on_answering_connection_id_and_answering_connection_server_id" ON "room_participants" (
243    "answering_connection_id",
244    "answering_connection_server_id"
245);
246
247CREATE TABLE "servers" (
248    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
249    "environment" VARCHAR NOT NULL
250);
251
252CREATE TABLE "followers" (
253    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
254    "room_id" INTEGER NOT NULL REFERENCES rooms (id) ON DELETE CASCADE,
255    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
256    "leader_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
257    "leader_connection_id" INTEGER NOT NULL,
258    "follower_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
259    "follower_connection_id" INTEGER NOT NULL
260);
261
262CREATE UNIQUE INDEX "index_followers_on_project_id_and_leader_connection_server_id_and_leader_connection_id_and_follower_connection_server_id_and_follower_connection_id" ON "followers" (
263    "project_id",
264    "leader_connection_server_id",
265    "leader_connection_id",
266    "follower_connection_server_id",
267    "follower_connection_id"
268);
269
270CREATE INDEX "index_followers_on_room_id" ON "followers" ("room_id");
271
272CREATE TABLE "channels" (
273    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
274    "name" VARCHAR NOT NULL,
275    "created_at" TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
276    "visibility" VARCHAR NOT NULL,
277    "parent_path" TEXT NOT NULL,
278    "requires_zed_cla" BOOLEAN NOT NULL DEFAULT FALSE,
279    "channel_order" INTEGER NOT NULL DEFAULT 1
280);
281
282CREATE INDEX "index_channels_on_parent_path" ON "channels" ("parent_path");
283
284CREATE INDEX "index_channels_on_parent_path_and_order" ON "channels" ("parent_path", "channel_order");
285
286CREATE TABLE IF NOT EXISTS "channel_chat_participants" (
287    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
288    "user_id" INTEGER NOT NULL REFERENCES users (id),
289    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
290    "connection_id" INTEGER NOT NULL,
291    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE
292);
293
294CREATE INDEX "index_channel_chat_participants_on_channel_id" ON "channel_chat_participants" ("channel_id");
295
296CREATE TABLE "channel_members" (
297    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
298    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
299    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
300    "role" VARCHAR NOT NULL,
301    "accepted" BOOLEAN NOT NULL DEFAULT false,
302    "updated_at" TIMESTAMP NOT NULL DEFAULT now
303);
304
305CREATE UNIQUE INDEX "index_channel_members_on_channel_id_and_user_id" ON "channel_members" ("channel_id", "user_id");
306
307CREATE TABLE "buffers" (
308    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
309    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
310    "epoch" INTEGER NOT NULL DEFAULT 0,
311    "latest_operation_epoch" INTEGER,
312    "latest_operation_replica_id" INTEGER,
313    "latest_operation_lamport_timestamp" INTEGER
314);
315
316CREATE INDEX "index_buffers_on_channel_id" ON "buffers" ("channel_id");
317
318CREATE TABLE "buffer_operations" (
319    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
320    "epoch" INTEGER NOT NULL,
321    "replica_id" INTEGER NOT NULL,
322    "lamport_timestamp" INTEGER NOT NULL,
323    "value" BLOB NOT NULL,
324    PRIMARY KEY (buffer_id, epoch, lamport_timestamp, replica_id)
325);
326
327CREATE TABLE "buffer_snapshots" (
328    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
329    "epoch" INTEGER NOT NULL,
330    "text" TEXT NOT NULL,
331    "operation_serialization_version" INTEGER NOT NULL,
332    PRIMARY KEY (buffer_id, epoch)
333);
334
335CREATE TABLE "channel_buffer_collaborators" (
336    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
337    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
338    "connection_id" INTEGER NOT NULL,
339    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
340    "connection_lost" BOOLEAN NOT NULL DEFAULT false,
341    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
342    "replica_id" INTEGER NOT NULL
343);
344
345CREATE INDEX "index_channel_buffer_collaborators_on_channel_id" ON "channel_buffer_collaborators" ("channel_id");
346
347CREATE UNIQUE INDEX "index_channel_buffer_collaborators_on_channel_id_and_replica_id" ON "channel_buffer_collaborators" ("channel_id", "replica_id");
348
349CREATE INDEX "index_channel_buffer_collaborators_on_connection_server_id" ON "channel_buffer_collaborators" ("connection_server_id");
350
351CREATE INDEX "index_channel_buffer_collaborators_on_connection_id" ON "channel_buffer_collaborators" ("connection_id");
352
353CREATE UNIQUE INDEX "index_channel_buffer_collaborators_on_channel_id_connection_id_and_server_id" ON "channel_buffer_collaborators" (
354    "channel_id",
355    "connection_id",
356    "connection_server_id"
357);
358
359CREATE TABLE "feature_flags" (
360    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
361    "flag" TEXT NOT NULL UNIQUE,
362    "enabled_for_all" BOOLEAN NOT NULL DEFAULT false
363);
364
365CREATE INDEX "index_feature_flags" ON "feature_flags" ("id");
366
367CREATE TABLE "user_features" (
368    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
369    "feature_id" INTEGER NOT NULL REFERENCES feature_flags (id) ON DELETE CASCADE,
370    PRIMARY KEY (user_id, feature_id)
371);
372
373CREATE UNIQUE INDEX "index_user_features_user_id_and_feature_id" ON "user_features" ("user_id", "feature_id");
374
375CREATE INDEX "index_user_features_on_user_id" ON "user_features" ("user_id");
376
377CREATE INDEX "index_user_features_on_feature_id" ON "user_features" ("feature_id");
378
379CREATE TABLE "observed_buffer_edits" (
380    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
381    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
382    "epoch" INTEGER NOT NULL,
383    "lamport_timestamp" INTEGER NOT NULL,
384    "replica_id" INTEGER NOT NULL,
385    PRIMARY KEY (user_id, buffer_id)
386);
387
388CREATE UNIQUE INDEX "index_observed_buffers_user_and_buffer_id" ON "observed_buffer_edits" ("user_id", "buffer_id");
389
390CREATE TABLE "notification_kinds" (
391    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
392    "name" VARCHAR NOT NULL
393);
394
395CREATE UNIQUE INDEX "index_notification_kinds_on_name" ON "notification_kinds" ("name");
396
397CREATE TABLE "notifications" (
398    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
399    "created_at" TIMESTAMP NOT NULL default CURRENT_TIMESTAMP,
400    "recipient_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
401    "kind" INTEGER NOT NULL REFERENCES notification_kinds (id),
402    "entity_id" INTEGER,
403    "content" TEXT,
404    "is_read" BOOLEAN NOT NULL DEFAULT FALSE,
405    "response" BOOLEAN
406);
407
408CREATE INDEX "index_notifications_on_recipient_id_is_read_kind_entity_id" ON "notifications" ("recipient_id", "is_read", "kind", "entity_id");
409
410CREATE TABLE contributors (
411    user_id INTEGER REFERENCES users (id),
412    signed_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
413    PRIMARY KEY (user_id)
414);
415
416CREATE TABLE extensions (
417    id INTEGER PRIMARY KEY AUTOINCREMENT,
418    external_id TEXT NOT NULL,
419    name TEXT NOT NULL,
420    latest_version TEXT NOT NULL,
421    total_download_count INTEGER NOT NULL DEFAULT 0
422);
423
424CREATE TABLE extension_versions (
425    extension_id INTEGER REFERENCES extensions (id),
426    version TEXT NOT NULL,
427    published_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
428    authors TEXT NOT NULL,
429    repository TEXT NOT NULL,
430    description TEXT NOT NULL,
431    schema_version INTEGER NOT NULL DEFAULT 0,
432    wasm_api_version TEXT,
433    download_count INTEGER NOT NULL DEFAULT 0,
434    provides_themes BOOLEAN NOT NULL DEFAULT FALSE,
435    provides_icon_themes BOOLEAN NOT NULL DEFAULT FALSE,
436    provides_languages BOOLEAN NOT NULL DEFAULT FALSE,
437    provides_grammars BOOLEAN NOT NULL DEFAULT FALSE,
438    provides_language_servers BOOLEAN NOT NULL DEFAULT FALSE,
439    provides_context_servers BOOLEAN NOT NULL DEFAULT FALSE,
440    provides_agent_servers BOOLEAN NOT NULL DEFAULT FALSE,
441    provides_slash_commands BOOLEAN NOT NULL DEFAULT FALSE,
442    provides_indexed_docs_providers BOOLEAN NOT NULL DEFAULT FALSE,
443    provides_snippets BOOLEAN NOT NULL DEFAULT FALSE,
444    provides_debug_adapters BOOLEAN NOT NULL DEFAULT FALSE,
445    PRIMARY KEY (extension_id, version)
446);
447
448CREATE UNIQUE INDEX "index_extensions_external_id" ON "extensions" ("external_id");
449
450CREATE INDEX "index_extensions_total_download_count" ON "extensions" ("total_download_count");
451
452CREATE TABLE IF NOT EXISTS "breakpoints" (
453    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
454    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
455    "position" INTEGER NOT NULL,
456    "log_message" TEXT NULL,
457    "worktree_id" BIGINT NOT NULL,
458    "path" TEXT NOT NULL,
459    "kind" VARCHAR NOT NULL
460);
461
462CREATE INDEX "index_breakpoints_on_project_id" ON "breakpoints" ("project_id");