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