-- ImageForge initial schema -- NOTE: This is a starting point; evolve via new migrations. BEGIN; -- Extensions CREATE EXTENSION IF NOT EXISTS pgcrypto; -- Enums DO $$ BEGIN CREATE TYPE user_role AS ENUM ('user', 'admin'); EXCEPTION WHEN duplicate_object THEN NULL; END $$; DO $$ BEGIN CREATE TYPE task_status AS ENUM ('pending', 'processing', 'completed', 'failed', 'cancelled'); EXCEPTION WHEN duplicate_object THEN NULL; END $$; DO $$ BEGIN CREATE TYPE file_status AS ENUM ('pending', 'processing', 'completed', 'failed'); EXCEPTION WHEN duplicate_object THEN NULL; END $$; DO $$ BEGIN CREATE TYPE compression_level AS ENUM ('high', 'medium', 'low'); EXCEPTION WHEN duplicate_object THEN NULL; END $$; DO $$ BEGIN CREATE TYPE task_source AS ENUM ('web', 'api'); EXCEPTION WHEN duplicate_object THEN NULL; END $$; DO $$ BEGIN CREATE TYPE subscription_status AS ENUM ('trialing', 'active', 'past_due', 'paused', 'canceled', 'incomplete'); EXCEPTION WHEN duplicate_object THEN NULL; END $$; DO $$ BEGIN CREATE TYPE invoice_status AS ENUM ('draft', 'open', 'paid', 'void', 'uncollectible'); EXCEPTION WHEN duplicate_object THEN NULL; END $$; DO $$ BEGIN CREATE TYPE payment_status AS ENUM ('pending', 'succeeded', 'failed', 'refunded'); EXCEPTION WHEN duplicate_object THEN NULL; END $$; -- users CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) NOT NULL UNIQUE, username VARCHAR(50) NOT NULL UNIQUE, password_hash VARCHAR(255) NOT NULL, role user_role NOT NULL DEFAULT 'user', is_active BOOLEAN NOT NULL DEFAULT true, email_verified_at TIMESTAMPTZ, billing_customer_id VARCHAR(200), rate_limit_override INTEGER, storage_limit_mb INTEGER, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_users_role ON users(role); CREATE INDEX IF NOT EXISTS idx_users_created_at ON users(created_at); CREATE INDEX IF NOT EXISTS idx_users_email_verified ON users(email_verified_at) WHERE email_verified_at IS NULL; -- email_verifications CREATE TABLE IF NOT EXISTS email_verifications ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash VARCHAR(64) NOT NULL, expires_at TIMESTAMPTZ NOT NULL, verified_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE UNIQUE INDEX IF NOT EXISTS idx_email_verifications_token ON email_verifications(token_hash); CREATE INDEX IF NOT EXISTS idx_email_verifications_user_id ON email_verifications(user_id); CREATE INDEX IF NOT EXISTS idx_email_verifications_expires ON email_verifications(expires_at) WHERE verified_at IS NULL; -- password_resets CREATE TABLE IF NOT EXISTS password_resets ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash VARCHAR(64) NOT NULL, expires_at TIMESTAMPTZ NOT NULL, used_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE UNIQUE INDEX IF NOT EXISTS idx_password_resets_token ON password_resets(token_hash); CREATE INDEX IF NOT EXISTS idx_password_resets_user_id ON password_resets(user_id); CREATE INDEX IF NOT EXISTS idx_password_resets_expires ON password_resets(expires_at) WHERE used_at IS NULL; -- plans CREATE TABLE IF NOT EXISTS plans ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), code VARCHAR(50) NOT NULL UNIQUE, name VARCHAR(100) NOT NULL, description TEXT, stripe_product_id VARCHAR(200), stripe_price_id VARCHAR(200), currency VARCHAR(10) NOT NULL DEFAULT 'CNY', amount_cents INTEGER NOT NULL DEFAULT 0, interval VARCHAR(20) NOT NULL DEFAULT 'monthly', included_units_per_period INTEGER NOT NULL, max_file_size_mb INTEGER NOT NULL, max_files_per_batch INTEGER NOT NULL, concurrency_limit INTEGER NOT NULL, retention_days INTEGER NOT NULL, features JSONB NOT NULL DEFAULT '{}'::jsonb, is_active BOOLEAN NOT NULL DEFAULT true, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_plans_is_active ON plans(is_active); -- subscriptions CREATE TABLE IF NOT EXISTS subscriptions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, plan_id UUID NOT NULL REFERENCES plans(id), status subscription_status NOT NULL DEFAULT 'incomplete', current_period_start TIMESTAMPTZ NOT NULL, current_period_end TIMESTAMPTZ NOT NULL, cancel_at_period_end BOOLEAN NOT NULL DEFAULT false, canceled_at TIMESTAMPTZ, provider VARCHAR(20) NOT NULL DEFAULT 'none', provider_customer_id VARCHAR(200), provider_subscription_id VARCHAR(200), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_subscriptions_user_id ON subscriptions(user_id); CREATE INDEX IF NOT EXISTS idx_subscriptions_status ON subscriptions(status); -- api_keys (Pro/Business only; enforced at application layer) CREATE TABLE IF NOT EXISTS api_keys ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, name VARCHAR(100) NOT NULL, key_prefix VARCHAR(20) NOT NULL, key_hash VARCHAR(255) NOT NULL, permissions JSONB NOT NULL DEFAULT '["compress"]', rate_limit INTEGER NOT NULL DEFAULT 100, is_active BOOLEAN NOT NULL DEFAULT true, last_used_at TIMESTAMPTZ, last_used_ip INET, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_api_keys_user_id ON api_keys(user_id); CREATE UNIQUE INDEX IF NOT EXISTS idx_api_keys_prefix ON api_keys(key_prefix); CREATE INDEX IF NOT EXISTS idx_api_keys_is_active ON api_keys(is_active); -- tasks CREATE TABLE IF NOT EXISTS tasks ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE SET NULL, session_id VARCHAR(100), api_key_id UUID REFERENCES api_keys(id) ON DELETE SET NULL, source task_source NOT NULL DEFAULT 'web', status task_status NOT NULL DEFAULT 'pending', compression_level compression_level NOT NULL DEFAULT 'medium', output_format VARCHAR(10), max_width INTEGER, max_height INTEGER, preserve_metadata BOOLEAN NOT NULL DEFAULT false, total_files INTEGER NOT NULL DEFAULT 0, completed_files INTEGER NOT NULL DEFAULT 0, failed_files INTEGER NOT NULL DEFAULT 0, total_original_size BIGINT NOT NULL DEFAULT 0, total_compressed_size BIGINT NOT NULL DEFAULT 0, error_message TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), started_at TIMESTAMPTZ, completed_at TIMESTAMPTZ, expires_at TIMESTAMPTZ NOT NULL DEFAULT (NOW() + INTERVAL '24 hours') ); CREATE INDEX IF NOT EXISTS idx_tasks_user_id ON tasks(user_id); CREATE INDEX IF NOT EXISTS idx_tasks_session_id ON tasks(session_id); CREATE INDEX IF NOT EXISTS idx_tasks_status ON tasks(status); CREATE INDEX IF NOT EXISTS idx_tasks_created_at ON tasks(created_at); CREATE INDEX IF NOT EXISTS idx_tasks_expires_at ON tasks(expires_at); -- task_files CREATE TABLE IF NOT EXISTS task_files ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), task_id UUID NOT NULL REFERENCES tasks(id) ON DELETE CASCADE, original_name VARCHAR(255) NOT NULL, original_format VARCHAR(10) NOT NULL, output_format VARCHAR(10) NOT NULL, original_size BIGINT NOT NULL, compressed_size BIGINT, saved_percent DECIMAL(6, 2), storage_path VARCHAR(500), status file_status NOT NULL DEFAULT 'pending', error_message TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), completed_at TIMESTAMPTZ ); CREATE INDEX IF NOT EXISTS idx_task_files_task_id ON task_files(task_id); CREATE INDEX IF NOT EXISTS idx_task_files_status ON task_files(status); -- idempotency_keys CREATE TABLE IF NOT EXISTS idempotency_keys ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, api_key_id UUID REFERENCES api_keys(id) ON DELETE CASCADE, idempotency_key VARCHAR(128) NOT NULL, request_hash VARCHAR(64) NOT NULL, response_status INTEGER NOT NULL, response_body JSONB, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL ); CREATE UNIQUE INDEX IF NOT EXISTS idx_idempotency_user_key ON idempotency_keys(user_id, idempotency_key) WHERE user_id IS NOT NULL; CREATE UNIQUE INDEX IF NOT EXISTS idx_idempotency_api_key_key ON idempotency_keys(api_key_id, idempotency_key) WHERE api_key_id IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_idempotency_expires_at ON idempotency_keys(expires_at); -- usage_events CREATE TABLE IF NOT EXISTS usage_events ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE SET NULL, api_key_id UUID REFERENCES api_keys(id) ON DELETE SET NULL, source task_source NOT NULL, task_id UUID REFERENCES tasks(id) ON DELETE SET NULL, task_file_id UUID REFERENCES task_files(id) ON DELETE SET NULL, units INTEGER NOT NULL DEFAULT 1, bytes_in BIGINT NOT NULL DEFAULT 0, bytes_out BIGINT NOT NULL DEFAULT 0, format_in VARCHAR(10), format_out VARCHAR(10), occurred_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE UNIQUE INDEX IF NOT EXISTS idx_usage_events_task_file_unique ON usage_events(task_file_id) WHERE task_file_id IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_usage_events_user_time ON usage_events(user_id, occurred_at); CREATE INDEX IF NOT EXISTS idx_usage_events_api_key_time ON usage_events(api_key_id, occurred_at); -- usage_periods CREATE TABLE IF NOT EXISTS usage_periods ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, subscription_id UUID REFERENCES subscriptions(id) ON DELETE SET NULL, period_start TIMESTAMPTZ NOT NULL, period_end TIMESTAMPTZ NOT NULL, used_units INTEGER NOT NULL DEFAULT 0, bytes_in BIGINT NOT NULL DEFAULT 0, bytes_out BIGINT NOT NULL DEFAULT 0, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(user_id, period_start, period_end) ); CREATE INDEX IF NOT EXISTS idx_usage_periods_user_period ON usage_periods(user_id, period_start); -- invoices CREATE TABLE IF NOT EXISTS invoices ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, subscription_id UUID REFERENCES subscriptions(id) ON DELETE SET NULL, invoice_number VARCHAR(50) NOT NULL UNIQUE, status invoice_status NOT NULL DEFAULT 'open', currency VARCHAR(10) NOT NULL DEFAULT 'CNY', total_amount_cents INTEGER NOT NULL DEFAULT 0, period_start TIMESTAMPTZ, period_end TIMESTAMPTZ, provider VARCHAR(20) NOT NULL DEFAULT 'none', provider_invoice_id VARCHAR(200), hosted_invoice_url TEXT, pdf_url TEXT, due_at TIMESTAMPTZ, paid_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_invoices_user_id ON invoices(user_id); CREATE INDEX IF NOT EXISTS idx_invoices_status ON invoices(status); -- payments CREATE TABLE IF NOT EXISTS payments ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, invoice_id UUID REFERENCES invoices(id) ON DELETE SET NULL, provider VARCHAR(20) NOT NULL DEFAULT 'none', provider_payment_id VARCHAR(200), status payment_status NOT NULL DEFAULT 'pending', currency VARCHAR(10) NOT NULL DEFAULT 'CNY', amount_cents INTEGER NOT NULL DEFAULT 0, paid_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_payments_user_id ON payments(user_id); CREATE INDEX IF NOT EXISTS idx_payments_status ON payments(status); -- webhook_events CREATE TABLE IF NOT EXISTS webhook_events ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), provider VARCHAR(20) NOT NULL, provider_event_id VARCHAR(200) NOT NULL, event_type VARCHAR(200) NOT NULL, payload JSONB NOT NULL, received_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), processed_at TIMESTAMPTZ, status VARCHAR(20) NOT NULL DEFAULT 'received', error_message TEXT ); CREATE UNIQUE INDEX IF NOT EXISTS idx_webhook_events_unique ON webhook_events(provider, provider_event_id); CREATE INDEX IF NOT EXISTS idx_webhook_events_status ON webhook_events(status); -- system_config CREATE TABLE IF NOT EXISTS system_config ( key VARCHAR(100) PRIMARY KEY, value JSONB NOT NULL, description TEXT, updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_by UUID REFERENCES users(id) ); -- audit_logs CREATE TABLE IF NOT EXISTS audit_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE SET NULL, action VARCHAR(50) NOT NULL, resource_type VARCHAR(50), resource_id UUID, details JSONB, ip_address INET, user_agent TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_audit_logs_user_id ON audit_logs(user_id); CREATE INDEX IF NOT EXISTS idx_audit_logs_action ON audit_logs(action); CREATE INDEX IF NOT EXISTS idx_audit_logs_created_at ON audit_logs(created_at); -- Default config seeds INSERT INTO system_config (key, value, description) VALUES ('features', '{"registration_enabled": true, "api_key_enabled": true, "anonymous_upload_enabled": true}', '功能开关'), ('rate_limits', '{"anonymous_per_minute": 10, "anonymous_units_per_day": 10, "user_per_minute": 60, "api_key_per_minute": 100}', '速率限制默认值'), ('file_limits', '{"max_image_pixels": 40000000}', '图片安全限制(像素上限等)') ON CONFLICT (key) DO NOTHING; INSERT INTO plans (code, name, stripe_price_id, currency, amount_cents, interval, included_units_per_period, max_file_size_mb, max_files_per_batch, concurrency_limit, retention_days, features) VALUES ('free', 'Free', NULL, 'CNY', 0, 'monthly', 500, 5, 10, 2, 1, '{"webhook": false, "api": false}'), ('pro_monthly', 'Pro(月付)', 'price_xxx_pro_monthly', 'CNY', 1999, 'monthly', 10000, 20, 50, 8, 7, '{"webhook": true, "api": true}'), ('business_monthly', 'Business(月付)', 'price_xxx_business_monthly', 'CNY', 9999, 'monthly', 100000, 50, 200, 32, 30, '{"webhook": true, "api": true, "ip_allowlist": true}') ON CONFLICT (code) DO NOTHING; COMMIT;