20221109000000_test_schema.sql

  1CREATE TABLE "users" (
  2    "id" INTEGER PRIMARY KEY,
  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 now,
 11    "metrics_id" TEXT,
 12    "github_user_id" INTEGER
 13);
 14CREATE UNIQUE INDEX "index_users_github_login" ON "users" ("github_login");
 15CREATE UNIQUE INDEX "index_invite_code_users" ON "users" ("invite_code");
 16CREATE INDEX "index_users_on_email_address" ON "users" ("email_address");
 17CREATE INDEX "index_users_on_github_user_id" ON "users" ("github_user_id");
 18
 19CREATE TABLE "access_tokens" (
 20    "id" INTEGER PRIMARY KEY,
 21    "user_id" INTEGER REFERENCES users (id),
 22    "hash" VARCHAR(128)
 23);
 24CREATE INDEX "index_access_tokens_user_id" ON "access_tokens" ("user_id");
 25
 26CREATE TABLE "contacts" (
 27    "id" INTEGER PRIMARY KEY,
 28    "user_id_a" INTEGER REFERENCES users (id) NOT NULL,
 29    "user_id_b" INTEGER REFERENCES users (id) NOT NULL,
 30    "a_to_b" BOOLEAN NOT NULL,
 31    "should_notify" BOOLEAN NOT NULL,
 32    "accepted" BOOLEAN NOT NULL
 33);
 34CREATE UNIQUE INDEX "index_contacts_user_ids" ON "contacts" ("user_id_a", "user_id_b");
 35CREATE INDEX "index_contacts_user_id_b" ON "contacts" ("user_id_b");
 36
 37CREATE TABLE "rooms" (
 38    "id" INTEGER PRIMARY KEY,
 39    "live_kit_room" VARCHAR NOT NULL
 40);
 41
 42CREATE TABLE "projects" (
 43    "id" INTEGER PRIMARY KEY,
 44    "room_id" INTEGER REFERENCES rooms (id) NOT NULL,
 45    "host_user_id" INTEGER REFERENCES users (id) NOT NULL,
 46    "host_connection_id" INTEGER NOT NULL,
 47    "host_connection_epoch" TEXT NOT NULL
 48);
 49CREATE INDEX "index_projects_on_host_connection_epoch" ON "projects" ("host_connection_epoch");
 50
 51CREATE TABLE "worktrees" (
 52    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
 53    "id" INTEGER NOT NULL,
 54    "root_name" VARCHAR NOT NULL,
 55    "abs_path" VARCHAR NOT NULL,
 56    "visible" BOOL NOT NULL,
 57    "scan_id" INTEGER NOT NULL,
 58    "is_complete" BOOL NOT NULL,
 59    PRIMARY KEY(project_id, id)
 60);
 61CREATE INDEX "index_worktrees_on_project_id" ON "worktrees" ("project_id");
 62
 63CREATE TABLE "worktree_entries" (
 64    "project_id" INTEGER NOT NULL,
 65    "worktree_id" INTEGER NOT NULL,
 66    "id" INTEGER NOT NULL,
 67    "is_dir" BOOL NOT NULL,
 68    "path" VARCHAR NOT NULL,
 69    "inode" INTEGER NOT NULL,
 70    "mtime_seconds" INTEGER NOT NULL,
 71    "mtime_nanos" INTEGER NOT NULL,
 72    "is_symlink" BOOL NOT NULL,
 73    "is_ignored" BOOL NOT NULL,
 74    PRIMARY KEY(project_id, worktree_id, id),
 75    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
 76);
 77CREATE INDEX "index_worktree_entries_on_project_id" ON "worktree_entries" ("project_id");
 78CREATE INDEX "index_worktree_entries_on_project_id_and_worktree_id" ON "worktree_entries" ("project_id", "worktree_id");
 79
 80CREATE TABLE "worktree_diagnostic_summaries" (
 81    "project_id" INTEGER NOT NULL,
 82    "worktree_id" INTEGER NOT NULL,
 83    "path" VARCHAR NOT NULL,
 84    "language_server_id" INTEGER NOT NULL,
 85    "error_count" INTEGER NOT NULL,
 86    "warning_count" INTEGER NOT NULL,
 87    PRIMARY KEY(project_id, worktree_id, path),
 88    FOREIGN KEY(project_id, worktree_id) REFERENCES worktrees (project_id, id) ON DELETE CASCADE
 89);
 90CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id" ON "worktree_diagnostic_summaries" ("project_id");
 91CREATE INDEX "index_worktree_diagnostic_summaries_on_project_id_and_worktree_id" ON "worktree_diagnostic_summaries" ("project_id", "worktree_id");
 92
 93CREATE TABLE "language_servers" (
 94    "id" INTEGER NOT NULL,
 95    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
 96    "name" VARCHAR NOT NULL,
 97    PRIMARY KEY(project_id, id)
 98);
 99CREATE INDEX "index_language_servers_on_project_id" ON "language_servers" ("project_id");
100
101CREATE TABLE "project_collaborators" (
102    "id" INTEGER PRIMARY KEY,
103    "project_id" INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE,
104    "connection_id" INTEGER NOT NULL,
105    "connection_epoch" TEXT NOT NULL,
106    "user_id" INTEGER NOT NULL,
107    "replica_id" INTEGER NOT NULL,
108    "is_host" BOOLEAN NOT NULL
109);
110CREATE INDEX "index_project_collaborators_on_project_id" ON "project_collaborators" ("project_id");
111CREATE UNIQUE INDEX "index_project_collaborators_on_project_id_and_replica_id" ON "project_collaborators" ("project_id", "replica_id");
112CREATE INDEX "index_project_collaborators_on_connection_epoch" ON "project_collaborators" ("connection_epoch");
113
114CREATE TABLE "room_participants" (
115    "id" INTEGER PRIMARY KEY,
116    "room_id" INTEGER NOT NULL REFERENCES rooms (id),
117    "user_id" INTEGER NOT NULL REFERENCES users (id),
118    "answering_connection_id" INTEGER,
119    "answering_connection_epoch" TEXT,
120    "location_kind" INTEGER,
121    "location_project_id" INTEGER,
122    "initial_project_id" INTEGER,
123    "calling_user_id" INTEGER NOT NULL REFERENCES users (id),
124    "calling_connection_id" INTEGER NOT NULL,
125    "calling_connection_epoch" TEXT NOT NULL
126);
127CREATE UNIQUE INDEX "index_room_participants_on_user_id" ON "room_participants" ("user_id");
128CREATE INDEX "index_room_participants_on_answering_connection_epoch" ON "room_participants" ("answering_connection_epoch");
129CREATE INDEX "index_room_participants_on_calling_connection_epoch" ON "room_participants" ("calling_connection_epoch");