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