Files
pawctioneer-bot/migrations/20240827001_initial_schema.sql
Dylan Knutson 348fa416e8 feat: implement database layer and rename auction -> listing
Major Changes:
- Set up SQLx database connection and migration system
- Create complete initial database schema with all tables
- Rename 'auction' to 'listing' throughout codebase for better terminology
- Update bot commands: /newauction -> /newlisting, /myauctions -> /mylistings
- Update all database tables: auctions -> listings, auction_medias -> listing_medias
- Update foreign key relationships and indexes
- Add automatic database migration on startup
- Update documentation and README
- Complete backlog tasks: task-001, task-002, task-010

The bot now has a solid database foundation ready for implementing core business logic.
All tests pass and code compiles successfully.
2025-08-27 19:24:15 +00:00

113 lines
3.6 KiB
SQL

-- Initial database schema for Pawctioneer Bot
-- Supports all listing types: standard, multi_slot, fixed_price, blind
-- Core user tracking
CREATE TABLE users (
id INTEGER PRIMARY KEY,
telegram_id INTEGER UNIQUE NOT NULL,
username TEXT,
display_name TEXT,
is_banned BOOLEAN DEFAULT FALSE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Main listing table (handles all listing types)
CREATE TABLE listings (
id INTEGER PRIMARY KEY,
seller_id INTEGER NOT NULL,
listing_type TEXT NOT NULL, -- 'standard', 'multi_slot', 'fixed_price', 'blind'
title TEXT NOT NULL,
description TEXT,
-- Pricing
starting_bid DECIMAL(10,2),
buy_now_price DECIMAL(10,2),
min_increment DECIMAL(10,2) DEFAULT 1.00,
-- Multi-slot/fixed price
slots_available INTEGER DEFAULT 1,
-- Timing
starts_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
ends_at TIMESTAMP NOT NULL,
anti_snipe_minutes INTEGER DEFAULT 5,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (seller_id) REFERENCES users(id)
);
-- 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 DECIMAL(10,2) NOT NULL,
is_active BOOLEAN DEFAULT TRUE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP 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
);
-- Actual bids that happened (events)
CREATE TABLE bids (
id INTEGER PRIMARY KEY,
listing_id INTEGER NOT NULL,
buyer_id INTEGER NOT NULL,
bid_amount DECIMAL(10,2) NOT NULL,
-- For blind listings
description TEXT,
-- Status
is_cancelled BOOLEAN DEFAULT FALSE,
slot_number INTEGER, -- For multi-slot listings
-- NULL = manual bid, NOT NULL = generated from proxy
proxy_bid_id INTEGER,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP 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)
);
-- 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 TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (listing_id) REFERENCES listings(id)
);
-- User preferences
CREATE TABLE user_settings (
user_id INTEGER PRIMARY KEY,
language_code TEXT DEFAULT 'en',
notify_outbid BOOLEAN DEFAULT TRUE,
notify_won BOOLEAN DEFAULT TRUE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (user_id) REFERENCES users(id)
);
-- Create indexes for better performance
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);
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);
CREATE INDEX idx_proxy_bids_listing_buyer ON proxy_bids(listing_id, buyer_id);
CREATE INDEX idx_listing_medias_listing_id ON listing_medias(listing_id);