Add new alert architecture
This commit is contained in:
197
migrations/001_create_alert_tables.sql
Normal file
197
migrations/001_create_alert_tables.sql
Normal file
@@ -0,0 +1,197 @@
|
||||
-- migrations/001_create_alert_tables.sql
|
||||
-- Database schema for unified alerts and recommendations system
|
||||
|
||||
-- Main alerts table (stores both alerts and recommendations)
|
||||
CREATE TABLE IF NOT EXISTS alerts (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
item_type VARCHAR(20) NOT NULL DEFAULT 'alert' CHECK (item_type IN ('alert', 'recommendation')),
|
||||
alert_type VARCHAR(50) NOT NULL, -- Specific type like 'critical_stock_shortage', 'inventory_optimization'
|
||||
severity VARCHAR(20) NOT NULL CHECK (severity IN ('urgent', 'high', 'medium', 'low')),
|
||||
status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'acknowledged', 'resolved')),
|
||||
service VARCHAR(50) NOT NULL,
|
||||
|
||||
title VARCHAR(255) NOT NULL,
|
||||
message TEXT NOT NULL,
|
||||
actions JSONB DEFAULT '[]',
|
||||
metadata JSONB DEFAULT '{}',
|
||||
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
acknowledged_at TIMESTAMP WITH TIME ZONE,
|
||||
acknowledged_by UUID,
|
||||
resolved_at TIMESTAMP WITH TIME ZONE,
|
||||
resolved_by UUID,
|
||||
|
||||
-- Add severity weight for sorting
|
||||
severity_weight INT GENERATED ALWAYS AS (
|
||||
CASE severity
|
||||
WHEN 'urgent' THEN 4
|
||||
WHEN 'high' THEN 3
|
||||
WHEN 'medium' THEN 2
|
||||
WHEN 'low' THEN 1
|
||||
END
|
||||
) STORED
|
||||
);
|
||||
|
||||
-- Indexes for performance
|
||||
CREATE INDEX IF NOT EXISTS idx_alerts_tenant_status ON alerts(tenant_id, status);
|
||||
CREATE INDEX IF NOT EXISTS idx_alerts_created_at ON alerts(created_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_alerts_severity ON alerts(severity_weight DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_alerts_tenant_active ON alerts(tenant_id, status) WHERE status = 'active';
|
||||
CREATE INDEX IF NOT EXISTS idx_alerts_item_type ON alerts(item_type);
|
||||
CREATE INDEX IF NOT EXISTS idx_alerts_service ON alerts(service);
|
||||
|
||||
-- Composite index for common queries
|
||||
CREATE INDEX IF NOT EXISTS idx_alerts_tenant_type_status ON alerts(tenant_id, item_type, status);
|
||||
|
||||
-- Alert history for audit trail (applies to both alerts and recommendations)
|
||||
CREATE TABLE IF NOT EXISTS alert_history (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
alert_id UUID REFERENCES alerts(id) ON DELETE CASCADE,
|
||||
tenant_id UUID NOT NULL,
|
||||
action VARCHAR(50) NOT NULL,
|
||||
performed_by UUID,
|
||||
performed_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
details JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_alert_history_alert ON alert_history(alert_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_alert_history_tenant ON alert_history(tenant_id);
|
||||
|
||||
-- Database triggers for immediate alerts (recommendations typically not triggered this way)
|
||||
-- Stock critical trigger
|
||||
CREATE OR REPLACE FUNCTION notify_stock_critical()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
-- Only trigger for alerts, not recommendations
|
||||
IF NEW.current_stock < NEW.minimum_stock AND
|
||||
OLD.current_stock >= OLD.minimum_stock THEN
|
||||
PERFORM pg_notify(
|
||||
'stock_alerts',
|
||||
json_build_object(
|
||||
'tenant_id', NEW.tenant_id,
|
||||
'ingredient_id', NEW.id,
|
||||
'name', NEW.name,
|
||||
'current_stock', NEW.current_stock,
|
||||
'minimum_stock', NEW.minimum_stock,
|
||||
'alert_type', 'critical_stock_shortage'
|
||||
)::text
|
||||
);
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Temperature breach trigger
|
||||
CREATE OR REPLACE FUNCTION notify_temperature_breach()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
IF NEW.temperature > NEW.max_threshold AND
|
||||
NEW.breach_duration_minutes > 30 THEN
|
||||
PERFORM pg_notify(
|
||||
'temperature_alerts',
|
||||
json_build_object(
|
||||
'tenant_id', NEW.tenant_id,
|
||||
'sensor_id', NEW.sensor_id,
|
||||
'location', NEW.location,
|
||||
'temperature', NEW.temperature,
|
||||
'duration', NEW.breach_duration_minutes,
|
||||
'alert_type', 'temperature_breach'
|
||||
)::text
|
||||
);
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Production delay trigger
|
||||
CREATE OR REPLACE FUNCTION notify_production_delay()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
IF NEW.status = 'delayed' AND OLD.status != 'delayed' THEN
|
||||
PERFORM pg_notify(
|
||||
'production_alerts',
|
||||
json_build_object(
|
||||
'tenant_id', NEW.tenant_id,
|
||||
'batch_id', NEW.id,
|
||||
'product_name', NEW.product_name,
|
||||
'planned_completion', NEW.planned_completion_time,
|
||||
'delay_minutes', EXTRACT(EPOCH FROM (NOW() - NEW.planned_completion_time))/60,
|
||||
'alert_type', 'production_delay'
|
||||
)::text
|
||||
);
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Create placeholder tables for triggers (these would exist in respective services)
|
||||
-- This is just for reference - actual tables should be in service-specific migrations
|
||||
|
||||
-- Inventory items table structure (for reference)
|
||||
CREATE TABLE IF NOT EXISTS inventory_items (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
current_stock DECIMAL(10,2) DEFAULT 0,
|
||||
minimum_stock DECIMAL(10,2) DEFAULT 0,
|
||||
maximum_stock DECIMAL(10,2),
|
||||
unit VARCHAR(50) DEFAULT 'kg',
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Temperature readings table structure (for reference)
|
||||
CREATE TABLE IF NOT EXISTS temperature_readings (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
sensor_id VARCHAR(100) NOT NULL,
|
||||
location VARCHAR(255) NOT NULL,
|
||||
temperature DECIMAL(5,2) NOT NULL,
|
||||
max_threshold DECIMAL(5,2) DEFAULT 25.0,
|
||||
breach_duration_minutes INT DEFAULT 0,
|
||||
recorded_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Production batches table structure (for reference)
|
||||
CREATE TABLE IF NOT EXISTS production_batches (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
product_name VARCHAR(255) NOT NULL,
|
||||
status VARCHAR(50) DEFAULT 'planned',
|
||||
planned_completion_time TIMESTAMP WITH TIME ZONE,
|
||||
actual_completion_time TIMESTAMP WITH TIME ZONE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Apply triggers (only if tables exist)
|
||||
DO $$
|
||||
BEGIN
|
||||
-- Stock critical trigger
|
||||
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'inventory_items') THEN
|
||||
DROP TRIGGER IF EXISTS stock_critical_trigger ON inventory_items;
|
||||
CREATE TRIGGER stock_critical_trigger
|
||||
AFTER UPDATE ON inventory_items
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION notify_stock_critical();
|
||||
END IF;
|
||||
|
||||
-- Temperature breach trigger
|
||||
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'temperature_readings') THEN
|
||||
DROP TRIGGER IF EXISTS temperature_breach_trigger ON temperature_readings;
|
||||
CREATE TRIGGER temperature_breach_trigger
|
||||
AFTER INSERT OR UPDATE ON temperature_readings
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION notify_temperature_breach();
|
||||
END IF;
|
||||
|
||||
-- Production delay trigger
|
||||
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'production_batches') THEN
|
||||
DROP TRIGGER IF EXISTS production_delay_trigger ON production_batches;
|
||||
CREATE TRIGGER production_delay_trigger
|
||||
AFTER UPDATE ON production_batches
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION notify_production_delay();
|
||||
END IF;
|
||||
END
|
||||
$$;
|
||||
Reference in New Issue
Block a user