Files
git.stella-ops.org/docs/db/schemas/notify.sql
StellaOps Bot 6a299d231f
Some checks failed
Docs CI / lint-and-preview (push) Has been cancelled
Policy Lint & Smoke / policy-lint (push) Has been cancelled
Add unit tests for Router configuration and transport layers
- Implemented tests for RouterConfig, RoutingOptions, StaticInstanceConfig, and RouterConfigOptions to ensure default values are set correctly.
- Added tests for RouterConfigProvider to validate configurations and ensure defaults are returned when no file is specified.
- Created tests for ConfigValidationResult to check success and error scenarios.
- Developed tests for ServiceCollectionExtensions to verify service registration for RouterConfig.
- Introduced UdpTransportTests to validate serialization, connection, request-response, and error handling in UDP transport.
- Added scripts for signing authority gaps and hashing DevPortal SDK snippets.
2025-12-05 08:01:47 +02:00

341 lines
12 KiB
PL/PgSQL

-- Notify Schema Migration 001: Initial Schema
-- Creates the notify schema for notifications, channels, and delivery tracking
-- Create schema
CREATE SCHEMA IF NOT EXISTS notify;
-- Channel types
DO $$ BEGIN
CREATE TYPE notify.channel_type AS ENUM (
'email', 'slack', 'teams', 'webhook', 'pagerduty', 'opsgenie'
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- Delivery status
DO $$ BEGIN
CREATE TYPE notify.delivery_status AS ENUM (
'pending', 'queued', 'sending', 'sent', 'delivered', 'failed', 'bounced'
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- Channels table
CREATE TABLE IF NOT EXISTS notify.channels (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
name TEXT NOT NULL,
channel_type notify.channel_type NOT NULL,
enabled BOOLEAN NOT NULL DEFAULT TRUE,
config JSONB NOT NULL DEFAULT '{}',
credentials JSONB,
metadata JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
created_by TEXT,
UNIQUE(tenant_id, name)
);
CREATE INDEX idx_channels_tenant ON notify.channels(tenant_id);
CREATE INDEX idx_channels_type ON notify.channels(tenant_id, channel_type);
-- Rules table (notification routing rules)
CREATE TABLE IF NOT EXISTS notify.rules (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
name TEXT NOT NULL,
description TEXT,
enabled BOOLEAN NOT NULL DEFAULT TRUE,
priority INT NOT NULL DEFAULT 0,
event_types TEXT[] NOT NULL DEFAULT '{}',
filter JSONB NOT NULL DEFAULT '{}',
channel_ids UUID[] NOT NULL DEFAULT '{}',
template_id UUID,
metadata JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(tenant_id, name)
);
CREATE INDEX idx_rules_tenant ON notify.rules(tenant_id);
CREATE INDEX idx_rules_enabled ON notify.rules(tenant_id, enabled, priority DESC);
-- Templates table
CREATE TABLE IF NOT EXISTS notify.templates (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
name TEXT NOT NULL,
channel_type notify.channel_type NOT NULL,
subject_template TEXT,
body_template TEXT NOT NULL,
locale TEXT NOT NULL DEFAULT 'en',
metadata JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(tenant_id, name, channel_type, locale)
);
CREATE INDEX idx_templates_tenant ON notify.templates(tenant_id);
-- Deliveries table
CREATE TABLE IF NOT EXISTS notify.deliveries (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
channel_id UUID NOT NULL REFERENCES notify.channels(id),
rule_id UUID REFERENCES notify.rules(id),
template_id UUID REFERENCES notify.templates(id),
status notify.delivery_status NOT NULL DEFAULT 'pending',
recipient TEXT NOT NULL,
subject TEXT,
body TEXT,
event_type TEXT NOT NULL,
event_payload JSONB NOT NULL DEFAULT '{}',
attempt INT NOT NULL DEFAULT 0,
max_attempts INT NOT NULL DEFAULT 3,
next_retry_at TIMESTAMPTZ,
error_message TEXT,
external_id TEXT,
correlation_id TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
queued_at TIMESTAMPTZ,
sent_at TIMESTAMPTZ,
delivered_at TIMESTAMPTZ,
failed_at TIMESTAMPTZ
);
CREATE INDEX idx_deliveries_tenant ON notify.deliveries(tenant_id);
CREATE INDEX idx_deliveries_status ON notify.deliveries(tenant_id, status);
CREATE INDEX idx_deliveries_pending ON notify.deliveries(status, next_retry_at)
WHERE status IN ('pending', 'queued');
CREATE INDEX idx_deliveries_channel ON notify.deliveries(channel_id);
CREATE INDEX idx_deliveries_correlation ON notify.deliveries(correlation_id);
CREATE INDEX idx_deliveries_created ON notify.deliveries(tenant_id, created_at);
-- Digests table (aggregated notifications)
CREATE TABLE IF NOT EXISTS notify.digests (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
channel_id UUID NOT NULL REFERENCES notify.channels(id),
recipient TEXT NOT NULL,
digest_key TEXT NOT NULL,
event_count INT NOT NULL DEFAULT 0,
events JSONB NOT NULL DEFAULT '[]',
status TEXT NOT NULL DEFAULT 'collecting' CHECK (status IN ('collecting', 'sending', 'sent')),
collect_until TIMESTAMPTZ NOT NULL,
sent_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(tenant_id, channel_id, recipient, digest_key)
);
CREATE INDEX idx_digests_tenant ON notify.digests(tenant_id);
CREATE INDEX idx_digests_collect ON notify.digests(status, collect_until)
WHERE status = 'collecting';
-- Quiet hours table
CREATE TABLE IF NOT EXISTS notify.quiet_hours (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
user_id UUID,
channel_id UUID REFERENCES notify.channels(id),
start_time TIME NOT NULL,
end_time TIME NOT NULL,
timezone TEXT NOT NULL DEFAULT 'UTC',
days_of_week INT[] NOT NULL DEFAULT '{0,1,2,3,4,5,6}',
enabled BOOLEAN NOT NULL DEFAULT TRUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_quiet_hours_tenant ON notify.quiet_hours(tenant_id);
-- Maintenance windows table
CREATE TABLE IF NOT EXISTS notify.maintenance_windows (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
name TEXT NOT NULL,
description TEXT,
start_at TIMESTAMPTZ NOT NULL,
end_at TIMESTAMPTZ NOT NULL,
suppress_channels UUID[],
suppress_event_types TEXT[],
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
created_by TEXT,
UNIQUE(tenant_id, name)
);
CREATE INDEX idx_maintenance_windows_tenant ON notify.maintenance_windows(tenant_id);
CREATE INDEX idx_maintenance_windows_active ON notify.maintenance_windows(start_at, end_at);
-- Escalation policies table
CREATE TABLE IF NOT EXISTS notify.escalation_policies (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
name TEXT NOT NULL,
description TEXT,
enabled BOOLEAN NOT NULL DEFAULT TRUE,
steps JSONB NOT NULL DEFAULT '[]',
repeat_count INT NOT NULL DEFAULT 0,
metadata JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(tenant_id, name)
);
CREATE INDEX idx_escalation_policies_tenant ON notify.escalation_policies(tenant_id);
-- Escalation states table
CREATE TABLE IF NOT EXISTS notify.escalation_states (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
policy_id UUID NOT NULL REFERENCES notify.escalation_policies(id),
incident_id UUID,
correlation_id TEXT NOT NULL,
current_step INT NOT NULL DEFAULT 0,
repeat_iteration INT NOT NULL DEFAULT 0,
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'acknowledged', 'resolved', 'expired')),
started_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
next_escalation_at TIMESTAMPTZ,
acknowledged_at TIMESTAMPTZ,
acknowledged_by TEXT,
resolved_at TIMESTAMPTZ,
resolved_by TEXT,
metadata JSONB NOT NULL DEFAULT '{}'
);
CREATE INDEX idx_escalation_states_tenant ON notify.escalation_states(tenant_id);
CREATE INDEX idx_escalation_states_active ON notify.escalation_states(status, next_escalation_at)
WHERE status = 'active';
CREATE INDEX idx_escalation_states_correlation ON notify.escalation_states(correlation_id);
-- On-call schedules table
CREATE TABLE IF NOT EXISTS notify.on_call_schedules (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
name TEXT NOT NULL,
description TEXT,
timezone TEXT NOT NULL DEFAULT 'UTC',
rotation_type TEXT NOT NULL DEFAULT 'weekly' CHECK (rotation_type IN ('daily', 'weekly', 'custom')),
participants JSONB NOT NULL DEFAULT '[]',
overrides JSONB NOT NULL DEFAULT '[]',
metadata JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(tenant_id, name)
);
CREATE INDEX idx_on_call_schedules_tenant ON notify.on_call_schedules(tenant_id);
-- Inbox table (in-app notifications)
CREATE TABLE IF NOT EXISTS notify.inbox (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
user_id UUID NOT NULL,
title TEXT NOT NULL,
body TEXT,
event_type TEXT NOT NULL,
event_payload JSONB NOT NULL DEFAULT '{}',
read BOOLEAN NOT NULL DEFAULT FALSE,
archived BOOLEAN NOT NULL DEFAULT FALSE,
action_url TEXT,
correlation_id TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
read_at TIMESTAMPTZ,
archived_at TIMESTAMPTZ
);
CREATE INDEX idx_inbox_tenant_user ON notify.inbox(tenant_id, user_id);
CREATE INDEX idx_inbox_unread ON notify.inbox(tenant_id, user_id, read, created_at DESC)
WHERE read = FALSE AND archived = FALSE;
-- Incidents table
CREATE TABLE IF NOT EXISTS notify.incidents (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
title TEXT NOT NULL,
description TEXT,
severity TEXT NOT NULL DEFAULT 'medium' CHECK (severity IN ('critical', 'high', 'medium', 'low')),
status TEXT NOT NULL DEFAULT 'open' CHECK (status IN ('open', 'acknowledged', 'resolved', 'closed')),
source TEXT,
correlation_id TEXT,
assigned_to UUID,
escalation_policy_id UUID REFERENCES notify.escalation_policies(id),
metadata JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
acknowledged_at TIMESTAMPTZ,
resolved_at TIMESTAMPTZ,
closed_at TIMESTAMPTZ,
created_by TEXT
);
CREATE INDEX idx_incidents_tenant ON notify.incidents(tenant_id);
CREATE INDEX idx_incidents_status ON notify.incidents(tenant_id, status);
CREATE INDEX idx_incidents_severity ON notify.incidents(tenant_id, severity);
CREATE INDEX idx_incidents_correlation ON notify.incidents(correlation_id);
-- Audit log table
CREATE TABLE IF NOT EXISTS notify.audit (
id BIGSERIAL PRIMARY KEY,
tenant_id TEXT NOT NULL,
user_id UUID,
action TEXT NOT NULL,
resource_type TEXT NOT NULL,
resource_id TEXT,
details JSONB,
correlation_id TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_audit_tenant ON notify.audit(tenant_id);
CREATE INDEX idx_audit_created ON notify.audit(tenant_id, created_at);
-- Locks table (lightweight distributed locks)
CREATE TABLE IF NOT EXISTS notify.locks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
tenant_id TEXT NOT NULL,
resource TEXT NOT NULL,
owner TEXT NOT NULL,
expires_at TIMESTAMPTZ NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(tenant_id, resource)
);
CREATE INDEX idx_locks_tenant ON notify.locks(tenant_id);
CREATE INDEX idx_locks_expiry ON notify.locks(expires_at);
-- Update timestamp function
CREATE OR REPLACE FUNCTION notify.update_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Triggers
CREATE TRIGGER trg_channels_updated_at
BEFORE UPDATE ON notify.channels
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
CREATE TRIGGER trg_rules_updated_at
BEFORE UPDATE ON notify.rules
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
CREATE TRIGGER trg_templates_updated_at
BEFORE UPDATE ON notify.templates
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
CREATE TRIGGER trg_digests_updated_at
BEFORE UPDATE ON notify.digests
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
CREATE TRIGGER trg_escalation_policies_updated_at
BEFORE UPDATE ON notify.escalation_policies
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
CREATE TRIGGER trg_on_call_schedules_updated_at
BEFORE UPDATE ON notify.on_call_schedules
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();