2021-03-25 14:29:24 -05:00

148 lines
4.1 KiB
PL/PgSQL

-- CreateTable
CREATE TABLE "users" (
"id" SERIAL NOT NULL,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
"name" TEXT,
"email" TEXT,
"email_verified" TIMESTAMP(3),
"image" TEXT,
PRIMARY KEY ("id")
);
-- CreateTable
CREATE TABLE "Message" (
"id" SERIAL NOT NULL,
"text" TEXT NOT NULL,
"userId" INTEGER NOT NULL,
PRIMARY KEY ("id")
);
-- Edit: create extension for path
CREATE EXTENSION ltree;
-- CreateTable
CREATE TABLE "Item" (
"id" SERIAL NOT NULL,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
"text" TEXT NOT NULL,
"url" TEXT NOT NULL,
"userId" INTEGER NOT NULL,
"parentId" INTEGER,
"parentPath" LTREE,
PRIMARY KEY ("id")
);
-- Edit: create index for path
CREATE INDEX "Item.parentPath_index" ON "Item" USING GIST ("parentPath");
-- Edit: create trigger for path
CREATE OR REPLACE FUNCTION update_item_parent_path() RETURNS TRIGGER AS $$
DECLARE
path ltree;
BEGIN
IF NEW.parent_id IS NULL THEN
NEW.parent_path = 'root'::ltree;
ELSEIF TG_OP = 'INSERT' OR OLD.parent_id IS NULL OR OLD.parent_id != NEW.parent_id THEN
SELECT parent_path || id::text FROM "Item" WHERE id = NEW.parent_id INTO path;
IF path IS NULL THEN
RAISE EXCEPTION 'Invalid parent_id %', NEW.parent_id;
END IF;
NEW.parent_path = path;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER parent_path_tgr
BEFORE INSERT OR UPDATE ON "Item"
FOR EACH ROW EXECUTE PROCEDURE update_item_parent_path();
-- CreateTable
CREATE TABLE "accounts" (
"id" SERIAL NOT NULL,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
"compound_id" TEXT NOT NULL,
"user_id" INTEGER NOT NULL,
"provider_type" TEXT NOT NULL,
"provider_id" TEXT NOT NULL,
"provider_account_id" TEXT NOT NULL,
"refresh_token" TEXT,
"access_token" TEXT,
"access_token_expires" TIMESTAMP(3),
PRIMARY KEY ("id")
);
-- CreateTable
CREATE TABLE "sessions" (
"id" SERIAL NOT NULL,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
"user_id" INTEGER NOT NULL,
"expires" TIMESTAMP(3) NOT NULL,
"session_token" TEXT NOT NULL,
"access_token" TEXT NOT NULL,
PRIMARY KEY ("id")
);
-- CreateTable
CREATE TABLE "verification_requests" (
"id" SERIAL NOT NULL,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
"identifier" TEXT NOT NULL,
"token" TEXT NOT NULL,
"expires" TIMESTAMP(3) NOT NULL,
PRIMARY KEY ("id")
);
-- CreateIndex
CREATE UNIQUE INDEX "users.name_unique" ON "users"("name");
-- CreateIndex
CREATE UNIQUE INDEX "users.email_unique" ON "users"("email");
-- CreateIndex
CREATE INDEX "Item.userId_index" ON "Item"("userId");
-- CreateIndex
CREATE INDEX "Item.parentId_index" ON "Item"("parentId");
-- CreateIndex
CREATE UNIQUE INDEX "accounts.compound_id_unique" ON "accounts"("compound_id");
-- CreateIndex
CREATE INDEX "accounts.provider_account_id_index" ON "accounts"("provider_account_id");
-- CreateIndex
CREATE INDEX "accounts.provider_id_index" ON "accounts"("provider_id");
-- CreateIndex
CREATE INDEX "accounts.user_id_index" ON "accounts"("user_id");
-- CreateIndex
CREATE UNIQUE INDEX "sessions.session_token_unique" ON "sessions"("session_token");
-- CreateIndex
CREATE UNIQUE INDEX "sessions.access_token_unique" ON "sessions"("access_token");
-- CreateIndex
CREATE UNIQUE INDEX "verification_requests.token_unique" ON "verification_requests"("token");
-- AddForeignKey
ALTER TABLE "Message" ADD FOREIGN KEY ("userId") REFERENCES "users"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "Item" ADD FOREIGN KEY ("userId") REFERENCES "users"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "Item" ADD FOREIGN KEY ("parentId") REFERENCES "Item"("id") ON DELETE SET NULL ON UPDATE CASCADE;