# LinguaForge 資料庫架構設計 ## 1. 資料庫關係圖 ```mermaid erDiagram users ||--o{ vocabulary_cards : creates users ||--o{ review_sessions : performs users ||--o{ pronunciation_assessments : submits users ||--|| user_preferences : has users ||--|| subscriptions : has vocabulary_cards ||--o{ review_records : has vocabulary_cards ||--o{ card_media : contains vocabulary_cards ||--o{ pronunciation_assessments : relates review_sessions ||--o{ review_records : contains subscription_plans ||--o{ subscriptions : defines users { uuid id PK string email UK string username UK string password_hash boolean email_verified timestamp created_at timestamp updated_at timestamp last_login_at string status } user_preferences { uuid id PK uuid user_id FK integer daily_review_goal string review_reminder_time boolean push_notifications string ui_language string learning_language jsonb study_settings timestamp updated_at } subscriptions { uuid id PK uuid user_id FK uuid plan_id FK string status timestamp started_at timestamp expires_at timestamp cancelled_at decimal amount_paid string payment_method } subscription_plans { uuid id PK string name string tier decimal monthly_price decimal yearly_price jsonb features boolean is_active timestamp created_at } vocabulary_cards { uuid id PK uuid user_id FK string word string definition jsonb examples string source_sentence string difficulty_level decimal easiness_factor integer repetition_count integer interval_days timestamp next_review_date timestamp created_at timestamp updated_at boolean is_active jsonb metadata } card_media { uuid id PK uuid card_id FK string media_type string url string storage_key integer file_size jsonb ai_generated_data timestamp created_at } review_sessions { uuid id PK uuid user_id FK timestamp started_at timestamp ended_at integer cards_reviewed integer cards_correct decimal average_quality jsonb session_stats } review_records { uuid id PK uuid card_id FK uuid session_id FK uuid user_id FK integer quality_rating integer time_spent_seconds timestamp reviewed_at decimal old_easiness_factor decimal new_easiness_factor integer old_interval integer new_interval string review_type } pronunciation_assessments { uuid id PK uuid user_id FK uuid card_id FK string text_assessed decimal accuracy_score decimal fluency_score decimal completeness_score decimal pronunciation_score jsonb detailed_feedback string audio_url timestamp assessed_at } ``` ## 2. 資料表詳細設計 ### 2.1 users (使用者表) ```sql CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) UNIQUE NOT NULL, username VARCHAR(50) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, email_verified BOOLEAN DEFAULT FALSE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, last_login_at TIMESTAMP, status VARCHAR(20) DEFAULT 'active' CHECK (status IN ('active', 'suspended', 'deleted')) ); CREATE INDEX idx_users_email ON users(email); CREATE INDEX idx_users_username ON users(username); CREATE INDEX idx_users_status ON users(status); ``` ### 2.2 user_preferences (使用者偏好設定) ```sql CREATE TABLE user_preferences ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID UNIQUE NOT NULL REFERENCES users(id) ON DELETE CASCADE, daily_review_goal INTEGER DEFAULT 20, review_reminder_time TIME DEFAULT '09:00:00', push_notifications BOOLEAN DEFAULT TRUE, ui_language VARCHAR(10) DEFAULT 'zh-TW', learning_language VARCHAR(10) DEFAULT 'en-US', study_settings JSONB DEFAULT '{}', updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); ``` ### 2.3 vocabulary_cards (詞彙卡片) ```sql CREATE TABLE vocabulary_cards ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, word VARCHAR(100) NOT NULL, definition TEXT NOT NULL, examples JSONB DEFAULT '[]', source_sentence TEXT, difficulty_level VARCHAR(20) DEFAULT 'medium', easiness_factor DECIMAL(3,2) DEFAULT 2.5, repetition_count INTEGER DEFAULT 0, interval_days INTEGER DEFAULT 1, next_review_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, is_active BOOLEAN DEFAULT TRUE, metadata JSONB DEFAULT '{}' ); CREATE INDEX idx_cards_user_id ON vocabulary_cards(user_id); CREATE INDEX idx_cards_next_review ON vocabulary_cards(user_id, next_review_date); CREATE INDEX idx_cards_word ON vocabulary_cards(word); CREATE INDEX idx_cards_active ON vocabulary_cards(is_active); ``` ### 2.4 card_media (卡片媒體資源) ```sql CREATE TABLE card_media ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), card_id UUID NOT NULL REFERENCES vocabulary_cards(id) ON DELETE CASCADE, media_type VARCHAR(20) NOT NULL CHECK (media_type IN ('image', 'audio', 'video')), url TEXT NOT NULL, storage_key VARCHAR(255) NOT NULL, file_size INTEGER, ai_generated_data JSONB DEFAULT '{}', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_media_card_id ON card_media(card_id); CREATE INDEX idx_media_type ON card_media(media_type); ``` ### 2.5 review_sessions (複習會話) ```sql CREATE TABLE review_sessions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, started_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, ended_at TIMESTAMP, cards_reviewed INTEGER DEFAULT 0, cards_correct INTEGER DEFAULT 0, average_quality DECIMAL(3,2), session_stats JSONB DEFAULT '{}' ); CREATE INDEX idx_sessions_user_id ON review_sessions(user_id); CREATE INDEX idx_sessions_date ON review_sessions(started_at); ``` ### 2.6 review_records (複習記錄) ```sql CREATE TABLE review_records ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), card_id UUID NOT NULL REFERENCES vocabulary_cards(id) ON DELETE CASCADE, session_id UUID REFERENCES review_sessions(id) ON DELETE SET NULL, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, quality_rating INTEGER NOT NULL CHECK (quality_rating BETWEEN 0 AND 5), time_spent_seconds INTEGER, reviewed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, old_easiness_factor DECIMAL(3,2), new_easiness_factor DECIMAL(3,2), old_interval INTEGER, new_interval INTEGER, review_type VARCHAR(20) DEFAULT 'normal' ); CREATE INDEX idx_records_card_id ON review_records(card_id); CREATE INDEX idx_records_user_id ON review_records(user_id); CREATE INDEX idx_records_session_id ON review_records(session_id); CREATE INDEX idx_records_date ON review_records(reviewed_at); ``` ### 2.7 pronunciation_assessments (發音評估) ```sql CREATE TABLE pronunciation_assessments ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, card_id UUID REFERENCES vocabulary_cards(id) ON DELETE SET NULL, text_assessed TEXT NOT NULL, accuracy_score DECIMAL(5,2), fluency_score DECIMAL(5,2), completeness_score DECIMAL(5,2), pronunciation_score DECIMAL(5,2), detailed_feedback JSONB DEFAULT '{}', audio_url TEXT, assessed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_assessments_user_id ON pronunciation_assessments(user_id); CREATE INDEX idx_assessments_card_id ON pronunciation_assessments(card_id); CREATE INDEX idx_assessments_date ON pronunciation_assessments(assessed_at); ``` ### 2.8 subscription_plans (訂閱方案) ```sql CREATE TABLE subscription_plans ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name VARCHAR(100) NOT NULL, tier VARCHAR(20) NOT NULL CHECK (tier IN ('free', 'basic', 'premium', 'enterprise')), monthly_price DECIMAL(10,2), yearly_price DECIMAL(10,2), features JSONB DEFAULT '{}', is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); ``` ### 2.9 subscriptions (訂閱記錄) ```sql CREATE TABLE 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 subscription_plans(id), status VARCHAR(20) NOT NULL CHECK (status IN ('active', 'expired', 'cancelled', 'pending')), started_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, expires_at TIMESTAMP, cancelled_at TIMESTAMP, amount_paid DECIMAL(10,2), payment_method VARCHAR(50) ); CREATE INDEX idx_subscriptions_user_id ON subscriptions(user_id); CREATE INDEX idx_subscriptions_status ON subscriptions(status); CREATE INDEX idx_subscriptions_expires ON subscriptions(expires_at); ``` ## 3. 資料庫優化策略 ### 3.1 分區策略 ```sql -- 按月份分區 review_records 表 CREATE TABLE review_records_2024_01 PARTITION OF review_records FOR VALUES FROM ('2024-01-01') TO ('2024-02-01'); CREATE TABLE review_records_2024_02 PARTITION OF review_records FOR VALUES FROM ('2024-02-01') TO ('2024-03-01'); ``` ### 3.2 物化視圖 ```sql -- 使用者學習統計物化視圖 CREATE MATERIALIZED VIEW user_learning_stats AS SELECT u.id as user_id, COUNT(DISTINCT vc.id) as total_cards, COUNT(DISTINCT rr.id) as total_reviews, AVG(rr.quality_rating) as avg_quality, MAX(rr.reviewed_at) as last_review_date FROM users u LEFT JOIN vocabulary_cards vc ON u.id = vc.user_id LEFT JOIN review_records rr ON vc.id = rr.card_id GROUP BY u.id; CREATE INDEX idx_user_stats ON user_learning_stats(user_id); ``` ### 3.3 觸發器 ```sql -- 自動更新 updated_at 時間戳 CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_cards_updated_at BEFORE UPDATE ON vocabulary_cards FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); ``` ## 4. 資料遷移策略 ### 4.1 版本控制 使用 Flyway 或 Liquibase 進行資料庫版本控制 ### 4.2 遷移腳本命名規範 ``` V1__create_users_table.sql V2__create_vocabulary_cards_table.sql V3__add_index_to_cards.sql ``` ## 5. 備份與恢復 ### 5.1 備份策略 ```bash # 每日完整備份 pg_dump -h localhost -U linguaforge -d linguaforge_db > backup_$(date +%Y%m%d).sql # 增量備份 (使用 pg_basebackup) pg_basebackup -h localhost -D /backup/incremental -U replicator -W ``` ### 5.2 恢復程序 ```bash # 恢復完整備份 psql -h localhost -U linguaforge -d linguaforge_db < backup_20240115.sql # Point-in-Time Recovery (PITR) recovery_target_time = '2024-01-15 14:30:00' ``` ## 6. 監控指標 ### 6.1 關鍵查詢 ```sql -- 監控慢查詢 SELECT query, calls, mean_exec_time, max_exec_time FROM pg_stat_statements WHERE mean_exec_time > 100 ORDER BY mean_exec_time DESC; -- 監控表大小 SELECT schemaname, tablename, pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) AS size FROM pg_tables ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC; -- 監控索引使用率 SELECT schemaname, tablename, indexname, idx_scan FROM pg_stat_user_indexes ORDER BY idx_scan; ```