103 lines
3.5 KiB
PL/PgSQL
103 lines
3.5 KiB
PL/PgSQL
-- Migration: Add Reviews System
|
|
-- Created: 2026-01-03
|
|
|
|
-- Create reviews table
|
|
CREATE TABLE IF NOT EXISTS reviews (
|
|
review_id SERIAL PRIMARY KEY,
|
|
product_id INTEGER NOT NULL REFERENCES products(product_id) ON DELETE CASCADE,
|
|
user_id INTEGER NOT NULL REFERENCES users(user_id) ON DELETE CASCADE,
|
|
rating INTEGER NOT NULL CHECK (rating >= 1 AND rating <= 5),
|
|
comment TEXT,
|
|
is_approved BOOLEAN DEFAULT TRUE,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(product_id, user_id) -- One review per user per product
|
|
);
|
|
|
|
-- Add indexes for better query performance
|
|
CREATE INDEX IF NOT EXISTS idx_reviews_product_id ON reviews(product_id);
|
|
CREATE INDEX IF NOT EXISTS idx_reviews_user_id ON reviews(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_reviews_rating ON reviews(rating);
|
|
CREATE INDEX IF NOT EXISTS idx_reviews_created_at ON reviews(created_at);
|
|
|
|
-- Add rating and review_count columns to products table if they don't exist
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (SELECT 1 FROM information_schema.columns
|
|
WHERE table_name='products' AND column_name='rating') THEN
|
|
ALTER TABLE products ADD COLUMN rating DECIMAL(3,2) DEFAULT 0.00;
|
|
END IF;
|
|
|
|
IF NOT EXISTS (SELECT 1 FROM information_schema.columns
|
|
WHERE table_name='products' AND column_name='review_count') THEN
|
|
ALTER TABLE products ADD COLUMN review_count INTEGER DEFAULT 0;
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Create function to automatically update updated_at timestamp
|
|
CREATE OR REPLACE FUNCTION update_reviews_updated_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Create trigger for reviews updated_at
|
|
DROP TRIGGER IF EXISTS trigger_reviews_updated_at ON reviews;
|
|
CREATE TRIGGER trigger_reviews_updated_at
|
|
BEFORE UPDATE ON reviews
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_reviews_updated_at();
|
|
|
|
-- Function to update product rating and review count
|
|
CREATE OR REPLACE FUNCTION update_product_rating(p_product_id INTEGER)
|
|
RETURNS VOID AS $$
|
|
DECLARE
|
|
avg_rating DECIMAL(3,2);
|
|
total_reviews INTEGER;
|
|
BEGIN
|
|
SELECT COALESCE(AVG(rating), 0.00), COUNT(*)
|
|
INTO avg_rating, total_reviews
|
|
FROM reviews
|
|
WHERE product_id = p_product_id AND is_approved = TRUE;
|
|
|
|
UPDATE products
|
|
SET rating = avg_rating,
|
|
review_count = total_reviews,
|
|
updated_at = CURRENT_TIMESTAMP
|
|
WHERE product_id = p_product_id;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Create trigger to auto-update product rating after review changes
|
|
CREATE OR REPLACE FUNCTION trigger_update_product_rating()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'DELETE' THEN
|
|
PERFORM update_product_rating(OLD.product_id);
|
|
RETURN OLD;
|
|
ELSE
|
|
PERFORM update_product_rating(NEW.product_id);
|
|
RETURN NEW;
|
|
END IF;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
DROP TRIGGER IF EXISTS trigger_review_insert_update_product_rating ON reviews;
|
|
CREATE TRIGGER trigger_review_insert_update_product_rating
|
|
AFTER INSERT OR UPDATE ON reviews
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION trigger_update_product_rating();
|
|
|
|
DROP TRIGGER IF EXISTS trigger_review_delete_update_product_rating ON reviews;
|
|
CREATE TRIGGER trigger_review_delete_update_product_rating
|
|
AFTER DELETE ON reviews
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION trigger_update_product_rating();
|
|
|
|
-- Grant permissions (adjust as needed)
|
|
-- GRANT ALL PRIVILEGES ON TABLE reviews TO your_db_user;
|
|
-- GRANT USAGE, SELECT ON SEQUENCE reviews_review_id_seq TO your_db_user;
|
|
|