-- Initial database schema for Pawctioneer Bot -- Supports all listing types: basic_auction, multi_slot_auction, fixed_price_listing, blind_auction -- Enable foreign key constraints PRAGMA foreign_keys = ON; -- Core user tracking CREATE TABLE users ( id INTEGER PRIMARY KEY, telegram_id INTEGER UNIQUE NOT NULL, username TEXT, first_name TEXT, last_name TEXT, is_banned INTEGER DEFAULT 0, created_at TEXT DEFAULT CURRENT_TIMESTAMP, updated_at TEXT DEFAULT CURRENT_TIMESTAMP ) STRICT; CREATE INDEX idx_users_telegram_id ON users(telegram_id); CREATE INDEX idx_users_username ON users(username); -- Main listing table (handles all listing types) CREATE TABLE listings ( id INTEGER PRIMARY KEY, seller_id INTEGER NOT NULL, listing_type TEXT NOT NULL, -- 'basic_auction', 'multi_slot_auction', 'fixed_price_listing', 'blind_auction' title TEXT NOT NULL, description TEXT, currency_type TEXT NOT NULL, -- 'usd' -- Pricing (stored as INTEGER cents for USD) starting_bid INTEGER, buy_now_price INTEGER, min_increment INTEGER DEFAULT 100, -- 1.00 USD = 100 cents -- Multi-slot/fixed price slots_available INTEGER DEFAULT 1, -- Timing is_active INTEGER DEFAULT 1, starts_at TEXT DEFAULT CURRENT_TIMESTAMP, ends_at TEXT NOT NULL, anti_snipe_minutes INTEGER DEFAULT 5, created_at TEXT DEFAULT CURRENT_TIMESTAMP, updated_at TEXT DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (seller_id) REFERENCES users(id) ) STRICT; CREATE INDEX idx_listings_seller_id ON listings(seller_id); CREATE INDEX idx_listings_type ON listings(listing_type); CREATE INDEX idx_listings_ends_at ON listings(ends_at); -- Proxy bid strategies (NOT actual bids, but bidding strategies) CREATE TABLE proxy_bids ( id INTEGER PRIMARY KEY, listing_id INTEGER NOT NULL, buyer_id INTEGER NOT NULL, max_amount INTEGER NOT NULL, -- stored as cents is_active INTEGER DEFAULT 1, created_at TEXT DEFAULT CURRENT_TIMESTAMP, updated_at TEXT DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (listing_id) REFERENCES listings(id), FOREIGN KEY (buyer_id) REFERENCES users(id), UNIQUE(listing_id, buyer_id) -- One active proxy per user per listing ) STRICT; CREATE INDEX idx_proxy_bids_listing_buyer ON proxy_bids(listing_id, buyer_id); -- Actual bids that happened (events) CREATE TABLE bids ( id INTEGER PRIMARY KEY, listing_id INTEGER NOT NULL, buyer_id INTEGER NOT NULL, bid_amount INTEGER NOT NULL, -- stored as cents -- For blind listings description TEXT, -- Status is_cancelled INTEGER DEFAULT 0, slot_number INTEGER, -- For multi-slot listings -- NULL = manual bid, NOT NULL = generated from proxy proxy_bid_id INTEGER, created_at TEXT DEFAULT CURRENT_TIMESTAMP, updated_at TEXT DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (listing_id) REFERENCES listings(id), FOREIGN KEY (buyer_id) REFERENCES users(id), FOREIGN KEY (proxy_bid_id) REFERENCES proxy_bids(id) ) STRICT; CREATE INDEX idx_bids_listing_id ON bids(listing_id); CREATE INDEX idx_bids_buyer_id ON bids(buyer_id); CREATE INDEX idx_bids_amount ON bids(bid_amount); -- Media attachments CREATE TABLE listing_medias ( id INTEGER PRIMARY KEY, listing_id INTEGER NOT NULL, telegram_file_id TEXT NOT NULL, media_type TEXT NOT NULL, -- 'photo', 'video' position INTEGER DEFAULT 0, created_at TEXT DEFAULT CURRENT_TIMESTAMP, updated_at TEXT DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (listing_id) REFERENCES listings(id) ) STRICT; CREATE INDEX idx_listing_medias_listing_id ON listing_medias(listing_id); -- User preferences CREATE TABLE user_settings ( user_id INTEGER PRIMARY KEY, language_code TEXT DEFAULT 'en', notify_outbid INTEGER DEFAULT 1, notify_won INTEGER DEFAULT 1, created_at TEXT DEFAULT CURRENT_TIMESTAMP, updated_at TEXT DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES users(id) ) STRICT; -- Message about a listing that were forwarded from the bot to a channel or user CREATE TABLE forwarded_listings ( id INTEGER PRIMARY KEY, listing_id INTEGER NOT NULL, telegram_message_id INTEGER NOT NULL, telegram_chat_id INTEGER NOT NULL, forwarding_user_id INTEGER NOT NULL, created_at TEXT DEFAULT CURRENT_TIMESTAMP, updated_at TEXT DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (listing_id) REFERENCES listings(id), FOREIGN KEY (forwarding_user_id) REFERENCES users(id) ) STRICT; CREATE INDEX idx_forwarded_listings_listing_id ON forwarded_listings(listing_id); CREATE INDEX idx_forwarded_listings_forwarding_user_id ON forwarded_listings(forwarding_user_id);