-- ============================================================ -- Migration: 010_create_notification_history -- Date: 2025-01-26 -- Description: Create table for logging all sent notifications -- ============================================================ -- UP: Apply migration -- ============================================================ CREATE TABLE IF NOT EXISTS notification_history ( id SERIAL PRIMARY KEY, -- Who received the notification user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE, -- Related beneficiary (optional, for beneficiary-related notifications) beneficiary_id INTEGER REFERENCES users(id) ON DELETE SET NULL, -- Notification content title VARCHAR(255) NOT NULL, body TEXT NOT NULL, -- Notification type (emergency, activity, low_battery, daily, weekly, system) type VARCHAR(50) NOT NULL, -- Delivery channel (push, email, sms) channel VARCHAR(20) NOT NULL DEFAULT 'push', -- Delivery status status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN ( 'pending', -- queued for delivery 'sent', -- successfully sent to provider 'delivered', -- confirmed delivered (if supported) 'failed', -- delivery failed 'skipped' -- skipped due to settings )), -- Skip/failure reason (if applicable) skip_reason VARCHAR(100), -- Additional data payload (JSON) data JSONB, -- Expo push ticket ID (for tracking delivery status) expo_ticket_id VARCHAR(255), -- Error details (if failed) error_message TEXT, -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), sent_at TIMESTAMPTZ, delivered_at TIMESTAMPTZ ); -- Indexes for common queries CREATE INDEX IF NOT EXISTS idx_notification_history_user ON notification_history(user_id); CREATE INDEX IF NOT EXISTS idx_notification_history_beneficiary ON notification_history(beneficiary_id); CREATE INDEX IF NOT EXISTS idx_notification_history_type ON notification_history(type); CREATE INDEX IF NOT EXISTS idx_notification_history_status ON notification_history(status); CREATE INDEX IF NOT EXISTS idx_notification_history_created ON notification_history(created_at DESC); CREATE INDEX IF NOT EXISTS idx_notification_history_user_created ON notification_history(user_id, created_at DESC); -- Comments COMMENT ON TABLE notification_history IS 'Log of all sent/attempted notifications'; COMMENT ON COLUMN notification_history.type IS 'Notification type: emergency, activity, low_battery, daily, weekly, system'; COMMENT ON COLUMN notification_history.channel IS 'Delivery channel: push, email, sms'; COMMENT ON COLUMN notification_history.status IS 'Delivery status: pending, sent, delivered, failed, skipped'; COMMENT ON COLUMN notification_history.skip_reason IS 'Reason for skipping: push_disabled, quiet_hours, no_tokens, etc.'; COMMENT ON COLUMN notification_history.expo_ticket_id IS 'Expo Push API ticket ID for delivery tracking'; -- ============================================================ -- DOWN: Rollback migration (for reference only) -- ============================================================ -- DROP TABLE IF EXISTS notification_history;