-- Create coupons table CREATE TABLE coupons ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), code VARCHAR(50) NOT NULL UNIQUE, description TEXT, discount_type VARCHAR(20) NOT NULL, -- 'percentage', 'fixed_amount' discount_value DECIMAL(10, 2) NOT NULL, -- Percentage or fixed amount value min_purchase_amount DECIMAL(10, 2), -- Minimum purchase amount to use the coupon (optional) max_discount_amount DECIMAL(10, 2), -- Maximum discount amount for percentage discounts (optional) redemption_limit INTEGER, -- NULL means unlimited redemptions current_redemptions INTEGER NOT NULL DEFAULT 0, -- Track how many times coupon has been used start_date TIMESTAMP WITH TIME ZONE, -- When the coupon becomes valid (optional) end_date TIMESTAMP WITH TIME ZONE, -- When the coupon expires (optional) is_active BOOLEAN NOT NULL DEFAULT TRUE, -- Whether the coupon is currently active created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create coupon_categories junction table CREATE TABLE coupon_categories ( coupon_id UUID NOT NULL REFERENCES coupons(id) ON DELETE CASCADE, category_id UUID NOT NULL REFERENCES product_categories(id) ON DELETE CASCADE, PRIMARY KEY (coupon_id, category_id) ); -- Create coupon_tags junction table CREATE TABLE coupon_tags ( coupon_id UUID NOT NULL REFERENCES coupons(id) ON DELETE CASCADE, tag_id UUID NOT NULL REFERENCES tags(id) ON DELETE CASCADE, PRIMARY KEY (coupon_id, tag_id) ); -- Create coupon_blacklist table for excluded products CREATE TABLE coupon_blacklist ( coupon_id UUID NOT NULL REFERENCES coupons(id) ON DELETE CASCADE, product_id UUID NOT NULL REFERENCES products(id) ON DELETE CASCADE, PRIMARY KEY (coupon_id, product_id) ); -- Create coupon_redemptions table to track usage CREATE TABLE coupon_redemptions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), coupon_id UUID NOT NULL REFERENCES coupons(id) ON DELETE CASCADE, order_id UUID NOT NULL REFERENCES orders(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id), discount_amount DECIMAL(10, 2) NOT NULL, redeemed_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Add applied_coupon_id to orders table ALTER TABLE orders ADD COLUMN coupon_id UUID REFERENCES coupons(id); ALTER TABLE orders ADD COLUMN discount_amount DECIMAL(10, 2) DEFAULT 0.00; -- Add indexes for better performance CREATE INDEX idx_coupon_code ON coupons(code); CREATE INDEX idx_coupon_is_active ON coupons(is_active); CREATE INDEX idx_coupon_end_date ON coupons(end_date); CREATE INDEX idx_coupon_redemptions_coupon_id ON coupon_redemptions(coupon_id); CREATE INDEX idx_coupon_redemptions_user_id ON coupon_redemptions(user_id); -- Create trigger to update the updated_at timestamp CREATE TRIGGER update_coupons_modtime BEFORE UPDATE ON coupons FOR EACH ROW EXECUTE FUNCTION update_modified_column();