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