-- Migration 015: Create notification tables -- NotificationRule: admin-defined rules for triggering notifications -- Notification: individual notification instance -- NotificationDelivery: tracks delivery attempts per channel -- Admin-defined notification rule CREATE TABLE notification_rules ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), name VARCHAR(200) NOT NULL, description TEXT, is_active BOOLEAN NOT NULL DEFAULT TRUE, -- Event types that trigger this rule (array of event_type strings) event_types VARCHAR(50)[] NOT NULL, -- Channels to deliver through (array of notification_channel strings) channels VARCHAR(10)[] NOT NULL, -- Target roles (array of team_role strings, optional) target_roles VARCHAR(20)[], -- Custom conditions for triggering (JSONB) conditions JSONB NOT NULL DEFAULT '{}'::JSONB, -- Templates subject_template VARCHAR(500), body_template TEXT ); -- M2M: NotificationRule targets specific TeamProfiles CREATE TABLE notification_rule_team_profiles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), rule_id UUID NOT NULL REFERENCES notification_rules(id) ON DELETE CASCADE, team_profile_id UUID NOT NULL REFERENCES team_profiles(id) ON DELETE CASCADE, UNIQUE (rule_id, team_profile_id) ); -- M2M: NotificationRule targets specific CustomerProfiles CREATE TABLE notification_rule_customer_profiles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), rule_id UUID NOT NULL REFERENCES notification_rules(id) ON DELETE CASCADE, customer_profile_id UUID NOT NULL REFERENCES customer_profiles(id) ON DELETE CASCADE, UNIQUE (rule_id, customer_profile_id) ); -- Individual notification instance CREATE TABLE notifications ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Polymorphic: recipient type recipient_type VARCHAR(20) NOT NULL, -- 'team_profile' or 'customer_profile' recipient_id UUID NOT NULL, -- References rule_id UUID REFERENCES notification_rules(id) ON DELETE SET NULL, event_id UUID, -- FK added in migration 016 after events table exists status notification_status NOT NULL DEFAULT 'PENDING', subject VARCHAR(500) NOT NULL, body TEXT NOT NULL, -- URL to navigate to when notification is clicked action_url VARCHAR(500), read_at TIMESTAMPTZ, metadata JSONB NOT NULL DEFAULT '{}'::JSONB ); -- Notification delivery attempt CREATE TABLE notification_deliveries ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), notification_id UUID NOT NULL REFERENCES notifications(id) ON DELETE CASCADE, channel notification_channel NOT NULL, status delivery_status NOT NULL DEFAULT 'PENDING', attempts INTEGER NOT NULL DEFAULT 0 CHECK (attempts >= 0), last_attempt_at TIMESTAMPTZ, sent_at TIMESTAMPTZ, delivered_at TIMESTAMPTZ, error_message TEXT, -- External service ID (e.g., email provider message ID) external_id VARCHAR(200), metadata JSONB NOT NULL DEFAULT '{}'::JSONB ); -- Indexes CREATE INDEX idx_notification_rules_active ON notification_rules(is_active); CREATE INDEX idx_notification_rule_team_profiles_rule ON notification_rule_team_profiles(rule_id); CREATE INDEX idx_notification_rule_customer_profiles_rule ON notification_rule_customer_profiles(rule_id); CREATE INDEX idx_notifications_recipient ON notifications(recipient_type, recipient_id); CREATE INDEX idx_notifications_status ON notifications(status); CREATE INDEX idx_notifications_created ON notifications(created_at DESC); CREATE INDEX idx_notification_deliveries_notification ON notification_deliveries(notification_id); CREATE INDEX idx_notification_deliveries_status ON notification_deliveries(status);