E-Commerce-Module/db/init/17-product-reviews.sql

80 lines
No EOL
2.9 KiB
PL/PgSQL

-- Create product reviews table
CREATE TABLE product_reviews (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
product_id UUID NOT NULL REFERENCES products(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES users(id),
parent_id UUID REFERENCES product_reviews(id) ON DELETE CASCADE,
title VARCHAR(255) NOT NULL,
content TEXT,
rating decimal CHECK (rating >= 0.0 AND rating <= 5.0),
is_approved BOOLEAN DEFAULT FALSE,
is_verified_purchase BOOLEAN DEFAULT FALSE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Add product average rating column to the products table
ALTER TABLE products ADD COLUMN IF NOT EXISTS average_rating DECIMAL(3, 2);
ALTER TABLE products ADD COLUMN IF NOT EXISTS review_count INTEGER DEFAULT 0;
-- Create indexes for performance
CREATE INDEX idx_product_reviews_product ON product_reviews(product_id);
CREATE INDEX idx_product_reviews_user ON product_reviews(user_id);
CREATE INDEX idx_product_reviews_parent ON product_reviews(parent_id);
CREATE INDEX idx_product_reviews_approved ON product_reviews(is_approved);
CREATE INDEX idx_product_reviews_rating ON product_reviews(rating);
-- Create trigger to automatically update the updated_at column
CREATE TRIGGER update_product_reviews_modtime
BEFORE UPDATE ON product_reviews
FOR EACH ROW EXECUTE FUNCTION update_modified_column();
-- Function to update product average rating and review count
CREATE OR REPLACE FUNCTION update_product_average_rating()
RETURNS TRIGGER AS $$
DECLARE
avg_rating DECIMAL(3, 2);
rev_count INTEGER;
BEGIN
-- Calculate average rating and count for approved top-level reviews
SELECT
AVG(rating)::DECIMAL(3, 2),
COUNT(*)
INTO
avg_rating,
rev_count
FROM product_reviews
WHERE product_id = NEW.product_id
AND parent_id IS NULL
AND is_approved = TRUE
AND rating IS NOT NULL;
-- Update the product with new average rating and count
UPDATE products
SET
average_rating = avg_rating,
review_count = rev_count
WHERE id = NEW.product_id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Create triggers to recalculate average rating when reviews are added/updated/deleted
CREATE TRIGGER update_product_rating_on_insert
AFTER INSERT ON product_reviews
FOR EACH ROW
WHEN (NEW.parent_id IS NULL) -- Only for top-level reviews
EXECUTE FUNCTION update_product_average_rating();
CREATE TRIGGER update_product_rating_on_update
AFTER UPDATE OF is_approved, rating ON product_reviews
FOR EACH ROW
WHEN (NEW.parent_id IS NULL) -- Only for top-level reviews
EXECUTE FUNCTION update_product_average_rating();
CREATE TRIGGER update_product_rating_on_delete
AFTER DELETE ON product_reviews
FOR EACH ROW
WHEN (OLD.parent_id IS NULL) -- Only for top-level reviews
EXECUTE FUNCTION update_product_average_rating();