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