diff --git a/db/final_db.sql b/db/final_db.sql index f1087d8..46bbd66 100644 --- a/db/final_db.sql +++ b/db/final_db.sql @@ -8,6 +8,8 @@ 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() @@ -47,10 +49,10 @@ BEGIN 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'); + 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 ('seller','buyer','service_provider'); + 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'); @@ -73,10 +75,27 @@ BEGIN 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; 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, @@ -85,14 +104,19 @@ CREATE TABLE users ( 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, + roles listing_role_enum[] NOT NULL DEFAULT '{seller_buyer}', + current_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', -- 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(), @@ -119,6 +143,8 @@ CREATE TABLE user_devices ( device_identifier TEXT, device_platform TEXT NOT NULL, fcm_token TEXT, -- For Push Notifications + lat NUMERIC(10,7), + lng NUMERIC(10,7), last_seen_at TIMESTAMPTZ, is_active BOOLEAN NOT NULL DEFAULT TRUE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), @@ -134,18 +160,6 @@ CREATE TABLE refresh_tokens ( 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 ( @@ -183,6 +197,14 @@ CREATE TABLE locations ( 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', selected_location BOOLEAN NOT NULL DEFAULT FALSE, deleted BOOLEAN NOT NULL DEFAULT FALSE, @@ -192,20 +214,7 @@ CREATE TABLE locations ( 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) -- ====================================================== @@ -225,6 +234,7 @@ CREATE TABLE animals ( 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, @@ -261,7 +271,16 @@ CREATE TABLE listings ( 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) @@ -352,7 +371,8 @@ CREATE TABLE reviews ( 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), + listing_rating INT CHECK (listing_rating >= 1 AND listing_rating <= 5), + seller_rating INT CHECK (seller_rating >= 1 AND seller_rating <= 5), comment TEXT, created_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(listing_id, reviewer_id) @@ -364,35 +384,38 @@ 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 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(), + 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, - media_id UUID UNIQUE REFERENCES conversation_media(id) ON DELETE SET NULL, + + -- Embedded Media + message_media TEXT, + media_type media_type_enum, + 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; +-- 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, @@ -415,8 +438,12 @@ 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 + 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 @@ -442,7 +469,7 @@ 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) + rating_average = (SELECT AVG(seller_rating) FROM reviews WHERE reviewee_id = NEW.reviewee_id) WHERE id = NEW.reviewee_id; RETURN NEW; END; @@ -452,6 +479,37 @@ 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(); + -- ====================================================== -- END OF SCRIPT -- ====================================================== \ No newline at end of file