feat: add initial database schema with migrations

Introduce foundational database schema with tables for `users`, `categories`, `contents`, `tags`, and `favorites`. Add foreign key relationships, constraints, and indexes for efficient querying.
This commit is contained in:
Mathis HERRIOT
2026-01-14 13:04:27 +01:00
parent 7cb5ff487d
commit 9e37272bff
4 changed files with 1543 additions and 0 deletions

View File

@@ -0,0 +1,177 @@
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
CREATE TYPE "public"."user_status" AS ENUM('active', 'verification', 'suspended', 'pending', 'deleted');--> statement-breakpoint
CREATE TYPE "public"."content_type" AS ENUM('meme', 'gif');--> statement-breakpoint
CREATE TYPE "public"."report_reason" AS ENUM('inappropriate', 'spam', 'copyright', 'other');--> statement-breakpoint
CREATE TYPE "public"."report_status" AS ENUM('pending', 'reviewed', 'resolved', 'dismissed');--> statement-breakpoint
CREATE TABLE "users" (
"uuid" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"status" "user_status" DEFAULT 'pending' NOT NULL,
"email" "bytea" NOT NULL,
"email_hash" varchar(64) NOT NULL,
"display_name" varchar(32),
"username" varchar(32) NOT NULL,
"password_hash" varchar(72) NOT NULL,
"two_factor_secret" "bytea",
"is_two_factor_enabled" boolean DEFAULT false NOT NULL,
"terms_version" varchar(16),
"privacy_version" varchar(16),
"gdpr_accepted_at" timestamp with time zone,
"last_login_at" timestamp with time zone,
"created_at" timestamp with time zone DEFAULT now() NOT NULL,
"updated_at" timestamp with time zone DEFAULT now() NOT NULL,
"deleted_at" timestamp with time zone,
CONSTRAINT "users_email_hash_unique" UNIQUE("email_hash"),
CONSTRAINT "users_username_unique" UNIQUE("username")
);
--> statement-breakpoint
CREATE TABLE "permissions" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"name" varchar(64) NOT NULL,
"slug" varchar(64) NOT NULL,
"description" varchar(128),
"created_at" timestamp with time zone DEFAULT now() NOT NULL,
CONSTRAINT "permissions_name_unique" UNIQUE("name"),
CONSTRAINT "permissions_slug_unique" UNIQUE("slug")
);
--> statement-breakpoint
CREATE TABLE "roles" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"name" varchar(64) NOT NULL,
"slug" varchar(64) NOT NULL,
"description" varchar(128),
"created_at" timestamp with time zone DEFAULT now() NOT NULL,
CONSTRAINT "roles_name_unique" UNIQUE("name"),
CONSTRAINT "roles_slug_unique" UNIQUE("slug")
);
--> statement-breakpoint
CREATE TABLE "roles_to_permissions" (
"role_id" uuid NOT NULL,
"permission_id" uuid NOT NULL,
CONSTRAINT "roles_to_permissions_role_id_permission_id_pk" PRIMARY KEY("role_id","permission_id")
);
--> statement-breakpoint
CREATE TABLE "users_to_roles" (
"user_id" uuid NOT NULL,
"role_id" uuid NOT NULL,
CONSTRAINT "users_to_roles_user_id_role_id_pk" PRIMARY KEY("user_id","role_id")
);
--> statement-breakpoint
CREATE TABLE "sessions" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"user_id" uuid NOT NULL,
"refresh_token" varchar(512) NOT NULL,
"user_agent" varchar(255),
"ip_hash" varchar(64),
"is_valid" boolean DEFAULT true NOT NULL,
"expires_at" timestamp with time zone NOT NULL,
"created_at" timestamp with time zone DEFAULT now() NOT NULL,
"updated_at" timestamp with time zone DEFAULT now() NOT NULL,
CONSTRAINT "sessions_refresh_token_unique" UNIQUE("refresh_token")
);
--> statement-breakpoint
CREATE TABLE "api_keys" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"user_id" uuid NOT NULL,
"key_hash" varchar(128) NOT NULL,
"name" varchar(128) NOT NULL,
"prefix" varchar(8) NOT NULL,
"is_active" boolean DEFAULT true NOT NULL,
"last_used_at" timestamp with time zone,
"expires_at" timestamp with time zone,
"created_at" timestamp with time zone DEFAULT now() NOT NULL,
"updated_at" timestamp with time zone DEFAULT now() NOT NULL,
CONSTRAINT "api_keys_key_hash_unique" UNIQUE("key_hash")
);
--> statement-breakpoint
CREATE TABLE "tags" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"name" varchar(64) NOT NULL,
"slug" varchar(64) NOT NULL,
"created_at" timestamp with time zone DEFAULT now() NOT NULL,
"updated_at" timestamp with time zone DEFAULT now() NOT NULL,
CONSTRAINT "tags_name_unique" UNIQUE("name"),
CONSTRAINT "tags_slug_unique" UNIQUE("slug")
);
--> statement-breakpoint
CREATE TABLE "contents" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"user_id" uuid NOT NULL,
"type" "content_type" NOT NULL,
"title" varchar(255) NOT NULL,
"storage_key" varchar(512) NOT NULL,
"mime_type" varchar(128) NOT NULL,
"file_size" integer NOT NULL,
"created_at" timestamp with time zone DEFAULT now() NOT NULL,
"updated_at" timestamp with time zone DEFAULT now() NOT NULL,
"deleted_at" timestamp with time zone,
CONSTRAINT "contents_storage_key_unique" UNIQUE("storage_key")
);
--> statement-breakpoint
CREATE TABLE "contents_to_tags" (
"content_id" uuid NOT NULL,
"tag_id" uuid NOT NULL,
CONSTRAINT "contents_to_tags_content_id_tag_id_pk" PRIMARY KEY("content_id","tag_id")
);
--> statement-breakpoint
CREATE TABLE "reports" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"reporter_id" uuid NOT NULL,
"content_id" uuid,
"tag_id" uuid,
"reason" "report_reason" NOT NULL,
"description" text,
"status" "report_status" DEFAULT 'pending' NOT NULL,
"expires_at" timestamp with time zone,
"created_at" timestamp with time zone DEFAULT now() NOT NULL,
"updated_at" timestamp with time zone DEFAULT now() NOT NULL
);
--> statement-breakpoint
CREATE TABLE "audit_logs" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"user_id" uuid,
"action" varchar(64) NOT NULL,
"entity_type" varchar(64) NOT NULL,
"entity_id" uuid,
"details" jsonb,
"ip_hash" varchar(64),
"user_agent" varchar(255),
"created_at" timestamp with time zone DEFAULT now() NOT NULL
);
--> statement-breakpoint
ALTER TABLE "roles_to_permissions" ADD CONSTRAINT "roles_to_permissions_role_id_roles_id_fk" FOREIGN KEY ("role_id") REFERENCES "public"."roles"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "roles_to_permissions" ADD CONSTRAINT "roles_to_permissions_permission_id_permissions_id_fk" FOREIGN KEY ("permission_id") REFERENCES "public"."permissions"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "users_to_roles" ADD CONSTRAINT "users_to_roles_user_id_users_uuid_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users"("uuid") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "users_to_roles" ADD CONSTRAINT "users_to_roles_role_id_roles_id_fk" FOREIGN KEY ("role_id") REFERENCES "public"."roles"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "sessions" ADD CONSTRAINT "sessions_user_id_users_uuid_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users"("uuid") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "api_keys" ADD CONSTRAINT "api_keys_user_id_users_uuid_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users"("uuid") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "contents" ADD CONSTRAINT "contents_user_id_users_uuid_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users"("uuid") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "contents_to_tags" ADD CONSTRAINT "contents_to_tags_content_id_contents_id_fk" FOREIGN KEY ("content_id") REFERENCES "public"."contents"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "contents_to_tags" ADD CONSTRAINT "contents_to_tags_tag_id_tags_id_fk" FOREIGN KEY ("tag_id") REFERENCES "public"."tags"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "reports" ADD CONSTRAINT "reports_reporter_id_users_uuid_fk" FOREIGN KEY ("reporter_id") REFERENCES "public"."users"("uuid") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "reports" ADD CONSTRAINT "reports_content_id_contents_id_fk" FOREIGN KEY ("content_id") REFERENCES "public"."contents"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "reports" ADD CONSTRAINT "reports_tag_id_tags_id_fk" FOREIGN KEY ("tag_id") REFERENCES "public"."tags"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "audit_logs" ADD CONSTRAINT "audit_logs_user_id_users_uuid_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users"("uuid") ON DELETE set null ON UPDATE no action;--> statement-breakpoint
CREATE INDEX "users_uuid_idx" ON "users" USING btree ("uuid");--> statement-breakpoint
CREATE INDEX "users_email_hash_idx" ON "users" USING btree ("email_hash");--> statement-breakpoint
CREATE INDEX "users_username_idx" ON "users" USING btree ("username");--> statement-breakpoint
CREATE INDEX "users_status_idx" ON "users" USING btree ("status");--> statement-breakpoint
CREATE INDEX "permissions_slug_idx" ON "permissions" USING btree ("slug");--> statement-breakpoint
CREATE INDEX "roles_slug_idx" ON "roles" USING btree ("slug");--> statement-breakpoint
CREATE INDEX "sessions_user_id_idx" ON "sessions" USING btree ("user_id");--> statement-breakpoint
CREATE INDEX "sessions_refresh_token_idx" ON "sessions" USING btree ("refresh_token");--> statement-breakpoint
CREATE INDEX "sessions_expires_at_idx" ON "sessions" USING btree ("expires_at");--> statement-breakpoint
CREATE INDEX "api_keys_user_id_idx" ON "api_keys" USING btree ("user_id");--> statement-breakpoint
CREATE INDEX "api_keys_key_hash_idx" ON "api_keys" USING btree ("key_hash");--> statement-breakpoint
CREATE INDEX "tags_slug_idx" ON "tags" USING btree ("slug");--> statement-breakpoint
CREATE INDEX "contents_user_id_idx" ON "contents" USING btree ("user_id");--> statement-breakpoint
CREATE INDEX "contents_storage_key_idx" ON "contents" USING btree ("storage_key");--> statement-breakpoint
CREATE INDEX "contents_deleted_at_idx" ON "contents" USING btree ("deleted_at");--> statement-breakpoint
CREATE INDEX "reports_reporter_id_idx" ON "reports" USING btree ("reporter_id");--> statement-breakpoint
CREATE INDEX "reports_content_id_idx" ON "reports" USING btree ("content_id");--> statement-breakpoint
CREATE INDEX "reports_tag_id_idx" ON "reports" USING btree ("tag_id");--> statement-breakpoint
CREATE INDEX "reports_status_idx" ON "reports" USING btree ("status");--> statement-breakpoint
CREATE INDEX "reports_expires_at_idx" ON "reports" USING btree ("expires_at");--> statement-breakpoint
CREATE INDEX "audit_logs_user_id_idx" ON "audit_logs" USING btree ("user_id");--> statement-breakpoint
CREATE INDEX "audit_logs_action_idx" ON "audit_logs" USING btree ("action");--> statement-breakpoint
CREATE INDEX "audit_logs_entity_idx" ON "audit_logs" USING btree ("entity_type","entity_id");--> statement-breakpoint
CREATE INDEX "audit_logs_created_at_idx" ON "audit_logs" USING btree ("created_at");