The scraper uses TEXT IDs like "A7-40063-2" but DatabaseService was creating
BIGINT columns, causing PRIMARY KEY constraint failures on the server.
Changes:
- auction_id: BIGINT -> TEXT PRIMARY KEY
- lot_id: BIGINT -> TEXT PRIMARY KEY
- sale_id: BIGINT -> TEXT
- Added UNIQUE constraints on URLs
- Added migration script (fix-schema.sql)
This fixes the "UNIQUE constraint failed: auctions.auction_id" errors
and allows bid data to populate correctly on the server.
🤖 Generated with [Claude Code](https://claude.com/claude-code)
Co-Authored-By: Claude <noreply@anthropic.com>
Former-commit-id: 12c3a732e4
129 lines
3.7 KiB
SQL
129 lines
3.7 KiB
SQL
-- Schema Fix Script for Server Database
|
|
-- This script migrates auction_id and lot_id from BIGINT to TEXT to match scraper format
|
|
-- The scraper uses TEXT IDs like "A7-40063-2" but DatabaseService.java was creating BIGINT columns
|
|
|
|
-- Step 1: Backup existing data
|
|
CREATE TABLE IF NOT EXISTS auctions_backup AS SELECT * FROM auctions;
|
|
CREATE TABLE IF NOT EXISTS lots_backup AS SELECT * FROM lots;
|
|
CREATE TABLE IF NOT EXISTS images_backup AS SELECT * FROM images;
|
|
|
|
-- Step 2: Drop existing tables (CASCADE would drop foreign keys)
|
|
DROP TABLE IF EXISTS images;
|
|
DROP TABLE IF EXISTS lots;
|
|
DROP TABLE IF EXISTS auctions;
|
|
|
|
-- Step 3: Recreate auctions table with TEXT primary key (matching scraper format)
|
|
CREATE TABLE auctions (
|
|
auction_id TEXT PRIMARY KEY,
|
|
title TEXT NOT NULL,
|
|
location TEXT,
|
|
city TEXT,
|
|
country TEXT,
|
|
url TEXT NOT NULL UNIQUE,
|
|
type TEXT,
|
|
lot_count INTEGER DEFAULT 0,
|
|
closing_time TEXT,
|
|
discovered_at INTEGER
|
|
);
|
|
|
|
-- Step 4: Recreate lots table with TEXT primary key (matching scraper format)
|
|
CREATE TABLE lots (
|
|
lot_id TEXT PRIMARY KEY,
|
|
sale_id TEXT,
|
|
auction_id TEXT,
|
|
title TEXT,
|
|
description TEXT,
|
|
manufacturer TEXT,
|
|
type TEXT,
|
|
year INTEGER,
|
|
category TEXT,
|
|
current_bid REAL,
|
|
currency TEXT DEFAULT 'EUR',
|
|
url TEXT UNIQUE,
|
|
closing_time TEXT,
|
|
closing_notified INTEGER DEFAULT 0,
|
|
starting_bid REAL,
|
|
minimum_bid REAL,
|
|
status TEXT,
|
|
brand TEXT,
|
|
model TEXT,
|
|
attributes_json TEXT,
|
|
first_bid_time TEXT,
|
|
last_bid_time TEXT,
|
|
bid_velocity REAL,
|
|
bid_increment REAL,
|
|
year_manufactured INTEGER,
|
|
condition_score REAL,
|
|
condition_description TEXT,
|
|
serial_number TEXT,
|
|
damage_description TEXT,
|
|
followers_count INTEGER DEFAULT 0,
|
|
estimated_min_price REAL,
|
|
estimated_max_price REAL,
|
|
lot_condition TEXT,
|
|
appearance TEXT,
|
|
estimated_min REAL,
|
|
estimated_max REAL,
|
|
next_bid_step_cents INTEGER,
|
|
condition TEXT,
|
|
category_path TEXT,
|
|
city_location TEXT,
|
|
country_code TEXT,
|
|
bidding_status TEXT,
|
|
packaging TEXT,
|
|
quantity INTEGER,
|
|
vat REAL,
|
|
buyer_premium_percentage REAL,
|
|
remarks TEXT,
|
|
reserve_price REAL,
|
|
reserve_met INTEGER,
|
|
view_count INTEGER,
|
|
bid_count INTEGER,
|
|
viewing_time TEXT,
|
|
pickup_date TEXT,
|
|
location TEXT,
|
|
scraped_at TEXT,
|
|
FOREIGN KEY (auction_id) REFERENCES auctions(auction_id),
|
|
FOREIGN KEY (sale_id) REFERENCES auctions(auction_id)
|
|
);
|
|
|
|
-- Step 5: Recreate images table
|
|
CREATE TABLE images (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
lot_id TEXT,
|
|
url TEXT,
|
|
local_path TEXT,
|
|
labels TEXT,
|
|
processed_at INTEGER,
|
|
downloaded INTEGER DEFAULT 0,
|
|
FOREIGN KEY (lot_id) REFERENCES lots(lot_id)
|
|
);
|
|
|
|
-- Step 6: Create bid_history table if it doesn't exist
|
|
CREATE TABLE IF NOT EXISTS bid_history (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
lot_id TEXT,
|
|
bid_amount REAL,
|
|
bid_time TEXT,
|
|
is_autobid INTEGER DEFAULT 0,
|
|
bidder_id TEXT,
|
|
bidder_number INTEGER,
|
|
FOREIGN KEY (lot_id) REFERENCES lots(lot_id)
|
|
);
|
|
|
|
-- Step 7: Restore data from backup (converting BIGINT to TEXT if needed)
|
|
INSERT OR IGNORE INTO auctions SELECT * FROM auctions_backup;
|
|
INSERT OR IGNORE INTO lots SELECT * FROM lots_backup;
|
|
INSERT OR IGNORE INTO images SELECT * FROM images_backup;
|
|
|
|
-- Step 8: Create indexes for performance
|
|
CREATE INDEX IF NOT EXISTS idx_auctions_country ON auctions(country);
|
|
CREATE INDEX IF NOT EXISTS idx_lots_sale_id ON lots(sale_id);
|
|
CREATE INDEX IF NOT EXISTS idx_lots_auction_id ON lots(auction_id);
|
|
CREATE INDEX IF NOT EXISTS idx_images_lot_id ON images(lot_id);
|
|
|
|
-- Step 9: Clean up backup tables (optional - comment out if you want to keep backups)
|
|
-- DROP TABLE auctions_backup;
|
|
-- DROP TABLE lots_backup;
|
|
-- DROP TABLE images_backup;
|