-- PostgreSQL migration for ai.card database schema -- Create custom types CREATE TYPE card_rarity AS ENUM ('normal', 'rare', 'super_rare', 'kira', 'unique'); -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Users table - stores atproto DID-based user information CREATE TABLE IF NOT EXISTS users ( id SERIAL PRIMARY KEY, did TEXT NOT NULL UNIQUE, -- atproto Decentralized Identifier handle TEXT NOT NULL, -- atproto handle (e.g., alice.bsky.social) created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_users_did ON users(did); CREATE INDEX IF NOT EXISTS idx_users_handle ON users(handle); -- Card master data - template definitions for all card types CREATE TABLE IF NOT EXISTS card_master ( id INTEGER PRIMARY KEY, -- Card ID (0-15 in current system) name TEXT NOT NULL, -- Card name (e.g., "ai", "dream", "radiance") base_cp_min INTEGER NOT NULL, -- Minimum base CP for this card base_cp_max INTEGER NOT NULL, -- Maximum base CP for this card color TEXT NOT NULL, -- Card color theme description TEXT NOT NULL -- Card description/lore ); -- User cards - actual card instances owned by users CREATE TABLE IF NOT EXISTS user_cards ( id SERIAL PRIMARY KEY, user_id INTEGER NOT NULL, card_id INTEGER NOT NULL, -- References card_master.id cp INTEGER NOT NULL, -- Calculated CP (base_cp * rarity_multiplier) status card_rarity NOT NULL, -- Card rarity skill TEXT, -- Optional skill description obtained_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), is_unique BOOLEAN NOT NULL DEFAULT FALSE, unique_id UUID, -- UUID for unique cards FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, FOREIGN KEY (card_id) REFERENCES card_master(id) ); CREATE INDEX IF NOT EXISTS idx_user_cards_user_id ON user_cards(user_id); CREATE INDEX IF NOT EXISTS idx_user_cards_card_id ON user_cards(card_id); CREATE INDEX IF NOT EXISTS idx_user_cards_status ON user_cards(status); CREATE INDEX IF NOT EXISTS idx_user_cards_unique_id ON user_cards(unique_id); -- Global unique card registry - tracks ownership of unique cards CREATE TABLE IF NOT EXISTS unique_card_registry ( id SERIAL PRIMARY KEY, unique_id UUID NOT NULL UNIQUE, -- UUID from user_cards.unique_id card_id INTEGER NOT NULL, -- Which card type is unique owner_did TEXT NOT NULL, -- Current owner's atproto DID obtained_at TIMESTAMP WITH TIME ZONE NOT NULL, verse_skill_id TEXT, -- Optional verse skill reference FOREIGN KEY (card_id) REFERENCES card_master(id), UNIQUE(card_id) -- Only one unique per card_id allowed ); CREATE INDEX IF NOT EXISTS idx_unique_registry_card_id ON unique_card_registry(card_id); CREATE INDEX IF NOT EXISTS idx_unique_registry_owner_did ON unique_card_registry(owner_did); -- Draw history - tracks all gacha draws for statistics CREATE TABLE IF NOT EXISTS draw_history ( id SERIAL PRIMARY KEY, user_id INTEGER NOT NULL, card_id INTEGER NOT NULL, status card_rarity NOT NULL, cp INTEGER NOT NULL, is_paid BOOLEAN NOT NULL DEFAULT FALSE, -- Paid vs free gacha drawn_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, FOREIGN KEY (card_id) REFERENCES card_master(id) ); CREATE INDEX IF NOT EXISTS idx_draw_history_user_id ON draw_history(user_id); CREATE INDEX IF NOT EXISTS idx_draw_history_drawn_at ON draw_history(drawn_at); CREATE INDEX IF NOT EXISTS idx_draw_history_status ON draw_history(status); -- Gacha pools - special event pools with rate-ups CREATE TABLE IF NOT EXISTS gacha_pools ( id SERIAL PRIMARY KEY, name TEXT NOT NULL, description TEXT NOT NULL, is_active BOOLEAN NOT NULL DEFAULT TRUE, start_at TIMESTAMP WITH TIME ZONE, end_at TIMESTAMP WITH TIME ZONE, pickup_card_ids INTEGER[], -- Array of card IDs rate_up_multiplier DECIMAL(4,2) NOT NULL DEFAULT 1.0 ); CREATE INDEX IF NOT EXISTS idx_gacha_pools_active ON gacha_pools(is_active); CREATE INDEX IF NOT EXISTS idx_gacha_pools_dates ON gacha_pools(start_at, end_at); -- Insert default card master data (0-15 cards from ai.json) INSERT INTO card_master (id, name, base_cp_min, base_cp_max, color, description) VALUES (0, 'ai', 100, 200, '#4A90E2', 'The core essence of existence'), (1, 'dream', 90, 180, '#9B59B6', 'Visions of possibility'), (2, 'radiance', 110, 220, '#F39C12', 'Brilliant light energy'), (3, 'neutron', 120, 240, '#34495E', 'Dense stellar core'), (4, 'sun', 130, 260, '#E74C3C', 'Solar radiance'), (5, 'night', 80, 160, '#2C3E50', 'Darkness and mystery'), (6, 'snow', 70, 140, '#ECF0F1', 'Pure frozen crystalline'), (7, 'thunder', 140, 280, '#F1C40F', 'Electric storm energy'), (8, 'ultimate', 150, 300, '#8E44AD', 'The highest form'), (9, 'sword', 160, 320, '#95A5A6', 'Blade of cutting truth'), (10, 'destruction', 170, 340, '#C0392B', 'Force of entropy'), (11, 'earth', 90, 180, '#27AE60', 'Grounding foundation'), (12, 'galaxy', 180, 360, '#3498DB', 'Cosmic expanse'), (13, 'create', 100, 200, '#16A085', 'Power of generation'), (14, 'supernova', 200, 400, '#E67E22', 'Stellar explosion'), (15, 'world', 250, 500, '#9B59B6', 'Reality itself') ON CONFLICT (id) DO NOTHING; -- Create function for updating updated_at timestamp CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ language 'plpgsql'; -- Create trigger for updating users.updated_at CREATE TRIGGER trigger_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();