-- Livestock Marketplace schema (PostgreSQL) -- Generated from specs in README.md CREATE EXTENSION IF NOT EXISTS "pgcrypto"; CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name VARCHAR(255) NOT NULL, phone VARCHAR(50) UNIQUE NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS species ( id SERIAL PRIMARY KEY, name VARCHAR(100) UNIQUE NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS breeds ( id SERIAL PRIMARY KEY, species_id INT NOT NULL REFERENCES species(id) ON DELETE RESTRICT, name VARCHAR(100) NOT NULL, description TEXT, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS locations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE SET NULL, is_saved_address BOOLEAN NOT NULL DEFAULT FALSE, location_type VARCHAR(50), country VARCHAR(100), state VARCHAR(100), district VARCHAR(100), city_village VARCHAR(150), pincode VARCHAR(20), lat DECIMAL(10,7), lng DECIMAL(10,7), source_type VARCHAR(50) NOT NULL DEFAULT 'unknown', source_confidence VARCHAR(50) NOT NULL DEFAULT 'medium', created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS animals ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), species_id INT NOT NULL REFERENCES species(id) ON DELETE RESTRICT, breed_id INT REFERENCES breeds(id) ON DELETE SET NULL, sex VARCHAR(20) NOT NULL, age_months INT, weight_kg DECIMAL(10,2), color_markings VARCHAR(200), quantity INT NOT NULL DEFAULT 1, purpose VARCHAR(50) NOT NULL, health_status VARCHAR(50) NOT NULL, vaccinated BOOLEAN NOT NULL DEFAULT FALSE, dewormed BOOLEAN NOT NULL DEFAULT FALSE, previous_pregnancies_count INT, pregnancy_status VARCHAR(50), milk_yield_litre_per_day DECIMAL(10,2), ear_tag_no VARCHAR(100), description TEXT, suggested_care TEXT, location_id UUID REFERENCES locations(id) ON DELETE SET NULL, created_from VARCHAR(50) NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS listings ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), seller_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, animal_id UUID NOT NULL UNIQUE REFERENCES animals(id) ON DELETE CASCADE, title VARCHAR(200) NOT NULL, price NUMERIC(12,2) NOT NULL, currency VARCHAR(10) NOT NULL, is_negotiable BOOLEAN NOT NULL DEFAULT TRUE, listing_type VARCHAR(50) NOT NULL, status VARCHAR(50) NOT NULL DEFAULT 'active', listing_score INT NOT NULL DEFAULT 0, views_count INT NOT NULL DEFAULT 0, bookmarks_count INT NOT NULL DEFAULT 0, enquiries_call_count INT NOT NULL DEFAULT 0, enquiries_whatsapp_count INT NOT NULL DEFAULT 0, clicks_count INT NOT NULL DEFAULT 0, listing_score_status VARCHAR(50) NOT NULL DEFAULT 'pending', created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS listing_media ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), listing_id UUID NOT NULL REFERENCES listings(id) ON DELETE CASCADE, media_url VARCHAR(500) NOT NULL, media_type VARCHAR(50) NOT NULL, is_primary BOOLEAN NOT NULL DEFAULT FALSE, sort_order INT NOT NULL DEFAULT 0, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS custom_requirements ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, requirement_text TEXT NOT NULL, animal_id UUID REFERENCES animals(id) ON DELETE SET NULL, status VARCHAR(50) NOT NULL DEFAULT 'open', created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP );