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