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 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    "hash" VARCHAR(128)
 23);
 24CREATE INDEX "index_access_tokens_user_id" ON "access_tokens" ("user_id");
 25
 26CREATE TABLE "contacts" (
 27    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 28    "user_id_a" INTEGER REFERENCES users (id) NOT NULL,
 29    "user_id_b" INTEGER REFERENCES users (id) NOT NULL,
 30    "a_to_b" BOOLEAN NOT NULL,
 31    "should_notify" BOOLEAN NOT NULL,
 32    "accepted" BOOLEAN NOT NULL
 33);
 34CREATE UNIQUE INDEX "index_contacts_user_ids" ON "contacts" ("user_id_a", "user_id_b");
 35CREATE INDEX "index_contacts_user_id_b" ON "contacts" ("user_id_b");
 36
 37CREATE TABLE "rooms" (
 38    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 39    "live_kit_room" VARCHAR NOT NULL,
 40    "release_channel" VARCHAR,
 41    "channel_id" INTEGER REFERENCES channels (id) ON DELETE CASCADE
 42);
 43
 44CREATE TABLE "projects" (
 45    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
 46    "room_id" INTEGER REFERENCES rooms (id) NOT NULL,
 47    "host_user_id" INTEGER REFERENCES users (id) NOT NULL,
 48    "host_connection_id" INTEGER,
 49    "host_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
 50    "unregistered" BOOLEAN NOT NULL DEFAULT FALSE
 51);
 52CREATE INDEX "index_projects_on_host_connection_server_id" ON "projects" ("host_connection_server_id");
 53CREATE INDEX "index_projects_on_host_connection_id_and_host_connection_server_id" ON "projects" ("host_connection_id", "host_connection_server_id");
 54
 55CREATE TABLE "worktrees" (
 56    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
 57    "id" INTEGER NOT NULL,
 58    "root_name" VARCHAR NOT NULL,
 59    "abs_path" VARCHAR NOT NULL,
 60    "visible" BOOL NOT NULL,
 61    "scan_id" INTEGER NOT NULL,
 62    "is_complete" BOOL NOT NULL DEFAULT FALSE,
 63    "completed_scan_id" INTEGER NOT NULL,
 64    PRIMARY KEY(project_id, id)
 65);
 66CREATE INDEX "index_worktrees_on_project_id" ON "worktrees" ("project_id");
 67
 68CREATE TABLE "worktree_entries" (
 69    "project_id" INTEGER NOT NULL,
 70    "worktree_id" INTEGER NOT NULL,
 71    "scan_id" INTEGER NOT NULL,
 72    "id" INTEGER NOT NULL,
 73    "is_dir" BOOL NOT NULL,
 74    "path" VARCHAR NOT NULL,
 75    "inode" INTEGER NOT NULL,
 76    "mtime_seconds" INTEGER NOT NULL,
 77    "mtime_nanos" INTEGER NOT NULL,
 78    "is_symlink" BOOL NOT NULL,
 79    "is_external" BOOL NOT NULL,
 80    "is_ignored" BOOL NOT NULL,
 81    "is_deleted" BOOL NOT NULL,
 82    "git_status" INTEGER,
 83    PRIMARY KEY(project_id, worktree_id, id),
 84    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
 85);
 86CREATE INDEX "index_worktree_entries_on_project_id" ON "worktree_entries" ("project_id");
 87CREATE INDEX "index_worktree_entries_on_project_id_and_worktree_id" ON "worktree_entries" ("project_id", "worktree_id");
 88
 89CREATE TABLE "worktree_repositories" (
 90    "project_id" INTEGER NOT NULL,
 91    "worktree_id" INTEGER NOT NULL,
 92    "work_directory_id" INTEGER NOT NULL,
 93    "branch" VARCHAR,
 94    "scan_id" INTEGER NOT NULL,
 95    "is_deleted" BOOL NOT NULL,
 96    PRIMARY KEY(project_id, worktree_id, work_directory_id),
 97    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE,
 98    FOREIGN KEY(project_id, worktree_id, work_directory_id) REFERENCES worktree_entries (project_id, worktree_id, id) ON DELETE CASCADE
 99);
