Major additions: - Multi-state expansion: states table, StateSelector, NationalDashboard, StateHeatmap, CrossStateCompare - Orchestrator services: trace service, error taxonomy, retry manager, proxy rotator - Discovery system: dutchie discovery service, geo validation, city seeding scripts - Analytics infrastructure: analytics v2 routes, brand/pricing/stores intelligence pages - Local development: setup-local.sh starts all 5 services (postgres, backend, cannaiq, findadispo, findagram) - Migrations 037-056: crawler profiles, states, analytics indexes, worker metadata Frontend pages added: - Discovery, ChainsDashboard, IntelligenceBrands, IntelligencePricing, IntelligenceStores - StateHeatmap, CrossStateCompare, SyncInfoPanel Components added: - StateSelector, OrchestratorTraceModal, WorkflowStepper 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
124 lines
5.8 KiB
SQL
124 lines
5.8 KiB
SQL
-- Migration 055: Workforce System Enhancements
|
|
-- Adds visibility tracking, slug change tracking, and scope support for workers
|
|
|
|
-- ============================================================
|
|
-- 1. VISIBILITY TRACKING FOR BELLA (Product Sync)
|
|
-- ============================================================
|
|
|
|
-- Add visibility tracking 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 if product disappeared from GraphQL results';
|
|
COMMENT ON COLUMN dutchie_products.visibility_lost_at IS 'When product was last marked as visibility lost';
|
|
COMMENT ON COLUMN dutchie_products.visibility_restored_at IS 'When product reappeared after being lost';
|
|
|
|
-- Index for visibility queries
|
|
CREATE INDEX IF NOT EXISTS idx_dutchie_products_visibility_lost
|
|
ON dutchie_products(dispensary_id, visibility_lost)
|
|
WHERE visibility_lost = TRUE;
|
|
|
|
-- ============================================================
|
|
-- 2. SLUG CHANGE TRACKING FOR ALICE (Store Discovery)
|
|
-- ============================================================
|
|
|
|
-- Add slug change and retirement tracking to discovery locations
|
|
ALTER TABLE dutchie_discovery_locations
|
|
ADD COLUMN IF NOT EXISTS slug_changed_at TIMESTAMPTZ,
|
|
ADD COLUMN IF NOT EXISTS previous_slug VARCHAR(255),
|
|
ADD COLUMN IF NOT EXISTS retired_at TIMESTAMPTZ,
|
|
ADD COLUMN IF NOT EXISTS retirement_reason VARCHAR(100);
|
|
|
|
COMMENT ON COLUMN dutchie_discovery_locations.slug_changed_at IS 'When the platform slug was last changed';
|
|
COMMENT ON COLUMN dutchie_discovery_locations.previous_slug IS 'Previous slug before the last change';
|
|
COMMENT ON COLUMN dutchie_discovery_locations.retired_at IS 'When store was marked as retired/removed';
|
|
COMMENT ON COLUMN dutchie_discovery_locations.retirement_reason IS 'Reason for retirement (removed_from_source, closed, etc.)';
|
|
|
|
-- Index for finding retired stores
|
|
CREATE INDEX IF NOT EXISTS idx_dutchie_discovery_locations_retired
|
|
ON dutchie_discovery_locations(retired_at)
|
|
WHERE retired_at IS NOT NULL;
|
|
|
|
-- ============================================================
|
|
-- 3. ID RESOLUTION TRACKING FOR HENRY (Entry Point Finder)
|
|
-- ============================================================
|
|
|
|
-- Add resolution tracking to dispensaries
|
|
ALTER TABLE dispensaries
|
|
ADD COLUMN IF NOT EXISTS last_id_resolution_at TIMESTAMPTZ,
|
|
ADD COLUMN IF NOT EXISTS id_resolution_attempts INT DEFAULT 0,
|
|
ADD COLUMN IF NOT EXISTS id_resolution_error TEXT;
|
|
|
|
COMMENT ON COLUMN dispensaries.last_id_resolution_at IS 'When platform_dispensary_id was last resolved/attempted';
|
|
COMMENT ON COLUMN dispensaries.id_resolution_attempts IS 'Number of resolution attempts';
|
|
COMMENT ON COLUMN dispensaries.id_resolution_error IS 'Last error message from resolution attempt';
|
|
|
|
-- Index for finding stores needing resolution
|
|
CREATE INDEX IF NOT EXISTS idx_dispensaries_needs_resolution
|
|
ON dispensaries(state, menu_type)
|
|
WHERE platform_dispensary_id IS NULL AND menu_type = 'dutchie';
|
|
|
|
-- ============================================================
|
|
-- 4. ENHANCED CITIES TABLE FOR ALICE
|
|
-- ============================================================
|
|
|
|
-- Add tracking columns to cities table
|
|
ALTER TABLE dutchie_discovery_cities
|
|
ADD COLUMN IF NOT EXISTS state_name VARCHAR(100),
|
|
ADD COLUMN IF NOT EXISTS discovered_at TIMESTAMPTZ DEFAULT NOW(),
|
|
ADD COLUMN IF NOT EXISTS last_verified_at TIMESTAMPTZ,
|
|
ADD COLUMN IF NOT EXISTS store_count_reported INT,
|
|
ADD COLUMN IF NOT EXISTS store_count_actual INT;
|
|
|
|
COMMENT ON COLUMN dutchie_discovery_cities.state_name IS 'Full state name from source';
|
|
COMMENT ON COLUMN dutchie_discovery_cities.discovered_at IS 'When city was first discovered';
|
|
COMMENT ON COLUMN dutchie_discovery_cities.last_verified_at IS 'When city was last verified to exist';
|
|
COMMENT ON COLUMN dutchie_discovery_cities.store_count_reported IS 'Store count reported by source';
|
|
COMMENT ON COLUMN dutchie_discovery_cities.store_count_actual IS 'Actual store count from discovery';
|
|
|
|
-- ============================================================
|
|
-- 5. UPDATE WORKER ROLES (Standardize naming)
|
|
-- ============================================================
|
|
|
|
-- Update existing workers to use standardized role names
|
|
UPDATE job_schedules SET worker_role = 'store_discovery'
|
|
WHERE worker_name = 'Alice' AND worker_role = 'Store Discovery';
|
|
|
|
UPDATE job_schedules SET worker_role = 'entry_point_finder'
|
|
WHERE worker_name = 'Henry' AND worker_role = 'Entry Point Finder';
|
|
|
|
UPDATE job_schedules SET worker_role = 'product_sync'
|
|
WHERE worker_name = 'Bella' AND worker_role = 'GraphQL Product Sync';
|
|
|
|
UPDATE job_schedules SET worker_role = 'analytics_refresh'
|
|
WHERE worker_name = 'Oscar' AND worker_role = 'Analytics Refresh';
|
|
|
|
-- ============================================================
|
|
-- 6. VISIBILITY EVENTS IN SNAPSHOTS (JSONB approach)
|
|
-- ============================================================
|
|
|
|
-- Add visibility_events array to product snapshots metadata
|
|
-- This will store: [{event_type, timestamp, worker_name}]
|
|
-- No schema change needed - we use existing metadata JSONB column
|
|
|
|
-- ============================================================
|
|
-- 7. INDEXES FOR WORKER QUERIES
|
|
-- ============================================================
|
|
|
|
-- Index for finding recently added stores (for Henry)
|
|
CREATE INDEX IF NOT EXISTS idx_dutchie_discovery_locations_created
|
|
ON dutchie_discovery_locations(created_at DESC)
|
|
WHERE active = TRUE;
|
|
|
|
-- Index for scope-based queries (by state)
|
|
CREATE INDEX IF NOT EXISTS idx_dispensaries_state_menu
|
|
ON dispensaries(state, menu_type)
|
|
WHERE menu_type IS NOT NULL;
|
|
|
|
-- Record migration
|
|
INSERT INTO schema_migrations (version, name, applied_at)
|
|
VALUES (55, '055_workforce_enhancements', NOW())
|
|
ON CONFLICT (version) DO NOTHING;
|