Finalized main database schema

This commit is contained in:
Soham Chari 2025-12-13 16:14:54 +05:30
parent edeb172a6c
commit 662ce498d8
5 changed files with 482 additions and 1 deletions

BIN
db/ERD.png Normal file

Binary file not shown.

After

Width:  |  Height:  |  Size: 551 KiB

Binary file not shown.

Before

Width:  |  Height:  |  Size: 467 KiB

24
db/description.txt Normal file
View File

@ -0,0 +1,24 @@
Performance Optimizations & Triggers:
The database uses triggers to automate maintenance tasks, keeping data consistent and fast without manual intervention.
1. Auto-Timestamps: Key tables (users, listings, animals, etc.) automatically update updated_at whenever modified.
2. Auto-Hydration (listings): Critical search data (species, breed, location, sex) is automatically copied types from animals/locations to listings.
3. Auto-Ratings: Seller ratings (average & count) are instantly recalculated and stored on the user profile whenever a review is added.
Tables:
1. listings (The Feed)
The central table. un-normalized for speed.
Optimization: It stores redundant copies of search fields (filter_species_id, filter_location_geog, etc.).
This allows millions of listings to be filtered/sorted instantly using a single table scan.
2. listing_analytics_events (High-Speed Buffer)
Tracks every user interaction (views, clicks, calls).
Design: Insert-only buffer. This prevents locking the main listings table for every single view, ensuring the marketplace stays responsive under high load.
3. breeds
Description stores text or link to an s3 document.
Extensions Used:
1. pgcrypto: Provides cryptographic functions, used here primarily for generating random UUIDs (gen_random_uuid()) and potentially for hashing if needed later.
2. uuid-ossp: Provides functions to generate universally unique identifiers (UUIDs), specifically used for uuid_generate_v4() as a fallback or alternative to gen_random_uuid().
3. postgis: Adds support for geographic objects to the PostgreSQL database. Crucial for the "Near Me" feature, analyzing the `geog` column in the listings table to find items within a certain radius.

File diff suppressed because one or more lines are too long

457
db/final_db.sql Normal file
View File

@ -0,0 +1,457 @@
-- ======================================================
-- 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
-- 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 ('user','admin','moderator');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'user_type_enum') THEN
CREATE TYPE user_type_enum AS ENUM ('seller','buyer','service_provider');
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;
END $$;
-- 4. USERS & AUTHENTICATION
-- ======================================================
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,
role listing_role_enum NOT NULL DEFAULT 'user',
user_type user_type_enum,
country_code VARCHAR(10) NOT NULL DEFAULT '+91',
-- Seller Ratings (Cached for speed)
rating_average NUMERIC(3, 2) DEFAULT 0.00,
rating_count INT DEFAULT 0,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_login_at TIMESTAMPTZ
);
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,
fcm_token TEXT, -- For Push Notifications
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 TABLE refresh_tokens (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
token_hash VARCHAR(255) NOT NULL,
expires_at TIMESTAMPTZ NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE user_contacts (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
contact_user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
is_blocked 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(),
UNIQUE(user_id, contact_user_id)
);
CREATE TRIGGER trg_user_contacts_updated_at BEFORE UPDATE ON user_contacts FOR EACH ROW EXECUTE FUNCTION set_updated_at();
-- 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,
source_type source_type_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 TRIGGER trg_locations_updated_at BEFORE UPDATE ON locations FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TABLE location_details (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
location_id UUID UNIQUE NOT NULL REFERENCES locations(id) ON DELETE CASCADE,
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),
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- 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',
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_location_geog GEOGRAPHY(POINT, 4326),
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[],
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()
);
-- 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),
rating INT CHECK (rating >= 1 AND rating <= 5),
comment TEXT,
created_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(listing_id, reviewer_id)
);
-- 10. 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),
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 conversation_media (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
media_type media_type_enum NOT NULL,
media_url TEXT NOT NULL,
thumbnail_url TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE messages (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
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,
media_id UUID UNIQUE REFERENCES conversation_media(id) ON DELETE SET NULL,
is_read BOOLEAN NOT NULL DEFAULT FALSE,
read_at TIMESTAMPTZ,
deleted BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Index for scrolling up in chat history (Newest first)
CREATE INDEX idx_messages_history ON messages (conversation_id, created_at 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,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- 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
INTO NEW.filter_species_id, NEW.filter_breed_id, NEW.filter_sex, NEW.filter_age_months
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(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();
-- ======================================================
-- END OF SCRIPT
-- ======================================================