-- Migration 068: Crawler Status Alerts -- Creates status_alerts table for dashboard notifications and status change logging -- ============================================================ -- STATUS ALERTS TABLE -- ============================================================ CREATE TABLE IF NOT EXISTS crawler_status_alerts ( id SERIAL PRIMARY KEY, -- References dispensary_id INTEGER REFERENCES dispensaries(id), profile_id INTEGER REFERENCES dispensary_crawler_profiles(id), -- Alert info alert_type VARCHAR(50) NOT NULL, -- 'status_change', 'crawl_error', 'validation_failed', 'promoted', 'demoted' severity VARCHAR(20) DEFAULT 'info', -- 'info', 'warning', 'error', 'critical' -- Status transition previous_status VARCHAR(50), new_status VARCHAR(50), -- Context message TEXT, error_details JSONB, metadata JSONB, -- Additional context (product counts, error codes, etc.) -- Tracking acknowledged BOOLEAN DEFAULT FALSE, acknowledged_at TIMESTAMP WITH TIME ZONE, acknowledged_by VARCHAR(100), -- Timestamps created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Indexes for common queries CREATE INDEX IF NOT EXISTS idx_crawler_status_alerts_dispensary ON crawler_status_alerts(dispensary_id); CREATE INDEX IF NOT EXISTS idx_crawler_status_alerts_type ON crawler_status_alerts(alert_type); CREATE INDEX IF NOT EXISTS idx_crawler_status_alerts_severity ON crawler_status_alerts(severity); CREATE INDEX IF NOT EXISTS idx_crawler_status_alerts_unack ON crawler_status_alerts(acknowledged) WHERE acknowledged = FALSE; CREATE INDEX IF NOT EXISTS idx_crawler_status_alerts_created ON crawler_status_alerts(created_at DESC); -- ============================================================ -- STATUS DEFINITIONS (for reference/validation) -- ============================================================ COMMENT ON TABLE crawler_status_alerts IS 'Crawler status change notifications for dashboard alerting'; COMMENT ON COLUMN crawler_status_alerts.alert_type IS 'Type: status_change, crawl_error, validation_failed, promoted, demoted'; COMMENT ON COLUMN crawler_status_alerts.severity IS 'Severity: info, warning, error, critical'; COMMENT ON COLUMN crawler_status_alerts.previous_status IS 'Previous crawler status before change'; COMMENT ON COLUMN crawler_status_alerts.new_status IS 'New crawler status after change'; -- ============================================================ -- STATUS TRACKING ON PROFILES -- ============================================================ -- Add columns for status tracking if not exists DO $$ BEGIN -- Consecutive success count for auto-promotion IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'dispensary_crawler_profiles' AND column_name = 'consecutive_successes') THEN ALTER TABLE dispensary_crawler_profiles ADD COLUMN consecutive_successes INTEGER DEFAULT 0; END IF; -- Consecutive failure count for auto-demotion IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'dispensary_crawler_profiles' AND column_name = 'consecutive_failures') THEN ALTER TABLE dispensary_crawler_profiles ADD COLUMN consecutive_failures INTEGER DEFAULT 0; END IF; -- Last status change timestamp IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'dispensary_crawler_profiles' AND column_name = 'status_changed_at') THEN ALTER TABLE dispensary_crawler_profiles ADD COLUMN status_changed_at TIMESTAMP WITH TIME ZONE; END IF; -- Status change reason IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'dispensary_crawler_profiles' AND column_name = 'status_reason') THEN ALTER TABLE dispensary_crawler_profiles ADD COLUMN status_reason TEXT; END IF; END $$; -- ============================================================ -- VALID STATUS VALUES -- ============================================================ -- Status values for dispensary_crawler_profiles.status: -- 'sandbox' - Newly created, being validated -- 'production' - Healthy, actively crawled -- 'needs_manual' - Requires human intervention -- 'failing' - Multiple consecutive failures -- 'disabled' - Manually disabled -- 'legacy' - No profile, uses default method (virtual status)