E-Commerce-Module/db/init/14-product-notifications.sql
2025-04-28 13:33:52 -05:00

53 lines
No EOL
1.9 KiB
PL/PgSQL

ALTER TABLE products ADD COLUMN IF NOT EXISTS stock_notification JSONB;
-- Create a function to send email notifications when stock drops below threshold
CREATE OR REPLACE FUNCTION notify_low_stock()
RETURNS TRIGGER AS $$
BEGIN
-- Check if notification is enabled and new stock is below threshold
IF (NEW.stock_notification IS NOT NULL AND
NEW.stock_notification->>'enabled' = 'true' AND
NEW.stock_notification->>'email' IS NOT NULL AND
(NEW.stock_notification->>'threshold')::int > 0 AND
NEW.stock_quantity <= (NEW.stock_notification->>'threshold')::int AND
(OLD.stock_quantity IS NULL OR OLD.stock_quantity > (NEW.stock_notification->>'threshold')::int)) THEN
-- Insert notification record into a notification log table
INSERT INTO notification_logs (
order_id, -- Using NULL as this isn't tied to a specific order
notification_type,
sent_at,
status
) VALUES (
NULL,
'low_stock_alert',
NOW(),
'pending'
);
-- Note: The actual email sending will be handled by a backend process
-- that periodically checks for pending notifications
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Create trigger to check stock level on update
CREATE TRIGGER check_stock_level_on_update
AFTER UPDATE OF stock_quantity ON products
FOR EACH ROW
EXECUTE FUNCTION notify_low_stock();
-- Create trigger to check stock level on insert (though less common)
CREATE TRIGGER check_stock_level_on_insert
AFTER INSERT ON products
FOR EACH ROW
EXECUTE FUNCTION notify_low_stock();
-- Add stock_notification column to products table
ALTER TABLE products ADD COLUMN IF NOT EXISTS stock_notification JSONB;
-- Create index for faster lookups of products with notifications
CREATE INDEX IF NOT EXISTS idx_products_stock_notification ON products ((stock_notification IS NOT NULL))
WHERE stock_notification IS NOT NULL;
ALTER TABLE notification_logs ALTER COLUMN order_id DROP NOT NULL;