-- +goose Up -- Users Table CREATE TABLE "users" ( "telegram_id" BIGINT PRIMARY KEY, "username" VARCHAR(255), "first_name" VARCHAR(255), "last_name" VARCHAR(255), "stars_balance" INT NOT NULL DEFAULT 0, "created_at" TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Quizzes Table CREATE TABLE "quizzes" ( "id" SERIAL PRIMARY KEY, "title" VARCHAR(255) NOT NULL, "description" TEXT, "image_url" VARCHAR(255), "reward_stars" INT NOT NULL DEFAULT 0, "has_timer" BOOLEAN NOT NULL DEFAULT false, "timer_per_question" INT, "can_repeat" BOOLEAN NOT NULL DEFAULT false, "repeat_cooldown_hours" INT, "is_active" BOOLEAN NOT NULL DEFAULT true, "created_by" BIGINT, "created_at" TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Questions Table CREATE TYPE question_type AS ENUM ('single', 'multiple'); CREATE TABLE "questions" ( "id" SERIAL PRIMARY KEY, "quiz_id" INT NOT NULL REFERENCES "quizzes"("id") ON DELETE CASCADE, "text" TEXT NOT NULL, "type" question_type NOT NULL, "options" JSONB NOT NULL, -- [{"id": 1, "text": "Option A", "is_correct": true}] "order_index" INT NOT NULL ); -- Quiz Attempts Table CREATE TABLE "quiz_attempts" ( "id" SERIAL PRIMARY KEY, "user_id" BIGINT NOT NULL REFERENCES "users"("telegram_id") ON DELETE CASCADE, "quiz_id" INT NOT NULL REFERENCES "quizzes"("id") ON DELETE CASCADE, "score" INT NOT NULL, "stars_earned" INT NOT NULL, "completed_at" TIMESTAMPTZ NOT NULL DEFAULT NOW(), "answers" JSONB ); -- Rewards (Prizes) Table CREATE TYPE delivery_type AS ENUM ('physical', 'digital'); CREATE TABLE "rewards" ( "id" SERIAL PRIMARY KEY, "title" VARCHAR(255) NOT NULL, "description" TEXT, "image_url" VARCHAR(255), "price_stars" INT NOT NULL, "delivery_type" delivery_type NOT NULL, "instructions" TEXT, "stock" INT NOT NULL DEFAULT 0, -- 0 for infinite "is_active" BOOLEAN NOT NULL DEFAULT true, "created_by" BIGINT, "created_at" TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Purchases Table CREATE TYPE purchase_status AS ENUM ('pending', 'delivered', 'cancelled'); CREATE TABLE "purchases" ( "id" SERIAL PRIMARY KEY, "user_id" BIGINT NOT NULL REFERENCES "users"("telegram_id") ON DELETE CASCADE, "reward_id" INT NOT NULL REFERENCES "rewards"("id") ON DELETE CASCADE, "stars_spent" INT NOT NULL, "purchased_at" TIMESTAMPTZ NOT NULL DEFAULT NOW(), "status" purchase_status NOT NULL DEFAULT 'pending' ); -- QR Scans Table CREATE TYPE qr_scan_type AS ENUM ('reward', 'quiz', 'shop'); CREATE TYPE qr_scan_source AS ENUM ('in_app', 'external'); CREATE TABLE "qr_scans" ( "id" SERIAL PRIMARY KEY, "user_id" BIGINT NOT NULL REFERENCES "users"("telegram_id") ON DELETE CASCADE, "type" qr_scan_type NOT NULL, "value" VARCHAR(255), "scanned_at" TIMESTAMPTZ NOT NULL DEFAULT NOW(), "source" qr_scan_source NOT NULL ); -- Admins & Operators Table CREATE TYPE admin_role AS ENUM ('admin', 'operator'); CREATE TABLE "admins" ( "telegram_id" BIGINT PRIMARY KEY, "role" admin_role NOT NULL, "name" VARCHAR(255), "added_by" BIGINT, "added_at" TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Add foreign key constraints for created_by fields ALTER TABLE "quizzes" ADD FOREIGN KEY ("created_by") REFERENCES "admins"("telegram_id"); ALTER TABLE "rewards" ADD FOREIGN KEY ("created_by") REFERENCES "admins"("telegram_id"); ALTER TABLE "admins" ADD FOREIGN KEY ("added_by") REFERENCES "admins"("telegram_id"); -- Indexes for performance CREATE INDEX ON "quiz_attempts" ("user_id", "quiz_id"); CREATE INDEX ON "purchases" ("user_id"); CREATE INDEX ON "qr_scans" ("user_id"); -- +goose Down -- Drop all tables in reverse order of creation DROP TABLE IF EXISTS "purchases"; DROP TABLE IF EXISTS "quiz_attempts"; DROP TABLE IF EXISTS "questions"; DROP TABLE IF EXISTS "rewards"; DROP TABLE IF EXISTS "quizzes"; DROP TABLE IF EXISTS "qr_scans"; DROP TABLE IF EXISTS "users"; DROP TABLE IF EXISTS "admins"; -- Drop custom types DROP TYPE IF EXISTS "question_type"; DROP TYPE IF EXISTS "delivery_type"; DROP TYPE IF EXISTS "purchase_status"; DROP TYPE IF EXISTS "qr_scan_type"; DROP TYPE IF EXISTS "qr_scan_source"; DROP TYPE IF EXISTS "admin_role";