Prmbr/create-prompt-stats-table.sql
2025-08-03 11:48:58 +08:00

62 lines
2.1 KiB
PL/PgSQL

-- 创建 prompt_stats 表的SQL脚本
-- 这个脚本可以在Supabase SQL编辑器中手动运行
CREATE TABLE IF NOT EXISTS "public"."prompt_stats" (
"id" TEXT NOT NULL,
"promptId" TEXT NOT NULL,
"viewCount" INTEGER NOT NULL DEFAULT 0,
"likeCount" INTEGER NOT NULL DEFAULT 0,
"rating" DOUBLE PRECISION,
"ratingCount" INTEGER NOT NULL DEFAULT 0,
"createdAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updatedAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT "prompt_stats_pkey" PRIMARY KEY ("id")
);
-- 创建唯一索引
CREATE UNIQUE INDEX IF NOT EXISTS "prompt_stats_promptId_key" ON "public"."prompt_stats"("promptId");
-- 添加外键约束
ALTER TABLE "public"."prompt_stats"
ADD CONSTRAINT "prompt_stats_promptId_fkey"
FOREIGN KEY ("promptId") REFERENCES "public"."prompts"("id")
ON DELETE CASCADE ON UPDATE CASCADE;
-- 为查询优化添加索引
CREATE INDEX IF NOT EXISTS "prompt_stats_viewCount_idx" ON "public"."prompt_stats"("viewCount");
CREATE INDEX IF NOT EXISTS "prompt_stats_rating_idx" ON "public"."prompt_stats"("rating");
-- 创建更新时间戳的触发器
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW."updatedAt" = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';
CREATE OR REPLACE TRIGGER update_prompt_stats_updated_at
BEFORE UPDATE ON "public"."prompt_stats"
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- 插入一些示例数据(可选)
-- 为现有的公开提示词创建基础统计记录
INSERT INTO "public"."prompt_stats" ("id", "promptId", "viewCount", "likeCount", "rating", "ratingCount")
SELECT
gen_random_uuid()::text,
p.id,
floor(random() * 100 + 1)::integer, -- 随机浏览量 1-100
0,
NULL,
0
FROM "public"."prompts" p
WHERE p.permissions = 'public'
AND p.visibility = 'published'
AND NOT EXISTS (
SELECT 1 FROM "public"."prompt_stats" ps WHERE ps."promptId" = p.id
);
-- 验证创建结果
SELECT 'prompt_stats table created successfully' AS result;
SELECT COUNT(*) AS total_stats_records FROM "public"."prompt_stats";