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