100CREATE INDEX "index_worktree_repositories_on_project_id" ON "worktree_repositories" ("project_id");
101CREATE INDEX "index_worktree_repositories_on_project_id_and_worktree_id" ON "worktree_repositories" ("project_id", "worktree_id");
102
103CREATE TABLE "worktree_settings_files" (
104    "project_id" INTEGER NOT NULL,
105    "worktree_id" INTEGER NOT NULL,
106    "path" VARCHAR NOT NULL,
107    "content" TEXT,
108    PRIMARY KEY(project_id, worktree_id, path),
109    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
110);
111CREATE INDEX "index_worktree_settings_files_on_project_id" ON "worktree_settings_files" ("project_id");
112CREATE INDEX "index_worktree_settings_files_on_project_id_and_worktree_id" ON "worktree_settings_files" ("project_id", "worktree_id");
113
114CREATE TABLE "worktree_diagnostic_summaries" (
115    "project_id" INTEGER NOT NULL,
116    "worktree_id" INTEGER NOT NULL,
117    "path" VARCHAR NOT NULL,
118    "language_server_id" INTEGER NOT NULL,
119    "error_count" INTEGER NOT NULL,
120    "warning_count" INTEGER NOT NULL,
121    PRIMARY KEY(project_id, worktree_id, path),
122    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
123);
124CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id" ON "worktree_diagnostic_summaries" ("project_id");
125CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id_and_worktree_id" ON "worktree_diagnostic_summaries" ("project_id", "worktree_id");
126
127CREATE TABLE "language_servers" (
128    "id" INTEGER NOT NULL,
129    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
130    "name" VARCHAR NOT NULL,
131    PRIMARY KEY(project_id, id)
132);
133CREATE INDEX "index_language_servers_on_project_id" ON "language_servers" ("project_id");
134
135CREATE TABLE "project_collaborators" (
136    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
137    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
138    "connection_id" INTEGER NOT NULL,
139    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
140    "user_id" INTEGER NOT NULL,
141    "replica_id" INTEGER NOT NULL,
142    "is_host" BOOLEAN NOT NULL
143);
144CREATE INDEX "index_project_collaborators_on_project_id" ON "project_collaborators" ("project_id");
145CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_and_replica_id" ON "project_collaborators" ("project_id", "replica_id");
146CREATE INDEX "index_project_collaborators_on_connection_server_id" ON "project_collaborators" ("connection_server_id");
147CREATE INDEX "index_project_collaborators_on_connection_id" ON "project_collaborators" ("connection_id");
148CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_connection_id_and_server_id" ON "project_collaborators" ("project_id", "connection_id", "connection_server_id");
149
150CREATE TABLE "room_participants" (
151    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
152    "room_id" INTEGER NOT NULL REFERENCES rooms (id),
153    "user_id" INTEGER NOT NULL REFERENCES users (id),
154    "answering_connection_id" INTEGER,
155    "answering_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE CASCADE,
156    "answering_connection_lost" BOOLEAN NOT NULL,
157    "location_kind" INTEGER,
158    "location_project_id" INTEGER,
159    "initial_project_id" INTEGER,
160    "calling_user_id" INTEGER NOT NULL REFERENCES users (id),
161    "calling_connection_id" INTEGER NOT NULL,
162    "calling_connection_server_id" INTEGER REFERENCES servers (id) ON DELETE SET NULL,
163    "participant_index" INTEGER
164);
165CREATE UNIQUE INDEX "index_room_participants_on_user_id" ON "room_participants" ("user_id");
166CREATE INDEX "index_room_participants_on_room_id" ON "room_participants" ("room_id");
167CREATE INDEX "index_room_participants_on_answering_connection_server_id" ON "room_participants" ("answering_connection_server_id");
168CREATE INDEX "index_room_participants_on_calling_connection_server_id" ON "room_participants" ("calling_connection_server_id");
169CREATE INDEX "index_room_participants_on_answering_connection_id" ON "room_participants" ("answering_connection_id");
170CREATE UNIQUE INDEX "index_room_participants_on_answering_connection_id_and_answering_connection_server_id" ON "room_participants" ("answering_connection_id", "answering_connection_server_id");
171
172CREATE TABLE "servers" (
173    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
174    "environment" VARCHAR NOT NULL
175);
176
177CREATE TABLE "followers" (
178    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
179    "room_id" INTEGER NOT NULL REFERENCES rooms (id) ON DELETE CASCADE,
180    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
181    "leader_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
182    "leader_connection_id" INTEGER NOT NULL,
183    "follower_connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
184    "follower_connection_id" INTEGER NOT NULL
185);
186CREATE UNIQUE INDEX
187    "index_followers_on_project_id_and_leader_connection_server_id_and_leader_connection_id_and_follower_connection_server_id_and_follower_connection_id"
188ON "followers" ("project_id", "leader_connection_server_id", "leader_connection_id", "follower_connection_server_id", "follower_connection_id");
189CREATE INDEX "index_followers_on_room_id" ON "followers" ("room_id");
190
191CREATE TABLE "channels" (
192    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
193    "name" VARCHAR NOT NULL,
194    "created_at" TIMESTAMP NOT NULL DEFAULT now
195);
196
197CREATE TABLE IF NOT EXISTS "channel_chat_participants" (
198    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
199    "user_id" INTEGER NOT NULL REFERENCES users (id),
200    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
201    "connection_id" INTEGER NOT NULL,
202    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE
203);
204CREATE INDEX "index_channel_chat_participants_on_channel_id" ON "channel_chat_participants" ("channel_id");
205
206CREATE TABLE IF NOT EXISTS "channel_messages" (
207    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
208    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
209    "sender_id" INTEGER NOT NULL REFERENCES users (id),
210    "body" TEXT NOT NULL,
211    "sent_at" TIMESTAMP,
212    "nonce" BLOB NOT NULL
213);
214CREATE INDEX "index_channel_messages_on_channel_id" ON "channel_messages" ("channel_id");
215CREATE UNIQUE INDEX "index_channel_messages_on_nonce" ON "channel_messages" ("nonce");
216
217CREATE TABLE "channel_paths" (
218    "id_path" TEXT NOT NULL PRIMARY KEY,
219    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE
220);
221CREATE INDEX "index_channel_paths_on_channel_id" ON "channel_paths" ("channel_id");
222
223CREATE TABLE "channel_members" (
224    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
225    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
226    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
227    "admin" BOOLEAN NOT NULL DEFAULT false,
228    "accepted" BOOLEAN NOT NULL DEFAULT false,
229    "updated_at" TIMESTAMP NOT NULL DEFAULT now
230);
231
232CREATE UNIQUE INDEX "index_channel_members_on_channel_id_and_user_id" ON "channel_members" ("channel_id", "user_id");
233
234CREATE TABLE "buffers" (
235    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
236    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
237    "epoch" INTEGER NOT NULL DEFAULT 0
238);
239
240CREATE INDEX "index_buffers_on_channel_id" ON "buffers" ("channel_id");
241
242CREATE TABLE "buffer_operations" (
243    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
244    "epoch" INTEGER NOT NULL,
245    "replica_id" INTEGER NOT NULL,
246    "lamport_timestamp" INTEGER NOT NULL,
247    "value" BLOB NOT NULL,
248    PRIMARY KEY(buffer_id, epoch, lamport_timestamp, replica_id)
249);
250
251CREATE TABLE "buffer_snapshots" (
252    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
253    "epoch" INTEGER NOT NULL,
254    "text" TEXT NOT NULL,
255    "operation_serialization_version" INTEGER NOT NULL,
256    PRIMARY KEY(buffer_id, epoch)
257);
258
259CREATE TABLE "channel_buffer_collaborators" (
260    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
261    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
262    "connection_id" INTEGER NOT NULL,
263    "connection_server_id" INTEGER NOT NULL REFERENCES servers (id) ON DELETE CASCADE,
264    "connection_lost" BOOLEAN NOT NULL DEFAULT false,
265    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
266    "replica_id" INTEGER NOT NULL
267);
268
269CREATE INDEX "index_channel_buffer_collaborators_on_channel_id" ON "channel_buffer_collaborators" ("channel_id");
270CREATE UNIQUE INDEX "index_channel_buffer_collaborators_on_channel_id_and_replica_id" ON "channel_buffer_collaborators" ("channel_id", "replica_id");
271CREATE INDEX "index_channel_buffer_collaborators_on_connection_server_id" ON "channel_buffer_collaborators" ("connection_server_id");
272CREATE INDEX "index_channel_buffer_collaborators_on_connection_id" ON "channel_buffer_collaborators" ("connection_id");
273CREATE 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");
274
275
276CREATE TABLE "feature_flags" (
277    "id" INTEGER PRIMARY KEY AUTOINCREMENT,
278    "flag" TEXT NOT NULL UNIQUE
279);
280
281CREATE INDEX "index_feature_flags" ON "feature_flags" ("id");
282
283
284CREATE TABLE "user_features" (
285    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
286    "feature_id" INTEGER NOT NULL REFERENCES feature_flags (id) ON DELETE CASCADE,
287    PRIMARY KEY (user_id, feature_id)
288);
289
290CREATE UNIQUE INDEX "index_user_features_user_id_and_feature_id" ON "user_features" ("user_id", "feature_id");
291CREATE INDEX "index_user_features_on_user_id" ON "user_features" ("user_id");
292CREATE INDEX "index_user_features_on_feature_id" ON "user_features" ("feature_id");
293
294
295CREATE TABLE "observed_buffer_edits" (
296    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
297    "buffer_id" INTEGER NOT NULL REFERENCES buffers (id) ON DELETE CASCADE,
298    "epoch" INTEGER NOT NULL,
299    "lamport_timestamp" INTEGER NOT NULL,
300    "replica_id" INTEGER NOT NULL,
301    PRIMARY KEY (user_id, buffer_id)
302);
303
304CREATE UNIQUE INDEX "index_observed_buffers_user_and_buffer_id" ON "observed_buffer_edits" ("user_id", "buffer_id");
305
306CREATE TABLE IF NOT EXISTS "observed_channel_messages" (
307    "user_id" INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE,
308    "channel_id" INTEGER NOT NULL REFERENCES channels (id) ON DELETE CASCADE,
309    "channel_message_id" INTEGER NOT NULL,
310    PRIMARY KEY (user_id, channel_id)
311);
312
313CREATE UNIQUE INDEX "index_observed_channel_messages_user_and_channel_id" ON "observed_channel_messages" ("user_id", "channel_id");