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