Files
cannaiq/backend/migrations/057_visibility_tracking_columns.sql
Kelly 8ac64ba077 feat(cannaiq): Add Workers Dashboard and visibility tracking
Workers Dashboard:
- New /workers route with two-pane layout
- Workers table showing Alice, Henry, Bella, Oscar with role badges
- Run history with visibility stats (lost/restored counts)
- "Run Now" action to trigger workers immediately

Migrations:
- 057: Add visibility tracking columns (visibility_lost, visibility_lost_at, visibility_restored_at)
- 058: Add ID resolution columns for Henry worker
- 059: Add job queue columns (max_retries, retry_count, worker_id, locked_at, locked_by)

Backend fixes:
- Add httpStatus to CrawlResult interface for error classification
- Fix pool.ts typing for event listener
- Update completeJob to accept visibility stats in metadata

Frontend fixes:
- Fix NationalDashboard crash with safe formatMoney helper
- Fix OrchestratorDashboard/Stores StoreInfo type mismatches
- Add workerName/workerRole to getDutchieAZSchedules API type

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-07 11:04:12 -07:00

65 lines
2.8 KiB
SQL

-- Migration 057: Add visibility tracking columns to dutchie_products
--
-- Supports Bella (Product Sync) worker visibility-loss tracking:
-- - visibility_lost: TRUE when product disappears from GraphQL feed
-- - visibility_lost_at: Timestamp when product first went missing
-- - visibility_restored_at: Timestamp when product reappeared
--
-- These columns enable tracking of products that temporarily or permanently
-- disappear from Dutchie GraphQL API responses.
-- ============================================================
-- 1. ADD VISIBILITY TRACKING COLUMNS TO dutchie_products
-- ============================================================
ALTER TABLE dutchie_products
ADD COLUMN IF NOT EXISTS visibility_lost BOOLEAN DEFAULT FALSE,
ADD COLUMN IF NOT EXISTS visibility_lost_at TIMESTAMPTZ,
ADD COLUMN IF NOT EXISTS visibility_restored_at TIMESTAMPTZ;
COMMENT ON COLUMN dutchie_products.visibility_lost IS 'TRUE when product is missing from GraphQL feed';
COMMENT ON COLUMN dutchie_products.visibility_lost_at IS 'Timestamp when product first went missing from feed';
COMMENT ON COLUMN dutchie_products.visibility_restored_at IS 'Timestamp when product reappeared after being missing';
-- ============================================================
-- 2. CREATE INDEX FOR VISIBILITY QUERIES
-- ============================================================
CREATE INDEX IF NOT EXISTS idx_dutchie_products_visibility_lost
ON dutchie_products(visibility_lost)
WHERE visibility_lost = TRUE;
CREATE INDEX IF NOT EXISTS idx_dutchie_products_visibility_lost_at
ON dutchie_products(visibility_lost_at)
WHERE visibility_lost_at IS NOT NULL;
-- ============================================================
-- 3. CREATE VIEW FOR VISIBILITY ANALYTICS
-- ============================================================
CREATE OR REPLACE VIEW v_visibility_summary AS
SELECT
d.id AS dispensary_id,
d.name AS dispensary_name,
d.state,
COUNT(dp.id) AS total_products,
COUNT(dp.id) FILTER (WHERE dp.visibility_lost = TRUE) AS visibility_lost_count,
COUNT(dp.id) FILTER (WHERE dp.visibility_lost = FALSE OR dp.visibility_lost IS NULL) AS visible_count,
COUNT(dp.id) FILTER (WHERE dp.visibility_restored_at IS NOT NULL) AS restored_count,
MAX(dp.visibility_lost_at) AS latest_loss_at,
MAX(dp.visibility_restored_at) AS latest_restore_at
FROM dispensaries d
LEFT JOIN dutchie_products dp ON d.id = dp.dispensary_id
WHERE d.menu_type = 'dutchie'
GROUP BY d.id, d.name, d.state;
COMMENT ON VIEW v_visibility_summary IS 'Aggregated visibility metrics per dispensary for dashboard analytics';
-- ============================================================
-- 4. RECORD MIGRATION
-- ============================================================
INSERT INTO schema_migrations (version, name, applied_at)
VALUES (57, '057_visibility_tracking_columns', NOW())
ON CONFLICT (version) DO NOTHING;