api-v1/db/final_db.sql

670 lines
26 KiB
PL/PgSQL

-- ======================================================
-- LIVESTOCK MARKETPLACE - COMPLETE PRODUCTION SCHEMA
-- ======================================================
-- 1. EXTENSIONS
-- ======================================================
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
CREATE EXTENSION IF NOT EXISTS "postgis"; -- Crucial for "Near Me" filters
SET timezone TO 'UTC';
-- 2. GLOBAL FUNCTIONS (Timestamps)
-- ======================================================
CREATE OR REPLACE FUNCTION set_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- 3. ENUM TYPES
-- ======================================================
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'sex_enum') THEN
CREATE TYPE sex_enum AS ENUM ('M','F','Neutered');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'purpose_enum') THEN
CREATE TYPE purpose_enum AS ENUM ('dairy','meat','breeding','pet','work','other');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'health_status_enum') THEN
CREATE TYPE health_status_enum AS ENUM ('healthy','minor_issues','serious_issues');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'location_type_enum') THEN
CREATE TYPE location_type_enum AS ENUM ('farm','home','office','temporary_gps','other_saved','other');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'source_type_enum') THEN
CREATE TYPE source_type_enum AS ENUM ('gps','device_gps','manual','imported','unknown');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'listing_type_enum') THEN
CREATE TYPE listing_type_enum AS ENUM ('sale','stud_service','adoption','other');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'listing_status_enum') THEN
CREATE TYPE listing_status_enum AS ENUM ('active','sold','expired','hidden','deleted');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'seller_type_enum') THEN
CREATE TYPE seller_type_enum AS ENUM ('owner','farmer','broker','agent','other');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'listing_role_enum') THEN
CREATE TYPE listing_role_enum AS ENUM ('seller_buyer','service_provider');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'user_type_enum') THEN
CREATE TYPE user_type_enum AS ENUM ('user','admin','moderator');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'message_type_enum') THEN
CREATE TYPE message_type_enum AS ENUM ('text','media','both');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'media_type_enum') THEN
CREATE TYPE media_type_enum AS ENUM ('image','video','audio','document');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'communication_type_enum') THEN
CREATE TYPE communication_type_enum AS ENUM ('call','missed_call','voicemail');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'call_status_enum') THEN
CREATE TYPE call_status_enum AS ENUM ('initiated','ringing','answered','completed','failed','busy','no_answer');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'pregnancy_status_enum') THEN
CREATE TYPE pregnancy_status_enum AS ENUM ('none', 'pregnant', 'unknown');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'requirement_status_enum') THEN
CREATE TYPE requirement_status_enum AS ENUM ('open', 'fulfilled', 'cancelled');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'analytics_event_type_enum') THEN
CREATE TYPE analytics_event_type_enum AS ENUM ('views_count','bookmarks_count','enquiries_call_count','enquiries_whatsapp_count');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'listing_score_status_enum') THEN
CREATE TYPE listing_score_status_enum AS ENUM ('pending', 'processing', 'completed', 'failed');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'source_confidence_enum') THEN
CREATE TYPE source_confidence_enum AS ENUM ('high', 'medium', 'low', 'unknown');
END IF;
END $$;
-- 4. USERS & AUTHENTICATION
-- ======================================================
CREATE TABLE subscription_plans (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(100) NOT NULL UNIQUE,
description TEXT,
price NUMERIC(10, 2),
currency VARCHAR(10) DEFAULT 'INR',
duration_days INT, -- Validity in days
features JSONB, -- Flexible JSON for features like {"max_listings": 10}
is_active BOOLEAN DEFAULT TRUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TRIGGER trg_subscription_plans_updated_at BEFORE UPDATE ON subscription_plans FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
phone_number VARCHAR(20) UNIQUE,
name VARCHAR(255),
avatar_url TEXT,
language VARCHAR(10),
timezone VARCHAR(50),
is_active BOOLEAN NOT NULL DEFAULT TRUE,
roles listing_role_enum[] NOT NULL DEFAULT '{seller_buyer}',
active_role listing_role_enum NOT NULL DEFAULT 'seller_buyer',
user_type user_type_enum NOT NULL DEFAULT 'user',
country_code VARCHAR(10) NOT NULL DEFAULT '+91',
-- Legacy role field (for backward compatibility with auth code)
role listing_role_enum, -- Deprecated: use user_type for system roles, roles[] for marketplace roles
-- Token version for global logout
token_version INT NOT NULL DEFAULT 1,
-- Seller Ratings (Cached for speed)
rating_average NUMERIC(3, 2) DEFAULT 0.00,
rating_count INT DEFAULT 0,
-- Subscription Info
subscription_plan_id UUID REFERENCES subscription_plans(id) ON DELETE SET NULL,
subscription_expires_at TIMESTAMPTZ,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_login_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TRIGGER trg_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE otp_requests (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
phone_number VARCHAR(20) NOT NULL,
country_code VARCHAR(10) NOT NULL DEFAULT '+91',
otp_hash VARCHAR(255) NOT NULL,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
expires_at TIMESTAMPTZ NOT NULL,
consumed_at TIMESTAMPTZ,
attempt_count INT NOT NULL DEFAULT 0,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_otp_phone_unconsumed ON otp_requests (phone_number) WHERE consumed_at IS NULL;
CREATE TABLE user_devices (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
device_identifier TEXT,
device_platform TEXT NOT NULL,
device_model TEXT,
os_version TEXT,
app_version TEXT,
language_code TEXT,
timezone TEXT,
fcm_token TEXT, -- For Push Notifications
lat NUMERIC(10,7),
lng NUMERIC(10,7),
first_seen_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_seen_at TIMESTAMPTZ,
is_active BOOLEAN NOT NULL DEFAULT TRUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(user_id, device_identifier)
);
CREATE INDEX idx_user_devices_user ON user_devices (user_id);
CREATE INDEX idx_user_devices_device_identifier ON user_devices (device_identifier);
CREATE INDEX idx_user_devices_platform ON user_devices (device_platform);
CREATE INDEX idx_user_devices_last_seen ON user_devices (last_seen_at);
CREATE TABLE refresh_tokens (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
device_id VARCHAR(255) NOT NULL,
token_id UUID NOT NULL UNIQUE,
token_hash VARCHAR(255) NOT NULL,
user_agent TEXT,
ip_address VARCHAR(45),
expires_at TIMESTAMPTZ NOT NULL,
last_used_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
revoked_at TIMESTAMPTZ,
reuse_detected_at TIMESTAMPTZ,
rotated_from_id UUID REFERENCES refresh_tokens(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_refresh_tokens_user_device ON refresh_tokens(user_id, device_id);
CREATE INDEX idx_refresh_tokens_expires ON refresh_tokens(expires_at);
CREATE INDEX idx_refresh_tokens_token_hash ON refresh_tokens(token_hash);
CREATE INDEX idx_refresh_tokens_revoked ON refresh_tokens(revoked_at);
-- Authentication Audit Logging (for security monitoring)
CREATE TABLE auth_audit (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
action VARCHAR(100) NOT NULL,
status VARCHAR(50) NOT NULL,
risk_level VARCHAR(20) DEFAULT 'INFO',
device_id VARCHAR(255),
ip_address VARCHAR(45),
user_agent TEXT,
meta JSONB,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_auth_audit_user ON auth_audit(user_id);
CREATE INDEX idx_auth_audit_created ON auth_audit(created_at);
CREATE INDEX idx_auth_audit_action ON auth_audit(action);
CREATE INDEX idx_auth_audit_status ON auth_audit(status);
CREATE INDEX idx_auth_audit_risk_level ON auth_audit(risk_level);
-- 5. MASTER DATA (Species & Breeds)
-- ======================================================
CREATE TABLE species (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(120) NOT NULL UNIQUE,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE breeds (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
species_id UUID NOT NULL REFERENCES species(id) ON DELETE RESTRICT,
name VARCHAR(150) NOT NULL,
description TEXT,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(species_id, name)
);
-- 6. LOCATIONS (Optimized with PostGIS)
-- ======================================================
CREATE TABLE locations (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
lat NUMERIC(10,7),
lng NUMERIC(10,7),
-- AUTOMATIC GEOGRAPHY COLUMN (The Magic for 'Near Me' queries)
-- This automatically creates a spatial point whenever you save lat/lng
geog GEOGRAPHY(POINT, 4326) GENERATED ALWAYS AS (
CASE WHEN lat IS NOT NULL AND lng IS NOT NULL
THEN ST_SetSRID(ST_MakePoint(lng, lat), 4326)::geography
ELSE NULL END
) STORED,
is_saved_address BOOLEAN NOT NULL DEFAULT FALSE,
location_type location_type_enum,
country VARCHAR(100),
state VARCHAR(100),
district VARCHAR(100),
city_village VARCHAR(150),
pincode VARCHAR(20),
source_type source_type_enum DEFAULT 'unknown',
source_confidence source_confidence_enum DEFAULT 'unknown',
selected_location BOOLEAN NOT NULL DEFAULT FALSE,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_locations_geog ON locations USING GIST (geog); -- Spatial Index
CREATE INDEX idx_locations_user ON locations (user_id);
CREATE INDEX idx_locations_lat_lng ON locations (lat, lng);
CREATE TRIGGER trg_locations_updated_at BEFORE UPDATE ON locations FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- 7. ANIMALS (The Inventory)
-- ======================================================
CREATE TABLE animals (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
species_id UUID NOT NULL REFERENCES species(id) ON DELETE RESTRICT,
breed_id UUID REFERENCES breeds(id) ON DELETE SET NULL,
location_id UUID REFERENCES locations(id) ON DELETE RESTRICT,
sex sex_enum,
age_months INT,
weight_kg NUMERIC(8,2),
color_markings VARCHAR(255),
quantity INT NOT NULL DEFAULT 1,
purpose purpose_enum,
health_status health_status_enum DEFAULT 'healthy',
vaccinated BOOLEAN DEFAULT FALSE,
dewormed BOOLEAN DEFAULT FALSE,
pregnancy_status pregnancy_status_enum NOT NULL DEFAULT 'unknown',
calving_number INT,
milk_yield_litre_per_day NUMERIC(8,3),
ear_tag_no VARCHAR(100),
description TEXT,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TRIGGER trg_animals_updated_at BEFORE UPDATE ON animals FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- 8. LISTINGS (Denormalized for Read Performance)
-- ======================================================
CREATE TABLE 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(255) NOT NULL,
price NUMERIC(12,2),
currency VARCHAR(10) DEFAULT 'INR',
is_negotiable BOOLEAN DEFAULT FALSE,
listing_type listing_type_enum DEFAULT 'sale',
status listing_status_enum DEFAULT 'active',
-- Counters (Updated via Batch Jobs)
views_count BIGINT DEFAULT 0,
bookmarks_count BIGINT DEFAULT 0,
enquiries_call_count BIGINT DEFAULT 0,
enquiries_whatsapp_count BIGINT DEFAULT 0,
-- DENORMALIZED COLUMNS (Auto-filled by Trigger)
-- These exist so the Home Feed doesn't need to join 4 tables
filter_species_id UUID,
filter_breed_id UUID,
filter_sex sex_enum,
filter_age_months INT,
filter_pregnancy_status pregnancy_status_enum,
filter_weight_kg NUMERIC(8,2),
filter_calving_number INT,
filter_milking_capacity NUMERIC(8,3),
filter_location_geog GEOGRAPHY(POINT, 4326),
-- AI Score
listing_score INT,
listing_score_status listing_score_status_enum DEFAULT 'pending',
thumbnail_url TEXT,
-- FULL TEXT SEARCH (Auto-generated)
search_vector tsvector GENERATED ALWAYS AS (
to_tsvector('english', title)
) STORED,
deleted_reason TEXT,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TRIGGER trg_listings_updated_at BEFORE UPDATE ON listings FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- OPTIMIZED INDEXES
-- 1. Main Feed: Status + Species + Price (ignoring deleted)
CREATE INDEX idx_listings_feed_optimized ON listings (status, filter_species_id, price) WHERE deleted = FALSE;
-- 2. Near Me: Spatial Search
CREATE INDEX idx_listings_spatial ON listings USING GIST (filter_location_geog) WHERE deleted = FALSE;
-- 3. Search Bar: Text Search
CREATE INDEX idx_listings_search_gin ON listings USING GIN (search_vector);
-- 4. My Listings: Seller + Status
CREATE INDEX idx_listings_seller_status ON listings (seller_id, status) WHERE deleted = FALSE;
CREATE TABLE listing_media (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
listing_id UUID NOT NULL REFERENCES listings(id) ON DELETE CASCADE,
media_url TEXT NOT NULL,
media_type media_type_enum NOT NULL,
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
sort_order INT NOT NULL DEFAULT 0,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE sold_information (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
listing_id UUID NOT NULL UNIQUE REFERENCES listings(id) ON DELETE CASCADE,
sold_to_user_id UUID REFERENCES users(id) ON DELETE SET NULL,
sale_price NUMERIC(12, 2),
sale_location_id UUID REFERENCES locations(id) ON DELETE SET NULL,
sale_date TIMESTAMPTZ,
notes TEXT,
attachment_urls TEXT[],
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TRIGGER trg_sold_information_updated_at BEFORE UPDATE ON sold_information FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- 9. ENGAGEMENT (Reviews, Analytics, Retention)
-- ======================================================
CREATE TABLE custom_requirements (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT,
animal_id UUID REFERENCES animals(id) ON DELETE SET NULL,
requirement_text TEXT NOT NULL,
status requirement_status_enum NOT NULL DEFAULT 'open',
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TRIGGER trg_custom_requirements_updated_at BEFORE UPDATE ON custom_requirements FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- New: High-speed analytics buffer
CREATE TABLE listing_analytics_events (
id BIGSERIAL PRIMARY KEY,
listing_id UUID NOT NULL REFERENCES listings(id) ON DELETE CASCADE,
event_type analytics_event_type_enum NOT NULL,
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ DEFAULT NOW()
);
-- Table for favorites
CREATE TABLE favorites (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT,
listing_id UUID NOT NULL REFERENCES listings(id) ON DELETE CASCADE,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(user_id, listing_id)
);
CREATE TRIGGER trg_favorites_updated_at BEFORE UPDATE ON favorites FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- New: Reviews & Ratings
CREATE TABLE reviews (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
listing_id UUID REFERENCES listings(id) ON DELETE SET NULL,
reviewer_id UUID REFERENCES users(id),
reviewee_id UUID REFERENCES users(id),
listing_rating INT CHECK (listing_rating >= 1 AND listing_rating <= 5),
seller_rating INT CHECK (seller_rating >= 1 AND seller_rating <= 5),
comment TEXT,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(listing_id, reviewer_id)
);
CREATE TRIGGER trg_reviews_updated_at BEFORE UPDATE ON reviews FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- 11. NOTIFICATIONS
-- ======================================================
CREATE TYPE notification_type_enum AS ENUM ('listing_expired', 'listing_enquiry', 'system_alert', 'other');
CREATE TABLE notifications (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
type notification_type_enum NOT NULL,
message TEXT NOT NULL,
data JSONB, -- Related entity IDs etc.
is_read BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_notifications_user_unread ON notifications(user_id) WHERE is_read = FALSE;
-- 12. CHAT & COMMUNICATIONS
-- ======================================================
CREATE TABLE conversations (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
buyer_id UUID NOT NULL REFERENCES users(id),
seller_id UUID NOT NULL REFERENCES users(id),
-- Denormalized Fields for Listing
last_message_content TEXT,
last_message_at TIMESTAMPTZ,
last_call_at TIMESTAMPTZ,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(buyer_id, seller_id)
);
CREATE TABLE messages (
id BIGSERIAL PRIMARY KEY, -- Changed to BIGINT for cursor pagination
conversation_id UUID NOT NULL REFERENCES conversations(id) ON DELETE CASCADE,
sender_id UUID NOT NULL REFERENCES users(id),
receiver_id UUID NOT NULL REFERENCES users(id),
message_type message_type_enum NOT NULL DEFAULT 'text',
content TEXT,
-- Embedded Media
message_media TEXT,
media_type media_type_enum,
media_metadata JSONB,
is_read BOOLEAN NOT NULL DEFAULT FALSE,
read_at TIMESTAMPTZ,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TRIGGER trg_messages_updated_at BEFORE UPDATE ON messages FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- Efficient Index for Cursor Pagination: (conversation as filter, id as cursor)
CREATE INDEX idx_messages_pagination ON messages(conversation_id, id DESC) WHERE deleted = FALSE;
CREATE TABLE communication_records (
communication_id BIGSERIAL PRIMARY KEY,
conversation_id UUID REFERENCES conversations(id) ON DELETE SET NULL,
buyer_id UUID NOT NULL REFERENCES users(id),
seller_id UUID NOT NULL REFERENCES users(id),
communication_type communication_type_enum NOT NULL,
call_status call_status_enum NOT NULL,
duration_seconds INT DEFAULT 0,
call_recording_url TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TRIGGER trg_communication_records_updated_at BEFORE UPDATE ON communication_records FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- 11. AUTOMATION TRIGGERS
-- ======================================================
-- Trigger 1: Sync Animal/Location Data to Listing (The "Speed" Trigger)
CREATE OR REPLACE FUNCTION sync_listing_search_data()
RETURNS TRIGGER AS $$
DECLARE
loc_geog GEOGRAPHY(POINT, 4326);
BEGIN
-- 1. Sync Animal Info
SELECT
species_id, breed_id, sex, age_months,
pregnancy_status, weight_kg, calving_number, milk_yield_litre_per_day
INTO
NEW.filter_species_id, NEW.filter_breed_id, NEW.filter_sex, NEW.filter_age_months,
NEW.filter_pregnancy_status, NEW.filter_weight_kg, NEW.filter_calving_number, NEW.filter_milking_capacity
FROM animals WHERE id = NEW.animal_id;
-- 2. Sync Location Info
SELECT geog INTO loc_geog
FROM locations
WHERE id = (SELECT location_id FROM animals WHERE id = NEW.animal_id);
NEW.filter_location_geog := loc_geog;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trg_hydrate_listing
BEFORE INSERT OR UPDATE ON listings
FOR EACH ROW EXECUTE FUNCTION sync_listing_search_data();
-- Trigger 2: Auto-Update User Rating when Review is added
CREATE OR REPLACE FUNCTION update_seller_rating()
RETURNS TRIGGER AS $$
BEGIN
UPDATE users
SET
rating_count = (SELECT COUNT(*) FROM reviews WHERE reviewee_id = NEW.reviewee_id),
rating_average = (SELECT AVG(seller_rating) FROM reviews WHERE reviewee_id = NEW.reviewee_id)
WHERE id = NEW.reviewee_id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trg_update_rating
AFTER INSERT OR UPDATE ON reviews
FOR EACH ROW EXECUTE FUNCTION update_seller_rating();
-- Trigger 3: Auto-Update Conversation Last Message & Call
CREATE OR REPLACE FUNCTION update_conversation_latest()
RETURNS TRIGGER AS $$
BEGIN
IF TG_TABLE_NAME = 'messages' THEN
UPDATE conversations
SET
last_message_content = NEW.content,
last_message_at = NEW.created_at,
updated_at = NOW()
WHERE id = NEW.conversation_id;
ELSIF TG_TABLE_NAME = 'communication_records' THEN
UPDATE conversations
SET
last_call_at = NEW.created_at,
updated_at = NOW()
WHERE id = NEW.conversation_id;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trg_update_conversation_msg
AFTER INSERT ON messages
FOR EACH ROW EXECUTE FUNCTION update_conversation_latest();
CREATE TRIGGER trg_update_conversation_call
AFTER INSERT ON communication_records
FOR EACH ROW EXECUTE FUNCTION update_conversation_latest();
-- Trigger 4: Auto-Update Listing Status when Sold Info is added
CREATE OR REPLACE FUNCTION update_listing_status_on_sold()
RETURNS TRIGGER AS $$
BEGIN
UPDATE listings
SET status = 'sold'
WHERE id = NEW.listing_id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trg_update_listing_status_on_sold
AFTER INSERT ON sold_information
FOR EACH ROW EXECUTE FUNCTION update_listing_status_on_sold();
-- Trigger 5: Propagate Animal Updates to Listings
CREATE OR REPLACE FUNCTION propagate_animal_updates_to_listings()
RETURNS TRIGGER AS $$
BEGIN
-- Update the related listing to trigger the sync logic
UPDATE listings
SET updated_at = NOW()
WHERE animal_id = NEW.id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trg_propagate_animal_updates
AFTER UPDATE ON animals
FOR EACH ROW EXECUTE FUNCTION propagate_animal_updates_to_listings();
-- Trigger 6: Cascade Delete Listing -> Animal
CREATE OR REPLACE FUNCTION cascade_delete_animal()
RETURNS TRIGGER AS $$
BEGIN
UPDATE animals
SET deleted = TRUE, updated_at = NOW()
WHERE id = NEW.animal_id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trg_cascade_delete_animal
AFTER UPDATE ON listings
FOR EACH ROW
WHEN (OLD.deleted = FALSE AND NEW.deleted = TRUE)
EXECUTE FUNCTION cascade_delete_animal();
-- Trigger 7: Ensure Single Primary Media per Listing
CREATE OR REPLACE FUNCTION ensure_single_primary_media()
RETURNS TRIGGER AS $$
BEGIN
-- If the new/updated row is set to be primary
IF NEW.is_primary = TRUE THEN
-- Reset is_primary for all OTHER records of this listing
UPDATE listing_media
SET is_primary = FALSE
WHERE listing_id = NEW.listing_id
AND id != NEW.id -- Don't unset the one we are just creating/updating
AND is_primary = TRUE; -- Optimization: only update if currently true
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trg_ensure_single_primary_media
BEFORE INSERT OR UPDATE ON listing_media
FOR EACH ROW EXECUTE FUNCTION ensure_single_primary_media();
-- ======================================================
-- END OF SCRIPT
-- ======================================================